Allow users to create unique indexes

Users can now create unique indexes on partition columns
for hash and range distributed tables.
pull/385/head
Murat Tuncer 2016-03-16 15:13:36 +02:00
parent 833048451c
commit e74decf8b4
4 changed files with 233 additions and 33 deletions

View File

@ -572,19 +572,60 @@ ErrorIfUnsupportedIndexStmt(IndexStmt *createIndexStatement)
"currently unsupported")));
}
if (createIndexStatement->unique)
{
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("creating unique indexes on distributed tables is "
"currently unsupported")));
}
if (createIndexStatement->concurrent)
{
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("creating indexes concurrently on distributed tables is "
"currently unsupported")));
}
if (createIndexStatement->unique)
{
RangeVar *relation = createIndexStatement->relation;
bool missingOk = false;
/* caller uses ShareLock for non-concurrent indexes, use the same lock here */
LOCKMODE lockMode = ShareLock;
Oid relationId = RangeVarGetRelid(relation, lockMode, missingOk);
Var *partitionKey = PartitionKey(relationId);
char partitionMethod = PartitionMethod(relationId);
List *indexParameterList = NIL;
ListCell *indexParameterCell = NULL;
bool indexContainsPartitionColumn = false;
if (partitionMethod == DISTRIBUTE_BY_APPEND)
{
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("creating unique indexes on append-partitioned tables "
"is currently unsupported")));
}
indexParameterList = createIndexStatement->indexParams;
foreach(indexParameterCell, indexParameterList)
{
IndexElem *indexElement = (IndexElem *) lfirst(indexParameterCell);
char *columnName = indexElement->name;
AttrNumber attributeNumber = InvalidAttrNumber;
/* column name is null for index expressions, skip it */
if (columnName == NULL)
{
continue;
}
attributeNumber = get_attnum(relationId, columnName);
if (attributeNumber == partitionKey->varattno)
{
indexContainsPartitionColumn = true;
}
}
if (!indexContainsPartitionColumn)
{
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("creating unique indexes on non-partition "
"columns is currently unsupported")));
}
}
}

View File

@ -3,6 +3,61 @@
--
-- Check that we can run CREATE INDEX and DROP INDEX statements on distributed
-- tables.
--
-- CREATE TEST TABLES
--
ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 102080;
CREATE TABLE index_test_range(a int, b int, c int);
SELECT master_create_distributed_table('index_test_range', 'a', 'range');
master_create_distributed_table
---------------------------------
(1 row)
SELECT master_create_empty_shard('index_test_range');
master_create_empty_shard
---------------------------
102080
(1 row)
SELECT master_create_empty_shard('index_test_range');
master_create_empty_shard
---------------------------
102081
(1 row)
CREATE TABLE index_test_hash(a int, b int, c int);
SELECT master_create_distributed_table('index_test_hash', 'a', 'hash');
master_create_distributed_table
---------------------------------
(1 row)
SELECT master_create_worker_shards('index_test_hash', 8, 2);
master_create_worker_shards
-----------------------------
(1 row)
CREATE TABLE index_test_append(a int, b int, c int);
SELECT master_create_distributed_table('index_test_append', 'a', 'append');
master_create_distributed_table
---------------------------------
(1 row)
SELECT master_create_empty_shard('index_test_append');
master_create_empty_shard
---------------------------
102090
(1 row)
SELECT master_create_empty_shard('index_test_append');
master_create_empty_shard
---------------------------
102091
(1 row)
--
-- CREATE INDEX
--
@ -13,18 +68,26 @@ CREATE INDEX lineitem_partial_index ON lineitem (l_shipdate)
WHERE l_shipdate < '1995-01-01';
SET client_min_messages = ERROR; -- avoid version dependant warning about WAL
CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey);
CREATE UNIQUE INDEX index_test_range_index_a ON index_test_range(a);
CREATE UNIQUE INDEX index_test_range_index_a_b ON index_test_range(a,b);
CREATE UNIQUE INDEX index_test_hash_index_a ON index_test_hash(a);
CREATE UNIQUE INDEX index_test_hash_index_a_b ON index_test_hash(a,b);
RESET client_min_messages;
-- Verify that all indexes got created on the master node and one of the workers
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+------------------------------+------------+------------------------------------------------------------------------------------------------------------------
public | lineitem | lineitem_orderkey_hash_index | | CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey)
public | lineitem | lineitem_orderkey_index | | CREATE INDEX lineitem_orderkey_index ON lineitem USING btree (l_orderkey)
public | lineitem | lineitem_partial_index | | CREATE INDEX lineitem_partial_index ON lineitem USING btree (l_shipdate) WHERE (l_shipdate < '01-01-1995'::date)
public | lineitem | lineitem_partkey_desc_index | | CREATE INDEX lineitem_partkey_desc_index ON lineitem USING btree (l_partkey DESC)
public | lineitem | lineitem_pkey | | CREATE UNIQUE INDEX lineitem_pkey ON lineitem USING btree (l_orderkey, l_linenumber)
public | lineitem | lineitem_time_index | | CREATE INDEX lineitem_time_index ON lineitem USING btree (l_shipdate)
(6 rows)
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' or tablename like 'index_test_%' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+------------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------------
public | index_test_hash | index_test_hash_index_a | | CREATE UNIQUE INDEX index_test_hash_index_a ON index_test_hash USING btree (a)
public | index_test_hash | index_test_hash_index_a_b | | CREATE UNIQUE INDEX index_test_hash_index_a_b ON index_test_hash USING btree (a, b)
public | index_test_range | index_test_range_index_a | | CREATE UNIQUE INDEX index_test_range_index_a ON index_test_range USING btree (a)
public | index_test_range | index_test_range_index_a_b | | CREATE UNIQUE INDEX index_test_range_index_a_b ON index_test_range USING btree (a, b)
public | lineitem | lineitem_orderkey_hash_index | | CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey)
public | lineitem | lineitem_orderkey_index | | CREATE INDEX lineitem_orderkey_index ON lineitem USING btree (l_orderkey)
public | lineitem | lineitem_partial_index | | CREATE INDEX lineitem_partial_index ON lineitem USING btree (l_shipdate) WHERE (l_shipdate < '01-01-1995'::date)
public | lineitem | lineitem_partkey_desc_index | | CREATE INDEX lineitem_partkey_desc_index ON lineitem USING btree (l_partkey DESC)
public | lineitem | lineitem_pkey | | CREATE UNIQUE INDEX lineitem_pkey ON lineitem USING btree (l_orderkey, l_linenumber)
public | lineitem | lineitem_time_index | | CREATE INDEX lineitem_time_index ON lineitem USING btree (l_shipdate)
(10 rows)
\c - - - :worker_1_port
SELECT count(*) FROM pg_indexes WHERE tablename = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1);
@ -33,14 +96,42 @@ SELECT count(*) FROM pg_indexes WHERE tablename = (SELECT relname FROM pg_class
6
(1 row)
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_hash%';
count
-------
16
(1 row)
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_range%';
count
-------
4
(1 row)
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_append%';
count
-------
0
(1 row)
\c - - - :master_port
-- Verify that we error out on unsupported statement types
CREATE INDEX CONCURRENTLY try_index ON lineitem (l_orderkey);
ERROR: creating indexes concurrently on distributed tables is currently unsupported
CREATE UNIQUE INDEX try_index ON lineitem (l_orderkey);
ERROR: creating unique indexes on distributed tables is currently unsupported
ERROR: creating unique indexes on append-partitioned tables is currently unsupported
CREATE INDEX try_index ON lineitem (l_orderkey) TABLESPACE newtablespace;
ERROR: specifying tablespaces with CREATE INDEX statements is currently unsupported
CREATE UNIQUE INDEX try_unique_range_index ON index_test_range(b);
ERROR: creating unique indexes on non-partition columns is currently unsupported
CREATE UNIQUE INDEX try_unique_hash_index ON index_test_hash(b);
ERROR: creating unique indexes on non-partition columns is currently unsupported
CREATE UNIQUE INDEX try_unique_append_index ON index_test_append(b);
ERROR: creating unique indexes on append-partitioned tables is currently unsupported
CREATE UNIQUE INDEX try_unique_append_index ON index_test_append(a);
ERROR: creating unique indexes on append-partitioned tables is currently unsupported
CREATE UNIQUE INDEX try_unique_append_index_a_b ON index_test_append(a,b);
ERROR: creating unique indexes on append-partitioned tables is currently unsupported
-- Verify that we error out in case of postgres errors on supported statement
-- types.
CREATE INDEX lineitem_orderkey_index ON lineitem (l_orderkey);
@ -56,16 +147,20 @@ WARNING: could not receive query results from localhost:57638
DETAIL: Client error: column "non_existent_column" does not exist
ERROR: could not execute DDL command on worker node shards
-- Verify that none of failed indexes got created on the master node
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+------------------------------+------------+------------------------------------------------------------------------------------------------------------------
public | lineitem | lineitem_orderkey_hash_index | | CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey)
public | lineitem | lineitem_orderkey_index | | CREATE INDEX lineitem_orderkey_index ON lineitem USING btree (l_orderkey)
public | lineitem | lineitem_partial_index | | CREATE INDEX lineitem_partial_index ON lineitem USING btree (l_shipdate) WHERE (l_shipdate < '01-01-1995'::date)
public | lineitem | lineitem_partkey_desc_index | | CREATE INDEX lineitem_partkey_desc_index ON lineitem USING btree (l_partkey DESC)
public | lineitem | lineitem_pkey | | CREATE UNIQUE INDEX lineitem_pkey ON lineitem USING btree (l_orderkey, l_linenumber)
public | lineitem | lineitem_time_index | | CREATE INDEX lineitem_time_index ON lineitem USING btree (l_shipdate)
(6 rows)
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' or tablename like 'index_test_%' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+------------------+------------------------------+------------+------------------------------------------------------------------------------------------------------------------
public | index_test_hash | index_test_hash_index_a | | CREATE UNIQUE INDEX index_test_hash_index_a ON index_test_hash USING btree (a)
public | index_test_hash | index_test_hash_index_a_b | | CREATE UNIQUE INDEX index_test_hash_index_a_b ON index_test_hash USING btree (a, b)
public | index_test_range | index_test_range_index_a | | CREATE UNIQUE INDEX index_test_range_index_a ON index_test_range USING btree (a)
public | index_test_range | index_test_range_index_a_b | | CREATE UNIQUE INDEX index_test_range_index_a_b ON index_test_range USING btree (a, b)
public | lineitem | lineitem_orderkey_hash_index | | CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey)
public | lineitem | lineitem_orderkey_index | | CREATE INDEX lineitem_orderkey_index ON lineitem USING btree (l_orderkey)
public | lineitem | lineitem_partial_index | | CREATE INDEX lineitem_partial_index ON lineitem USING btree (l_shipdate) WHERE (l_shipdate < '01-01-1995'::date)
public | lineitem | lineitem_partkey_desc_index | | CREATE INDEX lineitem_partkey_desc_index ON lineitem USING btree (l_partkey DESC)
public | lineitem | lineitem_pkey | | CREATE UNIQUE INDEX lineitem_pkey ON lineitem USING btree (l_orderkey, l_linenumber)
public | lineitem | lineitem_time_index | | CREATE INDEX lineitem_time_index ON lineitem USING btree (l_shipdate)
(10 rows)
--
-- DROP INDEX
@ -89,6 +184,10 @@ NOTICE: index "non_existent_index" does not exist, skipping
DROP INDEX IF EXISTS lineitem_orderkey_hash_index;
DROP INDEX lineitem_orderkey_hash_index;
ERROR: index "lineitem_orderkey_hash_index" does not exist
DROP INDEX index_test_range_index_a;
DROP INDEX index_test_range_index_a_b;
DROP INDEX index_test_hash_index_a;
DROP INDEX index_test_hash_index_a_b;
-- Verify that all the indexes are dropped from the master and one worker node.
-- As there's a primary key, so exclude those from this check.
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';
@ -96,10 +195,24 @@ SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (
----------+------------
(0 rows)
SELECT * FROM pg_indexes WHERE tablename LIKE 'index_test_%' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+-----------+------------+----------
(0 rows)
\c - - - :worker_1_port
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';;
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';
indrelid | indexrelid
----------+------------
(0 rows)
SELECT * FROM pg_indexes WHERE tablename LIKE 'index_test_%' ORDER BY indexname;
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+-----------+------------+----------
(0 rows)
\c - - - :master_port
-- Drop created tables
DROP TABLE index_test_range;
DROP TABLE index_test_hash;
DROP TABLE index_test_append;

View File

@ -74,7 +74,8 @@ test: multi_stage_large_records multi_master_delete_protocol
# ----------
# Tests around DDL statements run on distributed tables
# ----------
test: multi_index_statements multi_alter_table_statements
test: multi_index_statements
test: multi_alter_table_statements
# ----------
# multi_create_schema tests creation, staging and querying of a table in a new

View File

@ -5,6 +5,26 @@
-- Check that we can run CREATE INDEX and DROP INDEX statements on distributed
-- tables.
--
-- CREATE TEST TABLES
--
ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 102080;
CREATE TABLE index_test_range(a int, b int, c int);
SELECT master_create_distributed_table('index_test_range', 'a', 'range');
SELECT master_create_empty_shard('index_test_range');
SELECT master_create_empty_shard('index_test_range');
CREATE TABLE index_test_hash(a int, b int, c int);
SELECT master_create_distributed_table('index_test_hash', 'a', 'hash');
SELECT master_create_worker_shards('index_test_hash', 8, 2);
CREATE TABLE index_test_append(a int, b int, c int);
SELECT master_create_distributed_table('index_test_append', 'a', 'append');
SELECT master_create_empty_shard('index_test_append');
SELECT master_create_empty_shard('index_test_append');
--
-- CREATE INDEX
--
@ -20,12 +40,19 @@ CREATE INDEX lineitem_partial_index ON lineitem (l_shipdate)
SET client_min_messages = ERROR; -- avoid version dependant warning about WAL
CREATE INDEX lineitem_orderkey_hash_index ON lineitem USING hash (l_partkey);
CREATE UNIQUE INDEX index_test_range_index_a ON index_test_range(a);
CREATE UNIQUE INDEX index_test_range_index_a_b ON index_test_range(a,b);
CREATE UNIQUE INDEX index_test_hash_index_a ON index_test_hash(a);
CREATE UNIQUE INDEX index_test_hash_index_a_b ON index_test_hash(a,b);
RESET client_min_messages;
-- Verify that all indexes got created on the master node and one of the workers
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' ORDER BY indexname;
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' or tablename like 'index_test_%' ORDER BY indexname;
\c - - - :worker_1_port
SELECT count(*) FROM pg_indexes WHERE tablename = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1);
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_hash%';
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_range%';
SELECT count(*) FROM pg_indexes WHERE tablename LIKE 'index_test_append%';
\c - - - :master_port
-- Verify that we error out on unsupported statement types
@ -34,6 +61,12 @@ CREATE INDEX CONCURRENTLY try_index ON lineitem (l_orderkey);
CREATE UNIQUE INDEX try_index ON lineitem (l_orderkey);
CREATE INDEX try_index ON lineitem (l_orderkey) TABLESPACE newtablespace;
CREATE UNIQUE INDEX try_unique_range_index ON index_test_range(b);
CREATE UNIQUE INDEX try_unique_hash_index ON index_test_hash(b);
CREATE UNIQUE INDEX try_unique_append_index ON index_test_append(b);
CREATE UNIQUE INDEX try_unique_append_index ON index_test_append(a);
CREATE UNIQUE INDEX try_unique_append_index_a_b ON index_test_append(a,b);
-- Verify that we error out in case of postgres errors on supported statement
-- types.
@ -42,7 +75,7 @@ CREATE INDEX try_index ON lineitem USING gist (l_orderkey);
CREATE INDEX try_index ON lineitem (non_existent_column);
-- Verify that none of failed indexes got created on the master node
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' ORDER BY indexname;
SELECT * FROM pg_indexes WHERE tablename = 'lineitem' or tablename like 'index_test_%' ORDER BY indexname;
--
-- DROP INDEX
@ -67,9 +100,21 @@ DROP INDEX IF EXISTS non_existent_index;
DROP INDEX IF EXISTS lineitem_orderkey_hash_index;
DROP INDEX lineitem_orderkey_hash_index;
DROP INDEX index_test_range_index_a;
DROP INDEX index_test_range_index_a_b;
DROP INDEX index_test_hash_index_a;
DROP INDEX index_test_hash_index_a_b;
-- Verify that all the indexes are dropped from the master and one worker node.
-- As there's a primary key, so exclude those from this check.
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';
SELECT * FROM pg_indexes WHERE tablename LIKE 'index_test_%' ORDER BY indexname;
\c - - - :worker_1_port
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';;
SELECT indrelid::regclass, indexrelid::regclass FROM pg_index WHERE indrelid = (SELECT relname FROM pg_class WHERE relname LIKE 'lineitem%' ORDER BY relname LIMIT 1)::regclass AND NOT indisprimary AND indexrelid::regclass::text NOT LIKE 'lineitem_time_index%';
SELECT * FROM pg_indexes WHERE tablename LIKE 'index_test_%' ORDER BY indexname;
\c - - - :master_port
-- Drop created tables
DROP TABLE index_test_range;
DROP TABLE index_test_hash;
DROP TABLE index_test_append;