1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-05 07:21:24 +03:00

Fix some planner issues with degenerate outer join clauses.

An outer join clause that didn't actually reference the RHS (perhaps only
after constant-folding) could confuse the join order enforcement logic,
leading to wrong query results.  Also, nested occurrences of such things
could trigger an Assertion that on reflection seems incorrect.

Per fuzz testing by Andreas Seltenreich.  The practical use of such cases
seems thin enough that it's not too surprising we've not heard field
reports about it.

This has been broken for a long time, so back-patch to all active branches.
This commit is contained in:
Tom Lane
2015-08-01 20:57:41 -04:00
parent dea1491ffb
commit f69b4b9495
4 changed files with 211 additions and 12 deletions

View File

@ -3293,6 +3293,135 @@ using (join_key);
1 | |
(2 rows)
--
-- test successful handling of nested outer joins with degenerate join quals
--
explain (verbose, costs off)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
QUERY PLAN
----------------------------------------------------------------------
Hash Left Join
Output: t1.f1
Hash Cond: (i8.q2 = i4.f1)
-> Nested Loop Left Join
Output: t1.f1, i8.q2
Join Filter: (t1.f1 = '***'::text)
-> Seq Scan on public.text_tbl t1
Output: t1.f1
-> Materialize
Output: i8.q2
-> Hash Right Join
Output: i8.q2
Hash Cond: ((NULL::integer) = i8b1.q2)
-> Hash Left Join
Output: i8.q2, (NULL::integer)
Hash Cond: (i8.q1 = i8b2.q1)
-> Seq Scan on public.int8_tbl i8
Output: i8.q1, i8.q2
-> Hash
Output: i8b2.q1, (NULL::integer)
-> Seq Scan on public.int8_tbl i8b2
Output: i8b2.q1, NULL::integer
-> Hash
Output: i8b1.q2
-> Seq Scan on public.int8_tbl i8b1
Output: i8b1.q2
-> Hash
Output: i4.f1
-> Seq Scan on public.int4_tbl i4
Output: i4.f1
(30 rows)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
f1
-------------------
doh!
hi de ho neighbor
(2 rows)
explain (verbose, costs off)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2, int4_tbl i4b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
QUERY PLAN
----------------------------------------------------------------------------
Hash Left Join
Output: t1.f1
Hash Cond: (i8.q2 = i4.f1)
-> Nested Loop Left Join
Output: i8.q2, t1.f1
Join Filter: (t1.f1 = '***'::text)
-> Seq Scan on public.text_tbl t1
Output: t1.f1
-> Materialize
Output: i8.q2
-> Hash Right Join
Output: i8.q2
Hash Cond: ((NULL::integer) = i8b1.q2)
-> Hash Right Join
Output: i8.q2, (NULL::integer)
Hash Cond: (i8b2.q1 = i8.q1)
-> Nested Loop
Output: i8b2.q1, NULL::integer
-> Seq Scan on public.int8_tbl i8b2
Output: i8b2.q1, i8b2.q2
-> Materialize
-> Seq Scan on public.int4_tbl i4b2
-> Hash
Output: i8.q1, i8.q2
-> Seq Scan on public.int8_tbl i8
Output: i8.q1, i8.q2
-> Hash
Output: i8b1.q2
-> Seq Scan on public.int8_tbl i8b1
Output: i8b1.q2
-> Hash
Output: i4.f1
-> Seq Scan on public.int4_tbl i4
Output: i4.f1
(34 rows)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2, int4_tbl i4b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
f1
-------------------
doh!
hi de ho neighbor
(2 rows)
--
-- test ability to push constants through outer join clauses
--

View File

@ -984,6 +984,56 @@ left join
) foo3
using (join_key);
--
-- test successful handling of nested outer joins with degenerate join quals
--
explain (verbose, costs off)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
explain (verbose, costs off)
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2, int4_tbl i4b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
select t1.* from
text_tbl t1
left join (select *, '***'::text as d1 from int8_tbl i8b1) b1
left join int8_tbl i8
left join (select *, null::int as d2 from int8_tbl i8b2, int4_tbl i4b2) b2
on (i8.q1 = b2.q1)
on (b2.d2 = b1.q2)
on (t1.f1 = b1.d1)
left join int4_tbl i4
on (i8.q2 = i4.f1);
--
-- test ability to push constants through outer join clauses
--