1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-19 04:21:08 +03:00

Add regression tests for constraint errors in partitioned tables.

While  only applied to 11 (and 10 to some degree), it seems best
to add tests to all branches with partitioning support.

Reported-By: Daniel WM
Author: Andres Freund
Bug: 
Discussion: https://postgr.es/m/16293-26f5777d10143a66@postgresql.org
Backpatch: 10-
This commit is contained in:
Andres Freund
2020-03-23 14:24:06 -07:00
parent 44170a5809
commit 2060999a4d
2 changed files with 228 additions and 0 deletions
src/test/regress

@ -2149,3 +2149,130 @@ explain (costs off) select * from pp_intrangepart where a = '(1,2)'::int4range;
(2 rows) (2 rows)
drop table pp_intrangepart; drop table pp_intrangepart;
-- Verify that constraint errors across partition root / child are
-- handled correctly (Bug #16293)
CREATE TABLE errtst_parent (
partid int not null,
shdata int not null,
data int NOT NULL DEFAULT 0,
CONSTRAINT shdata_small CHECK(shdata < 3)
) PARTITION BY RANGE (partid);
-- fast defaults lead to attribute mapping being used in one
-- direction, but not the other
CREATE TABLE errtst_child_fastdef (
partid int not null,
shdata int not null,
CONSTRAINT shdata_small CHECK(shdata < 3)
);
-- no remapping in either direction necessary
CREATE TABLE errtst_child_plaindef (
partid int not null,
shdata int not null,
data int NOT NULL DEFAULT 0,
CONSTRAINT shdata_small CHECK(shdata < 3),
CHECK(data < 10)
);
-- remapping in both direction
CREATE TABLE errtst_child_reorder (
data int NOT NULL DEFAULT 0,
shdata int not null,
partid int not null,
CONSTRAINT shdata_small CHECK(shdata < 3),
CHECK(data < 10)
);
ALTER TABLE errtst_child_fastdef ADD COLUMN data int NOT NULL DEFAULT 0;
ALTER TABLE errtst_child_fastdef ADD CONSTRAINT errtest_child_fastdef_data_check CHECK (data < 10);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_fastdef FOR VALUES FROM (0) TO (10);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_plaindef FOR VALUES FROM (10) TO (20);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_reorder FOR VALUES FROM (20) TO (30);
-- insert without child check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', '5');
-- insert with child check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', '10');
ERROR: new row for relation "errtst_child_fastdef" violates check constraint "errtest_child_fastdef_data_check"
DETAIL: Failing row contains (0, 1, 10).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', '10');
ERROR: new row for relation "errtst_child_plaindef" violates check constraint "errtst_child_plaindef_data_check"
DETAIL: Failing row contains (10, 1, 10).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', '10');
ERROR: new row for relation "errtst_child_reorder" violates check constraint "errtst_child_reorder_data_check"
DETAIL: Failing row contains (20, 1, 10).
-- insert with child not null constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', NULL);
ERROR: null value in column "data" violates not-null constraint
DETAIL: Failing row contains (0, 1, null).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', NULL);
ERROR: null value in column "data" violates not-null constraint
DETAIL: Failing row contains (10, 1, null).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', NULL);
ERROR: null value in column "data" violates not-null constraint
DETAIL: Failing row contains (20, 1, null).
-- insert with shared check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '5', '5');
ERROR: new row for relation "errtst_child_fastdef" violates check constraint "shdata_small"
DETAIL: Failing row contains (0, 5, 5).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '5', '5');
ERROR: new row for relation "errtst_child_plaindef" violates check constraint "shdata_small"
DETAIL: Failing row contains (10, 5, 5).
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '5', '5');
ERROR: new row for relation "errtst_child_reorder" violates check constraint "shdata_small"
DETAIL: Failing row contains (20, 5, 5).
-- within partition update without child check constraint violation
BEGIN;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 0;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 10;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 20;
ROLLBACK;
-- within partition update with child check constraint violation
UPDATE errtst_parent SET data = data + 10 WHERE partid = 0;
ERROR: new row for relation "errtst_child_fastdef" violates check constraint "errtest_child_fastdef_data_check"
DETAIL: Failing row contains (0, 1, 15).
UPDATE errtst_parent SET data = data + 10 WHERE partid = 10;
ERROR: new row for relation "errtst_child_plaindef" violates check constraint "errtst_child_plaindef_data_check"
DETAIL: Failing row contains (10, 1, 15).
UPDATE errtst_parent SET data = data + 10 WHERE partid = 20;
ERROR: new row for relation "errtst_child_reorder" violates check constraint "errtst_child_reorder_data_check"
DETAIL: Failing row contains (15, 1, 20).
-- direct leaf partition update, without partition id violation
BEGIN;
UPDATE errtst_child_fastdef SET partid = 1 WHERE partid = 0;
UPDATE errtst_child_plaindef SET partid = 11 WHERE partid = 10;
UPDATE errtst_child_reorder SET partid = 21 WHERE partid = 20;
ROLLBACK;
-- direct leaf partition update, with partition id violation
UPDATE errtst_child_fastdef SET partid = partid + 10 WHERE partid = 0;
ERROR: new row for relation "errtst_child_fastdef" violates partition constraint
DETAIL: Failing row contains (10, 1, 5).
UPDATE errtst_child_plaindef SET partid = partid + 10 WHERE partid = 10;
ERROR: new row for relation "errtst_child_plaindef" violates partition constraint
DETAIL: Failing row contains (20, 1, 5).
UPDATE errtst_child_reorder SET partid = partid + 10 WHERE partid = 20;
ERROR: new row for relation "errtst_child_reorder" violates partition constraint
DETAIL: Failing row contains (5, 1, 30).
-- partition move, without child check constraint violation
UPDATE errtst_parent SET partid = 10, data = data + 1 WHERE partid = 0;
ERROR: new row for relation "errtst_child_fastdef" violates partition constraint
DETAIL: Failing row contains (10, 1, 6).
UPDATE errtst_parent SET partid = 20, data = data + 1 WHERE partid = 10;
ERROR: new row for relation "errtst_child_plaindef" violates partition constraint
DETAIL: Failing row contains (20, 1, 6).
UPDATE errtst_parent SET partid = 0, data = data + 1 WHERE partid = 20;
ERROR: new row for relation "errtst_child_reorder" violates partition constraint
DETAIL: Failing row contains (6, 1, 0).
-- partition move, with child check constraint violation
UPDATE errtst_parent SET partid = 10, data = data + 10 WHERE partid = 0;
ERROR: new row for relation "errtst_child_fastdef" violates check constraint "errtest_child_fastdef_data_check"
DETAIL: Failing row contains (10, 1, 15).
UPDATE errtst_parent SET partid = 20, data = data + 10 WHERE partid = 10;
ERROR: new row for relation "errtst_child_plaindef" violates check constraint "errtst_child_plaindef_data_check"
DETAIL: Failing row contains (20, 1, 15).
UPDATE errtst_parent SET partid = 0, data = data + 10 WHERE partid = 20;
ERROR: new row for relation "errtst_child_reorder" violates check constraint "errtst_child_reorder_data_check"
DETAIL: Failing row contains (15, 1, 0).
-- partition move, without target partition
UPDATE errtst_parent SET partid = 30, data = data + 10 WHERE partid = 20;
ERROR: new row for relation "errtst_child_reorder" violates check constraint "errtst_child_reorder_data_check"
DETAIL: Failing row contains (15, 1, 30).
DROP TABLE errtst_parent;

@ -755,3 +755,104 @@ create table pp_intrangepart2inf partition of pp_intrangepart for values in ('[2
explain (costs off) select * from pp_intrangepart where a = '[1,2]'::int4range; explain (costs off) select * from pp_intrangepart where a = '[1,2]'::int4range;
explain (costs off) select * from pp_intrangepart where a = '(1,2)'::int4range; explain (costs off) select * from pp_intrangepart where a = '(1,2)'::int4range;
drop table pp_intrangepart; drop table pp_intrangepart;
-- Verify that constraint errors across partition root / child are
-- handled correctly (Bug #16293)
CREATE TABLE errtst_parent (
partid int not null,
shdata int not null,
data int NOT NULL DEFAULT 0,
CONSTRAINT shdata_small CHECK(shdata < 3)
) PARTITION BY RANGE (partid);
-- fast defaults lead to attribute mapping being used in one
-- direction, but not the other
CREATE TABLE errtst_child_fastdef (
partid int not null,
shdata int not null,
CONSTRAINT shdata_small CHECK(shdata < 3)
);
-- no remapping in either direction necessary
CREATE TABLE errtst_child_plaindef (
partid int not null,
shdata int not null,
data int NOT NULL DEFAULT 0,
CONSTRAINT shdata_small CHECK(shdata < 3),
CHECK(data < 10)
);
-- remapping in both direction
CREATE TABLE errtst_child_reorder (
data int NOT NULL DEFAULT 0,
shdata int not null,
partid int not null,
CONSTRAINT shdata_small CHECK(shdata < 3),
CHECK(data < 10)
);
ALTER TABLE errtst_child_fastdef ADD COLUMN data int NOT NULL DEFAULT 0;
ALTER TABLE errtst_child_fastdef ADD CONSTRAINT errtest_child_fastdef_data_check CHECK (data < 10);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_fastdef FOR VALUES FROM (0) TO (10);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_plaindef FOR VALUES FROM (10) TO (20);
ALTER TABLE errtst_parent ATTACH PARTITION errtst_child_reorder FOR VALUES FROM (20) TO (30);
-- insert without child check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', '5');
-- insert with child check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', '10');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', '10');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', '10');
-- insert with child not null constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '1', NULL);
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '1', NULL);
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '1', NULL);
-- insert with shared check constraint error
INSERT INTO errtst_parent(partid, shdata, data) VALUES ( '0', '5', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('10', '5', '5');
INSERT INTO errtst_parent(partid, shdata, data) VALUES ('20', '5', '5');
-- within partition update without child check constraint violation
BEGIN;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 0;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 10;
UPDATE errtst_parent SET data = data + 1 WHERE partid = 20;
ROLLBACK;
-- within partition update with child check constraint violation
UPDATE errtst_parent SET data = data + 10 WHERE partid = 0;
UPDATE errtst_parent SET data = data + 10 WHERE partid = 10;
UPDATE errtst_parent SET data = data + 10 WHERE partid = 20;
-- direct leaf partition update, without partition id violation
BEGIN;
UPDATE errtst_child_fastdef SET partid = 1 WHERE partid = 0;
UPDATE errtst_child_plaindef SET partid = 11 WHERE partid = 10;
UPDATE errtst_child_reorder SET partid = 21 WHERE partid = 20;
ROLLBACK;
-- direct leaf partition update, with partition id violation
UPDATE errtst_child_fastdef SET partid = partid + 10 WHERE partid = 0;
UPDATE errtst_child_plaindef SET partid = partid + 10 WHERE partid = 10;
UPDATE errtst_child_reorder SET partid = partid + 10 WHERE partid = 20;
-- partition move, without child check constraint violation
UPDATE errtst_parent SET partid = 10, data = data + 1 WHERE partid = 0;
UPDATE errtst_parent SET partid = 20, data = data + 1 WHERE partid = 10;
UPDATE errtst_parent SET partid = 0, data = data + 1 WHERE partid = 20;
-- partition move, with child check constraint violation
UPDATE errtst_parent SET partid = 10, data = data + 10 WHERE partid = 0;
UPDATE errtst_parent SET partid = 20, data = data + 10 WHERE partid = 10;
UPDATE errtst_parent SET partid = 0, data = data + 10 WHERE partid = 20;
-- partition move, without target partition
UPDATE errtst_parent SET partid = 30, data = data + 10 WHERE partid = 20;
DROP TABLE errtst_parent;