Commit c7d43c4d authored by Alvaro Herrera's avatar Alvaro Herrera

Correct attach/detach logic for FKs in partitions

There was no code to handle foreign key constraints on partitioned
tables in the case of ALTER TABLE DETACH; and if you happened to ATTACH
a partition that already had an equivalent constraint, that one was
ignored and a new constraint was created.  Adding this to the fact that
foreign key cloning reuses the constraint name on the partition instead
of generating a new name (as it probably should, to cater to SQL
standard rules about constraint naming within schemas), the result was a
pretty poor user experience -- the most visible failure was that just
detaching a partition and re-attaching it failed with an error such as

  ERROR:  duplicate key value violates unique constraint "pg_constraint_conrelid_contypid_conname_index"
  DETAIL:  Key (conrelid, contypid, conname)=(26702, 0, test_result_asset_id_fkey) already exists.

because it would try to create an identically-named constraint in the
partition.  To make matters worse, if you tried to drop the constraint
in the now-independent partition, that would fail because the constraint
was still seen as dependent on the constraint in its former parent
partitioned table:
  ERROR:  cannot drop inherited constraint "test_result_asset_id_fkey" of relation "test_result_cbsystem_0001_0050_monthly_2018_09"

This fix attacks the problem from two angles: first, when the partition
is detached, the constraint is also marked as independent, so the drop
now works.  Second, when the partition is re-attached, we scan existing
constraints searching for one matching the FK in the parent, and if one
exists, we link that one to the parent constraint.  So we don't end up
with a duplicate -- and better yet, we don't need to scan the referenced
table to verify that the constraint holds.

To implement this I made a small change to previously planner-only
struct ForeignKeyCacheInfo to contain the constraint OID; also relcache
now maintains the list of FKs for partitioned tables too.

Backpatch to 11.

Reported-by: Michael Vitale (bug #15425)
Discussion: https://postgr.es/m/15425-2dbc9d2aa999f816@postgresql.org
parent f1885386
This diff is collapsed.
...@@ -14091,6 +14091,11 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd) ...@@ -14091,6 +14091,11 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd)
attachrel = heap_openrv(cmd->name, AccessExclusiveLock); attachrel = heap_openrv(cmd->name, AccessExclusiveLock);
/*
* XXX I think it'd be a good idea to grab locks on all tables referenced
* by FKs at this point also.
*/
/* /*
* Must be owner of both parent and source table -- parent was checked by * Must be owner of both parent and source table -- parent was checked by
* ATSimplePermissions call in ATPrepCmd * ATSimplePermissions call in ATPrepCmd
...@@ -14663,6 +14668,7 @@ ATExecDetachPartition(Relation rel, RangeVar *name) ...@@ -14663,6 +14668,7 @@ ATExecDetachPartition(Relation rel, RangeVar *name)
ObjectAddress address; ObjectAddress address;
Oid defaultPartOid; Oid defaultPartOid;
List *indexes; List *indexes;
List *fks;
ListCell *cell; ListCell *cell;
/* /*
...@@ -14738,6 +14744,23 @@ ATExecDetachPartition(Relation rel, RangeVar *name) ...@@ -14738,6 +14744,23 @@ ATExecDetachPartition(Relation rel, RangeVar *name)
} }
heap_close(classRel, RowExclusiveLock); heap_close(classRel, RowExclusiveLock);
/* Detach foreign keys */
fks = copyObject(RelationGetFKeyList(partRel));
foreach(cell, fks)
{
ForeignKeyCacheInfo *fk = lfirst(cell);
HeapTuple contup;
contup = SearchSysCache1(CONSTROID, ObjectIdGetDatum(fk->conoid));
if (!contup)
elog(ERROR, "cache lookup failed for constraint %u", fk->conoid);
ConstraintSetParentConstraint(fk->conoid, InvalidOid);
ReleaseSysCache(contup);
}
list_free_deep(fks);
/* /*
* Invalidate the parent's relcache so that the partition is no longer * Invalidate the parent's relcache so that the partition is no longer
* included in its partition descriptor. * included in its partition descriptor.
......
...@@ -4745,6 +4745,7 @@ _copyForeignKeyCacheInfo(const ForeignKeyCacheInfo *from) ...@@ -4745,6 +4745,7 @@ _copyForeignKeyCacheInfo(const ForeignKeyCacheInfo *from)
{ {
ForeignKeyCacheInfo *newnode = makeNode(ForeignKeyCacheInfo); ForeignKeyCacheInfo *newnode = makeNode(ForeignKeyCacheInfo);
COPY_SCALAR_FIELD(conoid);
COPY_SCALAR_FIELD(conrelid); COPY_SCALAR_FIELD(conrelid);
COPY_SCALAR_FIELD(confrelid); COPY_SCALAR_FIELD(confrelid);
COPY_SCALAR_FIELD(nkeys); COPY_SCALAR_FIELD(nkeys);
......
...@@ -3633,6 +3633,7 @@ _outForeignKeyCacheInfo(StringInfo str, const ForeignKeyCacheInfo *node) ...@@ -3633,6 +3633,7 @@ _outForeignKeyCacheInfo(StringInfo str, const ForeignKeyCacheInfo *node)
WRITE_NODE_TYPE("FOREIGNKEYCACHEINFO"); WRITE_NODE_TYPE("FOREIGNKEYCACHEINFO");
WRITE_OID_FIELD(conoid);
WRITE_OID_FIELD(conrelid); WRITE_OID_FIELD(conrelid);
WRITE_OID_FIELD(confrelid); WRITE_OID_FIELD(confrelid);
WRITE_INT_FIELD(nkeys); WRITE_INT_FIELD(nkeys);
......
...@@ -4108,8 +4108,9 @@ RelationGetFKeyList(Relation relation) ...@@ -4108,8 +4108,9 @@ RelationGetFKeyList(Relation relation)
if (relation->rd_fkeyvalid) if (relation->rd_fkeyvalid)
return relation->rd_fkeylist; return relation->rd_fkeylist;
/* Fast path: if it doesn't have any triggers, it can't have FKs */ /* Fast path: non-partitioned tables without triggers can't have FKs */
if (!relation->rd_rel->relhastriggers) if (!relation->rd_rel->relhastriggers &&
relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
return NIL; return NIL;
/* /*
...@@ -4144,6 +4145,7 @@ RelationGetFKeyList(Relation relation) ...@@ -4144,6 +4145,7 @@ RelationGetFKeyList(Relation relation)
continue; continue;
info = makeNode(ForeignKeyCacheInfo); info = makeNode(ForeignKeyCacheInfo);
info->conoid = HeapTupleGetOid(htup);
info->conrelid = constraint->conrelid; info->conrelid = constraint->conrelid;
info->confrelid = constraint->confrelid; info->confrelid = constraint->confrelid;
......
...@@ -202,12 +202,13 @@ typedef struct RelationData ...@@ -202,12 +202,13 @@ typedef struct RelationData
* The per-FK-column arrays can be fixed-size because we allow at most * The per-FK-column arrays can be fixed-size because we allow at most
* INDEX_MAX_KEYS columns in a foreign key constraint. * INDEX_MAX_KEYS columns in a foreign key constraint.
* *
* Currently, we only cache fields of interest to the planner, but the * Currently, we mostly cache fields of interest to the planner, but the set
* set of fields could be expanded in future. * of fields has already grown the constraint OID for other uses.
*/ */
typedef struct ForeignKeyCacheInfo typedef struct ForeignKeyCacheInfo
{ {
NodeTag type; NodeTag type;
Oid conoid; /* oid of the constraint itself */
Oid conrelid; /* relation constrained by the foreign key */ Oid conrelid; /* relation constrained by the foreign key */
Oid confrelid; /* relation referenced by the foreign key */ Oid confrelid; /* relation referenced by the foreign key */
int nkeys; /* number of columns in the foreign key */ int nkeys; /* number of columns in the foreign key */
......
...@@ -1648,6 +1648,125 @@ SELECT * FROM fk_partitioned_fk WHERE a = 142857; ...@@ -1648,6 +1648,125 @@ SELECT * FROM fk_partitioned_fk WHERE a = 142857;
-- verify that DROP works -- verify that DROP works
DROP TABLE fk_partitioned_fk_2; DROP TABLE fk_partitioned_fk_2;
-- Test behavior of the constraint together with attaching and detaching
-- partitions.
CREATE TABLE fk_partitioned_fk_2 PARTITION OF fk_partitioned_fk FOR VALUES IN (1500,1502);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_2;
BEGIN;
DROP TABLE fk_partitioned_fk;
-- constraint should still be there
\d fk_partitioned_fk_2;
Table "public.fk_partitioned_fk_2"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | | 2501
b | integer | | | 142857
Foreign-key constraints:
"fk_partitioned_fk_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
ROLLBACK;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2 FOR VALUES IN (1500,1502);
DROP TABLE fk_partitioned_fk_2;
CREATE TABLE fk_partitioned_fk_2 (b int, c text, a int,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk ON UPDATE CASCADE ON DELETE CASCADE);
ALTER TABLE fk_partitioned_fk_2 DROP COLUMN c;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2 FOR VALUES IN (1500,1502);
-- should have only one constraint
\d fk_partitioned_fk_2
Table "public.fk_partitioned_fk_2"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
b | integer | | |
a | integer | | |
Partition of: fk_partitioned_fk FOR VALUES IN (1500, 1502)
Foreign-key constraints:
"fk_partitioned_fk_2_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
DROP TABLE fk_partitioned_fk_2;
CREATE TABLE fk_partitioned_fk_4 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE) PARTITION BY RANGE (b, a);
CREATE TABLE fk_partitioned_fk_4_1 PARTITION OF fk_partitioned_fk_4 FOR VALUES FROM (1,1) TO (100,100);
CREATE TABLE fk_partitioned_fk_4_2 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE SET NULL);
ALTER TABLE fk_partitioned_fk_4 ATTACH PARTITION fk_partitioned_fk_4_2 FOR VALUES FROM (100,100) TO (1000,1000);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_4 FOR VALUES IN (3500,3502);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_4;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_4 FOR VALUES IN (3500,3502);
-- should only have one constraint
\d fk_partitioned_fk_4
Table "public.fk_partitioned_fk_4"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
b | integer | | |
Partition of: fk_partitioned_fk FOR VALUES IN (3500, 3502)
Partition key: RANGE (b, a)
Foreign-key constraints:
"fk_partitioned_fk_4_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
Number of partitions: 2 (Use \d+ to list them.)
\d fk_partitioned_fk_4_1
Table "public.fk_partitioned_fk_4_1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
b | integer | | |
Partition of: fk_partitioned_fk_4 FOR VALUES FROM (1, 1) TO (100, 100)
Foreign-key constraints:
"fk_partitioned_fk_4_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
-- this one has an FK with mismatched properties
\d fk_partitioned_fk_4_2
Table "public.fk_partitioned_fk_4_2"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
b | integer | | |
Partition of: fk_partitioned_fk_4 FOR VALUES FROM (100, 100) TO (1000, 1000)
Foreign-key constraints:
"fk_partitioned_fk_4_2_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE SET NULL
"fk_partitioned_fk_4_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
CREATE TABLE fk_partitioned_fk_5 (a int, b int,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE)
PARTITION BY RANGE (a);
CREATE TABLE fk_partitioned_fk_5_1 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_5 FOR VALUES IN (4500);
ALTER TABLE fk_partitioned_fk_5 ATTACH PARTITION fk_partitioned_fk_5_1 FOR VALUES FROM (0) TO (10);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_5;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_5 FOR VALUES IN (4500);
-- this one has two constraints, similar but not quite the one in the parent,
-- so it gets a new one
\d fk_partitioned_fk_5
Table "public.fk_partitioned_fk_5"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
b | integer | | |
Partition of: fk_partitioned_fk FOR VALUES IN (4500)
Partition key: RANGE (a)
Foreign-key constraints:
"fk_partitioned_fk_5_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE
"fk_partitioned_fk_5_a_fkey1" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE
"fk_partitioned_fk_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
Number of partitions: 1 (Use \d+ to list them.)
-- verify that it works to reattaching a child with multiple candidate
-- constraints
ALTER TABLE fk_partitioned_fk_5 DETACH PARTITION fk_partitioned_fk_5_1;
ALTER TABLE fk_partitioned_fk_5 ATTACH PARTITION fk_partitioned_fk_5_1 FOR VALUES FROM (0) TO (10);
\d fk_partitioned_fk_5_1
Table "public.fk_partitioned_fk_5_1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
a | integer | | |
b | integer | | |
Partition of: fk_partitioned_fk_5 FOR VALUES FROM (0) TO (10)
Foreign-key constraints:
"fk_partitioned_fk_5_1_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b)
"fk_partitioned_fk_5_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE
"fk_partitioned_fk_5_a_fkey1" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE
"fk_partitioned_fk_a_fkey" FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE
-- verify that attaching a table checks that the existing data satisfies the -- verify that attaching a table checks that the existing data satisfies the
-- constraint -- constraint
CREATE TABLE fk_partitioned_fk_2 (a int, b int) PARTITION BY RANGE (b); CREATE TABLE fk_partitioned_fk_2 (a int, b int) PARTITION BY RANGE (b);
......
...@@ -1226,6 +1226,56 @@ SELECT * FROM fk_partitioned_fk WHERE a = 142857; ...@@ -1226,6 +1226,56 @@ SELECT * FROM fk_partitioned_fk WHERE a = 142857;
-- verify that DROP works -- verify that DROP works
DROP TABLE fk_partitioned_fk_2; DROP TABLE fk_partitioned_fk_2;
-- Test behavior of the constraint together with attaching and detaching
-- partitions.
CREATE TABLE fk_partitioned_fk_2 PARTITION OF fk_partitioned_fk FOR VALUES IN (1500,1502);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_2;
BEGIN;
DROP TABLE fk_partitioned_fk;
-- constraint should still be there
\d fk_partitioned_fk_2;
ROLLBACK;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2 FOR VALUES IN (1500,1502);
DROP TABLE fk_partitioned_fk_2;
CREATE TABLE fk_partitioned_fk_2 (b int, c text, a int,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk ON UPDATE CASCADE ON DELETE CASCADE);
ALTER TABLE fk_partitioned_fk_2 DROP COLUMN c;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_2 FOR VALUES IN (1500,1502);
-- should have only one constraint
\d fk_partitioned_fk_2
DROP TABLE fk_partitioned_fk_2;
CREATE TABLE fk_partitioned_fk_4 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE) PARTITION BY RANGE (b, a);
CREATE TABLE fk_partitioned_fk_4_1 PARTITION OF fk_partitioned_fk_4 FOR VALUES FROM (1,1) TO (100,100);
CREATE TABLE fk_partitioned_fk_4_2 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE SET NULL);
ALTER TABLE fk_partitioned_fk_4 ATTACH PARTITION fk_partitioned_fk_4_2 FOR VALUES FROM (100,100) TO (1000,1000);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_4 FOR VALUES IN (3500,3502);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_4;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_4 FOR VALUES IN (3500,3502);
-- should only have one constraint
\d fk_partitioned_fk_4
\d fk_partitioned_fk_4_1
-- this one has an FK with mismatched properties
\d fk_partitioned_fk_4_2
CREATE TABLE fk_partitioned_fk_5 (a int, b int,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk(a, b) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE)
PARTITION BY RANGE (a);
CREATE TABLE fk_partitioned_fk_5_1 (a int, b int, FOREIGN KEY (a, b) REFERENCES fk_notpartitioned_pk);
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_5 FOR VALUES IN (4500);
ALTER TABLE fk_partitioned_fk_5 ATTACH PARTITION fk_partitioned_fk_5_1 FOR VALUES FROM (0) TO (10);
ALTER TABLE fk_partitioned_fk DETACH PARTITION fk_partitioned_fk_5;
ALTER TABLE fk_partitioned_fk ATTACH PARTITION fk_partitioned_fk_5 FOR VALUES IN (4500);
-- this one has two constraints, similar but not quite the one in the parent,
-- so it gets a new one
\d fk_partitioned_fk_5
-- verify that it works to reattaching a child with multiple candidate
-- constraints
ALTER TABLE fk_partitioned_fk_5 DETACH PARTITION fk_partitioned_fk_5_1;
ALTER TABLE fk_partitioned_fk_5 ATTACH PARTITION fk_partitioned_fk_5_1 FOR VALUES FROM (0) TO (10);
\d fk_partitioned_fk_5_1
-- verify that attaching a table checks that the existing data satisfies the -- verify that attaching a table checks that the existing data satisfies the
-- constraint -- constraint
CREATE TABLE fk_partitioned_fk_2 (a int, b int) PARTITION BY RANGE (b); CREATE TABLE fk_partitioned_fk_2 (a int, b int) PARTITION BY RANGE (b);
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment