Automatically set PRAGMAs using connection query params (#85)

* Automatically set PRAGMAs using connection query params

Introduce the flexibility to adjust certain PRAGMAs of the SQLite3
connection without having to hardcode those in your codebase (and wait
for compilation).

This allows applications to use `DATABASE_URL` to dynamically fine tune
their SQLite3 configuration.

The change complements `#setup_connection` that offers, via code, the
option to perform queries on setup of each connection.

Only a few PRAGMAs necessary to allow more performant concurrent reads
and reduce write locking.

These pragmas are detected and combined in a single SQL string to reduce
to 1 the number of calls to `sqlite3_exec` C function.

There is no validation of supplied values as SQLite3 automatically
ignores incorrect values for these pragmas.

Closes #84

References:
- https://www.sqlite.org/pragma.html

* Simplify PRAGMA mapping and detection

No longer prefix PRAGMAS with `_`, so the mapping between the real
SQLite3 pragmas and the usage in the URI is more direct.

Use macros instead of case to detect pragmas from URI params and return
those as NamedTuple.

* Update README.md

---------

Co-authored-by: Brian J. Cardiff <bcardiff@gmail.com>
This commit is contained in:
Luis Lavena 2023-02-18 21:06:09 +01:00 committed by GitHub
parent d15a8da05c
commit 84857724c1
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
4 changed files with 117 additions and 1 deletions

View file

@ -48,3 +48,39 @@ end
* `Time` is implemented as `TEXT` column using `SQLite3::DATE_FORMAT_SUBSECOND` format (or `SQLite3::DATE_FORMAT_SECOND` if the text does not contain a dot). * `Time` is implemented as `TEXT` column using `SQLite3::DATE_FORMAT_SUBSECOND` format (or `SQLite3::DATE_FORMAT_SECOND` if the text does not contain a dot).
* `Bool` is implemented as `INT` column mapping `0`/`1` values. * `Bool` is implemented as `INT` column mapping `0`/`1` values.
### Setting PRAGMAs
You can adjust certain [SQLite3 PRAGMAs](https://www.sqlite.org/pragma.html)
automatically when the connection is created by using the query parameters:
```crystal
require "sqlite3"
DB.open "sqlite3://./data.db?journal_mode=wal&synchronous=normal" do |db|
# this database now uses WAL journal and normal synchronous mode
# (defaults were `delete` and `full`, respectively)
end
```
The following is the list of supported options:
| Name | Connection key |
|---------------------------|-----------------|
| [Busy Timeout][pragma-to] | `busy_timeout` |
| [Cache Size][pragma-cs] | `cache_size` |
| [Foreign Keys][pragma-fk] | `foreign_keys` |
| [Journal Mode][pragma-jm] | `journal_mode` |
| [Synchronous][pragma-sync] | `synchronous` |
| [WAL autocheckoint][pragma-walck] | `wal_autocheckpoint` |
Please note there values passed using these connection keys are passed
directly to SQLite3 without check or evaluation. Using incorrect values result
in no error by the library.
[pragma-to]: https://www.sqlite.org/pragma.html#pragma_busy_timeout
[pragma-cs]: https://www.sqlite.org/pragma.html#pragma_cache_size
[pragma-fk]: https://www.sqlite.org/pragma.html#pragma_foreign_keys
[pragma-jm]: https://www.sqlite.org/pragma.html#pragma_journal_mode
[pragma-sync]: https://www.sqlite.org/pragma.html#pragma_synchronous
[pragma-walck]: https://www.sqlite.org/pragma.html#pragma_wal_autocheckpoint

View file

@ -10,6 +10,14 @@ private def dump(source, target)
end end
end end
private def it_sets_pragma_on_connection(pragma : String, value : String, expected, file = __FILE__, line = __LINE__)
it "sets pragma '#{pragma}' to #{expected}", file, line do
with_db("#{DB_FILENAME}?#{pragma}=#{value}") do |db|
db.scalar("PRAGMA #{pragma}").should eq(expected)
end
end
end
describe Connection do describe Connection do
it "opens a database and then backs it up to another db" do it "opens a database and then backs it up to another db" do
with_db do |db| with_db do |db|
@ -68,4 +76,34 @@ describe Connection do
cnn.scalar("select count(*) from person").should eq(1) cnn.scalar("select count(*) from person").should eq(1)
end end
end end
# adjust busy_timeout pragma (default is 0)
it_sets_pragma_on_connection "busy_timeout", "1000", 1000
# adjust cache_size pragma (default is -2000, 2MB)
it_sets_pragma_on_connection "cache_size", "-4000", -4000
# enable foreign_keys, no need to test off (is the default)
it_sets_pragma_on_connection "foreign_keys", "1", 1
it_sets_pragma_on_connection "foreign_keys", "yes", 1
it_sets_pragma_on_connection "foreign_keys", "true", 1
it_sets_pragma_on_connection "foreign_keys", "on", 1
# change journal_mode (default is delete)
it_sets_pragma_on_connection "journal_mode", "delete", "delete"
it_sets_pragma_on_connection "journal_mode", "truncate", "truncate"
it_sets_pragma_on_connection "journal_mode", "persist", "persist"
# change synchronous mode (default is 2, FULL)
it_sets_pragma_on_connection "synchronous", "0", 0
it_sets_pragma_on_connection "synchronous", "off", 0
it_sets_pragma_on_connection "synchronous", "1", 1
it_sets_pragma_on_connection "synchronous", "normal", 1
it_sets_pragma_on_connection "synchronous", "2", 2
it_sets_pragma_on_connection "synchronous", "full", 2
it_sets_pragma_on_connection "synchronous", "3", 3
it_sets_pragma_on_connection "synchronous", "extra", 3
# change wal_autocheckpoint (default is 1000)
it_sets_pragma_on_connection "wal_autocheckpoint", "0", 0
end end

View file

@ -2,10 +2,11 @@ class SQLite3::Connection < DB::Connection
def initialize(database) def initialize(database)
super super
filename = self.class.filename(database.uri) filename = self.class.filename(database.uri)
# TODO maybe enable Flag::URI to parse query string in the uri as additional flags
check LibSQLite3.open_v2(filename, out @db, (Flag::READWRITE | Flag::CREATE), nil) check LibSQLite3.open_v2(filename, out @db, (Flag::READWRITE | Flag::CREATE), nil)
# 2 means 2 arguments; 1 is the code for UTF-8 # 2 means 2 arguments; 1 is the code for UTF-8
check LibSQLite3.create_function(@db, "regexp", 2, 1, nil, SQLite3::REGEXP_FN, nil, nil) check LibSQLite3.create_function(@db, "regexp", 2, 1, nil, SQLite3::REGEXP_FN, nil, nil)
process_query_params(database.uri)
rescue rescue
raise DB::ConnectionRefused.new raise DB::ConnectionRefused.new
end end
@ -88,4 +89,44 @@ class SQLite3::Connection < DB::Connection
private def check(code) private def check(code)
raise Exception.new(self) unless code == 0 raise Exception.new(self) unless code == 0
end end
private def process_query_params(uri : URI)
return unless query = uri.query
detected_pragmas = extract_params(query,
busy_timeout: nil,
cache_size: nil,
foreign_keys: nil,
journal_mode: nil,
synchronous: nil,
wal_autocheckpoint: nil,
)
# concatenate all into a single SQL string
sql = String.build do |str|
detected_pragmas.each do |key, value|
next unless value
str << "PRAGMA #{key}=#{value};"
end
end
check LibSQLite3.exec(@db, sql, nil, nil, nil)
end
private def extract_params(query : String, **default : **T) forall T
res = default
URI::Params.parse(query) do |key, value|
{% begin %}
case key
{% for key in T %}
when {{ key.stringify }}
res = res.merge({{key.id}}: value)
{% end %}
end
{% end %}
end
res
end
end end

View file

@ -86,6 +86,7 @@ lib LibSQLite3
fun backup_finish = sqlite3_backup_finish(SQLite3Backup) : Code fun backup_finish = sqlite3_backup_finish(SQLite3Backup) : Code
fun prepare_v2 = sqlite3_prepare_v2(db : SQLite3, zSql : UInt8*, nByte : Int32, ppStmt : Statement*, pzTail : UInt8**) : Int32 fun prepare_v2 = sqlite3_prepare_v2(db : SQLite3, zSql : UInt8*, nByte : Int32, ppStmt : Statement*, pzTail : UInt8**) : Int32
fun exec = sqlite3_exec(db : SQLite3, zSql : UInt8*, pCallback : Callback, pCallbackArgs : Void*, pzErrMsg : UInt8**) : Int32
fun step = sqlite3_step(stmt : Statement) : Int32 fun step = sqlite3_step(stmt : Statement) : Int32
fun column_count = sqlite3_column_count(stmt : Statement) : Int32 fun column_count = sqlite3_column_count(stmt : Statement) : Int32
fun column_type = sqlite3_column_type(stmt : Statement, iCol : Int32) : ::SQLite3::Type fun column_type = sqlite3_column_type(stmt : Statement, iCol : Int32) : ::SQLite3::Type