aboutsummaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorTom Lane <tgl@sss.pgh.pa.us>2016-04-21 20:05:58 -0400
committerTom Lane <tgl@sss.pgh.pa.us>2016-04-21 20:05:58 -0400
commit94c685a7cb58bad13cde78ce3c39206b460d5ae6 (patch)
tree50c3bd5ee88227566984dcd4e66960a42792216c
parentd2e59cbc35c5e8f23148287e50e77dc3ddde8e00 (diff)
downloadpostgresql-94c685a7cb58bad13cde78ce3c39206b460d5ae6.tar.gz
postgresql-94c685a7cb58bad13cde78ce3c39206b460d5ae6.zip
Fix planner failure with full join in RHS of left join.
Given a left join containing a full join in its righthand side, with the left join's joinclause referencing only one side of the full join (in a non-strict fashion, so that the full join doesn't get simplified), the planner could fail with "failed to build any N-way joins" or related errors. This happened because the full join was seen as overlapping the left join's RHS, and then recent changes within join_is_legal() caused that function to conclude that the full join couldn't validly be formed. Rather than try to rejigger join_is_legal() yet more to allow this, I think it's better to fix initsplan.c so that the required join order is explicit in the SpecialJoinInfo data structure. The previous coding there essentially ignored full joins, relying on the fact that we don't flatten them in the joinlist data structure to preserve their ordering. That's sufficient to prevent a wrong plan from being formed, but as this example shows, it's not sufficient to ensure that the right plan will be formed. We need to work a bit harder to ensure that the right plan looks sane according to the SpecialJoinInfos. Per bug #14105 from Vojtech Rylko. This was apparently induced by commit 8703059c6 (though now that I've seen it, I wonder whether there are related cases that could have failed before that); so back-patch to all active branches. Unfortunately, that patch also went into 9.0, so this bug is a regression that won't be fixed in that branch.
-rw-r--r--src/backend/optimizer/plan/initsplan.c25
-rw-r--r--src/test/regress/expected/join.out31
-rw-r--r--src/test/regress/sql/join.sql17
3 files changed, 72 insertions, 1 deletions
diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c
index f2dce6a2969..de292e7da4f 100644
--- a/src/backend/optimizer/plan/initsplan.c
+++ b/src/backend/optimizer/plan/initsplan.c
@@ -1156,9 +1156,32 @@ make_outerjoininfo(PlannerInfo *root,
{
SpecialJoinInfo *otherinfo = (SpecialJoinInfo *) lfirst(l);
- /* ignore full joins --- other mechanisms preserve their ordering */
+ /*
+ * A full join is an optimization barrier: we can't associate into or
+ * out of it. Hence, if it overlaps either LHS or RHS of the current
+ * rel, expand that side's min relset to cover the whole full join.
+ */
if (otherinfo->jointype == JOIN_FULL)
+ {
+ if (bms_overlap(left_rels, otherinfo->syn_lefthand) ||
+ bms_overlap(left_rels, otherinfo->syn_righthand))
+ {
+ min_lefthand = bms_add_members(min_lefthand,
+ otherinfo->syn_lefthand);
+ min_lefthand = bms_add_members(min_lefthand,
+ otherinfo->syn_righthand);
+ }
+ if (bms_overlap(right_rels, otherinfo->syn_lefthand) ||
+ bms_overlap(right_rels, otherinfo->syn_righthand))
+ {
+ min_righthand = bms_add_members(min_righthand,
+ otherinfo->syn_lefthand);
+ min_righthand = bms_add_members(min_righthand,
+ otherinfo->syn_righthand);
+ }
+ /* Needn't do anything else with the full join */
continue;
+ }
/*
* For a lower OJ in our LHS, if our join condition uses the lower
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index bade3923946..8676bc9f1d3 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -3802,6 +3802,37 @@ where ss1.c2 = 0;
(0 rows)
--
+-- test successful handling of full join underneath left join (bug #14105)
+--
+explain (costs off)
+select * from
+ (select 1 as id) as xx
+ left join
+ (tenk1 as a1 full join (select 1 as id) as yy on (a1.unique1 = yy.id))
+ on (xx.id = coalesce(yy.id));
+ QUERY PLAN
+---------------------------------------
+ Nested Loop Left Join
+ Join Filter: ((1) = COALESCE((1)))
+ -> Result
+ -> Hash Full Join
+ Hash Cond: (a1.unique1 = (1))
+ -> Seq Scan on tenk1 a1
+ -> Hash
+ -> Result
+(8 rows)
+
+select * from
+ (select 1 as id) as xx
+ left join
+ (tenk1 as a1 full join (select 1 as id) as yy on (a1.unique1 = yy.id))
+ on (xx.id = coalesce(yy.id));
+ id | unique1 | unique2 | two | four | ten | twenty | hundred | thousand | twothousand | fivethous | tenthous | odd | even | stringu1 | stringu2 | string4 | id
+----+---------+---------+-----+------+-----+--------+---------+----------+-------------+-----------+----------+-----+------+----------+----------+---------+----
+ 1 | 1 | 2838 | 1 | 1 | 1 | 1 | 1 | 1 | 1 | 1 | 1 | 2 | 3 | BAAAAA | EFEAAA | OOOOxx | 1
+(1 row)
+
+--
-- test ability to push constants through outer join clauses
--
explain (costs off)
diff --git a/src/test/regress/sql/join.sql b/src/test/regress/sql/join.sql
index c3902d9e9fc..67c4d3956cc 100644
--- a/src/test/regress/sql/join.sql
+++ b/src/test/regress/sql/join.sql
@@ -1210,6 +1210,23 @@ select ss2.* from
where ss1.c2 = 0;
--
+-- test successful handling of full join underneath left join (bug #14105)
+--
+
+explain (costs off)
+select * from
+ (select 1 as id) as xx
+ left join
+ (tenk1 as a1 full join (select 1 as id) as yy on (a1.unique1 = yy.id))
+ on (xx.id = coalesce(yy.id));
+
+select * from
+ (select 1 as id) as xx
+ left join
+ (tenk1 as a1 full join (select 1 as id) as yy on (a1.unique1 = yy.id))
+ on (xx.id = coalesce(yy.id));
+
+--
-- test ability to push constants through outer join clauses
--