Re: Invalid optimization of VOLATILE function in WHERE clause? - Mailing list pgsql-hackers

From Merlin Moncure
Subject Re: Invalid optimization of VOLATILE function in WHERE clause?
Date
Msg-id CAHyXU0yw=datDeWGBfncNqwn1HL9Oj0MTbwoQrFPi4dLozgD5A@mail.gmail.com
Whole thread Raw
In response to Re: Invalid optimization of VOLATILE function in WHERE clause?  (Tom Lane <tgl@sss.pgh.pa.us>)
List pgsql-hackers
On Wed, Sep 19, 2012 at 9:30 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
> Florian.Schoppmann@emc.com (Florian Schoppmann) writes:
>> In PostgreSQL 9.1 and 9.2 (possibly also in earlier versions), the query
>
>> --8<--
>> WITH source AS (
>>     SELECT i FROM generate_series(1,10) AS i
>> )
>> SELECT
>>     i
>> FROM
>>     source, (
>>         SELECT
>>             count(*) AS _n
>>         FROM source
>>     ) AS _stats
>> WHERE
>>     random() < 5::DOUBLE PRECISION/_n;
>> -->8--
>
> [ doesn't do what you think it should ]
>
> I can't get excited about this.  Any time you put a volatile function
> into WHERE, you're playing with fire.  The docs warn against it:
> http://www.postgresql.org/docs/9.2/static/sql-expressions.html#SYNTAX-EXPRESS-EVAL
>
> To do what you want, I'd suggest wrapping the join into a sub-select
> with an "OFFSET 0" clause, which will serve as an optimization fence
> that prevents the random() call from being pushed down.

I like the more standard CTE approach to optimization fencing where it works:

postgres=# WITH source AS (   SELECT i, random() r   FROM generate_series(1,10) AS i
)
SELECT   i
FROM   source, (       SELECT           count(*) AS _n       FROM source   ) AS _stats
WHERE   r < 5::DOUBLE PRECISION/_n;

merlin



pgsql-hackers by date:

Previous
From: Tom Lane
Date:
Subject: Re: Invalid optimization of VOLATILE function in WHERE clause?
Next
From: Robert Haas
Date:
Subject: Re: Invalid optimization of VOLATILE function in WHERE clause?