Commit f56f8f8d authored by Alvaro Herrera's avatar Alvaro Herrera

Support foreign keys that reference partitioned tables

Previously, while primary keys could be made on partitioned tables, it
was not possible to define foreign keys that reference those primary
keys.  Now it is possible to do that.

Author: Álvaro Herrera
Reviewed-by: Amit Langote, Jesper Pedersen
Discussion: https://postgr.es/m/20181102234158.735b3fevta63msbj@alvherre.pgsql
parent 9155580f
......@@ -379,9 +379,6 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<para>
Partitioned tables do not support <literal>EXCLUDE</literal> constraints;
however, you can define these constraints on individual partitions.
Also, while it's possible to define <literal>PRIMARY KEY</literal>
constraints on partitioned tables, creating foreign keys that
reference a partitioned table is not yet supported.
</para>
<para>
......@@ -1028,9 +1025,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
addition of a foreign key constraint requires a
<literal>SHARE ROW EXCLUSIVE</literal> lock on the referenced table.
Note that foreign key constraints cannot be defined between temporary
tables and permanent tables. Also note that while it is possible to
define a foreign key on a partitioned table, it is not possible to
declare a foreign key that references a partitioned table.
tables and permanent tables.
</para>
<para>
......
This diff is collapsed.
This diff is collapsed.
......@@ -1836,6 +1836,24 @@ pg_get_partition_constraintdef(PG_FUNCTION_ARGS)
PG_RETURN_TEXT_P(string_to_text(consrc));
}
/*
* pg_get_partconstrdef_string
*
* Returns the partition constraint as a C-string for the input relation, with
* the given alias. No pretty-printing.
*/
char *
pg_get_partconstrdef_string(Oid partitionId, char *aliasname)
{
Expr *constr_expr;
List *context;
constr_expr = get_partition_qual_relid(partitionId);
context = deparse_context_for(aliasname, partitionId);
return deparse_expression((Node *) constr_expr, context, true, false);
}
/*
* pg_get_constraintdef
*
......
......@@ -2452,9 +2452,12 @@ describeOneTableDetails(const char *schemaname,
" pg_catalog.pg_get_constraintdef(r.oid, true) as condef,\n"
" conrelid::pg_catalog.regclass AS ontable\n"
"FROM pg_catalog.pg_constraint r\n"
"WHERE r.conrelid = '%s' AND r.contype = 'f'\n"
"ORDER BY conname;",
"WHERE r.conrelid = '%s' AND r.contype = 'f'\n",
oid);
if (pset.sversion >= 120000)
appendPQExpBuffer(&buf, " AND conparentid = 0\n");
appendPQExpBuffer(&buf, "ORDER BY conname");
}
result = PSQLexec(buf.data);
......
......@@ -76,10 +76,6 @@ extern void find_composite_type_dependencies(Oid typeOid,
extern void check_of_type(HeapTuple typetuple);
extern void createForeignKeyTriggers(Relation rel, Oid refRelOid,
Constraint *fkconstraint, Oid constraintOid,
Oid indexOid, bool create_action);
extern void register_on_commit_action(Oid relid, OnCommitAction action);
extern void remove_on_commit_action(Oid relid);
......
......@@ -263,6 +263,8 @@ extern bool RI_FKey_fk_upd_check_required(Trigger *trigger, Relation fk_rel,
TupleTableSlot *old_slot, TupleTableSlot *new_slot);
extern bool RI_Initial_Check(Trigger *trigger,
Relation fk_rel, Relation pk_rel);
extern void RI_PartitionRemove_Check(Trigger *trigger, Relation fk_rel,
Relation pk_rel);
/* result values for RI_FKey_trigger_type: */
#define RI_TRIGGER_PK 1 /* is a trigger on the PK relation */
......
......@@ -22,6 +22,7 @@ extern char *pg_get_indexdef_string(Oid indexrelid);
extern char *pg_get_indexdef_columns(Oid indexrelid, bool pretty);
extern char *pg_get_partkeydef_columns(Oid relid, bool pretty);
extern char *pg_get_partconstrdef_string(Oid partitionId, char *aliasname);
extern char *pg_get_constraintdef_command(Oid constraintId);
extern char *deparse_expression(Node *expr, List *dpcontext,
......
Parsed test spec with 2 sessions
starting permutation: s1b s1d s1c s2b s2a s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2b s1c s2a s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2b: begin;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2b s2a s1c s2c
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s1d s1c s2a s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s1d s2a s1c s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk1 where a = 1;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2b s2a s1d s2c s1c
step s1b: begin;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s1b s2b s2a s2c s1d s1c
step s1b: begin;
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s1b s1d s1c s2a s2c
step s2b: begin;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s1c: commit;
step s2a: alter table pfk attach partition pfk1 for values in (1);
ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s2b s1b s1d s2a s1c s2c
step s2b: begin;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
step s2a: alter table pfk attach partition pfk1 for values in (1); <waiting ...>
step s1c: commit;
step s2a: <... completed>
error in steps s1c s2a: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s2b s1b s2a s1d s2c s1c
step s2b: begin;
step s1b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s1b s2a s2c s1d s1c
step s2b: begin;
step s1b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s1b s1d s2c s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1b: begin;
step s1d: delete from ppk1 where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s1b s2c s1d s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s1b: begin;
step s2c: commit;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s2b s2a s2c s1b s1d s1c
step s2b: begin;
step s2a: alter table pfk attach partition pfk1 for values in (1);
step s2c: commit;
step s1b: begin;
step s1d: delete from ppk1 where a = 1;
ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
Parsed test spec with 2 sessions
starting permutation: s1b s1d s2b s2i s1c s2c
step s1b: begin;
step s1d: delete from ppk where a = 1;
step s2b: begin;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s1d s2bs s2i s1c s2c
step s1b: begin;
step s1d: delete from ppk where a = 1;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: could not serialize access due to concurrent update
step s2c: commit;
starting permutation: s1b s2b s1d s2i s1c s2c
step s1b: begin;
step s2b: begin;
step s1d: delete from ppk where a = 1;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: insert or update on table "pfk1" violates foreign key constraint "pfk_a_fkey"
step s2c: commit;
starting permutation: s1b s2bs s1d s2i s1c s2c
step s1b: begin;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s1d: delete from ppk where a = 1;
step s2i: insert into pfk values (1); <waiting ...>
step s1c: commit;
step s2i: <... completed>
error in steps s1c s2i: ERROR: could not serialize access due to concurrent update
step s2c: commit;
starting permutation: s1b s2b s2i s1d s2c s1c
step s1b: begin;
step s2b: begin;
step s2i: insert into pfk values (1);
step s1d: delete from ppk where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
starting permutation: s1b s2bs s2i s1d s2c s1c
step s1b: begin;
step s2bs: begin isolation level serializable; select 1;
?column?
1
step s2i: insert into pfk values (1);
step s1d: delete from ppk where a = 1; <waiting ...>
step s2c: commit;
step s1d: <... completed>
error in steps s2c s1d: ERROR: update or delete on table "ppk1" violates foreign key constraint "pfk_a_fkey1" on table "pfk"
step s1c: commit;
......@@ -24,6 +24,8 @@ test: deadlock-soft-2
test: fk-contention
test: fk-deadlock
test: fk-deadlock2
test: fk-partitioned-1
test: fk-partitioned-2
test: eval-plan-qual
test: lock-update-delete
test: lock-update-traversal
......
# Verify that cloning a foreign key constraint to a partition ensures
# that referenced values exist, even if they're being concurrently
# deleted.
setup {
drop table if exists ppk, pfk, pfk1;
create table ppk (a int primary key) partition by list (a);
create table ppk1 partition of ppk for values in (1);
insert into ppk values (1);
create table pfk (a int references ppk) partition by list (a);
create table pfk1 (a int not null);
insert into pfk1 values (1);
}
session "s1"
step "s1b" { begin; }
step "s1d" { delete from ppk1 where a = 1; }
step "s1c" { commit; }
session "s2"
step "s2b" { begin; }
step "s2a" { alter table pfk attach partition pfk1 for values in (1); }
step "s2c" { commit; }
teardown { drop table ppk, pfk, pfk1; }
permutation "s1b" "s1d" "s1c" "s2b" "s2a" "s2c"
permutation "s1b" "s1d" "s2b" "s1c" "s2a" "s2c"
permutation "s1b" "s1d" "s2b" "s2a" "s1c" "s2c"
#permutation "s1b" "s1d" "s2b" "s2a" "s2c" "s1c"
permutation "s1b" "s2b" "s1d" "s1c" "s2a" "s2c"
permutation "s1b" "s2b" "s1d" "s2a" "s1c" "s2c"
#permutation "s1b" "s2b" "s1d" "s2a" "s2c" "s1c"
#permutation "s1b" "s2b" "s2a" "s1d" "s1c" "s2c"
permutation "s1b" "s2b" "s2a" "s1d" "s2c" "s1c"
permutation "s1b" "s2b" "s2a" "s2c" "s1d" "s1c"
permutation "s2b" "s1b" "s1d" "s1c" "s2a" "s2c"
permutation "s2b" "s1b" "s1d" "s2a" "s1c" "s2c"
#permutation "s2b" "s1b" "s1d" "s2a" "s2c" "s1c"
#permutation "s2b" "s1b" "s2a" "s1d" "s1c" "s2c"
permutation "s2b" "s1b" "s2a" "s1d" "s2c" "s1c"
permutation "s2b" "s1b" "s2a" "s2c" "s1d" "s1c"
#permutation "s2b" "s2a" "s1b" "s1d" "s1c" "s2c"
permutation "s2b" "s2a" "s1b" "s1d" "s2c" "s1c"
permutation "s2b" "s2a" "s1b" "s2c" "s1d" "s1c"
permutation "s2b" "s2a" "s2c" "s1b" "s1d" "s1c"
# Make sure that FKs referencing partitioned tables actually work.
setup {
drop table if exists ppk, pfk, pfk1;
create table ppk (a int primary key) partition by list (a);
create table ppk1 partition of ppk for values in (1);
insert into ppk values (1);
create table pfk (a int references ppk) partition by list (a);
create table pfk1 partition of pfk for values in (1);
}
session "s1"
step "s1b" { begin; }
step "s1d" { delete from ppk where a = 1; }
step "s1c" { commit; }
session "s2"
step "s2b" { begin; }
step "s2bs" { begin isolation level serializable; select 1; }
step "s2i" { insert into pfk values (1); }
step "s2c" { commit; }
teardown { drop table ppk, pfk, pfk1; }
permutation "s1b" "s1d" "s2b" "s2i" "s1c" "s2c"
permutation "s1b" "s1d" "s2bs" "s2i" "s1c" "s2c"
permutation "s1b" "s2b" "s1d" "s2i" "s1c" "s2c"
permutation "s1b" "s2bs" "s1d" "s2i" "s1c" "s2c"
permutation "s1b" "s2b" "s2i" "s1d" "s2c" "s1c"
permutation "s1b" "s2bs" "s2i" "s1d" "s2c" "s1c"
This diff is collapsed.
......@@ -1145,18 +1145,6 @@ drop table pktable2, fktable2;
-- Foreign keys and partitioned tables
--
-- partitioned table in the referenced side are not allowed
CREATE TABLE fk_partitioned_pk (a int, b int, primary key (a, b))
PARTITION BY RANGE (a, b);
-- verify with create table first ...
CREATE TABLE fk_notpartitioned_fk (a int, b int,
FOREIGN KEY (a, b) REFERENCES fk_partitioned_pk);
-- and then with alter table.
CREATE TABLE fk_notpartitioned_fk_2 (a int, b int);
ALTER TABLE fk_notpartitioned_fk_2 ADD FOREIGN KEY (a, b)
REFERENCES fk_partitioned_pk;
DROP TABLE fk_partitioned_pk, fk_notpartitioned_fk_2;
-- Creation of a partitioned hierarchy with irregular definitions
CREATE TABLE fk_notpartitioned_pk (fdrop1 int, a int, fdrop2 int, b int,
PRIMARY KEY (a, b));
......@@ -1443,3 +1431,204 @@ alter table fkpart2.fk_part_1 drop constraint fkey; -- ok
alter table fkpart2.fk_part_1_1 drop constraint my_fkey; -- doesn't exist
drop schema fkpart0, fkpart1, fkpart2 cascade;
-- Test a partitioned table as referenced table.
-- Verify basic functionality with a regular partition creation and a partition
-- with a different column layout, as well as partitions added (created and
-- attached) after creating the foreign key.
CREATE SCHEMA fkpart3;
SET search_path TO fkpart3;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (0) TO (1000);
CREATE TABLE pk2 (b int, a int);
ALTER TABLE pk2 DROP COLUMN b;
ALTER TABLE pk2 ALTER a SET NOT NULL;
ALTER TABLE pk ATTACH PARTITION pk2 FOR VALUES FROM (1000) TO (2000);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (0) TO (750);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE fk2 (b int, a int) ;
ALTER TABLE fk2 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk2 FOR VALUES FROM (750) TO (3500);
CREATE TABLE pk3 PARTITION OF pk FOR VALUES FROM (2000) TO (3000);
CREATE TABLE pk4 (LIKE pk);
ALTER TABLE pk ATTACH PARTITION pk4 FOR VALUES FROM (3000) TO (4000);
CREATE TABLE pk5 (c int, b int, a int NOT NULL) PARTITION BY RANGE (a);
ALTER TABLE pk5 DROP COLUMN b, DROP COLUMN c;
CREATE TABLE pk51 PARTITION OF pk5 FOR VALUES FROM (4000) TO (4500);
CREATE TABLE pk52 PARTITION OF pk5 FOR VALUES FROM (4500) TO (5000);
ALTER TABLE pk ATTACH PARTITION pk5 FOR VALUES FROM (4000) TO (5000);
CREATE TABLE fk3 PARTITION OF fk FOR VALUES FROM (3500) TO (5000);
-- these should fail: referenced value not present
INSERT into fk VALUES (1);
INSERT into fk VALUES (1000);
INSERT into fk VALUES (2000);
INSERT into fk VALUES (3000);
INSERT into fk VALUES (4000);
INSERT into fk VALUES (4500);
-- insert into the referenced table, now they should work
INSERT into pk VALUES (1), (1000), (2000), (3000), (4000), (4500);
INSERT into fk VALUES (1), (1000), (2000), (3000), (4000), (4500);
-- should fail: referencing value present
DELETE FROM pk WHERE a = 1;
DELETE FROM pk WHERE a = 1000;
DELETE FROM pk WHERE a = 2000;
DELETE FROM pk WHERE a = 3000;
DELETE FROM pk WHERE a = 4000;
DELETE FROM pk WHERE a = 4500;
UPDATE pk SET a = 2 WHERE a = 1;
UPDATE pk SET a = 1002 WHERE a = 1000;
UPDATE pk SET a = 2002 WHERE a = 2000;
UPDATE pk SET a = 3002 WHERE a = 3000;
UPDATE pk SET a = 4002 WHERE a = 4000;
UPDATE pk SET a = 4502 WHERE a = 4500;
-- now they should work
DELETE FROM fk;
UPDATE pk SET a = 2 WHERE a = 1;
DELETE FROM pk WHERE a = 2;
UPDATE pk SET a = 1002 WHERE a = 1000;
DELETE FROM pk WHERE a = 1002;
UPDATE pk SET a = 2002 WHERE a = 2000;
DELETE FROM pk WHERE a = 2002;
UPDATE pk SET a = 3002 WHERE a = 3000;
DELETE FROM pk WHERE a = 3002;
UPDATE pk SET a = 4002 WHERE a = 4000;
DELETE FROM pk WHERE a = 4002;
UPDATE pk SET a = 4502 WHERE a = 4500;
DELETE FROM pk WHERE a = 4502;
CREATE SCHEMA fkpart4;
SET search_path TO fkpart4;
-- dropping/detaching PARTITIONs is prevented if that would break
-- a foreign key's existing data
CREATE TABLE droppk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE droppk1 PARTITION OF droppk FOR VALUES FROM (0) TO (1000);
CREATE TABLE droppk_d PARTITION OF droppk DEFAULT;
CREATE TABLE droppk2 PARTITION OF droppk FOR VALUES FROM (1000) TO (2000)
PARTITION BY RANGE (a);
CREATE TABLE droppk21 PARTITION OF droppk2 FOR VALUES FROM (1000) TO (1400);
CREATE TABLE droppk2_d PARTITION OF droppk2 DEFAULT;
INSERT into droppk VALUES (1), (1000), (1500), (2000);
CREATE TABLE dropfk (a int REFERENCES droppk);
INSERT into dropfk VALUES (1), (1000), (1500), (2000);
-- these should all fail
ALTER TABLE droppk DETACH PARTITION droppk_d;
ALTER TABLE droppk2 DETACH PARTITION droppk2_d;
ALTER TABLE droppk DETACH PARTITION droppk1;
ALTER TABLE droppk DETACH PARTITION droppk2;
ALTER TABLE droppk2 DETACH PARTITION droppk21;
-- dropping partitions is disallowed
DROP TABLE droppk_d;
DROP TABLE droppk2_d;
DROP TABLE droppk1;
DROP TABLE droppk2;
DROP TABLE droppk21;
DELETE FROM dropfk;
-- dropping partitions is disallowed, even when no referencing values
DROP TABLE droppk_d;
DROP TABLE droppk2_d;
DROP TABLE droppk1;
-- but DETACH is allowed, and DROP afterwards works
ALTER TABLE droppk2 DETACH PARTITION droppk21;
DROP TABLE droppk2;
-- Verify that initial constraint creation and cloning behave correctly
CREATE SCHEMA fkpart5;
SET search_path TO fkpart5;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY LIST (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES IN (1);
CREATE TABLE fk (a int) PARTITION BY LIST (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES IN (1) PARTITION BY LIST (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES IN (1);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk;
CREATE TABLE pk2 PARTITION OF pk FOR VALUES IN (2);
CREATE TABLE pk3 (a int NOT NULL) PARTITION BY LIST (a);
CREATE TABLE pk31 PARTITION OF pk3 FOR VALUES IN (31);
CREATE TABLE pk32 (b int, a int NOT NULL);
ALTER TABLE pk32 DROP COLUMN b;
ALTER TABLE pk3 ATTACH PARTITION pk32 FOR VALUES IN (32);
ALTER TABLE pk ATTACH PARTITION pk3 FOR VALUES IN (31, 32);
CREATE TABLE fk2 PARTITION OF fk FOR VALUES IN (2);
CREATE TABLE fk3 (b int, a int);
ALTER TABLE fk3 DROP COLUMN b;
ALTER TABLE fk ATTACH PARTITION fk3 FOR VALUES IN (3);
SELECT pg_describe_object('pg_constraint'::regclass, oid, 0), confrelid::regclass,
CASE WHEN conparentid <> 0 THEN pg_describe_object('pg_constraint'::regclass, conparentid, 0) ELSE 'TOP' END
FROM pg_catalog.pg_constraint
WHERE conrelid IN (SELECT relid FROM pg_partition_tree('fk'))
ORDER BY conrelid::regclass::text, conname;
CREATE TABLE fk4 (LIKE fk);
INSERT INTO fk4 VALUES (50);
ALTER TABLE fk ATTACH PARTITION fk4 FOR VALUES IN (50);
-- Verify ON UPDATE/DELETE behavior
CREATE SCHEMA fkpart6;
SET search_path TO fkpart6;
CREATE TABLE pk (a int PRIMARY KEY) PARTITION BY RANGE (a);
CREATE TABLE pk1 PARTITION OF pk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE pk11 PARTITION OF pk1 FOR VALUES FROM (1) TO (50);
CREATE TABLE pk12 PARTITION OF pk1 FOR VALUES FROM (50) TO (100);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE CASCADE ON DELETE CASCADE;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO pk VALUES (1);
INSERT INTO fk VALUES (1);
UPDATE pk SET a = 20;
SELECT tableoid::regclass, * FROM fk;
DELETE FROM pk WHERE a = 20;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (50);
CREATE TABLE fk (a int) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET NULL ON DELETE SET NULL;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (50);
UPDATE pk SET a = 21 WHERE a = 20;
DELETE FROM pk WHERE a = 50;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30), (50);
CREATE TABLE fk (id int, a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE SET DEFAULT ON DELETE SET DEFAULT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (1, 20), (2, 30);
DELETE FROM pk WHERE a = 20 RETURNING *;
UPDATE pk SET a = 90 WHERE a = 30 RETURNING *;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
TRUNCATE TABLE pk;
INSERT INTO pk VALUES (20), (30);
CREATE TABLE fk (a int DEFAULT 50) PARTITION BY RANGE (a);
CREATE TABLE fk1 PARTITION OF fk FOR VALUES FROM (1) TO (100) PARTITION BY RANGE (a);
CREATE TABLE fk11 PARTITION OF fk1 FOR VALUES FROM (1) TO (10);
CREATE TABLE fk12 PARTITION OF fk1 FOR VALUES FROM (10) TO (100);
ALTER TABLE fk ADD FOREIGN KEY (a) REFERENCES pk ON UPDATE RESTRICT ON DELETE RESTRICT;
CREATE TABLE fk_d PARTITION OF fk DEFAULT;
INSERT INTO fk VALUES (20), (30);
DELETE FROM pk WHERE a = 20;
UPDATE pk SET a = 90 WHERE a = 30;
SELECT tableoid::regclass, * FROM fk;
DROP TABLE fk;
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