case JOIN_ANTI:
jointype = "Anti";
break;
+ case JOIN_RIGHT_ANTI:
+ jointype = "Right Anti";
+ break;
default:
jointype = "???";
break;
* PHJ_BATCH_ALLOCATE* -- one allocates buckets
* PHJ_BATCH_LOAD -- all load the hash table from disk
* 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
*
* Batch 0 is a special case, because it starts out in phase
/*
* If the outer relation is completely empty, and it's not
- * right/full join, we can quit without building the hash
- * table. However, for an inner join it is only a win to
- * check this when the outer relation's startup cost is less
- * than the projected cost of building the hash table.
+ * right/right-anti/full join, we can quit without building
+ * the hash table. However, for an inner join it is only a
+ * win to check this when the outer relation's startup cost is
+ * less than the projected cost of building the hash table.
* 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
* should always make this check, since we aren't going to be
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
* tuple, then consider returning this one, but after that
case HJ_FILL_INNER_TUPLES:
/*
- * We have finished a batch, but we are doing right/full join,
- * so any unmatched inner tuples in the hashtable have to be
- * emitted before we continue to the next batch.
+ * We have finished a batch, but we are doing
+ * right/right-anti/full join, so any unmatched inner tuples
+ * in the hashtable have to be emitted before we continue to
+ * the next batch.
*/
if (!(parallel ? ExecParallelScanHashTableForUnmatched(node, econtext)
: ExecScanHashTableForUnmatched(node, econtext)))
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
break;
case JOIN_RIGHT:
+ case JOIN_RIGHT_ANTI:
hjstate->hj_NullOuterTupleSlot =
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
break;
* side, but there are exceptions:
*
* 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
- * have to process inner batches even if the outer batch is empty.
+ * the inner batch is empty. Similarly, in a right/right-anti/full outer
+ * 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
* scan inner batches since they might contain tuples that need to be
/*
* Okay to reuse the hash table; needn't rescan inner, either.
*
- * However, if it's a right/full join, we'd better reset the
- * inner-tuple match flags contained in the table.
+ * However, if it's a right/right-anti/full join, we'd better
+ * reset the inner-tuple match flags contained in the table.
*/
if (HJ_FILL_INNER(node))
ExecHashTableResetMatchFlags(node->hj_HashTable);
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
* tuple, then consider returning this one, but after that
* them will match this new outer tuple and therefore
* won't be emitted as fill tuples. This works *only*
* because we require the extra joinquals to be constant
- * when doing a right or full join --- otherwise some of
- * the rescanned tuples might fail the extra joinquals.
- * This obviously won't happen for a constant-true extra
- * joinqual, while the constant-false case is handled by
- * forcing the merge clause to never match, so we never
- * get here.
+ * when doing a right, right-anti or full join ---
+ * otherwise some of the rescanned tuples might fail the
+ * extra joinquals. This obviously won't happen for a
+ * constant-true extra joinqual, while the constant-false
+ * case is handled by forcing the merge clause to never
+ * match, so we never get here.
*/
if (!node->mj_SkipMarkRestore)
{
/*
* EXEC_MJ_ENDOUTER means we have run out of outer tuples, but
- * are doing a right/full join and therefore must null-fill
- * any remaining unmatched inner tuples.
+ * are doing a right/right-anti/full join and therefore must
+ * null-fill any remaining unmatched inner tuples.
*/
case EXEC_MJ_ENDOUTER:
MJ_printf("ExecMergeJoin: EXEC_MJ_ENDOUTER\n");
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
break;
case JOIN_RIGHT:
+ case JOIN_RIGHT_ANTI:
mergestate->mj_FillOuter = false;
mergestate->mj_FillInner = true;
mergestate->mj_NullOuterTupleSlot =
ExecInitNullTupleSlot(estate, outerDesc, &TTSOpsVirtual);
/*
- * Can't handle right or full join with non-constant extra
- * joinclauses. This should have been caught by planner.
+ * Can't handle right, right-anti or full join with non-constant
+ * extra joinclauses. This should have been caught by planner.
*/
if (!check_constant_qual(node->join.joinqual,
&mergestate->mj_ConstFalseJoin))
ExecInitNullTupleSlot(estate, innerDesc, &TTSOpsVirtual);
/*
- * Can't handle right or full join with non-constant extra
- * joinclauses. This should have been caught by planner.
+ * Can't handle right, right-anti or full join with non-constant
+ * extra joinclauses. This should have been caught by planner.
*/
if (!check_constant_qual(node->join.joinqual,
&mergestate->mj_ConstFalseJoin))
outerstartsel = 0.0;
outerendsel = 1.0;
}
- else if (jointype == JOIN_RIGHT)
+ else if (jointype == JOIN_RIGHT ||
+ jointype == JOIN_RIGHT_ANTI)
{
innerstartsel = 0.0;
innerendsel = 1.0;
* 2. Consider paths where the outer relation need not be explicitly
* sorted. This includes both nestloops and mergejoins where the outer
* 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
- * joins at all, so it wouldn't work in the prohibited cases either.)
+ * (That's okay because we know that nestloop can't handle
+ * right/right-anti/full joins at all, so it wouldn't work in the
+ * prohibited cases either.)
*/
if (mergejoin_allowed)
match_unsorted_outer(root, joinrel, outerrel, innerrel,
* 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
* outer path will be partial, and therefore we won't be able to properly
- * guarantee uniqueness. Similarly, we can't handle JOIN_FULL and
- * JOIN_RIGHT, because they can produce false null extended rows. Also,
- * the resulting path must not be parameterized.
+ * guarantee uniqueness. Similarly, we can't handle JOIN_FULL, JOIN_RIGHT
+ * and JOIN_RIGHT_ANTI, because they can produce false null extended rows.
+ * Also, the resulting path must not be parameterized.
*/
if (joinrel->consider_parallel &&
save_jointype != JOIN_UNIQUE_OUTER &&
save_jointype != JOIN_FULL &&
save_jointype != JOIN_RIGHT &&
+ save_jointype != JOIN_RIGHT_ANTI &&
outerrel->partial_pathlist != NIL &&
bms_is_empty(joinrel->lateral_relids))
{
/*
* 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
- * as join clauses, else we will not have a valid plan. (Although these
- * two flags are currently inverses, keep them separate for clarity and
- * possible future changes.)
+ * are doing a right, right-anti or full mergejoin, we must use *all* the
+ * mergeclauses as join clauses, else we will not have a valid plan.
+ * (Although these two flags are currently inverses, keep them separate
+ * for clarity and possible future changes.)
*/
switch (jointype)
{
useallclauses = false;
break;
case JOIN_RIGHT:
+ case JOIN_RIGHT_ANTI:
case JOIN_FULL:
nestjoinOK = false;
useallclauses = true;
* handle JOIN_UNIQUE_OUTER, because the outer path will be partial, and
* therefore we won't be able to properly guarantee uniqueness. Nor can
* we handle joins needing lateral rels, since partial paths must not be
- * parameterized. Similarly, we can't handle JOIN_FULL and JOIN_RIGHT,
- * because they can produce false null extended rows.
+ * parameterized. Similarly, we can't handle JOIN_FULL, JOIN_RIGHT and
+ * JOIN_RIGHT_ANTI, because they can produce false null extended rows.
*/
if (joinrel->consider_parallel &&
save_jointype != JOIN_UNIQUE_OUTER &&
save_jointype != JOIN_FULL &&
save_jointype != JOIN_RIGHT &&
+ save_jointype != JOIN_RIGHT_ANTI &&
outerrel->partial_pathlist != NIL &&
bms_is_empty(joinrel->lateral_relids))
{
* total inner path will also be parallel-safe, but if not, we'll
* have to search for the cheapest safe, unparameterized inner
* path. If doing JOIN_UNIQUE_INNER, we can't use any alternative
- * inner path. If full or right join, we can't use parallelism
- * (building the hash table in each backend) because no one
- * process has all the match bits.
+ * inner path. If full, right, or right-anti join, we can't use
+ * parallelism (building the hash table in each backend) because
+ * 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;
else if (cheapest_total_inner->parallel_safe)
cheapest_safe_inner = cheapest_total_inner;
* Returns a list of RestrictInfo nodes for those clauses.
*
* *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.
- * The executor's mergejoin machinery cannot handle such cases, so we have
- * to avoid generating a mergejoin plan. (Note that this flag does NOT
- * consider whether there are actually any mergejoinable clauses. This is
+ * this is a right/right-anti/full join and there are nonmergejoinable join
+ * clauses. The executor's mergejoin machinery cannot handle such cases, so
+ * we have to avoid generating a mergejoin plan. (Note that this flag does
+ * NOT consider whether there are actually any mergejoinable clauses. This is
* correct because in some cases we need to build a clauseless mergejoin.
* Simply returning NIL is therefore not enough to distinguish safe from
* unsafe cases.)
{
/*
* The executor can handle extra joinquals that are constants, but
- * not anything else, when doing right/full merge join. (The
- * reason to support constants is so we can do FULL JOIN ON
+ * not anything else, when doing right/right-anti/full merge join.
+ * (The reason to support constants is so we can do FULL JOIN ON
* FALSE.)
*/
if (!restrictinfo->clause || !IsA(restrictinfo->clause, Const))
switch (jointype)
{
case JOIN_RIGHT:
+ case JOIN_RIGHT_ANTI:
case JOIN_FULL:
*mergejoin_allowed = !have_nonmergeable_joinclause;
break;
add_paths_to_joinrel(root, joinrel, rel1, rel2,
JOIN_ANTI, sjinfo,
restrictlist);
+ add_paths_to_joinrel(root, joinrel, rel2, rel1,
+ JOIN_RIGHT_ANTI, sjinfo,
+ restrictlist);
break;
default:
/* other values not expected here */
* 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.
*
- * EXCEPTION: in a FULL or RIGHT join, we cannot treat the result as
- * having the outer path's path keys, because null lefthand rows may be
- * inserted at random points. It must be treated as unsorted.
+ * EXCEPTION: in a FULL, RIGHT or RIGHT_ANTI join, we cannot treat the
+ * result as having the outer path's path keys, because null lefthand rows
+ * may be inserted at random points. It must be treated as unsorted.
*
* We truncate away any pathkeys that are uninteresting for higher joins.
*
JoinType jointype,
List *outer_pathkeys)
{
- if (jointype == JOIN_FULL || jointype == JOIN_RIGHT)
+ if (jointype == JOIN_FULL ||
+ jointype == JOIN_RIGHT ||
+ jointype == JOIN_RIGHT_ANTI)
return NIL;
/*
* point of the available_rels machinations is to ensure that we only
* pull up quals for which that's okay.
*
- * We don't expect to see any pre-existing JOIN_SEMI or JOIN_ANTI
- * nodes here.
+ * We don't expect to see any pre-existing JOIN_SEMI, JOIN_ANTI, or
+ * JOIN_RIGHT_ANTI jointypes here.
*/
switch (j->jointype)
{
* distribute_qual_to_rels to get rid of such clauses.
*
* 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,
- * but the main reason to do it is to not need to invent a JOIN_REVERSE_ANTI
- * join type.
+ * JOIN_LEFT. This saves some code here and in some later planner routines;
+ * the main benefit is to reduce the number of jointypes that can appear in
+ * 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
* run after expression preprocessing (i.e., qual canonicalization and JOIN
/*
* These could only have been introduced by pull_up_sublinks,
* 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;
default:
* OuterTupleSlot is empty!)
* hj_OuterTupleSlot tuple slot for outer 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_FirstOuterTupleSlot first tuple retrieved from outer plan
* hj_JoinState current state of ExecHashJoin state machine
*/
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_RIGHT_ANTI, /* 1 copy of each RHS row that has no match */
/*
* These codes are used internally in the planner, but are not supported
((1 << JOIN_LEFT) | \
(1 << JOIN_FULL) | \
(1 << JOIN_RIGHT) | \
- (1 << JOIN_ANTI))) != 0)
+ (1 << JOIN_ANTI) | \
+ (1 << JOIN_RIGHT_ANTI))) != 0)
/*
* AggStrategy -
* min_lefthand and min_righthand for higher joins.)
*
* 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
- * in a join_info_list member are only LEFT, FULL, SEMI, or ANTI.
+ * the inputs to make it a LEFT JOIN. It's never JOIN_RIGHT_ANTI either.
+ * 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,
* if there is one. It is zero when jointype is INNER or SEMI, and can be
Sort
Sort Key: t1.a
-> Append
- -> Hash Anti Join
- Hash Cond: (t1_1.a = t2_1.b)
- -> Seq Scan on prt1_adv_p1 t1_1
- Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_1.b = t1_1.a)
+ -> Seq Scan on prt2_adv_p1 t2_1
-> 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
- Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p1 t1_1
+ Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_2.b = t1_2.a)
+ -> Seq Scan on prt2_adv_p2 t2_2
-> 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
- Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p2 t1_2
+ Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_3.b = t1_3.a)
+ -> Seq Scan on prt2_adv_p3 t2_3
-> Hash
- -> Seq Scan on prt2_adv_p3 t2_3
+ -> Seq Scan on prt1_adv_p3 t1_3
+ Filter: (b = 0)
(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;
Sort
Sort Key: t1.a
-> Append
- -> Hash Anti Join
- Hash Cond: (t1_1.a = t2_1.b)
- -> Seq Scan on prt1_adv_p1 t1_1
- Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_1.b = t1_1.a)
+ -> Seq Scan on prt2_adv_p1 t2_1
-> 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
- Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p1 t1_1
+ Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_2.b = t1_2.a)
+ -> Seq Scan on prt2_adv_p2 t2_2
-> 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
- Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p2 t1_2
+ Filter: (b = 0)
+ -> Hash Right Anti Join
+ Hash Cond: (t2_3.b = t1_3.a)
+ -> Seq Scan on prt2_adv_p3 t2_3
-> Hash
- -> Seq Scan on prt2_adv_p3 t2_3
+ -> Seq Scan on prt1_adv_p3 t1_3
+ Filter: (b = 0)
(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;
-- partitions on the nullable side
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;
- QUERY PLAN
-------------------------------------------------------
+ QUERY PLAN
+---------------------------------------------------------
Sort
Sort Key: t1.b
- -> Hash Anti Join
- Hash Cond: (t1.b = t2.a)
+ -> Hash Right Anti Join
+ Hash Cond: (t2.a = t1.b)
-> Append
- -> Seq Scan on prt2_adv_p1 t1_1
- Filter: (a = 0)
- -> Seq Scan on prt2_adv_p2 t1_2
- Filter: (a = 0)
- -> Seq Scan on prt2_adv_p3 t1_3
- Filter: (a = 0)
- -> Seq Scan on prt2_adv_extra t1_4
- Filter: (a = 0)
+ -> 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
- -> Seq Scan on prt1_adv_p1 t2_1
- -> Seq Scan on prt1_adv_p2 t2_2
- -> Seq Scan on prt1_adv_p3 t2_3
+ -> Seq Scan on prt2_adv_p1 t1_1
+ Filter: (a = 0)
+ -> Seq Scan on prt2_adv_p2 t1_2
+ Filter: (a = 0)
+ -> Seq Scan on prt2_adv_p3 t1_3
+ Filter: (a = 0)
+ -> Seq Scan on prt2_adv_extra t1_4
+ Filter: (a = 0)
(18 rows)
-- full join; currently we can't do partitioned join if there are no matched
-- anti join
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;
- QUERY PLAN
---------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------
Sort
Sort Key: t1.a
- -> Hash Anti Join
- Hash Cond: (t1.a = t2.b)
+ -> Hash Right Anti Join
+ Hash Cond: (t2.b = t1.a)
-> Append
- -> Seq Scan on prt1_adv_p1 t1_1
- Filter: (b = 0)
- -> Seq Scan on prt1_adv_p2 t1_2
- Filter: (b = 0)
- -> Seq Scan on prt1_adv_p3 t1_3
- Filter: (b = 0)
+ -> 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
- -> 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
+ -> Seq Scan on prt1_adv_p1 t1_1
+ Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p2 t1_2
+ Filter: (b = 0)
+ -> Seq Scan on prt1_adv_p3 t1_3
+ Filter: (b = 0)
(17 rows)
-- full join
-- anti join
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;
- QUERY PLAN
-----------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------
Sort
Sort Key: t1.a
-> Append
- -> Nested Loop Anti Join
- Join Filter: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
- -> Seq Scan on plt1_adv_p1 t1_1
- Filter: (b < 10)
+ -> Hash Right Anti Join
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
-> 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
- Filter: (b < 10)
+ -> Hash
+ -> Seq Scan on plt1_adv_p1 t1_1
+ 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
- -> Nested Loop Anti Join
- Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
- -> Seq Scan on plt1_adv_p3 t1_3
- Filter: (b < 10)
+ -> Hash
+ -> Seq Scan on plt1_adv_p2 t1_2
+ Filter: (b < 10)
+ -> Hash Right Anti Join
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
-> Seq Scan on plt2_adv_p3 t2_3
-(18 rows)
+ -> Hash
+ -> Seq Scan on plt1_adv_p3 t1_3
+ Filter: (b < 10)
+(21 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;
a | b | c
-- anti join
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;
- QUERY PLAN
-----------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------
Sort
Sort Key: t1.a
-> Append
- -> Nested Loop Anti Join
- Join Filter: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
- -> Seq Scan on plt1_adv_p1 t1_1
- Filter: (b < 10)
+ -> Hash Right Anti Join
+ Hash Cond: ((t2_1.a = t1_1.a) AND (t2_1.c = t1_1.c))
-> 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
- Filter: (b < 10)
+ -> Hash
+ -> Seq Scan on plt1_adv_p1 t1_1
+ 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
- -> Nested Loop Anti Join
- Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
- -> Seq Scan on plt1_adv_p3 t1_3
- Filter: (b < 10)
+ -> Hash
+ -> Seq Scan on plt1_adv_p2 t1_2
+ Filter: (b < 10)
+ -> Hash Right Anti Join
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
-> Seq Scan on plt2_adv_p3 t2_3
-(18 rows)
+ -> Hash
+ -> Seq Scan on plt1_adv_p3 t1_3
+ Filter: (b < 10)
+(21 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;
a | b | c
-- partitions on the nullable side
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;
- QUERY PLAN
-------------------------------------------------------
+ QUERY PLAN
+---------------------------------------------------------
Sort
Sort Key: t1.a
- -> Hash Anti Join
- Hash Cond: ((t1.a = t2.a) AND (t1.c = t2.c))
+ -> Hash Right Anti Join
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
-> Append
- -> Seq Scan on plt2_adv_extra t1_1
- Filter: (b < 10)
- -> Seq Scan on plt2_adv_p1 t1_2
- Filter: (b < 10)
- -> Seq Scan on plt2_adv_p2 t1_3
- Filter: (b < 10)
- -> Seq Scan on plt2_adv_p3 t1_4
- Filter: (b < 10)
+ -> 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
- -> Seq Scan on plt1_adv_p1 t2_1
- -> Seq Scan on plt1_adv_p2 t2_2
- -> Seq Scan on plt1_adv_p3 t2_3
+ -> Seq Scan on plt2_adv_extra t1_1
+ Filter: (b < 10)
+ -> Seq Scan on plt2_adv_p1 t1_2
+ Filter: (b < 10)
+ -> Seq Scan on plt2_adv_p2 t1_3
+ Filter: (b < 10)
+ -> Seq Scan on plt2_adv_p3 t1_4
+ Filter: (b < 10)
(18 rows)
-- full join; currently we can't do partitioned join if there are no matched
-- anti join
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;
- QUERY PLAN
---------------------------------------------------------
+ QUERY PLAN
+------------------------------------------------------
Sort
Sort Key: t1.a
- -> Hash Anti Join
- Hash Cond: ((t1.a = t2.a) AND (t1.c = t2.c))
+ -> Hash Right Anti Join
+ Hash Cond: ((t2.a = t1.a) AND (t2.c = t1.c))
-> Append
- -> Seq Scan on plt1_adv_p1 t1_1
- Filter: (b < 10)
- -> Seq Scan on plt1_adv_p2 t1_2
- Filter: (b < 10)
- -> Seq Scan on plt1_adv_p3 t1_3
- Filter: (b < 10)
+ -> 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
- -> 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
+ -> Seq Scan on plt1_adv_p1 t1_1
+ Filter: (b < 10)
+ -> Seq Scan on plt1_adv_p2 t1_2
+ Filter: (b < 10)
+ -> Seq Scan on plt1_adv_p3 t1_3
+ Filter: (b < 10)
(17 rows)
-- full join
-- anti join
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;
- QUERY PLAN
-----------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------
Sort
Sort Key: t1.a
-> Append
- -> Hash Anti Join
- Hash Cond: ((t1_1.a = t2_1.a) AND (t1_1.c = t2_1.c))
- -> Seq Scan on plt1_adv_p1_null t1_1
- Filter: (b < 10)
+ -> Hash Right Anti Join
+ 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 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
- Filter: (b < 10)
+ -> Seq Scan on plt1_adv_p1_null t1_1
+ 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
- -> Nested Loop Anti Join
- Join Filter: ((t1_3.a = t2_3.a) AND (t1_3.c = t2_3.c))
- -> Seq Scan on plt1_adv_p3 t1_3
- Filter: (b < 10)
+ -> Hash
+ -> Seq Scan on plt1_adv_p2 t1_2
+ Filter: (b < 10)
+ -> Hash Right Anti Join
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.c = t1_3.c))
-> Seq Scan on plt2_adv_p3_null t2_3
-(19 rows)
+ -> Hash
+ -> Seq Scan on plt1_adv_p3 t1_3
+ Filter: (b < 10)
+(21 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;
a | b | c