Virtual Tables

Virtual Tables are a feature introduced in SQLite 3.3.7. They let a developer provide an underlying table implementations, while still presenting a normal SQL interface to the user. The person writing SQL doesn’t need to know or care that some of the tables come from elsewhere.

Some examples of how you might use this:

  • Translating to/from information stored in other formats (eg a csv/ini format file)

  • Accessing the data remotely (eg you could make a table that backends into Amazon’s API)

  • Dynamic information (eg currently running processes, files and directories, objects in your program)

  • Information that needs reformatting (eg if you have complex rules about how to convert strings to/from Unicode in the dataset)

  • Information that isn’t relationally correct (eg if you have data that has ended up with duplicate “unique” keys with code that dynamically corrects it)

  • There are other examples on the SQLite page

You need to have 3 types of object. A module, a virtual table and a cursor. These are documented below. You can also read the SQLite C method documentation. At the C level, they are just one set of methods. At the Python/APSW level, they are split over the 3 types of object. The leading x is omitted in Python. You can return SQLite error codes (eg SQLITE_READONLY) by raising the appropriate exceptions (eg ReadOnlyError). exceptionfor() is a useful helper function to do the mapping.

VTModule class

class VTModule

Note

There is no actual VTModule class - it is shown this way for documentation convenience and is present as a typing protocol. Your module instance should implement all the methods documented here.

A module instance is used to create the virtual tables. Once you have a module object, you register it with a connection by calling Connection.createmodule():

# make an instance
mymod=MyModuleClass()

# register the vtable on connection con
con.createmodule("modulename", mymod)

# tell SQLite about the table
con.execute("create VIRTUAL table tablename USING modulename('arg1', 2)")

The create step is to tell SQLite about the existence of the table. Any number of tables referring to the same module can be made this way. Note the (optional) arguments which are passed to the module.

VTModule.Connect(connection: Connection, modulename: str, databasename: str, tablename: str, *args: Tuple[SQLiteValue, ...]) Tuple[str, VTTable]

The parameters and return are identical to Create(). This method is called when there are additional references to the table. Create() will be called the first time and Connect() after that.

The advise is to create caches, generated data and other heavyweight processing on Create() calls and then find and reuse that on the subsequent Connect() calls.

The corresponding call is VTTable.Disconnect(). If you have a simple virtual table implementation, then just set Connect() to be the same as Create():

class MyModule:

     def Create(self, connection, modulename, databasename, tablename, *args):
         # do lots of hard work

     Connect=Create
VTModule.Create(connection: Connection, modulename: str, databasename: str, tablename: str, *args: Tuple[SQLiteValue, ...]) Tuple[str, VTTable]

Called when a table is first created on a connection.

Parameters
  • connection – An instance of Connection

  • modulename – The string name under which the module was registered

  • databasename – The name of the database. This will be main for directly opened files and the name specified in ATTACH statements.

  • tablename – Name of the table the user wants to create.

  • args – Any arguments that were specified in the create virtual table statement.

Returns

A list of two items. The first is a SQL create table statement. The columns are parsed so that SQLite knows what columns and declared types exist for the table. The second item is an object that implements the table methods.

The corresponding call is VTTable.Destroy().

VTTable class

class VTTable

Note

There is no actual VTTable class - it is shown this way for documentation convenience and is present as a typing protocol. Your table instance should implement the methods documented here.

The VTTable object contains knowledge of the indices, makes cursors and can perform transactions.

A virtual table is structured as a series of rows, each of which has the same columns. The value in a column must be one of the 5 supported types, but the type can be different between rows for the same column. The virtual table routines identify the columns by number, starting at zero.

Each row has a unique 64 bit integer rowid with the Cursor routines operating on this number, as well as some of the Table routines such as UpdateChangeRow.

VTTable.Begin() None

This function is used as part of transactions. You do not have to provide the method.

VTTable.BestIndex(constraints: Sequence[Tuple[int, int], ...], orderbys: Sequence[Tuple[int, int], ...]) Any

This is a complex method. To get going initially, just return None and you will be fine. Implementing this method reduces the number of rows scanned in your table to satisfy queries, but only if you have an index or index like mechanism available.

Note

The implementation of this method differs slightly from the SQLite documentation for the C API. You are not passed “unusable” constraints. The argv/constraintarg positions are not off by one. In the C api, you have to return position 1 to get something passed to VTCursor.Filter() in position 0. With the APSW implementation, you return position 0 to get Filter arg 0, position 1 to get Filter arg 1 etc.

The purpose of this method is to ask if you have the ability to determine if a row meets certain constraints that doesn’t involve visiting every row. An example constraint is price > 74.99. In a traditional SQL database, queries with constraints can be speeded up with indices. If you return None, then SQLite will visit every row in your table and evaluate the constraint itself. Your index choice returned from BestIndex will also be passed to the Filter() method on your cursor object. Note that SQLite may call this method multiple times trying to find the most efficient way of answering a complex query.

constraints

You will be passed the constraints as a sequence of tuples containing two items. The first item is the column number and the second item is the operation.

Example query: select * from foo where price > 74.99 and quantity<=10 and customer='Acme Widgets'

If customer is column 0, price column 2 and quantity column 5 then the constraints will be:

(2, apsw.SQLITE_INDEX_CONSTRAINT_GT),
(5, apsw.SQLITE_INDEX_CONSTRAINT_LE),
(0, apsw.SQLITE_INDEX_CONSTRAINT_EQ)

Note that you do not get the value of the constraint (ie “Acme Widgets”, 74.99 and 10 in this example).

If you do have any suitable indices then you return a sequence the same length as constraints with the members mapping to the constraints in order. Each can be one of None, an integer or a tuple of an integer and a boolean. Conceptually SQLite is giving you a list of constraints and you are returning a list of the same length describing how you could satisfy each one.

Each list item returned corresponding to a constraint is one of:

None

This means you have no index for that constraint. SQLite will have to iterate over every row for it.

integer

This is the argument number for the constraintargs being passed into the Filter() function of your cursor (the values “Acme Widgets”, 74.99 and 10 in the example).

(integer, boolean)

By default SQLite will check what you return. For example if you said that you had an index on price, SQLite will still check that each row you returned is greater than 74.99. If you set the boolean to False then SQLite won’t do that double checking.

Example query: select * from foo where price > 74.99 and quantity<=10 and customer=='Acme Widgets'. customer is column 0, price column 2 and quantity column 5. You can index on customer equality and price.

Constraints (in)

Constraints used (out)

(2, apsw.SQLITE_INDEX_CONSTRAINT_GT),
(5, apsw.SQLITE_INDEX_CONSTRAINT_LE),
(0, apsw.SQLITE_INDEX_CONSTRAINT_EQ)
1,
None,
0

When your Filter method in the cursor is called, constraintarg[0] will be “Acme Widgets” (customer constraint value) and constraintarg[1] will be 74.99 (price constraint value). You can also return an index number (integer) and index string to use (SQLite attaches no significance to these values - they are passed as is to your VTCursor.Filter() method as a way for the BestIndex method to let the Filter() method know which of your indices or similar mechanism to use.

orderbys

The second argument to BestIndex is a sequence of orderbys because the query requested the results in a certain order. If your data is already in that order then SQLite can give the results back as is. If not, then SQLite will have to sort the results first.

Example query: select * from foo order by price desc, quantity asc

Price is column 2, quantity column 5 so orderbys will be:

(2, True),  # True means descending, False is ascending
(5, False)

Return

You should return up to 5 items. Items not present in the return have a default value.

0: constraints used (default None)

This must either be None or a sequence the same length as constraints passed in. Each item should be as specified above saying if that constraint is used, and if so which constraintarg to make the value be in your VTCursor.Filter() function.

1: index number (default zero)

This value is passed as is to VTCursor.Filter()

2: index string (default None)

This value is passed as is to VTCursor.Filter()

3: orderby consumed (default False)

Return True if your output will be in exactly the same order as the orderbys passed in

4: estimated cost (default a huge number)

Approximately how many disk operations are needed to provide the results. SQLite uses the cost to optimise queries. For example if the query includes A or B and A has 2,000 operations and B has 100 then it is best to evaluate B before A.

A complete example

Query is select * from foo where price>74.99 and quantity<=10 and customer=="Acme Widgets" order by price desc, quantity asc. Customer is column 0, price column 2 and quantity column 5. You can index on customer equality and price.

BestIndex(constraints, orderbys)

constraints= ( (2, apsw.SQLITE_INDEX_CONSTRAINT_GT),
               (5, apsw.SQLITE_INDEX_CONSTRAINT_LE),
               (0, apsw.SQLITE_INDEX_CONSTRAINT_EQ)  )

orderbys= ( (2, True), (5, False) )

# You return

( (1, None, 0),   # constraints used
  27,             # index number
  "idx_pr_cust",  # index name
  False,          # results are not in orderbys order
  1000            # about 1000 disk operations to access index
)

# Your Cursor.Filter method will be called with:

27,              # index number you returned
"idx_pr_cust",   # index name you returned
"Acme Widgets",  # constraintarg[0] - customer
74.99            # constraintarg[1] - price
VTTable.Commit() None

This function is used as part of transactions. You do not have to provide the method.

VTTable.Destroy() None

The opposite of VTModule.Create(). This method is called when the table is no longer used. Note that you must always release resources even if you intend to return an error, as it will not be called again on error. SQLite may also leak memory if you return an error.

VTTable.Disconnect() None

The opposite of VTModule.Connect(). This method is called when a reference to a virtual table is no longer used, but VTTable.Destroy() will be called when the table is no longer used.

VTTable.FindFunction(name: str, nargs: int)

Called to find if the virtual table has its own implementation of a particular scalar function. You should return the function if you have it, else return None. You do not have to provide this method.

This method is called while SQLite is preparing a query. If a query is in the statement cache then FindFunction won’t be called again. If you want to return different implementations for the same function over time then you will need to disable the statement cache.

Parameters
  • name – The function name

  • nargs – How many arguments the function takes

VTTable.Open() VTCursor

Returns a cursor object.

VTTable.Rename(newname: str) None

Notification that the table will be given a new name. If you return without raising an exception, then SQLite renames the table (you don’t have to do anything). If you raise an exception then the renaming is prevented. You do not have to provide this method.

VTTable.Rollback() None

This function is used as part of transactions. You do not have to provide the method.

VTTable.Sync() None

This function is used as part of transactions. You do not have to provide the method.

VTTable.UpdateChangeRow(row: int, newrowid: int, fields: Tuple[SQLiteValue, ...])

Change an existing row. You may also need to change the rowid - for example if the query was UPDATE table SET rowid=rowid+100 WHERE ...

Parameters
  • row – The existing 64 bit integer rowid

  • newrowid – If not the same as row then also change the rowid to this.

  • fields – A tuple of values the same length and order as columns in your table

VTTable.UpdateDeleteRow(rowid: int)

Delete the row with the specified rowid.

Parameters

rowid – 64 bit integer

VTTable.UpdateInsertRow(rowid: Optional[int], fields: Tuple[SQLiteValue, ...]) Optional[int]

Insert a row with the specified rowid.

Parameters
  • rowidNone if you should choose the rowid yourself, else a 64 bit integer

  • fields – A tuple of values the same length and order as columns in your table

Returns

If rowid was None then return the id you assigned to the row. If rowid was not None then the return value is ignored.

VTCursor class

class VTCursor

Note

There is no actual VTCursor class - it is shown this way for documentation convenience and is present as a typing protocol. Your cursor instance should implement all the methods documented here.

The VTCursor object is used for iterating over a table. There may be many cursors simultaneously so each one needs to keep track of where Virtual table structure it is.

VTCursor.Close() None

This is the destructor for the cursor. Note that you must cleanup. The method will not be called again if you raise an exception.

VTCursor.Column(number: int) SQLiteValue

Requests the value of the specified column number of the current row. If number is -1 then return the rowid.

Returns

Must be one one of the 5 supported types

VTCursor.Eof() bool

Called to ask if we are at the end of the table. It is called after each call to Filter and Next.

Returns

False if the cursor is at a valid row of data, else True

Note

This method can only return True or False to SQLite. If you have an exception in the method or provide a non-boolean return then True (no more data) will be returned to SQLite.

VTCursor.Filter(indexnum: int, indexname: str, constraintargs: Optional[Tuple]) None

This method is always called first to initialize an iteration to the first row of the table. The arguments come from the BestIndex() method in the table object with constraintargs being a tuple of the constraints you requested. If you always return None in BestIndex then indexnum will be zero, indexstring will be None and constraintargs will be empty).

VTCursor.Next() None

Move the cursor to the next row. Do not have an exception if there is no next row. Instead return False when Eof() is subsequently called.

If you said you had indices in your VTTable.BestIndex() return, and they were selected for use as provided in the parameters to Filter() then you should move to the next appropriate indexed and constrained row.

VTCursor.Rowid() int

Return the current rowid.

Troubleshooting virtual tables

A big help is using the local variables recipe as described in augmented stack traces which will give you more details in errors, and shows an example with the complex BestIndex() function.

You may also find errors compounding. For example if you have an error in the Filter method of a cursor, SQLite then closes the cursor. If you also return an error in the Close method then the first error may mask the second or vice versa.

Note

SQLite may ignore responses from your methods if they don’t make sense. For example in BestIndex, if you set multiple arguments to have the same constraintargs position then your Filter won’t receive any constraintargs at all.