Detaching a partition with a FK on itself is not possible - Mailing list pgsql-bugs
From | Christophe Courtois |
---|---|
Subject | Detaching a partition with a FK on itself is not possible |
Date | |
Msg-id | 06c75996-f72b-e57b-0efe-31e74a475c39@dalibo.com Whole thread Raw |
Responses |
Re: Detaching a partition with a FK on itself is not possible
|
List | pgsql-bugs |
Hi, A customer has found a limitation, more than a bug: When a partitioned table has a foreign key that points to itself, and this FK points only to lines in the same partition (the partition key is part of the FK), you cannot detach the partition: PostgreSQL claims that the constraint is violated ; although it's impossible that the remaining partitions contain lines pointing to the partition to-be-detached (or vice versa). In some way this is logical: the FK on a detached partition is still there, and points to the partitioned table. For a human, this sounds illogical: the data in the detached partition is « self-contained » and points to the same table. It's not possible to modify the inherited constraint before detaching the table, and not possible to detach the table because of the constraint. The only realistic workaround that we found was to get rid of the global FK, and rebuild independent FKs on each partition: logical but tedious, and error-prone to maintain. A suggestion: when the FK is on the partition itself and contains the partition key, allow to rewrite the constraint to point to the detached partition, or at least allow to drop it before detaching (in the same transaction). I have no idea if some syntax changes would be necessary, and no idea how easy to implement it would be. Is it worth it? The script below reproduces the case. Thanks for any comment. \timing off DROP TABLE IF EXISTS demo1, demo2, demo3, demo ; -- A table with 3 partitions and a FK to itself ; -- * the partition key is in the PK and FK * CREATE TABLE demo ( i int, j int, rj int, z text ) PARTITION BY LIST (i); ALTER TABLE demo ADD CONSTRAINT demo_pk PRIMARY KEY (i,j); ALTER TABLE demo ADD CONSTRAINT demo_fk FOREIGN KEY (i,rj) REFERENCES demo (i,j) DEFERRABLE; CREATE TABLE demo1 PARTITION OF demo FOR VALUES IN (1); CREATE TABLE demo2 PARTITION OF demo FOR VALUES IN (2); CREATE TABLE demo3 PARTITION OF demo FOR VALUES IN (3); -- few data in each partition INSERT INTO demo (i,j,rj) VALUES (1,10, null); -- data pointing to the same partition: detaching this partition will have problems: INSERT INTO demo (i,j,rj) VALUES (2, 21, null); INSERT INTO demo (i,j,rj) VALUES (2, 31, 21); -- no FK used: INSERT INTO demo (i,j,rj) VALUES (3, 31, null); \d+ demo \d+ demo2 TABLE demo1 ; TABLE demo2 ; TABLE demo3 ; -- Detaching partitions \set ECHO queries \echo "Detaching demo3: it works (FK unused)" BEGIN ; ALTER TABLE demo DETACH PARTITION demo3 ; \echo "Note that the constraint still points to the partitioned table" \d+ demo3 ROLLBACK ; BEGIN ; \echo "Cannot DETACH!" \echo "This is our problem" ALTER TABLE demo DETACH PARTITION demo2 ; -- ERROR: removing partition "demo2" violates foreign key constraint "demo_i_rj_fkey1" -- DETAIL : Key (i, rj)=(2, 21) is still referenced from table "demo". ROLLBACK ; \echo \echo "Trying work arounds" \echo BEGIN ; \echo "Drop FK only on partition: FAIL, not possible" ALTER TABLE demo2 DROP CONSTRAINT demo_fk ; -- ERROR: cannot drop inherited constraint "demo_fk" of relation "demo2" ALTER TABLE demo DETACH PARTITION demo2 ; -- fail ROLLBACK ; BEGIN ; \echo "UPDATE FK : works but destroys data and costly" UPDATE demo2 SET rj=null ; ALTER TABLE demo DETACH PARTITION demo2 ; ROLLBACK ; BEGIN ; \echo "UPDATE FK (partition key): not allowed and would be costly" UPDATE demo2 SET i=null ; --ERROR: new row for relation "demo2" violates partition constraint ALTER TABLE demo DETACH PARTITION demo2 ; --KO ROLLBACK ; BEGIN ; \echo "DROP whole constraint, DETACH, recreate : works but costly" ALTER TABLE demo DROP CONSTRAINT demo_fk ; ALTER TABLE demo DETACH PARTITION demo2 ; ALTER TABLE demo ADD CONSTRAINT demo_fk FOREIGN KEY (i,rj) REFERENCES demo (i,j); ROLLBACK ; \echo "Re-declare keys on partitions only: works but painful" BEGIN ; ALTER TABLE demo1 ADD CONSTRAINT demo_fk1 FOREIGN KEY (i,rj) REFERENCES demo1 ; ALTER TABLE demo2 ADD CONSTRAINT demo_fk2 FOREIGN KEY (i,rj) REFERENCES demo2 ; ALTER TABLE demo3 ADD CONSTRAINT demo_fk3 FOREIGN KEY (i,rj) REFERENCES demo3 ; ALTER TABLE demo DROP CONSTRAINT demo_fk ; ALTER TABLE demo DETACH PARTITION demo2 ; ROLLBACK ; -- Christophe Courtois Consultant Dalibo https://dalibo.com/
pgsql-bugs by date: