1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-13 07:41:39 +03:00

Allow specifying column list for foreign key ON DELETE SET actions

Extend the foreign key ON DELETE actions SET NULL and SET DEFAULT by
allowing the specification of a column list, like

    CREATE TABLE posts (
        ...
        FOREIGN KEY (tenant_id, author_id) REFERENCES users ON DELETE SET NULL (author_id)
    );

If a column list is specified, only those columns are set to
null/default, instead of all the columns in the foreign-key
constraint.

This is useful for multitenant or sharded schemas, where the tenant or
shard ID is included in the primary key of all tables but shouldn't be
set to null.

Author: Paul Martinez <paulmtz@google.com>
Discussion: https://www.postgresql.org/message-id/flat/CACqFVBZQyMYJV=njbSMxf+rbDHpx=W=B7AEaMKn8dWn9OZJY7w@mail.gmail.com
This commit is contained in:
Peter Eisentraut
2021-12-08 11:09:44 +01:00
parent e464cb7af3
commit d6f96ed94e
22 changed files with 557 additions and 72 deletions

View File

@ -2708,6 +2708,18 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
</para></entry>
</row>
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>confdelsetcols</structfield> <type>int2[]</type>
(references <link linkend="catalog-pg-attribute"><structname>pg_attribute</structname></link>.<structfield>attnum</structfield>)
</para>
<para>
If a foreign key with a <literal>SET NULL</literal> or <literal>SET
DEFAULT</literal> delete action, the columns that will be updated.
If null, all of the referencing columns will be updated.
</para></entry>
</row>
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>conexclop</structfield> <type>oid[]</type>

View File

@ -1083,10 +1083,41 @@ CREATE TABLE order_items (
manager to null or a default might be useful.
</para>
<para>
The actions <literal>SET NULL</literal> and <literal>SET DEFAULT</literal>
can take a column list to specify which columns to set. Normally, all
columns of the foreign-key constraint are set; setting only a subset is
useful in some special cases. Consider the following example:
<programlisting>
CREATE TABLE tenants (
tenant_id integer PRIMARY KEY
);
CREATE TABLE users (
tenant_id integer REFERENCES tenants ON DELETE CASCADE,
user_id integer NOT NULL,
PRIMARY KEY (tenant_id, user_id)
);
CREATE TABLE posts (
tenant_id integer REFERENCES tenants ON DELETE CASCADE,
post_id integer NOT NULL,
author_id integer,
PRIMARY KEY (tenant_id, post_id),
FOREIGN KEY (tenant_id, author_id) REFERENCES users ON DELETE SET NULL <emphasis>(author_id)</emphasis>
);
</programlisting>
Without the specification of the column, the foreign key would also set
the column <literal>tenant_id</literal> to null, but that column is still
required as part of the primary key.
</para>
<para>
Analogous to <literal>ON DELETE</literal> there is also
<literal>ON UPDATE</literal> which is invoked when a referenced
column is changed (updated). The possible actions are the same.
column is changed (updated). The possible actions are the same,
except that column lists cannot be specified for <literal>SET
NULL</literal> and <literal>SET DEFAULT</literal>.
In this case, <literal>CASCADE</literal> means that the updated values of the
referenced column(s) should be copied into the referencing row(s).
</para>

View File

@ -138,7 +138,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<phrase><replaceable class="parameter">referential_action</replaceable> in a <literal>FOREIGN KEY</literal>/<literal>REFERENCES</literal> constraint is:</phrase>
{ NO ACTION | RESTRICT | CASCADE | SET NULL | SET DEFAULT }
{ NO ACTION | RESTRICT | CASCADE | SET NULL [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] | SET DEFAULT [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] }
</synopsis>
</refsynopsisdiv>

View File

@ -108,7 +108,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<phrase><replaceable class="parameter">referential_action</replaceable> in a <literal>FOREIGN KEY</literal>/<literal>REFERENCES</literal> constraint is:</phrase>
{ NO ACTION | RESTRICT | CASCADE | SET NULL | SET DEFAULT }
{ NO ACTION | RESTRICT | CASCADE | SET NULL [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] | SET DEFAULT [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] }
</synopsis>
</refsynopsisdiv>
@ -1169,19 +1169,23 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</varlistentry>
<varlistentry>
<term><literal>SET NULL</literal></term>
<term><literal>SET NULL [ ( <replaceable>column_name</replaceable> [, ... ] ) ]</literal></term>
<listitem>
<para>
Set the referencing column(s) to null.
Set all of the referencing columns, or a specified subset of the
referencing columns, to null. A subset of columns can only be
specified for <literal>ON DELETE</literal> actions.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET DEFAULT</literal></term>
<term><literal>SET DEFAULT [ ( <replaceable>column_name</replaceable> [, ... ] ) ]</literal></term>
<listitem>
<para>
Set the referencing column(s) to their default values.
Set all of the referencing columns, or a specified subset of the
referencing columns, to their default values. A subset of columns
can only be specified for <literal>ON DELETE</literal> actions.
(There must be a row in the referenced table matching the default
values, if they are not null, or the operation will fail.)
</para>
@ -2223,6 +2227,16 @@ CREATE TABLE cities_partdef
</para>
</refsect2>
<refsect2>
<title>Foreign-Key Constraint Actions</title>
<para>
The ability to specify column lists in the foreign-key actions
<literal>SET DEFAULT</literal> and <literal>SET NULL</literal> is a
<productname>PostgreSQL</productname> extension.
</para>
</refsect2>
<refsect2>
<title><literal>NULL</literal> <quote>Constraint</quote></title>