diff options
author | Peter Eisentraut <peter@eisentraut.org> | 2021-12-08 11:09:44 +0100 |
---|---|---|
committer | Peter Eisentraut <peter@eisentraut.org> | 2021-12-08 11:13:57 +0100 |
commit | d6f96ed94e73052f99a2e545ed17a8b2fdc1fb8a (patch) | |
tree | 621d033b72ab7da8a21acb729b41c015b6322747 /doc/src/sgml/ddl.sgml | |
parent | e464cb7af317e216fef9bfe19a7c4df542817012 (diff) | |
download | postgresql-d6f96ed94e73052f99a2e545ed17a8b2fdc1fb8a.tar.gz postgresql-d6f96ed94e73052f99a2e545ed17a8b2fdc1fb8a.zip |
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
Diffstat (limited to 'doc/src/sgml/ddl.sgml')
-rw-r--r-- | doc/src/sgml/ddl.sgml | 33 |
1 files changed, 32 insertions, 1 deletions
diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 642ea2a70d0..64d90306522 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1084,9 +1084,40 @@ CREATE TABLE order_items ( </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> |