mirror of
https://git.postgresql.org/git/postgresql.git
synced 2026-02-14 10:27:04 +08:00
We now create contype='n' pg_constraint rows for not-null constraints on user tables. Only one such constraint is allowed for a column. We propagate these constraints to other tables during operations such as adding inheritance relationships, creating and attaching partitions and creating tables LIKE other tables. These related constraints mostly follow the well-known rules of conislocal and coninhcount that we have for CHECK constraints, with some adaptations: for example, as opposed to CHECK constraints, we don't match not-null ones by name when descending a hierarchy to alter or remove it, instead matching by the name of the column that they apply to. This means we don't require the constraint names to be identical across a hierarchy. The inheritance status of these constraints can be controlled: now we can be sure that if a parent table has one, then all children will have it as well. They can optionally be marked NO INHERIT, and then children are free not to have one. (There's currently no support for altering a NO INHERIT constraint into inheriting down the hierarchy, but that's a desirable future feature.) This also opens the door for having these constraints be marked NOT VALID, as well as allowing UNIQUE+NOT NULL to be used for functional dependency determination, as envisioned by commit e49ae8d3bc58. It's likely possible to allow DEFERRABLE constraints as followup work, as well. psql shows these constraints in \d+, though we may want to reconsider if this turns out to be too noisy. Earlier versions of this patch hid constraints that were on the same columns of the primary key, but I'm not sure that that's very useful. If clutter is a problem, we might be better off inventing a new \d++ command and not showing the constraints in \d+. For now, we omit these constraints on system catalog columns, because they're unlikely to achieve anything. The main difference to the previous attempt at this (b0e96f311985) is that we now require that such a constraint always exists when a primary key is in the column; we didn't require this previously which had a number of unpalatable consequences. With this requirement, the code is easier to reason about. For example: - We no longer have "throwaway constraints" during pg_dump. We needed those for the case where a table had a PK without a not-null underneath, to prevent a slow scan of the data during restore of the PK creation, which was particularly problematic for pg_upgrade. - We no longer have to cope with attnotnull being set spuriously in case a primary key is dropped indirectly (e.g., via DROP COLUMN). Some bits of code in this patch were authored by Jian He. Author: Álvaro Herrera <alvherre@alvh.no-ip.org> Author: Bernd Helmle <mailings@oopsware.de> Reviewed-by: 何建 (jian he) <jian.universality@gmail.com> Reviewed-by: 王刚 (Tender Wang) <tndrwang@gmail.com> Reviewed-by: Justin Pryzby <pryzby@telsasoft.com> Reviewed-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com> Reviewed-by: Dean Rasheed <dean.a.rasheed@gmail.com> Discussion: https://postgr.es/m/202408310358.sdhumtyuy2ht@alvherre.pgsql
239 lines
10 KiB
SQL
239 lines
10 KiB
SQL
/*
|
|
* 1.test CREATE INDEX
|
|
*
|
|
* Deliberately avoid dropping objects in this section, to get some pg_dump
|
|
* coverage.
|
|
*/
|
|
|
|
-- Regular index with included columns
|
|
CREATE TABLE tbl_include_reg (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_reg SELECT x, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
CREATE INDEX tbl_include_reg_idx ON tbl_include_reg (c1, c2) INCLUDE (c3, c4);
|
|
-- duplicate column is pretty pointless, but we allow it anyway
|
|
CREATE INDEX ON tbl_include_reg (c1, c2) INCLUDE (c1, c3);
|
|
SELECT pg_get_indexdef(i.indexrelid)
|
|
FROM pg_index i JOIN pg_class c ON i.indexrelid = c.oid
|
|
WHERE i.indrelid = 'tbl_include_reg'::regclass ORDER BY c.relname;
|
|
\d tbl_include_reg_idx
|
|
|
|
-- Unique index and unique constraint
|
|
CREATE TABLE tbl_include_unique1 (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_unique1 SELECT x, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
CREATE UNIQUE INDEX tbl_include_unique1_idx_unique ON tbl_include_unique1 using btree (c1, c2) INCLUDE (c3, c4);
|
|
ALTER TABLE tbl_include_unique1 add UNIQUE USING INDEX tbl_include_unique1_idx_unique;
|
|
ALTER TABLE tbl_include_unique1 add UNIQUE (c1, c2) INCLUDE (c3, c4);
|
|
SELECT pg_get_indexdef(i.indexrelid)
|
|
FROM pg_index i JOIN pg_class c ON i.indexrelid = c.oid
|
|
WHERE i.indrelid = 'tbl_include_unique1'::regclass ORDER BY c.relname;
|
|
|
|
-- Unique index and unique constraint. Both must fail.
|
|
CREATE TABLE tbl_include_unique2 (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_unique2 SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
CREATE UNIQUE INDEX tbl_include_unique2_idx_unique ON tbl_include_unique2 using btree (c1, c2) INCLUDE (c3, c4);
|
|
ALTER TABLE tbl_include_unique2 add UNIQUE (c1, c2) INCLUDE (c3, c4);
|
|
|
|
-- PK constraint
|
|
CREATE TABLE tbl_include_pk (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_pk SELECT 1, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
ALTER TABLE tbl_include_pk add PRIMARY KEY (c1, c2) INCLUDE (c3, c4);
|
|
SELECT pg_get_indexdef(i.indexrelid)
|
|
FROM pg_index i JOIN pg_class c ON i.indexrelid = c.oid
|
|
WHERE i.indrelid = 'tbl_include_pk'::regclass ORDER BY c.relname;
|
|
|
|
CREATE TABLE tbl_include_box (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_box SELECT 1, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
CREATE UNIQUE INDEX tbl_include_box_idx_unique ON tbl_include_box using btree (c1, c2) INCLUDE (c3, c4);
|
|
ALTER TABLE tbl_include_box add PRIMARY KEY USING INDEX tbl_include_box_idx_unique;
|
|
SELECT pg_get_indexdef(i.indexrelid)
|
|
FROM pg_index i JOIN pg_class c ON i.indexrelid = c.oid
|
|
WHERE i.indrelid = 'tbl_include_box'::regclass ORDER BY c.relname;
|
|
|
|
-- PK constraint. Must fail.
|
|
CREATE TABLE tbl_include_box_pk (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl_include_box_pk SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
ALTER TABLE tbl_include_box_pk add PRIMARY KEY (c1, c2) INCLUDE (c3, c4);
|
|
|
|
|
|
/*
|
|
* 2. Test CREATE TABLE with constraint
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
|
CONSTRAINT covering UNIQUE(c1,c2) INCLUDE(c3,c4));
|
|
SELECT indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass FROM pg_index WHERE indrelid = 'tbl'::regclass::oid;
|
|
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'tbl'::regclass::oid;
|
|
-- ensure that constraint works
|
|
INSERT INTO tbl SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
DROP TABLE tbl;
|
|
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
|
CONSTRAINT covering PRIMARY KEY(c1,c2) INCLUDE(c3,c4));
|
|
SELECT indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass FROM pg_index WHERE indrelid = 'tbl'::regclass::oid;
|
|
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'tbl'::regclass::oid AND contype = 'p';
|
|
-- ensure that constraint works
|
|
INSERT INTO tbl SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
INSERT INTO tbl SELECT 1, NULL, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
INSERT INTO tbl SELECT x, 2*x, NULL, NULL FROM generate_series(1,300) AS x;
|
|
explain (costs off)
|
|
select * from tbl where (c1,c2,c3) < (2,5,1);
|
|
select * from tbl where (c1,c2,c3) < (2,5,1);
|
|
-- row comparison that compares high key at page boundary
|
|
SET enable_seqscan = off;
|
|
explain (costs off)
|
|
select * from tbl where (c1,c2,c3) < (262,1,1) limit 1;
|
|
select * from tbl where (c1,c2,c3) < (262,1,1) limit 1;
|
|
DROP TABLE tbl;
|
|
RESET enable_seqscan;
|
|
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
|
UNIQUE(c1,c2) INCLUDE(c3,c4));
|
|
SELECT indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass FROM pg_index WHERE indrelid = 'tbl'::regclass::oid;
|
|
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'tbl'::regclass::oid;
|
|
-- ensure that constraint works
|
|
INSERT INTO tbl SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
DROP TABLE tbl;
|
|
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
|
PRIMARY KEY(c1,c2) INCLUDE(c3,c4));
|
|
SELECT indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass FROM pg_index WHERE indrelid = 'tbl'::regclass::oid;
|
|
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'tbl'::regclass::oid AND contype = 'p';
|
|
-- ensure that constraint works
|
|
INSERT INTO tbl SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
INSERT INTO tbl SELECT 1, NULL, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
INSERT INTO tbl SELECT x, 2*x, NULL, NULL FROM generate_series(1,10) AS x;
|
|
DROP TABLE tbl;
|
|
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
|
EXCLUDE USING btree (c1 WITH =) INCLUDE(c3,c4));
|
|
SELECT indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass FROM pg_index WHERE indrelid = 'tbl'::regclass::oid;
|
|
SELECT pg_get_constraintdef(oid), conname, conkey FROM pg_constraint WHERE conrelid = 'tbl'::regclass::oid;
|
|
-- ensure that constraint works
|
|
INSERT INTO tbl SELECT 1, 2, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
INSERT INTO tbl SELECT x, 2*x, NULL, NULL FROM generate_series(1,10) AS x;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 3.0 Test ALTER TABLE DROP COLUMN.
|
|
* Any column deletion leads to index deletion.
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 int);
|
|
CREATE UNIQUE INDEX tbl_idx ON tbl using btree(c1, c2, c3, c4);
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c3;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 3.1 Test ALTER TABLE DROP COLUMN.
|
|
* Included column deletion leads to the index deletion,
|
|
* AS well AS key columns deletion. It's explained in documentation.
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box);
|
|
CREATE UNIQUE INDEX tbl_idx ON tbl using btree(c1, c2) INCLUDE(c3,c4);
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c3;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 3.2 Test ALTER TABLE DROP COLUMN.
|
|
* Included column deletion leads to the index deletion.
|
|
* AS well AS key columns deletion. It's explained in documentation.
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDE(c3,c4));
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c3;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c1;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 3.3 Test ALTER TABLE SET STATISTICS
|
|
*/
|
|
CREATE TABLE tbl (c1 int, c2 int);
|
|
CREATE INDEX tbl_idx ON tbl (c1, (c1+0)) INCLUDE (c2);
|
|
ALTER INDEX tbl_idx ALTER COLUMN 1 SET STATISTICS 1000;
|
|
ALTER INDEX tbl_idx ALTER COLUMN 2 SET STATISTICS 1000;
|
|
ALTER INDEX tbl_idx ALTER COLUMN 3 SET STATISTICS 1000;
|
|
ALTER INDEX tbl_idx ALTER COLUMN 4 SET STATISTICS 1000;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 4. CREATE INDEX CONCURRENTLY
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDE(c3,c4));
|
|
INSERT INTO tbl SELECT x, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,1000) AS x;
|
|
CREATE UNIQUE INDEX CONCURRENTLY on tbl (c1, c2) INCLUDE (c3, c4);
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
DROP TABLE tbl;
|
|
|
|
|
|
/*
|
|
* 5. REINDEX
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDE(c3,c4));
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c3;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
REINDEX INDEX tbl_c1_c2_c3_c4_key;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
ALTER TABLE tbl DROP COLUMN c1;
|
|
SELECT indexdef FROM pg_indexes WHERE tablename = 'tbl' ORDER BY indexname;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 7. Check various AMs. All but btree, gist and spgist must fail.
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 box, c4 box);
|
|
CREATE INDEX on tbl USING brin(c1, c2) INCLUDE (c3, c4);
|
|
CREATE INDEX on tbl USING gist(c3) INCLUDE (c1, c4);
|
|
CREATE INDEX on tbl USING spgist(c3) INCLUDE (c4);
|
|
CREATE INDEX on tbl USING gin(c1, c2) INCLUDE (c3, c4);
|
|
CREATE INDEX on tbl USING hash(c1, c2) INCLUDE (c3, c4);
|
|
CREATE INDEX on tbl USING rtree(c3) INCLUDE (c1, c4);
|
|
CREATE INDEX on tbl USING btree(c1, c2) INCLUDE (c3, c4);
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 8. Update, delete values in indexed table.
|
|
*/
|
|
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
|
INSERT INTO tbl SELECT x, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
CREATE UNIQUE INDEX tbl_idx_unique ON tbl using btree(c1, c2) INCLUDE (c3,c4);
|
|
UPDATE tbl SET c1 = 100 WHERE c1 = 2;
|
|
UPDATE tbl SET c1 = 1 WHERE c1 = 3;
|
|
-- should fail
|
|
UPDATE tbl SET c2 = 2 WHERE c1 = 1;
|
|
UPDATE tbl SET c3 = 1;
|
|
DELETE FROM tbl WHERE c1 = 5 OR c3 = 12;
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 9. Alter column type.
|
|
*/
|
|
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDE(c3,c4));
|
|
INSERT INTO tbl SELECT x, 2*x, 3*x, box('4,4,4,4') FROM generate_series(1,10) AS x;
|
|
ALTER TABLE tbl ALTER c1 TYPE bigint;
|
|
ALTER TABLE tbl ALTER c3 TYPE bigint;
|
|
\d tbl
|
|
DROP TABLE tbl;
|
|
|
|
/*
|
|
* 10. Test coverage for names stored as cstrings in indexes
|
|
*/
|
|
CREATE TABLE nametbl (c1 int, c2 name, c3 float);
|
|
CREATE INDEX nametbl_c1_c2_idx ON nametbl (c2, c1) INCLUDE (c3);
|
|
INSERT INTO nametbl VALUES(1, 'two', 3.0);
|
|
VACUUM nametbl;
|
|
SET enable_seqscan = 0;
|
|
|
|
-- Ensure we get an index only scan plan
|
|
EXPLAIN (COSTS OFF) SELECT c2, c1, c3 FROM nametbl WHERE c2 = 'two' AND c1 = 1;
|
|
|
|
-- Validate the results look sane
|
|
SELECT c2, c1, c3 FROM nametbl WHERE c2 = 'two' AND c1 = 1;
|
|
|
|
RESET enable_seqscan;
|
|
|
|
DROP TABLE nametbl;
|