diff --git a/src/backend/distributed/planner/local_distributed_join_planner.c b/src/backend/distributed/planner/local_distributed_join_planner.c index 9f93b447c..449b96195 100644 --- a/src/backend/distributed/planner/local_distributed_join_planner.c +++ b/src/backend/distributed/planner/local_distributed_join_planner.c @@ -173,9 +173,6 @@ typedef enum ConversionChoice static bool HasConstantFilterOnUniqueColumn(RangeTblEntry *rangeTableEntry, RelationRestriction *relationRestriction); -static List * RequiredAttrNumbersForRelation(RangeTblEntry *relationRte, - PlannerRestrictionContext * - plannerRestrictionContext); static ConversionCandidates * CreateConversionCandidates(PlannerRestrictionContext * plannerRestrictionContext, List *rangeTableList, @@ -474,7 +471,7 @@ AppendUniqueIndexColumnsToList(Form_pg_index indexForm, List **uniqueIndexGroups * The function could be optimized by not adding the columns that only appear * WHERE clause as a filter (e.g., not a join clause). */ -static List * +List * RequiredAttrNumbersForRelation(RangeTblEntry *rangeTableEntry, PlannerRestrictionContext *plannerRestrictionContext) { diff --git a/src/backend/distributed/planner/recursive_planning.c b/src/backend/distributed/planner/recursive_planning.c index 2ebaba829..03b966e56 100644 --- a/src/backend/distributed/planner/recursive_planning.c +++ b/src/backend/distributed/planner/recursive_planning.c @@ -149,6 +149,11 @@ static void RecursivelyPlanNonColocatedSubqueriesInWhere(Query *query, colocatedJoinChecker, RecursivePlanningContext * recursivePlanningContext); +static void RecursivelyPlanRecurringTupleOuterJoins(Node *node, Query *query, + RecursivePlanningContext *context); +static bool IsJoinNodeRecurring(Node *joinNode, Query *query); +static void RecursivelyPlanDistributedJoinNode(Node *distributedNode, Query *query, + RecursivePlanningContext *context); static List * SublinkListFromWhere(Query *originalQuery); static bool ExtractSublinkWalker(Node *node, List **sublinkList); static bool ShouldRecursivelyPlanSublinks(Query *query); @@ -359,6 +364,18 @@ RecursivelyPlanSubqueriesAndCTEs(Query *query, RecursivePlanningContext *context RecursivelyPlanLocalTableJoins(query, context); } + /* + * Similarly, logical planner cannot handle outer joins when the outer rel + * is recurring, such as " LEFT JOIN ". In that case, + * we convert distributed table into a subquery and recursively plan inner + * side of the outer join. That way, inner rel gets converted into an intermediate + * result and logical planner can handle the new query since it's of the from + * " LEFT JOIN ". + * + * See DeferredErrorIfUnsupportedRecurringTuplesJoin for the supported join + * types. + */ + RecursivelyPlanRecurringTupleOuterJoins((Node *) query->jointree, query, context); return NULL; } @@ -599,6 +616,292 @@ RecursivelyPlanNonColocatedSubqueriesInWhere(Query *query, } +/* + * RecursivelyPlanRecurringTupleOuterJoins descends into a join tree and + * recursively plans all non-recurring (i.e., distributed) rels that that + * participate in an outer join expression together with a recurring rel, + * such as in " LEFT JOIN ", i.e., + * where the recurring rel causes returning recurring tuples from the worker + * nodes. + */ +static void +RecursivelyPlanRecurringTupleOuterJoins(Node *node, Query *query, + RecursivePlanningContext *recursivePlanningContext) +{ + if (node == NULL) + { + return; + } + else if (IsA(node, RangeTblRef)) + { + return; + } + else if (IsA(node, FromExpr)) + { + FromExpr *fromExpr = (FromExpr *) node; + ListCell *fromExprCell; + + /* search for join trees in each FROM element */ + foreach(fromExprCell, fromExpr->fromlist) + { + Node *fromElement = (Node *) lfirst(fromExprCell); + + RecursivelyPlanRecurringTupleOuterJoins(fromElement, query, + recursivePlanningContext); + } + + return; + } + else if (IsA(node, JoinExpr)) + { + JoinExpr *joinExpr = (JoinExpr *) node; + + Node *leftNode = joinExpr->larg; + Node *rightNode = joinExpr->rarg; + + /* there may be recursively plannable outer joins deeper in the join tree */ + RecursivelyPlanRecurringTupleOuterJoins(joinExpr->larg, query, + recursivePlanningContext); + RecursivelyPlanRecurringTupleOuterJoins(joinExpr->rarg, query, + recursivePlanningContext); + switch (joinExpr->jointype) + { + case JOIN_LEFT: + { + bool leftNodeRecurs = IsJoinNodeRecurring(leftNode, query); + bool rightNodeRecurs = IsJoinNodeRecurring(rightNode, query); + + /* left join */ + if (leftNodeRecurs && !rightNodeRecurs) + { + RecursivelyPlanDistributedJoinNode(rightNode, query, + recursivePlanningContext); + return; + } + + break; + } + + case JOIN_RIGHT: + { + bool leftNodeRecurs = IsJoinNodeRecurring(leftNode, query); + bool rightNodeRecurs = IsJoinNodeRecurring(rightNode, query); + + /* right join */ + if (!leftNodeRecurs && rightNodeRecurs) + { + RecursivelyPlanDistributedJoinNode(leftNode, query, + recursivePlanningContext); + return; + } + + break; + } + + case JOIN_FULL: + { + bool leftNodeRecurs = IsJoinNodeRecurring(leftNode, query); + bool rightNodeRecurs = IsJoinNodeRecurring(rightNode, query); + + /* + * full join + * full join + */ + if (leftNodeRecurs && !rightNodeRecurs) + { + RecursivelyPlanDistributedJoinNode(rightNode, query, + recursivePlanningContext); + return; + } + else if (!leftNodeRecurs && rightNodeRecurs) + { + RecursivelyPlanDistributedJoinNode(leftNode, query, + recursivePlanningContext); + return; + } + + break; + } + + case JOIN_INNER: + { + /* + * We don't need to recursively plan non-outer joins and we already + * descended into sub join trees to handle outer joins buried in them. + */ + break; + } + + default: + { + ereport(ERROR, (errmsg("got unexpected join type (%d) when recursively " + "planning a join", + joinExpr->jointype))); + } + } + } + else + { + ereport(ERROR, errmsg("got unexpected expr type when recursively " + "planning a join")); + } +} + + +/* + * IsJoinNodeRecurring determines whether a join node in a join tree + * is recurring. + */ +static bool +IsJoinNodeRecurring(Node *joinNode, Query *query) +{ + if (IsA(joinNode, JoinExpr)) + { + /* + * Then this is a sub (join) tree and here is how we determine whether a + * join tree is recurring or not: + * + * i) Outer join: + * + * If the outer side of the join is a recurring rel, then the join + * node itself is recurring too regardless of whether the inner + * side of the join is recurring or not. + * + * If outer side of the join is distributed, then the join + * node is distributed too. + * + * ii) Inner join: + * + * The join node is recurring only if both sides of the join are + * recurring. + * + * Otherwise, if at least one side of the join is distributed, then + * this would ensure not returning recurring tuples from the workers; + * hence makes the join node "not recurring". + */ + JoinExpr *joinExpr = (JoinExpr *) joinNode; + bool leftNodeIsRecurring = IsJoinNodeRecurring(joinExpr->larg, query); + bool rightNodeIsRecurring = IsJoinNodeRecurring(joinExpr->rarg, query); + + switch (joinExpr->jointype) + { + case JOIN_LEFT: + { + return leftNodeIsRecurring; + } + + case JOIN_RIGHT: + { + return rightNodeIsRecurring; + } + + case JOIN_FULL: + { + return leftNodeIsRecurring || rightNodeIsRecurring; + } + + case JOIN_INNER: + { + return leftNodeIsRecurring && rightNodeIsRecurring; + } + + default: + { + ereport(ERROR, (errmsg("unexpected join type"))); + } + } + } + else if (IsA(joinNode, RangeTblRef)) + { + RangeTblRef *rangeTableRef = (RangeTblRef *) joinNode; + int rangeTableIndex = rangeTableRef->rtindex; + List *rangeTableList = query->rtable; + RangeTblEntry *rangeTableEntry = rt_fetch(rangeTableIndex, rangeTableList); + + /* + * Inspect whether this side of the JOIN clause is recurring, + * as in RelationInfoContainsOnlyRecurringTuples. + */ + return !FindNodeMatchingCheckFunctionInRangeTableList(list_make1(rangeTableEntry), + IsDistributedTableRTE); + } + else + { + ereport(ERROR, (errmsg("unexpected join node type"))); + } +} + + +/* + * RecursivelyPlanDistributedJoinNode is a helper function for + * RecursivelyPlanRecurringTupleOuterJoins that recursively plans given + * distributed node that is known to be inner side of an outer join. + */ +static void +RecursivelyPlanDistributedJoinNode(Node *distributedNode, Query *query, + RecursivePlanningContext *recursivePlanningContext) +{ + if (IsA(distributedNode, JoinExpr)) + { + /* + * XXX: This, for example, means that RecursivelyPlanRecurringTupleOuterJoins + * needs to plan inner side, i.e., INNER JOIN , + * of the following join: + * + * LEFT JOIN ( INNER JOIN ) + * + * However, this would require moving part of the join tree into a + * subquery but this implies that we need to rebuild the rtable and + * re-point all the Vars to the new rtable indexes. We have not + * implemented that yet. + */ + ereport(DEBUG4, (errmsg("recursive planner cannot plan distributed sub " + "join nodes yet"))); + return; + } + + if (!IsA(distributedNode, RangeTblRef)) + { + ereport(ERROR, (errmsg("unexpected join node type"))); + } + + RangeTblRef *distributedRef = (RangeTblRef *) distributedNode; + RangeTblEntry *distributedRte = rt_fetch(distributedRef->rtindex, + query->rtable); + + if (distributedRte->rtekind == RTE_RELATION) + { + PlannerRestrictionContext *restrictionContext = + GetPlannerRestrictionContext(recursivePlanningContext); + List *requiredAttributes = + RequiredAttrNumbersForRelation(distributedRte, restrictionContext); + + ReplaceRTERelationWithRteSubquery(distributedRte, requiredAttributes, + recursivePlanningContext); + } + else if (distributedRte->rtekind == RTE_SUBQUERY) + { + /* + * XXX: Similar to JoinExpr, we don't know how to recursively plan distributed + * subqueries within join expressions yet. + */ + ereport(DEBUG4, (errmsg("recursive planner cannot plan distributed " + "subqueries within join expressions yet"))); + return; + } + else + { + /* + * We don't expect RecursivelyPlanRecurringTupleOuterJoins to try recursively + * plan such an RTE. + */ + ereport(ERROR, errmsg("got unexpected RTE type (%d) when recursively " + "planning a join", + distributedRte->rtekind)); + } +} + + /* * SublinkListFromWhere finds the subquery nodes in the where clause of the given query. Note * that the function should be called on the original query given that postgres diff --git a/src/include/distributed/local_distributed_join_planner.h b/src/include/distributed/local_distributed_join_planner.h index dd74c8fb1..f2108f603 100644 --- a/src/include/distributed/local_distributed_join_planner.h +++ b/src/include/distributed/local_distributed_join_planner.h @@ -30,5 +30,8 @@ extern int LocalTableJoinPolicy; extern bool ShouldConvertLocalTableJoinsToSubqueries(List *rangeTableList); extern void RecursivelyPlanLocalTableJoins(Query *query, RecursivePlanningContext *context); +extern List * RequiredAttrNumbersForRelation(RangeTblEntry *relationRte, + PlannerRestrictionContext * + plannerRestrictionContext); #endif /* LOCAL_DISTRIBUTED_JOIN_PLANNER_H */ diff --git a/src/test/regress/expected/citus_local_tables_queries.out b/src/test/regress/expected/citus_local_tables_queries.out index 8f6c47393..f14607155 100644 --- a/src/test/regress/expected/citus_local_tables_queries.out +++ b/src/test/regress/expected/citus_local_tables_queries.out @@ -497,9 +497,14 @@ NOTICE: executing the command locally: SELECT count(*) AS count FROM (((citus_l 1296 (1 row) --- not supported direct outer join SELECT count(*) FROM citus_local_table LEFT JOIN distributed_table ON (true); -ERROR: cannot pushdown the subquery +NOTICE: executing the command locally: SELECT NULL::integer AS "dummy-1" FROM citus_local_table_queries.citus_local_table_1509001 citus_local_table WHERE true +NOTICE: executing the command locally: SELECT count(*) AS count FROM ((SELECT NULL::integer AS a, NULL::integer AS b FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) citus_local_table_1) citus_local_table LEFT JOIN (SELECT NULL::integer AS a, NULL::integer AS b FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) distributed_table_1) distributed_table ON (true)) + count +--------------------------------------------------------------------- + 36 +(1 row) + -- distinct in subquery on CTE WITH one_row AS ( SELECT a from citus_local_table WHERE b = 1 diff --git a/src/test/regress/expected/citus_local_tables_queries_0.out b/src/test/regress/expected/citus_local_tables_queries_0.out index 4b8d3411e..3bac4fbee 100644 --- a/src/test/regress/expected/citus_local_tables_queries_0.out +++ b/src/test/regress/expected/citus_local_tables_queries_0.out @@ -497,9 +497,14 @@ NOTICE: executing the command locally: SELECT count(*) AS count FROM (((citus_l 1296 (1 row) --- not supported direct outer join SELECT count(*) FROM citus_local_table LEFT JOIN distributed_table ON (true); -ERROR: cannot pushdown the subquery +NOTICE: executing the command locally: SELECT NULL::integer AS "dummy-1" FROM citus_local_table_queries.citus_local_table_1509001 citus_local_table WHERE true +NOTICE: executing the command locally: SELECT count(*) AS count FROM ((SELECT NULL::integer AS a, NULL::integer AS b FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) citus_local_table_1) citus_local_table LEFT JOIN (SELECT NULL::integer AS a, NULL::integer AS b FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) distributed_table_1) distributed_table ON (true)) + count +--------------------------------------------------------------------- + 36 +(1 row) + -- distinct in subquery on CTE WITH one_row AS ( SELECT a from citus_local_table WHERE b = 1 diff --git a/src/test/regress/expected/citus_local_tables_queries_mx.out b/src/test/regress/expected/citus_local_tables_queries_mx.out index 2eff2cd1d..9d0b4a051 100644 --- a/src/test/regress/expected/citus_local_tables_queries_mx.out +++ b/src/test/regress/expected/citus_local_tables_queries_mx.out @@ -430,9 +430,13 @@ SELECT count(*) FROM reference_table 1296 (1 row) --- not supported direct outer join +-- supported outer join SELECT count(*) FROM citus_local_table LEFT JOIN distributed_table ON (true); -ERROR: cannot pushdown the subquery + count +--------------------------------------------------------------------- + 36 +(1 row) + -- distinct in subquery on CTE WITH one_row AS ( SELECT a from citus_local_table WHERE b = 1 diff --git a/src/test/regress/expected/cross_join.out b/src/test/regress/expected/cross_join.out index 279c4ab2f..5887a9ae3 100644 --- a/src/test/regress/expected/cross_join.out +++ b/src/test/regress/expected/cross_join.out @@ -90,28 +90,49 @@ SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table r -- two reference tables CROSS JOINNed, and later JOINED with distributed tables -- but the reference table CROSS JOIN is in the outer side of the JOIN with the distributed table --- so we cannot pushdown +-- so this is supported by recursively planning the distributed table (users_table) SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id = users_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 606 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 FULL JOIN users_table ON (ref1.id = users_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 606 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id != users_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 3030 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id > 0); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 3636 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (users_table.user_id > 0); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 3636 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 3636 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON false; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 36 +(1 row) + -- a reference tables CROSS JOINed with a distribted table, and later JOINED with distributed tables on distribution keys -- so safe to pushdown SELECT count(*) FROM users_table u1 CROSS JOIN users_ref_test_table ref2 JOIN users_table u2 ON (u1.user_id = u2.user_id); @@ -167,8 +188,11 @@ SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table r -- this is the same query as the above, but this time the outer query is also LEFT JOIN, meaning that Postgres -- cannot eliminate the outer join SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id = users_table.user_id) LEFT JOIN users_table u2 ON (u2.user_id = users_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 11802 +(1 row) + -- cross join that goes through non-colocated subquery logic -- for the "events_table" subquery as both distributed tables -- do not have JOIN on the distribution key diff --git a/src/test/regress/expected/local_dist_join_mixed.out b/src/test/regress/expected/local_dist_join_mixed.out index cc709b982..9115c1a32 100644 --- a/src/test/regress/expected/local_dist_join_mixed.out +++ b/src/test/regress/expected/local_dist_join_mixed.out @@ -1193,7 +1193,9 @@ DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS c SELECT count(*) FROM local LEFT JOIN distributed USING (id); DEBUG: Wrapping relation "local" to a subquery DEBUG: generating subplan XXX_1 for subquery SELECT id FROM local_dist_join_mixed.local WHERE true -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT NULL::integer AS "dummy-1", local_1.id, NULL::integer AS "dummy-3", NULL::text AS title, NULL::integer AS "dummy-5" FROM (SELECT intermediate_result.id FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint)) local_1) local LEFT JOIN local_dist_join_mixed.distributed USING (id)) +DEBUG: Wrapping relation "distributed" to a subquery +DEBUG: generating subplan XXX_2 for subquery SELECT NULL::integer AS "dummy-1" FROM local_dist_join_mixed.distributed WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT NULL::integer AS "dummy-1", local_1.id, NULL::integer AS "dummy-3", NULL::text AS title, NULL::integer AS "dummy-5" FROM (SELECT intermediate_result.id FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint)) local_1) local LEFT JOIN (SELECT NULL::integer AS "dummy-1", NULL::bigint AS id, NULL::text AS name, NULL::timestamp with time zone AS created_at FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) distributed_1) distributed USING (id)) count --------------------------------------------------------------------- 101 @@ -1212,9 +1214,14 @@ DEBUG: push down of limit count: 1 SELECT id, name FROM local LEFT JOIN distributed USING (id) ORDER BY 1 LIMIT 1; DEBUG: Wrapping relation "local" to a subquery DEBUG: generating subplan XXX_1 for subquery SELECT id FROM local_dist_join_mixed.local WHERE true -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT local.id, distributed.name FROM ((SELECT NULL::integer AS "dummy-1", local_1.id, NULL::integer AS "dummy-3", NULL::text AS title, NULL::integer AS "dummy-5" FROM (SELECT intermediate_result.id FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint)) local_1) local LEFT JOIN local_dist_join_mixed.distributed USING (id)) ORDER BY local.id LIMIT 1 -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table +DEBUG: Wrapping relation "distributed" to a subquery +DEBUG: generating subplan XXX_2 for subquery SELECT id, name FROM local_dist_join_mixed.distributed WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT local.id, distributed.name FROM ((SELECT NULL::integer AS "dummy-1", local_1.id, NULL::integer AS "dummy-3", NULL::text AS title, NULL::integer AS "dummy-5" FROM (SELECT intermediate_result.id FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint)) local_1) local LEFT JOIN (SELECT NULL::integer AS "dummy-1", distributed_1.id, distributed_1.name, NULL::timestamp with time zone AS created_at FROM (SELECT intermediate_result.id, intermediate_result.name FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, name text)) distributed_1) distributed USING (id)) ORDER BY local.id LIMIT 1 + id | name +--------------------------------------------------------------------- + 0 | 0 +(1 row) + SELECT foo1.id FROM diff --git a/src/test/regress/expected/local_table_join.out b/src/test/regress/expected/local_table_join.out index 3c2f73393..758ac5c45 100644 --- a/src/test/regress/expected/local_table_join.out +++ b/src/test/regress/expected/local_table_join.out @@ -1577,9 +1577,14 @@ SELECT 1 AS res FROM table2 RIGHT JOIN (SELECT 1 FROM table1, table2) AS sub1 ON DEBUG: Wrapping relation "table1" to a subquery DEBUG: generating subplan XXX_1 for subquery SELECT NULL::integer AS "dummy-1" FROM local_table_join.table1 WHERE true DEBUG: generating subplan XXX_2 for subquery SELECT 1 FROM (SELECT NULL::integer AS a FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) table1_1) table1, local_table_join.table2 -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT 1 AS res FROM (local_table_join.table2 RIGHT JOIN (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) sub1("?column?") ON (false)) -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table +DEBUG: Wrapping relation "table2" to a subquery +DEBUG: generating subplan XXX_3 for subquery SELECT NULL::integer AS "dummy-1" FROM local_table_join.table2 WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT 1 AS res FROM ((SELECT NULL::integer AS a FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) table2_1) table2 RIGHT JOIN (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) sub1("?column?") ON (false)) + res +--------------------------------------------------------------------- + 1 +(1 row) + ROLLBACK; BEGIN; SELECT create_reference_table('table1'); diff --git a/src/test/regress/expected/mixed_relkind_tests.out b/src/test/regress/expected/mixed_relkind_tests.out index 20cb6ebac..a180652f3 100644 --- a/src/test/regress/expected/mixed_relkind_tests.out +++ b/src/test/regress/expected/mixed_relkind_tests.out @@ -349,10 +349,15 @@ DEBUG: Wrapping relation "citus_local_table" to a subquery DEBUG: generating subplan XXX_1 for subquery SELECT NULL::integer AS "dummy-1" FROM mixed_relkind_tests.citus_local_table WHERE true DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT foo.a FROM (mixed_relkind_tests.partitioned_distributed_table foo JOIN (SELECT NULL::integer AS a FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) citus_local_table_1) citus_local_table ON (true)) DEBUG: performing repartitioned INSERT ... SELECT --- should fail SELECT COUNT(*) FROM reference_table LEFT JOIN partitioned_distributed_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +DEBUG: Wrapping relation "partitioned_distributed_table" to a subquery +DEBUG: generating subplan XXX_1 for subquery SELECT NULL::integer AS "dummy-1" FROM mixed_relkind_tests.partitioned_distributed_table WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (mixed_relkind_tests.reference_table LEFT JOIN (SELECT NULL::integer AS a, NULL::integer AS b FROM (SELECT intermediate_result."dummy-1" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("dummy-1" integer)) partitioned_distributed_table_1) partitioned_distributed_table ON (true)) + count +--------------------------------------------------------------------- + 468 +(1 row) + -- non-colocated subquery should work SELECT COUNT(*) FROM (SELECT *, random() FROM partitioned_distributed_table) AS foo, diff --git a/src/test/regress/expected/multi_dropped_column_aliases.out b/src/test/regress/expected/multi_dropped_column_aliases.out index c3f250d62..99b82bf40 100644 --- a/src/test/regress/expected/multi_dropped_column_aliases.out +++ b/src/test/regress/expected/multi_dropped_column_aliases.out @@ -51,12 +51,24 @@ SELECT count(*) FROM customer, orders WHERE c_custkey = o_custkey; 1956 (1 row) --- Test joinExpr aliases by performing an outer-join. This code path is --- currently not exercised, but we are adding this test to catch this bug when --- we start supporting outer joins. +-- Test joinExpr aliases by performing an outer-join. SELECT c_custkey FROM (customer LEFT OUTER JOIN orders ON (c_custkey = o_custkey)) AS test(c_custkey, c_nationkey) INNER JOIN lineitem ON (test.c_custkey = l_orderkey) +ORDER BY 1 LIMIT 10; -ERROR: complex joins are only supported when all distributed tables are co-located and joined on their distribution columns + c_custkey +--------------------------------------------------------------------- + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 + 1 +(10 rows) + diff --git a/src/test/regress/expected/multi_outer_join_reference.out b/src/test/regress/expected/multi_outer_join_reference.out index d75f67089..1e705d14d 100644 --- a/src/test/regress/expected/multi_outer_join_reference.out +++ b/src/test/regress/expected/multi_outer_join_reference.out @@ -208,13 +208,17 @@ FROM 20 | 0 (1 row) --- Right join should be disallowed in this case +-- Right join is allowed as we recursively plan the distributed table (multi_outer_join_left_hash) SELECT min(r_custkey), max(r_custkey) FROM multi_outer_join_left_hash a RIGHT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +LOG: join order: [ "multi_outer_join_left_hash" ] + min | max +--------------------------------------------------------------------- + 1 | 15 +(1 row) + -- Reverse right join should be same as left join SELECT min(l_custkey), max(l_custkey) @@ -319,13 +323,17 @@ FROM 25 | 1 (1 row) --- Right join should not be allowed in this case +-- Right join should be allowed in this case as we recursively plan the distributed table (multi_outer_join_left_hash SELECT min(r_custkey), max(r_custkey) FROM multi_outer_join_left_hash a RIGHT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +LOG: join order: [ "multi_outer_join_left_hash" ] + min | max +--------------------------------------------------------------------- + 11 | 30 +(1 row) + -- Reverse right join should be same as left join SELECT min(l_custkey), max(l_custkey) @@ -600,14 +608,48 @@ ORDER BY 1,2 DESC; | 16 (15 rows) --- full outer join should error out for mismatched shards +-- full outer join should work as we recursively plan the distributed table (multi_outer_join_left_hash SELECT l_custkey, t_custkey FROM multi_outer_join_left_hash l1 - FULL JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + FULL JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey) +ORDER BY 1,2; +LOG: join order: [ "multi_outer_join_left_hash" ] + l_custkey | t_custkey +--------------------------------------------------------------------- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 4 + 5 | 5 + 6 | 6 + 7 | 7 + 8 | 8 + 9 | 9 + 10 | 10 + 11 | 11 + 12 | 12 + 13 | 13 + 14 | 14 + 15 | 15 + 21 | 21 + 22 | 22 + 23 | 23 + 24 | 24 + 25 | 25 + 26 | 26 + 27 | 27 + 28 | 28 + 29 | 29 + 30 | 30 + | 16 + | 17 + | 18 + | 19 + | 20 +(30 rows) + -- inner join + single shard left join should work SELECT l_custkey, r_custkey, t_custkey diff --git a/src/test/regress/expected/multi_shard_update_delete.out b/src/test/regress/expected/multi_shard_update_delete.out index 1d494ecea..c599cc69a 100644 --- a/src/test/regress/expected/multi_shard_update_delete.out +++ b/src/test/regress/expected/multi_shard_update_delete.out @@ -665,14 +665,27 @@ WHERE user_id IN SELECT user_id FROM events_test_table); -- Reference tables can not locate on the outer part of the outer join -UPDATE users_test_table -SET value_1 = 4 -WHERE user_id IN - (SELECT DISTINCT e2.user_id - FROM users_reference_copy_table - LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1)) RETURNING *; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +WITH updated as ( + UPDATE users_test_table + SET value_1 = 4 + WHERE user_id IN ( + SELECT DISTINCT e2.user_id + FROM users_reference_copy_table + LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1) + ) + RETURNING * +) +SELECT * FROM updated ORDER BY 1; + user_id | value_1 | value_2 | value_3 +--------------------------------------------------------------------- + 5 | 4 | 1 | 0 + 5 | 4 | 1 | 0 + 5 | 4 | 1 | 0 + 6 | 4 | 11 | 0 + 6 | 4 | 15 | 0 + 16 | 4 | | 0 +(6 rows) + -- Volatile functions are also not supported UPDATE users_test_table SET value_2 = 5 diff --git a/src/test/regress/expected/multi_subquery_complex_reference_clause.out b/src/test/regress/expected/multi_subquery_complex_reference_clause.out index b9579ae7a..7dcdc7678 100644 --- a/src/test/regress/expected/multi_subquery_complex_reference_clause.out +++ b/src/test/regress/expected/multi_subquery_complex_reference_clause.out @@ -76,12 +76,20 @@ ORDER BY 1; 7 (10 rows) --- Shouldn't work, reference table at the outer side is not allowed +-- Should work, reference table at the outer side is allowed SELECT * FROM - (SELECT random() FROM users_ref_test_table LEFT JOIN user_buy_test_table + (SELECT random() > 2 FROM users_ref_test_table LEFT JOIN user_buy_test_table ON users_ref_test_table.id = user_buy_test_table.user_id) subquery_1; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + ?column? +--------------------------------------------------------------------- + f + f + f + f + f + f +(6 rows) + -- Should work, reference table at the inner side is allowed SELECT count(*) FROM (SELECT random() FROM users_ref_test_table RIGHT JOIN user_buy_test_table @@ -91,12 +99,20 @@ SELECT count(*) FROM 4 (1 row) --- Shouldn't work, reference table at the outer side is not allowed +-- Should work, reference table at the outer side is allowed SELECT * FROM - (SELECT random() FROM user_buy_test_table RIGHT JOIN users_ref_test_table + (SELECT random() > 2 FROM user_buy_test_table RIGHT JOIN users_ref_test_table ON user_buy_test_table.user_id = users_ref_test_table.id) subquery_1; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + ?column? +--------------------------------------------------------------------- + f + f + f + f + f + f +(6 rows) + -- Equi join test with reference table on non-partition keys SELECT count(*) FROM (SELECT random() FROM user_buy_test_table JOIN users_ref_test_table @@ -270,16 +286,22 @@ ON user_buy_test_table.item_id = users_ref_test_table.id; 4 (1 row) --- table function cannot be the outer relationship in an outer join +-- table function can be the outer relationship in an outer join SELECT count(*) FROM (SELECT random() FROM user_buy_test_table RIGHT JOIN generate_series(1,10) AS users_ref_test_table(id) ON user_buy_test_table.item_id > users_ref_test_table.id) subquery_1; -ERROR: cannot pushdown the subquery -DETAIL: There exist a table function in the outer part of the outer join + count +--------------------------------------------------------------------- + 16 +(1 row) + SELECT count(*) FROM user_buy_test_table RIGHT JOIN (SELECT * FROM generate_series(1,10) id) users_ref_test_table ON user_buy_test_table.item_id = users_ref_test_table.id; -ERROR: cannot pushdown the subquery -DETAIL: There exist a table function in the outer part of the outer join + count +--------------------------------------------------------------------- + 10 +(1 row) + -- volatile functions can be used as table expressions through recursive planning SET client_min_messages TO DEBUG; SELECT count(*) FROM @@ -351,11 +373,14 @@ ON user_buy_test_table.item_id = users_ref_test_table.id; 4 (1 row) --- subquery without FROM cannot be the outer relationship in an outer join +-- subquery without FROM can be the outer relationship in an outer join SELECT count(*) FROM user_buy_test_table RIGHT JOIN (SELECT 5 AS id) users_ref_test_table ON user_buy_test_table.item_id = users_ref_test_table.id; -ERROR: cannot pushdown the subquery -DETAIL: There exist a subquery without FROM in the outer part of the outer join + count +--------------------------------------------------------------------- + 1 +(1 row) + -- can perform a union with subquery without FROM -- with pulling data to coordinator SET client_min_messages TO DEBUG; @@ -498,8 +523,8 @@ DEBUG: Router planner cannot handle multi-shard select queries 1 (4 rows) --- query can be pushed down when a reference table inside union query is --- joined with a distributed table. reference table cannot be at +-- query is supported when a reference table inside union query is +-- joined with a distributed table. reference table can be at -- the outer part. SELECT * FROM (SELECT user_id FROM users_ref_test_table ref LEFT JOIN user_buy_test_table dis @@ -508,8 +533,24 @@ SELECT * FROM SELECT user_id FROM user_buy_test_table) sub ORDER BY 1 DESC; DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +DEBUG: Wrapping relation "user_buy_test_table" "dis" to a subquery +DEBUG: Router planner cannot handle multi-shard select queries +DEBUG: generating subplan XXX_1 for subquery SELECT user_id FROM public.user_buy_test_table dis WHERE true +DEBUG: Router planner cannot handle multi-shard select queries +DEBUG: generating subplan XXX_2 for subquery SELECT user_id FROM public.user_buy_test_table +DEBUG: Creating router plan +DEBUG: generating subplan XXX_3 for subquery SELECT dis.user_id FROM (public.users_ref_test_table ref LEFT JOIN (SELECT dis_1.user_id, NULL::integer AS item_id, NULL::integer AS buy_count FROM (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer)) dis_1) dis ON ((ref.id OPERATOR(pg_catalog.=) dis.user_id))) UNION SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer) +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT user_id FROM (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer)) sub ORDER BY user_id DESC +DEBUG: Creating router plan + user_id +--------------------------------------------------------------------- + + 7 + 3 + 2 + 1 +(5 rows) + RESET client_min_messages; -- should be able to pushdown since reference table is in the -- inner part of the left join @@ -533,7 +574,7 @@ FROM 6 | 210 (6 rows) --- should not be able to pushdown since reference table is in the +-- supported even if the reference table is in the -- direct outer part of the left join SELECT user_id, sum(value_1) @@ -545,18 +586,29 @@ FROM LEFT JOIN events_table ON (events_table.user_id = users_table.user_id) ) as foo GROUP BY user_id ORDER BY 2 DESC LIMIT 10; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join --- should not be able to pushdown since reference table is in the + user_id | sum +--------------------------------------------------------------------- + | + 2 | 31248 + 3 | 15120 + 4 | 14994 + 5 | 8694 + 1 | 7590 +(6 rows) + +-- supported even if the reference table is in the -- direct outer part of the left join wrapped into a subquery SELECT - * + COUNT(*) = 1581 FROM (SELECT *, random() FROM events_reference_table) as ref_all LEFT JOIN users_table ON (users_table.user_id = ref_all.value_2); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join --- should not be able to pushdown since reference table is in the + ?column? +--------------------------------------------------------------------- + t +(1 row) + +-- supported even if the reference table is in the -- outer part of the left join SELECT user_id, sum(value_1) @@ -568,8 +620,16 @@ FROM LEFT JOIN events_table ON (events_table.user_id = users_table.user_id) ) as foo GROUP BY user_id ORDER BY 2 DESC LIMIT 10; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + user_id | sum +--------------------------------------------------------------------- + | + 2 | 31248 + 3 | 15120 + 4 | 14994 + 5 | 8694 + 1 | 7590 +(6 rows) + -- should be able to pushdown since reference table is in the -- inner part of the left join SELECT * FROM @@ -1466,13 +1526,16 @@ ORDER BY types; 3 | 120 (4 rows) --- just a sanity check that we don't allow this if the reference table is on the +-- just a sanity check that we allow this even if the reference table is on the -- left part of the left join SELECT count(*) FROM (SELECT random() FROM users_ref_test_table LEFT JOIN user_buy_test_table ON user_buy_test_table.item_id > users_ref_test_table.id) subquery_1; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 12 +(1 row) + -- we do allow non equi join among subqueries via recursive planning SET client_min_messages TO DEBUG1; SELECT count(*) FROM @@ -1961,73 +2024,124 @@ LIMIT 5; 6 (1 row) --- outer part of the LEFT JOIN consists only reference tables, so we cannot push down +-- supported even if the outer part of the LEFT JOIN consists only reference tables -- we have different combinations for ON condition, true/false/two column join/single column filter SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 24 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 24 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON false; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON false; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref1.id > 5); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 9 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (user_buy_test_table.user_id > 5); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref1.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref2.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref1.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref2.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join --- outer part of the LEFT JOIN consists only reference tables within a subquery, so we cannot push down + count +--------------------------------------------------------------------- + 6 +(1 row) + +-- outer part of the LEFT JOIN consists only reference tables within a subquery -- we have different combinations for ON condition, true/false/two column join/single column filter SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 24 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 24 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON false; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON false; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON (foo.id > 5); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 9 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON (user_buy_test_table.user_id > 19); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON (foo.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 6 +(1 row) + -- one example where unsupported outer join is deep inside a subquery SELECT *, random() FROM ( SELECT *,random() FROM user_buy_test_table WHERE user_id > ( SELECT count(*) FROM (SELECT *,random() FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as bar) as foo LEFT JOIN (SELECT *, random() FROM (SELECT *,random() FROM user_buy_test_table d1 JOIN user_buy_test_table d2 USING (user_id)) as bar_inner ) as bar ON true)) as boo; ERROR: cannot pushdown the subquery DETAIL: There exist a reference table in the outer part of the outer join --- In theory, we should be able to pushdown this query --- however, as the LEFT JOIN condition is between a reference table and the distributed table --- Postgres generates a LEFT JOIN alternative among those tables SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN user_buy_test_table u1 on ref1.id = u1.user_id) as foo LEFT JOIN user_buy_test_table ON (foo.id = user_buy_test_table.user_id); -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table + count +--------------------------------------------------------------------- + 3 +(1 row) + -- same as the above query, but this time LEFT JOIN condition is between distributed tables -- so Postgres doesn't generate join restriction between reference and distributed tables SELECT count(*) FROM (SELECT u1.*, random() FROM users_ref_test_table ref1 INNER JOIN user_buy_test_table u1 on ref1.id = u1.user_id) as foo LEFT JOIN user_buy_test_table ON (foo.user_id = user_buy_test_table.user_id); @@ -2036,10 +2150,13 @@ SELECT count(*) FROM (SELECT u1.*, random() FROM users_ref_test_table ref1 INNER 3 (1 row) --- outer part of the LEFT JOIN consists only intermediate result due to LIMIT, so we cannot push down +-- outer part of the LEFT JOIN consists only intermediate result due to LIMIT but this is still supported SELECT count(*) FROM (SELECT ref1.* FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LIMIT 5) as foo LEFT JOIN user_buy_test_table ON true; -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table + count +--------------------------------------------------------------------- + 20 +(1 row) + -- should be fine as OUTER part is the distributed table SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id RIGHT JOIN user_buy_test_table ON true; count diff --git a/src/test/regress/expected/multi_subquery_in_where_reference_clause.out b/src/test/regress/expected/multi_subquery_in_where_reference_clause.out index 74fd8a624..d4ada83d3 100644 --- a/src/test/regress/expected/multi_subquery_in_where_reference_clause.out +++ b/src/test/regress/expected/multi_subquery_in_where_reference_clause.out @@ -162,8 +162,7 @@ WHERE ) ORDER BY user_id LIMIT 3; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join +ERROR: correlated subqueries are not supported when the FROM clause contains a CTE or subquery -- subqueries in WHERE with IN operator without equality SELECT users_table.user_id, count(*) diff --git a/src/test/regress/expected/multi_view.out b/src/test/regress/expected/multi_view.out index fafa242df..bc29c31ae 100644 --- a/src/test/regress/expected/multi_view.out +++ b/src/test/regress/expected/multi_view.out @@ -486,8 +486,8 @@ ORDER BY 2 DESC, 1; 5 | NO (3 rows) --- event vs table non-partition-key join is not supported --- given that we cannot recursively plan tables yet +-- event vs table non-partition-key join is supported +-- given that we can recursively plan events_table SELECT * FROM (SELECT ru.user_id, CASE WHEN et.user_id IS NULL THEN 'NO' ELSE 'YES' END as done_event FROM recent_users ru @@ -495,8 +495,64 @@ SELECT * FROM ON(ru.user_id = et.event_type) ) s1 ORDER BY 2 DESC, 1; -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table + user_id | done_event +--------------------------------------------------------------------- + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 1 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 3 | YES + 5 | YES + 5 | YES + 5 | YES + 5 | YES + 5 | YES + 5 | YES + 5 | YES +(54 rows) + -- create a select only view CREATE VIEW selected_users AS SELECT * FROM users_table WHERE value_1 >= 1 and value_1 <3; CREATE VIEW recent_selected_users AS SELECT su.* FROM selected_users su JOIN recent_users ru USING(user_id); diff --git a/src/test/regress/expected/non_colocated_subquery_joins.out b/src/test/regress/expected/non_colocated_subquery_joins.out index 1b7b1b1e7..5a90ea81a 100644 --- a/src/test/regress/expected/non_colocated_subquery_joins.out +++ b/src/test/regress/expected/non_colocated_subquery_joins.out @@ -987,7 +987,7 @@ DEBUG: skipping recursive planning for the subquery since it contains reference ERROR: complex joins are only supported when all distributed tables are co-located and joined on their distribution columns -- similar to the above, make sure that we skip recursive planning when -- the subquery contains only intermediate results -SELECT * +SELECT COUNT(*) = 176 FROM ( SELECT * FROM( @@ -1026,9 +1026,16 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_5 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4 FROM public.events_table WHERE (value_2 OPERATOR(pg_catalog.>) 2) DEBUG: Creating router plan DEBUG: generating subplan XXX_6 for subquery SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_4'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint) INTERSECT SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_5'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT users_table_limited.user_id, users_table_limited."time", users_table_limited.value_1, users_table_limited.value_2, users_table_limited.value_3, users_table_limited.value_4, foo.user_id, foo."time", foo.event_type, foo.value_2, foo.value_3, foo.value_4, foo.user_id_1 AS user_id, foo.time_1 AS "time", foo.value_1, foo.value_2_1 AS value_2, foo.value_3_1 AS value_3, foo.value_4_1 AS value_4 FROM ((SELECT users_table_union.user_id, users_table_union."time", users_table_union.value_1, users_table_union.value_2, users_table_union.value_3, users_table_union.value_4 FROM (SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.value_1, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, value_1 integer, value_2 integer, value_3 double precision, value_4 bigint)) users_table_union) users_table_limited JOIN LATERAL (SELECT bar.user_id, bar."time", bar.event_type, bar.value_2, bar.value_3, bar.value_4, u2.user_id, u2."time", u2.value_1, u2.value_2, u2.value_3, u2.value_4 FROM ((SELECT events_table.user_id, events_table."time", events_table.event_type, events_table.value_2, events_table.value_3, events_table.value_4 FROM (SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_6'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint)) events_table WHERE (events_table.user_id OPERATOR(pg_catalog.=) users_table_limited.user_id)) bar LEFT JOIN public.users_table u2 ON ((u2.user_id OPERATOR(pg_catalog.=) bar.value_2)))) foo(user_id, "time", event_type, value_2, value_3, value_4, user_id_1, time_1, value_1, value_2_1, value_3_1, value_4_1) ON (true)) +DEBUG: Wrapping relation "users_table" "u2" to a subquery DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery +DEBUG: generating subplan XXX_7 for subquery SELECT user_id FROM public.users_table u2 WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT (count(*) OPERATOR(pg_catalog.=) 176) FROM ((SELECT users_table_union.user_id, users_table_union."time", users_table_union.value_1, users_table_union.value_2, users_table_union.value_3, users_table_union.value_4 FROM (SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.value_1, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, value_1 integer, value_2 integer, value_3 double precision, value_4 bigint)) users_table_union) users_table_limited JOIN LATERAL (SELECT bar.user_id, bar."time", bar.event_type, bar.value_2, bar.value_3, bar.value_4, u2.user_id, u2."time", u2.value_1, u2.value_2, u2.value_3, u2.value_4 FROM ((SELECT events_table.user_id, events_table."time", events_table.event_type, events_table.value_2, events_table.value_3, events_table.value_4 FROM (SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_6'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint)) events_table WHERE (events_table.user_id OPERATOR(pg_catalog.=) users_table_limited.user_id)) bar LEFT JOIN (SELECT u2_1.user_id, NULL::timestamp without time zone AS "time", NULL::integer AS value_1, NULL::integer AS value_2, NULL::double precision AS value_3, NULL::bigint AS value_4 FROM (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_7'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer)) u2_1) u2 ON ((u2.user_id OPERATOR(pg_catalog.=) bar.value_2)))) foo(user_id, "time", event_type, value_2, value_3, value_4, user_id_1, time_1, value_1, value_2_1, value_3_1, value_4_1) ON (true)) +DEBUG: Creating router plan + ?column? +--------------------------------------------------------------------- + t +(1 row) + -- similar to the above, but this time there are multiple -- non-colocated subquery joins one of them contains lateral -- join @@ -1071,8 +1078,16 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_5 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4 FROM public.events_table WHERE (value_2 OPERATOR(pg_catalog.>) 2) DEBUG: Creating router plan DEBUG: generating subplan XXX_6 for subquery SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_4'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint) INTERSECT SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_5'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint) +DEBUG: Wrapping relation "users_table" "u2" to a subquery DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery +DEBUG: generating subplan XXX_7 for subquery SELECT user_id FROM public.users_table u2 WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM public.events_table WHERE (NOT (user_id OPERATOR(pg_catalog.=) ANY (SELECT users_table_limited.user_id FROM ((SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.value_1, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, value_1 integer, value_2 integer, value_3 double precision, value_4 bigint)) users_table_limited JOIN LATERAL (SELECT bar.user_id, bar."time", bar.event_type, bar.value_2, bar.value_3, bar.value_4, u2.user_id, u2."time", u2.value_1, u2.value_2, u2.value_3, u2.value_4 FROM ((SELECT events_table_1.user_id, events_table_1."time", events_table_1.event_type, events_table_1.value_2, events_table_1.value_3, events_table_1.value_4 FROM (SELECT intermediate_result.user_id, intermediate_result."time", intermediate_result.event_type, intermediate_result.value_2, intermediate_result.value_3, intermediate_result.value_4 FROM read_intermediate_result('XXX_6'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "time" timestamp without time zone, event_type integer, value_2 integer, value_3 double precision, value_4 bigint)) events_table_1 WHERE (events_table_1.user_id OPERATOR(pg_catalog.=) users_table_limited.user_id)) bar LEFT JOIN (SELECT u2_1.user_id, NULL::timestamp without time zone AS "time", NULL::integer AS value_1, NULL::integer AS value_2, NULL::double precision AS value_3, NULL::bigint AS value_4 FROM (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_7'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer)) u2_1) u2 ON ((u2.user_id OPERATOR(pg_catalog.=) bar.value_2)))) foo(user_id, "time", event_type, value_2, value_3, value_4, user_id_1, time_1, value_1, value_2_1, value_3_1, value_4_1) ON (true))))) +DEBUG: Router planner cannot handle multi-shard select queries + count +--------------------------------------------------------------------- + 62 +(1 row) + -- make sure that non-colocated subquery joins work fine in -- modifications CREATE TABLE table1 (id int, tenant_id int); diff --git a/src/test/regress/expected/set_operation_and_local_tables.out b/src/test/regress/expected/set_operation_and_local_tables.out index 40c7d618c..83f84339b 100644 --- a/src/test/regress/expected/set_operation_and_local_tables.out +++ b/src/test/regress/expected/set_operation_and_local_tables.out @@ -250,10 +250,15 @@ DEBUG: push down of limit count: 1 DEBUG: generating subplan XXX_2 for subquery SELECT x, y FROM recursive_set_local.test ORDER BY x LIMIT 1 DEBUG: Creating router plan DEBUG: generating subplan XXX_3 for subquery SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) INTERSECT SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN recursive_set_local.test USING (x)) ORDER BY u.x, u.y +DEBUG: Wrapping relation "test" to a subquery DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table +DEBUG: generating subplan XXX_4 for subquery SELECT x, y FROM recursive_set_local.test WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN (SELECT test_1.x, test_1.y FROM (SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_4'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) test_1) test USING (x)) ORDER BY u.x, u.y +DEBUG: Creating router plan + x | y | y +--------------------------------------------------------------------- +(0 rows) + -- we replace some queries including the local query, the intermediate result is on the inner part of an outer join SELECT * FROM ((SELECT * FROM local_test) INTERSECT (SELECT * FROM test ORDER BY x LIMIT 1)) u RIGHT JOIN test USING (x) ORDER BY 1,2; DEBUG: Local tables cannot be used in distributed queries. diff --git a/src/test/regress/expected/set_operations.out b/src/test/regress/expected/set_operations.out index 250c8ae7c..3f4e32bd1 100644 --- a/src/test/regress/expected/set_operations.out +++ b/src/test/regress/expected/set_operations.out @@ -505,10 +505,18 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_2 for subquery SELECT x, y FROM recursive_union.test DEBUG: Creating router plan DEBUG: generating subplan XXX_3 for subquery SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) UNION ALL SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN recursive_union.test USING (x)) ORDER BY u.x, u.y +DEBUG: Wrapping relation "test" to a subquery DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table +DEBUG: generating subplan XXX_4 for subquery SELECT x, y FROM recursive_union.test WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN (SELECT test_1.x, test_1.y FROM (SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_4'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) test_1) test USING (x)) ORDER BY u.x, u.y +DEBUG: Creating router plan + x | y | y +--------------------------------------------------------------------- + 1 | 1 | 1 + 1 | 1 | 1 + 2 | 2 | 2 +(3 rows) + -- unions in a join without partition column equality (column names from first query are used for join) SELECT * FROM ((SELECT x, y FROM test) UNION (SELECT y, x FROM test)) u JOIN test USING (x) ORDER BY 1,2; DEBUG: Router planner cannot handle multi-shard select queries @@ -686,10 +694,16 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_2 for subquery SELECT x, y FROM recursive_union.test DEBUG: Creating router plan DEBUG: generating subplan XXX_3 for subquery SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) INTERSECT SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN recursive_union.test USING (x)) ORDER BY u.x, u.y +DEBUG: Wrapping relation "test" to a subquery DEBUG: Router planner cannot handle multi-shard select queries -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table +DEBUG: generating subplan XXX_4 for subquery SELECT x, y FROM recursive_union.test WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT u.x, u.y, test.y FROM ((SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) u LEFT JOIN (SELECT test_1.x, test_1.y FROM (SELECT intermediate_result.x, intermediate_result.y FROM read_intermediate_result('XXX_4'::text, 'binary'::citus_copy_format) intermediate_result(x integer, y integer)) test_1) test USING (x)) ORDER BY u.x, u.y +DEBUG: Creating router plan + x | y | y +--------------------------------------------------------------------- + 1 | 1 | 1 +(1 row) + -- distributed table in WHERE clause is recursively planned SELECT * FROM ((SELECT * FROM test) UNION (SELECT * FROM ref WHERE a IN (SELECT x FROM test))) u ORDER BY 1,2; DEBUG: Router planner cannot handle multi-shard select queries diff --git a/src/test/regress/expected/sqlancer_failures.out b/src/test/regress/expected/sqlancer_failures.out index 234eadd87..207e71d56 100644 --- a/src/test/regress/expected/sqlancer_failures.out +++ b/src/test/regress/expected/sqlancer_failures.out @@ -149,8 +149,11 @@ SELECT create_reference_table('t10'); SELECT count(*) FROM ( SELECT ALL t7.c1, t7.c0, t8.c1, t10.c1, t8.c0 FROM t7 CROSS JOIN t10 FULL OUTER JOIN t8 ON (((((((('[832125354,1134163512)'::int4range)*('(0,2106623281)'::int4range)))-('(-600267905,509840582]'::int4range)))*('(-365203965,1662828182)'::int4range)))&<((((((('(-1286467417,697584012]'::int4range)*('[-1691485781,1341103963)'::int4range)))*((('(-1768368435,1719707648)'::int4range)*('(139536997,1275813540]'::int4range)))))*((((('[-2103910157,-1961746758)'::int4range)*('[-834534078,533073939)'::int4range)))*((('[-1030552151,552856781]'::int4range)*('[-1109419376,1205173697]'::int4range)))))))) ) AS foo; -ERROR: cannot pushdown the subquery -DETAIL: There exist a reference table in the outer part of the outer join + count +--------------------------------------------------------------------- + 0 +(1 row) + CREATE TABLE reference_table(id int, it_name varchar(25), k_no int); SELECT create_reference_table('reference_table'); create_reference_table diff --git a/src/test/regress/expected/values.out b/src/test/regress/expected/values.out index cc26f7432..b79bf76c3 100644 --- a/src/test/regress/expected/values.out +++ b/src/test/regress/expected/values.out @@ -248,7 +248,7 @@ ON (key = num); 101 (1 row) --- VALUES with unsupported OUTER join +-- VALUES with supported OUTER join (since test_values is recursively planned) SELECT count(*) FROM @@ -256,8 +256,14 @@ FROM RIGHT JOIN (SELECT a,b FROM (VALUES (1, 'one'), (2, 'two'), (3, 'three')) as t(a,b) ) as foo (num,letter) ON (key = num); -ERROR: cannot pushdown the subquery -DETAIL: There exist a VALUES clause in the outer part of the outer join +DEBUG: Wrapping relation "test_values" to a subquery +DEBUG: generating subplan XXX_1 for subquery SELECT key FROM values_subquery.test_values WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT test_values_1.key, NULL::text AS value, NULL::jsonb AS data FROM (SELECT intermediate_result.key FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer)) test_values_1) test_values RIGHT JOIN (SELECT t.a, t.b FROM (VALUES (1,'one'::text), (2,'two'::text), (3,'three'::text)) t(a, b)) foo(num, letter) ON ((test_values.key OPERATOR(pg_catalog.=) foo.num))) + count +--------------------------------------------------------------------- + 3 +(1 row) + -- values with router queries SELECT count(*) @@ -456,12 +462,18 @@ SELECT count(*) FROM 296 (1 row) --- VALUES cannot be the right relationship in a join +-- VALUES can be the right relationship in a join SELECT count(*) FROM (SELECT random() FROM test_values RIGHT JOIN (SELECT a, b FROM (VALUES (1, 'one'), (2, 'two'), (3, 'three')) as t(a,b)) as values_data(a,b) ON test_values.key > values_data.a) subquery_1; -ERROR: cannot pushdown the subquery -DETAIL: There exist a VALUES clause in the outer part of the outer join +DEBUG: Wrapping relation "test_values" to a subquery +DEBUG: generating subplan XXX_1 for subquery SELECT key FROM values_subquery.test_values WHERE true +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT random() AS random FROM ((SELECT test_values_1.key, NULL::text AS value, NULL::jsonb AS data FROM (SELECT intermediate_result.key FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer)) test_values_1) test_values RIGHT JOIN (SELECT t.a, t.b FROM (VALUES (1,'one'::text), (2,'two'::text), (3,'three'::text)) t(a, b)) values_data(a, b) ON ((test_values.key OPERATOR(pg_catalog.>) values_data.a)))) subquery_1 + count +--------------------------------------------------------------------- + 294 +(1 row) + -- subquery IN WHERE clause need to be recursively planned -- but it is correlated so cannot be pushed down SELECT diff --git a/src/test/regress/expected/with_join.out b/src/test/regress/expected/with_join.out index f20334403..22a53625b 100644 --- a/src/test/regress/expected/with_join.out +++ b/src/test/regress/expected/with_join.out @@ -151,7 +151,7 @@ LIMIT 2 (5 rows) --- cte LEFT JOIN distributed_table should error out +-- cte LEFT JOIN distributed_table should work -- as long as the CTE is recursively planned WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE user_id = 1 ORDER BY value_1 @@ -166,8 +166,15 @@ ORDER BY 1,2,3 LIMIT 5; -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table + user_id | time | event_type +--------------------------------------------------------------------- + 1 | Wed Nov 22 22:51:43.132261 2017 | 0 + 1 | Wed Nov 22 22:51:43.132261 2017 | 0 + 1 | Wed Nov 22 22:51:43.132261 2017 | 1 + 1 | Wed Nov 22 22:51:43.132261 2017 | 1 + 1 | Wed Nov 22 22:51:43.132261 2017 | 2 +(5 rows) + -- cte RIGHT JOIN distributed_table should work WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE user_id = 1 ORDER BY value_1 @@ -214,7 +221,7 @@ LIMIT 1 | Thu Nov 23 09:26:42.145043 2017 | 2 (5 rows) --- distributed_table RIGHT JOIN cte should error out +-- distributed_table RIGHT JOIN cte should work WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE value_1 = 1 ORDER BY value_1 ) @@ -228,9 +235,16 @@ ORDER BY 1,2,3 LIMIT 5; -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table --- cte FULL JOIN distributed_table should error out + user_id | time | event_type +--------------------------------------------------------------------- + 1 | Thu Nov 23 09:26:42.145043 2017 | 0 + 1 | Thu Nov 23 09:26:42.145043 2017 | 0 + 1 | Thu Nov 23 09:26:42.145043 2017 | 1 + 1 | Thu Nov 23 09:26:42.145043 2017 | 1 + 1 | Thu Nov 23 09:26:42.145043 2017 | 2 +(5 rows) + +-- cte FULL JOIN distributed_table should work WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE user_id = 1 ORDER BY value_1 ) @@ -244,8 +258,15 @@ ORDER BY 1,2,3 LIMIT 5; -ERROR: cannot pushdown the subquery -DETAIL: Complex subqueries, CTEs and local tables cannot be in the outer part of an outer join with a distributed table + user_id | time | event_type +--------------------------------------------------------------------- + 1 | Wed Nov 22 22:51:43.132261 2017 | 0 + 1 | Wed Nov 22 22:51:43.132261 2017 | 0 + 1 | Wed Nov 22 22:51:43.132261 2017 | 1 + 1 | Wed Nov 22 22:51:43.132261 2017 | 1 + 1 | Wed Nov 22 22:51:43.132261 2017 | 2 +(5 rows) + -- Joins with reference tables are planned as router queries WITH cte AS MATERIALIZED ( SELECT value_2, max(user_id) AS user_id FROM users_table WHERE value_2 = 1 GROUP BY value_2 HAVING count(*) > 1 diff --git a/src/test/regress/sql/citus_local_tables_queries.sql b/src/test/regress/sql/citus_local_tables_queries.sql index 5f1d561b3..adae17118 100644 --- a/src/test/regress/sql/citus_local_tables_queries.sql +++ b/src/test/regress/sql/citus_local_tables_queries.sql @@ -210,7 +210,6 @@ SELECT count(*) FROM reference_table LEFT JOIN postgres_local_table ON (true) LEFT JOIN reference_table r2 ON (true); --- not supported direct outer join SELECT count(*) FROM citus_local_table LEFT JOIN distributed_table ON (true); -- distinct in subquery on CTE diff --git a/src/test/regress/sql/citus_local_tables_queries_mx.sql b/src/test/regress/sql/citus_local_tables_queries_mx.sql index cad6a0386..8bdb41a19 100644 --- a/src/test/regress/sql/citus_local_tables_queries_mx.sql +++ b/src/test/regress/sql/citus_local_tables_queries_mx.sql @@ -203,7 +203,7 @@ SELECT count(*) FROM reference_table LEFT JOIN postgres_local_table ON (true) LEFT JOIN reference_table r2 ON (true); --- not supported direct outer join +-- supported outer join SELECT count(*) FROM citus_local_table LEFT JOIN distributed_table ON (true); -- distinct in subquery on CTE diff --git a/src/test/regress/sql/cross_join.sql b/src/test/regress/sql/cross_join.sql index 3e776368b..0726a79e1 100644 --- a/src/test/regress/sql/cross_join.sql +++ b/src/test/regress/sql/cross_join.sql @@ -33,7 +33,7 @@ SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table r -- two reference tables CROSS JOINNed, and later JOINED with distributed tables -- but the reference table CROSS JOIN is in the outer side of the JOIN with the distributed table --- so we cannot pushdown +-- so this is supported by recursively planning the distributed table (users_table) SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id = users_table.user_id); SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 FULL JOIN users_table ON (ref1.id = users_table.user_id); SELECT count(*) FROM users_ref_test_table ref1 CROSS JOIN users_ref_test_table ref2 LEFT JOIN users_table ON (ref1.id != users_table.user_id); diff --git a/src/test/regress/sql/mixed_relkind_tests.sql b/src/test/regress/sql/mixed_relkind_tests.sql index 8e258b7d1..6b7463cfd 100644 --- a/src/test/regress/sql/mixed_relkind_tests.sql +++ b/src/test/regress/sql/mixed_relkind_tests.sql @@ -103,10 +103,8 @@ INSERT INTO partitioned_distributed_table SELECT foo.* FROM partitioned_distribu INSERT INTO partitioned_distributed_table SELECT foo.* FROM distributed_table AS foo JOIN citus_local_table ON (true); INSERT INTO distributed_table SELECT foo.a FROM partitioned_distributed_table AS foo JOIN citus_local_table ON (true); --- should fail SELECT COUNT(*) FROM reference_table LEFT JOIN partitioned_distributed_table ON true; - -- non-colocated subquery should work SELECT COUNT(*) FROM (SELECT *, random() FROM partitioned_distributed_table) AS foo, diff --git a/src/test/regress/sql/multi_dropped_column_aliases.sql b/src/test/regress/sql/multi_dropped_column_aliases.sql index 7e6729351..204a895f1 100644 --- a/src/test/regress/sql/multi_dropped_column_aliases.sql +++ b/src/test/regress/sql/multi_dropped_column_aliases.sql @@ -22,12 +22,11 @@ SELECT * FROM customer LIMIT 2; -- Verify joins work with dropped columns. SELECT count(*) FROM customer, orders WHERE c_custkey = o_custkey; --- Test joinExpr aliases by performing an outer-join. This code path is --- currently not exercised, but we are adding this test to catch this bug when --- we start supporting outer joins. +-- Test joinExpr aliases by performing an outer-join. SELECT c_custkey FROM (customer LEFT OUTER JOIN orders ON (c_custkey = o_custkey)) AS test(c_custkey, c_nationkey) INNER JOIN lineitem ON (test.c_custkey = l_orderkey) +ORDER BY 1 LIMIT 10; diff --git a/src/test/regress/sql/multi_outer_join_reference.sql b/src/test/regress/sql/multi_outer_join_reference.sql index 6aa2658b7..9c824736b 100644 --- a/src/test/regress/sql/multi_outer_join_reference.sql +++ b/src/test/regress/sql/multi_outer_join_reference.sql @@ -159,7 +159,7 @@ FROM multi_outer_join_left_hash a LEFT JOIN multi_outer_join_right_reference b ON (l_custkey = r_custkey AND l_custkey = -1 /* nonexistant */); --- Right join should be disallowed in this case +-- Right join is allowed as we recursively plan the distributed table (multi_outer_join_left_hash) SELECT min(r_custkey), max(r_custkey) FROM @@ -259,7 +259,7 @@ FROM ON (l_custkey = r_custkey AND r_custkey = 21); --- Right join should not be allowed in this case +-- Right join should be allowed in this case as we recursively plan the distributed table (multi_outer_join_left_hash SELECT min(r_custkey), max(r_custkey) FROM @@ -377,12 +377,13 @@ WHERE l_custkey is NULL or r_custkey is NULL ORDER BY 1,2 DESC; --- full outer join should error out for mismatched shards +-- full outer join should work as we recursively plan the distributed table (multi_outer_join_left_hash SELECT l_custkey, t_custkey FROM multi_outer_join_left_hash l1 - FULL JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey); + FULL JOIN multi_outer_join_third_reference t1 ON (l1.l_custkey = t1.t_custkey) +ORDER BY 1,2; -- inner join + single shard left join should work SELECT diff --git a/src/test/regress/sql/multi_shard_update_delete.sql b/src/test/regress/sql/multi_shard_update_delete.sql index e0777ed27..8890108a5 100644 --- a/src/test/regress/sql/multi_shard_update_delete.sql +++ b/src/test/regress/sql/multi_shard_update_delete.sql @@ -569,12 +569,17 @@ WHERE user_id IN FROM events_test_table); -- Reference tables can not locate on the outer part of the outer join -UPDATE users_test_table -SET value_1 = 4 -WHERE user_id IN - (SELECT DISTINCT e2.user_id - FROM users_reference_copy_table - LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1)) RETURNING *; +WITH updated as ( + UPDATE users_test_table + SET value_1 = 4 + WHERE user_id IN ( + SELECT DISTINCT e2.user_id + FROM users_reference_copy_table + LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1) + ) + RETURNING * +) +SELECT * FROM updated ORDER BY 1; -- Volatile functions are also not supported UPDATE users_test_table diff --git a/src/test/regress/sql/multi_subquery_complex_reference_clause.sql b/src/test/regress/sql/multi_subquery_complex_reference_clause.sql index b8451f559..84987ec4d 100644 --- a/src/test/regress/sql/multi_subquery_complex_reference_clause.sql +++ b/src/test/regress/sql/multi_subquery_complex_reference_clause.sql @@ -42,9 +42,9 @@ SELECT subquery_1.user_id FROM ON user_buy_test_table.user_id > users_ref_test_table.id) subquery_1 ORDER BY 1; --- Shouldn't work, reference table at the outer side is not allowed +-- Should work, reference table at the outer side is allowed SELECT * FROM - (SELECT random() FROM users_ref_test_table LEFT JOIN user_buy_test_table + (SELECT random() > 2 FROM users_ref_test_table LEFT JOIN user_buy_test_table ON users_ref_test_table.id = user_buy_test_table.user_id) subquery_1; -- Should work, reference table at the inner side is allowed @@ -52,9 +52,9 @@ SELECT count(*) FROM (SELECT random() FROM users_ref_test_table RIGHT JOIN user_buy_test_table ON user_buy_test_table.user_id = users_ref_test_table.id) subquery_1; --- Shouldn't work, reference table at the outer side is not allowed +-- Should work, reference table at the outer side is allowed SELECT * FROM - (SELECT random() FROM user_buy_test_table RIGHT JOIN users_ref_test_table + (SELECT random() > 2 FROM user_buy_test_table RIGHT JOIN users_ref_test_table ON user_buy_test_table.user_id = users_ref_test_table.id) subquery_1; -- Equi join test with reference table on non-partition keys @@ -166,7 +166,7 @@ SELECT count(*) FROM SELECT count(*) FROM user_buy_test_table LEFT JOIN (SELECT * FROM generate_series(1,10) id) users_ref_test_table ON user_buy_test_table.item_id = users_ref_test_table.id; --- table function cannot be the outer relationship in an outer join +-- table function can be the outer relationship in an outer join SELECT count(*) FROM (SELECT random() FROM user_buy_test_table RIGHT JOIN generate_series(1,10) AS users_ref_test_table(id) ON user_buy_test_table.item_id > users_ref_test_table.id) subquery_1; @@ -208,7 +208,7 @@ ON user_buy_test_table.item_id = users_ref_test_table.id; SELECT count(*) FROM user_buy_test_table LEFT JOIN (SELECT 5 AS id) users_ref_test_table ON user_buy_test_table.item_id = users_ref_test_table.id; --- subquery without FROM cannot be the outer relationship in an outer join +-- subquery without FROM can be the outer relationship in an outer join SELECT count(*) FROM user_buy_test_table RIGHT JOIN (SELECT 5 AS id) users_ref_test_table ON user_buy_test_table.item_id = users_ref_test_table.id; @@ -276,8 +276,8 @@ SELECT * FROM SELECT user_id FROM user_buy_test_table) sub ORDER BY 1 DESC; --- query can be pushed down when a reference table inside union query is --- joined with a distributed table. reference table cannot be at +-- query is supported when a reference table inside union query is +-- joined with a distributed table. reference table can be at -- the outer part. SELECT * FROM (SELECT user_id FROM users_ref_test_table ref LEFT JOIN user_buy_test_table dis @@ -300,7 +300,7 @@ FROM ) as foo GROUP BY user_id ORDER BY 2 DESC LIMIT 10; --- should not be able to pushdown since reference table is in the +-- supported even if the reference table is in the -- direct outer part of the left join SELECT user_id, sum(value_1) @@ -313,15 +313,15 @@ FROM ) as foo GROUP BY user_id ORDER BY 2 DESC LIMIT 10; --- should not be able to pushdown since reference table is in the +-- supported even if the reference table is in the -- direct outer part of the left join wrapped into a subquery SELECT - * + COUNT(*) = 1581 FROM (SELECT *, random() FROM events_reference_table) as ref_all LEFT JOIN users_table ON (users_table.user_id = ref_all.value_2); --- should not be able to pushdown since reference table is in the +-- supported even if the reference table is in the -- outer part of the left join SELECT user_id, sum(value_1) @@ -1082,7 +1082,7 @@ INNER JOIN GROUP BY types ORDER BY types; --- just a sanity check that we don't allow this if the reference table is on the +-- just a sanity check that we allow this even if the reference table is on the -- left part of the left join SELECT count(*) FROM (SELECT random() FROM users_ref_test_table LEFT JOIN user_buy_test_table @@ -1425,7 +1425,7 @@ JOIN ORDER BY 1 LIMIT 5; --- outer part of the LEFT JOIN consists only reference tables, so we cannot push down +-- supported even if the outer part of the LEFT JOIN consists only reference tables -- we have different combinations for ON condition, true/false/two column join/single column filter SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON true; SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON true; @@ -1439,7 +1439,7 @@ SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table re SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id LEFT JOIN user_buy_test_table ON (ref2.id = user_buy_test_table.user_id); --- outer part of the LEFT JOIN consists only reference tables within a subquery, so we cannot push down +-- outer part of the LEFT JOIN consists only reference tables within a subquery -- we have different combinations for ON condition, true/false/two column join/single column filter SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON true; SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo LEFT JOIN user_buy_test_table ON true; @@ -1454,16 +1454,13 @@ SELECT *, random() FROM ( SELECT *,random() FROM user_buy_test_table WHERE user_id > ( SELECT count(*) FROM (SELECT *,random() FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as bar) as foo LEFT JOIN (SELECT *, random() FROM (SELECT *,random() FROM user_buy_test_table d1 JOIN user_buy_test_table d2 USING (user_id)) as bar_inner ) as bar ON true)) as boo; --- In theory, we should be able to pushdown this query --- however, as the LEFT JOIN condition is between a reference table and the distributed table --- Postgres generates a LEFT JOIN alternative among those tables SELECT count(*) FROM (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN user_buy_test_table u1 on ref1.id = u1.user_id) as foo LEFT JOIN user_buy_test_table ON (foo.id = user_buy_test_table.user_id); -- same as the above query, but this time LEFT JOIN condition is between distributed tables -- so Postgres doesn't generate join restriction between reference and distributed tables SELECT count(*) FROM (SELECT u1.*, random() FROM users_ref_test_table ref1 INNER JOIN user_buy_test_table u1 on ref1.id = u1.user_id) as foo LEFT JOIN user_buy_test_table ON (foo.user_id = user_buy_test_table.user_id); --- outer part of the LEFT JOIN consists only intermediate result due to LIMIT, so we cannot push down +-- outer part of the LEFT JOIN consists only intermediate result due to LIMIT but this is still supported SELECT count(*) FROM (SELECT ref1.* FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id LIMIT 5) as foo LEFT JOIN user_buy_test_table ON true; -- should be fine as OUTER part is the distributed table diff --git a/src/test/regress/sql/multi_view.sql b/src/test/regress/sql/multi_view.sql index 3165f50c4..48f613623 100644 --- a/src/test/regress/sql/multi_view.sql +++ b/src/test/regress/sql/multi_view.sql @@ -231,8 +231,8 @@ SELECT * FROM ) s1 ORDER BY 2 DESC, 1; --- event vs table non-partition-key join is not supported --- given that we cannot recursively plan tables yet +-- event vs table non-partition-key join is supported +-- given that we can recursively plan events_table SELECT * FROM (SELECT ru.user_id, CASE WHEN et.user_id IS NULL THEN 'NO' ELSE 'YES' END as done_event FROM recent_users ru diff --git a/src/test/regress/sql/non_colocated_subquery_joins.sql b/src/test/regress/sql/non_colocated_subquery_joins.sql index 0c8953d2c..e1d25a691 100644 --- a/src/test/regress/sql/non_colocated_subquery_joins.sql +++ b/src/test/regress/sql/non_colocated_subquery_joins.sql @@ -724,7 +724,7 @@ $$); -- similar to the above, make sure that we skip recursive planning when -- the subquery contains only intermediate results -SELECT * +SELECT COUNT(*) = 176 FROM ( SELECT * FROM( diff --git a/src/test/regress/sql/values.sql b/src/test/regress/sql/values.sql index 51328d4ff..4a5bb8352 100644 --- a/src/test/regress/sql/values.sql +++ b/src/test/regress/sql/values.sql @@ -159,7 +159,7 @@ FROM (SELECT a,b FROM (VALUES (1, 'one'), (2, 'two'), (3, 'three')) as t(a,b) ) as foo (num,letter) ON (key = num); --- VALUES with unsupported OUTER join +-- VALUES with supported OUTER join (since test_values is recursively planned) SELECT count(*) FROM @@ -299,7 +299,7 @@ SELECT count(*) FROM (SELECT random() FROM test_values LEFT JOIN (SELECT a, b FROM (VALUES (1, 'one'), (2, 'two'), (3, 'three')) as t(a,b)) as values_data(a,b) ON test_values.key > values_data.a) subquery_1; --- VALUES cannot be the right relationship in a join +-- VALUES can be the right relationship in a join SELECT count(*) FROM (SELECT random() FROM test_values RIGHT JOIN (SELECT a, b FROM (VALUES (1, 'one'), (2, 'two'), (3, 'three')) as t(a,b)) as values_data(a,b) ON test_values.key > values_data.a) subquery_1; diff --git a/src/test/regress/sql/with_join.sql b/src/test/regress/sql/with_join.sql index 54669d75f..b21c321b0 100644 --- a/src/test/regress/sql/with_join.sql +++ b/src/test/regress/sql/with_join.sql @@ -126,7 +126,7 @@ ORDER BY LIMIT 5; --- cte LEFT JOIN distributed_table should error out +-- cte LEFT JOIN distributed_table should work -- as long as the CTE is recursively planned WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE user_id = 1 ORDER BY value_1 @@ -173,7 +173,7 @@ ORDER BY LIMIT 5; --- distributed_table RIGHT JOIN cte should error out +-- distributed_table RIGHT JOIN cte should work WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE value_1 = 1 ORDER BY value_1 ) @@ -188,7 +188,7 @@ ORDER BY LIMIT 5; --- cte FULL JOIN distributed_table should error out +-- cte FULL JOIN distributed_table should work WITH cte AS MATERIALIZED ( SELECT * FROM users_table WHERE user_id = 1 ORDER BY value_1 )