From: Mike Bayer Date: Tue, 14 Oct 2025 15:52:19 +0000 (-0400) Subject: create real sections for PG table and constraint options X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=52bbb8130be3dd8f194e6fba4755ce5a1f7b9ad9;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git create real sections for PG table and constraint options add new docs, clarify INDEX/UNIQUE for covering indexes which was not clear at all previously Change-Id: Ibc11b63b87cd8a939e074973b387e1a23fc236e5 --- diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index 747dea6f3b..a11331a3df 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -983,8 +983,13 @@ to the PostgreSQL dialect. Covering Indexes ^^^^^^^^^^^^^^^^ -The ``postgresql_include`` option renders INCLUDE(colname) for the given -string names:: +A covering index includes additional columns that are not part of the index key +but are stored in the index, allowing PostgreSQL to satisfy queries using only +the index without accessing the table (an "index-only scan"). This is +indicated on the index using the ``INCLUDE`` clause. The +``postgresql_include`` option for :class:`.Index` (as well as +:class:`.UniqueConstraint`) renders ``INCLUDE(colname)`` for the given string +names:: Index("my_index", table.c.x, postgresql_include=["y"]) @@ -994,9 +999,11 @@ Note that this feature requires PostgreSQL 11 or later. .. seealso:: - :ref:`postgresql_constraint_options` + :ref:`postgresql_constraint_options_include` - the same feature implemented + for :class:`.UniqueConstraint` -.. versionadded:: 1.4 +.. versionadded:: 1.4 - support for covering indexes with :class:`.Index`. + support for :class:`.UniqueConstraint` was in 2.0.41 .. _postgresql_partial_indexes: @@ -1166,20 +1173,44 @@ PostgreSQL Table Options ------------------------ Several options for CREATE TABLE are supported directly by the PostgreSQL -dialect in conjunction with the :class:`_schema.Table` construct: +dialect in conjunction with the :class:`_schema.Table` construct, listed in +the following sections. -* ``INHERITS``:: +.. seealso:: + + `PostgreSQL CREATE TABLE options + `_ - + in the PostgreSQL documentation. + +``INHERITS`` +^^^^^^^^^^^^ + +Specifies one or more parent tables from which this table inherits columns and +constraints, enabling table inheritance hierarchies in PostgreSQL. + +:: Table("some_table", metadata, ..., postgresql_inherits="some_supertable") Table("some_table", metadata, ..., postgresql_inherits=("t1", "t2", ...)) -* ``ON COMMIT``:: +``ON COMMIT`` +^^^^^^^^^^^^^ + +Controls the behavior of temporary tables at transaction commit, with options +to preserve rows, delete rows, or drop the table. + +:: Table("some_table", metadata, ..., postgresql_on_commit="PRESERVE ROWS") -* - ``PARTITION BY``:: +``PARTITION BY`` +^^^^^^^^^^^^^^^^ + +Declares the table as a partitioned table using the specified partitioning +strategy (RANGE, LIST, or HASH) on the given column(s). + +:: Table( "some_table", @@ -1188,139 +1219,171 @@ dialect in conjunction with the :class:`_schema.Table` construct: postgresql_partition_by="LIST (part_column)", ) -* - ``TABLESPACE``:: +``TABLESPACE`` +^^^^^^^^^^^^^^ + +Specifies the tablespace where the table will be stored, allowing control over +the physical location of table data on disk. + +:: Table("some_table", metadata, ..., postgresql_tablespace="some_tablespace") - The above option is also available on the :class:`.Index` construct. +The above option is also available on the :class:`.Index` construct. + +``USING`` +^^^^^^^^^ + +Specifies the table access method to use for storing table data, such as +``heap`` (the default) or other custom access methods. -* - ``USING``:: +:: Table("some_table", metadata, ..., postgresql_using="heap") - .. versionadded:: 2.0.26 +.. versionadded:: 2.0.26 -* ``WITH OIDS``:: +``WITH OIDS`` +^^^^^^^^^^^^^ + +Enables the legacy OID (object identifier) system column for the table, which +assigns a unique identifier to each row. + +:: Table("some_table", metadata, ..., postgresql_with_oids=True) -* ``WITHOUT OIDS``:: +``WITHOUT OIDS`` +^^^^^^^^^^^^^^^^ - Table("some_table", metadata, ..., postgresql_with_oids=False) +Explicitly disables the OID system column for the table (the default behavior +in modern PostgreSQL versions). -.. seealso:: +:: - `PostgreSQL CREATE TABLE options - `_ - - in the PostgreSQL documentation. + Table("some_table", metadata, ..., postgresql_with_oids=False) .. _postgresql_constraint_options: PostgreSQL Constraint Options ----------------------------- -The following option(s) are supported by the PostgreSQL dialect in conjunction -with selected constraint constructs: - -* ``NOT VALID``: This option applies towards CHECK and FOREIGN KEY constraints - when the constraint is being added to an existing table via ALTER TABLE, - and has the effect that existing rows are not scanned during the ALTER - operation against the constraint being added. - - When using a SQL migration tool such as `Alembic `_ - that renders ALTER TABLE constructs, the ``postgresql_not_valid`` argument - may be specified as an additional keyword argument within the operation - that creates the constraint, as in the following Alembic example:: - - def update(): - op.create_foreign_key( - "fk_user_address", - "address", - "user", - ["user_id"], - ["id"], - postgresql_not_valid=True, - ) +The following sections indicate options which are supported by the PostgreSQL +dialect in conjunction with selected constraint constructs. - The keyword is ultimately accepted directly by the - :class:`_schema.CheckConstraint`, :class:`_schema.ForeignKeyConstraint` - and :class:`_schema.ForeignKey` constructs; when using a tool like - Alembic, dialect-specific keyword arguments are passed through to - these constructs from the migration operation directives:: - CheckConstraint("some_field IS NOT NULL", postgresql_not_valid=True) +``NOT VALID`` +^^^^^^^^^^^^^ - ForeignKeyConstraint( - ["some_id"], ["some_table.some_id"], postgresql_not_valid=True - ) +Allows a constraint to be added without validating existing rows, improving +performance when adding constraints to large tables. This option applies +towards CHECK and FOREIGN KEY constraints when the constraint is being added +to an existing table via ALTER TABLE, and has the effect that existing rows +are not scanned during the ALTER operation against the constraint being added. - .. versionadded:: 1.4.32 +When using a SQL migration tool such as `Alembic `_ +that renders ALTER TABLE constructs, the ``postgresql_not_valid`` argument +may be specified as an additional keyword argument within the operation +that creates the constraint, as in the following Alembic example:: - .. seealso:: + def update(): + op.create_foreign_key( + "fk_user_address", + "address", + "user", + ["user_id"], + ["id"], + postgresql_not_valid=True, + ) - `PostgreSQL ALTER TABLE options - `_ - - in the PostgreSQL documentation. +The keyword is ultimately accepted directly by the +:class:`_schema.CheckConstraint`, :class:`_schema.ForeignKeyConstraint` +and :class:`_schema.ForeignKey` constructs; when using a tool like +Alembic, dialect-specific keyword arguments are passed through to +these constructs from the migration operation directives:: -* ``INCLUDE``: This option adds one or more columns as a "payload" to the - unique index created automatically by PostgreSQL for the constraint. - For example, the following table definition:: + CheckConstraint("some_field IS NOT NULL", postgresql_not_valid=True) - Table( - "mytable", - metadata, - Column("id", Integer, nullable=False), - Column("value", Integer, nullable=False), - UniqueConstraint("id", postgresql_include=["value"]), - ) + ForeignKeyConstraint( + ["some_id"], ["some_table.some_id"], postgresql_not_valid=True + ) - would produce the DDL statement +.. versionadded:: 1.4.32 - .. sourcecode:: sql +.. seealso:: - CREATE TABLE mytable ( - id INTEGER NOT NULL, - value INTEGER NOT NULL, - UNIQUE (id) INCLUDE (value) - ) + `PostgreSQL ALTER TABLE options + `_ - + in the PostgreSQL documentation. + +.. _postgresql_constraint_options_include: + +``INCLUDE`` +^^^^^^^^^^^ + +This keyword is applicable to both a ``UNIQUE`` constraint as well as an +``INDEX``. The ``postgresql_include`` option available for +:class:`.UniqueConstraint` as well as :class:`.Index` creates a covering index +by including additional columns in the underlying index without making them +part of the key constraint. This option adds one or more columns as a "payload" +to the index created automatically by PostgreSQL for the constraint. For +example, the following table definition:: + + Table( + "mytable", + metadata, + Column("id", Integer, nullable=False), + Column("value", Integer, nullable=False), + UniqueConstraint("id", postgresql_include=["value"]), + ) - Note that this feature requires PostgreSQL 11 or later. +would produce the DDL statement - .. versionadded:: 2.0.41 +.. sourcecode:: sql - .. seealso:: + CREATE TABLE mytable ( + id INTEGER NOT NULL, + value INTEGER NOT NULL, + UNIQUE (id) INCLUDE (value) + ) - :ref:`postgresql_covering_indexes` +Note that this feature requires PostgreSQL 11 or later. - .. seealso:: +.. versionadded:: 2.0.41 - added support for ``postgresql_include`` to + :class:`.UniqueConstraint`, to complement the existing feature in + :class:`.Index`. - `PostgreSQL CREATE TABLE options - `_ - - in the PostgreSQL documentation. +.. seealso:: -* Column list with foreign key ``ON DELETE SET`` actions: This applies to - :class:`.ForeignKey` and :class:`.ForeignKeyConstraint`, the :paramref:`.ForeignKey.ondelete` - parameter will accept on the PostgreSQL backend only a string list of column - names inside parenthesis, following the ``SET NULL`` or ``SET DEFAULT`` - phrases, which will limit the set of columns that are subject to the - action:: + :ref:`postgresql_covering_indexes` - background on ``postgresql_include`` + for the :class:`.Index` construct. - fktable = Table( - "fktable", - metadata, - Column("tid", Integer), - Column("id", Integer), - Column("fk_id_del_set_null", Integer), - ForeignKeyConstraint( - columns=["tid", "fk_id_del_set_null"], - refcolumns=[pktable.c.tid, pktable.c.id], - ondelete="SET NULL (fk_id_del_set_null)", - ), - ) - .. versionadded:: 2.0.40 +Column list with foreign key ``ON DELETE SET`` actions +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +Allows selective column updates when a foreign key action is triggered, limiting +which columns are set to NULL or DEFAULT upon deletion of a referenced row. +This applies to :class:`.ForeignKey` and :class:`.ForeignKeyConstraint`, the +:paramref:`.ForeignKey.ondelete` parameter will accept on the PostgreSQL +backend only a string list of column names inside parenthesis, following the +``SET NULL`` or ``SET DEFAULT`` phrases, which will limit the set of columns +that are subject to the action:: + + fktable = Table( + "fktable", + metadata, + Column("tid", Integer), + Column("id", Integer), + Column("fk_id_del_set_null", Integer), + ForeignKeyConstraint( + columns=["tid", "fk_id_del_set_null"], + refcolumns=[pktable.c.tid, pktable.c.id], + ondelete="SET NULL (fk_id_del_set_null)", + ), + ) + +.. versionadded:: 2.0.40 .. _postgresql_table_valued_overview: