From a77b14bcea8b0f7189879256af4ffb9dcdefff8b Mon Sep 17 00:00:00 2001 From: Luis Lavena Date: Sun, 15 Jan 2023 19:27:27 +0100 Subject: [PATCH] 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 --- README.md | 36 ++++++++++++++++++++++++++++++++++++ spec/connection_spec.cr | 38 ++++++++++++++++++++++++++++++++++++++ src/sqlite3/connection.cr | 35 ++++++++++++++++++++++++++++++++++- src/sqlite3/lib_sqlite3.cr | 1 + 4 files changed, 109 insertions(+), 1 deletion(-) diff --git a/README.md b/README.md index eeef632..6086f06 100644 --- a/README.md +++ b/README.md @@ -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). * `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 diff --git a/spec/connection_spec.cr b/spec/connection_spec.cr index be3bf0c..0eabc13 100644 --- a/spec/connection_spec.cr +++ b/spec/connection_spec.cr @@ -10,6 +10,14 @@ private def dump(source, target) end end +private def it_sets_pragma_on_connection(pragma : String, option : String, value : String, expected, file = __FILE__, line = __LINE__) + it "sets pragma '#{pragma}' to #{expected} using '#{option}'", file, line do + with_db("#{DB_FILENAME}?#{option}=#{value}") do |db| + db.scalar("PRAGMA #{pragma}").should eq(expected) + end + end +end + describe Connection do it "opens a database and then backs it up to another db" do with_db do |db| @@ -68,4 +76,34 @@ describe Connection do cnn.scalar("select count(*) from person").should eq(1) end end + + # adjust busy_timeout pragma (default is 0) + it_sets_pragma_on_connection "busy_timeout", "_busy_timeout", "1000", 1000 + + # adjust cache_size pragma (default is -2000, 2MB) + it_sets_pragma_on_connection "cache_size", "_cache_size", "-4000", -4000 + + # enable foreign_keys, no need to test off (is the default) + it_sets_pragma_on_connection "foreign_keys", "_foreign_keys", "1", 1 + it_sets_pragma_on_connection "foreign_keys", "_foreign_keys", "yes", 1 + it_sets_pragma_on_connection "foreign_keys", "_foreign_keys", "true", 1 + it_sets_pragma_on_connection "foreign_keys", "_foreign_keys", "on", 1 + + # change journal_mode (default is delete) + it_sets_pragma_on_connection "journal_mode", "_journal_mode", "delete", "delete" + it_sets_pragma_on_connection "journal_mode", "_journal_mode", "truncate", "truncate" + it_sets_pragma_on_connection "journal_mode", "_journal_mode", "persist", "persist" + + # change synchronous mode (default is 2, FULL) + it_sets_pragma_on_connection "synchronous", "_synchronous", "0", 0 + it_sets_pragma_on_connection "synchronous", "_synchronous", "off", 0 + it_sets_pragma_on_connection "synchronous", "_synchronous", "1", 1 + it_sets_pragma_on_connection "synchronous", "_synchronous", "normal", 1 + it_sets_pragma_on_connection "synchronous", "_synchronous", "2", 2 + it_sets_pragma_on_connection "synchronous", "_synchronous", "full", 2 + it_sets_pragma_on_connection "synchronous", "_synchronous", "3", 3 + it_sets_pragma_on_connection "synchronous", "_synchronous", "extra", 3 + + # change wal_autocheckpoint (default is 1000) + it_sets_pragma_on_connection "wal_autocheckpoint", "_wal_autocheckpoint", "0", 0 end diff --git a/src/sqlite3/connection.cr b/src/sqlite3/connection.cr index ca60043..ec07224 100644 --- a/src/sqlite3/connection.cr +++ b/src/sqlite3/connection.cr @@ -2,10 +2,11 @@ class SQLite3::Connection < DB::Connection def initialize(database) super 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) # 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) + + process_query_params(database.uri) rescue raise DB::ConnectionRefused.new end @@ -88,4 +89,36 @@ class SQLite3::Connection < DB::Connection private def check(code) raise Exception.new(self) unless code == 0 end + + private def process_query_params(uri : URI) + return unless query = uri.query + + pragmas = Hash(String, String).new + + URI::Params.parse(query) do |key, value| + case key + when "_busy_timeout" + pragmas["busy_timeout"] = value + when "_cache_size" + pragmas["cache_size"] = value + when "_foreign_keys" + pragmas["foreign_keys"] = value + when "_journal_mode" + pragmas["journal_mode"] = value + when "_synchronous" + pragmas["synchronous"] = value + when "_wal_autocheckpoint" + pragmas["wal_autocheckpoint"] = value + end + end + + # concatenate all into a single SQL string + sql = String.build do |str| + pragmas.each do |key, value| + str << "PRAGMA #{key}=#{value};" + end + end + + check LibSQLite3.exec(@db, sql, nil, nil, nil) + end end diff --git a/src/sqlite3/lib_sqlite3.cr b/src/sqlite3/lib_sqlite3.cr index 9455f8b..310e69c 100644 --- a/src/sqlite3/lib_sqlite3.cr +++ b/src/sqlite3/lib_sqlite3.cr @@ -86,6 +86,7 @@ lib LibSQLite3 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 exec = sqlite3_exec(db : SQLite3, zSql : UInt8*, pCallback : Callback, pCallbackArgs : Void*, pzErrMsg : UInt8**) : Int32 fun step = sqlite3_step(stmt : Statement) : Int32 fun column_count = sqlite3_column_count(stmt : Statement) : Int32 fun column_type = sqlite3_column_type(stmt : Statement, iCol : Int32) : ::SQLite3::Type