Commit c64de21e authored by Tom Lane's avatar Tom Lane

Fix qual-clause-misplacement issues with pulled-up LATERAL subqueries.

In an example such as
SELECT * FROM
  i LEFT JOIN LATERAL (SELECT * FROM j WHERE i.n = j.n) j ON true;
it is safe to pull up the LATERAL subquery into its parent, but we must
then treat the "i.n = j.n" clause as a qual clause of the LEFT JOIN.  The
previous coding in deconstruct_recurse mistakenly labeled the clause as
"is_pushed_down", resulting in wrong semantics if the clause were applied
at the join node, as per an example submitted awhile ago by Jeremy Evans.
To fix, postpone processing of such clauses until we return back up to
the appropriate recursion depth in deconstruct_recurse.

In addition, tighten the is-safe-to-pull-up checks in is_simple_subquery;
we previously missed the possibility that the LATERAL subquery might itself
contain an outer join that makes lateral references in lower quals unsafe.

A regression test case equivalent to Jeremy's example was already in my
commit of yesterday, but was giving the wrong results because of this
bug.  This patch fixes the expected output for that, and also adds a
test case for the second problem.
parent 78e12201
......@@ -803,11 +803,10 @@ still expected to enforce any join clauses that can be pushed down to it,
so that all paths of the same parameterization have the same rowcount.
We also allow LATERAL subqueries to be flattened (pulled up into the parent
query) by the optimizer, but only when they don't contain any lateral
references to relations outside the lowest outer join that can null the
LATERAL subquery. This restriction prevents lateral references from being
introduced into outer-join qualifications, which would create semantic
confusion. Note that even with this restriction, pullup of a LATERAL
query) by the optimizer, but only when this does not introduce lateral
references into JOIN/ON quals that would refer to relations outside the
lowest outer join at/above that qual. The semantics of such a qual would
be unclear. Note that even with this restriction, pullup of a LATERAL
subquery can result in creating PlaceHolderVars that contain lateral
references to relations outside their syntactic scope. We still evaluate
such PHVs at their syntactic location or lower, but the presence of such a
......
This diff is collapsed.
......@@ -84,6 +84,8 @@ static bool is_simple_union_all(Query *subquery);
static bool is_simple_union_all_recurse(Node *setOp, Query *setOpQuery,
List *colTypes);
static bool is_safe_append_member(Query *subquery);
static bool jointree_contains_lateral_outer_refs(Node *jtnode, bool restricted,
Relids safe_upper_varnos);
static void replace_vars_in_jointree(Node *jtnode,
pullup_replace_vars_context *context,
JoinExpr *lowest_nulling_outer_join);
......@@ -1303,21 +1305,59 @@ is_simple_subquery(Query *subquery, RangeTblEntry *rte,
return false;
/*
* If the subquery is LATERAL, and we're below any outer join, and the
* subquery contains lateral references to rels outside the outer join,
* don't pull up. Doing so would risk creating outer-join quals that
* contain references to rels outside the outer join, which is a semantic
* mess that doesn't seem worth addressing at the moment.
* If the subquery is LATERAL, check for pullup restrictions from that.
*/
if (rte->lateral && lowest_outer_join != NULL)
if (rte->lateral)
{
bool restricted;
Relids safe_upper_varnos;
/*
* The subquery's WHERE and JOIN/ON quals mustn't contain any lateral
* references to rels outside a higher outer join (including the case
* where the outer join is within the subquery itself). In such a
* case, pulling up would result in a situation where we need to
* postpone quals from below an outer join to above it, which is
* probably completely wrong and in any case is a complication that
* doesn't seem worth addressing at the moment.
*/
if (lowest_outer_join != NULL)
{
Relids lvarnos = pull_varnos_of_level((Node *) subquery, 1);
Relids jvarnos = get_relids_in_jointree((Node *) lowest_outer_join,
restricted = true;
safe_upper_varnos = get_relids_in_jointree((Node *) lowest_outer_join,
true);
}
else
{
restricted = false;
safe_upper_varnos = NULL; /* doesn't matter */
}
if (jointree_contains_lateral_outer_refs((Node *) subquery->jointree,
restricted, safe_upper_varnos))
return false;
/*
* If there's an outer join above the LATERAL subquery, also disallow
* pullup if the subquery's targetlist has any references to rels
* outside the outer join, since these might get pulled into quals
* above the subquery (but in or below the outer join) and then lead
* to qual-postponement issues similar to the case checked for above.
* (We wouldn't need to prevent pullup if no such references appear in
* outer-query quals, but we don't have enough info here to check
* that. Also, maybe this restriction could be removed if we forced
* such refs to be wrapped in PlaceHolderVars, even when they're below
* the nearest outer join? But it's a pretty hokey usage, so not
* clear this is worth sweating over.)
*/
if (lowest_outer_join != NULL)
{
Relids lvarnos = pull_varnos_of_level((Node *) subquery->targetList, 1);
if (!bms_is_subset(lvarnos, jvarnos))
if (!bms_is_subset(lvarnos, safe_upper_varnos))
return false;
}
}
/*
* Don't pull up a subquery that has any set-returning functions in its
......@@ -1344,12 +1384,12 @@ is_simple_subquery(Query *subquery, RangeTblEntry *rte,
* correctly generate a Result plan for a jointree that's totally empty,
* but we can't cope with an empty FromExpr appearing lower down in a
* jointree: we identify join rels via baserelid sets, so we couldn't
* distinguish a join containing such a FromExpr from one without it.
* This would for example break the PlaceHolderVar mechanism, since we'd
* have no way to identify where to evaluate a PHV coming out of the
* subquery. Not worth working hard on this, just to collapse
* SubqueryScan/Result into Result; especially since the SubqueryScan can
* often be optimized away by setrefs.c anyway.
* distinguish a join containing such a FromExpr from one without it. This
* would for example break the PlaceHolderVar mechanism, since we'd have
* no way to identify where to evaluate a PHV coming out of the subquery.
* Not worth working hard on this, just to collapse SubqueryScan/Result
* into Result; especially since the SubqueryScan can often be optimized
* away by setrefs.c anyway.
*/
if (subquery->jointree->fromlist == NIL)
return false;
......@@ -1466,6 +1506,80 @@ is_safe_append_member(Query *subquery)
return true;
}
/*
* jointree_contains_lateral_outer_refs
* Check for disallowed lateral references in a jointree's quals
*
* If restricted is false, all level-1 Vars are allowed (but we still must
* search the jointree, since it might contain outer joins below which there
* will be restrictions). If restricted is true, return TRUE when any qual
* in the jointree contains level-1 Vars coming from outside the rels listed
* in safe_upper_varnos.
*/
static bool
jointree_contains_lateral_outer_refs(Node *jtnode, bool restricted,
Relids safe_upper_varnos)
{
if (jtnode == NULL)
return false;
if (IsA(jtnode, RangeTblRef))
return false;
else if (IsA(jtnode, FromExpr))
{
FromExpr *f = (FromExpr *) jtnode;
ListCell *l;
/* First, recurse to check child joins */
foreach(l, f->fromlist)
{
if (jointree_contains_lateral_outer_refs(lfirst(l),
restricted,
safe_upper_varnos))
return true;
}
/* Then check the top-level quals */
if (restricted &&
!bms_is_subset(pull_varnos_of_level(f->quals, 1),
safe_upper_varnos))
return true;
}
else if (IsA(jtnode, JoinExpr))
{
JoinExpr *j = (JoinExpr *) jtnode;
/*
* If this is an outer join, we mustn't allow any upper lateral
* references in or below it.
*/
if (j->jointype != JOIN_INNER)
{
restricted = true;
safe_upper_varnos = NULL;
}
/* Check the child joins */
if (jointree_contains_lateral_outer_refs(j->larg,
restricted,
safe_upper_varnos))
return true;
if (jointree_contains_lateral_outer_refs(j->rarg,
restricted,
safe_upper_varnos))
return true;
/* Check the JOIN's qual clauses */
if (restricted &&
!bms_is_subset(pull_varnos_of_level(j->quals, 1),
safe_upper_varnos))
return true;
}
else
elog(ERROR, "unrecognized node type: %d",
(int) nodeTag(jtnode));
return false;
}
/*
* Helper routine for pull_up_subqueries: do pullup_replace_vars on every
* expression in the jointree, without changing the jointree structure itself.
......
......@@ -3161,7 +3161,7 @@ explain (costs off)
Nested Loop Left Join
-> Seq Scan on int4_tbl x
-> Index Scan using tenk1_unique1 on tenk1
Index Cond: (unique1 = x.f1)
Index Cond: (x.f1 = unique1)
(4 rows)
-- check scoping of lateral versus parent references
......@@ -3648,12 +3648,12 @@ select * from int4_tbl i left join
lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
QUERY PLAN
-------------------------------------------
Nested Loop Left Join
Hash Left Join
Output: i.f1, j.f1
Filter: (i.f1 = j.f1)
Hash Cond: (i.f1 = j.f1)
-> Seq Scan on public.int4_tbl i
Output: i.f1
-> Materialize
-> Hash
Output: j.f1
-> Seq Scan on public.int2_tbl j
Output: j.f1
......@@ -3662,9 +3662,13 @@ select * from int4_tbl i left join
select * from int4_tbl i left join
lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
f1 | f1
----+----
-------------+----
0 | 0
(1 row)
123456 |
-123456 |
2147483647 |
-2147483647 |
(5 rows)
explain (verbose, costs off)
select * from int4_tbl i left join
......@@ -3691,6 +3695,62 @@ select * from int4_tbl i left join
-2147483647 |
(5 rows)
explain (verbose, costs off)
select * from int4_tbl a,
lateral (
select * from int4_tbl b left join int8_tbl c on (b.f1 = q1 and a.f1 = q2)
) ss;
QUERY PLAN
-------------------------------------------------
Nested Loop
Output: a.f1, b.f1, c.q1, c.q2
-> Seq Scan on public.int4_tbl a
Output: a.f1
-> Hash Left Join
Output: b.f1, c.q1, c.q2
Hash Cond: (b.f1 = c.q1)
-> Seq Scan on public.int4_tbl b
Output: b.f1
-> Hash
Output: c.q1, c.q2
-> Seq Scan on public.int8_tbl c
Output: c.q1, c.q2
Filter: (a.f1 = c.q2)
(14 rows)
select * from int4_tbl a,
lateral (
select * from int4_tbl b left join int8_tbl c on (b.f1 = q1 and a.f1 = q2)
) ss;
f1 | f1 | q1 | q2
-------------+-------------+----+----
0 | 0 | |
0 | 123456 | |
0 | -123456 | |
0 | 2147483647 | |
0 | -2147483647 | |
123456 | 0 | |
123456 | 123456 | |
123456 | -123456 | |
123456 | 2147483647 | |
123456 | -2147483647 | |
-123456 | 0 | |
-123456 | 123456 | |
-123456 | -123456 | |
-123456 | 2147483647 | |
-123456 | -2147483647 | |
2147483647 | 0 | |
2147483647 | 123456 | |
2147483647 | -123456 | |
2147483647 | 2147483647 | |
2147483647 | -2147483647 | |
-2147483647 | 0 | |
-2147483647 | 123456 | |
-2147483647 | -123456 | |
-2147483647 | 2147483647 | |
-2147483647 | -2147483647 | |
(25 rows)
-- lateral reference in a PlaceHolderVar evaluated at join level
explain (verbose, costs off)
select * from
......
......@@ -1022,6 +1022,15 @@ select * from int4_tbl i left join
lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
select * from int4_tbl i left join
lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
explain (verbose, costs off)
select * from int4_tbl a,
lateral (
select * from int4_tbl b left join int8_tbl c on (b.f1 = q1 and a.f1 = q2)
) ss;
select * from int4_tbl a,
lateral (
select * from int4_tbl b left join int8_tbl c on (b.f1 = q1 and a.f1 = q2)
) ss;
-- lateral reference in a PlaceHolderVar evaluated at join level
explain (verbose, costs off)
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment