Optimize joins when the inner relation can be proven unique.

If there can certainly be no more than one matching inner row for a given
outer row, then the executor can move on to the next outer row as soon as
it's found one match; there's no need to continue scanning the inner
relation for this outer row.  This saves useless scanning in nestloop
and hash joins.  In merge joins, it offers the opportunity to skip
mark/restore processing, because we know we have not advanced past the
first possible match for the next outer row.

Of course, the devil is in the details: the proof of uniqueness must
depend only on joinquals (not otherquals), and if we want to skip
mergejoin mark/restore then it must depend only on merge clauses.
To avoid adding more planning overhead than absolutely necessary,
the present patch errs in the conservative direction: there are cases
where inner_unique or skip_mark_restore processing could be used, but
it will not do so because it's not sure that the uniqueness proof
depended only on "safe" clauses.  This could be improved later.

David Rowley, reviewed and rather heavily editorialized on by me

Discussion: https://postgr.es/m/CAApHDvqF6Sw-TK98bW48TdtFJ+3a7D2mFyZ7++=D-RyPsL76gw@mail.gmail.com
This commit is contained in:
Tom Lane 2017-04-07 22:20:03 -04:00
parent f13a9121f9
commit 9c7f5229ad
26 changed files with 987 additions and 206 deletions

View File

@ -2336,8 +2336,8 @@ SELECT *
WHERE t.id IS NULL OR m.id IS NULL;
id | name | id | name
----+------+----+------
| | 2 | Two
2 | two | |
| | 2 | Two
(2 rows)
REFRESH MATERIALIZED VIEW CONCURRENTLY citext_matview;

View File

@ -2336,8 +2336,8 @@ SELECT *
WHERE t.id IS NULL OR m.id IS NULL;
id | name | id | name
----+------+----+------
| | 2 | Two
2 | two | |
| | 2 | Two
(2 rows)
REFRESH MATERIALIZED VIEW CONCURRENTLY citext_matview;

View File

@ -396,13 +396,14 @@ EXPLAIN (VERBOSE, COSTS OFF)
Output: t1.c1, t2."C 1"
-> Merge Join
Output: t1.c1, t2."C 1"
Inner Unique: true
Merge Cond: (t1.c1 = t2."C 1")
-> Foreign Scan on public.ft2 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
-> Index Only Scan using t1_pkey on "S 1"."T 1" t2
Output: t2."C 1"
(10 rows)
(11 rows)
SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
c1 | C 1
@ -429,13 +430,14 @@ EXPLAIN (VERBOSE, COSTS OFF)
Output: t1.c1, t2."C 1"
-> Merge Left Join
Output: t1.c1, t2."C 1"
Inner Unique: true
Merge Cond: (t1.c1 = t2."C 1")
-> Foreign Scan on public.ft2 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
-> Index Only Scan using t1_pkey on "S 1"."T 1" t2
Output: t2."C 1"
(10 rows)
(11 rows)
SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
c1 | C 1
@ -462,6 +464,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Output: t1."C 1"
-> Merge Right Join
Output: t1."C 1"
Inner Unique: true
Merge Cond: (t3.c1 = t1."C 1")
-> Foreign Scan
Output: t3.c1
@ -469,7 +472,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
-> Index Only Scan using t1_pkey on "S 1"."T 1" t1
Output: t1."C 1"
(11 rows)
(12 rows)
SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
C 1
@ -497,6 +500,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Output: t1."C 1", t2.c1, t3.c1
-> Merge Right Join
Output: t1."C 1", t2.c1, t3.c1
Inner Unique: true
Merge Cond: (t3.c1 = t1."C 1")
-> Foreign Scan
Output: t3.c1, t2.c1
@ -504,7 +508,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
-> Index Only Scan using t1_pkey on "S 1"."T 1" t1
Output: t1."C 1"
(11 rows)
(12 rows)
SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
C 1 | c1 | c1
@ -530,6 +534,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Output: t1."C 1", t2.c1, t3.c1
-> Merge Full Join
Output: t1."C 1", t2.c1, t3.c1
Inner Unique: true
Merge Cond: (t3.c1 = t1."C 1")
-> Foreign Scan
Output: t2.c1, t3.c1
@ -537,7 +542,7 @@ EXPLAIN (VERBOSE, COSTS OFF)
Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
-> Index Only Scan using t1_pkey on "S 1"."T 1" t1
Output: t1."C 1"
(11 rows)
(12 rows)
SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
C 1 | c1 | c1
@ -1844,8 +1849,8 @@ SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER B
-- SEMI JOIN, not pushed down
EXPLAIN (VERBOSE, COSTS OFF)
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
QUERY PLAN
---------------------------------------------------------------------------------------------
QUERY PLAN
---------------------------------------------------------------------------------------
Limit
Output: t1.c1
-> Merge Semi Join
@ -1854,12 +1859,10 @@ SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1)
-> Foreign Scan on public.ft1 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
-> Materialize
-> Foreign Scan on public.ft2 t2
Output: t2.c1
-> Foreign Scan on public.ft2 t2
Output: t2.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
(13 rows)
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
(11 rows)
SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
c1
@ -1889,12 +1892,10 @@ SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2
-> Foreign Scan on public.ft1 t1
Output: t1.c1
Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
-> Materialize
-> Foreign Scan on public.ft2 t2
Output: t2.c2
-> Foreign Scan on public.ft2 t2
Output: t2.c2
Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
(13 rows)
Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
(11 rows)
SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
c1
@ -3121,6 +3122,7 @@ select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x w
Group Key: x.b
-> Hash Join
Output: x.b
Inner Unique: true
Hash Cond: (ft1.c2 = x.a)
-> Foreign Scan on public.ft1
Output: ft1.c2
@ -3133,7 +3135,7 @@ select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x w
Output: ft1_1.c2, (sum(ft1_1.c1))
Relations: Aggregate on (public.ft1)
Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY c2
(20 rows)
(21 rows)
select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
count | b
@ -3252,6 +3254,7 @@ select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.
Output: sum(q.a), count(q.b)
-> Nested Loop Left Join
Output: q.a, q.b
Inner Unique: true
Join Filter: ((ft4.c1)::numeric <= q.b)
-> Foreign Scan on public.ft4
Output: ft4.c1, ft4.c2, ft4.c3
@ -3264,7 +3267,7 @@ select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.
Output: 13, (avg(ft1.c1)), NULL::bigint
Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
(16 rows)
(17 rows)
select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
sum | count
@ -4048,20 +4051,18 @@ explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
explain (verbose, costs off) select * from ft3 f, loct3 l
where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
QUERY PLAN
-------------------------------------------------------------
Hash Join
QUERY PLAN
---------------------------------------------------------
Nested Loop
Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
Hash Cond: ((f.f3)::text = (l.f3)::text)
Join Filter: ((f.f3)::text = (l.f3)::text)
-> Index Scan using loct3_f1_key on public.loct3 l
Output: l.f1, l.f2, l.f3
Index Cond: (l.f1 = 'foo'::text)
-> Foreign Scan on public.ft3 f
Output: f.f1, f.f2, f.f3
Remote SQL: SELECT f1, f2, f3 FROM public.loct3
-> Hash
Output: l.f1, l.f2, l.f3
-> Index Scan using loct3_f1_key on public.loct3 l
Output: l.f1, l.f2, l.f3
Index Cond: (l.f1 = 'foo'::text)
(11 rows)
(9 rows)
-- ===================================================================
-- test writable foreign table stuff
@ -6541,6 +6542,7 @@ select * from bar where f1 in (select f1 from foo) for update;
Output: bar.f1, bar.f2, bar.ctid, bar.*, bar.tableoid, foo.ctid, foo.*, foo.tableoid
-> Hash Join
Output: bar.f1, bar.f2, bar.ctid, bar.*, bar.tableoid, foo.ctid, foo.*, foo.tableoid
Inner Unique: true
Hash Cond: (bar.f1 = foo.f1)
-> Append
-> Seq Scan on public.bar
@ -6559,7 +6561,7 @@ select * from bar where f1 in (select f1 from foo) for update;
-> Foreign Scan on public.foo2
Output: foo2.ctid, foo2.*, foo2.tableoid, foo2.f1
Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
(22 rows)
(23 rows)
select * from bar where f1 in (select f1 from foo) for update;
f1 | f2
@ -6578,6 +6580,7 @@ select * from bar where f1 in (select f1 from foo) for share;
Output: bar.f1, bar.f2, bar.ctid, bar.*, bar.tableoid, foo.ctid, foo.*, foo.tableoid
-> Hash Join
Output: bar.f1, bar.f2, bar.ctid, bar.*, bar.tableoid, foo.ctid, foo.*, foo.tableoid
Inner Unique: true
Hash Cond: (bar.f1 = foo.f1)
-> Append
-> Seq Scan on public.bar
@ -6596,7 +6599,7 @@ select * from bar where f1 in (select f1 from foo) for share;
-> Foreign Scan on public.foo2
Output: foo2.ctid, foo2.*, foo2.tableoid, foo2.f1
Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
(22 rows)
(23 rows)
select * from bar where f1 in (select f1 from foo) for share;
f1 | f2
@ -6618,6 +6621,7 @@ update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
-> Hash Join
Output: bar.f1, (bar.f2 + 100), bar.ctid, foo.ctid, foo.*, foo.tableoid
Inner Unique: true
Hash Cond: (bar.f1 = foo.f1)
-> Seq Scan on public.bar
Output: bar.f1, bar.f2, bar.ctid
@ -6634,6 +6638,7 @@ update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
-> Hash Join
Output: bar2.f1, (bar2.f2 + 100), bar2.f3, bar2.ctid, foo.ctid, foo.*, foo.tableoid
Inner Unique: true
Hash Cond: (bar2.f1 = foo.f1)
-> Foreign Scan on public.bar2
Output: bar2.f1, bar2.f2, bar2.f3, bar2.ctid
@ -6649,7 +6654,7 @@ update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
-> Foreign Scan on public.foo2
Output: foo2.ctid, foo2.*, foo2.tableoid, foo2.f1
Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
(37 rows)
(39 rows)
update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
select tableoid::regclass, * from bar order by 1,2;

View File

@ -1343,6 +1343,23 @@ ExplainNode(PlanState *planstate, List *ancestors,
if (es->verbose)
show_plan_tlist(planstate, ancestors, es);
/* unique join */
switch (nodeTag(plan))
{
case T_NestLoop:
case T_MergeJoin:
case T_HashJoin:
/* try not to be too chatty about this in text mode */
if (es->format != EXPLAIN_FORMAT_TEXT ||
(es->verbose && ((Join *) plan)->inner_unique))
ExplainPropertyBool("Inner Unique",
((Join *) plan)->inner_unique,
es);
break;
default:
break;
}
/* quals, sort keys, etc */
switch (nodeTag(plan))
{

View File

@ -288,10 +288,11 @@ ExecHashJoin(HashJoinState *node)
}
/*
* In a semijoin, we'll consider returning the first
* match, but after that we're done with this outer tuple.
* If we only need to join to the first matching inner
* tuple, then consider returning this one, but after that
* continue with next outer tuple.
*/
if (node->js.jointype == JOIN_SEMI)
if (node->js.single_match)
node->hj_JoinState = HJ_NEED_NEW_OUTER;
if (otherqual == NULL || ExecQual(otherqual, econtext))
@ -435,6 +436,12 @@ ExecInitHashJoin(HashJoin *node, EState *estate, int eflags)
ExecInitResultTupleSlot(estate, &hjstate->js.ps);
hjstate->hj_OuterTupleSlot = ExecInitExtraTupleSlot(estate);
/*
* detect whether we need only consider the first matching inner tuple
*/
hjstate->js.single_match = (node->join.inner_unique ||
node->join.jointype == JOIN_SEMI);
/* set up null tuples for outer joins, if needed */
switch (node->join.jointype)
{

View File

@ -802,10 +802,11 @@ ExecMergeJoin(MergeJoinState *node)
}
/*
* In a semijoin, we'll consider returning the first
* match, but after that we're done with this outer tuple.
* If we only need to join to the first matching inner
* tuple, then consider returning this one, but after that
* continue with next outer tuple.
*/
if (node->js.jointype == JOIN_SEMI)
if (node->js.single_match)
node->mj_JoinState = EXEC_MJ_NEXTOUTER;
qualResult = (otherqual == NULL ||
@ -1050,6 +1051,10 @@ ExecMergeJoin(MergeJoinState *node)
* scan position to the first mark, and go join that tuple
* (and any following ones) to the new outer.
*
* If we were able to determine mark and restore are not
* needed, then we don't have to back up; the current
* inner is already the first possible match.
*
* NOTE: we do not need to worry about the MatchedInner
* state for the rescanned inner tuples. We know all of
* them will match this new outer tuple and therefore
@ -1062,16 +1067,19 @@ ExecMergeJoin(MergeJoinState *node)
* forcing the merge clause to never match, so we never
* get here.
*/
ExecRestrPos(innerPlan);
if (!node->mj_SkipMarkRestore)
{
ExecRestrPos(innerPlan);
/*
* ExecRestrPos probably should give us back a new Slot,
* but since it doesn't, use the marked slot. (The
* previously returned mj_InnerTupleSlot cannot be assumed
* to hold the required tuple.)
*/
node->mj_InnerTupleSlot = innerTupleSlot;
/* we need not do MJEvalInnerValues again */
/*
* ExecRestrPos probably should give us back a new
* Slot, but since it doesn't, use the marked slot.
* (The previously returned mj_InnerTupleSlot cannot
* be assumed to hold the required tuple.)
*/
node->mj_InnerTupleSlot = innerTupleSlot;
/* we need not do MJEvalInnerValues again */
}
node->mj_JoinState = EXEC_MJ_JOINTUPLES;
}
@ -1172,7 +1180,8 @@ ExecMergeJoin(MergeJoinState *node)
if (compareResult == 0)
{
ExecMarkPos(innerPlan);
if (!node->mj_SkipMarkRestore)
ExecMarkPos(innerPlan);
MarkInnerTuple(node->mj_InnerTupleSlot, node);
@ -1466,11 +1475,18 @@ ExecInitMergeJoin(MergeJoin *node, EState *estate, int eflags)
/*
* initialize child nodes
*
* inner child must support MARK/RESTORE.
* inner child must support MARK/RESTORE, unless we have detected that we
* don't need that. Note that skip_mark_restore must never be set if
* there are non-mergeclause joinquals, since the logic wouldn't work.
*/
Assert(node->join.joinqual == NIL || !node->skip_mark_restore);
mergestate->mj_SkipMarkRestore = node->skip_mark_restore;
outerPlanState(mergestate) = ExecInitNode(outerPlan(node), estate, eflags);
innerPlanState(mergestate) = ExecInitNode(innerPlan(node), estate,
eflags | EXEC_FLAG_MARK);
mergestate->mj_SkipMarkRestore ?
eflags :
(eflags | EXEC_FLAG_MARK));
/*
* For certain types of inner child nodes, it is advantageous to issue
@ -1483,7 +1499,8 @@ ExecInitMergeJoin(MergeJoin *node, EState *estate, int eflags)
* only if eflags doesn't specify REWIND.
*/
if (IsA(innerPlan(node), Material) &&
(eflags & EXEC_FLAG_REWIND) == 0)
(eflags & EXEC_FLAG_REWIND) == 0 &&
!mergestate->mj_SkipMarkRestore)
mergestate->mj_ExtraMarks = true;
else
mergestate->mj_ExtraMarks = false;
@ -1497,6 +1514,13 @@ ExecInitMergeJoin(MergeJoin *node, EState *estate, int eflags)
ExecSetSlotDescriptor(mergestate->mj_MarkedTupleSlot,
ExecGetResultType(innerPlanState(mergestate)));
/*
* detect whether we need only consider the first matching inner tuple
*/
mergestate->js.single_match = (node->join.inner_unique ||
node->join.jointype == JOIN_SEMI);
/* set up null tuples for outer joins, if needed */
switch (node->join.jointype)
{
case JOIN_INNER:

View File

@ -219,10 +219,11 @@ ExecNestLoop(NestLoopState *node)
}
/*
* In a semijoin, we'll consider returning the first match, but
* after that we're done with this outer tuple.
* If we only need to join to the first matching inner tuple, then
* consider returning this one, but after that continue with next
* outer tuple.
*/
if (node->js.jointype == JOIN_SEMI)
if (node->js.single_match)
node->nl_NeedNewOuter = true;
if (otherqual == NULL || ExecQual(otherqual, econtext))
@ -309,6 +310,13 @@ ExecInitNestLoop(NestLoop *node, EState *estate, int eflags)
*/
ExecInitResultTupleSlot(estate, &nlstate->js.ps);
/*
* detect whether we need only consider the first matching inner tuple
*/
nlstate->js.single_match = (node->join.inner_unique ||
node->join.jointype == JOIN_SEMI);
/* set up null tuples for outer joins, if needed */
switch (node->join.jointype)
{
case JOIN_INNER:

View File

@ -797,6 +797,7 @@ CopyJoinFields(const Join *from, Join *newnode)
CopyPlanFields((const Plan *) from, (Plan *) newnode);
COPY_SCALAR_FIELD(jointype);
COPY_SCALAR_FIELD(inner_unique);
COPY_NODE_FIELD(joinqual);
}
@ -857,6 +858,7 @@ _copyMergeJoin(const MergeJoin *from)
/*
* copy remainder of node
*/
COPY_SCALAR_FIELD(skip_mark_restore);
COPY_NODE_FIELD(mergeclauses);
numCols = list_length(from->mergeclauses);
if (numCols > 0)

View File

@ -305,6 +305,7 @@ _outJoinPlanInfo(StringInfo str, const Join *node)
_outPlanInfo(str, (const Plan *) node);
WRITE_ENUM_FIELD(jointype, JoinType);
WRITE_BOOL_FIELD(inner_unique);
WRITE_NODE_FIELD(joinqual);
}
@ -714,6 +715,7 @@ _outMergeJoin(StringInfo str, const MergeJoin *node)
_outJoinPlanInfo(str, (const Join *) node);
WRITE_BOOL_FIELD(skip_mark_restore);
WRITE_NODE_FIELD(mergeclauses);
numCols = list_length(node->mergeclauses);
@ -1707,6 +1709,7 @@ _outJoinPathInfo(StringInfo str, const JoinPath *node)
_outPathInfo(str, (const Path *) node);
WRITE_ENUM_FIELD(jointype, JoinType);
WRITE_BOOL_FIELD(inner_unique);
WRITE_NODE_FIELD(outerjoinpath);
WRITE_NODE_FIELD(innerjoinpath);
WRITE_NODE_FIELD(joinrestrictinfo);
@ -2114,6 +2117,7 @@ _outMergePath(StringInfo str, const MergePath *node)
WRITE_NODE_FIELD(path_mergeclauses);
WRITE_NODE_FIELD(outersortkeys);
WRITE_NODE_FIELD(innersortkeys);
WRITE_BOOL_FIELD(skip_mark_restore);
WRITE_BOOL_FIELD(materialize_inner);
}
@ -2246,6 +2250,7 @@ _outRelOptInfo(StringInfo str, const RelOptInfo *node)
WRITE_OID_FIELD(userid);
WRITE_BOOL_FIELD(useridiscurrent);
/* we don't try to print fdwroutine or fdw_private */
/* can't print unique_for_rels/non_unique_for_rels; BMSes aren't Nodes */
WRITE_NODE_FIELD(baserestrictinfo);
WRITE_UINT_FIELD(baserestrict_min_security);
WRITE_NODE_FIELD(joininfo);

View File

@ -1949,6 +1949,7 @@ ReadCommonJoin(Join *local_node)
ReadCommonPlan(&local_node->plan);
READ_ENUM_FIELD(jointype, JoinType);
READ_BOOL_FIELD(inner_unique);
READ_NODE_FIELD(joinqual);
}
@ -1992,6 +1993,7 @@ _readMergeJoin(void)
ReadCommonJoin(&local_node->join);
READ_BOOL_FIELD(skip_mark_restore);
READ_NODE_FIELD(mergeclauses);
numCols = list_length(local_node->mergeclauses);

View File

@ -2081,15 +2081,13 @@ cost_group(Path *path, PlannerInfo *root,
* 'jointype' is the type of join to be performed
* 'outer_path' is the outer input to the join
* 'inner_path' is the inner input to the join
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if jointype is SEMI or ANTI
* 'extra' contains miscellaneous information about the join
*/
void
initial_cost_nestloop(PlannerInfo *root, JoinCostWorkspace *workspace,
JoinType jointype,
Path *outer_path, Path *inner_path,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors)
JoinPathExtraData *extra)
{
Cost startup_cost = 0;
Cost run_cost = 0;
@ -2120,10 +2118,12 @@ initial_cost_nestloop(PlannerInfo *root, JoinCostWorkspace *workspace,
inner_run_cost = inner_path->total_cost - inner_path->startup_cost;
inner_rescan_run_cost = inner_rescan_total_cost - inner_rescan_start_cost;
if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
if (jointype == JOIN_SEMI || jointype == JOIN_ANTI ||
extra->inner_unique)
{
/*
* SEMI or ANTI join: executor will stop after first match.
* With a SEMI or ANTI join, or if the innerrel is known unique, the
* executor will stop after the first match.
*
* Getting decent estimates requires inspection of the join quals,
* which we choose to postpone to final_cost_nestloop.
@ -2156,14 +2156,12 @@ initial_cost_nestloop(PlannerInfo *root, JoinCostWorkspace *workspace,
*
* 'path' is already filled in except for the rows and cost fields
* 'workspace' is the result from initial_cost_nestloop
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if path->jointype is SEMI or ANTI
* 'extra' contains miscellaneous information about the join
*/
void
final_cost_nestloop(PlannerInfo *root, NestPath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors)
JoinPathExtraData *extra)
{
Path *outer_path = path->outerjoinpath;
Path *inner_path = path->innerjoinpath;
@ -2206,10 +2204,12 @@ final_cost_nestloop(PlannerInfo *root, NestPath *path,
/* cost of inner-relation source data (we already dealt with outer rel) */
if (path->jointype == JOIN_SEMI || path->jointype == JOIN_ANTI)
if (path->jointype == JOIN_SEMI || path->jointype == JOIN_ANTI ||
extra->inner_unique)
{
/*
* SEMI or ANTI join: executor will stop after first match.
* With a SEMI or ANTI join, or if the innerrel is known unique, the
* executor will stop after the first match.
*/
Cost inner_run_cost = workspace->inner_run_cost;
Cost inner_rescan_run_cost = workspace->inner_rescan_run_cost;
@ -2225,8 +2225,8 @@ final_cost_nestloop(PlannerInfo *root, NestPath *path,
* clamp inner_scan_frac to at most 1.0; but since match_count is at
* least 1, no such clamp is needed now.)
*/
outer_matched_rows = rint(outer_path_rows * semifactors->outer_match_frac);
inner_scan_frac = 2.0 / (semifactors->match_count + 1.0);
outer_matched_rows = rint(outer_path_rows * extra->semifactors.outer_match_frac);
inner_scan_frac = 2.0 / (extra->semifactors.match_count + 1.0);
/*
* Compute number of tuples processed (not number emitted!). First,
@ -2350,7 +2350,7 @@ final_cost_nestloop(PlannerInfo *root, NestPath *path,
* 'inner_path' is the inner input to the join
* 'outersortkeys' is the list of sort keys for the outer path
* 'innersortkeys' is the list of sort keys for the inner path
* 'sjinfo' is extra info about the join for selectivity estimation
* 'extra' contains miscellaneous information about the join
*
* Note: outersortkeys and innersortkeys should be NIL if no explicit
* sort is needed because the respective source path is already ordered.
@ -2361,7 +2361,7 @@ initial_cost_mergejoin(PlannerInfo *root, JoinCostWorkspace *workspace,
List *mergeclauses,
Path *outer_path, Path *inner_path,
List *outersortkeys, List *innersortkeys,
SpecialJoinInfo *sjinfo)
JoinPathExtraData *extra)
{
Cost startup_cost = 0;
Cost run_cost = 0;
@ -2562,26 +2562,33 @@ initial_cost_mergejoin(PlannerInfo *root, JoinCostWorkspace *workspace,
* final_cost_mergejoin
* Final estimate of the cost and result size of a mergejoin path.
*
* Unlike other costsize functions, this routine makes one actual decision:
* whether we should materialize the inner path. We do that either because
* the inner path can't support mark/restore, or because it's cheaper to
* use an interposed Material node to handle mark/restore. When the decision
* is cost-based it would be logically cleaner to build and cost two separate
* paths with and without that flag set; but that would require repeating most
* of the cost calculations, which are not all that cheap. Since the choice
* will not affect output pathkeys or startup cost, only total cost, there is
* no possibility of wanting to keep both paths. So it seems best to make
* the decision here and record it in the path's materialize_inner field.
* Unlike other costsize functions, this routine makes two actual decisions:
* whether the executor will need to do mark/restore, and whether we should
* materialize the inner path. It would be logically cleaner to build
* separate paths testing these alternatives, but that would require repeating
* most of the cost calculations, which are not all that cheap. Since the
* choice will not affect output pathkeys or startup cost, only total cost,
* there is no possibility of wanting to keep more than one path. So it seems
* best to make the decisions here and record them in the path's
* skip_mark_restore and materialize_inner fields.
*
* Mark/restore overhead is usually required, but can be skipped if we know
* that the executor need find only one match per outer tuple, and that the
* mergeclauses are sufficient to identify a match.
*
* We materialize the inner path if we need mark/restore and either the inner
* path can't support mark/restore, or it's cheaper to use an interposed
* Material node to handle mark/restore.
*
* 'path' is already filled in except for the rows and cost fields and
* materialize_inner
* skip_mark_restore and materialize_inner
* 'workspace' is the result from initial_cost_mergejoin
* 'sjinfo' is extra info about the join for selectivity estimation
* 'extra' contains miscellaneous information about the join
*/
void
final_cost_mergejoin(PlannerInfo *root, MergePath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo)
JoinPathExtraData *extra)
{
Path *outer_path = path->jpath.outerjoinpath;
Path *inner_path = path->jpath.innerjoinpath;
@ -2640,6 +2647,21 @@ final_cost_mergejoin(PlannerInfo *root, MergePath *path,
qp_qual_cost.startup -= merge_qual_cost.startup;
qp_qual_cost.per_tuple -= merge_qual_cost.per_tuple;
/*
* With a SEMI or ANTI join, or if the innerrel is known unique, the
* executor will stop scanning for matches after the first match. When
* all the joinclauses are merge clauses, this means we don't ever need to
* back up the merge, and so we can skip mark/restore overhead.
*/
if ((path->jpath.jointype == JOIN_SEMI ||
path->jpath.jointype == JOIN_ANTI ||
extra->inner_unique) &&
(list_length(path->jpath.joinrestrictinfo) ==
list_length(path->path_mergeclauses)))
path->skip_mark_restore = true;
else
path->skip_mark_restore = false;
/*
* Get approx # tuples passing the mergequals. We use approx_tuple_count
* here because we need an estimate done with JOIN_INNER semantics.
@ -2670,9 +2692,9 @@ final_cost_mergejoin(PlannerInfo *root, MergePath *path,
* computations?
*
* The whole issue is moot if we are working from a unique-ified outer
* input.
* input, or if we know we don't need to mark/restore at all.
*/
if (IsA(outer_path, UniquePath))
if (IsA(outer_path, UniquePath) ||path->skip_mark_restore)
rescannedtuples = 0;
else
{
@ -2711,11 +2733,17 @@ final_cost_mergejoin(PlannerInfo *root, MergePath *path,
mat_inner_cost = inner_run_cost +
cpu_operator_cost * inner_path_rows * rescanratio;
/*
* If we don't need mark/restore at all, we don't need materialization.
*/
if (path->skip_mark_restore)
path->materialize_inner = false;
/*
* Prefer materializing if it looks cheaper, unless the user has asked to
* suppress materialization.
*/
if (enable_material && mat_inner_cost < bare_inner_cost)
else if (enable_material && mat_inner_cost < bare_inner_cost)
path->materialize_inner = true;
/*
@ -2876,16 +2904,14 @@ cached_scansel(PlannerInfo *root, RestrictInfo *rinfo, PathKey *pathkey)
* 'hashclauses' is the list of joinclauses to be used as hash clauses
* 'outer_path' is the outer input to the join
* 'inner_path' is the inner input to the join
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if jointype is SEMI or ANTI
* 'extra' contains miscellaneous information about the join
*/
void
initial_cost_hashjoin(PlannerInfo *root, JoinCostWorkspace *workspace,
JoinType jointype,
List *hashclauses,
Path *outer_path, Path *inner_path,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors)
JoinPathExtraData *extra)
{
Cost startup_cost = 0;
Cost run_cost = 0;
@ -2970,14 +2996,12 @@ initial_cost_hashjoin(PlannerInfo *root, JoinCostWorkspace *workspace,
* 'path' is already filled in except for the rows and cost fields and
* num_batches
* 'workspace' is the result from initial_cost_hashjoin
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if path->jointype is SEMI or ANTI
* 'extra' contains miscellaneous information about the join
*/
void
final_cost_hashjoin(PlannerInfo *root, HashPath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors)
JoinPathExtraData *extra)
{
Path *outer_path = path->jpath.outerjoinpath;
Path *inner_path = path->jpath.innerjoinpath;
@ -3101,13 +3125,16 @@ final_cost_hashjoin(PlannerInfo *root, HashPath *path,
/* CPU costs */
if (path->jpath.jointype == JOIN_SEMI || path->jpath.jointype == JOIN_ANTI)
if (path->jpath.jointype == JOIN_SEMI ||
path->jpath.jointype == JOIN_ANTI ||
extra->inner_unique)
{
double outer_matched_rows;
Selectivity inner_scan_frac;
/*
* SEMI or ANTI join: executor will stop after first match.
* With a SEMI or ANTI join, or if the innerrel is known unique, the
* executor will stop after the first match.
*
* For an outer-rel row that has at least one match, we can expect the
* bucket scan to stop after a fraction 1/(match_count+1) of the
@ -3117,8 +3144,8 @@ final_cost_hashjoin(PlannerInfo *root, HashPath *path,
* to clamp inner_scan_frac to at most 1.0; but since match_count is
* at least 1, no such clamp is needed now.)
*/
outer_matched_rows = rint(outer_path_rows * semifactors->outer_match_frac);
inner_scan_frac = 2.0 / (semifactors->match_count + 1.0);
outer_matched_rows = rint(outer_path_rows * extra->semifactors.outer_match_frac);
inner_scan_frac = 2.0 / (extra->semifactors.match_count + 1.0);
startup_cost += hash_qual_cost.startup;
run_cost += hash_qual_cost.per_tuple * outer_matched_rows *
@ -3684,11 +3711,12 @@ get_restriction_qual_cost(PlannerInfo *root, RelOptInfo *baserel,
/*
* compute_semi_anti_join_factors
* Estimate how much of the inner input a SEMI or ANTI join
* Estimate how much of the inner input a SEMI, ANTI, or inner_unique join
* can be expected to scan.
*
* In a hash or nestloop SEMI/ANTI join, the executor will stop scanning
* inner rows as soon as it finds a match to the current outer row.
* The same happens if we have detected the inner rel is unique.
* We should therefore adjust some of the cost components for this effect.
* This function computes some estimates needed for these adjustments.
* These estimates will be the same regardless of the particular paths used
@ -3698,7 +3726,7 @@ get_restriction_qual_cost(PlannerInfo *root, RelOptInfo *baserel,
* Input parameters:
* outerrel: outer relation under consideration
* innerrel: inner relation under consideration
* jointype: must be JOIN_SEMI or JOIN_ANTI
* jointype: if not JOIN_SEMI or JOIN_ANTI, we assume it's inner_unique
* sjinfo: SpecialJoinInfo relevant to this join
* restrictlist: join quals
* Output parameters:
@ -3720,16 +3748,14 @@ compute_semi_anti_join_factors(PlannerInfo *root,
List *joinquals;
ListCell *l;
/* Should only be called in these cases */
Assert(jointype == JOIN_SEMI || jointype == JOIN_ANTI);
/*
* In an ANTI join, we must ignore clauses that are "pushed down", since
* those won't affect the match logic. In a SEMI join, we do not
* distinguish joinquals from "pushed down" quals, so just use the whole
* restrictinfo list.
* restrictinfo list. For other outer join types, we should consider only
* non-pushed-down quals, so that this devolves to an IS_OUTER_JOIN check.
*/
if (jointype == JOIN_ANTI)
if (IS_OUTER_JOIN(jointype))
{
joinquals = NIL;
foreach(l, restrictlist)
@ -3749,7 +3775,7 @@ compute_semi_anti_join_factors(PlannerInfo *root,
jselec = clauselist_selectivity(root,
joinquals,
0,
jointype,
(jointype == JOIN_ANTI) ? JOIN_ANTI : JOIN_SEMI,
sjinfo);
/*
@ -3776,7 +3802,7 @@ compute_semi_anti_join_factors(PlannerInfo *root,
&norm_sjinfo);
/* Avoid leaking a lot of ListCells */
if (jointype == JOIN_ANTI)
if (IS_OUTER_JOIN(jointype))
list_free(joinquals);
/*

View File

@ -21,6 +21,7 @@
#include "optimizer/cost.h"
#include "optimizer/pathnode.h"
#include "optimizer/paths.h"
#include "optimizer/planmain.h"
/* Hook for plugins to get control in add_paths_to_joinrel() */
set_join_pathlist_hook_type set_join_pathlist_hook = NULL;
@ -120,6 +121,35 @@ add_paths_to_joinrel(PlannerInfo *root,
extra.sjinfo = sjinfo;
extra.param_source_rels = NULL;
/*
* See if the inner relation is provably unique for this outer rel.
*
* We have some special cases: for JOIN_SEMI and JOIN_ANTI, it doesn't
* matter since the executor can make the equivalent optimization anyway;
* we need not expend planner cycles on proofs. For JOIN_UNIQUE_INNER, we
* know we're going to force uniqueness of the innerrel below. For
* JOIN_UNIQUE_OUTER, pass JOIN_INNER to avoid letting that value escape
* this module.
*/
switch (jointype)
{
case JOIN_SEMI:
case JOIN_ANTI:
extra.inner_unique = false; /* well, unproven */
break;
case JOIN_UNIQUE_INNER:
extra.inner_unique = true;
break;
case JOIN_UNIQUE_OUTER:
extra.inner_unique = innerrel_is_unique(root, outerrel, innerrel,
JOIN_INNER, restrictlist);
break;
default:
extra.inner_unique = innerrel_is_unique(root, outerrel, innerrel,
jointype, restrictlist);
break;
}
/*
* Find potential mergejoin clauses. We can skip this if we are not
* interested in doing a mergejoin. However, mergejoin may be our only
@ -136,10 +166,10 @@ add_paths_to_joinrel(PlannerInfo *root,
&mergejoin_allowed);
/*
* If it's SEMI or ANTI join, compute correction factors for cost
* estimation. These will be the same for all paths.
* If it's SEMI, ANTI, or inner_unique join, compute correction factors
* for cost estimation. These will be the same for all paths.
*/
if (jointype == JOIN_SEMI || jointype == JOIN_ANTI)
if (jointype == JOIN_SEMI || jointype == JOIN_ANTI || extra.inner_unique)
compute_semi_anti_join_factors(root, outerrel, innerrel,
jointype, sjinfo, restrictlist,
&extra.semifactors);
@ -336,8 +366,7 @@ try_nestloop_path(PlannerInfo *root,
* methodology worthwhile.
*/
initial_cost_nestloop(root, &workspace, jointype,
outer_path, inner_path,
extra->sjinfo, &extra->semifactors);
outer_path, inner_path, extra);
if (add_path_precheck(joinrel,
workspace.startup_cost, workspace.total_cost,
@ -348,8 +377,7 @@ try_nestloop_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
&extra->semifactors,
extra,
outer_path,
inner_path,
extra->restrictlist,
@ -399,8 +427,7 @@ try_partial_nestloop_path(PlannerInfo *root,
* cost. Bail out right away if it looks terrible.
*/
initial_cost_nestloop(root, &workspace, jointype,
outer_path, inner_path,
extra->sjinfo, &extra->semifactors);
outer_path, inner_path, extra);
if (!add_partial_path_precheck(joinrel, workspace.total_cost, pathkeys))
return;
@ -410,8 +437,7 @@ try_partial_nestloop_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
&extra->semifactors,
extra,
outer_path,
inner_path,
extra->restrictlist,
@ -486,7 +512,7 @@ try_mergejoin_path(PlannerInfo *root,
initial_cost_mergejoin(root, &workspace, jointype, mergeclauses,
outer_path, inner_path,
outersortkeys, innersortkeys,
extra->sjinfo);
extra);
if (add_path_precheck(joinrel,
workspace.startup_cost, workspace.total_cost,
@ -497,7 +523,7 @@ try_mergejoin_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
extra,
outer_path,
inner_path,
extra->restrictlist,
@ -562,7 +588,7 @@ try_partial_mergejoin_path(PlannerInfo *root,
initial_cost_mergejoin(root, &workspace, jointype, mergeclauses,
outer_path, inner_path,
outersortkeys, innersortkeys,
extra->sjinfo);
extra);
if (!add_partial_path_precheck(joinrel, workspace.total_cost, pathkeys))
return;
@ -573,7 +599,7 @@ try_partial_mergejoin_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
extra,
outer_path,
inner_path,
extra->restrictlist,
@ -620,8 +646,7 @@ try_hashjoin_path(PlannerInfo *root,
* never have any output pathkeys, per comments in create_hashjoin_path.
*/
initial_cost_hashjoin(root, &workspace, jointype, hashclauses,
outer_path, inner_path,
extra->sjinfo, &extra->semifactors);
outer_path, inner_path, extra);
if (add_path_precheck(joinrel,
workspace.startup_cost, workspace.total_cost,
@ -632,8 +657,7 @@ try_hashjoin_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
&extra->semifactors,
extra,
outer_path,
inner_path,
extra->restrictlist,
@ -683,8 +707,7 @@ try_partial_hashjoin_path(PlannerInfo *root,
* cost. Bail out right away if it looks terrible.
*/
initial_cost_hashjoin(root, &workspace, jointype, hashclauses,
outer_path, inner_path,
extra->sjinfo, &extra->semifactors);
outer_path, inner_path, extra);
if (!add_partial_path_precheck(joinrel, workspace.total_cost, NIL))
return;
@ -694,8 +717,7 @@ try_partial_hashjoin_path(PlannerInfo *root,
joinrel,
jointype,
&workspace,
extra->sjinfo,
&extra->semifactors,
extra,
outer_path,
inner_path,
extra->restrictlist,

View File

@ -41,6 +41,11 @@ static bool rel_supports_distinctness(PlannerInfo *root, RelOptInfo *rel);
static bool rel_is_distinct_for(PlannerInfo *root, RelOptInfo *rel,
List *clause_list);
static Oid distinct_col_search(int colno, List *colnos, List *opids);
static bool is_innerrel_unique_for(PlannerInfo *root,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
JoinType jointype,
List *restrictlist);
/*
@ -845,3 +850,171 @@ distinct_col_search(int colno, List *colnos, List *opids)
}
return InvalidOid;
}
/*
* innerrel_is_unique
* Check if the innerrel provably contains at most one tuple matching any
* tuple from the outerrel, based on join clauses in the 'restrictlist'.
*
* The proof must be made based only on clauses that will be "joinquals"
* rather than "otherquals" at execution. For an inner join there's no
* difference; but if the join is outer, we must ignore pushed-down quals,
* as those will become "otherquals". Note that this means the answer might
* vary depending on whether IS_OUTER_JOIN(jointype); since we cache the
* answer without regard to that, callers must take care not to call this
* with jointypes that would be classified differently by IS_OUTER_JOIN().
*
* The actual proof is undertaken by is_innerrel_unique_for(); this function
* is a frontend that is mainly concerned with caching the answers.
*/
bool
innerrel_is_unique(PlannerInfo *root,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
JoinType jointype,
List *restrictlist)
{
MemoryContext old_context;
ListCell *lc;
/* Certainly can't prove uniqueness when there are no joinclauses */
if (restrictlist == NIL)
return false;
/*
* Make a quick check to eliminate cases in which we will surely be unable
* to prove uniqueness of the innerrel.
*/
if (!rel_supports_distinctness(root, innerrel))
return false;
/*
* Query the cache to see if we've managed to prove that innerrel is
* unique for any subset of this outerrel. We don't need an exact match,
* as extra outerrels can't make the innerrel any less unique (or more
* formally, the restrictlist for a join to a superset outerrel must be a
* superset of the conditions we successfully used before).
*/
foreach(lc, innerrel->unique_for_rels)
{
Relids unique_for_rels = (Relids) lfirst(lc);
if (bms_is_subset(unique_for_rels, outerrel->relids))
return true; /* Success! */
}
/*
* Conversely, we may have already determined that this outerrel, or some
* superset thereof, cannot prove this innerrel to be unique.
*/
foreach(lc, innerrel->non_unique_for_rels)
{
Relids unique_for_rels = (Relids) lfirst(lc);
if (bms_is_subset(outerrel->relids, unique_for_rels))
return false;
}
/* No cached information, so try to make the proof. */
if (is_innerrel_unique_for(root, outerrel, innerrel,
jointype, restrictlist))
{
/*
* Cache the positive result for future probes, being sure to keep it
* in the planner_cxt even if we are working in GEQO.
*
* Note: one might consider trying to isolate the minimal subset of
* the outerrels that proved the innerrel unique. But it's not worth
* the trouble, because the planner builds up joinrels incrementally
* and so we'll see the minimally sufficient outerrels before any
* supersets of them anyway.
*/
old_context = MemoryContextSwitchTo(root->planner_cxt);
innerrel->unique_for_rels = lappend(innerrel->unique_for_rels,
bms_copy(outerrel->relids));
MemoryContextSwitchTo(old_context);
return true; /* Success! */
}
else
{
/*
* None of the join conditions for outerrel proved innerrel unique, so
* we can safely reject this outerrel or any subset of it in future
* checks.
*
* However, in normal planning mode, caching this knowledge is totally
* pointless; it won't be queried again, because we build up joinrels
* from smaller to larger. It is useful in GEQO mode, where the
* knowledge can be carried across successive planning attempts; and
* it's likely to be useful when using join-search plugins, too. Hence
* cache only when join_search_private is non-NULL. (Yeah, that's a
* hack, but it seems reasonable.)
*/
if (root->join_search_private)
{
old_context = MemoryContextSwitchTo(root->planner_cxt);
innerrel->non_unique_for_rels =
lappend(innerrel->non_unique_for_rels,
bms_copy(outerrel->relids));
MemoryContextSwitchTo(old_context);
}
return false;
}
}
/*
* is_innerrel_unique_for
* Check if the innerrel provably contains at most one tuple matching any
* tuple from the outerrel, based on join clauses in the 'restrictlist'.
*/
static bool
is_innerrel_unique_for(PlannerInfo *root,
RelOptInfo *outerrel,
RelOptInfo *innerrel,
JoinType jointype,
List *restrictlist)
{
List *clause_list = NIL;
ListCell *lc;
/*
* Search for mergejoinable clauses that constrain the inner rel against
* the outer rel. If an operator is mergejoinable then it behaves like
* equality for some btree opclass, so it's what we want. The
* mergejoinability test also eliminates clauses containing volatile
* functions, which we couldn't depend on.
*/
foreach(lc, restrictlist)
{
RestrictInfo *restrictinfo = (RestrictInfo *) lfirst(lc);
/*
* As noted above, if it's a pushed-down clause and we're at an outer
* join, we can't use it.
*/
if (restrictinfo->is_pushed_down && IS_OUTER_JOIN(jointype))
continue;
/* Ignore if it's not a mergejoinable clause */
if (!restrictinfo->can_join ||
restrictinfo->mergeopfamilies == NIL)
continue; /* not mergejoinable */
/*
* Check if clause has the form "outer op inner" or "inner op outer",
* and if so mark which side is inner.
*/
if (!clause_sides_match_join(restrictinfo, outerrel->relids,
innerrel->relids))
continue; /* no good for these input relations */
/* OK, add to list */
clause_list = lappend(clause_list, restrictinfo);
}
/* Let rel_is_distinct_for() do the hard work */
return rel_is_distinct_for(root, innerrel, clause_list);
}

View File

@ -215,12 +215,12 @@ static BitmapOr *make_bitmap_or(List *bitmapplans);
static NestLoop *make_nestloop(List *tlist,
List *joinclauses, List *otherclauses, List *nestParams,
Plan *lefttree, Plan *righttree,
JoinType jointype);
JoinType jointype, bool inner_unique);
static HashJoin *make_hashjoin(List *tlist,
List *joinclauses, List *otherclauses,
List *hashclauses,
Plan *lefttree, Plan *righttree,
JoinType jointype);
JoinType jointype, bool inner_unique);
static Hash *make_hash(Plan *lefttree,
Oid skewTable,
AttrNumber skewColumn,
@ -235,7 +235,8 @@ static MergeJoin *make_mergejoin(List *tlist,
int *mergestrategies,
bool *mergenullsfirst,
Plan *lefttree, Plan *righttree,
JoinType jointype);
JoinType jointype, bool inner_unique,
bool skip_mark_restore);
static Sort *make_sort(Plan *lefttree, int numCols,
AttrNumber *sortColIdx, Oid *sortOperators,
Oid *collations, bool *nullsFirst);
@ -3714,7 +3715,8 @@ create_nestloop_plan(PlannerInfo *root,
nestParams,
outer_plan,
inner_plan,
best_path->jointype);
best_path->jointype,
best_path->inner_unique);
copy_generic_path_info(&join_plan->join.plan, &best_path->path);
@ -4016,7 +4018,9 @@ create_mergejoin_plan(PlannerInfo *root,
mergenullsfirst,
outer_plan,
inner_plan,
best_path->jpath.jointype);
best_path->jpath.jointype,
best_path->jpath.inner_unique,
best_path->skip_mark_restore);
/* Costs of sort and material steps are included in path cost already */
copy_generic_path_info(&join_plan->join.plan, &best_path->jpath.path);
@ -4156,7 +4160,8 @@ create_hashjoin_plan(PlannerInfo *root,
hashclauses,
outer_plan,
(Plan *) hash_plan,
best_path->jpath.jointype);
best_path->jpath.jointype,
best_path->jpath.inner_unique);
copy_generic_path_info(&join_plan->join.plan, &best_path->jpath.path);
@ -5349,7 +5354,8 @@ make_nestloop(List *tlist,
List *nestParams,
Plan *lefttree,
Plan *righttree,
JoinType jointype)
JoinType jointype,
bool inner_unique)
{
NestLoop *node = makeNode(NestLoop);
Plan *plan = &node->join.plan;
@ -5359,6 +5365,7 @@ make_nestloop(List *tlist,
plan->lefttree = lefttree;
plan->righttree = righttree;
node->join.jointype = jointype;
node->join.inner_unique = inner_unique;
node->join.joinqual = joinclauses;
node->nestParams = nestParams;
@ -5372,7 +5379,8 @@ make_hashjoin(List *tlist,
List *hashclauses,
Plan *lefttree,
Plan *righttree,
JoinType jointype)
JoinType jointype,
bool inner_unique)
{
HashJoin *node = makeNode(HashJoin);
Plan *plan = &node->join.plan;
@ -5383,6 +5391,7 @@ make_hashjoin(List *tlist,
plan->righttree = righttree;
node->hashclauses = hashclauses;
node->join.jointype = jointype;
node->join.inner_unique = inner_unique;
node->join.joinqual = joinclauses;
return node;
@ -5424,7 +5433,9 @@ make_mergejoin(List *tlist,
bool *mergenullsfirst,
Plan *lefttree,
Plan *righttree,
JoinType jointype)
JoinType jointype,
bool inner_unique,
bool skip_mark_restore)
{
MergeJoin *node = makeNode(MergeJoin);
Plan *plan = &node->join.plan;
@ -5433,12 +5444,14 @@ make_mergejoin(List *tlist,
plan->qual = otherclauses;
plan->lefttree = lefttree;
plan->righttree = righttree;
node->skip_mark_restore = skip_mark_restore;
node->mergeclauses = mergeclauses;
node->mergeFamilies = mergefamilies;
node->mergeCollations = mergecollations;
node->mergeStrategies = mergestrategies;
node->mergeNullsFirst = mergenullsfirst;
node->join.jointype = jointype;
node->join.inner_unique = inner_unique;
node->join.joinqual = joinclauses;
return node;

View File

@ -2049,8 +2049,7 @@ calc_non_nestloop_required_outer(Path *outer_path, Path *inner_path)
* 'joinrel' is the join relation.
* 'jointype' is the type of join required
* 'workspace' is the result from initial_cost_nestloop
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if jointype is SEMI or ANTI
* 'extra' contains various information about the join
* 'outer_path' is the outer path
* 'inner_path' is the inner path
* 'restrict_clauses' are the RestrictInfo nodes to apply at the join
@ -2064,8 +2063,7 @@ create_nestloop_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,
@ -2109,7 +2107,7 @@ create_nestloop_path(PlannerInfo *root,
joinrel,
outer_path,
inner_path,
sjinfo,
extra->sjinfo,
required_outer,
&restrict_clauses);
pathnode->path.parallel_aware = false;
@ -2119,11 +2117,12 @@ create_nestloop_path(PlannerInfo *root,
pathnode->path.parallel_workers = outer_path->parallel_workers;
pathnode->path.pathkeys = pathkeys;
pathnode->jointype = jointype;
pathnode->inner_unique = extra->inner_unique;
pathnode->outerjoinpath = outer_path;
pathnode->innerjoinpath = inner_path;
pathnode->joinrestrictinfo = restrict_clauses;
final_cost_nestloop(root, pathnode, workspace, sjinfo, semifactors);
final_cost_nestloop(root, pathnode, workspace, extra);
return pathnode;
}
@ -2136,7 +2135,7 @@ create_nestloop_path(PlannerInfo *root,
* 'joinrel' is the join relation
* 'jointype' is the type of join required
* 'workspace' is the result from initial_cost_mergejoin
* 'sjinfo' is extra info about the join for selectivity estimation
* 'extra' contains various information about the join
* 'outer_path' is the outer path
* 'inner_path' is the inner path
* 'restrict_clauses' are the RestrictInfo nodes to apply at the join
@ -2152,7 +2151,7 @@ create_mergejoin_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,
@ -2172,7 +2171,7 @@ create_mergejoin_path(PlannerInfo *root,
joinrel,
outer_path,
inner_path,
sjinfo,
extra->sjinfo,
required_outer,
&restrict_clauses);
pathnode->jpath.path.parallel_aware = false;
@ -2182,15 +2181,17 @@ create_mergejoin_path(PlannerInfo *root,
pathnode->jpath.path.parallel_workers = outer_path->parallel_workers;
pathnode->jpath.path.pathkeys = pathkeys;
pathnode->jpath.jointype = jointype;
pathnode->jpath.inner_unique = extra->inner_unique;
pathnode->jpath.outerjoinpath = outer_path;
pathnode->jpath.innerjoinpath = inner_path;
pathnode->jpath.joinrestrictinfo = restrict_clauses;
pathnode->path_mergeclauses = mergeclauses;
pathnode->outersortkeys = outersortkeys;
pathnode->innersortkeys = innersortkeys;
/* pathnode->skip_mark_restore will be set by final_cost_mergejoin */
/* pathnode->materialize_inner will be set by final_cost_mergejoin */
final_cost_mergejoin(root, pathnode, workspace, sjinfo);
final_cost_mergejoin(root, pathnode, workspace, extra);
return pathnode;
}
@ -2202,8 +2203,7 @@ create_mergejoin_path(PlannerInfo *root,
* 'joinrel' is the join relation
* 'jointype' is the type of join required
* 'workspace' is the result from initial_cost_hashjoin
* 'sjinfo' is extra info about the join for selectivity estimation
* 'semifactors' contains valid data if jointype is SEMI or ANTI
* 'extra' contains various information about the join
* 'outer_path' is the cheapest outer path
* 'inner_path' is the cheapest inner path
* 'restrict_clauses' are the RestrictInfo nodes to apply at the join
@ -2216,8 +2216,7 @@ create_hashjoin_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,
@ -2234,7 +2233,7 @@ create_hashjoin_path(PlannerInfo *root,
joinrel,
outer_path,
inner_path,
sjinfo,
extra->sjinfo,
required_outer,
&restrict_clauses);
pathnode->jpath.path.parallel_aware = false;
@ -2256,13 +2255,14 @@ create_hashjoin_path(PlannerInfo *root,
*/
pathnode->jpath.path.pathkeys = NIL;
pathnode->jpath.jointype = jointype;
pathnode->jpath.inner_unique = extra->inner_unique;
pathnode->jpath.outerjoinpath = outer_path;
pathnode->jpath.innerjoinpath = inner_path;
pathnode->jpath.joinrestrictinfo = restrict_clauses;
pathnode->path_hashclauses = hashclauses;
/* final_cost_hashjoin will fill in pathnode->num_batches */
final_cost_hashjoin(root, pathnode, workspace, sjinfo, semifactors);
final_cost_hashjoin(root, pathnode, workspace, extra);
return pathnode;
}

View File

@ -126,6 +126,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
rel->lateral_vars = NIL;
rel->lateral_referencers = NULL;
rel->indexlist = NIL;
rel->statlist = NIL;
rel->pages = 0;
rel->tuples = 0;
rel->allvisfrac = 0;
@ -137,6 +138,8 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
rel->useridiscurrent = false;
rel->fdwroutine = NULL;
rel->fdw_private = NULL;
rel->unique_for_rels = NIL;
rel->non_unique_for_rels = NIL;
rel->baserestrictinfo = NIL;
rel->baserestrictcost.startup = 0;
rel->baserestrictcost.per_tuple = 0;
@ -147,7 +150,7 @@ build_simple_rel(PlannerInfo *root, int relid, RelOptInfo *parent)
/*
* Pass top parent's relids down the inheritance hierarchy. If the parent
* has top_parent_relids set, it's a direct or an indirect child of the top
* parent indicated by top_parent_relids. By extention this child is also
* parent indicated by top_parent_relids. By extension this child is also
* an indirect child of that parent.
*/
if (parent)
@ -503,6 +506,7 @@ build_join_rel(PlannerInfo *root,
joinrel->lateral_vars = NIL;
joinrel->lateral_referencers = NULL;
joinrel->indexlist = NIL;
joinrel->statlist = NIL;
joinrel->pages = 0;
joinrel->tuples = 0;
joinrel->allvisfrac = 0;
@ -514,6 +518,8 @@ build_join_rel(PlannerInfo *root,
joinrel->useridiscurrent = false;
joinrel->fdwroutine = NULL;
joinrel->fdw_private = NULL;
joinrel->unique_for_rels = NIL;
joinrel->non_unique_for_rels = NIL;
joinrel->baserestrictinfo = NIL;
joinrel->baserestrictcost.startup = 0;
joinrel->baserestrictcost.per_tuple = 0;

View File

@ -1536,6 +1536,8 @@ typedef struct JoinState
{
PlanState ps;
JoinType jointype;
bool single_match; /* True if we should skip to next outer tuple
* after finding one inner match */
ExprState *joinqual; /* JOIN quals (in addition to ps.qual) */
} JoinState;
@ -1561,6 +1563,7 @@ typedef struct NestLoopState
* NumClauses number of mergejoinable join clauses
* Clauses info for each mergejoinable clause
* JoinState current state of ExecMergeJoin state machine
* SkipMarkRestore true if we may skip Mark and Restore operations
* ExtraMarks true to issue extra Mark operations on inner scan
* ConstFalseJoin true if we have a constant-false joinqual
* FillOuter true if should emit unjoined outer tuples anyway
@ -1585,6 +1588,7 @@ typedef struct MergeJoinState
int mj_NumClauses;
MergeJoinClause mj_Clauses; /* array of length mj_NumClauses */
int mj_JoinState;
bool mj_SkipMarkRestore;
bool mj_ExtraMarks;
bool mj_ConstFalseJoin;
bool mj_FillOuter;

View File

@ -632,6 +632,7 @@ typedef struct CustomScan
* Join node
*
* jointype: rule for joining tuples from left and right subtrees
* inner_unique each outer tuple can match to no more than one inner tuple
* joinqual: qual conditions that came from JOIN/ON or JOIN/USING
* (plan.qual contains conditions that came from WHERE)
*
@ -642,12 +643,18 @@ typedef struct CustomScan
* (But plan.qual is still applied before actually returning a tuple.)
* For an outer join, only joinquals are allowed to be used as the merge
* or hash condition of a merge or hash join.
*
* inner_unique is set if the joinquals are such that no more than one inner
* tuple could match any given outer tuple. This allows the executor to
* skip searching for additional matches. (This must be provable from just
* the joinquals, ignoring plan.qual, due to where the executor tests it.)
* ----------------
*/
typedef struct Join
{
Plan plan;
JoinType jointype;
bool inner_unique;
List *joinqual; /* JOIN quals (in addition to plan.qual) */
} Join;
@ -689,6 +696,7 @@ typedef struct NestLoopParam
typedef struct MergeJoin
{
Join join;
bool skip_mark_restore; /* Can we skip mark/restore calls? */
List *mergeclauses; /* mergeclauses as expression trees */
/* these are arrays, but have the same length as the mergeclauses list: */
Oid *mergeFamilies; /* per-clause OIDs of btree opfamilies */

View File

@ -442,6 +442,19 @@ typedef struct PlannerInfo
* fdwroutine - function hooks for FDW, if foreign table (else NULL)
* fdw_private - private state for FDW, if foreign table (else NULL)
*
* Two fields are used to cache knowledge acquired during the join search
* about whether this rel is provably unique when being joined to given other
* relation(s), ie, it can have at most one row matching any given row from
* that join relation. Currently we only attempt such proofs, and thus only
* populate these fields, for base rels; but someday they might be used for
* join rels too:
*
* unique_for_rels - list of Relid sets, each one being a set of other
* rels for which this one has been proven unique
* non_unique_for_rels - list of Relid sets, each one being a set of
* other rels for which we have tried and failed to prove
* this one unique
*
* The presence of the remaining fields depends on the restrictions
* and joins that the relation participates in:
*
@ -562,6 +575,10 @@ typedef struct RelOptInfo
struct FdwRoutine *fdwroutine;
void *fdw_private;
/* cache space for remembering if we have proven this relation unique */
List *unique_for_rels; /* known unique for these other relid set(s) */
List *non_unique_for_rels; /* known not unique for these set(s) */
/* used by various scans and joins: */
List *baserestrictinfo; /* RestrictInfo structures (if base
* rel) */
@ -572,8 +589,8 @@ typedef struct RelOptInfo
* involving this rel */
bool has_eclass_joins; /* T means joininfo is incomplete */
/* used by "other" relations. */
Relids top_parent_relids; /* Relids of topmost parents. */
/* used by "other" relations */
Relids top_parent_relids; /* Relids of topmost parents */
} RelOptInfo;
/*
@ -1272,6 +1289,9 @@ typedef struct JoinPath
JoinType jointype;
bool inner_unique; /* each outer tuple provably matches no more
* than one inner tuple */
Path *outerjoinpath; /* path for the outer side of the join */
Path *innerjoinpath; /* path for the inner side of the join */
@ -1314,6 +1334,13 @@ typedef JoinPath NestPath;
* mergejoin. If it is not NIL then it is a PathKeys list describing
* the ordering that must be created by an explicit Sort node.
*
* skip_mark_restore is TRUE if the executor need not do mark/restore calls.
* Mark/restore overhead is usually required, but can be skipped if we know
* that the executor need find only one match per outer tuple, and that the
* mergeclauses are sufficient to identify a match. In such cases the
* executor can immediately advance the outer relation after processing a
* match, and therefoere it need never back up the inner relation.
*
* materialize_inner is TRUE if a Material node should be placed atop the
* inner input. This may appear with or without an inner Sort step.
*/
@ -1324,6 +1351,7 @@ typedef struct MergePath
List *path_mergeclauses; /* join clauses to be used for merge */
List *outersortkeys; /* keys for explicit sort, if any */
List *innersortkeys; /* keys for explicit sort, if any */
bool skip_mark_restore; /* can executor skip mark/restore? */
bool materialize_inner; /* add Materialize to inner? */
} MergePath;
@ -2112,8 +2140,8 @@ typedef struct PlannerParamItem
} PlannerParamItem;
/*
* When making cost estimates for a SEMI or ANTI join, there are some
* correction factors that are needed in both nestloop and hash joins
* When making cost estimates for a SEMI/ANTI/inner_unique join, there are
* some correction factors that are needed in both nestloop and hash joins
* to account for the fact that the executor can stop scanning inner rows
* as soon as it finds a match to the current outer row. These numbers
* depend only on the selected outer and inner join relations, not on the
@ -2140,14 +2168,17 @@ typedef struct SemiAntiJoinFactors
* clauses that apply to this join
* mergeclause_list is a list of RestrictInfo nodes for available
* mergejoin clauses in this join
* inner_unique is true if each outer tuple provably matches no more
* than one inner tuple
* sjinfo is extra info about special joins for selectivity estimation
* semifactors is as shown above (only valid for SEMI or ANTI joins)
* semifactors is as shown above (only valid for SEMI/ANTI/inner_unique joins)
* param_source_rels are OK targets for parameterization of result paths
*/
typedef struct JoinPathExtraData
{
List *restrictlist;
List *mergeclause_list;
bool inner_unique;
SpecialJoinInfo *sjinfo;
SemiAntiJoinFactors semifactors;
Relids param_source_rels;

View File

@ -129,33 +129,29 @@ extern void initial_cost_nestloop(PlannerInfo *root,
JoinCostWorkspace *workspace,
JoinType jointype,
Path *outer_path, Path *inner_path,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors);
JoinPathExtraData *extra);
extern void final_cost_nestloop(PlannerInfo *root, NestPath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors);
JoinPathExtraData *extra);
extern void initial_cost_mergejoin(PlannerInfo *root,
JoinCostWorkspace *workspace,
JoinType jointype,
List *mergeclauses,
Path *outer_path, Path *inner_path,
List *outersortkeys, List *innersortkeys,
SpecialJoinInfo *sjinfo);
JoinPathExtraData *extra);
extern void final_cost_mergejoin(PlannerInfo *root, MergePath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo);
JoinPathExtraData *extra);
extern void initial_cost_hashjoin(PlannerInfo *root,
JoinCostWorkspace *workspace,
JoinType jointype,
List *hashclauses,
Path *outer_path, Path *inner_path,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors);
JoinPathExtraData *extra);
extern void final_cost_hashjoin(PlannerInfo *root, HashPath *path,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors);
JoinPathExtraData *extra);
extern void cost_gather(GatherPath *path, PlannerInfo *root,
RelOptInfo *baserel, ParamPathInfo *param_info, double *rows);
extern void cost_subplan(PlannerInfo *root, SubPlan *subplan, Plan *plan);

View File

@ -119,8 +119,7 @@ extern NestPath *create_nestloop_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,
@ -131,7 +130,7 @@ extern MergePath *create_mergejoin_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,
@ -145,8 +144,7 @@ extern HashPath *create_hashjoin_path(PlannerInfo *root,
RelOptInfo *joinrel,
JoinType jointype,
JoinCostWorkspace *workspace,
SpecialJoinInfo *sjinfo,
SemiAntiJoinFactors *semifactors,
JoinPathExtraData *extra,
Path *outer_path,
Path *inner_path,
List *restrict_clauses,

View File

@ -105,6 +105,9 @@ extern void match_foreign_keys_to_quals(PlannerInfo *root);
extern List *remove_useless_joins(PlannerInfo *root, List *joinlist);
extern bool query_supports_distinctness(Query *query);
extern bool query_is_distinct_for(Query *query, List *colnos, List *opids);
extern bool innerrel_is_unique(PlannerInfo *root,
RelOptInfo *outerrel, RelOptInfo *innerrel,
JoinType jointype, List *restrictlist);
/*
* prototypes for plan/setrefs.c

View File

@ -982,29 +982,31 @@ explain (costs off) select a,c from t1 group by a,c,d;
explain (costs off) select *
from t1 inner join t2 on t1.a = t2.x and t1.b = t2.y
group by t1.a,t1.b,t1.c,t1.d,t2.x,t2.y,t2.z;
QUERY PLAN
-------------------------------------------------------
Group
QUERY PLAN
------------------------------------------------------
HashAggregate
Group Key: t1.a, t1.b, t2.x, t2.y
-> Merge Join
Merge Cond: ((t1.a = t2.x) AND (t1.b = t2.y))
-> Index Scan using t1_pkey on t1
-> Index Scan using t2_pkey on t2
(6 rows)
-> Hash Join
Hash Cond: ((t2.x = t1.a) AND (t2.y = t1.b))
-> Seq Scan on t2
-> Hash
-> Seq Scan on t1
(7 rows)
-- Test case where t1 can be optimized but not t2
explain (costs off) select t1.*,t2.x,t2.z
from t1 inner join t2 on t1.a = t2.x and t1.b = t2.y
group by t1.a,t1.b,t1.c,t1.d,t2.x,t2.z;
QUERY PLAN
-------------------------------------------------------
QUERY PLAN
------------------------------------------------------
HashAggregate
Group Key: t1.a, t1.b, t2.x, t2.z
-> Merge Join
Merge Cond: ((t1.a = t2.x) AND (t1.b = t2.y))
-> Index Scan using t1_pkey on t1
-> Index Scan using t2_pkey on t2
(6 rows)
-> Hash Join
Hash Cond: ((t2.x = t1.a) AND (t2.y = t1.b))
-> Seq Scan on t2
-> Hash
-> Seq Scan on t1
(7 rows)
-- Cannot optimize when PK is deferrable
explain (costs off) select * from t3 group by a,b,c;

View File

@ -317,12 +317,11 @@ explain (costs off)
-> Index Scan using ec1_expr2 on ec1 ec1_1
-> Index Scan using ec1_expr3 on ec1 ec1_2
-> Index Scan using ec1_expr4 on ec1 ec1_3
-> Materialize
-> Sort
Sort Key: ec1.f1 USING <
-> Index Scan using ec1_pkey on ec1
Index Cond: (ff = '42'::bigint)
(20 rows)
-> Sort
Sort Key: ec1.f1 USING <
-> Index Scan using ec1_pkey on ec1
Index Cond: (ff = '42'::bigint)
(19 rows)
-- check partially indexed scan
set enable_nestloop = on;
@ -374,12 +373,11 @@ explain (costs off)
Sort Key: (((ec1_2.ff + 3) + 1))
-> Seq Scan on ec1 ec1_2
-> Index Scan using ec1_expr4 on ec1 ec1_3
-> Materialize
-> Sort
Sort Key: ec1.f1 USING <
-> Index Scan using ec1_pkey on ec1
Index Cond: (ff = '42'::bigint)
(14 rows)
-> Sort
Sort Key: ec1.f1 USING <
-> Index Scan using ec1_pkey on ec1
Index Cond: (ff = '42'::bigint)
(13 rows)
-- check effects of row-level security
set enable_nestloop = on;

View File

@ -3979,7 +3979,7 @@ select id from a where id in (
);
QUERY PLAN
----------------------------
Hash Semi Join
Hash Join
Hash Cond: (a.id = b.id)
-> Seq Scan on a
-> Hash
@ -5327,3 +5327,310 @@ ERROR: invalid reference to FROM-clause entry for table "xx1"
LINE 1: ...xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
^
HINT: There is an entry for table "xx1", but it cannot be referenced from this part of the query.
--
-- test planner's ability to mark joins as unique
--
create table j1 (id int primary key);
create table j2 (id int primary key);
create table j3 (id int);
insert into j1 values(1),(2),(3);
insert into j2 values(1),(2),(3);
insert into j3 values(1),(1);
analyze j1;
analyze j2;
analyze j3;
-- ensure join is properly marked as unique
explain (verbose, costs off)
select * from j1 inner join j2 on j1.id = j2.id;
QUERY PLAN
-----------------------------------
Hash Join
Output: j1.id, j2.id
Inner Unique: true
Hash Cond: (j1.id = j2.id)
-> Seq Scan on public.j1
Output: j1.id
-> Hash
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(10 rows)
-- ensure join is not unique when not an equi-join
explain (verbose, costs off)
select * from j1 inner join j2 on j1.id > j2.id;
QUERY PLAN
-----------------------------------
Nested Loop
Output: j1.id, j2.id
Join Filter: (j1.id > j2.id)
-> Seq Scan on public.j1
Output: j1.id
-> Materialize
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(9 rows)
-- ensure non-unique rel is not chosen as inner
explain (verbose, costs off)
select * from j1 inner join j3 on j1.id = j3.id;
QUERY PLAN
-----------------------------------
Hash Join
Output: j1.id, j3.id
Inner Unique: true
Hash Cond: (j3.id = j1.id)
-> Seq Scan on public.j3
Output: j3.id
-> Hash
Output: j1.id
-> Seq Scan on public.j1
Output: j1.id
(10 rows)
-- ensure left join is marked as unique
explain (verbose, costs off)
select * from j1 left join j2 on j1.id = j2.id;
QUERY PLAN
-----------------------------------
Hash Left Join
Output: j1.id, j2.id
Inner Unique: true
Hash Cond: (j1.id = j2.id)
-> Seq Scan on public.j1
Output: j1.id
-> Hash
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(10 rows)
-- ensure right join is marked as unique
explain (verbose, costs off)
select * from j1 right join j2 on j1.id = j2.id;
QUERY PLAN
-----------------------------------
Hash Left Join
Output: j1.id, j2.id
Inner Unique: true
Hash Cond: (j2.id = j1.id)
-> Seq Scan on public.j2
Output: j2.id
-> Hash
Output: j1.id
-> Seq Scan on public.j1
Output: j1.id
(10 rows)
-- ensure full join is marked as unique
explain (verbose, costs off)
select * from j1 full join j2 on j1.id = j2.id;
QUERY PLAN
-----------------------------------
Hash Full Join
Output: j1.id, j2.id
Inner Unique: true
Hash Cond: (j1.id = j2.id)
-> Seq Scan on public.j1
Output: j1.id
-> Hash
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(10 rows)
-- a clauseless (cross) join can't be unique
explain (verbose, costs off)
select * from j1 cross join j2;
QUERY PLAN
-----------------------------------
Nested Loop
Output: j1.id, j2.id
-> Seq Scan on public.j1
Output: j1.id
-> Materialize
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(8 rows)
-- ensure a natural join is marked as unique
explain (verbose, costs off)
select * from j1 natural join j2;
QUERY PLAN
-----------------------------------
Hash Join
Output: j1.id
Inner Unique: true
Hash Cond: (j1.id = j2.id)
-> Seq Scan on public.j1
Output: j1.id
-> Hash
Output: j2.id
-> Seq Scan on public.j2
Output: j2.id
(10 rows)
-- ensure a distinct clause allows the inner to become unique
explain (verbose, costs off)
select * from j1
inner join (select distinct id from j3) j3 on j1.id = j3.id;
QUERY PLAN
-----------------------------------------------
Nested Loop
Output: j1.id, j3.id
Inner Unique: true
Join Filter: (j1.id = j3.id)
-> Seq Scan on public.j1
Output: j1.id
-> Materialize
Output: j3.id
-> Unique
Output: j3.id
-> Sort
Output: j3.id
Sort Key: j3.id
-> Seq Scan on public.j3
Output: j3.id
(15 rows)
-- ensure group by clause allows the inner to become unique
explain (verbose, costs off)
select * from j1
inner join (select id from j3 group by id) j3 on j1.id = j3.id;
QUERY PLAN
-----------------------------------------------
Nested Loop
Output: j1.id, j3.id
Inner Unique: true
Join Filter: (j1.id = j3.id)
-> Seq Scan on public.j1
Output: j1.id
-> Materialize
Output: j3.id
-> Group
Output: j3.id
Group Key: j3.id
-> Sort
Output: j3.id
Sort Key: j3.id
-> Seq Scan on public.j3
Output: j3.id
(16 rows)
drop table j1;
drop table j2;
drop table j3;
-- test more complex permutations of unique joins
create table j1 (id1 int, id2 int, primary key(id1,id2));
create table j2 (id1 int, id2 int, primary key(id1,id2));
create table j3 (id1 int, id2 int, primary key(id1,id2));
insert into j1 values(1,1),(1,2);
insert into j2 values(1,1);
insert into j3 values(1,1);
analyze j1;
analyze j2;
analyze j3;
-- ensure there's no unique join when not all columns which are part of the
-- unique index are seen in the join clause
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1;
QUERY PLAN
------------------------------------------
Nested Loop
Output: j1.id1, j1.id2, j2.id1, j2.id2
Join Filter: (j1.id1 = j2.id1)
-> Seq Scan on public.j2
Output: j2.id1, j2.id2
-> Seq Scan on public.j1
Output: j1.id1, j1.id2
(7 rows)
-- ensure proper unique detection with multiple join quals
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2;
QUERY PLAN
----------------------------------------------------------
Nested Loop
Output: j1.id1, j1.id2, j2.id1, j2.id2
Inner Unique: true
Join Filter: ((j1.id1 = j2.id1) AND (j1.id2 = j2.id2))
-> Seq Scan on public.j1
Output: j1.id1, j1.id2
-> Materialize
Output: j2.id1, j2.id2
-> Seq Scan on public.j2
Output: j2.id1, j2.id2
(10 rows)
-- ensure we don't detect the join to be unique when quals are not part of the
-- join condition
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1 where j1.id2 = 1;
QUERY PLAN
------------------------------------------
Nested Loop
Output: j1.id1, j1.id2, j2.id1, j2.id2
Join Filter: (j1.id1 = j2.id1)
-> Seq Scan on public.j1
Output: j1.id1, j1.id2
Filter: (j1.id2 = 1)
-> Seq Scan on public.j2
Output: j2.id1, j2.id2
(8 rows)
-- as above, but for left joins.
explain (verbose, costs off)
select * from j1
left join j2 on j1.id1 = j2.id1 where j1.id2 = 1;
QUERY PLAN
------------------------------------------
Nested Loop Left Join
Output: j1.id1, j1.id2, j2.id1, j2.id2
Join Filter: (j1.id1 = j2.id1)
-> Seq Scan on public.j1
Output: j1.id1, j1.id2
Filter: (j1.id2 = 1)
-> Seq Scan on public.j2
Output: j2.id1, j2.id2
(8 rows)
-- validate logic in merge joins which skips mark and restore.
-- it should only do this if all quals which were used to detect the unique
-- are present as join quals, and not plain quals.
set enable_nestloop to 0;
set enable_hashjoin to 0;
set enable_sort to 0;
-- create an index that will be preferred over the PK to perform the join
create index j1_id1_idx on j1 (id1) where id1 % 1000 = 1;
explain (costs off) select * from j1 j1
inner join j1 j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2
where j1.id1 % 1000 = 1 and j2.id1 % 1000 = 1;
QUERY PLAN
--------------------------------------------
Merge Join
Merge Cond: (j1.id1 = j2.id1)
Join Filter: (j1.id2 = j2.id2)
-> Index Scan using j1_id1_idx on j1
-> Index Scan using j1_id1_idx on j1 j2
(5 rows)
select * from j1 j1
inner join j1 j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2
where j1.id1 % 1000 = 1 and j2.id1 % 1000 = 1;
id1 | id2 | id1 | id2
-----+-----+-----+-----
1 | 1 | 1 | 1
1 | 2 | 1 | 2
(2 rows)
reset enable_nestloop;
reset enable_hashjoin;
reset enable_sort;
drop table j1;
drop table j2;
drop table j3;

View File

@ -1732,3 +1732,127 @@ update xx1 set x2 = f1 from xx1, lateral (select * from int4_tbl where f1 = x1)
delete from xx1 using (select * from int4_tbl where f1 = x1) ss;
delete from xx1 using (select * from int4_tbl where f1 = xx1.x1) ss;
delete from xx1 using lateral (select * from int4_tbl where f1 = x1) ss;
--
-- test planner's ability to mark joins as unique
--
create table j1 (id int primary key);
create table j2 (id int primary key);
create table j3 (id int);
insert into j1 values(1),(2),(3);
insert into j2 values(1),(2),(3);
insert into j3 values(1),(1);
analyze j1;
analyze j2;
analyze j3;
-- ensure join is properly marked as unique
explain (verbose, costs off)
select * from j1 inner join j2 on j1.id = j2.id;
-- ensure join is not unique when not an equi-join
explain (verbose, costs off)
select * from j1 inner join j2 on j1.id > j2.id;
-- ensure non-unique rel is not chosen as inner
explain (verbose, costs off)
select * from j1 inner join j3 on j1.id = j3.id;
-- ensure left join is marked as unique
explain (verbose, costs off)
select * from j1 left join j2 on j1.id = j2.id;
-- ensure right join is marked as unique
explain (verbose, costs off)
select * from j1 right join j2 on j1.id = j2.id;
-- ensure full join is marked as unique
explain (verbose, costs off)
select * from j1 full join j2 on j1.id = j2.id;
-- a clauseless (cross) join can't be unique
explain (verbose, costs off)
select * from j1 cross join j2;
-- ensure a natural join is marked as unique
explain (verbose, costs off)
select * from j1 natural join j2;
-- ensure a distinct clause allows the inner to become unique
explain (verbose, costs off)
select * from j1
inner join (select distinct id from j3) j3 on j1.id = j3.id;
-- ensure group by clause allows the inner to become unique
explain (verbose, costs off)
select * from j1
inner join (select id from j3 group by id) j3 on j1.id = j3.id;
drop table j1;
drop table j2;
drop table j3;
-- test more complex permutations of unique joins
create table j1 (id1 int, id2 int, primary key(id1,id2));
create table j2 (id1 int, id2 int, primary key(id1,id2));
create table j3 (id1 int, id2 int, primary key(id1,id2));
insert into j1 values(1,1),(1,2);
insert into j2 values(1,1);
insert into j3 values(1,1);
analyze j1;
analyze j2;
analyze j3;
-- ensure there's no unique join when not all columns which are part of the
-- unique index are seen in the join clause
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1;
-- ensure proper unique detection with multiple join quals
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2;
-- ensure we don't detect the join to be unique when quals are not part of the
-- join condition
explain (verbose, costs off)
select * from j1
inner join j2 on j1.id1 = j2.id1 where j1.id2 = 1;
-- as above, but for left joins.
explain (verbose, costs off)
select * from j1
left join j2 on j1.id1 = j2.id1 where j1.id2 = 1;
-- validate logic in merge joins which skips mark and restore.
-- it should only do this if all quals which were used to detect the unique
-- are present as join quals, and not plain quals.
set enable_nestloop to 0;
set enable_hashjoin to 0;
set enable_sort to 0;
-- create an index that will be preferred over the PK to perform the join
create index j1_id1_idx on j1 (id1) where id1 % 1000 = 1;
explain (costs off) select * from j1 j1
inner join j1 j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2
where j1.id1 % 1000 = 1 and j2.id1 % 1000 = 1;
select * from j1 j1
inner join j1 j2 on j1.id1 = j2.id1 and j1.id2 = j2.id2
where j1.id1 % 1000 = 1 and j2.id1 % 1000 = 1;
reset enable_nestloop;
reset enable_hashjoin;
reset enable_sort;
drop table j1;
drop table j2;
drop table j3;