Re: 8.2.4 serious slowdown

From: Sim Zacks <sim(at)compulab(dot)co(dot)il>
To: pgsql-general(at)postgresql(dot)org
Subject: Re: 8.2.4 serious slowdown
Date: 2008-01-13 05:59:22
Message-ID: fmc9ge$29in$1@news.hub.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general pgsql-hackers

How would you rewrite something like:
WHERE (COALESCE(b.quantity, 0) - COALESCE(b.deliveredsum, 0)) > 0;
I could write:
where case when b.quantity is null then 0 else b.quantity end - case when b.deliveredsum is null then 0 else b.deliveredsum end > 0

It is butt ugly, but is that the most efficient way to write it in 8.2.4?

Sim

Pavel Stehule wrote:
> Hello
>
> On 11/01/2008, Sim Zacks <sim(at)compulab(dot)co(dot)il> wrote:
>> I changed it to "where f.commited is not true" and the query now takes 1 second as opposed to 60.
>> (much faster then the 3 seconds it took on 8.0.1, which could also be because of the coalesce there)
>> Is it considered better practice (or more efficient) to always use (x is not or x=value)
>> instead of coalesce? Or does it make more sense to turn on the option "transform_null_equals"?
>>
>
> You can use without coalesce() = some operator IS DISTINCT FROM ... .
> Use coalesce only if you need some NON NULL value.
>
> for you sample
>
> where f.commited IS DISTINCT FROM true;
>
> operator IS DISTINCT FROM is NULL insensitive
>
> Regards
> Pavel Stehule
>
>> Thank you much
>> Sim
>>
>>> I assume that the original query is something along the lines of
>>>
>>> d left join f on (...) where coalesce(f.commited, false) = false
>>>
>>>
>>> In the meantime, Sim would probably have better luck if he restructured
>>> this particular clause in some other way, say
>>>
>>> where f.commited is not true
>>> or
>>> where f.commited = false or f.commited is null
>>>
>>> Note also that he really ought to move up to 8.2.6, as 8.2.4 is not
>>> very sane about what IS NULL means for a left join's result.
>>>
>>> regards, tom lane
>>>
>>> ---------------------------(end of broadcast)---------------------------
>>> TIP 6: explain analyze is your friend
>>>
>> ---------------------------(end of broadcast)---------------------------
>> TIP 5: don't forget to increase your free space map settings
>>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 3: Have you checked our extensive FAQ?
>
> http://www.postgresql.org/docs/faq
>

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Sim Zacks 2008-01-13 06:09:47 Re: 8.2.4 serious slowdown
Previous Message Rodrigo E. De León Plicet 2008-01-13 05:10:15 Re: UPDATE .. JOIN?

Browse pgsql-hackers by date

  From Date Subject
Next Message Sim Zacks 2008-01-13 06:09:47 Re: 8.2.4 serious slowdown
Previous Message Gurjeet Singh 2008-01-13 04:44:42 ERROR during WAL replay