]> granicus.if.org Git - postgresql/commitdiff
Fix thinko in previous patch for optimizing EXISTS-within-EXISTS.
authorTom Lane <tgl@sss.pgh.pa.us>
Mon, 20 Jun 2011 18:33:20 +0000 (14:33 -0400)
committerTom Lane <tgl@sss.pgh.pa.us>
Mon, 20 Jun 2011 18:33:42 +0000 (14:33 -0400)
When recursing after an optimization in pull_up_sublinks_qual_recurse, the
available_rels value passed down must include only the relations that are
in the righthand side of the new SEMI or ANTI join; it's incorrect to pull
up a sub-select that refers to other relations, as seen in the added test
case.  Per report from BangarRaju Vadapalli.

While at it, rethink the idea of recursing below a NOT EXISTS.  That is
essentially the same situation as pulling up ANY/EXISTS sub-selects that
are in the ON clause of an outer join, and it has the same disadvantage:
we'd force the two joins to be evaluated according to the syntactic nesting
order, because the lower join will most likely not be able to commute with
the ANTI join.  That could result in having to form a rather large join
product, whereas the handling of a correlated subselect is not quite that
dumb.  So until we can handle those cases better, #ifdef NOT_USED that
case.  (I think it's okay to pull up in the EXISTS/ANY cases, because SEMI
joins aren't so inflexible about ordering.)

Back-patch to 8.4, same as for previous patch in this area.  Fortunately
that patch hadn't made it into any shipped releases yet.

src/backend/optimizer/prep/prepjointree.c
src/test/regress/expected/subselect.out
src/test/regress/sql/subselect.sql

index 5d163292c58b4c6238dc3b6e0d13f3edb1610b48..ac622a34d9d96e726af679479e69e7b7d7eaa65a 100644 (file)
@@ -246,6 +246,7 @@ pull_up_sublinks_jointree_recurse(PlannerInfo *root, Node *jtnode,
                 * as a sublink that is executed only for row pairs that meet the
                 * other join conditions.  Fixing this seems to require considerable
                 * restructuring of the executor, but maybe someday it can happen.
+                * (See also the comparable case in pull_up_sublinks_qual_recurse.)
                 *
                 * We don't expect to see any pre-existing JOIN_SEMI or JOIN_ANTI
                 * nodes here.
@@ -331,9 +332,7 @@ pull_up_sublinks_qual_recurse(PlannerInfo *root, Node *node,
                                j->rarg = pull_up_sublinks_jointree_recurse(root,
                                                                                                                        j->rarg,
                                                                                                                        &child_rels);
-                               /* Pulled-up ANY/EXISTS quals can use those rels too */
-                               child_rels = bms_add_members(child_rels, available_rels);
-                               /* ... and any inserted joins get stacked onto j->rarg */
+                               /* Any inserted joins get stacked onto j->rarg */
                                j->quals = pull_up_sublinks_qual_recurse(root,
                                                                                                                 j->quals,
                                                                                                                 child_rels,
@@ -355,9 +354,7 @@ pull_up_sublinks_qual_recurse(PlannerInfo *root, Node *node,
                                j->rarg = pull_up_sublinks_jointree_recurse(root,
                                                                                                                        j->rarg,
                                                                                                                        &child_rels);
-                               /* Pulled-up ANY/EXISTS quals can use those rels too */
-                               child_rels = bms_add_members(child_rels, available_rels);
-                               /* ... and any inserted joins get stacked onto j->rarg */
+                               /* Any inserted joins get stacked onto j->rarg */
                                j->quals = pull_up_sublinks_qual_recurse(root,
                                                                                                                 j->quals,
                                                                                                                 child_rels,
@@ -377,7 +374,6 @@ pull_up_sublinks_qual_recurse(PlannerInfo *root, Node *node,
                /* If the immediate argument of NOT is EXISTS, try to convert */
                SubLink    *sublink = (SubLink *) get_notclausearg((Expr *) node);
                JoinExpr   *j;
-               Relids          child_rels;
 
                if (sublink && IsA(sublink, SubLink))
                {
@@ -387,17 +383,27 @@ pull_up_sublinks_qual_recurse(PlannerInfo *root, Node *node,
                                                                                                   available_rels);
                                if (j)
                                {
+                                       /*
+                                        * For the moment, refrain from recursing underneath NOT.
+                                        * As in pull_up_sublinks_jointree_recurse, recursing here
+                                        * would result in inserting a join underneath an ANTI
+                                        * join with which it could not commute, and that could
+                                        * easily lead to a worse plan than what we've
+                                        * historically generated.
+                                        */
+#ifdef NOT_USED
                                        /* Yes; recursively process what we pulled up */
+                                       Relids          child_rels;
+
                                        j->rarg = pull_up_sublinks_jointree_recurse(root,
                                                                                                                                j->rarg,
                                                                                                                                &child_rels);
-                                       /* Pulled-up ANY/EXISTS quals can use those rels too */
-                                       child_rels = bms_add_members(child_rels, available_rels);
-                                       /* ... and any inserted joins get stacked onto j->rarg */
+                                       /* Any inserted joins get stacked onto j->rarg */
                                        j->quals = pull_up_sublinks_qual_recurse(root,
                                                                                                                         j->quals,
                                                                                                                         child_rels,
                                                                                                                         &j->rarg);
+#endif
                                        /* Now insert the new join node into the join tree */
                                        j->larg = *jtlink;
                                        *jtlink = (Node *) j;
index 2440dcd822508620728a68a06e87103d38451341..8f180b9b19c3eab6f1fec3231535c37a6bb6441e 100644 (file)
@@ -530,3 +530,15 @@ select '1'::text in (select '1'::name union all select '1'::name);
  t
 (1 row)
 
+--
+-- Test case for planner bug with nested EXISTS handling
+--
+select a.thousand from tenk1 a, tenk1 b
+where a.thousand = b.thousand
+  and exists ( select 1 from tenk1 c where b.hundred = c.hundred
+                   and not exists ( select 1 from tenk1 d
+                                    where a.thousand = d.thousand ) );
+ thousand 
+----------
+(0 rows)
+
index 296e38b8c1eff171dac3ed536b06b732583e2cc2..0d117c878fa200b573b60a8a6300c36837af50e0 100644 (file)
@@ -341,3 +341,12 @@ from
 --
 
 select '1'::text in (select '1'::name union all select '1'::name);
+
+--
+-- Test case for planner bug with nested EXISTS handling
+--
+select a.thousand from tenk1 a, tenk1 b
+where a.thousand = b.thousand
+  and exists ( select 1 from tenk1 c where b.hundred = c.hundred
+                   and not exists ( select 1 from tenk1 d
+                                    where a.thousand = d.thousand ) );