mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
CREATE INDEX ... INCLUDING (column[, ...])
Now indexes (but only B-tree for now) can contain "extra" column(s) which doesn't participate in index structure, they are just stored in leaf tuples. It allows to use index only scan by using single index instead of two or more indexes. Author: Anastasia Lubennikova with minor editorializing by me Reviewers: David Rowley, Peter Geoghegan, Jeff Janes
This commit is contained in:
@ -2376,6 +2376,25 @@ DETAIL: Key ((f1 || f2))=(ABCDEF) already exists.
|
||||
-- but this shouldn't:
|
||||
INSERT INTO func_index_heap VALUES('QWERTY');
|
||||
--
|
||||
-- Test unique index with included columns
|
||||
--
|
||||
CREATE TABLE covering_index_heap (f1 int, f2 int, f3 text);
|
||||
CREATE UNIQUE INDEX covering_index_index on covering_index_heap (f1,f2) INCLUDING(f3);
|
||||
INSERT INTO covering_index_heap VALUES(1,1,'AAA');
|
||||
INSERT INTO covering_index_heap VALUES(1,2,'AAA');
|
||||
-- this should fail because of unique index on f1,f2:
|
||||
INSERT INTO covering_index_heap VALUES(1,2,'BBB');
|
||||
ERROR: duplicate key value violates unique constraint "covering_index_index"
|
||||
DETAIL: Key (f1, f2)=(1, 2) already exists.
|
||||
-- and this shouldn't:
|
||||
INSERT INTO covering_index_heap VALUES(1,4,'AAA');
|
||||
-- Try to build index on table that already contains data
|
||||
CREATE UNIQUE INDEX covering_pkey on covering_index_heap (f1,f2) INCLUDING(f3);
|
||||
-- Try to use existing covering index as primary key
|
||||
ALTER TABLE covering_index_heap ADD CONSTRAINT covering_pkey PRIMARY KEY USING INDEX
|
||||
covering_pkey;
|
||||
DROP TABLE covering_index_heap;
|
||||
--
|
||||
-- Also try building functional, expressional, and partial indexes on
|
||||
-- tables that already contain data.
|
||||
--
|
||||
|
301
src/test/regress/expected/index_including.out
Normal file
301
src/test/regress/expected/index_including.out
Normal file
@ -0,0 +1,301 @@
|
||||
/*
|
||||
* 1.test CREATE INDEX
|
||||
*/
|
||||
-- Regular index with included columns
|
||||
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 INDEX tbl_idx ON tbl using btree(c1, c2) INCLUDING (c3,c4);
|
||||
-- must fail because of intersection of key and included columns
|
||||
CREATE INDEX tbl_idx ON tbl using btree(c1, c2) INCLUDING (c1,c3);
|
||||
ERROR: included columns must not intersect with key columns
|
||||
DROP TABLE tbl;
|
||||
-- Unique index and unique constraint
|
||||
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) INCLUDING (c3,c4);
|
||||
ALTER TABLE tbl add UNIQUE USING INDEX tbl_idx_unique;
|
||||
ALTER TABLE tbl add UNIQUE(c1, c2) INCLUDING (c3, c4);
|
||||
DROP TABLE tbl;
|
||||
-- Unique index and unique constraint. Both must fail.
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 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) INCLUDING (c3,c4);
|
||||
ERROR: could not create unique index "tbl_idx_unique"
|
||||
DETAIL: Key (c1, c2)=(1, 2) is duplicated.
|
||||
ALTER TABLE tbl add UNIQUE(c1, c2) INCLUDING (c3, c4);
|
||||
ERROR: could not create unique index "tbl_c1_c2_c3_c4_key"
|
||||
DETAIL: Key (c1, c2)=(1, 2) is duplicated.
|
||||
DROP TABLE tbl;
|
||||
-- PK constraint
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ALTER TABLE tbl add PRIMARY KEY(c1, c2) INCLUDING (c3, c4);
|
||||
ERROR: could not create unique index "tbl_pkey"
|
||||
DETAIL: Key (c1, c2)=(1, 2) is duplicated.
|
||||
DROP TABLE tbl;
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 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) INCLUDING (c3,c4);
|
||||
ERROR: could not create unique index "tbl_idx_unique"
|
||||
DETAIL: Key (c1, c2)=(1, 2) is duplicated.
|
||||
ALTER TABLE tbl add PRIMARY KEY USING INDEX tbl_idx_unique;
|
||||
ERROR: index "tbl_idx_unique" does not exist
|
||||
LINE 1: ALTER TABLE tbl add PRIMARY KEY USING INDEX tbl_idx_unique;
|
||||
^
|
||||
DROP TABLE tbl;
|
||||
-- PK constraint. Must fail.
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ALTER TABLE tbl add PRIMARY KEY(c1, c2) INCLUDING (c3, c4);
|
||||
ERROR: could not create unique index "tbl_pkey"
|
||||
DETAIL: Key (c1, c2)=(1, 2) is duplicated.
|
||||
DROP TABLE tbl;
|
||||
/*
|
||||
* 2. Test CREATE TABLE with constraint
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
||||
CONSTRAINT covering UNIQUE(c1,c2) INCLUDING(c3,c4));
|
||||
select indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass from pg_index where indrelid = 'tbl'::regclass::oid;
|
||||
indexrelid | indnatts | indnkeyatts | indisunique | indisprimary | indkey | indclass
|
||||
------------+----------+-------------+-------------+--------------+---------+-----------
|
||||
covering | 4 | 2 | t | f | 1 2 3 4 | 1978 1978
|
||||
(1 row)
|
||||
|
||||
select pg_get_constraintdef(oid), conname, conkey, conincluding from pg_constraint where conrelid = 'tbl'::regclass::oid;
|
||||
pg_get_constraintdef | conname | conkey | conincluding
|
||||
------------------------------------+----------+--------+--------------
|
||||
UNIQUE (c1, c2) INCLUDING (c3, c4) | covering | {1,2} | {3,4}
|
||||
(1 row)
|
||||
|
||||
-- ensure that constraint works
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: duplicate key value violates unique constraint "covering"
|
||||
DETAIL: Key (c1, c2)=(1, 2) already exists.
|
||||
DROP TABLE tbl;
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
||||
CONSTRAINT covering PRIMARY KEY(c1,c2) INCLUDING(c3,c4));
|
||||
select indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass from pg_index where indrelid = 'tbl'::regclass::oid;
|
||||
indexrelid | indnatts | indnkeyatts | indisunique | indisprimary | indkey | indclass
|
||||
------------+----------+-------------+-------------+--------------+---------+-----------
|
||||
covering | 4 | 2 | t | t | 1 2 3 4 | 1978 1978
|
||||
(1 row)
|
||||
|
||||
select pg_get_constraintdef(oid), conname, conkey, conincluding from pg_constraint where conrelid = 'tbl'::regclass::oid;
|
||||
pg_get_constraintdef | conname | conkey | conincluding
|
||||
-----------------------------------------+----------+--------+--------------
|
||||
PRIMARY KEY (c1, c2) INCLUDING (c3, c4) | covering | {1,2} | {3,4}
|
||||
(1 row)
|
||||
|
||||
-- ensure that constraint works
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: duplicate key value violates unique constraint "covering"
|
||||
DETAIL: Key (c1, c2)=(1, 2) already exists.
|
||||
INSERT INTO tbl select 1, NULL, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: null value in column "c2" violates not-null constraint
|
||||
DETAIL: Failing row contains (1, null, 3, (4,4),(4,4)).
|
||||
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,
|
||||
UNIQUE(c1,c2) INCLUDING(c3,c4));
|
||||
select indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass from pg_index where indrelid = 'tbl'::regclass::oid;
|
||||
indexrelid | indnatts | indnkeyatts | indisunique | indisprimary | indkey | indclass
|
||||
---------------------+----------+-------------+-------------+--------------+---------+-----------
|
||||
tbl_c1_c2_c3_c4_key | 4 | 2 | t | f | 1 2 3 4 | 1978 1978
|
||||
(1 row)
|
||||
|
||||
select pg_get_constraintdef(oid), conname, conkey, conincluding from pg_constraint where conrelid = 'tbl'::regclass::oid;
|
||||
pg_get_constraintdef | conname | conkey | conincluding
|
||||
------------------------------------+---------------------+--------+--------------
|
||||
UNIQUE (c1, c2) INCLUDING (c3, c4) | tbl_c1_c2_c3_c4_key | {1,2} | {3,4}
|
||||
(1 row)
|
||||
|
||||
-- ensure that constraint works
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: duplicate key value violates unique constraint "tbl_c1_c2_c3_c4_key"
|
||||
DETAIL: Key (c1, c2)=(1, 2) already exists.
|
||||
DROP TABLE tbl;
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
||||
PRIMARY KEY(c1,c2) INCLUDING(c3,c4));
|
||||
select indexrelid::regclass, indnatts, indnkeyatts, indisunique, indisprimary, indkey, indclass from pg_index where indrelid = 'tbl'::regclass::oid;
|
||||
indexrelid | indnatts | indnkeyatts | indisunique | indisprimary | indkey | indclass
|
||||
------------+----------+-------------+-------------+--------------+---------+-----------
|
||||
tbl_pkey | 4 | 2 | t | t | 1 2 3 4 | 1978 1978
|
||||
(1 row)
|
||||
|
||||
select pg_get_constraintdef(oid), conname, conkey, conincluding from pg_constraint where conrelid = 'tbl'::regclass::oid;
|
||||
pg_get_constraintdef | conname | conkey | conincluding
|
||||
-----------------------------------------+----------+--------+--------------
|
||||
PRIMARY KEY (c1, c2) INCLUDING (c3, c4) | tbl_pkey | {1,2} | {3,4}
|
||||
(1 row)
|
||||
|
||||
-- ensure that constraint works
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: duplicate key value violates unique constraint "tbl_pkey"
|
||||
DETAIL: Key (c1, c2)=(1, 2) already exists.
|
||||
INSERT INTO tbl select 1, NULL, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ERROR: null value in column "c2" violates not-null constraint
|
||||
DETAIL: Failing row contains (1, null, 3, (4,4),(4,4)).
|
||||
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';
|
||||
indexdef
|
||||
-----------------------------------------------------------------
|
||||
CREATE UNIQUE INDEX tbl_idx ON tbl USING btree (c1, c2, c3, c4)
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
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) INCLUDING(c3,c4);
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------------------------------------------------------------------------
|
||||
CREATE UNIQUE INDEX tbl_idx ON tbl USING btree (c1, c2) INCLUDING (c3, c4)
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
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) INCLUDING(c3,c4));
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------------------------------------------------------------------------------------
|
||||
CREATE UNIQUE INDEX tbl_c1_c2_c3_c4_key ON tbl USING btree (c1, c2) INCLUDING (c3, c4)
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c1;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE tbl;
|
||||
/*
|
||||
* 4. CREATE INDEX CONCURRENTLY
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDING(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) INCLUDING (c3, c4);
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------------------------------------------------------------------------------------
|
||||
CREATE UNIQUE INDEX tbl_c1_c2_c3_c4_key ON tbl USING btree (c1, c2) INCLUDING (c3, c4)
|
||||
CREATE UNIQUE INDEX tbl_c1_c2_c3_c4_idx ON tbl USING btree (c1, c2) INCLUDING (c3, c4)
|
||||
(2 rows)
|
||||
|
||||
DROP TABLE tbl;
|
||||
/*
|
||||
* 5. REINDEX
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDING(c3,c4));
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------------------------------------------------------------------------------------
|
||||
CREATE UNIQUE INDEX tbl_c1_c2_c3_c4_key ON tbl USING btree (c1, c2) INCLUDING (c3, c4)
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
REINDEX INDEX tbl_c1_c2_c3_c4_key;
|
||||
ERROR: relation "tbl_c1_c2_c3_c4_key" does not exist
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
ALTER TABLE tbl DROP COLUMN c1;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
indexdef
|
||||
----------
|
||||
(0 rows)
|
||||
|
||||
DROP TABLE tbl;
|
||||
/*
|
||||
* 7. Check various AMs. All but brtee must fail.
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 box, c4 box);
|
||||
CREATE INDEX on tbl USING brin(c1, c2) INCLUDING (c3, c4);
|
||||
ERROR: access method "brin" does not support included columns
|
||||
CREATE INDEX on tbl USING gist(c3) INCLUDING (c4);
|
||||
ERROR: access method "gist" does not support included columns
|
||||
CREATE INDEX on tbl USING spgist(c3) INCLUDING (c4);
|
||||
ERROR: access method "spgist" does not support included columns
|
||||
CREATE INDEX on tbl USING gin(c1, c2) INCLUDING (c3, c4);
|
||||
ERROR: access method "gin" does not support included columns
|
||||
CREATE INDEX on tbl USING hash(c1, c2) INCLUDING (c3, c4);
|
||||
WARNING: hash indexes are not WAL-logged and their use is discouraged
|
||||
ERROR: access method "hash" does not support included columns
|
||||
CREATE INDEX on tbl USING rtree(c1, c2) INCLUDING (c3, c4);
|
||||
NOTICE: substituting access method "gist" for obsolete method "rtree"
|
||||
ERROR: access method "gist" does not support included columns
|
||||
CREATE INDEX on tbl USING btree(c1, c2) INCLUDING (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) INCLUDING (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;
|
||||
ERROR: duplicate key value violates unique constraint "tbl_idx_unique"
|
||||
DETAIL: Key (c1, c2)=(1, 2) already exists.
|
||||
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) INCLUDING(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
|
||||
Table "public.tbl"
|
||||
Column | Type | Modifiers
|
||||
--------+---------+-----------
|
||||
c1 | bigint |
|
||||
c2 | integer |
|
||||
c3 | bigint |
|
||||
c4 | box |
|
||||
Indexes:
|
||||
"tbl_c1_c2_c3_c4_key" UNIQUE CONSTRAINT, btree (c1, c2) INCLUDING (c3, c4)
|
||||
|
||||
DROP TABLE tbl;
|
@ -55,7 +55,7 @@ test: copy copyselect copydml
|
||||
# ----------
|
||||
test: create_misc create_operator
|
||||
# These depend on the above two
|
||||
test: create_index create_view
|
||||
test: create_index create_view index_including
|
||||
|
||||
# ----------
|
||||
# Another group of parallel tests
|
||||
|
@ -61,6 +61,7 @@ test: copydml
|
||||
test: create_misc
|
||||
test: create_operator
|
||||
test: create_index
|
||||
test: index_including
|
||||
test: create_view
|
||||
test: create_aggregate
|
||||
test: create_function_3
|
||||
|
@ -721,6 +721,26 @@ INSERT INTO func_index_heap VALUES('ABCD', 'EF');
|
||||
-- but this shouldn't:
|
||||
INSERT INTO func_index_heap VALUES('QWERTY');
|
||||
|
||||
--
|
||||
-- Test unique index with included columns
|
||||
--
|
||||
CREATE TABLE covering_index_heap (f1 int, f2 int, f3 text);
|
||||
CREATE UNIQUE INDEX covering_index_index on covering_index_heap (f1,f2) INCLUDING(f3);
|
||||
|
||||
INSERT INTO covering_index_heap VALUES(1,1,'AAA');
|
||||
INSERT INTO covering_index_heap VALUES(1,2,'AAA');
|
||||
-- this should fail because of unique index on f1,f2:
|
||||
INSERT INTO covering_index_heap VALUES(1,2,'BBB');
|
||||
-- and this shouldn't:
|
||||
INSERT INTO covering_index_heap VALUES(1,4,'AAA');
|
||||
-- Try to build index on table that already contains data
|
||||
CREATE UNIQUE INDEX covering_pkey on covering_index_heap (f1,f2) INCLUDING(f3);
|
||||
-- Try to use existing covering index as primary key
|
||||
ALTER TABLE covering_index_heap ADD CONSTRAINT covering_pkey PRIMARY KEY USING INDEX
|
||||
covering_pkey;
|
||||
DROP TABLE covering_index_heap;
|
||||
|
||||
|
||||
--
|
||||
-- Also try building functional, expressional, and partial indexes on
|
||||
-- tables that already contain data.
|
||||
|
181
src/test/regress/sql/index_including.sql
Normal file
181
src/test/regress/sql/index_including.sql
Normal file
@ -0,0 +1,181 @@
|
||||
/*
|
||||
* 1.test CREATE INDEX
|
||||
*/
|
||||
-- Regular index with included columns
|
||||
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 INDEX tbl_idx ON tbl using btree(c1, c2) INCLUDING (c3,c4);
|
||||
-- must fail because of intersection of key and included columns
|
||||
CREATE INDEX tbl_idx ON tbl using btree(c1, c2) INCLUDING (c1,c3);
|
||||
DROP TABLE tbl;
|
||||
|
||||
-- Unique index and unique constraint
|
||||
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) INCLUDING (c3,c4);
|
||||
ALTER TABLE tbl add UNIQUE USING INDEX tbl_idx_unique;
|
||||
ALTER TABLE tbl add UNIQUE(c1, c2) INCLUDING (c3, c4);
|
||||
DROP TABLE tbl;
|
||||
|
||||
-- Unique index and unique constraint. Both must fail.
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 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) INCLUDING (c3,c4);
|
||||
ALTER TABLE tbl add UNIQUE(c1, c2) INCLUDING (c3, c4);
|
||||
DROP TABLE tbl;
|
||||
|
||||
-- PK constraint
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ALTER TABLE tbl add PRIMARY KEY(c1, c2) INCLUDING (c3, c4);
|
||||
DROP TABLE tbl;
|
||||
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 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) INCLUDING (c3,c4);
|
||||
ALTER TABLE tbl add PRIMARY KEY USING INDEX tbl_idx_unique;
|
||||
DROP TABLE tbl;
|
||||
-- PK constraint. Must fail.
|
||||
CREATE TABLE tbl (c1 int, c2 int, c3 int, c4 box);
|
||||
INSERT INTO tbl select 1, 2, 3*x, box('4,4,4,4') from generate_series(1,10) as x;
|
||||
ALTER TABLE tbl add PRIMARY KEY(c1, c2) INCLUDING (c3, c4);
|
||||
DROP TABLE tbl;
|
||||
|
||||
|
||||
/*
|
||||
* 2. Test CREATE TABLE with constraint
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box,
|
||||
CONSTRAINT covering UNIQUE(c1,c2) INCLUDING(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, conincluding 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) INCLUDING(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, conincluding 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 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,
|
||||
UNIQUE(c1,c2) INCLUDING(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, conincluding 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) INCLUDING(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, conincluding 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 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;
|
||||
|
||||
|
||||
/*
|
||||
* 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';
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
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) INCLUDING(c3,c4);
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
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) INCLUDING(c3,c4));
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
ALTER TABLE tbl DROP COLUMN c1;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
DROP TABLE tbl;
|
||||
|
||||
|
||||
/*
|
||||
* 4. CREATE INDEX CONCURRENTLY
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDING(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) INCLUDING (c3, c4);
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
DROP TABLE tbl;
|
||||
|
||||
|
||||
/*
|
||||
* 5. REINDEX
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 int, c4 box, UNIQUE(c1, c2) INCLUDING(c3,c4));
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
ALTER TABLE tbl DROP COLUMN c3;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
REINDEX INDEX tbl_c1_c2_c3_c4_key;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
ALTER TABLE tbl DROP COLUMN c1;
|
||||
select indexdef from pg_indexes where tablename='tbl';
|
||||
DROP TABLE tbl;
|
||||
|
||||
/*
|
||||
* 7. Check various AMs. All but brtee must fail.
|
||||
*/
|
||||
CREATE TABLE tbl (c1 int,c2 int, c3 box, c4 box);
|
||||
CREATE INDEX on tbl USING brin(c1, c2) INCLUDING (c3, c4);
|
||||
CREATE INDEX on tbl USING gist(c3) INCLUDING (c4);
|
||||
CREATE INDEX on tbl USING spgist(c3) INCLUDING (c4);
|
||||
CREATE INDEX on tbl USING gin(c1, c2) INCLUDING (c3, c4);
|
||||
CREATE INDEX on tbl USING hash(c1, c2) INCLUDING (c3, c4);
|
||||
CREATE INDEX on tbl USING rtree(c1, c2) INCLUDING (c3, c4);
|
||||
CREATE INDEX on tbl USING btree(c1, c2) INCLUDING (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) INCLUDING (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) INCLUDING(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;
|
||||
|
Reference in New Issue
Block a user