]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
Support column list for foreign key ON DELETE SET actions on PostgreSQL
authorDenis Laxalde <denis@laxalde.org>
Thu, 13 Mar 2025 12:43:53 +0000 (08:43 -0400)
committerMike Bayer <mike_mp@zzzcomputing.com>
Mon, 17 Mar 2025 18:02:24 +0000 (14:02 -0400)
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

doc/build/changelog/unreleased_20/11595.rst [new file with mode: 0644]
doc/build/core/constraints.rst
lib/sqlalchemy/dialects/postgresql/base.py
lib/sqlalchemy/sql/compiler.py
lib/sqlalchemy/sql/schema.py
test/dialect/postgresql/test_compiler.py
test/dialect/postgresql/test_reflection.py
test/sql/test_compiler.py

diff --git a/doc/build/changelog/unreleased_20/11595.rst b/doc/build/changelog/unreleased_20/11595.rst
new file mode 100644 (file)
index 0000000..faefd24
--- /dev/null
@@ -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`
index 7927b1fbe6911bc21d0e1ce1374fce7188725c51..83b7e6eb9d698ee48ee3d491de8a57eb1ded2a24 100644 (file)
@@ -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
index ef7e67841ac0a3cec577599e09622b5a4e0cf2f8..6852080303ab75446693948063bbd703ff83d8ff 100644 (file)
@@ -1258,6 +1258,29 @@ with selected constraint constructs:
       <https://www.postgresql.org/docs/current/static/sql-altertable.html>`_ -
       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
@@ -1667,6 +1690,7 @@ RESERVED_WORDS = {
     "verbose",
 }
 
+
 colspecs = {
     sqltypes.ARRAY: _array.ARRAY,
     sqltypes.Interval: INTERVAL,
@@ -2245,6 +2269,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
 
@@ -4246,7 +4283,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)+)?"
         )
index 1fafafa7de911d5247ac269e4c29c35186b1fabe..20073a3afaa0a75390fe0f5881ec8be45cf83ef1 100644 (file)
@@ -7133,15 +7133,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:
index c9680becbc683130d56bc91c4f636e1b9905e776..8edc75b9512ff1ac579d167bdb21fc550e8eb43f 100644 (file)
@@ -2831,9 +2831,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 <value> 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.
@@ -4679,12 +4688,21 @@ class ForeignKeyConstraint(ColumnCollectionConstraint):
         :param name: Optional, the in-database name of the key.
 
         :param onupdate: Optional string. If set, emit ON UPDATE <value> 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 <value> 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.
index 8e241b82e5879e61430bf666fd04e6ce376ef62e..ac49f6f4b5105f481d3b32d497b9d0d224fff9f0 100644 (file)
@@ -1142,6 +1142,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))
index 4d889c6775fd7329b57b78d54c2b03b36fd1895c..20844a0eaea76629921253c7dc1b8e9058bf652c 100644 (file)
@@ -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(
index 9e5d11bbfdff8f3b796ed3720f548ac02990eec7..9d74a8d2f4c609d363ec95911715f8d1ef3492e6 100644 (file)
@@ -12,6 +12,7 @@ from __future__ import annotations
 
 import datetime
 import decimal
+import re
 from typing import TYPE_CHECKING
 
 from sqlalchemy import alias
@@ -6669,6 +6670,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(
@@ -6677,7 +6681,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,
                 )