Thread: Deferrable FK not behaving as expected.
v12.5
I added a deferrable FK constraint on sales_detail to ensure that no one can delete records from sales_header when an associated sales_detail record exists. That works perfectly.
The problem is that try to delete parent records before the child records inside a transaction also fails.
Here are sample tables, sample data and the failed delete statement.
What am I missing?
test=# \d sales_header
Partitioned table "public.sales_header"
Column | Type | Collation | Nullable | Default
---------------+-----------------------------+-----------+----------+---------
order_num | integer | | |
cust_id | integer | | not null |
order_ts | timestamp without time zone | | not null |
shipping_addr | text | | |
Partition key: RANGE (order_ts)
Indexes:
"sales_header_pkey" PRIMARY KEY, btree (cust_id, order_ts)
"sales_header_i1" btree (order_num)
Referenced by:
TABLE "sales_detail" CONSTRAINT "fk_sales_detail_sales_header"
FOREIGN KEY (cust_id, order_ts) REFERENCES sales_header(cust_id, order_ts) DEFERRABLE
test=# \d sales_detail
Partitioned table "public.sales_detail"
Column | Type | Collation | Nullable | Default
--------------+-----------------------------+-----------+----------+---------
cust_id | integer | | not null |
order_ts | timestamp without time zone | | not null |
seq_no | integer | | not null |
inventory_id | integer | | |
quantity | numeric(10,2) | | |
price | numeric(10,2) | | |
tax_rate | numeric(3,3) | | |
Partition key: RANGE (order_ts)
Indexes:
"sales_detail_pkey" PRIMARY KEY, btree (cust_id, order_ts, seq_no)
Foreign-key constraints:
"fk_sales_detail_sales_header" FOREIGN KEY (cust_id, order_ts)
REFERENCES sales_header(cust_id, order_ts) DEFERRABLE
Number of partitions: 12 (Use \d+ to list them.)
INSERT INTO sales_header VALUES (1, 1, '2020-01-05 13:05:42.567', '123 Main St, Anytown, Iowa');
INSERT INTO sales_detail VALUES (1, '2020-01-05 13:05:42.567', 1, 12345, 5.8, 28.40, 0.092);
INSERT INTO sales_detail VALUES (1, '2020-01-05 13:05:42.567', 2, 23456, 6.0, 98.40, 0.092);
INSERT INTO sales_detail VALUES (1, '2020-01-05 13:05:42.567', 3, 34567, 1.8, 67.00, 0.092);
INSERT INTO sales_detail VALUES (1, '2020-01-05 13:05:42.567', 4, 45678, 450, 2.00, 0.092);
INSERT INTO sales_header VALUES (2, 1, '2020-02-05 13:05:42.567', '234 Main St, Anytown, Iowa');
INSERT INTO sales_detail VALUES (1, '2020-02-05 13:05:42.567', 1, 6575, 5.2, 567, 0.045);
INSERT INTO sales_detail VALUES (1, '2020-02-05 13:05:42.567', 2, 4565, 456, 545, 0.045);
INSERT INTO sales_detail VALUES (1, '2020-02-05 13:05:42.567', 3, 7899, 768, 432, 0.045);
INSERT INTO sales_detail VALUES (1, '2020-02-05 13:05:42.567', 4, 2354, 556, 890, 0.045);
INSERT INTO sales_header VALUES (3, 1, '2020-03-05 13:05:42.567', '345 Main St, Anytown, Iowa');
INSERT INTO sales_detail VALUES (1, '2020-03-05 13:05:42.567', 1, 6575, 5.2, 567, 0.045);
INSERT INTO sales_detail VALUES (1, '2020-03-05 13:05:42.567', 2, 4565, 456, 545, 0.045);
INSERT INTO sales_detail VALUES (1, '2020-03-05 13:05:42.567', 3, 7899, 768, 432, 0.045);
test=# begin transaction;
BEGIN
test=# delete from sales_header where cust_id = 1;
ERROR: update or delete on table "sales_header_202001" violates foreign key constraint "sales_detail_cust_id_order_ts_fkey" on table "sales_detail"
DETAIL: Key (cust_id, order_ts)=(1, 2020-01-05 13:05:42.567) is still referenced from table "sales_detail".
test=#
test=# rollback;
--
Angular momentum makes the world go 'round.
Angular momentum makes the world go 'round.
Ron schrieb am 07.12.2020 um 19:15: > Referenced by: > TABLE "sales_detail" CONSTRAINT "fk_sales_detail_sales_header" > FOREIGN KEY (cust_id, order_ts) REFERENCES sales_header(cust_id, order_ts) *DEFERRABLE* I think if you only mention "deferrable" this is the same as "deferrable initially immediate", so you will need to make them deferrable in your transaction: SET CONSTRAINTS ALL DEFERRED; or create the constraint with deferrable initially deferred Thomas
On 12/7/20 12:19 PM, Thomas Kellerer wrote: > Ron schrieb am 07.12.2020 um 19:15: >> Referenced by: >> TABLE "sales_detail" CONSTRAINT "fk_sales_detail_sales_header" >> FOREIGN KEY (cust_id, order_ts) REFERENCES >> sales_header(cust_id, order_ts) *DEFERRABLE* > > I think if you only mention "deferrable" this is the same as "deferrable > initially immediate", > so you will need to make them deferrable in your transaction: > > SET CONSTRAINTS ALL DEFERRED; > > or create the constraint with > > deferrable initially deferred OK. For some reason, I thought INITIALLY DEFERRED was only applicable to INSERT and UPDATE statements. -- Angular momentum makes the world go 'round.
On 12/7/20 12:19 PM, Thomas Kellerer wrote:
Neither technique worked.
test=# ALTER TABLE sales_detail ALTER CONSTRAINT fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE
test=# \d sales_detail
Partitioned table "public.sales_detail"
Column | Type | Collation | Nullable | Default
--------------+-----------------------------+-----------+----------+---------
cust_id | integer | | not null |
order_ts | timestamp without time zone | | not null |
seq_no | integer | | not null |
inventory_id | integer | | |
quantity | numeric(10,2) | | |
price | numeric(10,2) | | |
tax_rate | numeric(3,3) | | |
Partition key: RANGE (order_ts)
Indexes:
"sales_detail_pkey" PRIMARY KEY, btree (cust_id, order_ts, seq_no)
Foreign-key constraints:
"fk_sales_detail_sales_header" FOREIGN KEY (cust_id, order_ts)
REFERENCES sales_header(cust_id, order_ts) DEFERRABLE INITIALLY DEFERRED
Number of partitions: 12 (Use \d+ to list them.)
test=# begin transaction;
BEGIN
test=# delete from sales_header where cust_id = 1;
ERROR: update or delete on table "sales_header_202001" violates foreign key constraint "sales_detail_cust_id_order_ts_fkey" on table "sales_detail"
DETAIL: Key (cust_id, order_ts)=(1, 2020-01-05 13:05:42.567) is still referenced from table "sales_detail".
test=# rollback;
ROLLBACK
Ron schrieb am 07.12.2020 um 19:15:Referenced by:
TABLE "sales_detail" CONSTRAINT "fk_sales_detail_sales_header"
FOREIGN KEY (cust_id, order_ts) REFERENCES sales_header(cust_id, order_ts) *DEFERRABLE*
I think if you only mention "deferrable" this is the same as "deferrable initially immediate",
so you will need to make them deferrable in your transaction:
SET CONSTRAINTS ALL DEFERRED;
or create the constraint with
deferrable initially deferred
Neither technique worked.
test=# ALTER TABLE sales_detail ALTER CONSTRAINT fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE
test=# \d sales_detail
Partitioned table "public.sales_detail"
Column | Type | Collation | Nullable | Default
--------------+-----------------------------+-----------+----------+---------
cust_id | integer | | not null |
order_ts | timestamp without time zone | | not null |
seq_no | integer | | not null |
inventory_id | integer | | |
quantity | numeric(10,2) | | |
price | numeric(10,2) | | |
tax_rate | numeric(3,3) | | |
Partition key: RANGE (order_ts)
Indexes:
"sales_detail_pkey" PRIMARY KEY, btree (cust_id, order_ts, seq_no)
Foreign-key constraints:
"fk_sales_detail_sales_header" FOREIGN KEY (cust_id, order_ts)
REFERENCES sales_header(cust_id, order_ts) DEFERRABLE INITIALLY DEFERRED
Number of partitions: 12 (Use \d+ to list them.)
test=# begin transaction;
BEGIN
test=# delete from sales_header where cust_id = 1;
ERROR: update or delete on table "sales_header_202001" violates foreign key constraint "sales_detail_cust_id_order_ts_fkey" on table "sales_detail"
DETAIL: Key (cust_id, order_ts)=(1, 2020-01-05 13:05:42.567) is still referenced from table "sales_detail".
test=# rollback;
ROLLBACK
--
Angular momentum makes the world go 'round.
Angular momentum makes the world go 'round.
Ron <ronljohnsonjr@gmail.com> writes: > Neither technique worked. > test=# ALTER TABLE sales_detail ALTER CONSTRAINT > fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED; > ALTER TABLE Hmm, reproduced here. There seems to be some kind of bug in ALTER CONSTRAINT --- it looks like it's updated all the child FKs successfully, but it actually hasn't. If you drop the FK constraint altogether, and recreate it having DEFERRABLE INITIALLY DEFERRED from the start, it should work --- at least it does for me. regards, tom lane
On 12/7/20 1:27 PM, Tom Lane wrote: > Ron <ronljohnsonjr@gmail.com> writes: >> Neither technique worked. >> test=# ALTER TABLE sales_detail ALTER CONSTRAINT >> fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED; >> ALTER TABLE > Hmm, reproduced here. There seems to be some kind of bug > in ALTER CONSTRAINT --- Do I need to file a bug report? > it looks like it's updated all the > child FKs successfully, but it actually hasn't. If you > drop the FK constraint altogether, and recreate it having > DEFERRABLE INITIALLY DEFERRED from the start, it should > work --- at least it does for me. That worked. -- Angular momentum makes the world go 'round.
On 12/7/20 1:15 PM, Ron wrote: > On 12/7/20 1:27 PM, Tom Lane wrote: >> Ron <ronljohnsonjr@gmail.com> writes: >>> Neither technique worked. >>> test=# ALTER TABLE sales_detail ALTER CONSTRAINT >>> fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED; >>> ALTER TABLE >> Hmm, reproduced here. There seems to be some kind of bug >> in ALTER CONSTRAINT --- > > Do I need to file a bug report? No: https://www.postgresql.org/message-id/3144850.1607369633%40sss.pgh.pa.us > >> it looks like it's updated all the >> child FKs successfully, but it actually hasn't. If you >> drop the FK constraint altogether, and recreate it having >> DEFERRABLE INITIALLY DEFERRED from the start, it should >> work --- at least it does for me. > > That worked. > -- Adrian Klaver adrian.klaver@aklaver.com
On 12/7/20 1:27 PM, Tom Lane wrote:
That works sometimes, but not when we really want it to work.
test=# alter table sales_detail drop CONSTRAINT fk_sales_detail_sales_header;
ALTER TABLE
test=# ALTER TABLE sales_detail
test-# ADD CONSTRAINT fk_sales_detail_sales_header
test-# FOREIGN KEY (cust_id, order_ts)
test-# REFERENCES sales_header (cust_id, order_ts) DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE
test=#
test=#
-- Works
test=# begin transaction;
BEGIN
test=# delete from sales_header where cust_id = 1;
DELETE 3
test=#
test=# rollback;
ROLLBACK
-- Does not work
test=# begin transaction;
BEGIN
test=# ALTER TABLE sales_header DETACH PARTITION sales_header_202001;
ERROR: removing partition "sales_header_202001" violates foreign key constraint "sales_detail_cust_id_order_ts_fkey"
DETAIL: Key (cust_id, order_ts)=(1, 2020-01-05 13:05:42.567) is still referenced from table "sales_detail".
test=# rollback;
ROLLBACK
Ron <ronljohnsonjr@gmail.com> writes:Neither technique worked.test=# ALTER TABLE sales_detail ALTER CONSTRAINT fk_sales_detail_sales_header DEFERRABLE INITIALLY DEFERRED; ALTER TABLEHmm, reproduced here. There seems to be some kind of bug in ALTER CONSTRAINT --- it looks like it's updated all the child FKs successfully, but it actually hasn't. If you drop the FK constraint altogether, and recreate it having DEFERRABLE INITIALLY DEFERRED from the start, it should work --- at least it does for me.
That works sometimes, but not when we really want it to work.
test=# alter table sales_detail drop CONSTRAINT fk_sales_detail_sales_header;
ALTER TABLE
test=# ALTER TABLE sales_detail
test-# ADD CONSTRAINT fk_sales_detail_sales_header
test-# FOREIGN KEY (cust_id, order_ts)
test-# REFERENCES sales_header (cust_id, order_ts) DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE
test=#
test=#
-- Works
test=# begin transaction;
BEGIN
test=# delete from sales_header where cust_id = 1;
DELETE 3
test=#
test=# rollback;
ROLLBACK
-- Does not work
test=# begin transaction;
BEGIN
test=# ALTER TABLE sales_header DETACH PARTITION sales_header_202001;
ERROR: removing partition "sales_header_202001" violates foreign key constraint "sales_detail_cust_id_order_ts_fkey"
DETAIL: Key (cust_id, order_ts)=(1, 2020-01-05 13:05:42.567) is still referenced from table "sales_detail".
test=# rollback;
ROLLBACK
--
Angular momentum makes the world go 'round.
Angular momentum makes the world go 'round.
Ron <ronljohnsonjr@gmail.com> writes: > That works *sometimes*, but not when we *really* want it to work. > test=# begin transaction; > BEGIN > test=# ALTER TABLE sales_header DETACH PARTITION sales_header_202001; > ERROR: removing partition "sales_header_202001" violates foreign key > constraint "sales_detail_cust_id_order_ts_fkey" That I think you're gonna have to live with. DETACH PARTITION isn't something we can defer to end of transaction. regards, tom lane
On 12/7/20 3:40 PM, Tom Lane wrote: > Ron <ronljohnsonjr@gmail.com> writes: >> That works *sometimes*, but not when we *really* want it to work. >> test=# begin transaction; >> BEGIN >> test=# ALTER TABLE sales_header DETACH PARTITION sales_header_202001; >> ERROR: removing partition "sales_header_202001" violates foreign key >> constraint "sales_detail_cust_id_order_ts_fkey" > That I think you're gonna have to live with. DETACH PARTITION isn't > something we can defer to end of transaction. Very sad, since it would simplify the archiving of the 24x365 system we're porting from Oracle to RDS Postgresql. -- Angular momentum makes the world go 'round.