From: Denis Laxalde Date: Thu, 13 Mar 2025 12:43:53 +0000 (-0400) Subject: Support column list for foreign key ON DELETE SET actions on PostgreSQL X-Git-Tag: rel_2_0_40~15^2 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=f6296c19f557111c5b34a8403d97a76b701280b3;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Support column list for foreign key ON DELETE SET actions on PostgreSQL Added support for specifying a list of columns for ``SET NULL`` and ``SET DEFAULT`` actions of ``ON DELETE`` clause of foreign key definition on PostgreSQL. Pull request courtesy Denis Laxalde. Fixes: #11595 Closes: #12421 Pull-request: https://github.com/sqlalchemy/sqlalchemy/pull/12421 Pull-request-sha: d0394db7066ba8a8eaf3d3972d779f3e170e9406 Change-Id: I036a559ae4a8efafe9ba64d776a840bd785a7397 (cherry picked from commit 39bb17442ce6ac9a3dde5e2b72376b77ffce5e28) --- diff --git a/doc/build/changelog/unreleased_20/11595.rst b/doc/build/changelog/unreleased_20/11595.rst new file mode 100644 index 0000000000..faefd245c0 --- /dev/null +++ b/doc/build/changelog/unreleased_20/11595.rst @@ -0,0 +1,11 @@ +.. change:: + :tags: usecase, postgresql + :tickets: 11595 + + Added support for specifying a list of columns for ``SET NULL`` and ``SET + DEFAULT`` actions of ``ON DELETE`` clause of foreign key definition on + PostgreSQL. Pull request courtesy Denis Laxalde. + + .. seealso:: + + :ref:`postgresql_constraint_options` diff --git a/doc/build/core/constraints.rst b/doc/build/core/constraints.rst index c63ad858e2..9251bbf830 100644 --- a/doc/build/core/constraints.rst +++ b/doc/build/core/constraints.rst @@ -308,8 +308,12 @@ arguments. The value is any string which will be output after the appropriate ), ) -Note that these clauses require ``InnoDB`` tables when used with MySQL. -They may also not be supported on other databases. +Note that some backends have special requirements for cascades to function: + +* MySQL / MariaDB - the ``InnoDB`` storage engine should be used (this is + typically the default in modern databases) +* SQLite - constraints are not enabled by default. + See :ref:`sqlite_foreign_keys` .. seealso:: @@ -320,6 +324,12 @@ They may also not be supported on other databases. :ref:`passive_deletes_many_to_many` + :ref:`postgresql_constraint_options` - indicates additional options + available for foreign key cascades such as column lists + + :ref:`sqlite_foreign_keys` - background on enabling foreign key support + with SQLite + .. _schema_unique_constraint: UNIQUE Constraint diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index c8f15d1447..45c83d7209 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -1264,6 +1264,29 @@ with selected constraint constructs: `_ - in the PostgreSQL documentation. +* 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:: + + 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: Table values, Table and Column valued functions, Row and Tuple objects @@ -1673,6 +1696,7 @@ RESERVED_WORDS = { "verbose", } + colspecs = { sqltypes.ARRAY: _array.ARRAY, sqltypes.Interval: INTERVAL, @@ -2257,6 +2281,19 @@ class PGDDLCompiler(compiler.DDLCompiler): text += self._define_constraint_validity(constraint) return text + @util.memoized_property + def _fk_ondelete_pattern(self): + return re.compile( + r"^(?:RESTRICT|CASCADE|SET (?:NULL|DEFAULT)(?:\s*\(.+\))?" + r"|NO ACTION)$", + re.I, + ) + + def define_constraint_ondelete_cascade(self, constraint): + return " ON DELETE %s" % self.preparer.validate_sql_phrase( + constraint.ondelete, self._fk_ondelete_pattern + ) + def visit_create_enum_type(self, create, **kw): type_ = create.element @@ -4258,7 +4295,8 @@ class PGDialect(default.DefaultDialect): r"[\s]?(ON UPDATE " r"(CASCADE|RESTRICT|NO ACTION|SET NULL|SET DEFAULT)+)?" r"[\s]?(ON DELETE " - r"(CASCADE|RESTRICT|NO ACTION|SET NULL|SET DEFAULT)+)?" + r"(CASCADE|RESTRICT|NO ACTION|" + r"SET (?:NULL|DEFAULT)(?:\s\(.+\))?)+)?" r"[\s]?(DEFERRABLE|NOT DEFERRABLE)?" r"[\s]?(INITIALLY (DEFERRED|IMMEDIATE)+)?" ) diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index 146dde7a1b..f55f0d96bb 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -7112,15 +7112,26 @@ class DDLCompiler(Compiled): ) -> str: text = "" if constraint.ondelete is not None: - text += " ON DELETE %s" % self.preparer.validate_sql_phrase( - constraint.ondelete, FK_ON_DELETE - ) + text += self.define_constraint_ondelete_cascade(constraint) + if constraint.onupdate is not None: - text += " ON UPDATE %s" % self.preparer.validate_sql_phrase( - constraint.onupdate, FK_ON_UPDATE - ) + text += self.define_constraint_onupdate_cascade(constraint) return text + def define_constraint_ondelete_cascade( + self, constraint: ForeignKeyConstraint + ) -> str: + return " ON DELETE %s" % self.preparer.validate_sql_phrase( + constraint.ondelete, FK_ON_DELETE + ) + + def define_constraint_onupdate_cascade( + self, constraint: ForeignKeyConstraint + ) -> str: + return " ON UPDATE %s" % self.preparer.validate_sql_phrase( + constraint.onupdate, FK_ON_UPDATE + ) + def define_constraint_deferrability(self, constraint: Constraint) -> str: text = "" if constraint.deferrable is not None: diff --git a/lib/sqlalchemy/sql/schema.py b/lib/sqlalchemy/sql/schema.py index a6c24ce618..d65b2de06a 100644 --- a/lib/sqlalchemy/sql/schema.py +++ b/lib/sqlalchemy/sql/schema.py @@ -2837,9 +2837,18 @@ class ForeignKey(DialectKWArgs, SchemaItem): issuing DDL for this constraint. Typical values include CASCADE, DELETE and RESTRICT. + .. seealso:: + + :ref:`on_update_on_delete` + :param ondelete: Optional string. If set, emit ON DELETE when issuing DDL for this constraint. Typical values include CASCADE, - SET NULL and RESTRICT. + SET NULL and RESTRICT. Some dialects may allow for additional + syntaxes. + + .. seealso:: + + :ref:`on_update_on_delete` :param deferrable: Optional bool. If set, emit DEFERRABLE or NOT DEFERRABLE when issuing DDL for this constraint. @@ -4623,12 +4632,21 @@ class ForeignKeyConstraint(ColumnCollectionConstraint): :param name: Optional, the in-database name of the key. :param onupdate: Optional string. If set, emit ON UPDATE when - issuing DDL for this constraint. Typical values include CASCADE, - DELETE and RESTRICT. + issuing DDL for this constraint. Typical values include CASCADE, + DELETE and RESTRICT. + + .. seealso:: + + :ref:`on_update_on_delete` :param ondelete: Optional string. If set, emit ON DELETE when - issuing DDL for this constraint. Typical values include CASCADE, - SET NULL and RESTRICT. + issuing DDL for this constraint. Typical values include CASCADE, + SET NULL and RESTRICT. Some dialects may allow for additional + syntaxes. + + .. seealso:: + + :ref:`on_update_on_delete` :param deferrable: Optional bool. If set, emit DEFERRABLE or NOT DEFERRABLE when issuing DDL for this constraint. diff --git a/test/dialect/postgresql/test_compiler.py b/test/dialect/postgresql/test_compiler.py index 55a43d20d1..34ab31395f 100644 --- a/test/dialect/postgresql/test_compiler.py +++ b/test/dialect/postgresql/test_compiler.py @@ -1140,6 +1140,48 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): ")", ) + def test_create_foreign_key_constraint_ondelete_column_list(self): + m = MetaData() + pktable = Table( + "pktable", + m, + Column("tid", Integer, primary_key=True), + Column("id", Integer, primary_key=True), + ) + fktable = Table( + "fktable", + m, + Column("tid", Integer), + Column("id", Integer), + Column("fk_id_del_set_null", Integer), + Column("fk_id_del_set_default", Integer, server_default=text("0")), + ForeignKeyConstraint( + columns=["tid", "fk_id_del_set_null"], + refcolumns=[pktable.c.tid, pktable.c.id], + ondelete="SET NULL (fk_id_del_set_null)", + ), + ForeignKeyConstraint( + columns=["tid", "fk_id_del_set_default"], + refcolumns=[pktable.c.tid, pktable.c.id], + ondelete="SET DEFAULT(fk_id_del_set_default)", + ), + ) + + self.assert_compile( + schema.CreateTable(fktable), + "CREATE TABLE fktable (" + "tid INTEGER, id INTEGER, " + "fk_id_del_set_null INTEGER, " + "fk_id_del_set_default INTEGER DEFAULT 0, " + "FOREIGN KEY(tid, fk_id_del_set_null)" + " REFERENCES pktable (tid, id)" + " ON DELETE SET NULL (fk_id_del_set_null), " + "FOREIGN KEY(tid, fk_id_del_set_default)" + " REFERENCES pktable (tid, id)" + " ON DELETE SET DEFAULT(fk_id_del_set_default)" + ")", + ) + def test_exclude_constraint_min(self): m = MetaData() tbl = Table("testtbl", m, Column("room", Integer, primary_key=True)) diff --git a/test/dialect/postgresql/test_reflection.py b/test/dialect/postgresql/test_reflection.py index 4d889c6775..20844a0eae 100644 --- a/test/dialect/postgresql/test_reflection.py +++ b/test/dialect/postgresql/test_reflection.py @@ -7,6 +7,7 @@ from sqlalchemy import BigInteger from sqlalchemy import Column from sqlalchemy import exc from sqlalchemy import ForeignKey +from sqlalchemy import ForeignKeyConstraint from sqlalchemy import Identity from sqlalchemy import Index from sqlalchemy import inspect @@ -20,6 +21,7 @@ from sqlalchemy import String from sqlalchemy import Table from sqlalchemy import testing from sqlalchemy import Text +from sqlalchemy import text from sqlalchemy import UniqueConstraint from sqlalchemy.dialects.postgresql import ARRAY from sqlalchemy.dialects.postgresql import base as postgresql @@ -908,6 +910,53 @@ class ReflectionTest( subject = Table("subject", meta2, autoload_with=connection) eq_(subject.primary_key.columns.keys(), ["p2", "p1"]) + def test_reflected_foreign_key_ondelete_column_list( + self, metadata, connection + ): + meta1 = metadata + pktable = Table( + "pktable", + meta1, + Column("tid", Integer, primary_key=True), + Column("id", Integer, primary_key=True), + ) + Table( + "fktable", + meta1, + Column("tid", Integer), + Column("id", Integer), + Column("fk_id_del_set_null", Integer), + Column("fk_id_del_set_default", Integer, server_default=text("0")), + ForeignKeyConstraint( + name="fktable_tid_fk_id_del_set_null_fkey", + columns=["tid", "fk_id_del_set_null"], + refcolumns=[pktable.c.tid, pktable.c.id], + ondelete="SET NULL (fk_id_del_set_null)", + ), + ForeignKeyConstraint( + name="fktable_tid_fk_id_del_set_default_fkey", + columns=["tid", "fk_id_del_set_default"], + refcolumns=[pktable.c.tid, pktable.c.id], + ondelete="SET DEFAULT(fk_id_del_set_default)", + ), + ) + + meta1.create_all(connection) + meta2 = MetaData() + fktable = Table("fktable", meta2, autoload_with=connection) + fkey_set_null = next( + c + for c in fktable.foreign_key_constraints + if c.name == "fktable_tid_fk_id_del_set_null_fkey" + ) + eq_(fkey_set_null.ondelete, "SET NULL (fk_id_del_set_null)") + fkey_set_default = next( + c + for c in fktable.foreign_key_constraints + if c.name == "fktable_tid_fk_id_del_set_default_fkey" + ) + eq_(fkey_set_default.ondelete, "SET DEFAULT (fk_id_del_set_default)") + def test_pg_weirdchar_reflection(self, metadata, connection): meta1 = metadata subject = Table( diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index 3e8fca59a8..4d546b57b3 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -12,6 +12,7 @@ from __future__ import annotations import datetime import decimal +import re from typing import TYPE_CHECKING from sqlalchemy import alias @@ -6674,6 +6675,9 @@ class DDLTest(fixtures.TestBase, AssertsCompiledSQL): "FOO RESTRICT", "CASCADE WRONG", "SET NULL", + # test that PostgreSQL's syntax added in #11595 is not + # accepted by base compiler + "SET NULL(postgresql_db.some_column)", ): const = schema.AddConstraint( schema.ForeignKeyConstraint( @@ -6682,7 +6686,7 @@ class DDLTest(fixtures.TestBase, AssertsCompiledSQL): ) assert_raises_message( exc.CompileError, - r"Unexpected SQL phrase: '%s'" % phrase, + rf"Unexpected SQL phrase: '{re.escape(phrase)}'", const.compile, )