Release: 1.0.0 | Release Date: Not released

SQLAlchemy 1.0 Documentation

SQLite

Support for the SQLite database.

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.

SQLite Auto Incrementing Behavior

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

Two things to note:

  • The AUTOINCREMENT keyword is not required for SQLite tables to generate primary key values automatically. AUTOINCREMENT only means that the algorithm used to generate ROWID values should be slightly different.
  • SQLite does not generate primary key (i.e. ROWID) values, even for one column, if the table has a composite (i.e. multi-column) primary key. This is regardless of the AUTOINCREMENT keyword being present or not.

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)

Transaction Isolation Level

create_engine() accepts an isolation_level parameter which results in the command PRAGMA read_uncommitted <level> being invoked for every new connection. Valid values for this parameter are SERIALIZABLE and READ UNCOMMITTED corresponding to a value of 0 and 1, respectively. See the section Serializable Transaction Isolation for an important workaround when using serializable isolation with Pysqlite.

Database Locking Behavior / Concurrency

Note that SQLite is not designed for a high level of concurrency. The database itself, being a file, is locked completely during write operations and within transactions, meaning exactly one connection 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 BEGIN method, only commit and rollback. This implies that a SQLite DBAPI driver would technically allow only serialized access to a particular database file at all times. The pysqlite driver attempts to ameliorate this by deferring the actual BEGIN statement until the first DML (INSERT, UPDATE, or DELETE) is received within a transaction. While this breaks serializable isolation, it at least delays the exclusive locking inherent in SQLite’s design.

SQLAlchemy’s default mode of usage with the ORM is known as “autocommit=False”, which means the moment the Session begins to be used, a transaction is begun. As the Session is used, the autoflush feature, also on by default, will flush out pending changes to the database before each query. The effect of this is that a Session used in its default mode will often emit DML early on, long before the transaction is actually committed. This again will have the effect of serializing access to the SQLite database. If highly concurrent reads are desired against the SQLite database, it is advised that the autoflush feature be disabled, and potentially even that autocommit be re-enabled, which has the effect of each SQL statement and flush committing changes immediately.

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

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()

See also

SQLite Foreign Key Support - on the SQLite web site.

Events - SQLAlchemy event API.

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.

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
class sqlalchemy.dialects.sqlite.DATETIME(*args, **kwargs)

Bases: sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.DateTime

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 sqlalchemy.dialects.sqlite.DATE(storage_format=None, regexp=None, **kw)

Bases: sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.Date

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 sqlalchemy.dialects.sqlite.TIME(*args, **kwargs)

Bases: sqlalchemy.dialects.sqlite.base._DateTimeMixin, sqlalchemy.types.Time

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)).

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.

    Changed in version 0.7: Default selection of NullPool for SQLite file-based databases. Previous versions select SingletonThreadPool by default for all SQLite databases.

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 Transaction Isolation

The pysqlite DBAPI driver has a long-standing bug in which transactional state is not begun until the first DML statement, that is INSERT, UPDATE or DELETE, is emitted. A SELECT statement will not cause transactional state to begin. While this mode of usage is fine for typical situations and has the advantage that the SQLite database file is not prematurely locked, it breaks serializable transaction isolation, which requires that the database file be locked upon any SQL being emitted.

To work around this issue, the BEGIN keyword can be emitted at the start of each transaction. The following recipe establishes a ConnectionEvents.begin() handler to achieve this:

from sqlalchemy import create_engine, event

engine = create_engine("sqlite:///myfile.db",
                       isolation_level='SERIALIZABLE')

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