SQLite

Support for the SQLite database.

The following table summarizes current support levels for database release versions.

DBAPI Support

The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.

Date and Time Types

SQLite does not have built-in DATE, TIME, or DATETIME types, and pysqlite does not provide out of the box functionality for translating values between Python datetime objects and a SQLite-supported format. SQLAlchemy’s own DateTime and related types provide date formatting and parsing functionality when SQLite is used. The implementation classes are DATETIME, DATE and TIME. These types represent dates and times as ISO formatted strings, which also nicely support ordering. There’s no reliance on typical “libc” internals for these functions so historical dates are fully supported.

Ensuring Text affinity

The DDL rendered for these types is the standard DATE, TIME and DATETIME indicators. However, custom storage formats can also be applied to these types. When the storage format is detected as containing no alpha characters, the DDL for these types is rendered as DATE_CHAR, TIME_CHAR, and DATETIME_CHAR, so that the column continues to have textual affinity.

See also

Type Affinity - in the SQLite documentation

SQLite Auto Incrementing Behavior

Background on SQLite’s autoincrement is at: http://sqlite.org/autoinc.html

Key concepts:

  • SQLite has an implicit “auto increment” feature that takes place for any non-composite primary-key column that is specifically created using “INTEGER PRIMARY KEY” for the type + primary key.

  • SQLite also has an explicit “AUTOINCREMENT” keyword, that is not equivalent to the implicit autoincrement feature; this keyword is not recommended for general use. SQLAlchemy does not render this keyword unless a special SQLite-specific directive is used (see below). However, it still requires that the column’s type is named “INTEGER”.

Using the AUTOINCREMENT Keyword

To specifically render the AUTOINCREMENT keyword on the primary key column when rendering DDL, add the flag sqlite_autoincrement=True to the Table construct:

Table('sometable', metadata,
        Column('id', Integer, primary_key=True),
        sqlite_autoincrement=True)

Allowing autoincrement behavior SQLAlchemy types other than Integer/INTEGER

SQLite’s typing model is based on naming conventions. Among other things, this means that any type name which contains the substring "INT" will be determined to be of “integer affinity”. A type named "BIGINT", "SPECIAL_INT" or even "XYZINTQPR", will be considered by SQLite to be of “integer” affinity. However, the SQLite autoincrement feature, whether implicitly or explicitly enabled, requires that the name of the column’s type is exactly the string “INTEGER”. Therefore, if an application uses a type like BigInteger for a primary key, on SQLite this type will need to be rendered as the name "INTEGER" when emitting the initial CREATE TABLE statement in order for the autoincrement behavior to be available.

One approach to achieve this is to use Integer on SQLite only using TypeEngine.with_variant():

table = Table(
    "my_table", metadata,
    Column("id", BigInteger().with_variant(Integer, "sqlite"), primary_key=True)
)

Another is to use a subclass of BigInteger that overrides its DDL name to be INTEGER when compiled against SQLite:

from sqlalchemy import BigInteger
from sqlalchemy.ext.compiler import compiles

class SLBigInteger(BigInteger):
    pass

@compiles(SLBigInteger, 'sqlite')
def bi_c(element, compiler, **kw):
    return "INTEGER"

@compiles(SLBigInteger)
def bi_c(element, compiler, **kw):
    return compiler.visit_BIGINT(element, **kw)


table = Table(
    "my_table", metadata,
    Column("id", SLBigInteger(), primary_key=True)
)

Database Locking Behavior / Concurrency

SQLite is not designed for a high level of write concurrency. The database itself, being a file, is locked completely during write operations within transactions, meaning exactly one “connection” (in reality a file handle) has exclusive access to the database during this period - all other “connections” will be blocked during this time.

The Python DBAPI specification also calls for a connection model that is always in a transaction; there is no connection.begin() method, only connection.commit() and connection.rollback(), upon which a new transaction is to be begun immediately. This may seem to imply that the SQLite driver would in theory allow only a single filehandle on a particular database file at any time; however, there are several factors both within SQLite itself as well as within the pysqlite driver which loosen this restriction significantly.

However, no matter what locking modes are used, SQLite will still always lock the database file once a transaction is started and DML (e.g. INSERT, UPDATE, DELETE) has at least been emitted, and this will block other transactions at least at the point that they also attempt to emit DML. By default, the length of time on this block is very short before it times out with an error.

This behavior becomes more critical when used in conjunction with the SQLAlchemy ORM. SQLAlchemy’s Session object by default runs within a transaction, and with its autoflush model, may emit DML preceding any SELECT statement. This may lead to a SQLite database that locks more quickly than is expected. The locking mode of SQLite and the pysqlite driver can be manipulated to some degree, however it should be noted that achieving a high degree of write-concurrency with SQLite is a losing battle.

For more information on SQLite’s lack of write concurrency by design, please see Situations Where Another RDBMS May Work Better - High Concurrency near the bottom of the page.

The following subsections introduce areas that are impacted by SQLite’s file-based architecture and additionally will usually require workarounds to work when using the pysqlite driver.

Transaction Isolation Level

SQLite supports “transaction isolation” in a non-standard way, along two axes. One is that of the PRAGMA read_uncommitted instruction. This setting can essentially switch SQLite between its default mode of SERIALIZABLE isolation, and a “dirty read” isolation mode normally referred to as READ UNCOMMITTED.

SQLAlchemy ties into this PRAGMA statement using the create_engine.isolation_level parameter of create_engine(). Valid values for this parameter when used with SQLite are "SERIALIZABLE" and "READ UNCOMMITTED" corresponding to a value of 0 and 1, respectively. SQLite defaults to SERIALIZABLE, however its behavior is impacted by the pysqlite driver’s default behavior.

The other axis along which SQLite’s transactional locking is impacted is via the nature of the BEGIN statement used. The three varieties are “deferred”, “immediate”, and “exclusive”, as described at BEGIN TRANSACTION. A straight BEGIN statement uses the “deferred” mode, where the database file is not locked until the first read or write operation, and read access remains open to other transactions until the first write operation. But again, it is critical to note that the pysqlite driver interferes with this behavior by not even emitting BEGIN until the first write operation.

Warning

SQLite’s transactional scope is impacted by unresolved issues in the pysqlite driver, which defers BEGIN statements to a greater degree than is often feasible. See the section Serializable isolation / Savepoints / Transactional DDL for techniques to work around this behavior.

SAVEPOINT Support

SQLite supports SAVEPOINTs, which only function once a transaction is begun. SQLAlchemy’s SAVEPOINT support is available using the Connection.begin_nested() method at the Core level, and Session.begin_nested() at the ORM level. However, SAVEPOINTs won’t work at all with pysqlite unless workarounds are taken.

Warning

SQLite’s SAVEPOINT feature is impacted by unresolved issues in the pysqlite driver, which defers BEGIN statements to a greater degree than is often feasible. See the section Serializable isolation / Savepoints / Transactional DDL for techniques to work around this behavior.

Transactional DDL

The SQLite database supports transactional DDL as well. In this case, the pysqlite driver is not only failing to start transactions, it also is ending any existing transaction when DDL is detected, so again, workarounds are required.

Warning

SQLite’s transactional DDL is impacted by unresolved issues in the pysqlite driver, which fails to emit BEGIN and additionally forces a COMMIT to cancel any transaction when DDL is encountered. See the section Serializable isolation / Savepoints / Transactional DDL for techniques to work around this behavior.

Foreign Key Support

SQLite supports FOREIGN KEY syntax when emitting CREATE statements for tables, however by default these constraints have no effect on the operation of the table.

Constraint checking on SQLite has three prerequisites:

  • At least version 3.6.19 of SQLite must be in use

  • The SQLite library must be compiled without the SQLITE_OMIT_FOREIGN_KEY or SQLITE_OMIT_TRIGGER symbols enabled.

  • The PRAGMA foreign_keys = ON statement must be emitted on all connections before use.

SQLAlchemy allows for the PRAGMA statement to be emitted automatically for new connections through the usage of events:

from sqlalchemy.engine import Engine
from sqlalchemy import event

@event.listens_for(Engine, "connect")
def set_sqlite_pragma(dbapi_connection, connection_record):
    cursor = dbapi_connection.cursor()
    cursor.execute("PRAGMA foreign_keys=ON")
    cursor.close()

Warning

When SQLite foreign keys are enabled, it is not possible to emit CREATE or DROP statements for tables that contain mutually-dependent foreign key constraints; to emit the DDL for these tables requires that ALTER TABLE be used to create or drop these constraints separately, for which SQLite has no support.

See also

SQLite Foreign Key Support - on the SQLite web site.

Events - SQLAlchemy event API.

Creating/Dropping Foreign Key Constraints via ALTER - more information on SQLAlchemy’s facilities for handling

mutually-dependent foreign key constraints.

Type Reflection

SQLite types are unlike those of most other database backends, in that the string name of the type usually does not correspond to a “type” in a one-to-one fashion. Instead, SQLite links per-column typing behavior to one of five so-called “type affinities” based on a string matching pattern for the type.

SQLAlchemy’s reflection process, when inspecting types, uses a simple lookup table to link the keywords returned to provided SQLAlchemy types. This lookup table is present within the SQLite dialect as it is for all other dialects. However, the SQLite dialect has a different “fallback” routine for when a particular type name is not located in the lookup map; it instead implements the SQLite “type affinity” scheme located at http://www.sqlite.org/datatype3.html section 2.1.

The provided typemap will make direct associations from an exact string name match for the following types:

BIGINT, BLOB, BOOLEAN, BOOLEAN, CHAR, DATE, DATETIME, FLOAT, DECIMAL, FLOAT, INTEGER, INTEGER, NUMERIC, REAL, SMALLINT, TEXT, TIME, TIMESTAMP, VARCHAR, NVARCHAR, NCHAR

When a type name does not match one of the above types, the “type affinity” lookup is used instead:

  • INTEGER is returned if the type name includes the string INT

  • TEXT is returned if the type name includes the string CHAR, CLOB or TEXT

  • NullType is returned if the type name includes the string BLOB

  • REAL is returned if the type name includes the string REAL, FLOA or DOUB.

  • Otherwise, the NUMERIC type is used.

New in version 0.9.3: Support for SQLite type affinity rules when reflecting columns.

Partial Indexes

A partial index, e.g. one which uses a WHERE clause, can be specified with the DDL system using the argument sqlite_where:

tbl = Table('testtbl', m, Column('data', Integer))
idx = Index('test_idx1', tbl.c.data,
            sqlite_where=and_(tbl.c.data > 5, tbl.c.data < 10))

The index will be rendered at create time as:

CREATE INDEX test_idx1 ON testtbl (data)
WHERE data > 5 AND data < 10

New in version 0.9.9.

Dotted Column Names

Using table or column names that explicitly have periods in them is not recommended. While this is generally a bad idea for relational databases in general, as the dot is a syntactically significant character, the SQLite driver up until version 3.10.0 of SQLite has a bug which requires that SQLAlchemy filter out these dots in result sets.

Changed in version 1.1: The following SQLite issue has been resolved as of version 3.10.0 of SQLite. SQLAlchemy as of 1.1 automatically disables its internal workarounds based on detection of this version.

The bug, entirely outside of SQLAlchemy, can be illustrated thusly:

import sqlite3

assert sqlite3.sqlite_version_info < (3, 10, 0), "bug is fixed in this version"

conn = sqlite3.connect(":memory:")
cursor = conn.cursor()

cursor.execute("create table x (a integer, b integer)")
cursor.execute("insert into x (a, b) values (1, 1)")
cursor.execute("insert into x (a, b) values (2, 2)")

cursor.execute("select x.a, x.b from x")
assert [c[0] for c in cursor.description] == ['a', 'b']

cursor.execute('''
    select x.a, x.b from x where a=1
    union
    select x.a, x.b from x where a=2
''')
assert [c[0] for c in cursor.description] == ['a', 'b'], \
    [c[0] for c in cursor.description]

The second assertion fails:

Traceback (most recent call last):
  File "test.py", line 19, in <module>
    [c[0] for c in cursor.description]
AssertionError: ['x.a', 'x.b']

Where above, the driver incorrectly reports the names of the columns including the name of the table, which is entirely inconsistent vs. when the UNION is not present.

SQLAlchemy relies upon column names being predictable in how they match to the original statement, so the SQLAlchemy dialect has no choice but to filter these out:

from sqlalchemy import create_engine

eng = create_engine("sqlite://")
conn = eng.connect()

conn.execute("create table x (a integer, b integer)")
conn.execute("insert into x (a, b) values (1, 1)")
conn.execute("insert into x (a, b) values (2, 2)")

result = conn.execute("select x.a, x.b from x")
assert result.keys() == ["a", "b"]

result = conn.execute('''
    select x.a, x.b from x where a=1
    union
    select x.a, x.b from x where a=2
''')
assert result.keys() == ["a", "b"]

Note that above, even though SQLAlchemy filters out the dots, both names are still addressable:

>>> row = result.first()
>>> row["a"]
1
>>> row["x.a"]
1
>>> row["b"]
1
>>> row["x.b"]
1

Therefore, the workaround applied by SQLAlchemy only impacts ResultProxy.keys() and RowProxy.keys() in the public API. In the very specific case where an application is forced to use column names that contain dots, and the functionality of ResultProxy.keys() and RowProxy.keys() is required to return these dotted names unmodified, the sqlite_raw_colnames execution option may be provided, either on a per-Connection basis:

result = conn.execution_options(sqlite_raw_colnames=True).execute('''
    select x.a, x.b from x where a=1
    union
    select x.a, x.b from x where a=2
''')
assert result.keys() == ["x.a", "x.b"]

or on a per-Engine basis:

engine = create_engine("sqlite://", execution_options={"sqlite_raw_colnames": True})

When using the per-Engine execution option, note that Core and ORM queries that use UNION may not function properly.

SQLite Data Types

As with all SQLAlchemy dialects, all UPPERCASE types that are known to be valid with SQLite are importable from the top level dialect, whether they originate from sqlalchemy.types or from the local dialect:

from sqlalchemy.dialects.sqlite import \
            BLOB, BOOLEAN, CHAR, DATE, DATETIME, DECIMAL, FLOAT, \
            INTEGER, NUMERIC, SMALLINT, TEXT, TIME, TIMESTAMP, \
            VARCHAR
Object Name Description

DATE

Represent a Python date object in SQLite using a string.

DATETIME

Represent a Python datetime object in SQLite using a string.

TIME

Represent a Python time object in SQLite using a string.

class sqlalchemy.dialects.sqlite.DATETIME(*args, **kwargs)

Represent a Python datetime object in SQLite using a string.

The default string storage format is:

"%(year)04d-%(month)02d-%(day)02d %(hour)02d:%(min)02d:%(second)02d.%(microsecond)06d"

e.g.:

2011-03-15 12:05:57.10558

The storage format can be customized to some degree using the storage_format and regexp parameters, such as:

import re
from sqlalchemy.dialects.sqlite import DATETIME

dt = DATETIME(storage_format="%(year)04d/%(month)02d/%(day)02d "
                             "%(hour)02d:%(min)02d:%(second)02d",
              regexp=r"(\d+)/(\d+)/(\d+) (\d+)-(\d+)-(\d+)"
)
Parameters:
  • storage_format – format string which will be applied to the dict with keys year, month, day, hour, minute, second, and microsecond.

  • regexp – regular expression which will be applied to incoming result rows. If the regexp contains named groups, the resulting match dict is applied to the Python datetime() constructor as keyword arguments. Otherwise, if positional groups are used, the datetime() constructor is called with positional arguments via *map(int, match_obj.groups(0)).

Class signature

class sqlalchemy.dialects.sqlite.DATETIME (sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.DateTime)

class sqlalchemy.dialects.sqlite.DATE(storage_format=None, regexp=None, **kw)

Represent a Python date object in SQLite using a string.

The default string storage format is:

"%(year)04d-%(month)02d-%(day)02d"

e.g.:

2011-03-15

The storage format can be customized to some degree using the storage_format and regexp parameters, such as:

import re
from sqlalchemy.dialects.sqlite import DATE

d = DATE(
        storage_format="%(month)02d/%(day)02d/%(year)04d",
        regexp=re.compile("(?P<month>\d+)/(?P<day>\d+)/(?P<year>\d+)")
    )
Parameters:
  • storage_format – format string which will be applied to the dict with keys year, month, and day.

  • regexp – regular expression which will be applied to incoming result rows. If the regexp contains named groups, the resulting match dict is applied to the Python date() constructor as keyword arguments. Otherwise, if positional groups are used, the date() constructor is called with positional arguments via *map(int, match_obj.groups(0)).

Class signature

class sqlalchemy.dialects.sqlite.DATE (sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.Date)

class sqlalchemy.dialects.sqlite.TIME(*args, **kwargs)

Represent a Python time object in SQLite using a string.

The default string storage format is:

"%(hour)02d:%(minute)02d:%(second)02d.%(microsecond)06d"

e.g.:

12:05:57.10558

The storage format can be customized to some degree using the storage_format and regexp parameters, such as:

import re
from sqlalchemy.dialects.sqlite import TIME

t = TIME(storage_format="%(hour)02d-%(minute)02d-"
                        "%(second)02d-%(microsecond)06d",
         regexp=re.compile("(\d+)-(\d+)-(\d+)-(?:-(\d+))?")
)
Parameters:
  • storage_format – format string which will be applied to the dict with keys hour, minute, second, and microsecond.

  • regexp – regular expression which will be applied to incoming result rows. If the regexp contains named groups, the resulting match dict is applied to the Python time() constructor as keyword arguments. Otherwise, if positional groups are used, the time() constructor is called with positional arguments via *map(int, match_obj.groups(0)).

Class signature

class sqlalchemy.dialects.sqlite.TIME (sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.Time)

Pysqlite

Support for the SQLite database via the pysqlite driver.

Note that pysqlite is the same driver as the sqlite3 module included with the Python distribution.

DBAPI

Documentation and download information (if applicable) for pysqlite is available at: http://docs.python.org/library/sqlite3.html

Connecting

Connect String:

sqlite+pysqlite:///file_path

Driver

When using Python 2.5 and above, the built in sqlite3 driver is already installed and no additional installation is needed. Otherwise, the pysqlite2 driver needs to be present. This is the same driver as sqlite3, just with a different name.

The pysqlite2 driver will be loaded first, and if not found, sqlite3 is loaded. This allows an explicitly installed pysqlite driver to take precedence over the built in one. As with all dialects, a specific DBAPI module may be provided to create_engine() to control this explicitly:

from sqlite3 import dbapi2 as sqlite
e = create_engine('sqlite+pysqlite:///file.db', module=sqlite)

Connect Strings

The file specification for the SQLite database is taken as the “database” portion of the URL. Note that the format of a SQLAlchemy url is:

driver://user:pass@host/database

This means that the actual filename to be used starts with the characters to the right of the third slash. So connecting to a relative filepath looks like:

# relative path
e = create_engine('sqlite:///path/to/database.db')

An absolute path, which is denoted by starting with a slash, means you need four slashes:

# absolute path
e = create_engine('sqlite:////path/to/database.db')

To use a Windows path, regular drive specifications and backslashes can be used. Double backslashes are probably needed:

# absolute path on Windows
e = create_engine('sqlite:///C:\\path\\to\\database.db')

The sqlite :memory: identifier is the default if no filepath is present. Specify sqlite:// and nothing else:

# in-memory database
e = create_engine('sqlite://')

Compatibility with sqlite3 “native” date and datetime types

The pysqlite driver includes the sqlite3.PARSE_DECLTYPES and sqlite3.PARSE_COLNAMES options, which have the effect of any column or expression explicitly cast as “date” or “timestamp” will be converted to a Python date or datetime object. The date and datetime types provided with the pysqlite dialect are not currently compatible with these options, since they render the ISO date/datetime including microseconds, which pysqlite’s driver does not. Additionally, SQLAlchemy does not at this time automatically render the “cast” syntax required for the freestanding functions “current_timestamp” and “current_date” to return datetime/date types natively. Unfortunately, pysqlite does not provide the standard DBAPI types in cursor.description, leaving SQLAlchemy with no way to detect these types on the fly without expensive per-row type checks.

Keeping in mind that pysqlite’s parsing option is not recommended, nor should be necessary, for use with SQLAlchemy, usage of PARSE_DECLTYPES can be forced if one configures “native_datetime=True” on create_engine():

engine = create_engine('sqlite://',
    connect_args={'detect_types':
        sqlite3.PARSE_DECLTYPES|sqlite3.PARSE_COLNAMES},
    native_datetime=True
)

With this flag enabled, the DATE and TIMESTAMP types (but note - not the DATETIME or TIME types…confused yet ?) will not perform any bind parameter or result processing. Execution of “func.current_date()” will return a string. “func.current_timestamp()” is registered as returning a DATETIME type in SQLAlchemy, so this function still receives SQLAlchemy-level result processing.

Threading/Pooling Behavior

Pysqlite’s default behavior is to prohibit the usage of a single connection in more than one thread. This is originally intended to work with older versions of SQLite that did not support multithreaded operation under various circumstances. In particular, older SQLite versions did not allow a :memory: database to be used in multiple threads under any circumstances.

Pysqlite does include a now-undocumented flag known as check_same_thread which will disable this check, however note that pysqlite connections are still not safe to use in concurrently in multiple threads. In particular, any statement execution calls would need to be externally mutexed, as Pysqlite does not provide for thread-safe propagation of error messages among other things. So while even :memory: databases can be shared among threads in modern SQLite, Pysqlite doesn’t provide enough thread-safety to make this usage worth it.

SQLAlchemy sets up pooling to work with Pysqlite’s default behavior:

  • When a :memory: SQLite database is specified, the dialect by default will use SingletonThreadPool. This pool maintains a single connection per thread, so that all access to the engine within the current thread use the same :memory: database - other threads would access a different :memory: database.

  • When a file-based database is specified, the dialect will use NullPool as the source of connections. This pool closes and discards connections which are returned to the pool immediately. SQLite file-based connections have extremely low overhead, so pooling is not necessary. The scheme also prevents a connection from being used again in a different thread and works best with SQLite’s coarse-grained file locking.

Using a Memory Database in Multiple Threads

To use a :memory: database in a multithreaded scenario, the same connection object must be shared among threads, since the database exists only within the scope of that connection. The StaticPool implementation will maintain a single connection globally, and the check_same_thread flag can be passed to Pysqlite as False:

from sqlalchemy.pool import StaticPool
engine = create_engine('sqlite://',
                    connect_args={'check_same_thread':False},
                    poolclass=StaticPool)

Note that using a :memory: database in multiple threads requires a recent version of SQLite.

Using Temporary Tables with SQLite

Due to the way SQLite deals with temporary tables, if you wish to use a temporary table in a file-based SQLite database across multiple checkouts from the connection pool, such as when using an ORM Session where the temporary table should continue to remain after Session.commit() or Session.rollback() is called, a pool which maintains a single connection must be used. Use SingletonThreadPool if the scope is only needed within the current thread, or StaticPool is scope is needed within multiple threads for this case:

# maintain the same connection per thread
from sqlalchemy.pool import SingletonThreadPool
engine = create_engine('sqlite:///mydb.db',
                    poolclass=SingletonThreadPool)


# maintain the same connection across all threads
from sqlalchemy.pool import StaticPool
engine = create_engine('sqlite:///mydb.db',
                    poolclass=StaticPool)

Note that SingletonThreadPool should be configured for the number of threads that are to be used; beyond that number, connections will be closed out in a non deterministic way.

Unicode

The pysqlite driver only returns Python unicode objects in result sets, never plain strings, and accommodates unicode objects within bound parameter values in all cases. Regardless of the SQLAlchemy string type in use, string-based result values will by Python unicode in Python 2. The Unicode type should still be used to indicate those columns that require unicode, however, so that non-unicode values passed inadvertently will emit a warning. Pysqlite will emit an error if a non-unicode string is passed containing non-ASCII characters.

Serializable isolation / Savepoints / Transactional DDL

In the section Database Locking Behavior / Concurrency, we refer to the pysqlite driver’s assortment of issues that prevent several features of SQLite from working correctly. The pysqlite DBAPI driver has several long-standing bugs which impact the correctness of its transactional behavior. In its default mode of operation, SQLite features such as SERIALIZABLE isolation, transactional DDL, and SAVEPOINT support are non-functional, and in order to use these features, workarounds must be taken.

The issue is essentially that the driver attempts to second-guess the user’s intent, failing to start transactions and sometimes ending them prematurely, in an effort to minimize the SQLite databases’s file locking behavior, even though SQLite itself uses “shared” locks for read-only activities.

SQLAlchemy chooses to not alter this behavior by default, as it is the long-expected behavior of the pysqlite driver; if and when the pysqlite driver attempts to repair these issues, that will be more of a driver towards defaults for SQLAlchemy.

The good news is that with a few events, we can implement transactional support fully, by disabling pysqlite’s feature entirely and emitting BEGIN ourselves. This is achieved using two event listeners:

from sqlalchemy import create_engine, event

engine = create_engine("sqlite:///myfile.db")

@event.listens_for(engine, "connect")
def do_connect(dbapi_connection, connection_record):
    # disable pysqlite's emitting of the BEGIN statement entirely.
    # also stops it from emitting COMMIT before any DDL.
    dbapi_connection.isolation_level = None

@event.listens_for(engine, "begin")
def do_begin(conn):
    # emit our own BEGIN
    conn.execute("BEGIN")

Above, we intercept a new pysqlite connection and disable any transactional integration. Then, at the point at which SQLAlchemy knows that transaction scope is to begin, we emit "BEGIN" ourselves.

When we take control of "BEGIN", we can also control directly SQLite’s locking modes, introduced at BEGIN TRANSACTION, by adding the desired locking mode to our "BEGIN":

@event.listens_for(engine, "begin")
def do_begin(conn):
    conn.execute("BEGIN EXCLUSIVE")

See also

BEGIN TRANSACTION - on the SQLite site

sqlite3 SELECT does not BEGIN a transaction - on the Python bug tracker

sqlite3 module breaks transactions and potentially corrupts data - on the Python bug tracker

Pysqlcipher

Support for the SQLite database via the pysqlcipher driver.

pysqlcipher is a fork of the standard pysqlite driver to make use of the SQLCipher backend.

pysqlcipher3 is a fork of pysqlcipher for Python 3. This dialect will attempt to import it if pysqlcipher is non-present.

New in version 1.1.4: - added fallback import for pysqlcipher3

New in version 0.9.9: - added pysqlcipher dialect

DBAPI

Documentation and download information (if applicable) for pysqlcipher is available at: https://pypi.python.org/pypi/pysqlcipher

Connecting

Connect String:

sqlite+pysqlcipher://:passphrase/file_path[?kdf_iter=<iter>]

Driver

The driver here is the pysqlcipher driver, which makes use of the SQLCipher engine. This system essentially introduces new PRAGMA commands to SQLite which allows the setting of a passphrase and other encryption parameters, allowing the database file to be encrypted.

pysqlcipher3 is a fork of pysqlcipher with support for Python 3, the driver is the same.

Connect Strings

The format of the connect string is in every way the same as that of the pysqlite driver, except that the “password” field is now accepted, which should contain a passphrase:

e = create_engine('sqlite+pysqlcipher://:testing@/foo.db')

For an absolute file path, two leading slashes should be used for the database name:

e = create_engine('sqlite+pysqlcipher://:testing@//path/to/foo.db')

A selection of additional encryption-related pragmas supported by SQLCipher as documented at https://www.zetetic.net/sqlcipher/sqlcipher-api/ can be passed in the query string, and will result in that PRAGMA being called for each new connection. Currently, cipher, kdf_iter cipher_page_size and cipher_use_hmac are supported:

e = create_engine('sqlite+pysqlcipher://:testing@/foo.db?cipher=aes-256-cfb&kdf_iter=64000')

Pooling Behavior

The driver makes a change to the default pool behavior of pysqlite as described in Threading/Pooling Behavior. The pysqlcipher driver has been observed to be significantly slower on connection than the pysqlite driver, most likely due to the encryption overhead, so the dialect here defaults to using the SingletonThreadPool implementation, instead of the NullPool pool used by pysqlite. As always, the pool implementation is entirely configurable using the create_engine.poolclass parameter; the StaticPool may be more feasible for single-threaded use, or NullPool may be used to prevent unencrypted connections from being held open for long periods of time, at the expense of slower startup time for new connections.