自定义 DDL

Customizing DDL

在前面的章节中,我们讨论了各种模式构造,包括 TableForeignKeyConstraintCheckConstraintSequence。在整个过程中,我们依赖于 TableMetaDatacreate()create_all() 方法来发出所有构造的数据定义语言(DDL)。当发出时,会调用预定的操作顺序,并无条件地创建每个表的DDL,包括与其相关的所有约束和其他对象。对于需要数据库特定DDL的更复杂场景,SQLAlchemy提供了两种技术,可以根据任何条件添加任何DDL,无论是伴随标准的表生成还是单独生成。

In the preceding sections we’ve discussed a variety of schema constructs including Table, ForeignKeyConstraint, CheckConstraint, and Sequence. Throughout, we’ve relied upon the create() and create_all() methods of Table and MetaData in order to issue data definition language (DDL) for all constructs. When issued, a pre-determined order of operations is invoked, and DDL to create each table is created unconditionally including all constraints and other objects associated with it. For more complex scenarios where database-specific DDL is required, SQLAlchemy offers two techniques which can be used to add any DDL based on any condition, either accompanying the standard generation of tables or by itself.

自定义 DDL

Custom DDL

自定义 DDL 语句可以最方便地通过 DDL 构造实现。 该构造与其他所有 DDL 元素类似,只不过它接受一个字符串作为要执行的文本:

event.listen(
    metadata,
    "after_create",
    DDL(
        "ALTER TABLE users ADD CONSTRAINT "
        "cst_user_name_length "
        " CHECK (length(user_name) >= 8)"
    ),
)

一种更全面的方式是使用自定义编译机制来创建 DDL 构造的库——详见 自定义 SQL 构造和编译扩展

Custom DDL phrases are most easily achieved using the DDL construct. This construct works like all the other DDL elements except it accepts a string which is the text to be emitted:

event.listen(
    metadata,
    "after_create",
    DDL(
        "ALTER TABLE users ADD CONSTRAINT "
        "cst_user_name_length "
        " CHECK (length(user_name) >= 8)"
    ),
)

A more comprehensive method of creating libraries of DDL constructs is to use custom compilation - see 自定义 SQL 构造和编译扩展 for details.

控制 DDL 序列

Controlling DDL Sequences

前面提到的 DDL 构造还可以根据数据库的检查结果有条件地执行。 该功能可通过 ExecutableDDLElement.execute_if() 方法实现。 例如,如果我们只想在 PostgreSQL 后端创建触发器,可以这样调用:

mytable = Table(
    "mytable",
    metadata,
    Column("id", Integer, primary_key=True),
    Column("data", String(50)),
)

func = DDL(
    "CREATE FUNCTION my_func() "
    "RETURNS TRIGGER AS $$ "
    "BEGIN "
    "NEW.data := 'ins'; "
    "RETURN NEW; "
    "END; $$ LANGUAGE PLPGSQL"
)

trigger = DDL(
    "CREATE TRIGGER dt_ins BEFORE INSERT ON mytable "
    "FOR EACH ROW EXECUTE PROCEDURE my_func();"
)

event.listen(mytable, "after_create", func.execute_if(dialect="postgresql"))

event.listen(mytable, "after_create", trigger.execute_if(dialect="postgresql"))

ExecutableDDLElement.execute_if.dialect 关键字也接受一个由字符串组成的元组,表示多个方言名称:

event.listen(
    mytable, "after_create", trigger.execute_if(dialect=("postgresql", "mysql"))
)
event.listen(
    mytable, "before_drop", trigger.execute_if(dialect=("postgresql", "mysql"))
)

ExecutableDDLElement.execute_if() 方法也可以使用一个可调用对象, 该对象会接收当前使用的数据库连接。 在下面的示例中,我们通过先查询 PostgreSQL 的系统目录, 判断 CHECK 约束是否已存在,来有条件地创建该约束:

def should_create(ddl, target, connection, **kw):
    row = connection.execute(
        "select conname from pg_constraint where conname='%s'" % ddl.element.name
    ).scalar()
    return not bool(row)


def should_drop(ddl, target, connection, **kw):
    return not should_create(ddl, target, connection, **kw)


event.listen(
    users,
    "after_create",
    DDL(
        "ALTER TABLE users ADD CONSTRAINT "
        "cst_user_name_length CHECK (length(user_name) >= 8)"
    ).execute_if(callable_=should_create),
)
event.listen(
    users,
    "before_drop",
    DDL("ALTER TABLE users DROP CONSTRAINT cst_user_name_length").execute_if(
        callable_=should_drop
    ),
)

users.create(engine)
CREATE TABLE users ( user_id SERIAL NOT NULL, user_name VARCHAR(40) NOT NULL, PRIMARY KEY (user_id) ) SELECT conname FROM pg_constraint WHERE conname='cst_user_name_length' ALTER TABLE users ADD CONSTRAINT cst_user_name_length CHECK (length(user_name) >= 8)
users.drop(engine)
SELECT conname FROM pg_constraint WHERE conname='cst_user_name_length' ALTER TABLE users DROP CONSTRAINT cst_user_name_length DROP TABLE users

The DDL construct introduced previously also has the ability to be invoked conditionally based on inspection of the database. This feature is available using the ExecutableDDLElement.execute_if() method. For example, if we wanted to create a trigger but only on the PostgreSQL backend, we could invoke this as:

mytable = Table(
    "mytable",
    metadata,
    Column("id", Integer, primary_key=True),
    Column("data", String(50)),
)

func = DDL(
    "CREATE FUNCTION my_func() "
    "RETURNS TRIGGER AS $$ "
    "BEGIN "
    "NEW.data := 'ins'; "
    "RETURN NEW; "
    "END; $$ LANGUAGE PLPGSQL"
)

trigger = DDL(
    "CREATE TRIGGER dt_ins BEFORE INSERT ON mytable "
    "FOR EACH ROW EXECUTE PROCEDURE my_func();"
)

event.listen(mytable, "after_create", func.execute_if(dialect="postgresql"))

event.listen(mytable, "after_create", trigger.execute_if(dialect="postgresql"))

The ExecutableDDLElement.execute_if.dialect keyword also accepts a tuple of string dialect names:

event.listen(
    mytable, "after_create", trigger.execute_if(dialect=("postgresql", "mysql"))
)
event.listen(
    mytable, "before_drop", trigger.execute_if(dialect=("postgresql", "mysql"))
)

The ExecutableDDLElement.execute_if() method can also work against a callable function that will receive the database connection in use. In the example below, we use this to conditionally create a CHECK constraint, first looking within the PostgreSQL catalogs to see if it exists:

def should_create(ddl, target, connection, **kw):
    row = connection.execute(
        "select conname from pg_constraint where conname='%s'" % ddl.element.name
    ).scalar()
    return not bool(row)


def should_drop(ddl, target, connection, **kw):
    return not should_create(ddl, target, connection, **kw)


event.listen(
    users,
    "after_create",
    DDL(
        "ALTER TABLE users ADD CONSTRAINT "
        "cst_user_name_length CHECK (length(user_name) >= 8)"
    ).execute_if(callable_=should_create),
)
event.listen(
    users,
    "before_drop",
    DDL("ALTER TABLE users DROP CONSTRAINT cst_user_name_length").execute_if(
        callable_=should_drop
    ),
)

users.create(engine)
CREATE TABLE users ( user_id SERIAL NOT NULL, user_name VARCHAR(40) NOT NULL, PRIMARY KEY (user_id) ) SELECT conname FROM pg_constraint WHERE conname='cst_user_name_length' ALTER TABLE users ADD CONSTRAINT cst_user_name_length CHECK (length(user_name) >= 8)
users.drop(engine)
SELECT conname FROM pg_constraint WHERE conname='cst_user_name_length' ALTER TABLE users DROP CONSTRAINT cst_user_name_length DROP TABLE users

使用内置 DDLElement 类

Using the built-in DDLElement Classes

sqlalchemy.schema 包含了一些 SQL 表达式构造,用于生成 DDL 表达式, 它们都继承自通用的基类 ExecutableDDLElement。 例如,要生成一个 CREATE TABLE 语句,可以使用 CreateTable 构造:

from sqlalchemy.schema import CreateTable

with engine.connect() as conn:
    conn.execute(CreateTable(mytable))
CREATE TABLE mytable ( col1 INTEGER, col2 INTEGER, col3 INTEGER, col4 INTEGER, col5 INTEGER, col6 INTEGER )

如上所示,CreateTable 构造的工作方式类似于其他表达式构造(如 select()table.insert() 等)。 SQLAlchemy 中所有与 DDL 相关的构造都是 ExecutableDDLElement 的子类; 这个基类对应所有的 CREATE、DROP 以及 ALTER 操作对象, 不仅适用于 SQLAlchemy,也适用于 Alembic Migrations。 可用构造的完整参考请参见 DDL 表达式构造 API

用户也可以自定义继承自 ExecutableDDLElement 的类,以创建自己的 DDL 构造。 文档 自定义 SQL 构造和编译扩展 中包含了多个示例。

The sqlalchemy.schema package contains SQL expression constructs that provide DDL expressions, all of which extend from the common base ExecutableDDLElement. For example, to produce a CREATE TABLE statement, one can use the CreateTable construct:

from sqlalchemy.schema import CreateTable

with engine.connect() as conn:
    conn.execute(CreateTable(mytable))
CREATE TABLE mytable ( col1 INTEGER, col2 INTEGER, col3 INTEGER, col4 INTEGER, col5 INTEGER, col6 INTEGER )

Above, the CreateTable construct works like any other expression construct (such as select(), table.insert(), etc.). All of SQLAlchemy’s DDL oriented constructs are subclasses of the ExecutableDDLElement base class; this is the base of all the objects corresponding to CREATE and DROP as well as ALTER, not only in SQLAlchemy but in Alembic Migrations as well. A full reference of available constructs is in DDL 表达式构造 API.

User-defined DDL constructs may also be created as subclasses of ExecutableDDLElement itself. The documentation in 自定义 SQL 构造和编译扩展 has several examples of this.

控制 DDL 约束和索引的生成

Controlling DDL Generation of Constraints and Indexes

在 2.0 版本加入.

前面提到的 ExecutableDDLElement.execute_if() 方法在需要有条件执行自定义 DDL 类时非常有用, 但对于通常与特定 Table 相关的元素(如约束和索引),也常常有类似的“条件”需求。 例如,一个索引可能包含某些特定于 PostgreSQL 或 SQL Server 后端的特性。 针对这种用例,可以使用 Constraint.ddl_if()Index.ddl_if() 方法, 它们可以用于 CheckConstraintUniqueConstraintIndex 等构造, 并接受与 ExecutableDDLElement.execute_if() 方法相同的参数,以控制这些对象的 DDL 是否会在其所属的 Table 上下文中被执行。这些方法可以在定义 Table 时内联使用 (或者同样地,在 ORM 声明式映射中通过 __table_args__ 集合使用),如下所示:

from sqlalchemy import CheckConstraint, Index
from sqlalchemy import MetaData, Table, Column
from sqlalchemy import Integer, String

meta = MetaData()

my_table = Table(
    "my_table",
    meta,
    Column("id", Integer, primary_key=True),
    Column("num", Integer),
    Column("data", String),
    Index("my_pg_index", "data").ddl_if(dialect="postgresql"),
    CheckConstraint("num > 5").ddl_if(dialect="postgresql"),
)

在上面的示例中,Table 构造包含一个 Index 和一个 CheckConstraint 构造, 它们都通过 .ddl_if(dialect="postgresql") 指定仅在 PostgreSQL 方言下生效, 因此它们只会在生成 PostgreSQL 的 CREATE TABLE 语句时被包含。 例如,如果我们对 SQLite 方言执行 meta.create_all(),两个构造都不会被包含:

>>> from sqlalchemy import create_engine
>>> sqlite_engine = create_engine("sqlite+pysqlite://", echo=True)
>>> meta.create_all(sqlite_engine)
BEGIN (implicit) PRAGMA main.table_info("my_table") [raw sql] () PRAGMA temp.table_info("my_table") [raw sql] () CREATE TABLE my_table ( id INTEGER NOT NULL, num INTEGER, data VARCHAR, PRIMARY KEY (id) )

然而,如果我们在 PostgreSQL 数据库上运行相同命令,将会看到针对 CHECK 约束的内联 DDL, 以及为索引单独生成的 CREATE 语句:

>>> from sqlalchemy import create_engine
>>> postgresql_engine = create_engine(
...     "postgresql+psycopg2://scott:tiger@localhost/test", echo=True
... )
>>> meta.create_all(postgresql_engine)
BEGIN (implicit) select relname from pg_class c join pg_namespace n on n.oid=c.relnamespace where pg_catalog.pg_table_is_visible(c.oid) and relname=%(name)s [generated in 0.00009s] {'name': 'my_table'} CREATE TABLE my_table ( id SERIAL NOT NULL, num INTEGER, data VARCHAR, PRIMARY KEY (id), CHECK (num > 5) ) [no key 0.00007s] {} CREATE INDEX my_pg_index ON my_table (data) [no key 0.00013s] {} COMMIT

Constraint.ddl_if()Index.ddl_if() 方法所创建的事件钩子不仅可以在 DDL 执行时被调用, 还会在 SQL 编译阶段参与处理,比如在 CreateTable 对象渲染 CHECK (num > 5) 语句时。 因此,通过 ddl_if.callable_() 参数所接收的事件钩子会包含更丰富的参数, 比如 dialect 关键字参数,以及 compiler 参数,该参数是 DDLCompiler 的一个实例, 用于处理 CREATE TABLE 语句中内联渲染的部分。 需要注意的是,当事件在 DDLCompiler 阶段触发时, 不会 提供 bind 参数。 因此,如果希望检测数据库版本信息,推荐使用传入的 Dialect 对象。 比如,要检测 PostgreSQL 14 及以上版本,可以这样编写:

def only_pg_14(ddl_element, target, bind, dialect, **kw):
    return dialect.name == "postgresql" and dialect.server_version_info >= (14,)


my_table = Table(
    "my_table",
    meta,
    Column("id", Integer, primary_key=True),
    Column("num", Integer),
    Column("data", String),
    Index("my_pg_index", "data").ddl_if(callable_=only_pg_14),
)

While the previously mentioned ExecutableDDLElement.execute_if() method is useful for custom DDL classes which need to invoke conditionally, there is also a common need for elements that are typically related to a particular Table, namely constraints and indexes, to also be subject to “conditional” rules, such as an index that includes features that are specific to a particular backend such as PostgreSQL or SQL Server. For this use case, the Constraint.ddl_if() and Index.ddl_if() methods may be used against constructs such as CheckConstraint, UniqueConstraint and Index, accepting the same arguments as the ExecutableDDLElement.execute_if() method in order to control whether or not their DDL will be emitted in terms of their parent Table object. These methods may be used inline when creating the definition for a Table (or similarly, when using the __table_args__ collection in an ORM declarative mapping), such as:

from sqlalchemy import CheckConstraint, Index
from sqlalchemy import MetaData, Table, Column
from sqlalchemy import Integer, String

meta = MetaData()

my_table = Table(
    "my_table",
    meta,
    Column("id", Integer, primary_key=True),
    Column("num", Integer),
    Column("data", String),
    Index("my_pg_index", "data").ddl_if(dialect="postgresql"),
    CheckConstraint("num > 5").ddl_if(dialect="postgresql"),
)

In the above example, the Table construct refers to both an Index and a CheckConstraint construct, both which indicate .ddl_if(dialect="postgresql"), which indicates that these elements will be included in the CREATE TABLE sequence only against the PostgreSQL dialect. If we run meta.create_all() against the SQLite dialect, for example, neither construct will be included:

>>> from sqlalchemy import create_engine
>>> sqlite_engine = create_engine("sqlite+pysqlite://", echo=True)
>>> meta.create_all(sqlite_engine)
BEGIN (implicit) PRAGMA main.table_info("my_table") [raw sql] () PRAGMA temp.table_info("my_table") [raw sql] () CREATE TABLE my_table ( id INTEGER NOT NULL, num INTEGER, data VARCHAR, PRIMARY KEY (id) )

However, if we run the same commands against a PostgreSQL database, we will see inline DDL for the CHECK constraint as well as a separate CREATE statement emitted for the index:

>>> from sqlalchemy import create_engine
>>> postgresql_engine = create_engine(
...     "postgresql+psycopg2://scott:tiger@localhost/test", echo=True
... )
>>> meta.create_all(postgresql_engine)
BEGIN (implicit) select relname from pg_class c join pg_namespace n on n.oid=c.relnamespace where pg_catalog.pg_table_is_visible(c.oid) and relname=%(name)s [generated in 0.00009s] {'name': 'my_table'} CREATE TABLE my_table ( id SERIAL NOT NULL, num INTEGER, data VARCHAR, PRIMARY KEY (id), CHECK (num > 5) ) [no key 0.00007s] {} CREATE INDEX my_pg_index ON my_table (data) [no key 0.00013s] {} COMMIT

The Constraint.ddl_if() and Index.ddl_if() methods create an event hook that may be consulted not just at DDL execution time, as is the behavior with ExecutableDDLElement.execute_if(), but also within the SQL compilation phase of the CreateTable object, which is responsible for rendering the CHECK (num > 5) DDL inline within the CREATE TABLE statement. As such, the event hook that is received by the ddl_if.callable_() parameter has a richer argument set present, including that there is a dialect keyword argument passed, as well as an instance of DDLCompiler via the compiler keyword argument for the “inline rendering” portion of the sequence. The bind argument is not present when the event is triggered within the DDLCompiler sequence, so a modern event hook that wishes to inspect the database versioning information would best use the given Dialect object, such as to test PostgreSQL versioning:

def only_pg_14(ddl_element, target, bind, dialect, **kw):
    return dialect.name == "postgresql" and dialect.server_version_info >= (14,)


my_table = Table(
    "my_table",
    meta,
    Column("id", Integer, primary_key=True),
    Column("num", Integer),
    Column("data", String),
    Index("my_pg_index", "data").ddl_if(callable_=only_pg_14),
)

DDL 表达式构造 API

DDL Expression Constructs API

Object Name Description

_CreateDropBase

Base class for DDL constructs that represent CREATE and DROP or equivalents.

AddConstraint

Represent an ALTER TABLE ADD CONSTRAINT statement.

BaseDDLElement

The root of DDL constructs, including those that are sub-elements within the “create table” and other processes.

CreateColumn

Represent a Column as rendered in a CREATE TABLE statement, via the CreateTable construct.

CreateIndex

Represent a CREATE INDEX statement.

CreateSchema

Represent a CREATE SCHEMA statement.

CreateSequence

Represent a CREATE SEQUENCE statement.

CreateTable

Represent a CREATE TABLE statement.

DDL

A literal DDL statement.

DropConstraint

Represent an ALTER TABLE DROP CONSTRAINT statement.

DropIndex

Represent a DROP INDEX statement.

DropSchema

Represent a DROP SCHEMA statement.

DropSequence

Represent a DROP SEQUENCE statement.

DropTable

Represent a DROP TABLE statement.

ExecutableDDLElement

Base class for standalone executable DDL expression constructs.

sort_tables(tables[, skip_fn, extra_dependencies])

Sort a collection of Table objects based on dependency.

sort_tables_and_constraints(tables[, filter_fn, extra_dependencies, _warn_for_cycles])

Sort a collection of Table / ForeignKeyConstraint objects.

function sqlalchemy.schema.sort_tables(tables: Iterable[TableClause], skip_fn: Callable[[ForeignKeyConstraint], bool] | None = None, extra_dependencies: typing_Sequence[Tuple[TableClause, TableClause]] | None = None) List[Table]

Sort a collection of Table objects based on dependency.

This is a dependency-ordered sort which will emit Table objects such that they will follow their dependent Table objects. Tables are dependent on another based on the presence of ForeignKeyConstraint objects as well as explicit dependencies added by Table.add_is_dependent_on().

警告

The sort_tables() function cannot by itself accommodate automatic resolution of dependency cycles between tables, which are usually caused by mutually dependent foreign key constraints. When these cycles are detected, the foreign keys of these tables are omitted from consideration in the sort. A warning is emitted when this condition occurs, which will be an exception raise in a future release. Tables which are not part of the cycle will still be returned in dependency order.

To resolve these cycles, the ForeignKeyConstraint.use_alter parameter may be applied to those constraints which create a cycle. Alternatively, the sort_tables_and_constraints() function will automatically return foreign key constraints in a separate collection when cycles are detected so that they may be applied to a schema separately.

参数:
  • tables – a sequence of Table objects.

  • skip_fn – optional callable which will be passed a ForeignKeyConstraint object; if it returns True, this constraint will not be considered as a dependency. Note this is different from the same parameter in sort_tables_and_constraints(), which is instead passed the owning ForeignKeyConstraint object.

  • extra_dependencies – a sequence of 2-tuples of tables which will also be considered as dependent on each other.

参见

sort_tables_and_constraints()

MetaData.sorted_tables - uses this function to sort

function sqlalchemy.schema.sort_tables_and_constraints(tables, filter_fn=None, extra_dependencies=None, _warn_for_cycles=False)

Sort a collection of Table / ForeignKeyConstraint objects.

This is a dependency-ordered sort which will emit tuples of (Table, [ForeignKeyConstraint, ...]) such that each Table follows its dependent Table objects. Remaining ForeignKeyConstraint objects that are separate due to dependency rules not satisfied by the sort are emitted afterwards as (None, [ForeignKeyConstraint ...]).

Tables are dependent on another based on the presence of ForeignKeyConstraint objects, explicit dependencies added by Table.add_is_dependent_on(), as well as dependencies stated here using the sort_tables_and_constraints.skip_fn and/or sort_tables_and_constraints.extra_dependencies parameters.

参数:
  • tables – a sequence of Table objects.

  • filter_fn – optional callable which will be passed a ForeignKeyConstraint object, and returns a value based on whether this constraint should definitely be included or excluded as an inline constraint, or neither. If it returns False, the constraint will definitely be included as a dependency that cannot be subject to ALTER; if True, it will only be included as an ALTER result at the end. Returning None means the constraint is included in the table-based result unless it is detected as part of a dependency cycle.

  • extra_dependencies – a sequence of 2-tuples of tables which will also be considered as dependent on each other.

参见

sort_tables()

class sqlalchemy.schema.BaseDDLElement

The root of DDL constructs, including those that are sub-elements within the “create table” and other processes.

在 2.0 版本加入.

class sqlalchemy.schema.ExecutableDDLElement

Base class for standalone executable DDL expression constructs.

This class is the base for the general purpose DDL class, as well as the various create/drop clause constructs such as CreateTable, DropTable, AddConstraint, etc.

在 2.0 版本发生变更: ExecutableDDLElement is renamed from DDLElement, which still exists for backwards compatibility.

ExecutableDDLElement integrates closely with SQLAlchemy events, introduced in 事件. An instance of one is itself an event receiving callable:

event.listen(
    users,
    "after_create",
    AddConstraint(constraint).execute_if(dialect="postgresql"),
)
method sqlalchemy.schema.ExecutableDDLElement.__call__(target, bind, **kw)

Execute the DDL as a ddl_listener.

method sqlalchemy.schema.ExecutableDDLElement.against(target: SchemaItem) Self

Return a copy of this ExecutableDDLElement which will include the given target.

This essentially applies the given item to the .target attribute of the returned ExecutableDDLElement object. This target is then usable by event handlers and compilation routines in order to provide services such as tokenization of a DDL string in terms of a particular Table.

When a ExecutableDDLElement object is established as an event handler for the DDLEvents.before_create() or DDLEvents.after_create() events, and the event then occurs for a given target such as a Constraint or Table, that target is established with a copy of the ExecutableDDLElement object using this method, which then proceeds to the ExecutableDDLElement.execute() method in order to invoke the actual DDL instruction.

参数:

target – a SchemaItem that will be the subject of a DDL operation.

返回:

a copy of this ExecutableDDLElement with the .target attribute assigned to the given SchemaItem.

参见

DDL - uses tokenization against the “target” when processing the DDL string.

method sqlalchemy.schema.ExecutableDDLElement.execute_if(dialect: str | None = None, callable_: DDLIfCallable | None = None, state: Any | None = None) Self

Return a callable that will execute this ExecutableDDLElement conditionally within an event handler.

Used to provide a wrapper for event listening:

event.listen(
    metadata,
    "before_create",
    DDL("my_ddl").execute_if(dialect="postgresql"),
)
参数:
  • dialect

    May be a string or tuple of strings. If a string, it will be compared to the name of the executing database dialect:

    DDL("something").execute_if(dialect="postgresql")

    If a tuple, specifies multiple dialect names:

    DDL("something").execute_if(dialect=("postgresql", "mysql"))

  • callable_

    A callable, which will be invoked with three positional arguments as well as optional keyword arguments:

    ddl:

    This DDL element.

    target:

    The Table or MetaData object which is the target of this event. May be None if the DDL is executed explicitly.

    bind:

    The Connection being used for DDL execution. May be None if this construct is being created inline within a table, in which case compiler will be present.

    tables:

    Optional keyword argument - a list of Table objects which are to be created/ dropped within a MetaData.create_all() or drop_all() method call.

    dialect:

    keyword argument, but always present - the Dialect involved in the operation.

    compiler:

    keyword argument. Will be None for an engine level DDL invocation, but will refer to a DDLCompiler if this DDL element is being created inline within a table.

    state:

    Optional keyword argument - will be the state argument passed to this function.

    checkfirst:

    Keyword argument, will be True if the ‘checkfirst’ flag was set during the call to create(), create_all(), drop(), drop_all().

    If the callable returns a True value, the DDL statement will be executed.

  • state – any value which will be passed to the callable_ as the state keyword argument.

参见

SchemaItem.ddl_if()

DDLEvents

事件

class sqlalchemy.schema.DDL

A literal DDL statement.

Specifies literal SQL DDL to be executed by the database. DDL objects function as DDL event listeners, and can be subscribed to those events listed in DDLEvents, using either Table or MetaData objects as targets. Basic templating support allows a single DDL instance to handle repetitive tasks for multiple tables.

Examples:

from sqlalchemy import event, DDL

tbl = Table("users", metadata, Column("uid", Integer))
event.listen(tbl, "before_create", DDL("DROP TRIGGER users_trigger"))

spow = DDL("ALTER TABLE %(table)s SET secretpowers TRUE")
event.listen(tbl, "after_create", spow.execute_if(dialect="somedb"))

drop_spow = DDL("ALTER TABLE users SET secretpowers FALSE")
connection.execute(drop_spow)

When operating on Table events, the following statement string substitutions are available:

%(table)s  - the Table name, with any required quoting applied
%(schema)s - the schema name, with any required quoting applied
%(fullname)s - the Table name including schema, quoted if needed

The DDL’s “context”, if any, will be combined with the standard substitutions noted above. Keys present in the context will override the standard substitutions.

Members

__init__()

method sqlalchemy.schema.DDL.__init__(statement, context=None)

Create a DDL statement.

参数:
  • statement

    A string or unicode string to be executed. Statements will be processed with Python’s string formatting operator using a fixed set of string substitutions, as well as additional substitutions provided by the optional DDL.context parameter.

    A literal ‘%’ in a statement must be escaped as ‘%%’.

    SQL bind parameters are not available in DDL statements.

  • context – Optional dictionary, defaults to None. These values will be available for use in string substitutions on the DDL statement.

参见

DDLEvents

事件

class sqlalchemy.schema._CreateDropBase

Base class for DDL constructs that represent CREATE and DROP or equivalents.

The common theme of _CreateDropBase is a single element attribute which refers to the element to be created or dropped.

Class signature

class sqlalchemy.schema._CreateDropBase (sqlalchemy.schema.ExecutableDDLElement, typing.Generic)

class sqlalchemy.schema.CreateTable

Represent a CREATE TABLE statement.

Members

__init__()

Class signature

class sqlalchemy.schema.CreateTable (sqlalchemy.schema._CreateBase)

method sqlalchemy.schema.CreateTable.__init__(element: Table, include_foreign_key_constraints: typing_Sequence[ForeignKeyConstraint] | None = None, if_not_exists: bool = False) None

Create a CreateTable construct.

参数:
  • element – a Table that’s the subject of the CREATE

  • on – See the description for ‘on’ in DDL.

  • include_foreign_key_constraints – optional sequence of ForeignKeyConstraint objects that will be included inline within the CREATE construct; if omitted, all foreign key constraints that do not specify use_alter=True are included.

  • if_not_exists

    if True, an IF NOT EXISTS operator will be applied to the construct.

    在 1.4.0b2 版本加入.

class sqlalchemy.schema.DropTable

Represent a DROP TABLE statement.

Members

__init__()

Class signature

class sqlalchemy.schema.DropTable (sqlalchemy.schema._DropBase)

method sqlalchemy.schema.DropTable.__init__(element: Table, if_exists: bool = False) None

Create a DropTable construct.

参数:
  • element – a Table that’s the subject of the DROP.

  • on – See the description for ‘on’ in DDL.

  • if_exists

    if True, an IF EXISTS operator will be applied to the construct.

    在 1.4.0b2 版本加入.

class sqlalchemy.schema.CreateColumn

Represent a Column as rendered in a CREATE TABLE statement, via the CreateTable construct.

This is provided to support custom column DDL within the generation of CREATE TABLE statements, by using the compiler extension documented in 自定义 SQL 构造和编译扩展 to extend CreateColumn.

Typical integration is to examine the incoming Column object, and to redirect compilation if a particular flag or condition is found:

from sqlalchemy import schema
from sqlalchemy.ext.compiler import compiles


@compiles(schema.CreateColumn)
def compile(element, compiler, **kw):
    column = element.element

    if "special" not in column.info:
        return compiler.visit_create_column(element, **kw)

    text = "%s SPECIAL DIRECTIVE %s" % (
        column.name,
        compiler.type_compiler.process(column.type),
    )
    default = compiler.get_column_default_string(column)
    if default is not None:
        text += " DEFAULT " + default

    if not column.nullable:
        text += " NOT NULL"

    if column.constraints:
        text += " ".join(
            compiler.process(const) for const in column.constraints
        )
    return text

The above construct can be applied to a Table as follows:

from sqlalchemy import Table, Metadata, Column, Integer, String
from sqlalchemy import schema

metadata = MetaData()

table = Table(
    "mytable",
    MetaData(),
    Column("x", Integer, info={"special": True}, primary_key=True),
    Column("y", String(50)),
    Column("z", String(20), info={"special": True}),
)

metadata.create_all(conn)

Above, the directives we’ve added to the Column.info collection will be detected by our custom compilation scheme:

CREATE TABLE mytable (
        x SPECIAL DIRECTIVE INTEGER NOT NULL,
        y VARCHAR(50),
        z SPECIAL DIRECTIVE VARCHAR(20),
    PRIMARY KEY (x)
)

The CreateColumn construct can also be used to skip certain columns when producing a CREATE TABLE. This is accomplished by creating a compilation rule that conditionally returns None. This is essentially how to produce the same effect as using the system=True argument on Column, which marks a column as an implicitly-present “system” column.

For example, suppose we wish to produce a Table which skips rendering of the PostgreSQL xmin column against the PostgreSQL backend, but on other backends does render it, in anticipation of a triggered rule. A conditional compilation rule could skip this name only on PostgreSQL:

from sqlalchemy.schema import CreateColumn


@compiles(CreateColumn, "postgresql")
def skip_xmin(element, compiler, **kw):
    if element.element.name == "xmin":
        return None
    else:
        return compiler.visit_create_column(element, **kw)


my_table = Table(
    "mytable",
    metadata,
    Column("id", Integer, primary_key=True),
    Column("xmin", Integer),
)

Above, a CreateTable construct will generate a CREATE TABLE which only includes the id column in the string; the xmin column will be omitted, but only against the PostgreSQL backend.

class sqlalchemy.schema.CreateSequence

Represent a CREATE SEQUENCE statement.

Class signature

class sqlalchemy.schema.CreateSequence (sqlalchemy.schema._CreateBase)

class sqlalchemy.schema.DropSequence

Represent a DROP SEQUENCE statement.

Class signature

class sqlalchemy.schema.DropSequence (sqlalchemy.schema._DropBase)

class sqlalchemy.schema.CreateIndex

Represent a CREATE INDEX statement.

Members

__init__()

Class signature

class sqlalchemy.schema.CreateIndex (sqlalchemy.schema._CreateBase)

method sqlalchemy.schema.CreateIndex.__init__(element: Index, if_not_exists: bool = False) None

Create a Createindex construct.

参数:
  • element – a Index that’s the subject of the CREATE.

  • if_not_exists

    if True, an IF NOT EXISTS operator will be applied to the construct.

    在 1.4.0b2 版本加入.

class sqlalchemy.schema.DropIndex

Represent a DROP INDEX statement.

Members

__init__()

Class signature

class sqlalchemy.schema.DropIndex (sqlalchemy.schema._DropBase)

method sqlalchemy.schema.DropIndex.__init__(element: Index, if_exists: bool = False) None

Create a DropIndex construct.

参数:
  • element – a Index that’s the subject of the DROP.

  • if_exists

    if True, an IF EXISTS operator will be applied to the construct.

    在 1.4.0b2 版本加入.

class sqlalchemy.schema.AddConstraint

Represent an ALTER TABLE ADD CONSTRAINT statement.

Members

__init__()

Class signature

class sqlalchemy.schema.AddConstraint (sqlalchemy.schema._CreateBase)

method sqlalchemy.schema.AddConstraint.__init__(element: Constraint, *, isolate_from_table: bool = True) None

Construct a new AddConstraint construct.

参数:
  • element – a Constraint object

  • isolate_from_table

    optional boolean, defaults to True. Has the effect of the incoming constraint being isolated from being included in a CREATE TABLE sequence when associated with a Table.

    在 2.0.39 版本加入: - added AddConstraint.isolate_from_table, defaulting to True. Previously, the behavior of this parameter was implicitly turned on in all cases.

class sqlalchemy.schema.DropConstraint

Represent an ALTER TABLE DROP CONSTRAINT statement.

Members

__init__()

Class signature

class sqlalchemy.schema.DropConstraint (sqlalchemy.schema._DropBase)

method sqlalchemy.schema.DropConstraint.__init__(element: Constraint, *, cascade: bool = False, if_exists: bool = False, isolate_from_table: bool = True, **kw: Any) None

Construct a new DropConstraint construct.

参数:
  • element – a Constraint object

  • cascade – optional boolean, indicates backend-specific “CASCADE CONSTRAINT” directive should be rendered if available

  • if_exists – optional boolean, indicates backend-specific “IF EXISTS” directive should be rendered if available

  • isolate_from_table

    optional boolean, defaults to True. Has the effect of the incoming constraint being isolated from being included in a CREATE TABLE sequence when associated with a Table.

    在 2.0.39 版本加入: - added DropConstraint.isolate_from_table, defaulting to True. Previously, the behavior of this parameter was implicitly turned on in all cases.

class sqlalchemy.schema.CreateSchema

Represent a CREATE SCHEMA statement.

The argument here is the string name of the schema.

Members

__init__()

Class signature

class sqlalchemy.schema.CreateSchema (sqlalchemy.schema._CreateBase)

method sqlalchemy.schema.CreateSchema.__init__(name: str, if_not_exists: bool = False) None

Create a new CreateSchema construct.

class sqlalchemy.schema.DropSchema

Represent a DROP SCHEMA statement.

The argument here is the string name of the schema.

Members

__init__()

Class signature

class sqlalchemy.schema.DropSchema (sqlalchemy.schema._DropBase)

method sqlalchemy.schema.DropSchema.__init__(name: str, cascade: bool = False, if_exists: bool = False) None

Create a new DropSchema construct.