From 6f308c5e2ddb5c03cdd017b0cb3ed28f8b1e5971 Mon Sep 17 00:00:00 2001 From: Jason Petersen Date: Thu, 11 Feb 2016 16:09:35 -0700 Subject: [PATCH] Allow DML commands on append-partitioned tables This entirely removes any restriction on the type of partitioning during DML planning and execution. Though there aren't actually any technical limitations preventing DML commands against append- (or even range-) partitioned tables, we had initially forbidden this, as any future stage operation could cause shards to overlap, banning all subsequent DML operations to partition values contained within more than one shards. This ended up mostly restricting us, so we're now removing that restriction. --- .../distributed/planner/modify_planner.c | 10 ------- .../regress/expected/multi_modifications.out | 29 ++++++++++++++----- .../regress/expected/multi_simple_queries.out | 26 ++++++++--------- src/test/regress/sql/multi_modifications.sql | 21 ++++++++++---- 4 files changed, 49 insertions(+), 37 deletions(-) diff --git a/src/backend/distributed/planner/modify_planner.c b/src/backend/distributed/planner/modify_planner.c index 15a08ea16..faeb6b6b0 100644 --- a/src/backend/distributed/planner/modify_planner.c +++ b/src/backend/distributed/planner/modify_planner.c @@ -121,16 +121,6 @@ ErrorIfQueryNotSupported(Query *queryTree) Assert(commandType == CMD_INSERT || commandType == CMD_UPDATE || commandType == CMD_DELETE); - if (!(partitionMethod == DISTRIBUTE_BY_HASH || - partitionMethod == DISTRIBUTE_BY_RANGE)) - { - ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot perform distributed planning for the given" - " modification"), - errdetail("Only hash- or range-partitioned tables may be the " - "target of distributed modifications"))); - } - /* * Reject subqueries which are in SELECT or WHERE clause. * Queries which include subqueries in FROM clauses are rejected below. diff --git a/src/test/regress/expected/multi_modifications.out b/src/test/regress/expected/multi_modifications.out index 5da80026b..d48c47551 100644 --- a/src/test/regress/expected/multi_modifications.out +++ b/src/test/regress/expected/multi_modifications.out @@ -61,10 +61,14 @@ SELECT master_create_empty_shard('range_partitioned') AS new_shard_id \gset UPDATE pg_dist_shard SET shardminvalue = 50000, shardmaxvalue = 99999 WHERE shardid = :new_shard_id; --- create append-partitioned shard +-- create append-partitioned shards SELECT master_create_empty_shard('append_partitioned') AS new_shard_id \gset -UPDATE pg_dist_shard SET shardminvalue = 0, shardmaxvalue = 100000 +UPDATE pg_dist_shard SET shardminvalue = 0, shardmaxvalue = 500000 +WHERE shardid = :new_shard_id; +SELECT master_create_empty_shard('append_partitioned') AS new_shard_id +\gset +UPDATE pg_dist_shard SET shardminvalue = 500000, shardmaxvalue = 1000000 WHERE shardid = :new_shard_id; -- basic single-row INSERT INSERT INTO limit_orders VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', @@ -82,7 +86,10 @@ ERROR: distributed modifications must target exactly one shard -- try an insert to a range-partitioned table INSERT INTO range_partitioned VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); --- ensure the value is where we put it and query to find it is properly pruned +-- also insert to an append-partitioned table +INSERT INTO append_partitioned VALUES (414123, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', + 20.69); +-- ensure the values are where we put them and query to ensure they are properly pruned SET client_min_messages TO 'DEBUG2'; SET citusdb.task_executor_type TO 'router'; SELECT * FROM range_partitioned WHERE id = 32743; @@ -92,17 +99,23 @@ DEBUG: predicate pruning for shardId 103070 32743 | AAPL | 9580 | Tue Oct 19 10:23:54 2004 | buy | 20.69 (1 row) +SELECT * FROM append_partitioned WHERE id = 414123; +DEBUG: predicate pruning for shardId 103072 + id | symbol | bidder_id | placed_at | kind | limit_price +--------+--------+-----------+--------------------------+------+------------- + 414123 | AAPL | 9580 | Tue Oct 19 10:23:54 2004 | buy | 20.69 +(1 row) + SET client_min_messages TO DEFAULT; SET citusdb.task_executor_type TO DEFAULT; --- also try inserting without a range-partitioned shard to receive the value +-- try inserting without a range-partitioned shard to receive the value INSERT INTO range_partitioned VALUES (999999, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); ERROR: distributed modifications must target exactly one shard --- try an insert to an append-partitioned table -INSERT INTO append_partitioned VALUES (414123, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', +-- and insert into an append-partitioned table with a value that spans shards: +INSERT INTO append_partitioned VALUES (500000, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); -ERROR: cannot perform distributed planning for the given modification -DETAIL: Only hash- or range-partitioned tables may be the target of distributed modifications +ERROR: distributed modifications must target exactly one shard -- INSERT with DEFAULT in the target list INSERT INTO limit_orders VALUES (12756, 'MSFT', 10959, '2013-05-08 07:29:23', 'sell', DEFAULT); diff --git a/src/test/regress/expected/multi_simple_queries.out b/src/test/regress/expected/multi_simple_queries.out index 4407ec697..734dfbde2 100644 --- a/src/test/regress/expected/multi_simple_queries.out +++ b/src/test/regress/expected/multi_simple_queries.out @@ -309,7 +309,7 @@ SET client_min_messages TO 'DEBUG2'; SELECT * FROM articles WHERE author_id = 1; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 id | author_id | title | word_count ----+-----------+--------------+------------ 1 | 1 | arsenous | 9572 @@ -323,7 +323,7 @@ DEBUG: predicate pruning for shardId 103093 SELECT * FROM articles WHERE author_id = 1 OR author_id = 17; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 id | author_id | title | word_count ----+-----------+--------------+------------ 1 | 1 | arsenous | 9572 @@ -343,7 +343,7 @@ HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". SELECT id as article_id, word_count * id as random_value FROM articles WHERE author_id = 1; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 article_id | random_value ------------+-------------- 1 | 9572 @@ -360,7 +360,7 @@ SELECT a.author_id as first_author, b.word_count as second_word_count WHERE a.author_id = 10 and a.author_id = b.author_id LIMIT 3; DEBUG: push down of limit count: 3 -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 DEBUG: join prunable for intervals [-2147483648,-1] and [0,2147483647] first_author | second_word_count --------------+------------------- @@ -375,7 +375,7 @@ SELECT a.author_id as first_author, b.word_count as second_word_count WHERE a.author_id = 10 and a.author_id = b.author_id LIMIT 3; DEBUG: push down of limit count: 3 -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 ERROR: cannot use router executor with JOINs HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- do not create the master query for LIMIT on a single shard SELECT @@ -384,7 +384,7 @@ SELECT * WHERE author_id = 1 LIMIT 2; DEBUG: push down of limit count: 2 -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 id | author_id | title | word_count ----+-----------+----------+------------ 1 | 1 | arsenous | 9572 @@ -398,7 +398,7 @@ SELECT id FROM articles WHERE author_id = 1 GROUP BY id; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 id ---- 41 @@ -415,7 +415,7 @@ COPY articles_single_shard TO stdout; SELECT avg(word_count) FROM articles WHERE author_id = 2; -DEBUG: predicate pruning for shardId 103092 +DEBUG: predicate pruning for shardId 103093 ERROR: cannot use router executor with aggregates HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- max, min, sum, count is somehow implemented @@ -424,7 +424,7 @@ SELECT max(word_count) as max, min(word_count) as min, sum(word_count) as sum, count(word_count) as cnt FROM articles WHERE author_id = 2; -DEBUG: predicate pruning for shardId 103092 +DEBUG: predicate pruning for shardId 103093 ERROR: cannot use router executor with aggregates HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- error out for queries with ORDER BY @@ -432,7 +432,7 @@ SELECT * FROM articles WHERE author_id = 1 ORDER BY word_count; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 ERROR: cannot use router executor with ORDER BY clauses HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- error out for queries with ORDER BY and LIMIT @@ -442,7 +442,7 @@ SELECT * ORDER BY word_count LIMIT 2; DEBUG: push down of limit count: 2 -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 ERROR: cannot use router executor with ORDER BY clauses HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- error out for queries with aggregates and GROUP BY @@ -450,14 +450,14 @@ SELECT max(word_count) FROM articles WHERE author_id = 1 GROUP BY author_id; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 ERROR: cannot use router executor with aggregates HINT: Set citusdb.task_executor_type to "real-time" or "task-tracker". -- error out for queries with repartition jobs SELECT * FROM articles a, articles b WHERE a.id = b.id AND a.author_id = 1; -DEBUG: predicate pruning for shardId 103093 +DEBUG: predicate pruning for shardId 103094 DEBUG: join prunable for task partitionId 0 and 1 DEBUG: join prunable for task partitionId 0 and 2 DEBUG: join prunable for task partitionId 0 and 3 diff --git a/src/test/regress/sql/multi_modifications.sql b/src/test/regress/sql/multi_modifications.sql index 040411079..390913dfb 100644 --- a/src/test/regress/sql/multi_modifications.sql +++ b/src/test/regress/sql/multi_modifications.sql @@ -40,10 +40,15 @@ SELECT master_create_empty_shard('range_partitioned') AS new_shard_id UPDATE pg_dist_shard SET shardminvalue = 50000, shardmaxvalue = 99999 WHERE shardid = :new_shard_id; --- create append-partitioned shard +-- create append-partitioned shards SELECT master_create_empty_shard('append_partitioned') AS new_shard_id \gset -UPDATE pg_dist_shard SET shardminvalue = 0, shardmaxvalue = 100000 +UPDATE pg_dist_shard SET shardminvalue = 0, shardmaxvalue = 500000 +WHERE shardid = :new_shard_id; + +SELECT master_create_empty_shard('append_partitioned') AS new_shard_id +\gset +UPDATE pg_dist_shard SET shardminvalue = 500000, shardmaxvalue = 1000000 WHERE shardid = :new_shard_id; -- basic single-row INSERT @@ -59,19 +64,23 @@ INSERT INTO insufficient_shards VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:5 INSERT INTO range_partitioned VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); --- ensure the value is where we put it and query to find it is properly pruned +-- also insert to an append-partitioned table +INSERT INTO append_partitioned VALUES (414123, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', + 20.69); +-- ensure the values are where we put them and query to ensure they are properly pruned SET client_min_messages TO 'DEBUG2'; SET citusdb.task_executor_type TO 'router'; SELECT * FROM range_partitioned WHERE id = 32743; +SELECT * FROM append_partitioned WHERE id = 414123; SET client_min_messages TO DEFAULT; SET citusdb.task_executor_type TO DEFAULT; --- also try inserting without a range-partitioned shard to receive the value +-- try inserting without a range-partitioned shard to receive the value INSERT INTO range_partitioned VALUES (999999, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); --- try an insert to an append-partitioned table -INSERT INTO append_partitioned VALUES (414123, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', +-- and insert into an append-partitioned table with a value that spans shards: +INSERT INTO append_partitioned VALUES (500000, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 20.69); -- INSERT with DEFAULT in the target list