mirror of https://github.com/citusdata/citus.git
Phase - I: recursively plan non-recurring relations
parent
3cc5d9842a
commit
f339450a9d
|
@ -1845,6 +1845,8 @@ multi_join_restriction_hook(PlannerInfo *root,
|
|||
*/
|
||||
joinRestrictionContext->hasSemiJoin = joinRestrictionContext->hasSemiJoin ||
|
||||
extra->sjinfo->jointype == JOIN_SEMI;
|
||||
joinRestrictionContext->hasOuterJoin = joinRestrictionContext->hasOuterJoin ||
|
||||
IS_OUTER_JOIN(extra->sjinfo->jointype);
|
||||
|
||||
MemoryContextSwitchTo(oldMemoryContext);
|
||||
}
|
||||
|
|
|
@ -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)
|
||||
{
|
||||
|
|
|
@ -137,6 +137,7 @@ static bool ShouldRecursivelyPlanNonColocatedSubqueries(Query *subquery,
|
|||
RecursivePlanningContext *
|
||||
context);
|
||||
static bool ContainsSubquery(Query *query);
|
||||
static bool ShouldRecursivelyPlanOuterJoins(RecursivePlanningContext *context);
|
||||
static void RecursivelyPlanNonColocatedSubqueries(Query *subquery,
|
||||
RecursivePlanningContext *context);
|
||||
static void RecursivelyPlanNonColocatedJoinWalker(Node *joinNode,
|
||||
|
@ -149,6 +150,11 @@ static void RecursivelyPlanNonColocatedSubqueriesInWhere(Query *query,
|
|||
colocatedJoinChecker,
|
||||
RecursivePlanningContext *
|
||||
recursivePlanningContext);
|
||||
static bool RecursivelyPlanRecurringTupleOuterJoinWalker(Node *node, Query *query,
|
||||
RecursivePlanningContext *context);
|
||||
static void RecursivelyPlanDistributedJoinNode(Node *node, Query *query,
|
||||
RecursivePlanningContext *context);
|
||||
static bool IsRTERefRecurring(RangeTblRef *rangeTableRef, Query *query);
|
||||
static List * SublinkListFromWhere(Query *originalQuery);
|
||||
static bool ExtractSublinkWalker(Node *node, List **sublinkList);
|
||||
static bool ShouldRecursivelyPlanSublinks(Query *query);
|
||||
|
@ -359,6 +365,22 @@ RecursivelyPlanSubqueriesAndCTEs(Query *query, RecursivePlanningContext *context
|
|||
RecursivelyPlanLocalTableJoins(query, context);
|
||||
}
|
||||
|
||||
/*
|
||||
* Similarly, logical planner cannot handle outer joins when the outer rel
|
||||
* is recurring, such as "<recurring> LEFT JOIN <distributed>". 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
|
||||
* "<recurring> LEFT JOIN <recurring>".
|
||||
*
|
||||
* See DeferredErrorIfUnsupportedRecurringTuplesJoin for the supported join
|
||||
* types.
|
||||
*/
|
||||
if (ShouldRecursivelyPlanOuterJoins(context))
|
||||
{
|
||||
RecursivelyPlanRecurringTupleOuterJoinWalker((Node *) query->jointree,
|
||||
query, context);
|
||||
}
|
||||
|
||||
return NULL;
|
||||
}
|
||||
|
@ -440,6 +462,25 @@ ContainsSubquery(Query *query)
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
* ShouldRecursivelyPlanOuterJoins returns true if the JoinRestrictionContext
|
||||
* that given RecursivePlanningContext holds implies that the query has outer
|
||||
* join(s) that might need to be recursively planned.
|
||||
*/
|
||||
static bool
|
||||
ShouldRecursivelyPlanOuterJoins(RecursivePlanningContext *context)
|
||||
{
|
||||
if (!context || !context->plannerRestrictionContext ||
|
||||
!context->plannerRestrictionContext->joinRestrictionContext)
|
||||
{
|
||||
ereport(ERROR, (errmsg("unexpectedly got NULL pointer in recursive "
|
||||
"planning context")));
|
||||
}
|
||||
|
||||
return context->plannerRestrictionContext->joinRestrictionContext->hasOuterJoin;
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* RecursivelyPlanNonColocatedSubqueries gets a query which includes one or more
|
||||
* other subqueries that are not joined on their distribution keys. The function
|
||||
|
@ -599,6 +640,300 @@ RecursivelyPlanNonColocatedSubqueriesInWhere(Query *query,
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
* RecursivelyPlanRecurringTupleOuterJoinWalker 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 <distributed> in "<recurring> LEFT JOIN <distributed>", i.e.,
|
||||
* where the recurring rel causes returning recurring tuples from the worker
|
||||
* nodes.
|
||||
*
|
||||
* Returns true if given node is recurring.
|
||||
*
|
||||
* See RecursivelyPlanDistributedJoinNode() function for the explanation on
|
||||
* what does it mean for a node to be "recurring" or "distributed".
|
||||
*/
|
||||
static bool
|
||||
RecursivelyPlanRecurringTupleOuterJoinWalker(Node *node, Query *query,
|
||||
RecursivePlanningContext *
|
||||
recursivePlanningContext)
|
||||
{
|
||||
if (node == NULL)
|
||||
{
|
||||
return false;
|
||||
}
|
||||
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);
|
||||
|
||||
RecursivelyPlanRecurringTupleOuterJoinWalker(fromElement, query,
|
||||
recursivePlanningContext);
|
||||
}
|
||||
|
||||
/*
|
||||
* Can only appear during the top-level call and top-level callers
|
||||
* are not interested in the return value. Even more, we can't tell
|
||||
* whether a FromExpr is recurring or not.
|
||||
*/
|
||||
return false;
|
||||
}
|
||||
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.
|
||||
*
|
||||
* We first handle the sub join trees and then the top level one since the
|
||||
* top level join expression might not require recursive planning after
|
||||
* handling the sub join trees.
|
||||
*/
|
||||
bool leftNodeRecurs =
|
||||
RecursivelyPlanRecurringTupleOuterJoinWalker(leftNode, query,
|
||||
recursivePlanningContext);
|
||||
bool rightNodeRecurs =
|
||||
RecursivelyPlanRecurringTupleOuterJoinWalker(rightNode, query,
|
||||
recursivePlanningContext);
|
||||
switch (joinExpr->jointype)
|
||||
{
|
||||
case JOIN_LEFT:
|
||||
{
|
||||
/* <recurring> left join <distributed> */
|
||||
if (leftNodeRecurs && !rightNodeRecurs)
|
||||
{
|
||||
ereport(DEBUG1, (errmsg("recursively planning right side of "
|
||||
"the left join since the outer side "
|
||||
"is a recurring rel")));
|
||||
RecursivelyPlanDistributedJoinNode(rightNode, query,
|
||||
recursivePlanningContext);
|
||||
}
|
||||
|
||||
/*
|
||||
* A LEFT JOIN is recurring if the lhs is recurring.
|
||||
* Note that we should have converted the rhs into a recurring
|
||||
* one too if the lhs is recurring, but this anyway has no
|
||||
* effects when deciding whether a LEFT JOIN is recurring.
|
||||
*/
|
||||
return leftNodeRecurs;
|
||||
}
|
||||
|
||||
case JOIN_RIGHT:
|
||||
{
|
||||
/* <distributed> right join <recurring> */
|
||||
if (!leftNodeRecurs && rightNodeRecurs)
|
||||
{
|
||||
ereport(DEBUG1, (errmsg("recursively planning left side of "
|
||||
"the right join since the outer side "
|
||||
"is a recurring rel")));
|
||||
RecursivelyPlanDistributedJoinNode(leftNode, query,
|
||||
recursivePlanningContext);
|
||||
}
|
||||
|
||||
/*
|
||||
* Similar to LEFT JOINs, a RIGHT JOIN is recurring if the rhs
|
||||
* is recurring.
|
||||
*/
|
||||
return rightNodeRecurs;
|
||||
}
|
||||
|
||||
case JOIN_FULL:
|
||||
{
|
||||
/*
|
||||
* <recurring> full join <distributed>
|
||||
* <distributed> full join <recurring>
|
||||
*/
|
||||
if (leftNodeRecurs && !rightNodeRecurs)
|
||||
{
|
||||
ereport(DEBUG1, (errmsg("recursively planning right side of "
|
||||
"the full join since the other side "
|
||||
"is a recurring rel")));
|
||||
RecursivelyPlanDistributedJoinNode(rightNode, query,
|
||||
recursivePlanningContext);
|
||||
}
|
||||
else if (!leftNodeRecurs && rightNodeRecurs)
|
||||
{
|
||||
ereport(DEBUG1, (errmsg("recursively planning left side of "
|
||||
"the full join since the other side "
|
||||
"is a recurring rel")));
|
||||
RecursivelyPlanDistributedJoinNode(leftNode, query,
|
||||
recursivePlanningContext);
|
||||
}
|
||||
|
||||
/*
|
||||
* An OUTER JOIN is recurring if any sides of the join is
|
||||
* recurring. As in other outer join types, it doesn't matter
|
||||
* whether the other side was / became recurring or not.
|
||||
*/
|
||||
return leftNodeRecurs || rightNodeRecurs;
|
||||
}
|
||||
|
||||
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.
|
||||
*/
|
||||
return leftNodeRecurs && rightNodeRecurs;
|
||||
}
|
||||
|
||||
default:
|
||||
{
|
||||
ereport(ERROR, (errmsg("got unexpected join type (%d) when recursively "
|
||||
"planning a join",
|
||||
joinExpr->jointype)));
|
||||
}
|
||||
}
|
||||
}
|
||||
else if (IsA(node, RangeTblRef))
|
||||
{
|
||||
return IsRTERefRecurring((RangeTblRef *) node, query);
|
||||
}
|
||||
else
|
||||
{
|
||||
ereport(ERROR, errmsg("got unexpected node type (%d) when recursively "
|
||||
"planning a join",
|
||||
nodeTag(node)));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* RecursivelyPlanDistributedJoinNode is a helper function for
|
||||
* RecursivelyPlanRecurringTupleOuterJoinWalker that recursively plans given
|
||||
* distributed node that is known to be inner side of an outer join.
|
||||
*
|
||||
* We call a node "distributed" if it points to a distributed table or a
|
||||
* more complex object (i.e., a join tree or a subquery) that can be pushed
|
||||
* down to the worker nodes directly. For a join, this means that it's either
|
||||
* an INNER join where any side of it is a distributed table / a distributed
|
||||
* sub join tree, or an OUTER join where the outer side is a distributed table
|
||||
* / a distributed sub join tree.
|
||||
*/
|
||||
static void
|
||||
RecursivelyPlanDistributedJoinNode(Node *node, Query *query,
|
||||
RecursivePlanningContext *recursivePlanningContext)
|
||||
{
|
||||
if (IsA(node, JoinExpr))
|
||||
{
|
||||
/*
|
||||
* XXX: This, for example, means that RecursivelyPlanRecurringTupleOuterJoins
|
||||
* needs to plan inner side, i.e., <distributed> INNER JOIN <distributed>,
|
||||
* of the following join:
|
||||
*
|
||||
* <recurring> LEFT JOIN (<distributed> INNER JOIN <distributed>)
|
||||
*
|
||||
* 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(node, RangeTblRef))
|
||||
{
|
||||
ereport(ERROR, (errmsg("unexpected join node type (%d)",
|
||||
nodeTag(node))));
|
||||
}
|
||||
|
||||
RangeTblRef *rangeTableRef = (RangeTblRef *) node;
|
||||
if (IsRTERefRecurring(rangeTableRef, query))
|
||||
{
|
||||
/*
|
||||
* Not the top-level callers but RecursivelyPlanDistributedJoinNode
|
||||
* might call itself for recurring nodes and need to skip them.
|
||||
*/
|
||||
return;
|
||||
}
|
||||
|
||||
RangeTblEntry *distributedRte = rt_fetch(rangeTableRef->rtindex,
|
||||
query->rtable);
|
||||
if (distributedRte->rtekind == RTE_RELATION)
|
||||
{
|
||||
ereport(DEBUG1, (errmsg("recursively planning distributed relation %s "
|
||||
"since it is part of a distributed join node "
|
||||
"that is outer joined with a recurring rel",
|
||||
GetRelationNameAndAliasName(distributedRte))));
|
||||
|
||||
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 RecursivelyPlanRecurringTupleOuterJoinWalker to try recursively
|
||||
* plan such an RTE.
|
||||
*/
|
||||
ereport(ERROR, errmsg("got unexpected RTE type (%d) when recursively "
|
||||
"planning a join",
|
||||
distributedRte->rtekind));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* IsRTERefRecurring returns true if given rte reference points to a recurring
|
||||
* rte.
|
||||
*
|
||||
* If an rte points to a table, then we call it recurring if the table is not
|
||||
* a distributed table. Otherwise, e.g., if it points a query, then we call it
|
||||
* recurring if none of the rtes that belongs to the query point to a distributed
|
||||
* table.
|
||||
*
|
||||
* Note that it's safe to assume a subquery is not recurring if we have a rte reference
|
||||
* to a distributed table somewhere in the query tree. For example, considering
|
||||
* the subquery (q) of the the following query:
|
||||
* SELECT * FROM ref LEFT JOIN (SELECT * FROM ref LEFT dist) q,
|
||||
* one might think that it's not appropriate to call IsRTERefRecurring for subquery
|
||||
* (q). However, this is already not the case because this function is called
|
||||
* in the context of recursive planning and hence any query that contains
|
||||
* rtes pointing to distributed tables and that cannot be pushed down to worker
|
||||
* nodes should've been recursively planned already. This is because, the recursive
|
||||
* planner processes the queries in bottom-up fashion. For this reason, the subquery
|
||||
* in the example should've already be converted to the following before we check
|
||||
* the rte reference that points to the subquery (q):
|
||||
* SELECT * FROM ref LEFT JOIN (SELECT * FROM ref LEFT (SELECT * FROM read_intermediate_result()) dist_1)
|
||||
* That way, we wouldn't incorrectly say that (SELECT * FROM ref LEFT dist) is a
|
||||
* distributed subquery (due to having a reference to a distributed table).
|
||||
*/
|
||||
static bool
|
||||
IsRTERefRecurring(RangeTblRef *rangeTableRef, Query *query)
|
||||
{
|
||||
int rangeTableIndex = rangeTableRef->rtindex;
|
||||
List *rangeTableList = query->rtable;
|
||||
RangeTblEntry *rangeTableEntry = rt_fetch(rangeTableIndex, rangeTableList);
|
||||
return !FindNodeMatchingCheckFunctionInRangeTableList(list_make1(rangeTableEntry),
|
||||
IsDistributedTableRTE);
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* 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
|
||||
|
|
|
@ -2230,6 +2230,7 @@ FilterJoinRestrictionContext(JoinRestrictionContext *joinRestrictionContext, Rel
|
|||
* the same query and as these values are calculated per-query basis.
|
||||
*/
|
||||
filtererdJoinRestrictionContext->hasSemiJoin = joinRestrictionContext->hasSemiJoin;
|
||||
filtererdJoinRestrictionContext->hasOuterJoin = joinRestrictionContext->hasOuterJoin;
|
||||
|
||||
return filtererdJoinRestrictionContext;
|
||||
}
|
||||
|
|
|
@ -72,6 +72,7 @@ typedef struct JoinRestrictionContext
|
|||
{
|
||||
List *joinRestrictionList;
|
||||
bool hasSemiJoin;
|
||||
bool hasOuterJoin;
|
||||
} JoinRestrictionContext;
|
||||
|
||||
typedef struct JoinRestriction
|
||||
|
|
|
@ -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 */
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -1212,9 +1212,16 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "distributed" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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
|
||||
|
|
|
@ -1577,9 +1577,16 @@ 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: recursively planning left side of the right join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "table2" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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');
|
||||
|
|
|
@ -349,10 +349,17 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "partitioned_distributed_table" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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,
|
||||
|
|
|
@ -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)
|
||||
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -664,15 +664,28 @@ WHERE user_id IN
|
|||
INTERSECT
|
||||
SELECT user_id
|
||||
FROM events_test_table);
|
||||
-- Reference tables can not locate on the outer part of the outer join
|
||||
-- Reference tables can locate on the outer part of the outer join
|
||||
-- Note that we don't need to sort the output because
|
||||
-- citus.sort_returning is enabled by default during
|
||||
-- regression tests.
|
||||
UPDATE users_test_table
|
||||
SET value_1 = 4
|
||||
WHERE user_id IN
|
||||
(SELECT DISTINCT e2.user_id
|
||||
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
|
||||
LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1)
|
||||
)
|
||||
RETURNING *;
|
||||
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
|
||||
|
|
|
@ -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,26 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "user_buy_test_table" "dis" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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 +576,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 +588,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 +622,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 +1528,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 +2026,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 +2152,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
|
||||
|
@ -2062,123 +2181,212 @@ SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table r
|
|||
-- left outer part of the FULL JOIN consists only reference tables, so we cannot push down
|
||||
-- we have different combinations for ON condition, true/false/two column join/single column filter
|
||||
SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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 FULL 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 FULL 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 FULL 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
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL JOIN user_buy_test_table ON (ref1.id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL JOIN user_buy_test_table ON (user_buy_test_table.user_id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id FULL 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
-- right outer part of the FULL JOIN consists only reference tables, so we cannot push down
|
||||
-- we have different combinations for ON condition, true/false/two column join/single column filter
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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 user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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 user_buy_test_table FULL JOIN users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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 user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id ON false;
|
||||
ERROR: cannot pushdown the subquery
|
||||
DETAIL: There exist a reference table in the outer part of the outer join
|
||||
count
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id ON false;
|
||||
ERROR: cannot pushdown the subquery
|
||||
DETAIL: There exist a reference table in the outer part of the outer join
|
||||
count
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id ON (ref1.id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id ON (user_buy_test_table.user_id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
-- left outer part of the FULL JOIN consists only reference tables within a subquery, so we cannot push down
|
||||
-- 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 FULL 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 FULL 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 FULL 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
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(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 FULL 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
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(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 FULL JOIN user_buy_test_table ON (foo.id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
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 FULL JOIN user_buy_test_table ON (user_buy_test_table.user_id > 19);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
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 FULL 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(1 row)
|
||||
|
||||
-- right outer part of the FULL JOIN consists only reference tables within a subquery, so we cannot push down
|
||||
-- we have different combinations for ON condition, true/false/two column join/single column filter
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo 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 user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo 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 user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo ON false;
|
||||
ERROR: cannot pushdown the subquery
|
||||
DETAIL: There exist a reference table in the outer part of the outer join
|
||||
count
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo ON false;
|
||||
ERROR: cannot pushdown the subquery
|
||||
DETAIL: There exist a reference table in the outer part of the outer join
|
||||
count
|
||||
---------------------------------------------------------------------
|
||||
10
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo ON (foo.id > 5);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 LEFT JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo ON (user_buy_test_table.user_id > 19);
|
||||
ERROR: FULL JOIN is only supported with merge-joinable or hash-joinable join conditions
|
||||
SELECT count(*) FROM user_buy_test_table FULL JOIN (SELECT ref1.*, random() FROM users_ref_test_table ref1 INNER JOIN users_ref_test_table ref2 on ref1.id = ref2.id) as foo 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
|
||||
---------------------------------------------------------------------
|
||||
7
|
||||
(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 FULL 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
|
||||
user_id | item_id | buy_count | random | random
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- In theory, we should be able to pushdown this query
|
||||
-- however, as the FULL JOIN condition is between a reference table and the distributed table
|
||||
-- Postgres generates a FULL 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 FULL 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
|
||||
---------------------------------------------------------------------
|
||||
4
|
||||
(1 row)
|
||||
|
||||
-- same as the above query, but this time FULL 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 FULL JOIN user_buy_test_table ON (foo.user_id = user_buy_test_table.user_id);
|
||||
|
@ -2189,8 +2397,11 @@ SELECT count(*) FROM (SELECT u1.*, random() FROM users_ref_test_table ref1 INNER
|
|||
|
||||
-- left outer part of the FULL JOIN consists only intermediate result due to LIMIT, so we cannot push down
|
||||
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 FULL 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)
|
||||
|
||||
DROP TABLE user_buy_test_table;
|
||||
DROP TABLE users_ref_test_table;
|
||||
DROP TABLE users_return_test_table;
|
||||
|
|
|
@ -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(*)
|
||||
|
|
|
@ -486,17 +486,23 @@ 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
|
||||
SELECT * FROM
|
||||
-- event vs table non-partition-key join is supported
|
||||
-- given that we can recursively plan events_table
|
||||
SELECT count(*), user_id, done_event FROM
|
||||
(SELECT ru.user_id, CASE WHEN et.user_id IS NULL THEN 'NO' ELSE 'YES' END as done_event
|
||||
FROM recent_users ru
|
||||
LEFT JOIN events_table et
|
||||
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
|
||||
GROUP BY user_id, done_event
|
||||
ORDER BY 1,2,3;
|
||||
count | user_id | done_event
|
||||
---------------------------------------------------------------------
|
||||
7 | 5 | YES
|
||||
23 | 3 | YES
|
||||
24 | 1 | YES
|
||||
(3 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);
|
||||
|
|
|
@ -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,18 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "users_table" "u2" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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 +1080,18 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "users_table" "u2" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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);
|
||||
|
|
|
@ -250,10 +250,17 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "test" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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.
|
||||
|
|
|
@ -505,10 +505,20 @@ 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "test" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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 +696,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) 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: recursively planning right side of the left join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "test" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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,16 @@ 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: recursively planning left side of the right join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "test_values" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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 +464,20 @@ 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: recursively planning left side of the right join since the outer side is a recurring rel
|
||||
DEBUG: recursively planning distributed relation "test_values" since it is part of a distributed join node that is outer joined with a recurring rel
|
||||
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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -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);
|
||||
|
|
|
@ -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,
|
||||
|
|
|
@ -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;
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -568,13 +568,18 @@ WHERE user_id IN
|
|||
SELECT user_id
|
||||
FROM events_test_table);
|
||||
|
||||
-- Reference tables can not locate on the outer part of the outer join
|
||||
-- Reference tables can locate on the outer part of the outer join
|
||||
-- Note that we don't need to sort the output because
|
||||
-- citus.sort_returning is enabled by default during
|
||||
-- regression tests.
|
||||
UPDATE users_test_table
|
||||
SET value_1 = 4
|
||||
WHERE user_id IN
|
||||
(SELECT DISTINCT e2.user_id
|
||||
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 *;
|
||||
LEFT JOIN users_test_table e2 ON (e2.user_id = users_reference_copy_table.value_1)
|
||||
)
|
||||
RETURNING *;
|
||||
|
||||
-- Volatile functions are also not supported
|
||||
UPDATE users_test_table
|
||||
|
|
|
@ -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
|
||||
|
|
|
@ -231,15 +231,16 @@ 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
|
||||
SELECT * FROM
|
||||
-- event vs table non-partition-key join is supported
|
||||
-- given that we can recursively plan events_table
|
||||
SELECT count(*), user_id, done_event FROM
|
||||
(SELECT ru.user_id, CASE WHEN et.user_id IS NULL THEN 'NO' ELSE 'YES' END as done_event
|
||||
FROM recent_users ru
|
||||
LEFT JOIN events_table et
|
||||
ON(ru.user_id = et.event_type)
|
||||
) s1
|
||||
ORDER BY 2 DESC, 1;
|
||||
GROUP BY user_id, done_event
|
||||
ORDER BY 1,2,3;
|
||||
|
||||
-- create a select only view
|
||||
CREATE VIEW selected_users AS SELECT * FROM users_table WHERE value_1 >= 1 and value_1 <3;
|
||||
|
|
|
@ -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(
|
||||
|
|
|
@ -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;
|
||||
|
|
|
@ -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
|
||||
)
|
||||
|
|
Loading…
Reference in New Issue