From ab5f97861be8b5e81069c224dfb5b812ae4ba013 Mon Sep 17 00:00:00 2001 From: Burak Yucesoy Date: Wed, 2 Aug 2017 17:35:03 +0300 Subject: [PATCH] Add regression tests for distributed partitioned tables --- .../regress/expected/multi_partitioning.out | 937 ++++++++++++++++++ .../regress/expected/multi_partitioning_0.out | 934 +++++++++++++++++ src/test/regress/multi_schedule | 11 +- src/test/regress/sql/multi_partitioning.sql | 665 +++++++++++++ 4 files changed, 2542 insertions(+), 5 deletions(-) create mode 100644 src/test/regress/expected/multi_partitioning.out create mode 100644 src/test/regress/expected/multi_partitioning_0.out create mode 100644 src/test/regress/sql/multi_partitioning.sql diff --git a/src/test/regress/expected/multi_partitioning.out b/src/test/regress/expected/multi_partitioning.out new file mode 100644 index 000000000..272312f2a --- /dev/null +++ b/src/test/regress/expected/multi_partitioning.out @@ -0,0 +1,937 @@ +-- +-- Distributed Partitioned Table Tests +-- +ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1660000; +SET citus.shard_count TO 4; +SET citus.shard_replication_factor TO 1; +-- +-- Distributed Partitioned Table Creation Tests +-- +-- 1-) Distributing partitioned table +-- create partitioned table +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); + +-- create its partitions +CREATE TABLE partitioning_test_2009 PARTITION OF partitioning_test FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +CREATE TABLE partitioning_test_2010 PARTITION OF partitioning_test FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +-- load some data and distribute tables +INSERT INTO partitioning_test VALUES (1, '2009-06-06'); +INSERT INTO partitioning_test VALUES (2, '2010-07-07'); +INSERT INTO partitioning_test_2009 VALUES (3, '2009-09-09'); +INSERT INTO partitioning_test_2010 VALUES (4, '2010-03-03'); +-- distribute partitioned table +SELECT create_distributed_table('partitioning_test', 'id'); +NOTICE: Copying data from local table... +NOTICE: Copying data from local table... + create_distributed_table +-------------------------- + +(1 row) + +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + id | time +----+------------ + 1 | 06-06-2009 + 2 | 07-07-2010 + 3 | 09-09-2009 + 4 | 03-03-2010 +(4 rows) + +-- see partitioned table and its partitions are distributed +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +ORDER BY 1; + logicalrelid +------------------------ + partitioning_test + partitioning_test_2009 + partitioning_test_2010 +(3 rows) + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +GROUP BY + logicalrelid +ORDER BY + 1,2; + logicalrelid | count +------------------------+------- + partitioning_test | 4 + partitioning_test_2009 | 4 + partitioning_test_2010 | 4 +(3 rows) + +-- 2-) Creating partition of a distributed table +CREATE TABLE partitioning_test_2011 PARTITION OF partitioning_test FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); +-- new partition is automatically distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +ORDER BY 1; + logicalrelid +------------------------ + partitioning_test + partitioning_test_2011 +(2 rows) + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +GROUP BY + logicalrelid +ORDER BY + 1,2; + logicalrelid | count +------------------------+------- + partitioning_test | 4 + partitioning_test_2011 | 4 +(2 rows) + +-- 3-) Attaching non distributed table to a distributed table +CREATE TABLE partitioning_test_2012(id int, time date); +-- load some data +INSERT INTO partitioning_test_2012 VALUES (5, '2012-06-06'); +INSERT INTO partitioning_test_2012 VALUES (6, '2012-07-07'); +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2012 FOR VALUES FROM ('2012-01-01') TO ('2013-01-01'); +NOTICE: Copying data from local table... +-- attached partition is distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +ORDER BY 1; + logicalrelid +------------------------ + partitioning_test + partitioning_test_2012 +(2 rows) + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +GROUP BY + logicalrelid +ORDER BY + 1,2; + logicalrelid | count +------------------------+------- + partitioning_test | 4 + partitioning_test_2012 | 4 +(2 rows) + +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + id | time +----+------------ + 1 | 06-06-2009 + 2 | 07-07-2010 + 3 | 09-09-2009 + 4 | 03-03-2010 + 5 | 06-06-2012 + 6 | 07-07-2012 +(6 rows) + +-- 4-) Attaching distributed table to distributed table +CREATE TABLE partitioning_test_2013(id int, time date); +SELECT create_distributed_table('partitioning_test_2013', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +-- load some data +INSERT INTO partitioning_test_2013 VALUES (7, '2013-06-06'); +INSERT INTO partitioning_test_2013 VALUES (8, '2013-07-07'); +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2013 FOR VALUES FROM ('2013-01-01') TO ('2014-01-01'); +NOTICE: using one-phase commit for distributed DDL commands +HINT: You can enable two-phase commit for extra safety with: SET citus.multi_shard_commit_protocol TO '2pc' +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + id | time +----+------------ + 1 | 06-06-2009 + 2 | 07-07-2010 + 3 | 09-09-2009 + 4 | 03-03-2010 + 5 | 06-06-2012 + 6 | 07-07-2012 + 7 | 06-06-2013 + 8 | 07-07-2013 +(8 rows) + +-- 5-) Failure cases while creating distributed partitioned tables +-- cannot distribute a partition if its parent is not distributed +CREATE TABLE partitioning_test_failure(id int, time date) PARTITION BY RANGE (time); +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); +ERROR: cannot distribute relation "partitioning_test_failure_2009" which is partition of "partitioning_test_failure" +DETAIL: Citus does not support distributing partitions if their parent is not distributed table. +HINT: Distribute the partitioned table "partitioning_test_failure" instead. +-- only hash distributed tables can have partitions +SELECT create_distributed_table('partitioning_test_failure', 'id', 'append'); +ERROR: distributing partitioned tables in only supported for hash-distributed tables +SELECT create_distributed_table('partitioning_test_failure', 'id', 'range'); +ERROR: distributing partitioned tables in only supported for hash-distributed tables +SELECT create_reference_table('partitioning_test_failure'); +ERROR: distributing partitioned tables in only supported for hash-distributed tables +-- replication factor > 1 is not allowed in distributed partitioned tables +SET citus.shard_replication_factor TO 2; +SELECT create_distributed_table('partitioning_test_failure', 'id'); +ERROR: distributing partitioned tables with replication factor greater than 1 is not supported +SET citus.shard_replication_factor TO 1; +-- non-distributed tables cannot have distributed partitions; +DROP TABLE partitioning_test_failure_2009; +CREATE TABLE partitioning_test_failure_2009(id int, time date); +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +ALTER TABLE partitioning_test_failure ATTACH PARTITION partitioning_test_failure_2009 FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +ERROR: non-distributed tables cannot have distributed partitions +HINT: Distribute the partitioned table "partitioning_test_failure_2009" instead +-- multi-level partitioning is not allowed +DROP TABLE partitioning_test_failure_2009; +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); +SELECT create_distributed_table('partitioning_test_failure', 'id'); +ERROR: distributing multi-level partitioned tables is not supported +DETAIL: Relation "partitioning_test_failure_2009" is partitioned table itself and it is also partition of relation "partitioning_test_failure". +-- multi-level partitioning is not allowed in different order +DROP TABLE partitioning_test_failure_2009; +SELECT create_distributed_table('partitioning_test_failure', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); +ERROR: distributing multi-level partitioned tables is not supported +DETAIL: Relation "partitioning_test_failure_2009" is partitioned table itself and it is also partition of relation "partitioning_test_failure". +-- +-- DMLs in distributed partitioned tables +-- +-- test COPY +-- COPY data to partitioned table +COPY partitioning_test FROM STDIN WITH CSV; +-- COPY data to partition directly +COPY partitioning_test_2009 FROM STDIN WITH CSV; +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 9 ORDER BY 1; + id | time +----+------------ + 9 | 01-01-2009 + 10 | 01-01-2010 + 11 | 01-01-2011 + 12 | 01-01-2012 + 13 | 01-02-2009 + 14 | 01-03-2009 +(6 rows) + +-- test INSERT +-- INSERT INTO the partitioned table +INSERT INTO partitioning_test VALUES(15, '2009-02-01'); +INSERT INTO partitioning_test VALUES(16, '2010-02-01'); +INSERT INTO partitioning_test VALUES(17, '2011-02-01'); +INSERT INTO partitioning_test VALUES(18, '2012-02-01'); +-- INSERT INTO the partitions directly table +INSERT INTO partitioning_test VALUES(19, '2009-02-02'); +INSERT INTO partitioning_test VALUES(20, '2010-02-02'); +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 15 ORDER BY 1; + id | time +----+------------ + 15 | 02-01-2009 + 16 | 02-01-2010 + 17 | 02-01-2011 + 18 | 02-01-2012 + 19 | 02-02-2009 + 20 | 02-02-2010 +(6 rows) + +-- test INSERT/SELECT +-- INSERT/SELECT from partition to partitioned table +INSERT INTO partitioning_test SELECT * FROM partitioning_test_2011; +-- INSERT/SELECT from partitioned table to partition +INSERT INTO partitioning_test_2012 SELECT * FROM partitioning_test WHERE time >= '2012-01-01' AND time < '2013-01-01'; +-- see the data is loaded to shards (rows in the given range should be duplicated) +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2013-01-01' ORDER BY 1; + id | time +----+------------ + 5 | 06-06-2012 + 5 | 06-06-2012 + 6 | 07-07-2012 + 6 | 07-07-2012 + 11 | 01-01-2011 + 11 | 01-01-2011 + 12 | 01-01-2012 + 12 | 01-01-2012 + 17 | 02-01-2011 + 17 | 02-01-2011 + 18 | 02-01-2012 + 18 | 02-01-2012 +(12 rows) + +-- test UPDATE +-- UPDATE partitioned table +UPDATE partitioning_test SET time = '2013-07-07' WHERE id = 7; +-- UPDATE partition directly +UPDATE partitioning_test_2013 SET time = '2013-08-08' WHERE id = 8; +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 7 OR id = 8 ORDER BY 1; + id | time +----+------------ + 7 | 07-07-2013 + 8 | 08-08-2013 +(2 rows) + +-- UPDATE that tries to move a row to a non-existing partition (this should fail) +UPDATE partitioning_test SET time = '2020-07-07' WHERE id = 7; +ERROR: new row for relation "partitioning_test_2013_1660021" violates partition constraint +DETAIL: Failing row contains (7, 2020-07-07). +CONTEXT: while executing command on localhost:57638 +-- UPDATE with subqueries on partitioned table +UPDATE + partitioning_test +SET + time = time + INTERVAL '1 day' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 1); +-- UPDATE with subqueries on partition +UPDATE + partitioning_test_2009 +SET + time = time + INTERVAL '1 month' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 2); +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 1 OR id = 2 ORDER BY 1; + id | time +----+------------ + 1 | 06-07-2009 + 2 | 07-07-2010 +(2 rows) + +-- test DELETE +-- DELETE from partitioned table +DELETE FROM partitioning_test WHERE id = 9; +-- DELETE from partition directly +DELETE FROM partitioning_test_2010 WHERE id = 10; +-- see the data is deleted +SELECT * FROM partitioning_test WHERE id = 9 OR id = 10 ORDER BY 1; + id | time +----+------ +(0 rows) + +-- test master_modify_multiple_shards +-- master_modify_multiple_shards on partitioned table +SELECT master_modify_multiple_shards('UPDATE partitioning_test SET time = time + INTERVAL ''1 day'''); + master_modify_multiple_shards +------------------------------- + 24 +(1 row) + +-- see rows are UPDATED +SELECT * FROM partitioning_test ORDER BY 1; + id | time +----+------------ + 1 | 06-08-2009 + 2 | 07-08-2010 + 3 | 09-10-2009 + 4 | 03-04-2010 + 5 | 06-07-2012 + 5 | 06-07-2012 + 6 | 07-08-2012 + 6 | 07-08-2012 + 7 | 07-08-2013 + 8 | 08-09-2013 + 11 | 01-02-2011 + 11 | 01-02-2011 + 12 | 01-02-2012 + 12 | 01-02-2012 + 13 | 01-03-2009 + 14 | 01-04-2009 + 15 | 02-02-2009 + 16 | 02-02-2010 + 17 | 02-02-2011 + 17 | 02-02-2011 + 18 | 02-02-2012 + 18 | 02-02-2012 + 19 | 02-03-2009 + 20 | 02-03-2010 +(24 rows) + +-- master_modify_multiple_shards on partition directly +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''1 day'''); + master_modify_multiple_shards +------------------------------- + 6 +(1 row) + +-- see rows are UPDATED +SELECT * FROM partitioning_test_2009 ORDER BY 1; + id | time +----+------------ + 1 | 06-09-2009 + 3 | 09-11-2009 + 13 | 01-04-2009 + 14 | 01-05-2009 + 15 | 02-03-2009 + 19 | 02-04-2009 +(6 rows) + +-- test master_modify_multiple_shards which fails in workers (updated value is outside of partition bounds) +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''6 month'''); +ERROR: new row for relation "partitioning_test_2009_1660005" violates partition constraint +DETAIL: Failing row contains (3, 2010-03-11). +CONTEXT: while executing command on localhost:57638 +-- +-- DDL in distributed partitioned tables +-- +-- test CREATE INDEX +-- CREATE INDEX on partitioned table - this will error out +CREATE INDEX partitioning_index ON partitioning_test(id); +ERROR: cannot create index on partitioned table "partitioning_test" +-- CREATE INDEX on partition +CREATE INDEX partitioning_2009_index ON partitioning_test_2009(id); +-- CREATE INDEX CONCURRENTLY on partition +CREATE INDEX CONCURRENTLY partitioned_2010_index ON partitioning_test_2010(id); +-- see index is created +SELECT tablename, indexname FROM pg_indexes WHERE tablename LIKE 'partitioning_test%' ORDER BY indexname; + tablename | indexname +------------------------+------------------------- + partitioning_test_2010 | partitioned_2010_index + partitioning_test_2009 | partitioning_2009_index +(2 rows) + +-- test add COLUMN +-- add COLUMN to partitioned table +ALTER TABLE partitioning_test ADD new_column int; +-- add COLUMN to partition - this will error out +ALTER TABLE partitioning_test_2010 ADD new_column_2 int; +ERROR: cannot add column to a partition +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; + name | type +------------+--------- + id | integer + new_column | integer + time | date +(3 rows) + +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test_2010'::regclass ORDER BY 1; + name | type +------------+--------- + id | integer + new_column | integer + time | date +(3 rows) + +-- test add PRIMARY KEY +-- add PRIMARY KEY to partitioned table - this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_primary PRIMARY KEY (id); +ERROR: primary key constraints are not supported on partitioned tables +LINE 1: ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_pr... + ^ +-- ADD PRIMARY KEY to partition +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_2009_primary PRIMARY KEY (id); +-- see PRIMARY KEY is created +SELECT + table_name, + constraint_name, + constraint_type +FROM + information_schema.table_constraints +WHERE + table_name = 'partitioning_test_2009' AND + constraint_name = 'partitioning_2009_primary'; + table_name | constraint_name | constraint_type +------------------------+---------------------------+----------------- + partitioning_test_2009 | partitioning_2009_primary | PRIMARY KEY +(1 row) + +-- test ADD FOREIGN CONSTRAINT +-- add FOREIGN CONSTRAINT to partitioned table -- this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id); +ERROR: foreign key constraints are not supported on partitioned tables +LINE 1: ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_fo... + ^ +-- add FOREIGN CONSTRAINT to partition +INSERT INTO partitioning_test_2009 VALUES (5, '2009-06-06'); +INSERT INTO partitioning_test_2009 VALUES (6, '2009-07-07'); +INSERT INTO partitioning_test_2009 VALUES(12, '2009-02-01'); +INSERT INTO partitioning_test_2009 VALUES(18, '2009-02-01'); +ALTER TABLE partitioning_test_2012 ADD CONSTRAINT partitioning_2012_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id) ON DELETE CASCADE; +-- see FOREIGN KEY is created +SELECT "Constraint" FROM table_fkeys WHERE relid = 'partitioning_test_2012'::regclass ORDER BY 1; + Constraint +--------------------------- + partitioning_2012_foreign +(1 row) + +-- test ON DELETE CASCADE works +DELETE FROM partitioning_test_2009 WHERE id = 5; +-- see that element is deleted from both partitions +SELECT * FROM partitioning_test_2009 WHERE id = 5 ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +SELECT * FROM partitioning_test_2012 WHERE id = 5 ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- test DETACH partition +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; +-- see DETACHed partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2009-01-01' AND time < '2010-01-01' ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- +-- Transaction tests +-- +-- DDL in transaction +BEGIN; +ALTER TABLE partitioning_test ADD newer_column int; +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; + name | type +--------------+--------- + id | integer + new_column | integer + newer_column | integer + time | date +(4 rows) + +ROLLBACK; +-- see rollback is successful +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; + name | type +------------+--------- + id | integer + new_column | integer + time | date +(3 rows) + +-- COPY in transaction +BEGIN; +COPY partitioning_test FROM STDIN WITH CSV; +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 22 ORDER BY 1; + id | time | new_column +----+------------+------------ + 22 | 01-01-2010 | 22 +(1 row) + +SELECT * FROM partitioning_test WHERE id = 23 ORDER BY 1; + id | time | new_column +----+------------+------------ + 23 | 01-01-2011 | 23 +(1 row) + +SELECT * FROM partitioning_test WHERE id = 24 ORDER BY 1; + id | time | new_column +----+------------+------------ + 24 | 01-01-2013 | 24 +(1 row) + +ROLLBACK; +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id >= 22 ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- DML in transaction +BEGIN; +-- INSERT in transaction +INSERT INTO partitioning_test VALUES(25, '2010-02-02'); +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + id | time | new_column +----+------------+------------ + 25 | 02-02-2010 | +(1 row) + +-- INSERT/SELECT in transaction +INSERT INTO partitioning_test SELECT * FROM partitioning_test WHERE id = 25; +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + id | time | new_column +----+------------+------------ + 25 | 02-02-2010 | + 25 | 02-02-2010 | +(2 rows) + +-- UPDATE in transaction +UPDATE partitioning_test SET time = '2010-10-10' WHERE id = 25; +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + id | time | new_column +----+------------+------------ + 25 | 10-10-2010 | + 25 | 10-10-2010 | +(2 rows) + +-- perform operations on partition and partioned tables together +INSERT INTO partitioning_test VALUES(26, '2010-02-02', 26); +INSERT INTO partitioning_test_2010 VALUES(26, '2010-02-02', 26); +COPY partitioning_test FROM STDIN WITH CSV; +COPY partitioning_test_2010 FROM STDIN WITH CSV; +-- see the data is loaded to shards (we should see 4 rows with same content) +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; + id | time | new_column +----+------------+------------ + 26 | 02-02-2010 | 26 + 26 | 02-02-2010 | 26 + 26 | 02-02-2010 | 26 + 26 | 02-02-2010 | 26 +(4 rows) + +ROLLBACK; +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- DETACH and DROP in a transaction +BEGIN; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; +DROP TABLE partitioning_test_2011; +COMMIT; +-- see DROPed partitions content is not accessible +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2012-01-01' ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- +-- Misc tests +-- +-- test TRUNCATE +-- test TRUNCATE partition +TRUNCATE partitioning_test_2012; +-- see partition is TRUNCATEd +SELECT * FROM partitioning_test_2012 ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- test TRUNCATE partitioned table +TRUNCATE partitioning_test; +-- see partitioned table is TRUNCATEd +SELECT * FROM partitioning_test ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- test DROP +-- test DROP partition +INSERT INTO partitioning_test_2010 VALUES(27, '2010-02-01'); +DROP TABLE partitioning_test_2010; +-- see DROPped partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2010-01-01' AND time < '2011-01-01' ORDER BY 1; + id | time | new_column +----+------+------------ +(0 rows) + +-- test DROP partitioned table +DROP TABLE partitioning_test; +-- dropping the parent should CASCADE to the children as well +SELECT table_name FROM information_schema.tables WHERE table_name LIKE 'partitioning_test%' ORDER BY 1; + table_name +--------------------------- + partitioning_test_2009 + partitioning_test_failure +(2 rows) + +-- test distributing partitioned table colocated with non-partitioned table +CREATE TABLE partitioned_users_table (user_id int, time timestamp, value_1 int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); +CREATE TABLE partitioned_events_table (user_id int, time timestamp, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); +SELECT create_distributed_table('partitioned_users_table', 'user_id', colocate_with => 'users_table'); + create_distributed_table +-------------------------- + +(1 row) + +SELECT create_distributed_table('partitioned_events_table', 'user_id', colocate_with => 'events_table'); + create_distributed_table +-------------------------- + +(1 row) + +-- INSERT/SELECT from regular table to partitioned table +CREATE TABLE partitioned_users_table_2009 PARTITION OF partitioned_users_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); +CREATE TABLE partitioned_events_table_2009 PARTITION OF partitioned_events_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); +INSERT INTO partitioned_events_table SELECT * FROM events_table; +INSERT INTO partitioned_users_table_2009 SELECT * FROM users_table; +-- +-- Complex JOINs, subqueries, UNIONs etc... +-- +-- subquery with UNIONs on partitioned table +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM( + (SELECT + "events"."user_id", "events"."time", 0 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15)) + UNION + (SELECT + "events"."user_id", "events"."time", 1 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (15, 16, 17, 18, 19) ) + UNION + (SELECT + "events"."user_id", "events"."time", 2 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) + UNION + (SELECT + "events"."user_id", "events"."time", 3 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13))) t1 + GROUP BY "t1"."user_id") AS t) "q" +) AS final_query +GROUP BY types +ORDER BY types; + types | sumofeventtype +-------+---------------- + 0 | 55 + 1 | 38 + 2 | 70 + 3 | 58 +(4 rows) + +-- UNION and JOIN on both partitioned and regular tables +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT + *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM ( + (SELECT + * + FROM + (SELECT + "events"."time", 0 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1) + UNION + (SELECT * + FROM + ( + SELECT * FROM + ( + SELECT + max("events"."time"), + 0 AS event, + "events"."user_id" + FROM + events_table as "events", users_table as "users" + WHERE + events.user_id = users.user_id AND + event_type IN (10, 11, 12, 13, 14, 15) + GROUP BY "events"."user_id" + ) as events_subquery_5 + ) events_subquery_2) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 2 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 3 AS event, "events"."user_id" + FROM + events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13)) events_subquery_4) + ) t1 + GROUP BY "t1"."user_id") AS t) "q" +INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + value_1 > 50 and value_1 < 70) AS t + ON (t.user_id = q.user_id)) as final_query +GROUP BY + types +ORDER BY + types; + types | sumofeventtype +-------+---------------- + 0 | 115 + 2 | 160 + 3 | 158 +(3 rows) + +-- test LIST partitioning +CREATE TABLE list_partitioned_events_table (user_id int, time date, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY LIST (time); +CREATE TABLE list_partitioned_events_table_2014_01_01_05 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-01', '2014-01-02', '2014-01-03', '2014-01-04', '2014-01-05'); +CREATE TABLE list_partitioned_events_table_2014_01_06_10 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-06', '2014-01-07', '2014-01-08', '2014-01-09', '2014-01-10'); +CREATE TABLE list_partitioned_events_table_2014_01_11_15 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-11', '2014-01-12', '2014-01-13', '2014-01-14', '2014-01-15'); +-- test distributing partitioned table colocated with another partitioned table +SELECT create_distributed_table('list_partitioned_events_table', 'user_id', colocate_with => 'partitioned_events_table'); + create_distributed_table +-------------------------- + +(1 row) + +-- INSERT/SELECT from partitioned table to partitioned table +INSERT INTO + list_partitioned_events_table +SELECT + user_id, + date_trunc('day', time) as time, + event_type, + value_2, + value_3, + value_4 +FROM + events_table +WHERE + time >= '2014-01-01' AND + time <= '2014-01-15'; +-- LEFT JOINs used with INNER JOINs on range partitioned table, list partitioned table and non-partitioned table +SELECT +count(*) AS cnt, "generated_group_field" + FROM + (SELECT + "eventQuery"."user_id", random(), generated_group_field + FROM + (SELECT + "multi_group_wrapper_1".*, generated_group_field, random() + FROM + (SELECT * + FROM + (SELECT + "list_partitioned_events_table"."time", "list_partitioned_events_table"."user_id" as event_user_id + FROM + list_partitioned_events_table as "list_partitioned_events_table" + WHERE + user_id > 80) "temp_data_queries" + INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + user_id > 80 and value_2 = 5) "user_filters_1" + ON ("temp_data_queries".event_user_id = "user_filters_1".user_id)) AS "multi_group_wrapper_1" + LEFT JOIN + (SELECT + "users"."user_id" AS "user_id", value_2 AS "generated_group_field" + FROM + partitioned_users_table as "users") "left_group_by_1" + ON ("left_group_by_1".user_id = "multi_group_wrapper_1".event_user_id)) "eventQuery") "pushedDownQuery" + GROUP BY + "generated_group_field" + ORDER BY + cnt DESC, generated_group_field ASC + LIMIT 10; + cnt | generated_group_field +-----+----------------------- + 68 | 551 + 68 | 569 + 68 | 645 + 68 | 713 + 68 | 734 + 34 | 3 + 34 | 5 + 34 | 15 + 34 | 32 + 34 | 68 +(10 rows) + +-- +-- Additional partitioning features +-- +-- test multi column partitioning +CREATE TABLE multi_column_partitioning(c1 int, c2 int) PARTITION BY RANGE (c1, c2); +CREATE TABLE multi_column_partitioning_0_0_10_0 PARTITION OF multi_column_partitioning FOR VALUES FROM (0, 0) TO (10, 0); +SELECT create_distributed_table('multi_column_partitioning', 'c1'); + create_distributed_table +-------------------------- + +(1 row) + +-- test INSERT to multi-column partitioned table +INSERT INTO multi_column_partitioning VALUES(1, 1); +INSERT INTO multi_column_partitioning_0_0_10_0 VALUES(5, -5); +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(10, 1); +ERROR: no partition of relation "multi_column_partitioning_1660068" found for row +DETAIL: Partition key of the failing row contains (c1, c2) = (10, 1). +CONTEXT: while executing command on localhost:57637 +-- test with MINVALUE/MAXVALUE +CREATE TABLE multi_column_partitioning_10_max_20_min PARTITION OF multi_column_partitioning FOR VALUES FROM (10, MAXVALUE) TO (20, MINVALUE); +-- test INSERT to partition with MINVALUE/MAXVALUE bounds +INSERT INTO multi_column_partitioning VALUES(11, -11); +INSERT INTO multi_column_partitioning_10_max_20_min VALUES(19, -19); +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(20, -20); +ERROR: no partition of relation "multi_column_partitioning_1660068" found for row +DETAIL: Partition key of the failing row contains (c1, c2) = (20, -20). +CONTEXT: while executing command on localhost:57637 +-- see data is loaded to multi-column partitioned table +SELECT * FROM multi_column_partitioning; + c1 | c2 +----+----- + 1 | 1 + 5 | -5 + 19 | -19 + 11 | -11 +(4 rows) + +DROP TABLE IF EXISTS partitioning_test_2012, partitioning_test_2013, partitioned_events_table, partitioned_users_table, list_partitioned_events_table, multi_column_partitioning; +NOTICE: table "partitioning_test_2012" does not exist, skipping +NOTICE: table "partitioning_test_2013" does not exist, skipping diff --git a/src/test/regress/expected/multi_partitioning_0.out b/src/test/regress/expected/multi_partitioning_0.out new file mode 100644 index 000000000..b0d11e11c --- /dev/null +++ b/src/test/regress/expected/multi_partitioning_0.out @@ -0,0 +1,934 @@ +-- +-- Distributed Partitioned Table Tests +-- +ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1660000; +SET citus.shard_count TO 4; +SET citus.shard_replication_factor TO 1; +-- +-- Distributed Partitioned Table Creation Tests +-- +-- 1-) Distributing partitioned table +-- create partitioned table +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test(id int, time date) PARTITION ... + ^ + +-- create its partitions +CREATE TABLE partitioning_test_2009 PARTITION OF partitioning_test FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_2009 PARTITION OF partitionin... + ^ +CREATE TABLE partitioning_test_2010 PARTITION OF partitioning_test FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_2010 PARTITION OF partitionin... + ^ +-- load some data and distribute tables +INSERT INTO partitioning_test VALUES (1, '2009-06-06'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES (1, '2009-06-06'); + ^ +INSERT INTO partitioning_test VALUES (2, '2010-07-07'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES (2, '2010-07-07'); + ^ +INSERT INTO partitioning_test_2009 VALUES (3, '2009-09-09'); +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: INSERT INTO partitioning_test_2009 VALUES (3, '2009-09-09'); + ^ +INSERT INTO partitioning_test_2010 VALUES (4, '2010-03-03'); +ERROR: relation "partitioning_test_2010" does not exist +LINE 1: INSERT INTO partitioning_test_2010 VALUES (4, '2010-03-03'); + ^ +-- distribute partitioned table +SELECT create_distributed_table('partitioning_test', 'id'); +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test', 'id'); + ^ +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test ORDER BY 1; + ^ +-- see partitioned table and its partitions are distributed +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 6: logicalrelid IN ('partitioning_test', 'partitioning_test_20... + ^ +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +GROUP BY + logicalrelid +ORDER BY + 1,2; +ERROR: relation "partitioning_test" does not exist +LINE 4: WHERE logicalrelid IN ('partitioning_test', 'partitioning_t... + ^ +-- 2-) Creating partition of a distributed table +CREATE TABLE partitioning_test_2011 PARTITION OF partitioning_test FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_2011 PARTITION OF partitionin... + ^ +-- new partition is automatically distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 6: logicalrelid IN ('partitioning_test', 'partitioning_test_20... + ^ +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +GROUP BY + logicalrelid +ORDER BY + 1,2; +ERROR: relation "partitioning_test" does not exist +LINE 4: WHERE logicalrelid IN ('partitioning_test', 'partitioning_t... + ^ +-- 3-) Attaching non distributed table to a distributed table +CREATE TABLE partitioning_test_2012(id int, time date); +-- load some data +INSERT INTO partitioning_test_2012 VALUES (5, '2012-06-06'); +INSERT INTO partitioning_test_2012 VALUES (6, '2012-07-07'); +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2012 FOR VALUES FROM ('2012-01-01') TO ('2013-01-01'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE partitioning_test ATTACH PARTITION partitioning_... + ^ +-- attached partition is distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 6: logicalrelid IN ('partitioning_test', 'partitioning_test_20... + ^ +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +GROUP BY + logicalrelid +ORDER BY + 1,2; +ERROR: relation "partitioning_test" does not exist +LINE 4: WHERE logicalrelid IN ('partitioning_test', 'partitioning_t... + ^ +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test ORDER BY 1; + ^ +-- 4-) Attaching distributed table to distributed table +CREATE TABLE partitioning_test_2013(id int, time date); +SELECT create_distributed_table('partitioning_test_2013', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +-- load some data +INSERT INTO partitioning_test_2013 VALUES (7, '2013-06-06'); +INSERT INTO partitioning_test_2013 VALUES (8, '2013-07-07'); +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2013 FOR VALUES FROM ('2013-01-01') TO ('2014-01-01'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE partitioning_test ATTACH PARTITION partitioning_... + ^ +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test ORDER BY 1; + ^ +-- 5-) Failure cases while creating distributed partitioned tables +-- cannot distribute a partition if its parent is not distributed +CREATE TABLE partitioning_test_failure(id int, time date) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...ABLE partitioning_test_failure(id int, time date) PARTITION ... + ^ +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_failure_2009 PARTITION OF par... + ^ +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); +ERROR: relation "partitioning_test_failure_2009" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure_2... + ^ +-- only hash distributed tables can have partitions +SELECT create_distributed_table('partitioning_test_failure', 'id', 'append'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure',... + ^ +SELECT create_distributed_table('partitioning_test_failure', 'id', 'range'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure',... + ^ +SELECT create_reference_table('partitioning_test_failure'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_reference_table('partitioning_test_failure'); + ^ +-- replication factor > 1 is not allowed in distributed partitioned tables +SET citus.shard_replication_factor TO 2; +SELECT create_distributed_table('partitioning_test_failure', 'id'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure',... + ^ +SET citus.shard_replication_factor TO 1; +-- non-distributed tables cannot have distributed partitions; +DROP TABLE partitioning_test_failure_2009; +ERROR: table "partitioning_test_failure_2009" does not exist +CREATE TABLE partitioning_test_failure_2009(id int, time date); +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); + create_distributed_table +-------------------------- + +(1 row) + +ALTER TABLE partitioning_test_failure ATTACH PARTITION partitioning_test_failure_2009 FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +ERROR: syntax error at or near "ATTACH" +LINE 1: ALTER TABLE partitioning_test_failure ATTACH PARTITION parti... + ^ +-- multi-level partitioning is not allowed +DROP TABLE partitioning_test_failure_2009; +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_failure_2009 PARTITION OF par... + ^ +SELECT create_distributed_table('partitioning_test_failure', 'id'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure',... + ^ +-- multi-level partitioning is not allowed in different order +DROP TABLE partitioning_test_failure_2009; +ERROR: table "partitioning_test_failure_2009" does not exist +SELECT create_distributed_table('partitioning_test_failure', 'id'); +ERROR: relation "partitioning_test_failure" does not exist +LINE 1: SELECT create_distributed_table('partitioning_test_failure',... + ^ +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioning_test_failure_2009 PARTITION OF par... + ^ +-- +-- DMLs in distributed partitioned tables +-- +-- test COPY +-- COPY data to partitioned table +COPY partitioning_test FROM STDIN WITH CSV; +ERROR: relation "partitioning_test" does not exist +9,2009-01-01 +10,2010-01-01 +11,2011-01-01 +12,2012-01-01 +\. +invalid command \. +-- COPY data to partition directly +COPY partitioning_test_2009 FROM STDIN WITH CSV; +ERROR: syntax error at or near "9" +LINE 1: 9,2009-01-01 + ^ +13,2009-01-02 +14,2009-01-03 +\. +invalid command \. +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 9 ORDER BY 1; +ERROR: syntax error at or near "13" +LINE 1: 13,2009-01-02 + ^ +-- test INSERT +-- INSERT INTO the partitioned table +INSERT INTO partitioning_test VALUES(15, '2009-02-01'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(15, '2009-02-01'); + ^ +INSERT INTO partitioning_test VALUES(16, '2010-02-01'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(16, '2010-02-01'); + ^ +INSERT INTO partitioning_test VALUES(17, '2011-02-01'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(17, '2011-02-01'); + ^ +INSERT INTO partitioning_test VALUES(18, '2012-02-01'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(18, '2012-02-01'); + ^ +-- INSERT INTO the partitions directly table +INSERT INTO partitioning_test VALUES(19, '2009-02-02'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(19, '2009-02-02'); + ^ +INSERT INTO partitioning_test VALUES(20, '2010-02-02'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(20, '2010-02-02'); + ^ +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 15 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id >= 15 ORDER BY 1; + ^ +-- test INSERT/SELECT +-- INSERT/SELECT from partition to partitioned table +INSERT INTO partitioning_test SELECT * FROM partitioning_test_2011; +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test SELECT * FROM partitioning_tes... + ^ +-- INSERT/SELECT from partitioned table to partition +INSERT INTO partitioning_test_2012 SELECT * FROM partitioning_test WHERE time >= '2012-01-01' AND time < '2013-01-01'; +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test_2012 SELECT * FROM partitionin... + ^ +-- see the data is loaded to shards (rows in the given range should be duplicated) +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2013-01-01' ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE time >= '2011-01-01' A... + ^ +-- test UPDATE +-- UPDATE partitioned table +UPDATE partitioning_test SET time = '2013-07-07' WHERE id = 7; +ERROR: relation "partitioning_test" does not exist +LINE 1: UPDATE partitioning_test SET time = '2013-07-07' WHERE id = ... + ^ +-- UPDATE partition directly +UPDATE partitioning_test_2013 SET time = '2013-08-08' WHERE id = 8; +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 7 OR id = 8 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id = 7 OR id = 8 ORDER... + ^ +-- UPDATE that tries to move a row to a non-existing partition (this should fail) +UPDATE partitioning_test SET time = '2020-07-07' WHERE id = 7; +ERROR: relation "partitioning_test" does not exist +LINE 1: UPDATE partitioning_test SET time = '2020-07-07' WHERE id = ... + ^ +-- UPDATE with subqueries on partitioned table +UPDATE + partitioning_test +SET + time = time + INTERVAL '1 day' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 1); +ERROR: relation "partitioning_test" does not exist +LINE 2: partitioning_test + ^ +-- UPDATE with subqueries on partition +UPDATE + partitioning_test_2009 +SET + time = time + INTERVAL '1 month' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 2); +ERROR: relation "partitioning_test_2009" does not exist +LINE 2: partitioning_test_2009 + ^ +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 1 OR id = 2 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id = 1 OR id = 2 ORDER... + ^ +-- test DELETE +-- DELETE from partitioned table +DELETE FROM partitioning_test WHERE id = 9; +ERROR: relation "partitioning_test" does not exist +LINE 1: DELETE FROM partitioning_test WHERE id = 9; + ^ +-- DELETE from partition directly +DELETE FROM partitioning_test_2010 WHERE id = 10; +ERROR: relation "partitioning_test_2010" does not exist +LINE 1: DELETE FROM partitioning_test_2010 WHERE id = 10; + ^ +-- see the data is deleted +SELECT * FROM partitioning_test WHERE id = 9 OR id = 10 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id = 9 OR id = 10 ORDE... + ^ +-- test master_modify_multiple_shards +-- master_modify_multiple_shards on partitioned table +SELECT master_modify_multiple_shards('UPDATE partitioning_test SET time = time + INTERVAL ''1 day'''); +ERROR: relation "partitioning_test" does not exist +-- see rows are UPDATED +SELECT * FROM partitioning_test ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test ORDER BY 1; + ^ +-- master_modify_multiple_shards on partition directly +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''1 day'''); +ERROR: relation "partitioning_test_2009" does not exist +-- see rows are UPDATED +SELECT * FROM partitioning_test_2009 ORDER BY 1; +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: SELECT * FROM partitioning_test_2009 ORDER BY 1; + ^ +-- test master_modify_multiple_shards which fails in workers (updated value is outside of partition bounds) +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''6 month'''); +ERROR: relation "partitioning_test_2009" does not exist +-- +-- DDL in distributed partitioned tables +-- +-- test CREATE INDEX +-- CREATE INDEX on partitioned table - this will error out +CREATE INDEX partitioning_index ON partitioning_test(id); +ERROR: relation "partitioning_test" does not exist +-- CREATE INDEX on partition +CREATE INDEX partitioning_2009_index ON partitioning_test_2009(id); +ERROR: relation "partitioning_test_2009" does not exist +-- CREATE INDEX CONCURRENTLY on partition +CREATE INDEX CONCURRENTLY partitioned_2010_index ON partitioning_test_2010(id); +ERROR: relation "partitioning_test_2010" does not exist +-- see index is created +SELECT tablename, indexname FROM pg_indexes WHERE tablename LIKE 'partitioning_test%' ORDER BY indexname; + tablename | indexname +-----------+----------- +(0 rows) + +-- test add COLUMN +-- add COLUMN to partitioned table +ALTER TABLE partitioning_test ADD new_column int; +ERROR: relation "partitioning_test" does not exist +-- add COLUMN to partition - this will error out +ALTER TABLE partitioning_test_2010 ADD new_column_2 int; +ERROR: relation "partitioning_test_2010" does not exist +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT name, type FROM table_attrs WHERE relid = 'partitioni... + ^ +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test_2010'::regclass ORDER BY 1; +ERROR: relation "partitioning_test_2010" does not exist +LINE 1: SELECT name, type FROM table_attrs WHERE relid = 'partitioni... + ^ +-- test add PRIMARY KEY +-- add PRIMARY KEY to partitioned table - this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_primary PRIMARY KEY (id); +ERROR: relation "partitioning_test" does not exist +-- ADD PRIMARY KEY to partition +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_2009_primary PRIMARY KEY (id); +ERROR: relation "partitioning_test_2009" does not exist +-- see PRIMARY KEY is created +SELECT + table_name, + constraint_name, + constraint_type +FROM + information_schema.table_constraints +WHERE + table_name = 'partitioning_test_2009' AND + constraint_name = 'partitioning_2009_primary'; + table_name | constraint_name | constraint_type +------------+-----------------+----------------- +(0 rows) + +-- test ADD FOREIGN CONSTRAINT +-- add FOREIGN CONSTRAINT to partitioned table -- this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id); +ERROR: relation "partitioning_test" does not exist +-- add FOREIGN CONSTRAINT to partition +INSERT INTO partitioning_test_2009 VALUES (5, '2009-06-06'); +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: INSERT INTO partitioning_test_2009 VALUES (5, '2009-06-06'); + ^ +INSERT INTO partitioning_test_2009 VALUES (6, '2009-07-07'); +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: INSERT INTO partitioning_test_2009 VALUES (6, '2009-07-07'); + ^ +INSERT INTO partitioning_test_2009 VALUES(12, '2009-02-01'); +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: INSERT INTO partitioning_test_2009 VALUES(12, '2009-02-01'); + ^ +INSERT INTO partitioning_test_2009 VALUES(18, '2009-02-01'); +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: INSERT INTO partitioning_test_2009 VALUES(18, '2009-02-01'); + ^ +ALTER TABLE partitioning_test_2012 ADD CONSTRAINT partitioning_2012_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id) ON DELETE CASCADE; +ERROR: relation "partitioning_test_2009" does not exist +-- see FOREIGN KEY is created +SELECT "Constraint" FROM table_fkeys WHERE relid = 'partitioning_test_2012'::regclass ORDER BY 1; + Constraint +------------ +(0 rows) + +-- test ON DELETE CASCADE works +DELETE FROM partitioning_test_2009 WHERE id = 5; +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: DELETE FROM partitioning_test_2009 WHERE id = 5; + ^ +-- see that element is deleted from both partitions +SELECT * FROM partitioning_test_2009 WHERE id = 5 ORDER BY 1; +ERROR: relation "partitioning_test_2009" does not exist +LINE 1: SELECT * FROM partitioning_test_2009 WHERE id = 5 ORDER BY 1... + ^ +SELECT * FROM partitioning_test_2012 WHERE id = 5 ORDER BY 1; + id | time +----+------------ + 5 | 06-06-2012 +(1 row) + +-- test DETACH partition +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; +ERROR: syntax error at or near "DETACH" +LINE 1: ALTER TABLE partitioning_test DETACH PARTITION partitioning_... + ^ +-- see DETACHed partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2009-01-01' AND time < '2010-01-01' ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE time >= '2009-01-01' A... + ^ +-- +-- Transaction tests +-- +-- DDL in transaction +BEGIN; +ALTER TABLE partitioning_test ADD newer_column int; +ERROR: relation "partitioning_test" does not exist +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- see rollback is successful +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT name, type FROM table_attrs WHERE relid = 'partitioni... + ^ +-- COPY in transaction +BEGIN; +COPY partitioning_test FROM STDIN WITH CSV; +ERROR: relation "partitioning_test" does not exist +22,2010-01-01,22 +23,2011-01-01,23 +24,2013-01-01,24 +\. +invalid command \. +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 22 ORDER BY 1; +ERROR: syntax error at or near "22" +LINE 1: 22,2010-01-01,22 + ^ +SELECT * FROM partitioning_test WHERE id = 23 ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +SELECT * FROM partitioning_test WHERE id = 24 ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +ROLLBACK; +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id >= 22 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id >= 22 ORDER BY 1; + ^ +-- DML in transaction +BEGIN; +-- INSERT in transaction +INSERT INTO partitioning_test VALUES(25, '2010-02-02'); +ERROR: relation "partitioning_test" does not exist +LINE 1: INSERT INTO partitioning_test VALUES(25, '2010-02-02'); + ^ +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +-- INSERT/SELECT in transaction +INSERT INTO partitioning_test SELECT * FROM partitioning_test WHERE id = 25; +ERROR: current transaction is aborted, commands ignored until end of transaction block +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +-- UPDATE in transaction +UPDATE partitioning_test SET time = '2010-10-10' WHERE id = 25; +ERROR: current transaction is aborted, commands ignored until end of transaction block +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; +ERROR: current transaction is aborted, commands ignored until end of transaction block +-- perform operations on partition and partioned tables together +INSERT INTO partitioning_test VALUES(26, '2010-02-02', 26); +ERROR: current transaction is aborted, commands ignored until end of transaction block +INSERT INTO partitioning_test_2010 VALUES(26, '2010-02-02', 26); +ERROR: current transaction is aborted, commands ignored until end of transaction block +COPY partitioning_test FROM STDIN WITH CSV; +ERROR: current transaction is aborted, commands ignored until end of transaction block +26,2010-02-02,26 +\. +invalid command \. +COPY partitioning_test_2010 FROM STDIN WITH CSV; +ERROR: syntax error at or near "26" +LINE 1: 26,2010-02-02,26 + ^ +26,2010-02-02,26 +\. +invalid command \. +-- see the data is loaded to shards (we should see 4 rows with same content) +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; +ERROR: syntax error at or near "26" +LINE 1: 26,2010-02-02,26 + ^ +ROLLBACK; +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; + ^ +-- DETACH and DROP in a transaction +BEGIN; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; +ERROR: syntax error at or near "DETACH" +LINE 1: ALTER TABLE partitioning_test DETACH PARTITION partitioning_... + ^ +DROP TABLE partitioning_test_2011; +ERROR: current transaction is aborted, commands ignored until end of transaction block +COMMIT; +-- see DROPed partitions content is not accessible +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2012-01-01' ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE time >= '2011-01-01' A... + ^ +-- +-- Misc tests +-- +-- test TRUNCATE +-- test TRUNCATE partition +TRUNCATE partitioning_test_2012; +-- see partition is TRUNCATEd +SELECT * FROM partitioning_test_2012 ORDER BY 1; + id | time +----+------ +(0 rows) + +-- test TRUNCATE partitioned table +TRUNCATE partitioning_test; +ERROR: relation "partitioning_test" does not exist +-- see partitioned table is TRUNCATEd +SELECT * FROM partitioning_test ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test ORDER BY 1; + ^ +-- test DROP +-- test DROP partition +INSERT INTO partitioning_test_2010 VALUES(27, '2010-02-01'); +ERROR: relation "partitioning_test_2010" does not exist +LINE 1: INSERT INTO partitioning_test_2010 VALUES(27, '2010-02-01'); + ^ +DROP TABLE partitioning_test_2010; +ERROR: table "partitioning_test_2010" does not exist +-- see DROPped partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2010-01-01' AND time < '2011-01-01' ORDER BY 1; +ERROR: relation "partitioning_test" does not exist +LINE 1: SELECT * FROM partitioning_test WHERE time >= '2010-01-01' A... + ^ +-- test DROP partitioned table +DROP TABLE partitioning_test; +ERROR: table "partitioning_test" does not exist +-- dropping the parent should CASCADE to the children as well +SELECT table_name FROM information_schema.tables WHERE table_name LIKE 'partitioning_test%' ORDER BY 1; + table_name +------------------------ + partitioning_test_2012 + partitioning_test_2013 +(2 rows) + +-- test distributing partitioned table colocated with non-partitioned table +CREATE TABLE partitioned_users_table (user_id int, time timestamp, value_1 int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ... int, value_2 int, value_3 float, value_4 bigint) PARTITION ... + ^ +CREATE TABLE partitioned_events_table (user_id int, time timestamp, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ... int, value_2 int, value_3 float, value_4 bigint) PARTITION ... + ^ +SELECT create_distributed_table('partitioned_users_table', 'user_id', colocate_with => 'users_table'); +ERROR: relation "partitioned_users_table" does not exist +LINE 1: SELECT create_distributed_table('partitioned_users_table', '... + ^ +SELECT create_distributed_table('partitioned_events_table', 'user_id', colocate_with => 'events_table'); +ERROR: relation "partitioned_events_table" does not exist +LINE 1: SELECT create_distributed_table('partitioned_events_table', ... + ^ +-- INSERT/SELECT from regular table to partitioned table +CREATE TABLE partitioned_users_table_2009 PARTITION OF partitioned_users_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioned_users_table_2009 PARTITION OF parti... + ^ +CREATE TABLE partitioned_events_table_2009 PARTITION OF partitioned_events_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE partitioned_events_table_2009 PARTITION OF part... + ^ +INSERT INTO partitioned_events_table SELECT * FROM events_table; +ERROR: relation "partitioned_events_table" does not exist +LINE 1: INSERT INTO partitioned_events_table SELECT * FROM events_ta... + ^ +INSERT INTO partitioned_users_table_2009 SELECT * FROM users_table; +ERROR: relation "partitioned_users_table_2009" does not exist +LINE 1: INSERT INTO partitioned_users_table_2009 SELECT * FROM users... + ^ +-- +-- Complex JOINs, subqueries, UNIONs etc... +-- +-- subquery with UNIONs on partitioned table +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM( + (SELECT + "events"."user_id", "events"."time", 0 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15)) + UNION + (SELECT + "events"."user_id", "events"."time", 1 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (15, 16, 17, 18, 19) ) + UNION + (SELECT + "events"."user_id", "events"."time", 2 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) + UNION + (SELECT + "events"."user_id", "events"."time", 3 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13))) t1 + GROUP BY "t1"."user_id") AS t) "q" +) AS final_query +GROUP BY types +ORDER BY types; +ERROR: relation "partitioned_events_table" does not exist +LINE 14: partitioned_events_table as "events" + ^ +-- UNION and JOIN on both partitioned and regular tables +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT + *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM ( + (SELECT + * + FROM + (SELECT + "events"."time", 0 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1) + UNION + (SELECT * + FROM + ( + SELECT * FROM + ( + SELECT + max("events"."time"), + 0 AS event, + "events"."user_id" + FROM + events_table as "events", users_table as "users" + WHERE + events.user_id = users.user_id AND + event_type IN (10, 11, 12, 13, 14, 15) + GROUP BY "events"."user_id" + ) as events_subquery_5 + ) events_subquery_2) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 2 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 3 AS event, "events"."user_id" + FROM + events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13)) events_subquery_4) + ) t1 + GROUP BY "t1"."user_id") AS t) "q" +INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + value_1 > 50 and value_1 < 70) AS t + ON (t.user_id = q.user_id)) as final_query +GROUP BY + types +ORDER BY + types; +ERROR: relation "partitioned_events_table" does not exist +LINE 18: partitioned_events_table as "events" + ^ +-- test LIST partitioning +CREATE TABLE list_partitioned_events_table (user_id int, time date, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY LIST (time); +ERROR: syntax error at or near "PARTITION" +LINE 1: ... int, value_2 int, value_3 float, value_4 bigint) PARTITION ... + ^ +CREATE TABLE list_partitioned_events_table_2014_01_01_05 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-01', '2014-01-02', '2014-01-03', '2014-01-04', '2014-01-05'); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...TABLE list_partitioned_events_table_2014_01_01_05 PARTITION ... + ^ +CREATE TABLE list_partitioned_events_table_2014_01_06_10 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-06', '2014-01-07', '2014-01-08', '2014-01-09', '2014-01-10'); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...TABLE list_partitioned_events_table_2014_01_06_10 PARTITION ... + ^ +CREATE TABLE list_partitioned_events_table_2014_01_11_15 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-11', '2014-01-12', '2014-01-13', '2014-01-14', '2014-01-15'); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...TABLE list_partitioned_events_table_2014_01_11_15 PARTITION ... + ^ +-- test distributing partitioned table colocated with another partitioned table +SELECT create_distributed_table('list_partitioned_events_table', 'user_id', colocate_with => 'partitioned_events_table'); +ERROR: relation "list_partitioned_events_table" does not exist +LINE 1: SELECT create_distributed_table('list_partitioned_events_tab... + ^ +-- INSERT/SELECT from partitioned table to partitioned table +INSERT INTO + list_partitioned_events_table +SELECT + user_id, + date_trunc('day', time) as time, + event_type, + value_2, + value_3, + value_4 +FROM + events_table +WHERE + time >= '2014-01-01' AND + time <= '2014-01-15'; +ERROR: relation "list_partitioned_events_table" does not exist +LINE 2: list_partitioned_events_table + ^ +-- LEFT JOINs used with INNER JOINs on range partitioned table, list partitioned table and non-partitioned table +SELECT +count(*) AS cnt, "generated_group_field" + FROM + (SELECT + "eventQuery"."user_id", random(), generated_group_field + FROM + (SELECT + "multi_group_wrapper_1".*, generated_group_field, random() + FROM + (SELECT * + FROM + (SELECT + "list_partitioned_events_table"."time", "list_partitioned_events_table"."user_id" as event_user_id + FROM + list_partitioned_events_table as "list_partitioned_events_table" + WHERE + user_id > 80) "temp_data_queries" + INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + user_id > 80 and value_2 = 5) "user_filters_1" + ON ("temp_data_queries".event_user_id = "user_filters_1".user_id)) AS "multi_group_wrapper_1" + LEFT JOIN + (SELECT + "users"."user_id" AS "user_id", value_2 AS "generated_group_field" + FROM + partitioned_users_table as "users") "left_group_by_1" + ON ("left_group_by_1".user_id = "multi_group_wrapper_1".event_user_id)) "eventQuery") "pushedDownQuery" + GROUP BY + "generated_group_field" + ORDER BY + cnt DESC, generated_group_field ASC + LIMIT 10; +ERROR: relation "list_partitioned_events_table" does not exist +LINE 15: list_partitioned_events_table as "list_partitio... + ^ +-- +-- Additional partitioning features +-- +-- test multi column partitioning +CREATE TABLE multi_column_partitioning(c1 int, c2 int) PARTITION BY RANGE (c1, c2); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...E TABLE multi_column_partitioning(c1 int, c2 int) PARTITION ... + ^ +CREATE TABLE multi_column_partitioning_0_0_10_0 PARTITION OF multi_column_partitioning FOR VALUES FROM (0, 0) TO (10, 0); +ERROR: syntax error at or near "PARTITION" +LINE 1: CREATE TABLE multi_column_partitioning_0_0_10_0 PARTITION OF... + ^ +SELECT create_distributed_table('multi_column_partitioning', 'c1'); +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: SELECT create_distributed_table('multi_column_partitioning',... + ^ +-- test INSERT to multi-column partitioned table +INSERT INTO multi_column_partitioning VALUES(1, 1); +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: INSERT INTO multi_column_partitioning VALUES(1, 1); + ^ +INSERT INTO multi_column_partitioning_0_0_10_0 VALUES(5, -5); +ERROR: relation "multi_column_partitioning_0_0_10_0" does not exist +LINE 1: INSERT INTO multi_column_partitioning_0_0_10_0 VALUES(5, -5)... + ^ +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(10, 1); +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: INSERT INTO multi_column_partitioning VALUES(10, 1); + ^ +-- test with MINVALUE/MAXVALUE +CREATE TABLE multi_column_partitioning_10_max_20_min PARTITION OF multi_column_partitioning FOR VALUES FROM (10, MAXVALUE) TO (20, MINVALUE); +ERROR: syntax error at or near "PARTITION" +LINE 1: ...ATE TABLE multi_column_partitioning_10_max_20_min PARTITION ... + ^ +-- test INSERT to partition with MINVALUE/MAXVALUE bounds +INSERT INTO multi_column_partitioning VALUES(11, -11); +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: INSERT INTO multi_column_partitioning VALUES(11, -11); + ^ +INSERT INTO multi_column_partitioning_10_max_20_min VALUES(19, -19); +ERROR: relation "multi_column_partitioning_10_max_20_min" does not exist +LINE 1: INSERT INTO multi_column_partitioning_10_max_20_min VALUES(1... + ^ +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(20, -20); +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: INSERT INTO multi_column_partitioning VALUES(20, -20); + ^ +-- see data is loaded to multi-column partitioned table +SELECT * FROM multi_column_partitioning; +ERROR: relation "multi_column_partitioning" does not exist +LINE 1: SELECT * FROM multi_column_partitioning; + ^ +DROP TABLE IF EXISTS partitioning_test_2012, partitioning_test_2013, partitioned_events_table, partitioned_users_table, list_partitioned_events_table, multi_column_partitioning; +NOTICE: table "partitioned_events_table" does not exist, skipping +NOTICE: table "partitioned_users_table" does not exist, skipping +NOTICE: table "list_partitioned_events_table" does not exist, skipping +NOTICE: table "multi_column_partitioning" does not exist, skipping diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index d942a65e7..e0f63a6bd 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -23,11 +23,6 @@ test: multi_table_ddl test: multi_name_lengths test: multi_metadata_access -# --- -# Tests for partitioning support -# --- -test: multi_partitioning_utils - # ---------- # The following distributed tests depend on creating a partitioned table and # uploading data to it. @@ -41,6 +36,12 @@ test: multi_behavioral_analytics_create_table test: multi_behavioral_analytics_basics multi_behavioral_analytics_single_shard_queries multi_insert_select_non_pushable_queries test: multi_insert_select +# --- +# Tests for partitioning support +# --- +test: multi_partitioning_utils +test: multi_partitioning + # ---------- # Miscellaneous tests to check our query planning behavior # ---------- diff --git a/src/test/regress/sql/multi_partitioning.sql b/src/test/regress/sql/multi_partitioning.sql new file mode 100644 index 000000000..715c67ef6 --- /dev/null +++ b/src/test/regress/sql/multi_partitioning.sql @@ -0,0 +1,665 @@ +-- +-- Distributed Partitioned Table Tests +-- +ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1660000; + +SET citus.shard_count TO 4; +SET citus.shard_replication_factor TO 1; + +-- +-- Distributed Partitioned Table Creation Tests +-- + +-- 1-) Distributing partitioned table +-- create partitioned table +CREATE TABLE partitioning_test(id int, time date) PARTITION BY RANGE (time); + +-- create its partitions +CREATE TABLE partitioning_test_2009 PARTITION OF partitioning_test FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +CREATE TABLE partitioning_test_2010 PARTITION OF partitioning_test FOR VALUES FROM ('2010-01-01') TO ('2011-01-01'); + +-- load some data and distribute tables +INSERT INTO partitioning_test VALUES (1, '2009-06-06'); +INSERT INTO partitioning_test VALUES (2, '2010-07-07'); + +INSERT INTO partitioning_test_2009 VALUES (3, '2009-09-09'); +INSERT INTO partitioning_test_2010 VALUES (4, '2010-03-03'); + +-- distribute partitioned table +SELECT create_distributed_table('partitioning_test', 'id'); + +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + +-- see partitioned table and its partitions are distributed +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +ORDER BY 1; + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2009', 'partitioning_test_2010') +GROUP BY + logicalrelid +ORDER BY + 1,2; + +-- 2-) Creating partition of a distributed table +CREATE TABLE partitioning_test_2011 PARTITION OF partitioning_test FOR VALUES FROM ('2011-01-01') TO ('2012-01-01'); + +-- new partition is automatically distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +ORDER BY 1; + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2011') +GROUP BY + logicalrelid +ORDER BY + 1,2; + +-- 3-) Attaching non distributed table to a distributed table +CREATE TABLE partitioning_test_2012(id int, time date); + +-- load some data +INSERT INTO partitioning_test_2012 VALUES (5, '2012-06-06'); +INSERT INTO partitioning_test_2012 VALUES (6, '2012-07-07'); + +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2012 FOR VALUES FROM ('2012-01-01') TO ('2013-01-01'); + +-- attached partition is distributed as well +SELECT + logicalrelid +FROM + pg_dist_partition +WHERE + logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +ORDER BY 1; + +SELECT + logicalrelid, count(*) +FROM pg_dist_shard + WHERE logicalrelid IN ('partitioning_test', 'partitioning_test_2012') +GROUP BY + logicalrelid +ORDER BY + 1,2; + +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + +-- 4-) Attaching distributed table to distributed table +CREATE TABLE partitioning_test_2013(id int, time date); +SELECT create_distributed_table('partitioning_test_2013', 'id'); + +-- load some data +INSERT INTO partitioning_test_2013 VALUES (7, '2013-06-06'); +INSERT INTO partitioning_test_2013 VALUES (8, '2013-07-07'); + +ALTER TABLE partitioning_test ATTACH PARTITION partitioning_test_2013 FOR VALUES FROM ('2013-01-01') TO ('2014-01-01'); + +-- see the data is loaded to shards +SELECT * FROM partitioning_test ORDER BY 1; + +-- 5-) Failure cases while creating distributed partitioned tables +-- cannot distribute a partition if its parent is not distributed +CREATE TABLE partitioning_test_failure(id int, time date) PARTITION BY RANGE (time); +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); + +-- only hash distributed tables can have partitions +SELECT create_distributed_table('partitioning_test_failure', 'id', 'append'); +SELECT create_distributed_table('partitioning_test_failure', 'id', 'range'); +SELECT create_reference_table('partitioning_test_failure'); + +-- replication factor > 1 is not allowed in distributed partitioned tables +SET citus.shard_replication_factor TO 2; +SELECT create_distributed_table('partitioning_test_failure', 'id'); +SET citus.shard_replication_factor TO 1; + +-- non-distributed tables cannot have distributed partitions; +DROP TABLE partitioning_test_failure_2009; +CREATE TABLE partitioning_test_failure_2009(id int, time date); +SELECT create_distributed_table('partitioning_test_failure_2009', 'id'); +ALTER TABLE partitioning_test_failure ATTACH PARTITION partitioning_test_failure_2009 FOR VALUES FROM ('2009-01-01') TO ('2010-01-01'); + +-- multi-level partitioning is not allowed +DROP TABLE partitioning_test_failure_2009; +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); +SELECT create_distributed_table('partitioning_test_failure', 'id'); + +-- multi-level partitioning is not allowed in different order +DROP TABLE partitioning_test_failure_2009; +SELECT create_distributed_table('partitioning_test_failure', 'id'); +CREATE TABLE partitioning_test_failure_2009 PARTITION OF partitioning_test_failure FOR VALUES FROM ('2009-01-01') TO ('2010-01-01') PARTITION BY RANGE (time); + + +-- +-- DMLs in distributed partitioned tables +-- + +-- test COPY +-- COPY data to partitioned table +COPY partitioning_test FROM STDIN WITH CSV; +9,2009-01-01 +10,2010-01-01 +11,2011-01-01 +12,2012-01-01 +\. + + +-- COPY data to partition directly +COPY partitioning_test_2009 FROM STDIN WITH CSV; +13,2009-01-02 +14,2009-01-03 +\. + +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 9 ORDER BY 1; + +-- test INSERT +-- INSERT INTO the partitioned table +INSERT INTO partitioning_test VALUES(15, '2009-02-01'); +INSERT INTO partitioning_test VALUES(16, '2010-02-01'); +INSERT INTO partitioning_test VALUES(17, '2011-02-01'); +INSERT INTO partitioning_test VALUES(18, '2012-02-01'); + +-- INSERT INTO the partitions directly table +INSERT INTO partitioning_test VALUES(19, '2009-02-02'); +INSERT INTO partitioning_test VALUES(20, '2010-02-02'); + +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id >= 15 ORDER BY 1; + +-- test INSERT/SELECT +-- INSERT/SELECT from partition to partitioned table +INSERT INTO partitioning_test SELECT * FROM partitioning_test_2011; + +-- INSERT/SELECT from partitioned table to partition +INSERT INTO partitioning_test_2012 SELECT * FROM partitioning_test WHERE time >= '2012-01-01' AND time < '2013-01-01'; + +-- see the data is loaded to shards (rows in the given range should be duplicated) +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2013-01-01' ORDER BY 1; + +-- test UPDATE +-- UPDATE partitioned table +UPDATE partitioning_test SET time = '2013-07-07' WHERE id = 7; + +-- UPDATE partition directly +UPDATE partitioning_test_2013 SET time = '2013-08-08' WHERE id = 8; + +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 7 OR id = 8 ORDER BY 1; + +-- UPDATE that tries to move a row to a non-existing partition (this should fail) +UPDATE partitioning_test SET time = '2020-07-07' WHERE id = 7; + +-- UPDATE with subqueries on partitioned table +UPDATE + partitioning_test +SET + time = time + INTERVAL '1 day' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 1); + +-- UPDATE with subqueries on partition +UPDATE + partitioning_test_2009 +SET + time = time + INTERVAL '1 month' +WHERE + id IN (SELECT id FROM partitioning_test WHERE id = 2); + +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 1 OR id = 2 ORDER BY 1; + +-- test DELETE +-- DELETE from partitioned table +DELETE FROM partitioning_test WHERE id = 9; + +-- DELETE from partition directly +DELETE FROM partitioning_test_2010 WHERE id = 10; + +-- see the data is deleted +SELECT * FROM partitioning_test WHERE id = 9 OR id = 10 ORDER BY 1; + +-- test master_modify_multiple_shards +-- master_modify_multiple_shards on partitioned table +SELECT master_modify_multiple_shards('UPDATE partitioning_test SET time = time + INTERVAL ''1 day'''); + +-- see rows are UPDATED +SELECT * FROM partitioning_test ORDER BY 1; + +-- master_modify_multiple_shards on partition directly +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''1 day'''); + +-- see rows are UPDATED +SELECT * FROM partitioning_test_2009 ORDER BY 1; + +-- test master_modify_multiple_shards which fails in workers (updated value is outside of partition bounds) +SELECT master_modify_multiple_shards('UPDATE partitioning_test_2009 SET time = time + INTERVAL ''6 month'''); + +-- +-- DDL in distributed partitioned tables +-- + +-- test CREATE INDEX +-- CREATE INDEX on partitioned table - this will error out +CREATE INDEX partitioning_index ON partitioning_test(id); + +-- CREATE INDEX on partition +CREATE INDEX partitioning_2009_index ON partitioning_test_2009(id); + +-- CREATE INDEX CONCURRENTLY on partition +CREATE INDEX CONCURRENTLY partitioned_2010_index ON partitioning_test_2010(id); + +-- see index is created +SELECT tablename, indexname FROM pg_indexes WHERE tablename LIKE 'partitioning_test%' ORDER BY indexname; + +-- test add COLUMN +-- add COLUMN to partitioned table +ALTER TABLE partitioning_test ADD new_column int; + +-- add COLUMN to partition - this will error out +ALTER TABLE partitioning_test_2010 ADD new_column_2 int; + +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test_2010'::regclass ORDER BY 1; + +-- test add PRIMARY KEY +-- add PRIMARY KEY to partitioned table - this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_primary PRIMARY KEY (id); + +-- ADD PRIMARY KEY to partition +ALTER TABLE partitioning_test_2009 ADD CONSTRAINT partitioning_2009_primary PRIMARY KEY (id); + +-- see PRIMARY KEY is created +SELECT + table_name, + constraint_name, + constraint_type +FROM + information_schema.table_constraints +WHERE + table_name = 'partitioning_test_2009' AND + constraint_name = 'partitioning_2009_primary'; + +-- test ADD FOREIGN CONSTRAINT +-- add FOREIGN CONSTRAINT to partitioned table -- this will error out +ALTER TABLE partitioning_test ADD CONSTRAINT partitioning_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id); + +-- add FOREIGN CONSTRAINT to partition +INSERT INTO partitioning_test_2009 VALUES (5, '2009-06-06'); +INSERT INTO partitioning_test_2009 VALUES (6, '2009-07-07'); +INSERT INTO partitioning_test_2009 VALUES(12, '2009-02-01'); +INSERT INTO partitioning_test_2009 VALUES(18, '2009-02-01'); +ALTER TABLE partitioning_test_2012 ADD CONSTRAINT partitioning_2012_foreign FOREIGN KEY (id) REFERENCES partitioning_test_2009 (id) ON DELETE CASCADE; + +-- see FOREIGN KEY is created +SELECT "Constraint" FROM table_fkeys WHERE relid = 'partitioning_test_2012'::regclass ORDER BY 1; + +-- test ON DELETE CASCADE works +DELETE FROM partitioning_test_2009 WHERE id = 5; + +-- see that element is deleted from both partitions +SELECT * FROM partitioning_test_2009 WHERE id = 5 ORDER BY 1; +SELECT * FROM partitioning_test_2012 WHERE id = 5 ORDER BY 1; + +-- test DETACH partition +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2009; + +-- see DETACHed partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2009-01-01' AND time < '2010-01-01' ORDER BY 1; + +-- +-- Transaction tests +-- + +-- DDL in transaction +BEGIN; +ALTER TABLE partitioning_test ADD newer_column int; + +-- see additional column is created +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; + +ROLLBACK; + +-- see rollback is successful +SELECT name, type FROM table_attrs WHERE relid = 'partitioning_test'::regclass ORDER BY 1; + +-- COPY in transaction +BEGIN; +COPY partitioning_test FROM STDIN WITH CSV; +22,2010-01-01,22 +23,2011-01-01,23 +24,2013-01-01,24 +\. + +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 22 ORDER BY 1; +SELECT * FROM partitioning_test WHERE id = 23 ORDER BY 1; +SELECT * FROM partitioning_test WHERE id = 24 ORDER BY 1; + +ROLLBACK; + +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id >= 22 ORDER BY 1; + +-- DML in transaction +BEGIN; + +-- INSERT in transaction +INSERT INTO partitioning_test VALUES(25, '2010-02-02'); + +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + +-- INSERT/SELECT in transaction +INSERT INTO partitioning_test SELECT * FROM partitioning_test WHERE id = 25; + +-- see the data is loaded to shards +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + +-- UPDATE in transaction +UPDATE partitioning_test SET time = '2010-10-10' WHERE id = 25; + +-- see the data is updated +SELECT * FROM partitioning_test WHERE id = 25 ORDER BY 1; + +-- perform operations on partition and partioned tables together +INSERT INTO partitioning_test VALUES(26, '2010-02-02', 26); +INSERT INTO partitioning_test_2010 VALUES(26, '2010-02-02', 26); +COPY partitioning_test FROM STDIN WITH CSV; +26,2010-02-02,26 +\. +COPY partitioning_test_2010 FROM STDIN WITH CSV; +26,2010-02-02,26 +\. + +-- see the data is loaded to shards (we should see 4 rows with same content) +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; + +ROLLBACK; + +-- see rollback is successful +SELECT * FROM partitioning_test WHERE id = 26 ORDER BY 1; + +-- DETACH and DROP in a transaction +BEGIN; +ALTER TABLE partitioning_test DETACH PARTITION partitioning_test_2011; +DROP TABLE partitioning_test_2011; +COMMIT; + +-- see DROPed partitions content is not accessible +SELECT * FROM partitioning_test WHERE time >= '2011-01-01' AND time < '2012-01-01' ORDER BY 1; + +-- +-- Misc tests +-- + +-- test TRUNCATE +-- test TRUNCATE partition +TRUNCATE partitioning_test_2012; + +-- see partition is TRUNCATEd +SELECT * FROM partitioning_test_2012 ORDER BY 1; + +-- test TRUNCATE partitioned table +TRUNCATE partitioning_test; + +-- see partitioned table is TRUNCATEd +SELECT * FROM partitioning_test ORDER BY 1; + +-- test DROP +-- test DROP partition +INSERT INTO partitioning_test_2010 VALUES(27, '2010-02-01'); +DROP TABLE partitioning_test_2010; + +-- see DROPped partitions content is not accessible from partitioning_test; +SELECT * FROM partitioning_test WHERE time >= '2010-01-01' AND time < '2011-01-01' ORDER BY 1; + +-- test DROP partitioned table +DROP TABLE partitioning_test; + +-- dropping the parent should CASCADE to the children as well +SELECT table_name FROM information_schema.tables WHERE table_name LIKE 'partitioning_test%' ORDER BY 1; + +-- test distributing partitioned table colocated with non-partitioned table +CREATE TABLE partitioned_users_table (user_id int, time timestamp, value_1 int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); +CREATE TABLE partitioned_events_table (user_id int, time timestamp, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY RANGE (time); + +SELECT create_distributed_table('partitioned_users_table', 'user_id', colocate_with => 'users_table'); +SELECT create_distributed_table('partitioned_events_table', 'user_id', colocate_with => 'events_table'); + +-- INSERT/SELECT from regular table to partitioned table +CREATE TABLE partitioned_users_table_2009 PARTITION OF partitioned_users_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); +CREATE TABLE partitioned_events_table_2009 PARTITION OF partitioned_events_table FOR VALUES FROM ('2014-01-01') TO ('2015-01-01'); + +INSERT INTO partitioned_events_table SELECT * FROM events_table; +INSERT INTO partitioned_users_table_2009 SELECT * FROM users_table; + +-- +-- Complex JOINs, subqueries, UNIONs etc... +-- + +-- subquery with UNIONs on partitioned table +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM( + (SELECT + "events"."user_id", "events"."time", 0 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15)) + UNION + (SELECT + "events"."user_id", "events"."time", 1 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (15, 16, 17, 18, 19) ) + UNION + (SELECT + "events"."user_id", "events"."time", 2 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) + UNION + (SELECT + "events"."user_id", "events"."time", 3 AS event + FROM + partitioned_events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13))) t1 + GROUP BY "t1"."user_id") AS t) "q" +) AS final_query +GROUP BY types +ORDER BY types; + +-- UNION and JOIN on both partitioned and regular tables +SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType +FROM + (SELECT + *, random() + FROM + (SELECT + "t"."user_id", "t"."time", unnest("t"."collected_events") AS "event_types" + FROM + (SELECT + "t1"."user_id", min("t1"."time") AS "time", array_agg(("t1"."event") ORDER BY TIME ASC, event DESC) AS collected_events + FROM ( + (SELECT + * + FROM + (SELECT + "events"."time", 0 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1) + UNION + (SELECT * + FROM + ( + SELECT * FROM + ( + SELECT + max("events"."time"), + 0 AS event, + "events"."user_id" + FROM + events_table as "events", users_table as "users" + WHERE + events.user_id = users.user_id AND + event_type IN (10, 11, 12, 13, 14, 15) + GROUP BY "events"."user_id" + ) as events_subquery_5 + ) events_subquery_2) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 2 AS event, "events"."user_id" + FROM + partitioned_events_table as "events" + WHERE + event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3) + UNION + (SELECT * + FROM + (SELECT + "events"."time", 3 AS event, "events"."user_id" + FROM + events_table as "events" + WHERE + event_type IN (26, 27, 28, 29, 30, 13)) events_subquery_4) + ) t1 + GROUP BY "t1"."user_id") AS t) "q" +INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + value_1 > 50 and value_1 < 70) AS t + ON (t.user_id = q.user_id)) as final_query +GROUP BY + types +ORDER BY + types; + +-- test LIST partitioning +CREATE TABLE list_partitioned_events_table (user_id int, time date, event_type int, value_2 int, value_3 float, value_4 bigint) PARTITION BY LIST (time); +CREATE TABLE list_partitioned_events_table_2014_01_01_05 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-01', '2014-01-02', '2014-01-03', '2014-01-04', '2014-01-05'); +CREATE TABLE list_partitioned_events_table_2014_01_06_10 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-06', '2014-01-07', '2014-01-08', '2014-01-09', '2014-01-10'); +CREATE TABLE list_partitioned_events_table_2014_01_11_15 PARTITION OF list_partitioned_events_table FOR VALUES IN ('2014-01-11', '2014-01-12', '2014-01-13', '2014-01-14', '2014-01-15'); + +-- test distributing partitioned table colocated with another partitioned table +SELECT create_distributed_table('list_partitioned_events_table', 'user_id', colocate_with => 'partitioned_events_table'); + +-- INSERT/SELECT from partitioned table to partitioned table +INSERT INTO + list_partitioned_events_table +SELECT + user_id, + date_trunc('day', time) as time, + event_type, + value_2, + value_3, + value_4 +FROM + events_table +WHERE + time >= '2014-01-01' AND + time <= '2014-01-15'; + +-- LEFT JOINs used with INNER JOINs on range partitioned table, list partitioned table and non-partitioned table +SELECT +count(*) AS cnt, "generated_group_field" + FROM + (SELECT + "eventQuery"."user_id", random(), generated_group_field + FROM + (SELECT + "multi_group_wrapper_1".*, generated_group_field, random() + FROM + (SELECT * + FROM + (SELECT + "list_partitioned_events_table"."time", "list_partitioned_events_table"."user_id" as event_user_id + FROM + list_partitioned_events_table as "list_partitioned_events_table" + WHERE + user_id > 80) "temp_data_queries" + INNER JOIN + (SELECT + "users"."user_id" + FROM + partitioned_users_table as "users" + WHERE + user_id > 80 and value_2 = 5) "user_filters_1" + ON ("temp_data_queries".event_user_id = "user_filters_1".user_id)) AS "multi_group_wrapper_1" + LEFT JOIN + (SELECT + "users"."user_id" AS "user_id", value_2 AS "generated_group_field" + FROM + partitioned_users_table as "users") "left_group_by_1" + ON ("left_group_by_1".user_id = "multi_group_wrapper_1".event_user_id)) "eventQuery") "pushedDownQuery" + GROUP BY + "generated_group_field" + ORDER BY + cnt DESC, generated_group_field ASC + LIMIT 10; + +-- +-- Additional partitioning features +-- + +-- test multi column partitioning +CREATE TABLE multi_column_partitioning(c1 int, c2 int) PARTITION BY RANGE (c1, c2); +CREATE TABLE multi_column_partitioning_0_0_10_0 PARTITION OF multi_column_partitioning FOR VALUES FROM (0, 0) TO (10, 0); +SELECT create_distributed_table('multi_column_partitioning', 'c1'); + +-- test INSERT to multi-column partitioned table +INSERT INTO multi_column_partitioning VALUES(1, 1); +INSERT INTO multi_column_partitioning_0_0_10_0 VALUES(5, -5); + +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(10, 1); + +-- test with MINVALUE/MAXVALUE +CREATE TABLE multi_column_partitioning_10_max_20_min PARTITION OF multi_column_partitioning FOR VALUES FROM (10, MAXVALUE) TO (20, MINVALUE); + +-- test INSERT to partition with MINVALUE/MAXVALUE bounds +INSERT INTO multi_column_partitioning VALUES(11, -11); +INSERT INTO multi_column_partitioning_10_max_20_min VALUES(19, -19); + +-- test INSERT to multi-column partitioned table where no suitable partition exists +INSERT INTO multi_column_partitioning VALUES(20, -20); + +-- see data is loaded to multi-column partitioned table +SELECT * FROM multi_column_partitioning; + +DROP TABLE IF EXISTS partitioning_test_2012, partitioning_test_2013, partitioned_events_table, partitioned_users_table, list_partitioned_events_table, multi_column_partitioning;