From 93e79b92626cce49b5c03d4d0624903ce056ce4a Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 15 Oct 2021 17:46:09 +0200 Subject: [PATCH] Never allow co-located joins of append-distributed tables --- .../planner/multi_logical_planner.c | 6 + .../planner/multi_physical_planner.c | 34 +- .../relation_restriction_equivalence.c | 41 ++ .../regress/expected/multi_join_pruning.out | 6 +- .../expected/multi_partition_pruning.out | 51 +-- .../regress/input/multi_outer_join.source | 23 +- .../regress/output/multi_outer_join.source | 414 ++++++++++-------- .../regress/sql/multi_partition_pruning.sql | 6 +- 8 files changed, 341 insertions(+), 240 deletions(-) diff --git a/src/backend/distributed/planner/multi_logical_planner.c b/src/backend/distributed/planner/multi_logical_planner.c index 0691df7cb..3bab7d1bc 100644 --- a/src/backend/distributed/planner/multi_logical_planner.c +++ b/src/backend/distributed/planner/multi_logical_planner.c @@ -234,6 +234,12 @@ TargetListOnPartitionColumn(Query *query, List *targetEntryList) continue; } + /* append-distributed tables do not have a strict partition column */ + if (IsCitusTableType(relationId, APPEND_DISTRIBUTED)) + { + continue; + } + if (isPartitionColumn) { FieldSelect *compositeField = CompositeFieldRecursive(targetExpression, diff --git a/src/backend/distributed/planner/multi_physical_planner.c b/src/backend/distributed/planner/multi_physical_planner.c index b9531a4be..a8f4f50c9 100644 --- a/src/backend/distributed/planner/multi_physical_planner.c +++ b/src/backend/distributed/planner/multi_physical_planner.c @@ -2445,16 +2445,6 @@ ErrorIfUnsupportedShardDistribution(Query *query) } else { - CitusTableCacheEntry *distTableEntry = GetCitusTableCacheEntry(relationId); - if (distTableEntry->hasOverlappingShardInterval) - { - ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("cannot push down this subquery"), - errdetail("Currently append partitioned relations " - "with overlapping shard intervals are " - "not supported"))); - } - appendDistributedRelationCount++; } } @@ -2647,14 +2637,19 @@ QueryPushdownTaskCreate(Query *originalQuery, int shardIndex, bool CoPartitionedTables(Oid firstRelationId, Oid secondRelationId) { - if (firstRelationId == secondRelationId) - { - return true; - } - CitusTableCacheEntry *firstTableCache = GetCitusTableCacheEntry(firstRelationId); CitusTableCacheEntry *secondTableCache = GetCitusTableCacheEntry(secondRelationId); + if (firstTableCache->partitionMethod == DISTRIBUTE_BY_APPEND || + secondTableCache->partitionMethod == DISTRIBUTE_BY_APPEND) + { + /* + * Append-distributed tables can have overlapping shards. Therefore they are + * never co-partitioned, not even with themselves. + */ + return false; + } + /* * Check if the tables have the same colocation ID - if so, we know * they're colocated. @@ -2665,6 +2660,15 @@ CoPartitionedTables(Oid firstRelationId, Oid secondRelationId) return true; } + if (firstRelationId == secondRelationId) + { + /* + * Even without an explicit co-location ID, non-append tables can be considered + * co-located with themselves. + */ + return true; + } + return false; } diff --git a/src/backend/distributed/planner/relation_restriction_equivalence.c b/src/backend/distributed/planner/relation_restriction_equivalence.c index eb4394256..437bef6b4 100644 --- a/src/backend/distributed/planner/relation_restriction_equivalence.c +++ b/src/backend/distributed/planner/relation_restriction_equivalence.c @@ -85,6 +85,7 @@ typedef struct AttributeEquivalenceClassMember static bool ContextContainsLocalRelation(RelationRestrictionContext *restrictionContext); +static bool ContextContainsAppendRelation(RelationRestrictionContext *restrictionContext); static int RangeTableOffsetCompat(PlannerInfo *root, AppendRelInfo *appendRelInfo); static Var * FindUnionAllVar(PlannerInfo *root, List *translatedVars, Oid relationOid, Index relationRteIndex, Index *partitionKeyIndex); @@ -236,6 +237,29 @@ ContextContainsLocalRelation(RelationRestrictionContext *restrictionContext) } +/* + * ContextContainsAppendRelation determines whether the given + * RelationRestrictionContext contains any append-distributed tables. + */ +static bool +ContextContainsAppendRelation(RelationRestrictionContext *restrictionContext) +{ + ListCell *relationRestrictionCell = NULL; + + foreach(relationRestrictionCell, restrictionContext->relationRestrictionList) + { + RelationRestriction *relationRestriction = lfirst(relationRestrictionCell); + + if (IsCitusTableType(relationRestriction->relationId, APPEND_DISTRIBUTED)) + { + return true; + } + } + + return false; +} + + /* * SafeToPushdownUnionSubquery returns true if all the relations are returns * partition keys in the same ordinal position and there is no reference table @@ -504,6 +528,12 @@ RestrictionEquivalenceForPartitionKeys(PlannerRestrictionContext *restrictionCon /* there is a single distributed relation, no need to continue */ return true; } + else if (ContextContainsAppendRelation( + restrictionContext->relationRestrictionContext)) + { + /* we never consider append-distributed tables co-located */ + return false; + } List *attributeEquivalenceList = GenerateAllAttributeEquivalences(restrictionContext); @@ -1906,6 +1936,17 @@ AllRelationsInRestrictionContextColocated(RelationRestrictionContext *restrictio continue; } + if (IsCitusTableType(relationId, APPEND_DISTRIBUTED)) + { + /* + * If we got to this point, it means there are multiple distributed + * relations and at least one of them is append-distributed. Since + * we do not consider append-distributed tables to be co-located, + * we can immediately return false. + */ + return false; + } + int colocationId = TableColocationId(relationId); if (initialColocationId == INVALID_COLOCATION_ID) diff --git a/src/test/regress/expected/multi_join_pruning.out b/src/test/regress/expected/multi_join_pruning.out index 77131da45..df6d94197 100644 --- a/src/test/regress/expected/multi_join_pruning.out +++ b/src/test/regress/expected/multi_join_pruning.out @@ -101,7 +101,7 @@ EXPLAIN (COSTS OFF) SELECT count(*) FROM array_partitioned_table table1, array_partitioned_table table2 WHERE table1.array_column = table2.array_column; -DEBUG: Router planner does not support append-partitioned tables. +DEBUG: Router planner cannot handle multi-shard select queries DEBUG: join prunable for intervals [{},{AZZXSP27F21T6,AZZXSP27F21T6}] and [{BA1000U2AMO4ZGX,BZZXSP27F21T6},{CA1000U2AMO4ZGX,CZZXSP27F21T6}] DEBUG: join prunable for intervals [{BA1000U2AMO4ZGX,BZZXSP27F21T6},{CA1000U2AMO4ZGX,CZZXSP27F21T6}] and [{},{AZZXSP27F21T6,AZZXSP27F21T6}] QUERY PLAN @@ -115,7 +115,7 @@ EXPLAIN (COSTS OFF) SELECT count(*) FROM composite_partitioned_table table1, composite_partitioned_table table2 WHERE table1.composite_column = table2.composite_column; -DEBUG: Router planner does not support append-partitioned tables. +DEBUG: Router planner cannot handle multi-shard select queries DEBUG: join prunable for intervals [(a,3,b),(b,4,c)] and [(c,5,d),(d,6,e)] DEBUG: join prunable for intervals [(c,5,d),(d,6,e)] and [(a,3,b),(b,4,c)] QUERY PLAN @@ -130,7 +130,7 @@ EXPLAIN (COSTS OFF) SELECT count(*) FROM varchar_partitioned_table table1, varchar_partitioned_table table2 WHERE table1.varchar_column = table2.varchar_column; -DEBUG: Router planner does not support append-partitioned tables. +DEBUG: Router planner cannot handle multi-shard select queries DEBUG: join prunable for intervals [AA1000U2AMO4ZGX,AZZXSP27F21T6] and [BA1000U2AMO4ZGX,BZZXSP27F21T6] DEBUG: join prunable for intervals [BA1000U2AMO4ZGX,BZZXSP27F21T6] and [AA1000U2AMO4ZGX,AZZXSP27F21T6] QUERY PLAN diff --git a/src/test/regress/expected/multi_partition_pruning.out b/src/test/regress/expected/multi_partition_pruning.out index 1d65721b7..87eee868a 100644 --- a/src/test/regress/expected/multi_partition_pruning.out +++ b/src/test/regress/expected/multi_partition_pruning.out @@ -57,7 +57,7 @@ CREATE TABLE varchar_partitioned_table ( varchar_column varchar(100) ); -SELECT create_distributed_table('varchar_partitioned_table', 'varchar_column', 'append'); +SELECT create_distributed_table('varchar_partitioned_table', 'varchar_column', 'range'); create_distributed_table --------------------------------------------------------------------- @@ -85,7 +85,7 @@ CREATE TABLE array_partitioned_table ( array_column text[] ); -SELECT create_distributed_table('array_partitioned_table', 'array_column', 'append'); +SELECT create_distributed_table('array_partitioned_table', 'array_column', 'range'); create_distributed_table --------------------------------------------------------------------- @@ -121,7 +121,7 @@ CREATE TABLE composite_partitioned_table ( composite_column composite_type ); -SELECT create_distributed_table('composite_partitioned_table', 'composite_column', 'append'); +SELECT create_distributed_table('composite_partitioned_table', 'composite_column', 'range'); create_distributed_table --------------------------------------------------------------------- @@ -150,40 +150,37 @@ INSERT INTO pg_dist_shard_placement (shardid, shardstate, shardlength, nodename, SET client_min_messages TO ERROR; EXPLAIN (COSTS OFF) SELECT count(*) FROM varchar_partitioned_table WHERE varchar_column = 'BA2'; - QUERY PLAN + QUERY PLAN --------------------------------------------------------------------- - Aggregate - -> Custom Scan (Citus Adaptive) - Task Count: 1 - Tasks Shown: All - -> Task - Error: Could not get remote plan. -(6 rows) + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Error: Could not get remote plan. +(5 rows) EXPLAIN (COSTS OFF) SELECT count(*) FROM array_partitioned_table WHERE array_column > '{BA1000U2AMO4ZGX, BZZXSP27F21T6}'; - QUERY PLAN + QUERY PLAN --------------------------------------------------------------------- - Aggregate - -> Custom Scan (Citus Adaptive) - Task Count: 1 - Tasks Shown: All - -> Task - Error: Could not get remote plan. -(6 rows) + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Error: Could not get remote plan. +(5 rows) EXPLAIN (COSTS OFF) SELECT count(*) FROM composite_partitioned_table WHERE composite_column < '(b,5,c)'::composite_type; - QUERY PLAN + QUERY PLAN --------------------------------------------------------------------- - Aggregate - -> Custom Scan (Citus Adaptive) - Task Count: 1 - Tasks Shown: All - -> Task - Error: Could not get remote plan. -(6 rows) + Custom Scan (Citus Adaptive) + Task Count: 1 + Tasks Shown: All + -> Task + Error: Could not get remote plan. +(5 rows) SET client_min_messages TO NOTICE; diff --git a/src/test/regress/input/multi_outer_join.source b/src/test/regress/input/multi_outer_join.source index 820e9c625..f4708da13 100644 --- a/src/test/regress/input/multi_outer_join.source +++ b/src/test/regress/input/multi_outer_join.source @@ -16,7 +16,7 @@ CREATE TABLE multi_outer_join_left l_mktsegment char(10) not null, l_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_left', 'l_custkey', 'append'); +SELECT create_distributed_table('multi_outer_join_left', 'l_custkey', 'hash'); CREATE TABLE multi_outer_join_right ( @@ -29,7 +29,7 @@ CREATE TABLE multi_outer_join_right r_mktsegment char(10) not null, r_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_right', 'r_custkey', 'append'); +SELECT create_distributed_table('multi_outer_join_right', 'r_custkey', 'hash'); CREATE TABLE multi_outer_join_right_reference ( @@ -55,7 +55,7 @@ CREATE TABLE multi_outer_join_third t_mktsegment char(10) not null, t_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_third', 't_custkey', 'append'); +SELECT create_distributed_table('multi_outer_join_third', 't_custkey', 'hash'); CREATE TABLE multi_outer_join_third_reference ( @@ -70,18 +70,8 @@ CREATE TABLE multi_outer_join_third_reference ); SELECT create_reference_table('multi_outer_join_third_reference'); - --- Make sure we do not crash if both tables have no shards -SELECT - min(l_custkey), max(l_custkey) -FROM - multi_outer_join_left a LEFT JOIN multi_outer_join_third b ON (l_custkey = t_custkey); - --- Left table is a large table \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-1-10.data' with delimiter '|' \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-11-20.data' with delimiter '|' - --- Right table is a small table \copy multi_outer_join_right FROM '@abs_srcdir@/data/customer-1-15.data' with delimiter '|' \copy multi_outer_join_right_reference FROM '@abs_srcdir@/data/customer-1-15.data' with delimiter '|' @@ -187,8 +177,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); -- empty tables -SELECT * FROM master_apply_delete_command('DELETE FROM multi_outer_join_left'); -SELECT * FROM master_apply_delete_command('DELETE FROM multi_outer_join_right'); +TRUNCATE multi_outer_join_left; +TRUNCATE multi_outer_join_right; -- reload shards with 1-1 matching \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-subset-11-20.data' with delimiter '|' @@ -482,7 +472,8 @@ FROM (multi_outer_join_right r1 LEFT OUTER JOIN multi_outer_join_left l1 ON (l1.l_custkey = r1.r_custkey)) AS test(c_custkey, c_nationkey) - INNER JOIN multi_outer_join_third t1 ON (test.c_custkey = t1.t_custkey); + INNER JOIN multi_outer_join_third t1 ON (test.c_custkey = t1.t_custkey) +ORDER BY 1; -- simple test to ensure anti-joins work with hash-partitioned tables CREATE TABLE left_values(val int); diff --git a/src/test/regress/output/multi_outer_join.source b/src/test/regress/output/multi_outer_join.source index e4b43ec0d..94a152989 100644 --- a/src/test/regress/output/multi_outer_join.source +++ b/src/test/regress/output/multi_outer_join.source @@ -12,10 +12,10 @@ CREATE TABLE multi_outer_join_left l_mktsegment char(10) not null, l_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_left', 'l_custkey', 'append'); - master_create_distributed_table ---------------------------------- - +SELECT create_distributed_table('multi_outer_join_left', 'l_custkey', 'hash'); + create_distributed_table +--------------------------------------------------------------------- + (1 row) CREATE TABLE multi_outer_join_right @@ -29,10 +29,10 @@ CREATE TABLE multi_outer_join_right r_mktsegment char(10) not null, r_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_right', 'r_custkey', 'append'); - master_create_distributed_table ---------------------------------- - +SELECT create_distributed_table('multi_outer_join_right', 'r_custkey', 'hash'); + create_distributed_table +--------------------------------------------------------------------- + (1 row) CREATE TABLE multi_outer_join_right_reference @@ -47,9 +47,9 @@ CREATE TABLE multi_outer_join_right_reference r_comment varchar(117) not null ); SELECT create_reference_table('multi_outer_join_right_reference'); - create_reference_table ------------------------- - + create_reference_table +--------------------------------------------------------------------- + (1 row) CREATE TABLE multi_outer_join_third @@ -63,10 +63,10 @@ CREATE TABLE multi_outer_join_third t_mktsegment char(10) not null, t_comment varchar(117) not null ); -SELECT master_create_distributed_table('multi_outer_join_third', 't_custkey', 'append'); - master_create_distributed_table ---------------------------------- - +SELECT create_distributed_table('multi_outer_join_third', 't_custkey', 'hash'); + create_distributed_table +--------------------------------------------------------------------- + (1 row) CREATE TABLE multi_outer_join_third_reference @@ -81,25 +81,13 @@ CREATE TABLE multi_outer_join_third_reference t_comment varchar(117) not null ); SELECT create_reference_table('multi_outer_join_third_reference'); - create_reference_table ------------------------- - + create_reference_table +--------------------------------------------------------------------- + (1 row) --- Make sure we do not crash if both tables have no shards -SELECT - min(l_custkey), max(l_custkey) -FROM - multi_outer_join_left a LEFT JOIN multi_outer_join_third b ON (l_custkey = t_custkey); - min | max ------+----- - | -(1 row) - --- Left table is a large table \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-1-10.data' with delimiter '|' \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-11-20.data' with delimiter '|' --- Right table is a small table \copy multi_outer_join_right FROM '@abs_srcdir@/data/customer-1-15.data' with delimiter '|' \copy multi_outer_join_right_reference FROM '@abs_srcdir@/data/customer-1-15.data' with delimiter '|' -- Make sure we do not crash if one table has no shards @@ -107,14 +95,18 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_third b ON (l_custkey = t_custkey); -ERROR: shard counts of co-located tables do not match + min | max +--------------------------------------------------------------------- + 1 | 20 +(1 row) + SELECT min(t_custkey), max(t_custkey) FROM multi_outer_join_third a LEFT JOIN multi_outer_join_right_reference b ON (r_custkey = t_custkey); - min | max ------+----- - | + min | max +--------------------------------------------------------------------- + | (1 row) -- Third table is a single shard table with all data @@ -125,8 +117,8 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 1 | 20 (1 row) @@ -135,8 +127,8 @@ SELECT count(*) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_nationkey = r_nationkey); - count -------- + count +--------------------------------------------------------------------- 28 (1 row) @@ -147,8 +139,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey) WHERE r_custkey IS NULL; - min | max ------+----- + min | max +--------------------------------------------------------------------- 16 | 20 (1 row) @@ -159,8 +151,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey) WHERE r_custkey IS NULL OR r_custkey = 5; - min | max ------+----- + min | max +--------------------------------------------------------------------- 5 | 20 (1 row) @@ -172,8 +164,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey) WHERE r_custkey = 5 or r_custkey > 15; - min | max ------+----- + min | max +--------------------------------------------------------------------- 5 | 5 (1 row) @@ -183,8 +175,8 @@ SELECT FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey AND r_custkey = 5); - count | count --------+------- + count | count +--------------------------------------------------------------------- 20 | 1 (1 row) @@ -194,8 +186,8 @@ SELECT FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey AND r_custkey = -1 /* nonexistant */); - count | count --------+------- + count | count +--------------------------------------------------------------------- 20 | 0 (1 row) @@ -205,8 +197,8 @@ SELECT FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey AND l_custkey = -1 /* nonexistant */); - count | count --------+------- + count | count +--------------------------------------------------------------------- 20 | 0 (1 row) @@ -215,14 +207,18 @@ SELECT min(r_custkey), max(r_custkey) FROM multi_outer_join_left a RIGHT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); -ERROR: shard counts of co-located tables do not match + min | max +--------------------------------------------------------------------- + 1 | 15 +(1 row) + -- Reverse right join should be same as left join SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_right_reference a RIGHT JOIN multi_outer_join_left b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 1 | 20 (1 row) @@ -233,24 +229,14 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 1 | 20 (1 row) -- empty tables -SELECT * FROM master_apply_delete_command('DELETE FROM multi_outer_join_left'); - master_apply_delete_command ------------------------------ - 2 -(1 row) - -SELECT * FROM master_apply_delete_command('DELETE FROM multi_outer_join_right'); - master_apply_delete_command ------------------------------ - 2 -(1 row) - +TRUNCATE multi_outer_join_left; +TRUNCATE multi_outer_join_right; -- reload shards with 1-1 matching \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-subset-11-20.data' with delimiter '|' \copy multi_outer_join_left FROM '@abs_srcdir@/data/customer-21-30.data' with delimiter '|' @@ -262,8 +248,8 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 11 | 30 (1 row) @@ -280,8 +266,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey) WHERE r_custkey IS NULL; - min | max ------+----- + min | max +--------------------------------------------------------------------- 23 | 29 (1 row) @@ -292,8 +278,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey) WHERE r_custkey IS NULL OR r_custkey = 15; - min | max ------+----- + min | max +--------------------------------------------------------------------- 23 | 29 (1 row) @@ -305,8 +291,8 @@ FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey) WHERE r_custkey = 21 or r_custkey < 10; - min | max ------+----- + min | max +--------------------------------------------------------------------- 21 | 21 (1 row) @@ -316,8 +302,8 @@ SELECT FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey AND r_custkey = 21); - count | count --------+------- + count | count +--------------------------------------------------------------------- 17 | 1 (1 row) @@ -326,8 +312,8 @@ SELECT min(r_custkey), max(r_custkey) FROM multi_outer_join_left a RIGHT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 11 | 30 (1 row) @@ -336,8 +322,8 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_right a RIGHT JOIN multi_outer_join_left b ON (l_custkey = r_custkey); - min | max ------+----- + min | max +--------------------------------------------------------------------- 11 | 30 (1 row) @@ -351,8 +337,8 @@ FROM RIGHT JOIN multi_outer_join_left l2 ON (r2.r_custkey = l2.l_custkey) ORDER BY 1 LIMIT 1; - l_custkey ------------ + l_custkey +--------------------------------------------------------------------- 11 (1 row) @@ -368,9 +354,9 @@ WHERE r1.r_custkey is NULL ORDER BY 1 LIMIT 1; - l_custkey ------------ - + l_custkey +--------------------------------------------------------------------- + (1 row) -- Three way join 2-2-1 (local + broadcast join) should work @@ -381,8 +367,8 @@ FROM LEFT JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) LEFT JOIN multi_outer_join_third_reference t1 ON (r1.r_custkey = t1.t_custkey) ORDER BY l_custkey, r_custkey, t_custkey; - l_custkey | r_custkey | t_custkey ------------+-----------+----------- + l_custkey | r_custkey | t_custkey +--------------------------------------------------------------------- 11 | 11 | 11 12 | 12 | 12 14 | 14 | 14 @@ -392,13 +378,13 @@ ORDER BY l_custkey, r_custkey, t_custkey; 20 | 20 | 20 21 | 21 | 21 22 | 22 | 22 - 23 | | + 23 | | 24 | 24 | 24 - 25 | | + 25 | | 26 | 26 | 26 27 | 27 | 27 28 | 28 | 28 - 29 | | + 29 | | 30 | 30 | 30 (17 rows) @@ -420,17 +406,17 @@ FROM RIGHT JOIN multi_outer_join_right r1 ON (t1.t_custkey = r1.r_custkey) LEFT JOIN multi_outer_join_left l1 ON (r1.r_custkey = l1.l_custkey) ORDER BY t_custkey, r_custkey, l_custkey; - t_custkey | r_custkey | l_custkey ------------+-----------+----------- + t_custkey | r_custkey | l_custkey +--------------------------------------------------------------------- 11 | 11 | 11 12 | 12 | 12 - 13 | 13 | + 13 | 13 | 14 | 14 | 14 - 15 | 15 | + 15 | 15 | 16 | 16 | 16 17 | 17 | 17 18 | 18 | 18 - 19 | 19 | + 19 | 19 | 20 | 20 | 20 21 | 21 | 21 22 | 22 | 22 @@ -451,11 +437,11 @@ FROM WHERE l_custkey is NULL ORDER BY t_custkey, r_custkey, l_custkey; - t_custkey | r_custkey | l_custkey ------------+-----------+----------- - 13 | 13 | - 15 | 15 | - 19 | 19 | + t_custkey | r_custkey | l_custkey +--------------------------------------------------------------------- + 13 | 13 | + 15 | 15 | + 19 | 19 | (3 rows) -- Cascading right join with single shard left most table @@ -466,8 +452,8 @@ FROM RIGHT JOIN multi_outer_join_right r1 ON (t1.t_custkey = r1.r_custkey) RIGHT JOIN multi_outer_join_left l1 ON (r1.r_custkey = l1.l_custkey) ORDER BY 1,2,3; - t_custkey | r_custkey | l_custkey ------------+-----------+----------- + t_custkey | r_custkey | l_custkey +--------------------------------------------------------------------- 11 | 11 | 11 12 | 12 | 12 14 | 14 | 14 @@ -494,19 +480,19 @@ FROM multi_outer_join_left l1 FULL JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) ORDER BY 1 DESC, 2 DESC; - l_custkey | r_custkey ------------+----------- + l_custkey | r_custkey +--------------------------------------------------------------------- | 19 | 15 | 13 30 | 30 - 29 | + 29 | 28 | 28 27 | 27 26 | 26 - 25 | + 25 | 24 | 24 - 23 | + 23 | 22 | 22 21 | 21 20 | 20 @@ -524,14 +510,14 @@ SELECT FROM multi_outer_join_left l1 FULL JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) -WHERE +WHERE r_custkey is NULL ORDER BY 1 DESC, 2 DESC; - l_custkey | r_custkey ------------+----------- - 29 | - 25 | - 23 | + l_custkey | r_custkey +--------------------------------------------------------------------- + 29 | + 25 | + 23 | (3 rows) -- full outer join + anti (left) should work with 1-1 matched shards @@ -540,11 +526,11 @@ SELECT FROM multi_outer_join_left l1 FULL JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) -WHERE +WHERE l_custkey is NULL ORDER BY 1 DESC, 2 DESC; - l_custkey | r_custkey ------------+----------- + l_custkey | r_custkey +--------------------------------------------------------------------- | 19 | 15 | 13 @@ -556,17 +542,17 @@ SELECT FROM multi_outer_join_left l1 FULL JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) -WHERE +WHERE l_custkey is NULL or r_custkey is NULL ORDER BY 1 DESC, 2 DESC; - l_custkey | r_custkey ------------+----------- + l_custkey | r_custkey +--------------------------------------------------------------------- | 19 | 15 | 13 - 29 | - 25 | - 23 | + 29 | + 25 | + 23 | (6 rows) -- full outer join should error out for mismatched shards @@ -576,7 +562,40 @@ FROM multi_outer_join_left l1 FULL JOIN multi_outer_join_third t1 ON (l1.l_custkey = t1.t_custkey) ORDER BY 1 DESC, 2 DESC; -ERROR: shard counts of co-located tables do not match + l_custkey | t_custkey +--------------------------------------------------------------------- + | 19 + | 15 + | 13 + | 10 + | 9 + | 8 + | 7 + | 6 + | 5 + | 4 + | 3 + | 2 + | 1 + 30 | 30 + 29 | 29 + 28 | 28 + 27 | 27 + 26 | 26 + 25 | 25 + 24 | 24 + 23 | 23 + 22 | 22 + 21 | 21 + 20 | 20 + 18 | 18 + 17 | 17 + 16 | 16 + 14 | 14 + 12 | 12 + 11 | 11 +(30 rows) + -- inner join + single shard left join should work SELECT l_custkey, r_custkey, t_custkey @@ -585,8 +604,8 @@ FROM INNER JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) LEFT JOIN multi_outer_join_third_reference t1 ON (r1.r_custkey = t1.t_custkey) ORDER BY 1 DESC, 2 DESC, 3 DESC; - l_custkey | r_custkey | t_custkey ------------+-----------+----------- + l_custkey | r_custkey | t_custkey +--------------------------------------------------------------------- 30 | 30 | 30 28 | 28 | 28 27 | 27 | 27 @@ -611,16 +630,16 @@ FROM INNER JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey) LEFT JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) ORDER BY 1 DESC, 2 DESC, 3 DESC; - l_custkey | t_custkey | r_custkey ------------+-----------+----------- + l_custkey | t_custkey | r_custkey +--------------------------------------------------------------------- 30 | 30 | 30 - 29 | 29 | + 29 | 29 | 28 | 28 | 28 27 | 27 | 27 26 | 26 | 26 - 25 | 25 | + 25 | 25 | 24 | 24 | 24 - 23 | 23 | + 23 | 23 | 22 | 22 | 22 21 | 21 | 21 20 | 20 | 20 @@ -641,8 +660,8 @@ FROM LEFT JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) ORDER BY t_custkey, l_custkey, r_custkey; - t_custkey | l_custkey | r_custkey ------------+-----------+----------- + t_custkey | l_custkey | r_custkey +--------------------------------------------------------------------- 11 | 11 | 11 12 | 12 | 12 14 | 14 | 14 @@ -652,13 +671,13 @@ ORDER BY 20 | 20 | 20 21 | 21 | 21 22 | 22 | 22 - 23 | 23 | + 23 | 23 | 24 | 24 | 24 - 25 | 25 | + 25 | 25 | 26 | 26 | 26 27 | 27 | 27 28 | 28 | 28 - 29 | 29 | + 29 | 29 | 30 | 30 | 30 (17 rows) @@ -670,16 +689,16 @@ FROM INNER JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey) LEFT JOIN multi_outer_join_right r1 ON (l1.l_custkey = r1.r_custkey) ORDER BY 1 DESC, 2 DESC, 3 DESC; - l_custkey | t_custkey | r_custkey ------------+-----------+----------- + l_custkey | t_custkey | r_custkey +--------------------------------------------------------------------- 30 | 30 | 30 - 29 | 29 | + 29 | 29 | 28 | 28 | 28 27 | 27 | 27 26 | 26 | 26 - 25 | 25 | + 25 | 25 | 24 | 24 | 24 - 23 | 23 | + 23 | 23 | 22 | 22 | 22 21 | 21 | 21 20 | 20 | 20 @@ -701,24 +720,24 @@ FROM WHERE r_custkey is NULL ORDER BY 1 DESC, 2 DESC, 3 DESC; - l_custkey | t_custkey | r_custkey ------------+-----------+----------- - 29 | 29 | - 25 | 25 | - 23 | 23 | + l_custkey | t_custkey | r_custkey +--------------------------------------------------------------------- + 29 | 29 | + 25 | 25 | + 23 | 23 | (3 rows) --- Test joinExpr aliases by performing an outer-join. -SELECT +-- Test joinExpr aliases by performing an outer-join. +SELECT t_custkey -FROM - (multi_outer_join_right r1 +FROM + (multi_outer_join_right r1 LEFT OUTER JOIN multi_outer_join_left l1 ON (l1.l_custkey = r1.r_custkey)) AS test(c_custkey, c_nationkey) INNER JOIN multi_outer_join_third_reference t1 ON (test.c_custkey = t1.t_custkey) ORDER BY 1 DESC; - t_custkey ------------ + t_custkey +--------------------------------------------------------------------- 30 28 27 @@ -755,8 +774,8 @@ LEFT JOIN ( GROUP BY l1.l_custkey ORDER BY cnt DESC, l1.l_custkey DESC LIMIT 20; - l_custkey | cnt ------------+----- + l_custkey | cnt +--------------------------------------------------------------------- 30 | 1 29 | 1 28 | 1 @@ -782,45 +801,88 @@ SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a LEFT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); -ERROR: cannot push down this subquery -DETAIL: Currently append partitioned relations with overlapping shard intervals are not supported + min | max +--------------------------------------------------------------------- + 1 | 1000 +(1 row) + SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a RIGHT JOIN multi_outer_join_right b ON (l_custkey = r_custkey); -ERROR: cannot push down this subquery -DETAIL: Currently append partitioned relations with overlapping shard intervals are not supported + min | max +--------------------------------------------------------------------- + 11 | 30 +(1 row) + SELECT min(l_custkey), max(l_custkey) FROM multi_outer_join_left a FULL JOIN multi_outer_join_right b ON (l_custkey = r_custkey); -ERROR: cannot push down this subquery -DETAIL: Currently append partitioned relations with overlapping shard intervals are not supported -SELECT + min | max +--------------------------------------------------------------------- + 1 | 1000 +(1 row) + +SELECT t_custkey -FROM - (multi_outer_join_right r1 +FROM + (multi_outer_join_right r1 LEFT OUTER JOIN multi_outer_join_left l1 ON (l1.l_custkey = r1.r_custkey)) AS test(c_custkey, c_nationkey) - INNER JOIN multi_outer_join_third t1 ON (test.c_custkey = t1.t_custkey); -ERROR: cannot push down this subquery -DETAIL: Currently append partitioned relations with overlapping shard intervals are not supported + INNER JOIN multi_outer_join_third t1 ON (test.c_custkey = t1.t_custkey) +ORDER BY 1; + t_custkey +--------------------------------------------------------------------- + 11 + 11 + 12 + 12 + 13 + 14 + 14 + 15 + 16 + 16 + 17 + 17 + 18 + 18 + 19 + 20 + 20 + 21 + 21 + 22 + 22 + 24 + 24 + 26 + 26 + 27 + 27 + 28 + 28 + 30 + 30 +(31 rows) + -- simple test to ensure anti-joins work with hash-partitioned tables CREATE TABLE left_values(val int); SET citus.shard_count to 16; SET citus.shard_replication_factor to 1; SELECT create_distributed_table('left_values', 'val'); - create_distributed_table --------------------------- - + create_distributed_table +--------------------------------------------------------------------- + (1 row) \copy left_values from stdin CREATE TABLE right_values(val int); SELECT create_distributed_table('right_values', 'val'); - create_distributed_table --------------------------- - + create_distributed_table +--------------------------------------------------------------------- + (1 row) \copy right_values from stdin @@ -832,9 +894,9 @@ FROM WHERE r.val IS NULL ORDER BY 1 DESC, 2 DESC; - val | val ------+----- - 5 | - 1 | + val | val +--------------------------------------------------------------------- + 5 | + 1 | (2 rows) diff --git a/src/test/regress/sql/multi_partition_pruning.sql b/src/test/regress/sql/multi_partition_pruning.sql index 1fcb17b61..4e849b803 100644 --- a/src/test/regress/sql/multi_partition_pruning.sql +++ b/src/test/regress/sql/multi_partition_pruning.sql @@ -38,7 +38,7 @@ CREATE TABLE varchar_partitioned_table ( varchar_column varchar(100) ); -SELECT create_distributed_table('varchar_partitioned_table', 'varchar_column', 'append'); +SELECT create_distributed_table('varchar_partitioned_table', 'varchar_column', 'range'); -- Create logical shards and shard placements with shardid 100,101 @@ -67,7 +67,7 @@ CREATE TABLE array_partitioned_table ( array_column text[] ); -SELECT create_distributed_table('array_partitioned_table', 'array_column', 'append'); +SELECT create_distributed_table('array_partitioned_table', 'array_column', 'range'); SET client_min_messages TO DEBUG2; -- Create logical shard with shardid 102, 103 @@ -105,7 +105,7 @@ CREATE TABLE composite_partitioned_table ( composite_column composite_type ); -SELECT create_distributed_table('composite_partitioned_table', 'composite_column', 'append'); +SELECT create_distributed_table('composite_partitioned_table', 'composite_column', 'range'); SET client_min_messages TO DEBUG2; -- Create logical shard with shardid 104, 105