About reducing EXISTS sublink - Mailing list pgsql-hackers

From Richard Guo
Subject About reducing EXISTS sublink
Date
Msg-id CAMbWs48nQdAPOBrfDQHtmLgAFB9xcDAHpJ0BUi98WHKhoQ5DCQ@mail.gmail.com
Whole thread Raw
Responses Re: About reducing EXISTS sublink  ("David G. Johnston" <david.g.johnston@gmail.com>)
List pgsql-hackers
Hi hackers,

For EXISTS SubLink, in some cases the subquery can be reduced to
constant TRUE or FALSE, based on the knowledge that it's being used in
EXISTS(). One such case is when the subquery has aggregates without
GROUP BY or HAVING, and we know its result is exactly one row, unless
that row is discarded by LIMIT/OFFSET. (Greenplum does this.)

For example:

# explain (costs off) select * from a where exists
                        (select avg(i) from b where a.i = b.i);
            QUERY PLAN
-----------------------------------
 Seq Scan on a
   Filter: (SubPlan 1)
   SubPlan 1
     ->  Aggregate
           ->  Seq Scan on b
                 Filter: (a.i = i)
(6 rows)

This query can be reduced to:

# explain (costs off) select * from a where exists
                        (select avg(i) from b where a.i = b.i);
  QUERY PLAN
---------------
 Seq Scan on a
(1 row)

And likewise, for this query below:

# explain (costs off) select * from a where exists
                        (select avg(i) from b where a.i = b.i offset 1);
               QUERY PLAN
-----------------------------------------
 Seq Scan on a
   Filter: (SubPlan 1)
   SubPlan 1
     ->  Limit
           ->  Aggregate
                 ->  Seq Scan on b
                       Filter: (a.i = i)
(7 rows)

It can be reduced to:

# explain (costs off) select * from a where exists
                        (select avg(i) from b where a.i = b.i offset 1);
        QUERY PLAN
--------------------------
 Result
   One-Time Filter: false
(2 rows)

Is it worthwhile to add some codes for such optimization? If so, I can
try to propose a patch.

Thanks
Richard

pgsql-hackers by date:

Previous
From: Etsuro Fujita
Date:
Subject: Re: Optimizer docs typos
Next
From: Richard Guo
Date:
Subject: Re: Optimizer docs typos