A foreign key in SQL is a table-level construct that constrains one or more
columns in that table to only allow values that are present in a different set
of columns, typically but not always located on a different table. We call the
columns which are constrained the foreign key columns and the columns which
they are constrained towards the referenced columns. The referenced columns
almost always define the primary key for their owning table, though there are
exceptions to this. The foreign key is the “joint” that connects together
pairs of rows which have a relationship with each other, and SQLAlchemy
assigns very deep importance to this concept in virtually every area of its
operation.
In SQLAlchemy as well as in DDL, foreign key constraints can be defined as
additional attributes within the table clause, or for single-column foreign
keys they may optionally be specified within the definition of a single
column. The single column foreign key is more common, and at the column level
is specified by constructing a ForeignKey object
as an argument to a Column object:
Above, we define a new table user_preference for which each row must
contain a value in the user_id column that also exists in the user
table’s user_id column.
The argument to ForeignKey is most commonly a
string of the form <tablename>.<columnname>, or for a table in a remote
schema or “owner” of the form <schemaname>.<tablename>.<columnname>. It may
also be an actual Column object, which as we’ll
see later is accessed from an existing Table
object via its c collection:
ForeignKey(user.c.user_id)
The advantage to using a string is that the in-python linkage between user
and user_preference is resolved only when first needed, so that table
objects can be easily spread across multiple modules and defined in any order.
Foreign keys may also be defined at the table level, using the
ForeignKeyConstraint object. This object can
describe a single- or multi-column foreign key. A multi-column foreign key is
known as a composite foreign key, and almost always references a table that
has a composite primary key. Below we define a table invoice which has a
composite primary key:
It’s important to note that the
ForeignKeyConstraint is the only way to define a
composite foreign key. While we could also have placed individual
ForeignKey objects on both the
invoice_item.invoice_id and invoice_item.ref_num columns, SQLAlchemy
would not be aware that these two values should be paired together - it would
be two individual foreign key constraints instead of a single composite
foreign key referencing two columns.
Creating/Dropping Foreign Key Constraints via ALTER¶
The behavior we’ve seen in tutorials and elsewhere involving
foreign keys with DDL illustrates that the constraints are typically
rendered “inline” within the CREATE TABLE statement, such as:
The CONSTRAINT..FOREIGNKEY directive is used to create the constraint
in an “inline” fashion within the CREATE TABLE definition. The
MetaData.create_all() and MetaData.drop_all() methods do
this by default, using a topological sort of all the Table objects
involved such that tables are created and dropped in order of their foreign
key dependency (this sort is also available via the
MetaData.sorted_tables accessor).
This approach can’t work when two or more foreign key constraints are
involved in a “dependency cycle”, where a set of tables
are mutually dependent on each other, assuming the backend enforces foreign
keys (always the case except on SQLite, MySQL/MyISAM). The methods will
therefore break out constraints in such a cycle into separate ALTER
statements, on all backends other than SQLite which does not support
most forms of ALTER. Given a schema like:
When we call upon MetaData.create_all() on a backend such as the
PostgreSQL backend, the cycle between these two tables is resolved and the
constraints are created separately:
In order to emit DROP for these tables, the same logic applies, however
note here that in SQL, to emit DROP CONSTRAINT requires that the constraint
has a name. In the case of the 'node' table above, we haven’t named
this constraint; the system will therefore attempt to emit DROP for only
those constraints that are named:
In the case where the cycle cannot be resolved, such as if we hadn’t applied
a name to either constraint here, we will receive the following error:
sqlalchemy.exc.CircularDependencyError: Can't sort tables for DROP;
an unresolvable foreign key dependency exists between tables:
element, node. Please ensure that the ForeignKey and ForeignKeyConstraint
objects involved in the cycle have names so that they can be dropped
using DROP CONSTRAINT.
This error only applies to the DROP case as we can emit “ADD CONSTRAINT”
in the CREATE case without a name; the database typically assigns one
automatically.
Most databases support cascading of foreign key values, that is the when a
parent row is updated the new value is placed in child rows, or when the
parent row is deleted all corresponding child rows are set to null or deleted.
In data definition language these are specified using phrases like “ON UPDATE
CASCADE”, “ON DELETE CASCADE”, and “ON DELETE SET NULL”, corresponding to
foreign key constraints. The phrase after “ON UPDATE” or “ON DELETE” may also
allow other phrases that are specific to the database in use. The
ForeignKey and
ForeignKeyConstraint objects support the
generation of this clause via the onupdate and ondelete keyword
arguments. The value is any string which will be output after the appropriate
“ON UPDATE” or “ON DELETE” phrase:
Unique constraints can be created anonymously on a single column using the
unique keyword on Column. Explicitly named
unique constraints and/or those with multiple columns are created via the
UniqueConstraint table-level construct.
Check constraints can be named or unnamed and can be created at the Column or
Table level, using the CheckConstraint construct.
The text of the check constraint is passed directly through to the database,
so there is limited “database independent” behavior. Column level check
constraints generally should only refer to the column to which they are
placed, while table level constraints can refer to any columns in the table.
Note that some databases do not actively support check constraints such as
older versions of MySQL (prior to 8.0.16).
The primary key constraint of any Table object is implicitly
present, based on the Column objects that are marked with the
Column.primary_key flag. The PrimaryKeyConstraint
object provides explicit access to this constraint, which includes the
option of being configured directly:
Setting up Constraints when using the Declarative ORM Extension¶
The Table is the SQLAlchemy Core construct that allows one to define
table metadata, which among other things can be used by the SQLAlchemy ORM
as a target to map a class. The Declarative
extension allows the Table object to be created automatically, given
the contents of the table primarily as a mapping of Column objects.
To apply table-level constraint objects such as ForeignKeyConstraint
to a table defined using Declarative, use the __table_args__ attribute,
described at Table Configuration.
Relational databases typically assign explicit names to all constraints and
indexes. In the common case that a table is created using CREATETABLE
where constraints such as CHECK, UNIQUE, and PRIMARY KEY constraints are
produced inline with the table definition, the database usually has a system
in place in which names are automatically assigned to these constraints, if
a name is not otherwise specified. When an existing database table is altered
in a database using a command such as ALTERTABLE, this command typically
needs to specify explicit names for new constraints as well as be able to
specify the name of an existing constraint that is to be dropped or modified.
Constraints can be named explicitly using the Constraint.name parameter,
and for indexes the Index.name parameter. However, in the
case of constraints this parameter is optional. There are also the use
cases of using the Column.unique and Column.index
parameters which create UniqueConstraint and Index objects
without an explicit name being specified.
The use case of alteration of existing tables and constraints can be handled
by schema migration tools such as Alembic.
However, neither Alembic nor SQLAlchemy currently create names for constraint
objects where the name is otherwise unspecified, leading to the case where
being able to alter existing constraints means that one must reverse-engineer
the naming system used by the relational database to auto-assign names,
or that care must be taken to ensure that all constraints are named.
In contrast to having to assign explicit names to all Constraint
and Index objects, automated naming schemes can be constructed
using events. This approach has the advantage that constraints will get
a consistent naming scheme without the need for explicit name parameters
throughout the code, and also that the convention takes place just as well
for those constraints and indexes produced by the Column.unique
and Column.index parameters. As of SQLAlchemy 0.9.2 this
event-based approach is included, and can be configured using the argument
MetaData.naming_convention.
Configuring a Naming Convention for a MetaData Collection¶
MetaData.naming_convention refers to a dictionary which accepts
the Index class or individual Constraint classes as keys,
and Python string templates as values. It also accepts a series of
string-codes as alternative keys, "fk", "pk",
"ix", "ck", "uq" for foreign key, primary key, index,
check, and unique constraint, respectively. The string templates in this
dictionary are used whenever a constraint or index is associated with this
MetaData object that does not have an existing name given (including
one exception case where an existing name can be further embellished).
An example naming convention that suits basic cases is as follows:
The above convention will establish names for all constraints within
the target MetaData collection.
For example, we can observe the name produced when we create an unnamed
UniqueConstraint:
A key advantage to the naming convention approach is that the names are established
at Python construction time, rather than at DDL emit time. The effect this has
when using Alembic’s --autogenerate feature is that the naming convention
will be explicit when a new migration script is generated:
The above "uq_user_name" string was copied from the UniqueConstraint
object that --autogenerate located in our metadata.
The tokens available include %(table_name)s, %(referred_table_name)s,
%(column_0_name)s, %(column_0_label)s, %(column_0_key)s,
%(referred_column_0_name)s, and %(constraint_name)s, as well as
multiple-column versions of each including %(column_0N_name)s,
%(column_0_N_name)s, %(referred_column_0_N_name)s which render all
column names separated with or without an underscore. The documentation for
MetaData.naming_convention has further detail on each of these
conventions.
The default value for MetaData.naming_convention handles
the long-standing SQLAlchemy behavior of assigning a name to a Index
object that is created using the Column.index parameter:
When a generated name, particularly those that use the multiple-column tokens,
is too long for the identifier length limit of the target database
(for example, PostgreSQL has a limit of 63 characters), the name will be
deterministically truncated using a 4-character suffix based on the md5
hash of the long name. For example, the naming convention below will
generate very long names given the column names in use:
The above suffix a79e is based on the md5 hash of the long name and will
generate the same value every time to produce consistent names for a given
schema.
New tokens can also be added, by specifying an additional token
and a callable within the naming_convention dictionary. For example, if we
wanted to name our foreign key constraints using a GUID scheme, we could do
that as follows:
New in version 1.3.0: added multi-column naming tokens such as %(column_0_N_name)s.
Generated names that go beyond the character limit for the target database will be
deterministically truncated.
The CheckConstraint object is configured against an arbitrary
SQL expression, which can have any number of columns present, and additionally
is often configured using a raw SQL string. Therefore a common convention
to use with CheckConstraint is one where we expect the object
to have a name already, and we then enhance it with other convention elements.
A typical convention is "ck_%(table_name)s_%(constraint_name)s":
CheckConstraint also supports the %(columns_0_name)s
token; we can make use of this by ensuring we use a Column or
column() element within the constraint’s expression,
either by declaring the constraint separate from the table:
The determination of the name of “column zero” is performed by scanning
the given expression for column objects. If the expression has more than
one column present, the scan does use a deterministic search, however the
structure of the expression will determine which column is noted as
“column zero”.
Configuring Naming for Boolean, Enum, and other schema types¶
The SchemaType class refers to type objects such as Boolean
and Enum which generate a CHECK constraint accompanying the type.
The name for the constraint here is most directly set up by sending
the “name” parameter, e.g. Boolean.name:
The naming convention feature may be combined with these types as well,
normally by using a convention which includes %(constraint_name)s
and then applying a name to the type:
The SchemaType classes use special internal symbols so that
the naming convention is only determined at DDL compile time. On PostgreSQL,
there’s a native BOOLEAN type, so the CHECK constraint of Boolean
is not needed; we are safe to set up a Boolean type without a
name, even though a naming convention is in place for check constraints.
This convention will only be consulted for the CHECK constraint if we
run against a database without a native BOOLEAN type like SQLite or
MySQL.
The CHECK constraint may also make use of the column_0_name token,
which works nicely with SchemaType since these constraints have
only one column:
Optional string that will render an SQL comment on
foreign key constraint creation.
New in version 2.0.
**dialect_kw¶ – Additional keyword arguments are dialect
specific, and passed in the form <dialectname>_<argname>. See
the documentation regarding an individual dialect at
Dialects for detail on documented arguments.
_create_rule¶ – used internally by some datatypes that also create constraints.
_type_bound¶ – used internally to indicate that this constraint is associated with
a specific datatype.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
A string containing the constraint definition, which will be used
verbatim, or a SQL expression construct. If given as a string,
the object is converted to a text() object.
If the textual
string includes a colon character, escape this using a backslash:
CheckConstraint(r"foo ~ E'a(?\:b|c)d")
Warning
The CheckConstraint.sqltext argument to CheckConstraint can be passed as a Python string argument, which will be treated as trusted SQL text and rendered as given. DO NOT PASS UNTRUSTED INPUT TO THIS PARAMETER.
name¶ – Optional, the in-database name of the constraint.
deferrable¶ – Optional bool. If set, emit DEFERRABLE or NOT DEFERRABLE when
issuing DDL for this constraint.
initially¶ – Optional string. If set, emit INITIALLY <value> when issuing DDL
for this constraint.
info¶ – Optional data dictionary which will be populated into the
SchemaItem.info attribute of this object.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
Note that ForeignKey is only a marker object that defines
a dependency between two columns. The actual constraint
is in all cases represented by the ForeignKeyConstraint
object. This object will be generated automatically when
a ForeignKey is associated with a Column which
in turn is associated with a Table. Conversely,
when ForeignKeyConstraint is applied to a
Table,
ForeignKey markers are automatically generated to be
present on each associated Column, which are also
associated with the constraint object.
Note that you cannot define a “composite” foreign key constraint,
that is a constraint between a grouping of multiple parent/child
columns, using ForeignKey objects. To define this grouping,
the ForeignKeyConstraint object must be used, and applied
to the Table. The associated ForeignKey objects
are created automatically.
The ForeignKey objects associated with an individual
Column
object are available in the foreign_keys collection
of that column.
The ForeignKey object when constructed generates a
ForeignKeyConstraint
which is associated with the parent
Table object’s collection of constraints.
Parameters:
column¶ – A single target column for the key relationship. A
Column object or a column name as a string:
tablename.columnkey or schema.tablename.columnkey.
columnkey is the key which has been assigned to the column
(defaults to the column name itself), unless link_to_name is
True in which case the rendered name of the column is used.
name¶ – Optional string. An in-database name for the key if
constraint is not provided.
Optional string. If set, emit ON DELETE <value> when
issuing DDL for this constraint. Typical values include CASCADE,
SET NULL and RESTRICT. Some dialects may allow for additional
syntaxes.
passed to the underlying
ForeignKeyConstraint
to indicate the constraint should
be generated/dropped externally from the CREATE TABLE/ DROP TABLE
statement. See ForeignKeyConstraint.use_alter
for further description.
Optional string that will render an SQL comment on
foreign key constraint creation.
New in version 2.0.
**dialect_kw¶ – Additional keyword arguments are dialect
specific, and passed in the form <dialectname>_<argname>. The
arguments are ultimately handled by a corresponding
ForeignKeyConstraint.
See the documentation regarding
an individual dialect at Dialects for detail on
documented arguments.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
Defines a single column or composite FOREIGN KEY … REFERENCES
constraint. For a no-frills, single column foreign key, adding a
ForeignKey to the definition of a Column
is a
shorthand equivalent for an unnamed, single column
ForeignKeyConstraint.
columns¶ – A sequence of local column names. The named columns
must be defined and present in the parent Table. The names should
match the key given to each column (defaults to the name) unless
link_to_name is True.
refcolumns¶ – A sequence of foreign column names or Column
objects. The columns must all be located within the same Table.
name¶ – Optional, the in-database name of the key.
Optional string. If set, emit ON DELETE <value> when
issuing DDL for this constraint. Typical values include CASCADE,
SET NULL and RESTRICT. Some dialects may allow for additional
syntaxes.
If True, do not emit the DDL for this constraint as
part of the CREATE TABLE definition. Instead, generate it via an
ALTER TABLE statement issued after the full collection of tables
have been created, and drop it via an ALTER TABLE statement before
the full collection of tables are dropped.
The use of ForeignKeyConstraint.use_alter is
particularly geared towards the case where two or more tables
are established within a mutually-dependent foreign key constraint
relationship; however, the MetaData.create_all() and
MetaData.drop_all()
methods will perform this resolution
automatically, so the flag is normally not needed.
Optional string that will render an SQL comment on
foreign key constraint creation.
New in version 2.0.
**dialect_kw¶ – Additional keyword arguments are dialect
specific, and passed in the form <dialectname>_<argname>. See
the documentation regarding an individual dialect at
Dialects for detail on documented arguments.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
Return a list of string keys representing the local
columns in this ForeignKeyConstraint.
This list is either the original string arguments sent
to the constructor of the ForeignKeyConstraint,
or if the constraint has been initialized with Column
objects, is the string .key of each element.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
This is a dynamically calculated attribute which may not be available
if the constraint and/or parent table is not yet associated with
a metadata collection that contains the referred table.
The primary key of a Table can also be specified by using
a PrimaryKeyConstraint object explicitly; in this mode of usage,
the “name” of the constraint can also be specified, as well as other
options which may be recognized by dialects:
The two styles of column-specification should generally not be mixed.
An warning is emitted if the columns present in the
PrimaryKeyConstraint
don’t match the columns that were marked as primary_key=True, if both
are present; in this case, the columns are taken strictly from the
PrimaryKeyConstraint declaration, and those columns otherwise
marked as primary_key=True are ignored. This behavior is intended to
be backwards compatible with previous behavior.
For the use case where specific options are to be specified on the
PrimaryKeyConstraint, but the usual style of using
primary_key=True flags is still desirable, an empty
PrimaryKeyConstraint may be specified, which will take on the
primary key column collection from the Table based on the
flags:
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
Defines a single column or composite UNIQUE constraint. For a no-frills,
single column constraint, adding unique=True to the Column
definition is a shorthand equivalent for an unnamed, single column
UniqueConstraint.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.
The name of the above constraint will be rendered as "ck_t_x5".
That is, the existing name x5 is used in the naming convention as the
constraint_name token.
In some situations, such as in migration scripts, we may be rendering
the above CheckConstraint with a name that’s already been
converted. In order to make sure the name isn’t double-modified, the
new name is applied using the conv() marker. We can
use this explicitly as follows:
Indexes can be created anonymously (using an auto-generated name ix_<columnlabel>) for a single column using the inline index keyword on
Column, which also modifies the usage of
unique to apply the uniqueness to the index itself, instead of adding a
separate UNIQUE constraint. For indexes with specific names or which encompass
more than one column, use the Index construct,
which requires a name.
Below we illustrate a Table with several
Index objects associated. The DDL for “CREATE
INDEX” is issued right after the create statements for the table:
metadata_obj=MetaData()mytable=Table("mytable",metadata_obj,# an indexed column, with index "ix_mytable_col1"Column("col1",Integer,index=True),# a uniquely indexed column with index "ix_mytable_col2"Column("col2",Integer,index=True,unique=True),Column("col3",Integer),Column("col4",Integer),Column("col5",Integer),Column("col6",Integer),)# place an index on col3, col4Index("idx_col34",mytable.c.col3,mytable.c.col4)# place a unique index on col5, col6Index("myindex",mytable.c.col5,mytable.c.col6,unique=True)mytable.create(engine)
Note in the example above, the Index construct is created
externally to the table which it corresponds, using Column
objects directly. Index also supports
“inline” definition inside the Table, using string names to
identify columns:
metadata_obj=MetaData()mytable=Table("mytable",metadata_obj,Column("col1",Integer),Column("col2",Integer),Column("col3",Integer),Column("col4",Integer),# place an index on col1, col2Index("idx_col12","col1","col2"),# place a unique index on col3, col4Index("idx_col34","col3","col4",unique=True),)
The Index object also supports its own create() method:
Index supports SQL and function expressions, as supported by the
target backend. To create an index against a column using a descending
value, the ColumnElement.desc() modifier may be used:
Functional indexes are supported as well, typically by using the
func construct in conjunction with table-bound
Column objects:
Index("some_index",func.lower(sometable.c.name))
An Index can also be manually associated with a
Table,
either through inline declaration or using
Table.append_constraint(). When this approach is used,
the names
of the indexed columns can be specified as strings:
*expressions¶ – Column expressions to include in the index. The expressions
are normally instances of Column, but may also
be arbitrary SQL expressions which ultimately refer to a
Column.
unique=False¶ – Keyword only argument; if True, create a unique index.
quote=None¶ – Keyword only argument; whether to apply quoting to the name of
the index. Works in the same manner as that of
Column.quote.
info=None¶ – Optional data dictionary which will be populated
into the SchemaItem.info attribute of this object.
**dialect_kw¶ – Additional keyword arguments not mentioned above
are dialect specific, and passed in the form
<dialectname>_<argname>. See the documentation regarding an
individual dialect at Dialects for detail on
documented arguments.
The DialectKWArgs.argument_for() method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a
data member of the dialect class. The use case for ad-hoc addition of
argument names is typically for end-user code that is also using
a custom compilation scheme which consumes the additional arguments.
Parameters:
dialect_name¶ – name of a dialect. The dialect must be
locatable, else a NoSuchModuleError is raised. The
dialect must also include an existing
DefaultDialect.construct_arguments collection, indicating
that it participates in the keyword-argument validation and default
system, else ArgumentError is raised. If the dialect does
not include this collection, then any keyword argument can be
specified on behalf of this dialect already. All dialects packaged
within SQLAlchemy include this collection, however for third party
dialects, support may vary.
A collection of keyword arguments specified as dialect-specific
options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg> where the value will be assembled
into the list of options.