|
The RBU extension is an add-on for SQLite that facilitates rapid incremental updates of large SQLite database files on low-power devices at the edge of a network.
The RBU name stands for "Resumable Bulk Update".
Updating an SQLite database file on a remote device can normally be accomplished simply by sending the text of various INSERT, DELETE, and UPDATE commands to the device and evaluating them all inside of a transaction. RBU provides some advantages over this simple approach:
The most efficient way to apply changes to a B-Tree is to make the changes in row order. But if an SQL table has indexes, the row order for the indexes will all be different from each other and from the row order of the original table. RBU works around this by applying all changes to the table in one pass, then applying changes to each index in separate passes, thus updating each B-Trees in its optimal sequence. For a large database file (one that does not fit in the OS disk cache) this procedure can result in two orders of magnitude faster updates.
The changes can be applied to the database file by a background process that does not interfere with read access to the database file.
The changes can be applied to the database incrementally, with intervening power outages and/or system resets. And yet the original unmodified data remains visible to the device until the moment that entire change set commits.
The following limitations apply to RBU updates:
The changes must consist of INSERT, UPDATE, and DELETE operations only. CREATE and DROP operations are not supported.
INSERT statements may not use default values.
UPDATE and DELETE statements must identify the target rows by rowid or by non-NULL PRIMARY KEY values.
UPDATE statements may not modify PRIMARY KEY or rowid values.
RBU updates cannot be applied to any tables that contain a column named "rbu_control".
The RBU update will not fire any triggers.
The RBU update will not detect or prevent foreign key or CHECK constraint violations.
All RBU updates us the "OR ROLLBACK" constraint handling mechanism.
The target database may not be in WAL mode.
No other writes may occur on the target database while the RBU update is being applied. A read-lock is held on the target database to prevent this.
All changes to be applied by RBU are stored in a separate SQLite database called the "RBU database". The database that is to be modified is called the "target database".
For each table in the target database, the RBU database should contain a table named "data_<target-table-name>" with the all the same columns as the target table, plus one additional column named "rbu_control". The data_% table should have no PRIMARY KEY or UNIQUE constraints, but each column should have the same type as the corresponding column in the target database. The rbu_control column should have no type at all. For example, if the target database contains:
CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT, c UNIQUE);
Then the RBU database should contain:
CREATE TABLE data_t1(a INTEGER, b TEXT, c, rbu_control);
The order of the columns in the data_% table does not matter.
If the target database table is a virtual table or a table that has no PRIMARY KEY declaration, the data_% table must also contain a column named "rbu_rowid". The rbu_rowid column is mapped to the tables ROWID. For example, if the target database contains either of the following:
CREATE VIRTUAL TABLE x1 USING fts3(a, b); CREATE TABLE x1(a, b);
then the RBU database should contain:
CREATE TABLE data_x1(a, b, rbu_rowid, rbu_control);
Virtual tables for which the "rowid" column does not function like a primary key value cannot be updated using RBU.
All non-hidden columns (i.e. all columns matched by "SELECT *") of the target table must be present in the input table. For virtual tables, hidden columns are optional - they are updated by RBU if present in the input table, or not otherwise. For example, to write to an fts4 table with a hidden languageid column such as:
CREATE VIRTUAL TABLE ft1 USING fts4(a, b, languageid='langid');
Either of the following input table schemas may be used:
CREATE TABLE data_ft1(a, b, langid, rbu_rowid, rbu_control); CREATE TABLE data_ft1(a, b, rbu_rowid, rbu_control);
For each row to INSERT into the target database as part of the RBU update, the corresponding data_% table should contain a single record with the "rbu_control" column set to contain integer value 0. The other columns should be set to the values that make up the new record to insert.
If the target database table has an INTEGER PRIMARY KEY, it is not possible to insert a NULL value into the IPK column. Attempting to do so results in an SQLITE_MISMATCH error.
For each row to DELETE from the target database as part of the RBU update, the corresponding data_% table should contain a single record with the "rbu_control" column set to contain integer value 1. The real primary key values of the row to delete should be stored in the corresponding columns of the data_% table. The values stored in the other columns are not used.
For each row to UPDATE from the target database as part of the RBU update, the corresponding data_% table should contain a single record with the "rbu_control" column set to contain a value of type text. The real primary key values identifying the row to update should be stored in the corresponding columns of the data_% table row, as should the new values of all columns being update. The text value in the "rbu_control" column must contain the same number of characters as there are columns in the target database table, and must consist entirely of 'x' and '.' characters (or in some special cases 'd' - see below). For each column that is being updated, the corresponding character is set to 'x'. For those that remain as they are, the corresponding character of the rbu_control value should be set to '.'. For example, given the tables above, the update statement:
UPDATE t1 SET c = 'usa' WHERE a = 4;
is represented by the data_t1 row created by:
INSERT INTO data_t1(a, b, c, rbu_control) VALUES(4, NULL, 'usa', '..x');
Instead of an 'x' character, characters of the rbu_control value specified for UPDATEs may also be set to 'd'. In this case, instead of updating the target table with the value stored in the corresponding data_% column, the user-defined SQL function "rbu_delta()" is invoked and the result stored in the target table column. rbu_delta() is invoked with two arguments - the original value currently stored in the target table column and the value specified in the data_xxx table.
For example, this row:
INSERT INTO data_t1(a, b, c, rbu_control) VALUES(4, NULL, 'usa', '..d');
is similar to an UPDATE statement such as:
UPDATE t1 SET c = rbu_delta(c, 'usa') WHERE a = 4;
If the target database table is a virtual table or a table with no PRIMARY KEY, the rbu_control value should not include a character corresponding to the rbu_rowid value. For example, this:
INSERT INTO data_ft1(a, b, rbu_rowid, rbu_control) VALUES(NULL, 'usa', 12, '.x');
causes a result similar to:
UPDATE ft1 SET b = 'usa' WHERE rowid = 12;
The data_xxx tables themselves should have no PRIMARY KEY declarations. However, RBU is more efficient if reading the rows in from each data_xxx table in "rowid" order is roughly the same as reading them sorted by the PRIMARY KEY of the corresponding target database table. In other words, rows should be sorted using the destination table PRIMARY KEY fields before they are inserted into the data_xxx tables.
Enable the RBU extension by compiling the amalgamation with the SQLITE_ENABLE_RBU compile-time option.
The RBU extension interface allows an application to apply an RBU update stored in an RBU database to an existing target database. The procedures is as follows:
Open an RBU handle using the sqlite3rbu_open(T,A,S) function.
The T argument is the name of the target database file. The A argument is the name of the RBU database file. The S argument is the name of a "state database" used to store state information needed to resume the update after an interruption. The S argument can be NULL in which case the state information is stored in the RBU database in various tables whose names all begin with "rbu_".
The sqlite3rbu_open(T,A,S) function returns a pointer to an "sqlite3rbu" object, which is then passed into the subsequent interfaces.
Register any required virtual table modules with the database handle returned by sqlite3rbu_db(X) (where argument X is the sqlite3rbu pointer returned from sqlite3rbu_open()). Also, if required, register the rbu_delta() SQL function using sqlite3_create_function_v2().
Invoke the sqlite3rbu_step(X) function one or more times on the sqlite3rbu object pointer X. Each call to sqlite3rbu_step() performs a single b-tree operation, so thousands of calls may be required to apply a complete update. The sqlite3rbu_step() interface will return SQLITE_DONE when the update has been completely applied.
Call sqlite3rbu_close(X) to destroy the sqlite3rbu object pointer. If sqlite3rbu_step(X) has been called enough times to completely apply the update to the target database, then the RBU database is marked as fully applied. Otherwise, the state of the RBU update application is saved in the state database (or in the RBU database if the name of the state database file in sqlite3rbu_open() is NULL) for later resumption of the update.
If an update is only partially applied to the target database by the time sqlite3rbu_close() is called, state information is saved within the state database if it exists, or otherwise in the RBU database. This allows subsequent processes to automatically resume the RBU update from where it left off. If state information is stored in the RBU database, it can be removed by dropping all tables whose names begin with "rbu_".