module documentation

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 ~sqlalchemy.types.DateTime and related types provide date formatting and parsing functionality when SQLite is used. The implementation classes are _sqlite.DATETIME, _sqlite.DATE and _sqlite.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: https://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 / Autocommit

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 :paramref:`_sa.create_engine.isolation_level` parameter of _sa.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.

When using the pysqlite driver, the "AUTOCOMMIT" isolation level is also available, which will alter the pysqlite connection using the .isolation_level attribute on the DBAPI connection and set it to None for the duration of the setting.

New in version 1.3.16: added support for SQLite AUTOCOMMIT isolation level when using the pysqlite / sqlite3 SQLite driver.

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 :ref:`pysqlite_serializable` 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 _engine.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 :ref:`pysqlite_serializable` for techniques to work around this behavior.

Transactional DDL

The SQLite database supports transactional :term:`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 :ref:`pysqlite_serializable` 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 -- including the initial call to sqlalchemy.schema.MetaData.create_all.

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.

:ref:`event_toplevel` - SQLAlchemy event API.

:ref:`use_alter` - more information on SQLAlchemy's facilities for handling
mutually-dependent foreign key constraints.

ON CONFLICT support for constraints

See Also

This section describes the :term:`DDL` version of "ON CONFLICT" for SQLite, which occurs within a CREATE TABLE statement. For "ON CONFLICT" as applied to an INSERT statement, see :ref:`sqlite_on_conflict_insert`.

SQLite supports a non-standard DDL clause known as ON CONFLICT which can be applied to primary key, unique, check, and not null constraints. In DDL, it is rendered either within the "CONSTRAINT" clause or within the column definition itself depending on the location of the target constraint. To render this clause within DDL, the extension parameter sqlite_on_conflict can be specified with a string conflict resolution algorithm within the .PrimaryKeyConstraint, .UniqueConstraint, .CheckConstraint objects. Within the _schema.Column object, there are individual parameters sqlite_on_conflict_not_null, sqlite_on_conflict_primary_key, sqlite_on_conflict_unique which each correspond to the three types of relevant constraint types that can be indicated from a _schema.Column object.

See Also

ON CONFLICT - in the SQLite documentation

New in version 1.3.

The sqlite_on_conflict parameters accept a string argument which is just the resolution name to be chosen, which on SQLite can be one of ROLLBACK, ABORT, FAIL, IGNORE, and REPLACE. For example, to add a UNIQUE constraint that specifies the IGNORE algorithm:

some_table = Table(
    'some_table', metadata,
    Column('id', Integer, primary_key=True),
    Column('data', Integer),
    UniqueConstraint('id', 'data', sqlite_on_conflict='IGNORE')
)

The above renders CREATE TABLE DDL as:

CREATE TABLE some_table (
    id INTEGER NOT NULL,
    data INTEGER,
    PRIMARY KEY (id),
    UNIQUE (id, data) ON CONFLICT IGNORE
)

When using the :paramref:`_schema.Column.unique` flag to add a UNIQUE constraint to a single column, the sqlite_on_conflict_unique parameter can be added to the _schema.Column as well, which will be added to the UNIQUE constraint in the DDL:

some_table = Table(
    'some_table', metadata,
    Column('id', Integer, primary_key=True),
    Column('data', Integer, unique=True,
           sqlite_on_conflict_unique='IGNORE')
)

rendering:

CREATE TABLE some_table (
    id INTEGER NOT NULL,
    data INTEGER,
    PRIMARY KEY (id),
    UNIQUE (data) ON CONFLICT IGNORE
)

To apply the FAIL algorithm for a NOT NULL constraint, sqlite_on_conflict_not_null is used:

some_table = Table(
    'some_table', metadata,
    Column('id', Integer, primary_key=True),
    Column('data', Integer, nullable=False,
           sqlite_on_conflict_not_null='FAIL')
)

this renders the column inline ON CONFLICT phrase:

CREATE TABLE some_table (
    id INTEGER NOT NULL,
    data INTEGER NOT NULL ON CONFLICT FAIL,
    PRIMARY KEY (id)
)

Similarly, for an inline primary key, use sqlite_on_conflict_primary_key:

some_table = Table(
    'some_table', metadata,
    Column('id', Integer, primary_key=True,
           sqlite_on_conflict_primary_key='FAIL')
)

SQLAlchemy renders the PRIMARY KEY constraint separately, so the conflict resolution algorithm is applied to the constraint itself:

CREATE TABLE some_table (
    id INTEGER NOT NULL,
    PRIMARY KEY (id) ON CONFLICT FAIL
)

INSERT...ON CONFLICT (Upsert)

See Also

This section describes the :term:`DML` version of "ON CONFLICT" for SQLite, which occurs within an INSERT statement. For "ON CONFLICT" as applied to a CREATE TABLE statement, see :ref:`sqlite_on_conflict_ddl`.

From version 3.24.0 onwards, SQLite supports "upserts" (update or insert) of rows into a table via the ON CONFLICT clause of the INSERT statement. A candidate row will only be inserted if that row does not violate any unique or primary key constraints. In the case of a unique constraint violation, a secondary action can occur which can be either "DO UPDATE", indicating that the data in the target row should be updated, or "DO NOTHING", which indicates to silently skip this row.

Conflicts are determined using columns that are part of existing unique constraints and indexes. These constraints are identified by stating the columns and conditions that comprise the indexes.

SQLAlchemy provides ON CONFLICT support via the SQLite-specific _sqlite.insert() function, which provides the generative methods _sqlite.Insert.on_conflict_do_update and _sqlite.Insert.on_conflict_do_nothing:

>>> from sqlalchemy.dialects.sqlite import insert

>>> insert_stmt = insert(my_table).values(
...     id='some_existing_id',
...     data='inserted value')

>>> do_update_stmt = insert_stmt.on_conflict_do_update(
...     index_elements=['id'],
...     set_=dict(data='updated value')
... )

>>> print(do_update_stmt)
{opensql}INSERT INTO my_table (id, data) VALUES (?, ?)
ON CONFLICT (id) DO UPDATE SET data = ?{stop}

>>> do_nothing_stmt = insert_stmt.on_conflict_do_nothing(
...     index_elements=['id']
... )

>>> print(do_nothing_stmt)
{opensql}INSERT INTO my_table (id, data) VALUES (?, ?)
ON CONFLICT (id) DO NOTHING
New in version 1.4.

See Also

Upsert - in the SQLite documentation.

Specifying the Target

Both methods supply the "target" of the conflict using column inference:

  • The :paramref:`_sqlite.Insert.on_conflict_do_update.index_elements` argument specifies a sequence containing string column names, _schema.Column objects, and/or SQL expression elements, which would identify a unique index or unique constraint.

  • When using :paramref:`_sqlite.Insert.on_conflict_do_update.index_elements` to infer an index, a partial index can be inferred by also specifying the :paramref:`_sqlite.Insert.on_conflict_do_update.index_where` parameter:

    >>> stmt = insert(my_table).values(user_email='a@b.com', data='inserted data')
    
    >>> do_update_stmt = stmt.on_conflict_do_update(
    ...     index_elements=[my_table.c.user_email],
    ...     index_where=my_table.c.user_email.like('%@gmail.com'),
    ...     set_=dict(data=stmt.excluded.data)
    ...     )
    
    >>> print(do_update_stmt)
    {opensql}INSERT INTO my_table (data, user_email) VALUES (?, ?)
    ON CONFLICT (user_email)
    WHERE user_email LIKE '%@gmail.com'
    DO UPDATE SET data = excluded.data
    >>>
    

The SET Clause

ON CONFLICT...DO UPDATE is used to perform an update of the already existing row, using any combination of new values as well as values from the proposed insertion. These values are specified using the :paramref:`_sqlite.Insert.on_conflict_do_update.set_` parameter. This parameter accepts a dictionary which consists of direct values for UPDATE:

>>> stmt = insert(my_table).values(id='some_id', data='inserted value')

>>> do_update_stmt = stmt.on_conflict_do_update(
...     index_elements=['id'],
...     set_=dict(data='updated value')
... )

>>> print(do_update_stmt)

{opensql}INSERT INTO my_table (id, data) VALUES (?, ?)
ON CONFLICT (id) DO UPDATE SET data = ?

Warning

The _sqlite.Insert.on_conflict_do_update method does not take into account Python-side default UPDATE values or generation functions, e.g. those specified using :paramref:`_schema.Column.onupdate`. These values will not be exercised for an ON CONFLICT style of UPDATE, unless they are manually specified in the :paramref:`_sqlite.Insert.on_conflict_do_update.set_` dictionary.

Updating using the Excluded INSERT Values

In order to refer to the proposed insertion row, the special alias ~.sqlite.Insert.excluded is available as an attribute on the _sqlite.Insert object; this object creates an "excluded." prefix on a column, that informs the DO UPDATE to update the row with the value that would have been inserted had the constraint not failed:

>>> stmt = insert(my_table).values(
...     id='some_id',
...     data='inserted value',
...     author='jlh'
... )

>>> do_update_stmt = stmt.on_conflict_do_update(
...     index_elements=['id'],
...     set_=dict(data='updated value', author=stmt.excluded.author)
... )

>>> print(do_update_stmt)
{opensql}INSERT INTO my_table (id, data, author) VALUES (?, ?, ?)
ON CONFLICT (id) DO UPDATE SET data = ?, author = excluded.author

Additional WHERE Criteria

The _sqlite.Insert.on_conflict_do_update method also accepts a WHERE clause using the :paramref:`_sqlite.Insert.on_conflict_do_update.where` parameter, which will limit those rows which receive an UPDATE:

>>> stmt = insert(my_table).values(
...     id='some_id',
...     data='inserted value',
...     author='jlh'
... )

>>> on_update_stmt = stmt.on_conflict_do_update(
...     index_elements=['id'],
...     set_=dict(data='updated value', author=stmt.excluded.author),
...     where=(my_table.c.status == 2)
... )
>>> print(on_update_stmt)
{opensql}INSERT INTO my_table (id, data, author) VALUES (?, ?, ?)
ON CONFLICT (id) DO UPDATE SET data = ?, author = excluded.author
WHERE my_table.status = ?

Skipping Rows with DO NOTHING

ON CONFLICT may be used to skip inserting a row entirely if any conflict with a unique constraint occurs; below this is illustrated using the _sqlite.Insert.on_conflict_do_nothing method:

>>> stmt = insert(my_table).values(id='some_id', data='inserted value')
>>> stmt = stmt.on_conflict_do_nothing(index_elements=['id'])
>>> print(stmt)
{opensql}INSERT INTO my_table (id, data) VALUES (?, ?) ON CONFLICT (id) DO NOTHING

If DO NOTHING is used without specifying any columns or constraint, it has the effect of skipping the INSERT for any unique violation which occurs:

>>> stmt = insert(my_table).values(id='some_id', data='inserted value')
>>> stmt = stmt.on_conflict_do_nothing()
>>> print(stmt)
{opensql}INSERT INTO my_table (id, data) VALUES (?, ?) ON CONFLICT DO NOTHING

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 https://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:

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

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

  • _types.INTEGER is returned if the type name includes the string INT
  • _types.TEXT is returned if the type name includes the string CHAR, CLOB or TEXT
  • _types.NullType is returned if the type name includes the string BLOB
  • _types.REAL is returned if the type name includes the string REAL, FLOA or DOUB.
  • Otherwise, the _types.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.exec_driver_sql("create table x (a integer, b integer)")
conn.exec_driver_sql("insert into x (a, b) values (1, 1)")
conn.exec_driver_sql("insert into x (a, b) values (2, 2)")

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

result = conn.exec_driver_sql('''
    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 _engine.CursorResult.keys and .Row.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 _engine.CursorResult.keys and .Row.keys() is required to return these dotted names unmodified, the sqlite_raw_colnames execution option may be provided, either on a per-_engine.Connection basis:

result = conn.execution_options(sqlite_raw_colnames=True).exec_driver_sql('''
    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.Engine basis:

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

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

SQLite-specific table options

One option for CREATE TABLE is supported directly by the SQLite dialect in conjunction with the _schema.Table construct:

  • WITHOUT ROWID:

    Table("some_table", metadata, ..., sqlite_with_rowid=False)
    
Variable colspecs Undocumented
Variable ischema​_names Undocumented
Class _​Date​Time​Mixin No class docstring; 1/1 property, 0/2 instance variable, 0/3 method documented
Class _​SQlite​Json Undocumented
Class ​SQLite​Compiler Undocumented
Class ​SQLite​DDLCompiler No class docstring; 1/9 method documented
Class ​SQLite​Dialect No class docstring; 0/9 instance variable, 0/11 class variable, 1/23 method documented
Class ​SQLite​Execution​Context Undocumented
Class ​SQLite​Identifier​Preparer Undocumented
Class ​SQLite​Type​Compiler Undocumented
colspecs =

Undocumented

ischema_names =

Undocumented