mirror of
https://github.com/postgres/postgres.git
synced 2025-06-06 00:02:36 -04:00
Support "Right Anti Join" plan shapes.
Merge and hash joins can support antijoin with the non-nullable input on the right, using very simple combinations of their existing logic for right join and anti join. This gives the planner more freedom about how to order the join. It's particularly useful for hash join, since we may now have the option to hash the smaller table instead of the larger. Richard Guo, reviewed by Ronan Dunklau and myself Discussion: https://postgr.es/m/CAMbWs48xh9hMzXzSy3VaPzGAz+fkxXXTUbCLohX1_L8THFRm2Q@mail.gmail.com
This commit is contained in:
parent
dad50f677c
commit
16dc2703c5
@ -1561,6 +1561,9 @@ ExplainNode(PlanState *planstate, List *ancestors,
|
|||||||
case JOIN_ANTI:
|
case JOIN_ANTI:
|
||||||
jointype = "Anti";
|
jointype = "Anti";
|
||||||
break;
|
break;
|
||||||
|
case JOIN_RIGHT_ANTI:
|
||||||
|
jointype = "Right Anti";
|
||||||
|
break;
|
||||||
default:
|
default:
|
||||||
jointype = "???";
|
jointype = "???";
|
||||||
break;
|
break;
|
||||||
|
@ -86,7 +86,7 @@
|
|||||||
* PHJ_BATCH_ALLOCATE* -- one allocates buckets
|
* PHJ_BATCH_ALLOCATE* -- one allocates buckets
|
||||||
* PHJ_BATCH_LOAD -- all load the hash table from disk
|
* PHJ_BATCH_LOAD -- all load the hash table from disk
|
||||||
* PHJ_BATCH_PROBE -- all probe
|
* PHJ_BATCH_PROBE -- all probe
|
||||||
* PHJ_BATCH_SCAN* -- one does full/right unmatched scan
|
* PHJ_BATCH_SCAN* -- one does right/right-anti/full unmatched scan
|
||||||
* PHJ_BATCH_FREE* -- one frees memory
|
* PHJ_BATCH_FREE* -- one frees memory
|
||||||
*
|
*
|
||||||
* Batch 0 is a special case, because it starts out in phase
|
* Batch 0 is a special case, because it starts out in phase
|
||||||
@ -228,10 +228,10 @@ ExecHashJoinImpl(PlanState *pstate, bool parallel)
|
|||||||
|
|
||||||
/*
|
/*
|
||||||
* If the outer relation is completely empty, and it's not
|
* If the outer relation is completely empty, and it's not
|
||||||
* right/full join, we can quit without building the hash
|
* right/right-anti/full join, we can quit without building
|
||||||
* table. However, for an inner join it is only a win to
|
* the hash table. However, for an inner join it is only a
|
||||||
* check this when the outer relation's startup cost is less
|
* win to check this when the outer relation's startup cost is
|
||||||
* than the projected cost of building the hash table.
|
* less than the projected cost of building the hash table.
|
||||||
* Otherwise it's best to build the hash table first and see
|
* Otherwise it's best to build the hash table first and see
|
||||||
* if the inner relation is empty. (When it's a left join, we
|
* if the inner relation is empty. (When it's a left join, we
|
||||||
* should always make this check, since we aren't going to be
|
* should always make this check, since we aren't going to be
|
||||||
@ -519,6 +519,14 @@ ExecHashJoinImpl(PlanState *pstate, bool parallel)
|
|||||||
continue;
|
continue;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
* In a right-antijoin, we never return a matched tuple.
|
||||||
|
* And we need to stay on the current outer tuple to
|
||||||
|
* continue scanning the inner side for matches.
|
||||||
|
*/
|
||||||
|
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||||
|
continue;
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* If we only need to join to the first matching inner
|
* If we only need to join to the first matching inner
|
||||||
* tuple, then consider returning this one, but after that
|
* tuple, then consider returning this one, but after that
|
||||||
@ -564,9 +572,10 @@ ExecHashJoinImpl(PlanState *pstate, bool parallel)
|
|||||||
case HJ_FILL_INNER_TUPLES:
|
case HJ_FILL_INNER_TUPLES:
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* We have finished a batch, but we are doing right/full join,
|
* We have finished a batch, but we are doing
|
||||||
* so any unmatched inner tuples in the hashtable have to be
|
* right/right-anti/full join, so any unmatched inner tuples
|
||||||
* emitted before we continue to the next batch.
|
* in the hashtable have to be emitted before we continue to
|
||||||
|
* the next batch.
|
||||||
*/
|
*/
|
||||||
if (!(parallel ? ExecParallelScanHashTableForUnmatched(node, econtext)
|
if (!(parallel ? ExecParallelScanHashTableForUnmatched(node, econtext)
|
||||||
: ExecScanHashTableForUnmatched(node, econtext)))
|
: ExecScanHashTableForUnmatched(node, econtext)))
|
||||||
@ -732,6 +741,7 @@ ExecInitHashJoin(HashJoin *node, EState *estate, int eflags)
|
|||||||
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
||||||
break;
|
break;
|
||||||
case JOIN_RIGHT:
|
case JOIN_RIGHT:
|
||||||
|
case JOIN_RIGHT_ANTI:
|
||||||
hjstate->hj_NullOuterTupleSlot =
|
hjstate->hj_NullOuterTupleSlot =
|
||||||
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
|
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
|
||||||
break;
|
break;
|
||||||
@ -1027,8 +1037,9 @@ ExecHashJoinNewBatch(HashJoinState *hjstate)
|
|||||||
* side, but there are exceptions:
|
* side, but there are exceptions:
|
||||||
*
|
*
|
||||||
* 1. In a left/full outer join, we have to process outer batches even if
|
* 1. In a left/full outer join, we have to process outer batches even if
|
||||||
* the inner batch is empty. Similarly, in a right/full outer join, we
|
* the inner batch is empty. Similarly, in a right/right-anti/full outer
|
||||||
* have to process inner batches even if the outer batch is empty.
|
* join, we have to process inner batches even if the outer batch is
|
||||||
|
* empty.
|
||||||
*
|
*
|
||||||
* 2. If we have increased nbatch since the initial estimate, we have to
|
* 2. If we have increased nbatch since the initial estimate, we have to
|
||||||
* scan inner batches since they might contain tuples that need to be
|
* scan inner batches since they might contain tuples that need to be
|
||||||
@ -1349,8 +1360,8 @@ ExecReScanHashJoin(HashJoinState *node)
|
|||||||
/*
|
/*
|
||||||
* Okay to reuse the hash table; needn't rescan inner, either.
|
* Okay to reuse the hash table; needn't rescan inner, either.
|
||||||
*
|
*
|
||||||
* However, if it's a right/full join, we'd better reset the
|
* However, if it's a right/right-anti/full join, we'd better
|
||||||
* inner-tuple match flags contained in the table.
|
* reset the inner-tuple match flags contained in the table.
|
||||||
*/
|
*/
|
||||||
if (HJ_FILL_INNER(node))
|
if (HJ_FILL_INNER(node))
|
||||||
ExecHashTableResetMatchFlags(node->hj_HashTable);
|
ExecHashTableResetMatchFlags(node->hj_HashTable);
|
||||||
|
@ -805,6 +805,14 @@ ExecMergeJoin(PlanState *pstate)
|
|||||||
break;
|
break;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
* In a right-antijoin, we never return a matched tuple.
|
||||||
|
* And we need to stay on the current outer tuple to
|
||||||
|
* continue scanning the inner side for matches.
|
||||||
|
*/
|
||||||
|
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||||
|
break;
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* If we only need to join to the first matching inner
|
* If we only need to join to the first matching inner
|
||||||
* tuple, then consider returning this one, but after that
|
* tuple, then consider returning this one, but after that
|
||||||
@ -1063,12 +1071,12 @@ ExecMergeJoin(PlanState *pstate)
|
|||||||
* them will match this new outer tuple and therefore
|
* them will match this new outer tuple and therefore
|
||||||
* won't be emitted as fill tuples. This works *only*
|
* won't be emitted as fill tuples. This works *only*
|
||||||
* because we require the extra joinquals to be constant
|
* because we require the extra joinquals to be constant
|
||||||
* when doing a right or full join --- otherwise some of
|
* when doing a right, right-anti or full join ---
|
||||||
* the rescanned tuples might fail the extra joinquals.
|
* otherwise some of the rescanned tuples might fail the
|
||||||
* This obviously won't happen for a constant-true extra
|
* extra joinquals. This obviously won't happen for a
|
||||||
* joinqual, while the constant-false case is handled by
|
* constant-true extra joinqual, while the constant-false
|
||||||
* forcing the merge clause to never match, so we never
|
* case is handled by forcing the merge clause to never
|
||||||
* get here.
|
* match, so we never get here.
|
||||||
*/
|
*/
|
||||||
if (!node->mj_SkipMarkRestore)
|
if (!node->mj_SkipMarkRestore)
|
||||||
{
|
{
|
||||||
@ -1332,8 +1340,8 @@ ExecMergeJoin(PlanState *pstate)
|
|||||||
|
|
||||||
/*
|
/*
|
||||||
* EXEC_MJ_ENDOUTER means we have run out of outer tuples, but
|
* EXEC_MJ_ENDOUTER means we have run out of outer tuples, but
|
||||||
* are doing a right/full join and therefore must null-fill
|
* are doing a right/right-anti/full join and therefore must
|
||||||
* any remaining unmatched inner tuples.
|
* null-fill any remaining unmatched inner tuples.
|
||||||
*/
|
*/
|
||||||
case EXEC_MJ_ENDOUTER:
|
case EXEC_MJ_ENDOUTER:
|
||||||
MJ_printf("ExecMergeJoin: EXEC_MJ_ENDOUTER\n");
|
MJ_printf("ExecMergeJoin: EXEC_MJ_ENDOUTER\n");
|
||||||
@ -1554,14 +1562,15 @@ ExecInitMergeJoin(MergeJoin *node, EState *estate, int eflags)
|
|||||||
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
||||||
break;
|
break;
|
||||||
case JOIN_RIGHT:
|
case JOIN_RIGHT:
|
||||||
|
case JOIN_RIGHT_ANTI:
|
||||||
mergestate->mj_FillOuter = false;
|
mergestate->mj_FillOuter = false;
|
||||||
mergestate->mj_FillInner = true;
|
mergestate->mj_FillInner = true;
|
||||||
mergestate->mj_NullOuterTupleSlot =
|
mergestate->mj_NullOuterTupleSlot =
|
||||||
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
|
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Can't handle right or full join with non-constant extra
|
* Can't handle right, right-anti or full join with non-constant
|
||||||
* joinclauses. This should have been caught by planner.
|
* extra joinclauses. This should have been caught by planner.
|
||||||
*/
|
*/
|
||||||
if (!check_constant_qual(node->join.joinqual,
|
if (!check_constant_qual(node->join.joinqual,
|
||||||
&mergestate->mj_ConstFalseJoin))
|
&mergestate->mj_ConstFalseJoin))
|
||||||
@ -1578,8 +1587,8 @@ ExecInitMergeJoin(MergeJoin *node, EState *estate, int eflags)
|
|||||||
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Can't handle right or full join with non-constant extra
|
* Can't handle right, right-anti or full join with non-constant
|
||||||
* joinclauses. This should have been caught by planner.
|
* extra joinclauses. This should have been caught by planner.
|
||||||
*/
|
*/
|
||||||
if (!check_constant_qual(node->join.joinqual,
|
if (!check_constant_qual(node->join.joinqual,
|
||||||
&mergestate->mj_ConstFalseJoin))
|
&mergestate->mj_ConstFalseJoin))
|
||||||
|
@ -3330,7 +3330,8 @@ initial_cost_mergejoin(PlannerInfo *root, JoinCostWorkspace *workspace,
|
|||||||
outerstartsel = 0.0;
|
outerstartsel = 0.0;
|
||||||
outerendsel = 1.0;
|
outerendsel = 1.0;
|
||||||
}
|
}
|
||||||
else if (jointype == JOIN_RIGHT)
|
else if (jointype == JOIN_RIGHT ||
|
||||||
|
jointype == JOIN_RIGHT_ANTI)
|
||||||
{
|
{
|
||||||
innerstartsel = 0.0;
|
innerstartsel = 0.0;
|
||||||
innerendsel = 1.0;
|
innerendsel = 1.0;
|
||||||
|
@ -286,8 +286,9 @@ add_paths_to_joinrel(PlannerInfo *root,
|
|||||||
* 2. Consider paths where the outer relation need not be explicitly
|
* 2. Consider paths where the outer relation need not be explicitly
|
||||||
* sorted. This includes both nestloops and mergejoins where the outer
|
* sorted. This includes both nestloops and mergejoins where the outer
|
||||||
* path is already ordered. Again, skip this if we can't mergejoin.
|
* path is already ordered. Again, skip this if we can't mergejoin.
|
||||||
* (That's okay because we know that nestloop can't handle right/full
|
* (That's okay because we know that nestloop can't handle
|
||||||
* joins at all, so it wouldn't work in the prohibited cases either.)
|
* right/right-anti/full joins at all, so it wouldn't work in the
|
||||||
|
* prohibited cases either.)
|
||||||
*/
|
*/
|
||||||
if (mergejoin_allowed)
|
if (mergejoin_allowed)
|
||||||
match_unsorted_outer(root, joinrel, outerrel, innerrel,
|
match_unsorted_outer(root, joinrel, outerrel, innerrel,
|
||||||
@ -1261,14 +1262,15 @@ sort_inner_and_outer(PlannerInfo *root,
|
|||||||
* If the joinrel is parallel-safe, we may be able to consider a partial
|
* If the joinrel is parallel-safe, we may be able to consider a partial
|
||||||
* merge join. However, we can't handle JOIN_UNIQUE_OUTER, because the
|
* merge join. However, we can't handle JOIN_UNIQUE_OUTER, because the
|
||||||
* outer path will be partial, and therefore we won't be able to properly
|
* outer path will be partial, and therefore we won't be able to properly
|
||||||
* guarantee uniqueness. Similarly, we can't handle JOIN_FULL and
|
* guarantee uniqueness. Similarly, we can't handle JOIN_FULL, JOIN_RIGHT
|
||||||
* JOIN_RIGHT, because they can produce false null extended rows. Also,
|
* and JOIN_RIGHT_ANTI, because they can produce false null extended rows.
|
||||||
* the resulting path must not be parameterized.
|
* Also, the resulting path must not be parameterized.
|
||||||
*/
|
*/
|
||||||
if (joinrel->consider_parallel &&
|
if (joinrel->consider_parallel &&
|
||||||
save_jointype != JOIN_UNIQUE_OUTER &&
|
save_jointype != JOIN_UNIQUE_OUTER &&
|
||||||
save_jointype != JOIN_FULL &&
|
save_jointype != JOIN_FULL &&
|
||||||
save_jointype != JOIN_RIGHT &&
|
save_jointype != JOIN_RIGHT &&
|
||||||
|
save_jointype != JOIN_RIGHT_ANTI &&
|
||||||
outerrel->partial_pathlist != NIL &&
|
outerrel->partial_pathlist != NIL &&
|
||||||
bms_is_empty(joinrel->lateral_relids))
|
bms_is_empty(joinrel->lateral_relids))
|
||||||
{
|
{
|
||||||
@ -1663,10 +1665,10 @@ match_unsorted_outer(PlannerInfo *root,
|
|||||||
|
|
||||||
/*
|
/*
|
||||||
* Nestloop only supports inner, left, semi, and anti joins. Also, if we
|
* Nestloop only supports inner, left, semi, and anti joins. Also, if we
|
||||||
* are doing a right or full mergejoin, we must use *all* the mergeclauses
|
* are doing a right, right-anti or full mergejoin, we must use *all* the
|
||||||
* as join clauses, else we will not have a valid plan. (Although these
|
* mergeclauses as join clauses, else we will not have a valid plan.
|
||||||
* two flags are currently inverses, keep them separate for clarity and
|
* (Although these two flags are currently inverses, keep them separate
|
||||||
* possible future changes.)
|
* for clarity and possible future changes.)
|
||||||
*/
|
*/
|
||||||
switch (jointype)
|
switch (jointype)
|
||||||
{
|
{
|
||||||
@ -1678,6 +1680,7 @@ match_unsorted_outer(PlannerInfo *root,
|
|||||||
useallclauses = false;
|
useallclauses = false;
|
||||||
break;
|
break;
|
||||||
case JOIN_RIGHT:
|
case JOIN_RIGHT:
|
||||||
|
case JOIN_RIGHT_ANTI:
|
||||||
case JOIN_FULL:
|
case JOIN_FULL:
|
||||||
nestjoinOK = false;
|
nestjoinOK = false;
|
||||||
useallclauses = true;
|
useallclauses = true;
|
||||||
@ -1849,13 +1852,14 @@ match_unsorted_outer(PlannerInfo *root,
|
|||||||
* handle JOIN_UNIQUE_OUTER, because the outer path will be partial, and
|
* handle JOIN_UNIQUE_OUTER, because the outer path will be partial, and
|
||||||
* therefore we won't be able to properly guarantee uniqueness. Nor can
|
* therefore we won't be able to properly guarantee uniqueness. Nor can
|
||||||
* we handle joins needing lateral rels, since partial paths must not be
|
* we handle joins needing lateral rels, since partial paths must not be
|
||||||
* parameterized. Similarly, we can't handle JOIN_FULL and JOIN_RIGHT,
|
* parameterized. Similarly, we can't handle JOIN_FULL, JOIN_RIGHT and
|
||||||
* because they can produce false null extended rows.
|
* JOIN_RIGHT_ANTI, because they can produce false null extended rows.
|
||||||
*/
|
*/
|
||||||
if (joinrel->consider_parallel &&
|
if (joinrel->consider_parallel &&
|
||||||
save_jointype != JOIN_UNIQUE_OUTER &&
|
save_jointype != JOIN_UNIQUE_OUTER &&
|
||||||
save_jointype != JOIN_FULL &&
|
save_jointype != JOIN_FULL &&
|
||||||
save_jointype != JOIN_RIGHT &&
|
save_jointype != JOIN_RIGHT &&
|
||||||
|
save_jointype != JOIN_RIGHT_ANTI &&
|
||||||
outerrel->partial_pathlist != NIL &&
|
outerrel->partial_pathlist != NIL &&
|
||||||
bms_is_empty(joinrel->lateral_relids))
|
bms_is_empty(joinrel->lateral_relids))
|
||||||
{
|
{
|
||||||
@ -2228,11 +2232,13 @@ hash_inner_and_outer(PlannerInfo *root,
|
|||||||
* total inner path will also be parallel-safe, but if not, we'll
|
* total inner path will also be parallel-safe, but if not, we'll
|
||||||
* have to search for the cheapest safe, unparameterized inner
|
* have to search for the cheapest safe, unparameterized inner
|
||||||
* path. If doing JOIN_UNIQUE_INNER, we can't use any alternative
|
* path. If doing JOIN_UNIQUE_INNER, we can't use any alternative
|
||||||
* inner path. If full or right join, we can't use parallelism
|
* inner path. If full, right, or right-anti join, we can't use
|
||||||
* (building the hash table in each backend) because no one
|
* parallelism (building the hash table in each backend) because
|
||||||
* process has all the match bits.
|
* no one process has all the match bits.
|
||||||
*/
|
*/
|
||||||
if (save_jointype == JOIN_FULL || save_jointype == JOIN_RIGHT)
|
if (save_jointype == JOIN_FULL ||
|
||||||
|
save_jointype == JOIN_RIGHT ||
|
||||||
|
save_jointype == JOIN_RIGHT_ANTI)
|
||||||
cheapest_safe_inner = NULL;
|
cheapest_safe_inner = NULL;
|
||||||
else if (cheapest_total_inner->parallel_safe)
|
else if (cheapest_total_inner->parallel_safe)
|
||||||
cheapest_safe_inner = cheapest_total_inner;
|
cheapest_safe_inner = cheapest_total_inner;
|
||||||
@ -2256,10 +2262,10 @@ hash_inner_and_outer(PlannerInfo *root,
|
|||||||
* Returns a list of RestrictInfo nodes for those clauses.
|
* Returns a list of RestrictInfo nodes for those clauses.
|
||||||
*
|
*
|
||||||
* *mergejoin_allowed is normally set to true, but it is set to false if
|
* *mergejoin_allowed is normally set to true, but it is set to false if
|
||||||
* this is a right/full join and there are nonmergejoinable join clauses.
|
* this is a right/right-anti/full join and there are nonmergejoinable join
|
||||||
* The executor's mergejoin machinery cannot handle such cases, so we have
|
* clauses. The executor's mergejoin machinery cannot handle such cases, so
|
||||||
* to avoid generating a mergejoin plan. (Note that this flag does NOT
|
* we have to avoid generating a mergejoin plan. (Note that this flag does
|
||||||
* consider whether there are actually any mergejoinable clauses. This is
|
* NOT consider whether there are actually any mergejoinable clauses. This is
|
||||||
* correct because in some cases we need to build a clauseless mergejoin.
|
* correct because in some cases we need to build a clauseless mergejoin.
|
||||||
* Simply returning NIL is therefore not enough to distinguish safe from
|
* Simply returning NIL is therefore not enough to distinguish safe from
|
||||||
* unsafe cases.)
|
* unsafe cases.)
|
||||||
@ -2305,8 +2311,8 @@ select_mergejoin_clauses(PlannerInfo *root,
|
|||||||
{
|
{
|
||||||
/*
|
/*
|
||||||
* The executor can handle extra joinquals that are constants, but
|
* The executor can handle extra joinquals that are constants, but
|
||||||
* not anything else, when doing right/full merge join. (The
|
* not anything else, when doing right/right-anti/full merge join.
|
||||||
* reason to support constants is so we can do FULL JOIN ON
|
* (The reason to support constants is so we can do FULL JOIN ON
|
||||||
* FALSE.)
|
* FALSE.)
|
||||||
*/
|
*/
|
||||||
if (!restrictinfo->clause || !IsA(restrictinfo->clause, Const))
|
if (!restrictinfo->clause || !IsA(restrictinfo->clause, Const))
|
||||||
@ -2349,6 +2355,7 @@ select_mergejoin_clauses(PlannerInfo *root,
|
|||||||
switch (jointype)
|
switch (jointype)
|
||||||
{
|
{
|
||||||
case JOIN_RIGHT:
|
case JOIN_RIGHT:
|
||||||
|
case JOIN_RIGHT_ANTI:
|
||||||
case JOIN_FULL:
|
case JOIN_FULL:
|
||||||
*mergejoin_allowed = !have_nonmergeable_joinclause;
|
*mergejoin_allowed = !have_nonmergeable_joinclause;
|
||||||
break;
|
break;
|
||||||
|
@ -925,6 +925,9 @@ populate_joinrel_with_paths(PlannerInfo *root, RelOptInfo *rel1,
|
|||||||
add_paths_to_joinrel(root, joinrel, rel1, rel2,
|
add_paths_to_joinrel(root, joinrel, rel1, rel2,
|
||||||
JOIN_ANTI, sjinfo,
|
JOIN_ANTI, sjinfo,
|
||||||
restrictlist);
|
restrictlist);
|
||||||
|
add_paths_to_joinrel(root, joinrel, rel2, rel1,
|
||||||
|
JOIN_RIGHT_ANTI, sjinfo,
|
||||||
|
restrictlist);
|
||||||
break;
|
break;
|
||||||
default:
|
default:
|
||||||
/* other values not expected here */
|
/* other values not expected here */
|
||||||
|
@ -1077,9 +1077,9 @@ find_var_for_subquery_tle(RelOptInfo *rel, TargetEntry *tle)
|
|||||||
* Build the path keys for a join relation constructed by mergejoin or
|
* Build the path keys for a join relation constructed by mergejoin or
|
||||||
* nestloop join. This is normally the same as the outer path's keys.
|
* nestloop join. This is normally the same as the outer path's keys.
|
||||||
*
|
*
|
||||||
* EXCEPTION: in a FULL or RIGHT join, we cannot treat the result as
|
* EXCEPTION: in a FULL, RIGHT or RIGHT_ANTI join, we cannot treat the
|
||||||
* having the outer path's path keys, because null lefthand rows may be
|
* result as having the outer path's path keys, because null lefthand rows
|
||||||
* inserted at random points. It must be treated as unsorted.
|
* may be inserted at random points. It must be treated as unsorted.
|
||||||
*
|
*
|
||||||
* We truncate away any pathkeys that are uninteresting for higher joins.
|
* We truncate away any pathkeys that are uninteresting for higher joins.
|
||||||
*
|
*
|
||||||
@ -1095,7 +1095,9 @@ build_join_pathkeys(PlannerInfo *root,
|
|||||||
JoinType jointype,
|
JoinType jointype,
|
||||||
List *outer_pathkeys)
|
List *outer_pathkeys)
|
||||||
{
|
{
|
||||||
if (jointype == JOIN_FULL || jointype == JOIN_RIGHT)
|
if (jointype == JOIN_FULL ||
|
||||||
|
jointype == JOIN_RIGHT ||
|
||||||
|
jointype == JOIN_RIGHT_ANTI)
|
||||||
return NIL;
|
return NIL;
|
||||||
|
|
||||||
/*
|
/*
|
||||||
|
@ -406,8 +406,8 @@ pull_up_sublinks_jointree_recurse(PlannerInfo *root, Node *jtnode,
|
|||||||
* point of the available_rels machinations is to ensure that we only
|
* point of the available_rels machinations is to ensure that we only
|
||||||
* pull up quals for which that's okay.
|
* pull up quals for which that's okay.
|
||||||
*
|
*
|
||||||
* We don't expect to see any pre-existing JOIN_SEMI or JOIN_ANTI
|
* We don't expect to see any pre-existing JOIN_SEMI, JOIN_ANTI, or
|
||||||
* nodes here.
|
* JOIN_RIGHT_ANTI jointypes here.
|
||||||
*/
|
*/
|
||||||
switch (j->jointype)
|
switch (j->jointype)
|
||||||
{
|
{
|
||||||
@ -2640,9 +2640,10 @@ flatten_simple_union_all(PlannerInfo *root)
|
|||||||
* distribute_qual_to_rels to get rid of such clauses.
|
* distribute_qual_to_rels to get rid of such clauses.
|
||||||
*
|
*
|
||||||
* Also, we get rid of JOIN_RIGHT cases by flipping them around to become
|
* Also, we get rid of JOIN_RIGHT cases by flipping them around to become
|
||||||
* JOIN_LEFT. This saves some code here and in some later planner routines,
|
* JOIN_LEFT. This saves some code here and in some later planner routines;
|
||||||
* but the main reason to do it is to not need to invent a JOIN_REVERSE_ANTI
|
* the main benefit is to reduce the number of jointypes that can appear in
|
||||||
* join type.
|
* SpecialJoinInfo nodes. Note that we can still generate Paths and Plans
|
||||||
|
* that use JOIN_RIGHT (or JOIN_RIGHT_ANTI) by switching the inputs again.
|
||||||
*
|
*
|
||||||
* To ease recognition of strict qual clauses, we require this routine to be
|
* To ease recognition of strict qual clauses, we require this routine to be
|
||||||
* run after expression preprocessing (i.e., qual canonicalization and JOIN
|
* run after expression preprocessing (i.e., qual canonicalization and JOIN
|
||||||
@ -2896,7 +2897,8 @@ reduce_outer_joins_pass2(Node *jtnode,
|
|||||||
/*
|
/*
|
||||||
* These could only have been introduced by pull_up_sublinks,
|
* These could only have been introduced by pull_up_sublinks,
|
||||||
* so there's no way that upper quals could refer to their
|
* so there's no way that upper quals could refer to their
|
||||||
* righthand sides, and no point in checking.
|
* righthand sides, and no point in checking. We don't expect
|
||||||
|
* to see JOIN_RIGHT_ANTI yet.
|
||||||
*/
|
*/
|
||||||
break;
|
break;
|
||||||
default:
|
default:
|
||||||
|
@ -2073,7 +2073,8 @@ typedef struct MergeJoinState
|
|||||||
* OuterTupleSlot is empty!)
|
* OuterTupleSlot is empty!)
|
||||||
* hj_OuterTupleSlot tuple slot for outer tuples
|
* hj_OuterTupleSlot tuple slot for outer tuples
|
||||||
* hj_HashTupleSlot tuple slot for inner (hashed) tuples
|
* hj_HashTupleSlot tuple slot for inner (hashed) tuples
|
||||||
* hj_NullOuterTupleSlot prepared null tuple for right/full outer joins
|
* hj_NullOuterTupleSlot prepared null tuple for right/right-anti/full
|
||||||
|
* outer joins
|
||||||
* hj_NullInnerTupleSlot prepared null tuple for left/full outer joins
|
* hj_NullInnerTupleSlot prepared null tuple for left/full outer joins
|
||||||
* hj_FirstOuterTupleSlot first tuple retrieved from outer plan
|
* hj_FirstOuterTupleSlot first tuple retrieved from outer plan
|
||||||
* hj_JoinState current state of ExecHashJoin state machine
|
* hj_JoinState current state of ExecHashJoin state machine
|
||||||
|
@ -317,6 +317,7 @@ typedef enum JoinType
|
|||||||
*/
|
*/
|
||||||
JOIN_SEMI, /* 1 copy of each LHS row that has match(es) */
|
JOIN_SEMI, /* 1 copy of each LHS row that has match(es) */
|
||||||
JOIN_ANTI, /* 1 copy of each LHS row that has no match */
|
JOIN_ANTI, /* 1 copy of each LHS row that has no match */
|
||||||
|
JOIN_RIGHT_ANTI, /* 1 copy of each RHS row that has no match */
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* These codes are used internally in the planner, but are not supported
|
* These codes are used internally in the planner, but are not supported
|
||||||
@ -349,7 +350,8 @@ typedef enum JoinType
|
|||||||
((1 << JOIN_LEFT) | \
|
((1 << JOIN_LEFT) | \
|
||||||
(1 << JOIN_FULL) | \
|
(1 << JOIN_FULL) | \
|
||||||
(1 << JOIN_RIGHT) | \
|
(1 << JOIN_RIGHT) | \
|
||||||
(1 << JOIN_ANTI))) != 0)
|
(1 << JOIN_ANTI) | \
|
||||||
|
(1 << JOIN_RIGHT_ANTI))) != 0)
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* AggStrategy -
|
* AggStrategy -
|
||||||
|
@ -2766,8 +2766,9 @@ typedef struct PlaceHolderVar
|
|||||||
* min_lefthand and min_righthand for higher joins.)
|
* min_lefthand and min_righthand for higher joins.)
|
||||||
*
|
*
|
||||||
* jointype is never JOIN_RIGHT; a RIGHT JOIN is handled by switching
|
* jointype is never JOIN_RIGHT; a RIGHT JOIN is handled by switching
|
||||||
* the inputs to make it a LEFT JOIN. So the allowed values of jointype
|
* the inputs to make it a LEFT JOIN. It's never JOIN_RIGHT_ANTI either.
|
||||||
* in a join_info_list member are only LEFT, FULL, SEMI, or ANTI.
|
* So the allowed values of jointype in a join_info_list member are only
|
||||||
|
* LEFT, FULL, SEMI, or ANTI.
|
||||||
*
|
*
|
||||||
* ojrelid is the RT index of the join RTE representing this outer join,
|
* ojrelid is the RT index of the join RTE representing this outer join,
|
||||||
* if there is one. It is zero when jointype is INNER or SEMI, and can be
|
* if there is one. It is zero when jointype is INNER or SEMI, and can be
|
||||||
|
@ -2415,24 +2415,24 @@ SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t
|
|||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Append
|
-> Append
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: (t1_1.a = t2_1.b)
|
Hash Cond: (t2_1.b = t1_1.a)
|
||||||
|
-> Seq Scan on prt2_adv_p1 t2_1
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on prt1_adv_p1 t1_1
|
-> Seq Scan on prt1_adv_p1 t1_1
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
|
-> Hash Right Anti Join
|
||||||
|
Hash Cond: (t2_2.b = t1_2.a)
|
||||||
|
-> Seq Scan on prt2_adv_p2 t2_2
|
||||||
-> Hash
|
-> Hash
|
||||||
-> Seq Scan on prt2_adv_p1 t2_1
|
|
||||||
-> Hash Anti Join
|
|
||||||
Hash Cond: (t1_2.a = t2_2.b)
|
|
||||||
-> Seq Scan on prt1_adv_p2 t1_2
|
-> Seq Scan on prt1_adv_p2 t1_2
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
|
-> Hash Right Anti Join
|
||||||
|
Hash Cond: (t2_3.b = t1_3.a)
|
||||||
|
-> Seq Scan on prt2_adv_p3 t2_3
|
||||||
-> Hash
|
-> Hash
|
||||||
-> Seq Scan on prt2_adv_p2 t2_2
|
|
||||||
-> Hash Anti Join
|
|
||||||
Hash Cond: (t1_3.a = t2_3.b)
|
|
||||||
-> Seq Scan on prt1_adv_p3 t1_3
|
-> Seq Scan on prt1_adv_p3 t1_3
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
-> Hash
|
|
||||||
-> Seq Scan on prt2_adv_p3 t2_3
|
|
||||||
(21 rows)
|
(21 rows)
|
||||||
|
|
||||||
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
||||||
@ -2650,24 +2650,24 @@ SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t
|
|||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Append
|
-> Append
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: (t1_1.a = t2_1.b)
|
Hash Cond: (t2_1.b = t1_1.a)
|
||||||
|
-> Seq Scan on prt2_adv_p1 t2_1
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on prt1_adv_p1 t1_1
|
-> Seq Scan on prt1_adv_p1 t1_1
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
|
-> Hash Right Anti Join
|
||||||
|
Hash Cond: (t2_2.b = t1_2.a)
|
||||||
|
-> Seq Scan on prt2_adv_p2 t2_2
|
||||||
-> Hash
|
-> Hash
|
||||||
-> Seq Scan on prt2_adv_p1 t2_1
|
|
||||||
-> Hash Anti Join
|
|
||||||
Hash Cond: (t1_2.a = t2_2.b)
|
|
||||||
-> Seq Scan on prt1_adv_p2 t1_2
|
-> Seq Scan on prt1_adv_p2 t1_2
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
|
-> Hash Right Anti Join
|
||||||
|
Hash Cond: (t2_3.b = t1_3.a)
|
||||||
|
-> Seq Scan on prt2_adv_p3 t2_3
|
||||||
-> Hash
|
-> Hash
|
||||||
-> Seq Scan on prt2_adv_p2 t2_2
|
|
||||||
-> Hash Anti Join
|
|
||||||
Hash Cond: (t1_3.a = t2_3.b)
|
|
||||||
-> Seq Scan on prt1_adv_p3 t1_3
|
-> Seq Scan on prt1_adv_p3 t1_3
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
-> Hash
|
|
||||||
-> Seq Scan on prt2_adv_p3 t2_3
|
|
||||||
(21 rows)
|
(21 rows)
|
||||||
|
|
||||||
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
||||||
@ -2684,11 +2684,16 @@ SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM prt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt1_adv t2 WHERE t1.b = t2.a) AND t1.a = 0 ORDER BY t1.b;
|
SELECT t1.* FROM prt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt1_adv t2 WHERE t1.b = t2.a) AND t1.a = 0 ORDER BY t1.b;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
------------------------------------------------------
|
---------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.b
|
Sort Key: t1.b
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: (t1.b = t2.a)
|
Hash Cond: (t2.a = t1.b)
|
||||||
|
-> Append
|
||||||
|
-> Seq Scan on prt1_adv_p1 t2_1
|
||||||
|
-> Seq Scan on prt1_adv_p2 t2_2
|
||||||
|
-> Seq Scan on prt1_adv_p3 t2_3
|
||||||
|
-> Hash
|
||||||
-> Append
|
-> Append
|
||||||
-> Seq Scan on prt2_adv_p1 t1_1
|
-> Seq Scan on prt2_adv_p1 t1_1
|
||||||
Filter: (a = 0)
|
Filter: (a = 0)
|
||||||
@ -2698,11 +2703,6 @@ SELECT t1.* FROM prt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt1_adv t2 WHERE t
|
|||||||
Filter: (a = 0)
|
Filter: (a = 0)
|
||||||
-> Seq Scan on prt2_adv_extra t1_4
|
-> Seq Scan on prt2_adv_extra t1_4
|
||||||
Filter: (a = 0)
|
Filter: (a = 0)
|
||||||
-> Hash
|
|
||||||
-> Append
|
|
||||||
-> Seq Scan on prt1_adv_p1 t2_1
|
|
||||||
-> Seq Scan on prt1_adv_p2 t2_2
|
|
||||||
-> Seq Scan on prt1_adv_p3 t2_3
|
|
||||||
(18 rows)
|
(18 rows)
|
||||||
|
|
||||||
-- full join; currently we can't do partitioned join if there are no matched
|
-- full join; currently we can't do partitioned join if there are no matched
|
||||||
@ -2871,11 +2871,17 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_adv t1 LEFT JOIN prt2_adv t2 ON (t1.a =
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t1.a = t2.b) AND t1.b = 0 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
--------------------------------------------------------
|
------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: (t1.a = t2.b)
|
Hash Cond: (t2.b = t1.a)
|
||||||
|
-> Append
|
||||||
|
-> Seq Scan on prt2_adv_p1 t2_1
|
||||||
|
-> Seq Scan on prt2_adv_p2 t2_2
|
||||||
|
-> Seq Scan on prt2_adv_p3_1 t2_3
|
||||||
|
-> Seq Scan on prt2_adv_p3_2 t2_4
|
||||||
|
-> Hash
|
||||||
-> Append
|
-> Append
|
||||||
-> Seq Scan on prt1_adv_p1 t1_1
|
-> Seq Scan on prt1_adv_p1 t1_1
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
@ -2883,12 +2889,6 @@ SELECT t1.* FROM prt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM prt2_adv t2 WHERE t
|
|||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
-> Seq Scan on prt1_adv_p3 t1_3
|
-> Seq Scan on prt1_adv_p3 t1_3
|
||||||
Filter: (b = 0)
|
Filter: (b = 0)
|
||||||
-> Hash
|
|
||||||
-> Append
|
|
||||||
-> Seq Scan on prt2_adv_p1 t2_1
|
|
||||||
-> Seq Scan on prt2_adv_p2 t2_2
|
|
||||||
-> Seq Scan on prt2_adv_p3_1 t2_3
|
|
||||||
-> Seq Scan on prt2_adv_p3_2 t2_4
|
|
||||||
(17 rows)
|
(17 rows)
|
||||||
|
|
||||||
-- full join
|
-- full join
|
||||||
@ -3293,26 +3293,29 @@ SELECT t1.a, t1.c, t2.a, t2.c FROM plt1_adv t1 LEFT JOIN plt2_adv t2 ON (t1.a =
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
----------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Append
|
-> Append
|
||||||
-> Nested Loop Anti Join
|
-> Hash Right Anti Join
|
||||||
Join Filter: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
|
Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
|
||||||
|
-> Seq Scan on plt2_adv_p1 t2_1
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p1 t1_1
|
-> Seq Scan on plt1_adv_p1 t1_1
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p1 t2_1
|
-> Hash Right Anti Join
|
||||||
-> Nested Loop Anti Join
|
Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
|
||||||
Join Filter: ((t1_2.a = t2_2.a) AND (t1_2.c = t2_2.c))
|
-> Seq Scan on plt2_adv_p2 t2_2
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p2 t1_2
|
-> Seq Scan on plt1_adv_p2 t1_2
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p2 t2_2
|
-> Hash Right Anti Join
|
||||||
-> Nested Loop Anti Join
|
Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
|
||||||
Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
|
-> Seq Scan on plt2_adv_p3 t2_3
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p3 t1_3
|
-> Seq Scan on plt1_adv_p3 t1_3
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p3 t2_3
|
(21 rows)
|
||||||
(18 rows)
|
|
||||||
|
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
a | b | c
|
a | b | c
|
||||||
@ -3506,26 +3509,29 @@ SELECT t1.a, t1.c, t2.a, t2.c FROM plt2_adv t1 LEFT JOIN plt1_adv t2 ON (t1.a =
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
----------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Append
|
-> Append
|
||||||
-> Nested Loop Anti Join
|
-> Hash Right Anti Join
|
||||||
Join Filter: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
|
Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
|
||||||
|
-> Seq Scan on plt2_adv_p1 t2_1
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p1 t1_1
|
-> Seq Scan on plt1_adv_p1 t1_1
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p1 t2_1
|
-> Hash Right Anti Join
|
||||||
-> Nested Loop Anti Join
|
Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
|
||||||
Join Filter: ((t1_2.a = t2_2.a) AND (t1_2.c = t2_2.c))
|
-> Seq Scan on plt2_adv_p2 t2_2
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p2 t1_2
|
-> Seq Scan on plt1_adv_p2 t1_2
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p2 t2_2
|
-> Hash Right Anti Join
|
||||||
-> Nested Loop Anti Join
|
Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
|
||||||
Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
|
-> Seq Scan on plt2_adv_p3 t2_3
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p3 t1_3
|
-> Seq Scan on plt1_adv_p3 t1_3
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p3 t2_3
|
(21 rows)
|
||||||
(18 rows)
|
|
||||||
|
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
a | b | c
|
a | b | c
|
||||||
@ -3539,11 +3545,16 @@ SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM plt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt1_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt1_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
------------------------------------------------------
|
---------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: ((t1.a = t2.a) AND (t1.c = t2.c))
|
Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
|
||||||
|
-> Append
|
||||||
|
-> Seq Scan on plt1_adv_p1 t2_1
|
||||||
|
-> Seq Scan on plt1_adv_p2 t2_2
|
||||||
|
-> Seq Scan on plt1_adv_p3 t2_3
|
||||||
|
-> Hash
|
||||||
-> Append
|
-> Append
|
||||||
-> Seq Scan on plt2_adv_extra t1_1
|
-> Seq Scan on plt2_adv_extra t1_1
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
@ -3553,11 +3564,6 @@ SELECT t1.* FROM plt2_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt1_adv t2 WHERE t
|
|||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p3 t1_4
|
-> Seq Scan on plt2_adv_p3 t1_4
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Hash
|
|
||||||
-> Append
|
|
||||||
-> Seq Scan on plt1_adv_p1 t2_1
|
|
||||||
-> Seq Scan on plt1_adv_p2 t2_2
|
|
||||||
-> Seq Scan on plt1_adv_p3 t2_3
|
|
||||||
(18 rows)
|
(18 rows)
|
||||||
|
|
||||||
-- full join; currently we can't do partitioned join if there are no matched
|
-- full join; currently we can't do partitioned join if there are no matched
|
||||||
@ -3668,11 +3674,17 @@ SELECT t1.a, t1.c, t2.a, t2.c FROM plt1_adv t1 LEFT JOIN plt2_adv t2 ON (t1.a =
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
--------------------------------------------------------
|
------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: ((t1.a = t2.a) AND (t1.c = t2.c))
|
Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
|
||||||
|
-> Append
|
||||||
|
-> Seq Scan on plt2_adv_p1 t2_1
|
||||||
|
-> Seq Scan on plt2_adv_p2_1 t2_2
|
||||||
|
-> Seq Scan on plt2_adv_p2_2 t2_3
|
||||||
|
-> Seq Scan on plt2_adv_p3 t2_4
|
||||||
|
-> Hash
|
||||||
-> Append
|
-> Append
|
||||||
-> Seq Scan on plt1_adv_p1 t1_1
|
-> Seq Scan on plt1_adv_p1 t1_1
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
@ -3680,12 +3692,6 @@ SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t
|
|||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt1_adv_p3 t1_3
|
-> Seq Scan on plt1_adv_p3 t1_3
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Hash
|
|
||||||
-> Append
|
|
||||||
-> Seq Scan on plt2_adv_p1 t2_1
|
|
||||||
-> Seq Scan on plt2_adv_p2_1 t2_2
|
|
||||||
-> Seq Scan on plt2_adv_p2_2 t2_3
|
|
||||||
-> Seq Scan on plt2_adv_p3 t2_4
|
|
||||||
(17 rows)
|
(17 rows)
|
||||||
|
|
||||||
-- full join
|
-- full join
|
||||||
@ -3843,27 +3849,29 @@ SELECT t1.a, t1.c, t2.a, t2.c FROM plt1_adv t1 LEFT JOIN plt2_adv t2 ON (t1.a =
|
|||||||
EXPLAIN (COSTS OFF)
|
EXPLAIN (COSTS OFF)
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
QUERY PLAN
|
QUERY PLAN
|
||||||
----------------------------------------------------------------------
|
--------------------------------------------------------------------
|
||||||
Sort
|
Sort
|
||||||
Sort Key: t1.a
|
Sort Key: t1.a
|
||||||
-> Append
|
-> Append
|
||||||
-> Hash Anti Join
|
-> Hash Right Anti Join
|
||||||
Hash Cond: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
|
Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
|
||||||
|
-> Seq Scan on plt2_adv_p1 t2_1
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p1_null t1_1
|
-> Seq Scan on plt1_adv_p1_null t1_1
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
|
-> Hash Right Anti Join
|
||||||
|
Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.c = t1_2.c))
|
||||||
|
-> Seq Scan on plt2_adv_p2 t2_2
|
||||||
-> Hash
|
-> Hash
|
||||||
-> Seq Scan on plt2_adv_p1 t2_1
|
|
||||||
-> Nested Loop Anti Join
|
|
||||||
Join Filter: ((t1_2.a = t2_2.a) AND (t1_2.c = t2_2.c))
|
|
||||||
-> Seq Scan on plt1_adv_p2 t1_2
|
-> Seq Scan on plt1_adv_p2 t1_2
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p2 t2_2
|
-> Hash Right Anti Join
|
||||||
-> Nested Loop Anti Join
|
Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
|
||||||
Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
|
-> Seq Scan on plt2_adv_p3_null t2_3
|
||||||
|
-> Hash
|
||||||
-> Seq Scan on plt1_adv_p3 t1_3
|
-> Seq Scan on plt1_adv_p3 t1_3
|
||||||
Filter: (b < 10)
|
Filter: (b < 10)
|
||||||
-> Seq Scan on plt2_adv_p3_null t2_3
|
(21 rows)
|
||||||
(19 rows)
|
|
||||||
|
|
||||||
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
SELECT t1.* FROM plt1_adv t1 WHERE NOT EXISTS (SELECT 1 FROM plt2_adv t2 WHERE t1.a = t2.a AND t1.c = t2.c) AND t1.b < 10 ORDER BY t1.a;
|
||||||
a | b | c
|
a | b | c
|
||||||
|
Loading…
x
Reference in New Issue
Block a user