Thread: Repeating Append operation

Repeating Append operation

From
Gurjeet Singh
Date:
<div dir="ltr">Hi all,<br /><br /><span style="font-family: courier new,monospace;">explain </span><br
style="font-family:courier new,monospace;" /><span style="font-family: courier new,monospace;">select v from
(</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier new,monospace;">select
array(</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier new,monospace;">       
select1</span><br style="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">       union all</span><br style="font-family: courier new,monospace;" /><span style="font-family:
couriernew,monospace;">        select 2) as v</span><br style="font-family: courier new,monospace;" /><span
style="font-family:courier new,monospace;">from (select 1) ) as s</span><br style="font-family: courier new,monospace;"
/><spanstyle="font-family: courier new,monospace;">where v is not null;</span><br style="font-family: courier
new,monospace;"/><br style="font-family: courier new,monospace;" />The plan looks like:<br /><br /><span
style="font-family:courier new,monospace;">                       QUERY PLAN</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier
new,monospace;">--------------------------------------------------------</span><brstyle="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;"> Result  (cost=0.08..0.10 rows=1 width=0)</span><br
style="font-family:courier new,monospace;" /><span style="font-family: courier new,monospace;">   One-Time Filter: ($1
ISNOT NULL)</span><br style="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">  InitPlan</span><br style="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">    ->  Append  (cost=0.00..0.04 rows=2 width=0)</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;">           ->  Result  (cost=0.00..0.01 rows=1
width=0)</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">          ->  Result  (cost=0.00..0.01 rows=1 width=0)</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;">     ->  Append  (cost=0.00..0.04 rows=2
width=0)</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">          ->  Result  (cost=0.00..0.01 rows=1 width=0)</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;">           ->  Result  (cost=0.00..0.01 rows=1
width=0)</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier new,monospace;">  
-> Result  (cost=0.00..0.01 rows=1 width=0)</span><br style="font-family: courier new,monospace;" /><span
style="font-family:courier new,monospace;">(10 rows)</span><br style="font-family: courier new,monospace;" /><br />   
Itseems that that the UNION ALL part of the query will be executed twice. If I remove the WHERE clause the I see only
oneAppend operation. I had a suspicion that its just the display of the plan that showed the same plan twice, but then
Inoticed that the overall cost of the query also drops making me think that this UNION ALL will actually be executed
twice.<br/><br />    The plan without the WHERE clause is:<br /><span style="font-family: courier
new,monospace;">                             QUERY PLAN</span><br style="font-family: courier new,monospace;" /><span
style="font-family:courier
new,monospace;">----------------------------------------------------------------------</span><brstyle="font-family:
couriernew,monospace;" /><span style="font-family: courier new,monospace;"> Subquery Scan __unnamed_subquery_0 
(cost=0.04..0.06rows=1 width=0)</span><br style="font-family: courier new,monospace;" /><span style="font-family:
couriernew,monospace;">   InitPlan</span><br style="font-family: courier new,monospace;" /><span style="font-family:
couriernew,monospace;">     ->  Append  (cost=0.00..0.04 rows=2 width=0)</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;">           ->  Result  (cost=0.00..0.01 rows=1
width=0)</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier
new,monospace;">          ->  Result  (cost=0.00..0.01 rows=1 width=0)</span><br style="font-family: courier
new,monospace;"/><span style="font-family: courier new,monospace;">   ->  Result  (cost=0.00..0.01 rows=1
width=0)</span><brstyle="font-family: courier new,monospace;" /><span style="font-family: courier new,monospace;">(6
rows)</span><br/><br />    I had seen this with a bigger query on actual tables, and this is just a reproducible test
case.In the original query I see 'SubPlan' instead of the 'InitPlan' seen here.<br /><br />Head of plan with WHERE 
clause:<br/><span style="font-family: courier new,monospace;">  Seq Scan on "Person" p  (cost=0.00..280486580881.10
rows=1373415width=4)</span><br /><br />Head of plan without WHERE  clause:<br /><span style="font-family: courier
new,monospace;"> Seq Scan on "Person" p  (cost=0.00..140594841889.03 rows=1380317 width=4)</span><br /><br clear="all"
/>   Is there a way to avoid this double evaluation?<br /><br />Thanks in advance.<br />-- <br />gurjeet.singh<br />@
EnterpriseDB- The Enterprise Postgres Company<br /><a
href="http://www.enterprisedb.com">http://www.enterprisedb.com</a><br/><br />singh.gurjeet@{ gmail | yahoo }.com<br
/>Twitter/Skype:singh_gurjeet<br /><br />Mail sent from my BlackLaptop device<br /></div> 

Re: Repeating Append operation

From
Robert Haas
Date:
On Fri, Mar 19, 2010 at 2:09 PM, Gurjeet Singh <singh.gurjeet@gmail.com> wrote:
>     Is there a way to avoid this double evaluation?

Maybe with a CTE?

WITH x AS (...) SELECT ...

It does look like surprising behavior.

...Robert


Re: Repeating Append operation

From
Gurjeet Singh
Date:
On Sun, Mar 21, 2010 at 4:29 PM, Robert Haas <robertmhaas@gmail.com> wrote:
On Fri, Mar 19, 2010 at 2:09 PM, Gurjeet Singh <singh.gurjeet@gmail.com> wrote:
>     Is there a way to avoid this double evaluation?

Maybe with a CTE?

WITH x AS (...) SELECT ...

It does look like surprising behavior.
 
It was discussed on the IRC that same day, and RhodiumToad (Andrew) pointed out that this behaviour is because of subquery un-nesting. Putting an OFFSET 0 clause (hint) in the inline view prevents it from being merged with the outer query:

explain
select v from (
select array(
        select 1
        union all
        select 2) as v
from (select 1) offset 0) as s
where v is not null;
                                    QUERY PLAN
----------------------------------------------------------------------------------
 Subquery Scan s  (cost=0.04..0.07 rows=1 width=32)
   Filter: (v IS NOT NULL)
   ->  Limit  (cost=0.04..0.06 rows=1 width=0)
         InitPlan
           ->  Append  (cost=0.00..0.04 rows=2 width=0)
                 ->  Result  (cost=0.00..0.01 rows=1 width=0)
                 ->  Result  (cost=0.00..0.01 rows=1 width=0)
         ->  Subquery Scan __unnamed_subquery_0  (cost=0.00..0.02 rows=1 width=0)
               ->  Result  (cost=0.00..0.01 rows=1 width=0)
(9 rows)

   This raises the point that we do subquery un-nesting purely on heuristics, and not on cost basis. I guess we should be be doing a cost comparison too. I think that this un-nesting happens quite before we start generating alternative plans for cost comparisons, and that we might not have costs to compare at this stage, but IMHO we should somehow incorporate cost comparisons too.

Regards,


--
gurjeet.singh
@ EnterpriseDB - The Enterprise Postgres Company
http://www.enterprisedb.com

singh.gurjeet@{ gmail | yahoo }.com
Twitter/Skype: singh_gurjeet

Mail sent from my BlackLaptop device

Re: Repeating Append operation

From
Robert Haas
Date:
On Tue, Mar 23, 2010 at 2:09 PM, Gurjeet Singh <singh.gurjeet@gmail.com> wrote:
> On Sun, Mar 21, 2010 at 4:29 PM, Robert Haas <robertmhaas@gmail.com> wrote:
>>
>> On Fri, Mar 19, 2010 at 2:09 PM, Gurjeet Singh <singh.gurjeet@gmail.com>
>> wrote:
>> >     Is there a way to avoid this double evaluation?
>>
>> Maybe with a CTE?
>>
>> WITH x AS (...) SELECT ...
>>
>> It does look like surprising behavior.
>
> It was discussed on the IRC that same day, and RhodiumToad (Andrew) pointed
> out that this behaviour is because of subquery un-nesting. Putting an OFFSET
> 0 clause (hint) in the inline view prevents it from being merged with the
> outer query:
>
> explain
> select v from (
> select array(
>         select 1
>         union all
>         select 2) as v
> from (select 1) offset 0) as s
> where v is not null;
>                                     QUERY PLAN
> ----------------------------------------------------------------------------------
>  Subquery Scan s  (cost=0.04..0.07 rows=1 width=32)
>    Filter: (v IS NOT NULL)
>    ->  Limit  (cost=0.04..0.06 rows=1 width=0)
>          InitPlan
>            ->  Append  (cost=0.00..0.04 rows=2 width=0)
>                  ->  Result  (cost=0.00..0.01 rows=1 width=0)
>                  ->  Result  (cost=0.00..0.01 rows=1 width=0)
>          ->  Subquery Scan __unnamed_subquery_0  (cost=0.00..0.02 rows=1
> width=0)
>                ->  Result  (cost=0.00..0.01 rows=1 width=0)
> (9 rows)
>
>    This raises the point that we do subquery un-nesting purely on
> heuristics, and not on cost basis. I guess we should be be doing a cost
> comparison too. I think that this un-nesting happens quite before we start
> generating alternative plans for cost comparisons, and that we might not
> have costs to compare at this stage, but IMHO we should somehow incorporate
> cost comparisons too.

I don't think this is right.  Flattening the subquery doesn't prevent
the join from being implemented a nested loop, which is essentially
what happens when it's treated as an initplan.  It just allows other
options also.

...Robert