From 7ad6498fd5a654de6e743814c36cf619a3b5ddb6 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Sat, 30 Mar 2019 12:48:19 -0400 Subject: [PATCH] Avoid crash in partitionwise join planning under GEQO. While trying to plan a partitionwise join, we may be faced with cases where one or both input partitions for a particular segment of the join have been pruned away. In HEAD and v11, this is problematic because earlier processing didn't bother to make a pruned RelOptInfo fully valid. With an upcoming patch to make partition pruning more efficient, this'll be even more problematic because said RelOptInfo won't exist at all. The existing code attempts to deal with this by retroactively making the RelOptInfo fully valid, but that causes crashes under GEQO because join planning is done in a short-lived memory context. In v11 we could probably have fixed this by switching to the planner's main context while fixing up the RelOptInfo, but that idea doesn't scale well to the upcoming patch. It would be better not to mess with the base-relation data structures during join planning, anyway --- that's just a recipe for order-of-operations bugs. In many cases, though, we don't actually need the child RelOptInfo, because if the input is certainly empty then the join segment's result is certainly empty, so we can skip making a join plan altogether. (The existing code ultimately arrives at the same conclusion, but only after doing a lot more work.) This approach works except when the pruned-away partition is on the nullable side of a LEFT, ANTI, or FULL join, and the other side isn't pruned. But in those cases the existing code leaves a lot to be desired anyway --- the correct output is just the result of the unpruned side of the join, but we were emitting a useless outer join against a dummy Result. Pending somebody writing code to handle that more nicely, let's just abandon the partitionwise-join optimization in such cases. When the modified code skips making a join plan, it doesn't make a join RelOptInfo either; this requires some upper-level code to cope with nulls in part_rels[] arrays. We would have had to have that anyway after the upcoming patch. Back-patch to v11 since the crash is demonstrable there. Discussion: https://postgr.es/m/8305.1553884377@sss.pgh.pa.us --- src/backend/optimizer/path/allpaths.c | 14 +-- src/backend/optimizer/path/joinrels.c | 89 ++++++++++------- src/backend/optimizer/plan/planner.c | 17 ++-- .../regress/expected/partition_aggregate.out | 98 ++++++++----------- src/test/regress/expected/partition_join.out | 91 +++++++---------- src/test/regress/sql/partition_aggregate.sql | 10 +- src/test/regress/sql/partition_join.sql | 3 + 7 files changed, 157 insertions(+), 165 deletions(-) diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c index 56a5084312..3c9d84f665 100644 --- a/src/backend/optimizer/path/allpaths.c +++ b/src/backend/optimizer/path/allpaths.c @@ -1112,11 +1112,11 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel, * for partitioned child rels. * * Note: here we abuse the consider_partitionwise_join flag by setting - * it *even* for child rels that are not partitioned. In that case, - * we set it to tell try_partitionwise_join() that it doesn't need to - * generate their targetlists and EC entries as they have already been - * generated here, as opposed to the dummy child rels for which the - * flag is left set to false so that it will generate them. + * it for child rels that are not themselves partitioned. We do so to + * tell try_partitionwise_join() that the child rel is sufficiently + * valid to be used as a per-partition input, even if it later gets + * proven to be dummy. (It's not usable until we've set up the + * reltarget and EC entries, which we just did.) */ if (rel->consider_partitionwise_join) childrel->consider_partitionwise_join = true; @@ -3564,7 +3564,9 @@ generate_partitionwise_join_paths(PlannerInfo *root, RelOptInfo *rel) { RelOptInfo *child_rel = part_rels[cnt_parts]; - Assert(child_rel != NULL); + /* If it's been pruned entirely, it's certainly dummy. */ + if (child_rel == NULL) + continue; /* Add partitionwise join paths for partitioned child-joins. */ generate_partitionwise_join_paths(root, child_rel); diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c index 9604a54b77..34cc7dacdf 100644 --- a/src/backend/optimizer/path/joinrels.c +++ b/src/backend/optimizer/path/joinrels.c @@ -15,9 +15,7 @@ #include "postgres.h" #include "miscadmin.h" -#include "nodes/nodeFuncs.h" #include "optimizer/appendinfo.h" -#include "optimizer/clauses.h" #include "optimizer/joininfo.h" #include "optimizer/pathnode.h" #include "optimizer/paths.h" @@ -44,8 +42,6 @@ static void try_partitionwise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, RelOptInfo *joinrel, SpecialJoinInfo *parent_sjinfo, List *parent_restrictlist); -static void update_child_rel_info(PlannerInfo *root, - RelOptInfo *rel, RelOptInfo *childrel); static SpecialJoinInfo *build_child_join_sjinfo(PlannerInfo *root, SpecialJoinInfo *parent_sjinfo, Relids left_relids, Relids right_relids); @@ -1405,6 +1401,10 @@ try_partitionwise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, { RelOptInfo *child_rel1 = rel1->part_rels[cnt_parts]; RelOptInfo *child_rel2 = rel2->part_rels[cnt_parts]; + bool rel1_empty = (child_rel1 == NULL || + IS_DUMMY_REL(child_rel1)); + bool rel2_empty = (child_rel2 == NULL || + IS_DUMMY_REL(child_rel2)); SpecialJoinInfo *child_sjinfo; List *child_restrictlist; RelOptInfo *child_joinrel; @@ -1413,24 +1413,69 @@ try_partitionwise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, int nappinfos; /* - * If a child table has consider_partitionwise_join=false, it means + * Check for cases where we can prove that this segment of the join + * returns no rows, due to one or both inputs being empty (including + * inputs that have been pruned away entirely). If so just ignore it. + * These rules are equivalent to populate_joinrel_with_paths's rules + * for dummy input relations. + */ + switch (parent_sjinfo->jointype) + { + case JOIN_INNER: + case JOIN_SEMI: + if (rel1_empty || rel2_empty) + continue; /* ignore this join segment */ + break; + case JOIN_LEFT: + case JOIN_ANTI: + if (rel1_empty) + continue; /* ignore this join segment */ + break; + case JOIN_FULL: + if (rel1_empty && rel2_empty) + continue; /* ignore this join segment */ + break; + default: + /* other values not expected here */ + elog(ERROR, "unrecognized join type: %d", + (int) parent_sjinfo->jointype); + break; + } + + /* + * If a child has been pruned entirely then we can't generate paths + * for it, so we have to reject partitionwise joining unless we were + * able to eliminate this partition above. + */ + if (child_rel1 == NULL || child_rel2 == NULL) + { + /* + * Mark the joinrel as unpartitioned so that later functions treat + * it correctly. + */ + joinrel->nparts = 0; + return; + } + + /* + * If a leaf relation has consider_partitionwise_join=false, it means * that it's a dummy relation for which we skipped setting up tlist - * expressions and adding EC members in set_append_rel_size(), so do - * that now for use later. + * expressions and adding EC members in set_append_rel_size(), so + * again we have to fail here. */ if (rel1_is_simple && !child_rel1->consider_partitionwise_join) { Assert(child_rel1->reloptkind == RELOPT_OTHER_MEMBER_REL); Assert(IS_DUMMY_REL(child_rel1)); - update_child_rel_info(root, rel1, child_rel1); - child_rel1->consider_partitionwise_join = true; + joinrel->nparts = 0; + return; } if (rel2_is_simple && !child_rel2->consider_partitionwise_join) { Assert(child_rel2->reloptkind == RELOPT_OTHER_MEMBER_REL); Assert(IS_DUMMY_REL(child_rel2)); - update_child_rel_info(root, rel2, child_rel2); - child_rel2->consider_partitionwise_join = true; + joinrel->nparts = 0; + return; } /* We should never try to join two overlapping sets of rels. */ @@ -1474,28 +1519,6 @@ try_partitionwise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, } } -/* - * Set up tlist expressions for the childrel, and add EC members referencing - * the childrel. - */ -static void -update_child_rel_info(PlannerInfo *root, - RelOptInfo *rel, RelOptInfo *childrel) -{ - AppendRelInfo *appinfo = root->append_rel_array[childrel->relid]; - - /* Make child tlist expressions */ - childrel->reltarget->exprs = (List *) - adjust_appendrel_attrs(root, - (Node *) rel->reltarget->exprs, - 1, &appinfo); - - /* Make child entries in the EquivalenceClass as well */ - if (rel->has_eclass_joins || has_useful_pathkeys(root, rel)) - add_child_rel_equivalences(root, appinfo, rel, childrel); - childrel->has_eclass_joins = rel->has_eclass_joins; -} - /* * Construct the SpecialJoinInfo for a child-join by translating * SpecialJoinInfo for the join between parents. left_relids and right_relids diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index ca7a0fbbf5..031e709718 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -6993,6 +6993,10 @@ apply_scanjoin_target_to_paths(PlannerInfo *root, List *child_scanjoin_targets = NIL; ListCell *lc; + /* Pruned or dummy children can be ignored. */ + if (child_rel == NULL || IS_DUMMY_REL(child_rel)) + continue; + /* Translate scan/join targets for this child. */ appinfos = find_appinfos_by_relids(root, child_rel->relids, &nappinfos); @@ -7093,8 +7097,9 @@ create_partitionwise_grouping_paths(PlannerInfo *root, RelOptInfo *child_grouped_rel; RelOptInfo *child_partially_grouped_rel; - /* Input child rel must have a path */ - Assert(child_input_rel->pathlist != NIL); + /* Pruned or dummy children can be ignored. */ + if (child_input_rel == NULL || IS_DUMMY_REL(child_input_rel)) + continue; /* * Copy the given "extra" structure as is and then override the @@ -7136,14 +7141,6 @@ create_partitionwise_grouping_paths(PlannerInfo *root, extra->target_parallel_safe, child_extra.havingQual); - /* Ignore empty children. They contribute nothing. */ - if (IS_DUMMY_REL(child_input_rel)) - { - mark_dummy_rel(child_grouped_rel); - - continue; - } - /* Create grouping paths for this child relation. */ create_ordinary_grouping_paths(root, child_input_rel, child_grouped_rel, diff --git a/src/test/regress/expected/partition_aggregate.out b/src/test/regress/expected/partition_aggregate.out index 6bc106831e..e1549cbb5c 100644 --- a/src/test/regress/expected/partition_aggregate.out +++ b/src/test/regress/expected/partition_aggregate.out @@ -716,37 +716,33 @@ SELECT a.x, sum(b.x) FROM pagg_tab1 a FULL OUTER JOIN pagg_tab2 b ON a.x = b.y G | 500 (16 rows) --- LEFT JOIN, with dummy relation on right side, +-- LEFT JOIN, with dummy relation on right side, ideally -- should produce full partitionwise aggregation plan as GROUP BY is on --- non-nullable columns +-- non-nullable columns. +-- But right now we are unable to do partitionwise join in this case. EXPLAIN (COSTS OFF) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a LEFT JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; - QUERY PLAN ------------------------------------------------------------------------------ + QUERY PLAN +----------------------------------------------------------------------- Sort - Sort Key: pagg_tab1_p1.x, y - -> Append - -> HashAggregate - Group Key: pagg_tab1_p1.x, y - -> Hash Left Join - Hash Cond: (pagg_tab1_p1.x = y) - Filter: ((pagg_tab1_p1.x > 5) OR (y < 20)) + Sort Key: pagg_tab1_p1.x, pagg_tab2_p2.y + -> HashAggregate + Group Key: pagg_tab1_p1.x, pagg_tab2_p2.y + -> Hash Left Join + Hash Cond: (pagg_tab1_p1.x = pagg_tab2_p2.y) + Filter: ((pagg_tab1_p1.x > 5) OR (pagg_tab2_p2.y < 20)) + -> Append -> Seq Scan on pagg_tab1_p1 Filter: (x < 20) - -> Hash - -> Result - One-Time Filter: false - -> HashAggregate - Group Key: pagg_tab1_p2.x, pagg_tab2_p2.y - -> Hash Left Join - Hash Cond: (pagg_tab1_p2.x = pagg_tab2_p2.y) - Filter: ((pagg_tab1_p2.x > 5) OR (pagg_tab2_p2.y < 20)) -> Seq Scan on pagg_tab1_p2 Filter: (x < 20) - -> Hash + -> Hash + -> Append -> Seq Scan on pagg_tab2_p2 Filter: (y > 10) -(23 rows) + -> Seq Scan on pagg_tab2_p3 + Filter: (y > 10) +(18 rows) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a LEFT JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; x | y | count @@ -760,49 +756,33 @@ SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a LEFT JOI 18 | 18 | 100 (7 rows) --- FULL JOIN, with dummy relations on both sides, +-- FULL JOIN, with dummy relations on both sides, ideally -- should produce partial partitionwise aggregation plan as GROUP BY is on --- nullable columns +-- nullable columns. +-- But right now we are unable to do partitionwise join in this case. EXPLAIN (COSTS OFF) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a FULL JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; - QUERY PLAN ------------------------------------------------------------------------------------ - Finalize GroupAggregate - Group Key: pagg_tab1_p1.x, y - -> Sort - Sort Key: pagg_tab1_p1.x, y - -> Append - -> Partial HashAggregate - Group Key: pagg_tab1_p1.x, y - -> Hash Full Join - Hash Cond: (pagg_tab1_p1.x = y) - Filter: ((pagg_tab1_p1.x > 5) OR (y < 20)) - -> Seq Scan on pagg_tab1_p1 - Filter: (x < 20) - -> Hash - -> Result - One-Time Filter: false - -> Partial HashAggregate - Group Key: pagg_tab1_p2.x, pagg_tab2_p2.y - -> Hash Full Join - Hash Cond: (pagg_tab1_p2.x = pagg_tab2_p2.y) - Filter: ((pagg_tab1_p2.x > 5) OR (pagg_tab2_p2.y < 20)) - -> Seq Scan on pagg_tab1_p2 - Filter: (x < 20) - -> Hash - -> Seq Scan on pagg_tab2_p2 - Filter: (y > 10) - -> Partial HashAggregate - Group Key: x, pagg_tab2_p3.y - -> Hash Full Join - Hash Cond: (pagg_tab2_p3.y = x) - Filter: ((x > 5) OR (pagg_tab2_p3.y < 20)) + QUERY PLAN +----------------------------------------------------------------------- + Sort + Sort Key: pagg_tab1_p1.x, pagg_tab2_p2.y + -> HashAggregate + Group Key: pagg_tab1_p1.x, pagg_tab2_p2.y + -> Hash Full Join + Hash Cond: (pagg_tab1_p1.x = pagg_tab2_p2.y) + Filter: ((pagg_tab1_p1.x > 5) OR (pagg_tab2_p2.y < 20)) + -> Append + -> Seq Scan on pagg_tab1_p1 + Filter: (x < 20) + -> Seq Scan on pagg_tab1_p2 + Filter: (x < 20) + -> Hash + -> Append + -> Seq Scan on pagg_tab2_p2 + Filter: (y > 10) -> Seq Scan on pagg_tab2_p3 Filter: (y > 10) - -> Hash - -> Result - One-Time Filter: false -(35 rows) +(18 rows) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a FULL JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; x | y | count diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out index e19535d6c7..1296edcdae 100644 --- a/src/test/regress/expected/partition_join.out +++ b/src/test/regress/expected/partition_join.out @@ -205,28 +205,27 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 300 | 0300 | 300 | 0300 (1 row) +-- Currently we can't do partitioned join if nullable-side partitions are pruned EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; QUERY PLAN ----------------------------------------------------------- Sort - Sort Key: prt1_p1.a, b - -> Append - -> Hash Left Join - Hash Cond: (prt1_p1.a = b) - -> Seq Scan on prt1_p1 - Filter: ((a < 450) AND (b = 0)) - -> Hash - -> Result - One-Time Filter: false - -> Hash Right Join - Hash Cond: (prt2_p2.b = prt1_p2.a) + Sort Key: prt1_p1.a, prt2_p2.b + -> Hash Right Join + Hash Cond: (prt2_p2.b = prt1_p1.a) + -> Append -> Seq Scan on prt2_p2 Filter: (b > 250) - -> Hash + -> Seq Scan on prt2_p3 + Filter: (b > 250) + -> Hash + -> Append + -> Seq Scan on prt1_p1 + Filter: ((a < 450) AND (b = 0)) -> Seq Scan on prt1_p2 Filter: ((a < 450) AND (b = 0)) -(17 rows) +(15 rows) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; a | c | b | c @@ -242,38 +241,28 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JO 400 | 0400 | | (9 rows) +-- Currently we can't do partitioned join if nullable-side partitions are pruned EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 OR t2.a = 0 ORDER BY t1.a, t2.b; - QUERY PLAN ------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------ Sort - Sort Key: prt1_p1.a, b - -> Append - -> Hash Full Join - Hash Cond: (prt1_p1.a = b) - Filter: ((prt1_p1.b = 0) OR (a = 0)) + Sort Key: prt1_p1.a, prt2_p2.b + -> Hash Full Join + Hash Cond: (prt1_p1.a = prt2_p2.b) + Filter: ((prt1_p1.b = 0) OR (prt2_p2.a = 0)) + -> Append -> Seq Scan on prt1_p1 Filter: (a < 450) - -> Hash - -> Result - One-Time Filter: false - -> Hash Full Join - Hash Cond: (prt1_p2.a = prt2_p2.b) - Filter: ((prt1_p2.b = 0) OR (prt2_p2.a = 0)) -> Seq Scan on prt1_p2 Filter: (a < 450) - -> Hash + -> Hash + -> Append -> Seq Scan on prt2_p2 Filter: (b > 250) - -> Hash Full Join - Hash Cond: (prt2_p3.b = a) - Filter: ((b = 0) OR (prt2_p3.a = 0)) - -> Seq Scan on prt2_p3 - Filter: (b > 250) - -> Hash - -> Result - One-Time Filter: false -(27 rows) + -> Seq Scan on prt2_p3 + Filter: (b > 250) +(16 rows) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 OR t2.a = 0 ORDER BY t1.a, t2.b; a | c | b | c @@ -992,34 +981,30 @@ SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 (12 rows) -- MergeAppend on nullable column +-- This should generate a partitionwise join, but currently fails to EXPLAIN (COSTS OFF) SELECT t1.a, t2.b FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; QUERY PLAN ----------------------------------------------------------- Sort - Sort Key: prt1_p1.a, b - -> Append - -> Merge Left Join - Merge Cond: (prt1_p1.a = b) - -> Sort - Sort Key: prt1_p1.a + Sort Key: prt1_p1.a, prt2_p2.b + -> Merge Left Join + Merge Cond: (prt1_p1.a = prt2_p2.b) + -> Sort + Sort Key: prt1_p1.a + -> Append -> Seq Scan on prt1_p1 Filter: ((a < 450) AND (b = 0)) - -> Sort - Sort Key: b - -> Result - One-Time Filter: false - -> Merge Left Join - Merge Cond: (prt1_p2.a = prt2_p2.b) - -> Sort - Sort Key: prt1_p2.a -> Seq Scan on prt1_p2 Filter: ((a < 450) AND (b = 0)) - -> Sort - Sort Key: prt2_p2.b + -> Sort + Sort Key: prt2_p2.b + -> Append -> Seq Scan on prt2_p2 Filter: (b > 250) -(23 rows) + -> Seq Scan on prt2_p3 + Filter: (b > 250) +(18 rows) SELECT t1.a, t2.b FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; a | b diff --git a/src/test/regress/sql/partition_aggregate.sql b/src/test/regress/sql/partition_aggregate.sql index c387d64db3..dcd6edbad2 100644 --- a/src/test/regress/sql/partition_aggregate.sql +++ b/src/test/regress/sql/partition_aggregate.sql @@ -149,16 +149,18 @@ EXPLAIN (COSTS OFF) SELECT a.x, sum(b.x) FROM pagg_tab1 a FULL OUTER JOIN pagg_tab2 b ON a.x = b.y GROUP BY a.x ORDER BY 1 NULLS LAST; SELECT a.x, sum(b.x) FROM pagg_tab1 a FULL OUTER JOIN pagg_tab2 b ON a.x = b.y GROUP BY a.x ORDER BY 1 NULLS LAST; --- LEFT JOIN, with dummy relation on right side, +-- LEFT JOIN, with dummy relation on right side, ideally -- should produce full partitionwise aggregation plan as GROUP BY is on --- non-nullable columns +-- non-nullable columns. +-- But right now we are unable to do partitionwise join in this case. EXPLAIN (COSTS OFF) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a LEFT JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a LEFT JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; --- FULL JOIN, with dummy relations on both sides, +-- FULL JOIN, with dummy relations on both sides, ideally -- should produce partial partitionwise aggregation plan as GROUP BY is on --- nullable columns +-- nullable columns. +-- But right now we are unable to do partitionwise join in this case. EXPLAIN (COSTS OFF) SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a FULL JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; SELECT a.x, b.y, count(*) FROM (SELECT * FROM pagg_tab1 WHERE x < 20) a FULL JOIN (SELECT * FROM pagg_tab2 WHERE y > 10) b ON a.x = b.y WHERE a.x > 5 or b.y < 20 GROUP BY a.x, b.y ORDER BY 1, 2; diff --git a/src/test/regress/sql/partition_join.sql b/src/test/regress/sql/partition_join.sql index c1c9859651..db9a6b4a96 100644 --- a/src/test/regress/sql/partition_join.sql +++ b/src/test/regress/sql/partition_join.sql @@ -54,10 +54,12 @@ EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.b = 0 ORDER BY t1.a, t2.b; SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.b = 0 ORDER BY t1.a, t2.b; +-- Currently we can't do partitioned join if nullable-side partitions are pruned EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; +-- Currently we can't do partitioned join if nullable-side partitions are pruned EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 OR t2.a = 0 ORDER BY t1.a, t2.b; SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT * FROM prt1 WHERE a < 450) t1 FULL JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 OR t2.a = 0 ORDER BY t1.a, t2.b; @@ -156,6 +158,7 @@ SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 SELECT t1.a, t1.c, t2.b, t2.c, t3.a + t3.b, t3.c FROM (prt1 t1 LEFT JOIN prt2 t2 ON t1.a = t2.b) RIGHT JOIN prt1_e t3 ON (t1.a = (t3.a + t3.b)/2) WHERE t3.c = 0 ORDER BY t1.a, t2.b, t3.a + t3.b; -- MergeAppend on nullable column +-- This should generate a partitionwise join, but currently fails to EXPLAIN (COSTS OFF) SELECT t1.a, t2.b FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b; SELECT t1.a, t2.b FROM (SELECT * FROM prt1 WHERE a < 450) t1 LEFT JOIN (SELECT * FROM prt2 WHERE b > 250) t2 ON t1.a = t2.b WHERE t1.b = 0 ORDER BY t1.a, t2.b;