Re: [HACKERS] Allow use of immutable functions operating on constants with constraint exclusion

2007-05-09 Thread ITAGAKI Takahiro

"Marshall, Steve" <[EMAIL PROTECTED]> wrote:

> the first query would be optimized using 
> constraint exclusion, while the second query would not:
> 
> SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
> 05:00:00+00'::timestamptz;
> SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
> 05:00:00+00'::timestamptz + '0 days'::interval;

Hmmm... CE seems to be still not enough to optimize complex expressions.
If I added the wrapper function, it worked.

CREATE FUNCTION timeadd(timestamptz, interval) RETURNS timestamptz
AS $$ SELECT $1 + $2; $$ LANGUAGE sql IMMUTABLE;

SELECT * FROM test_bulletins WHERE created_at >
timeadd('2006-09-09 05:00:00+00', '0 days');


I noticed that we should be careful about CE with prepared statements
and functions. Seamless partitioning requires more works.

Regards,
---
ITAGAKI Takahiro
NTT Open Source Software Center



---(end of broadcast)---
TIP 1: if posting/reading through Usenet, please send an appropriate
   subscribe-nomail command to [EMAIL PROTECTED] so that your
   message can get through to the mailing list cleanly


Re: [HACKERS] Allow use of immutable functions operating on constants with constraint exclusion

2007-05-08 Thread Tom Lane
"Marshall, Steve" <[EMAIL PROTECTED]> writes:
> Currently, immutable functions are not expanded 
> during planning

Incorrect, see eval_const_expressions().

regards, tom lane

---(end of broadcast)---
TIP 4: Have you searched our list archives?

   http://archives.postgresql.org


Re: [HACKERS] Allow use of immutable functions operating on constants with constraint exclusion

2007-05-08 Thread Martijn van Oosterhout
On Tue, May 08, 2007 at 08:08:28AM -0400, Marshall, Steve wrote:
> However, I think it would be possible to expand immutable functions 
> operating on constants to optimize constraint exclusion.  Immutable 
> functions will always return the same result given the same inputs, so 
> this would be safe.  Currently, immutable functions are not expanded 
> during planning such that the first query would be optimized using 
> constraint exclusion, while the second query would not:

The problem with this is that at planning time you don't necessarily
have an active transaction snapshot. Prepared statements are the
obvious example, but I think even in one-off statements there's no
snapshot until after the planner has completed. This is also one of the
problems with type input/output functions looking up stuff in tables.

There was discussion about the handling type input/output functins and
casts as a sort off InitExpr that is executed once, then inserted into
the tree. However, that would still be too late to affect the planning.

Have a nice day,
-- 
Martijn van Oosterhout   <[EMAIL PROTECTED]>   http://svana.org/kleptog/
> From each according to his ability. To each according to his ability to 
> litigate.


signature.asc
Description: Digital signature


Re: [HACKERS] Allow use of immutable functions operating on constants with constraint exclusion

2007-05-08 Thread Marshall, Steve

ITAGAKI Takahiro wrote:


Tom Lane <[EMAIL PROTECTED]> wrote:

 


"Marshall, Steve" <[EMAIL PROTECTED]> writes:
   

I have developed a small patch to optimizer/util/plancat.c that 
eliminates one of hte caveats associated with constraint exclusions, 
namely the inability to avoid searching tables based on the results of 
stable functions.
 


Do you not understand why this is completely unsafe?
   



I think the proposal itself is very useful, because time-based
partitioning is commonly used and functions like now() or
CURRENT_TIMESTAMP are marked as stable.

I'm not clear why the optimization is unsafe. I'm confused to read the
definition of stable functions in our documentation. Which is required
for stable functions 'stable in a single table scan' or 'stable in a
SQL statements' ? If the latter definition is true, can we use them
in constraint exclusions?

| STABLE indicates that the function cannot modify the database, and
| that within a single table scan it will consistently return the same
| result for the same argument values, but that its result could change
| across SQL statements
 

The lack of safety comes from prepared statements.  If the above 
optimization was used, the value of the stable function would be used 
when the statement was prepared, and the query plan would then be set 
using the stable function value as though it were a constant.  For 
partitioned tables, this could result in a failure to scan tables needed 
to meet the query constraints.


I think the optimization could work if you could exclude prepared 
statements.  However, I looked at the planning code and found no clear 
way to distinguish between a statement being prepared for later 
execution, and a statement being planned only for immediate execution.   
As a result, I don't think stable functions can (or should) be expanded 
to help optimize queries using constraint exclusion. 

However, I think it would be possible to expand immutable functions 
operating on constants to optimize constraint exclusion.  Immutable 
functions will always return the same result given the same inputs, so 
this would be safe.  Currently, immutable functions are not expanded 
during planning such that the first query would be optimized using 
constraint exclusion, while the second query would not:


SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
05:00:00+00'::timestamptz;
SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
05:00:00+00'::timestamptz + '0 days'::interval;


See the attached SQL file for table creation and other SQL examples.

The real question here is if the optimization is worth the effort.  
Personally, I commonly use queries of this sort, and so would be in 
favor of this expansion of immutable functions operating on constrats as 
an optimization.  I find it convenient to use the database to do the 
time manipulation (e.g. adding intervals to timestamps).  However, the 
logic to manipulate times can be pushed into application code if need 
be.   I've found I have to do a lot of explaining to developers as to 
why two queries that look so similar perform very differently.




--
--  Create and connect to the test database
--
CREATE DATABASE test_ce_db;
ALTER DATABASE test_ce_db OWNER TO postgres;

\connect test_ce_db;

--
--  Make a parent table and three child tables partitioned by time using 
created_at column.
--
CREATE TABLE test_bulletins (
created_at timestamp with time zone NOT NULL,
data text NOT NULL
);

CREATE TABLE test_bulletins_20060908 (CONSTRAINT time_partition_limits CHECK 
(((created_at >= '2006-09-08 00:00:00+00'::timestamp with time zone) AND 
(created_at < '2006-09-09 00:00:00+00'::timestamp with time zone)))
)
INHERITS (test_bulletins);

CREATE TABLE test_bulletins_20060909 (CONSTRAINT time_partition_limits CHECK 
(((created_at >= '2006-09-09 00:00:00+00'::timestamp with time zone) AND 
(created_at < '2006-09-10 00:00:00+00'::timestamp with time zone)))
)
INHERITS (test_bulletins);

CREATE TABLE test_bulletins_20060910 (CONSTRAINT time_partition_limits CHECK 
(((created_at >= '2006-09-10 00:00:00+00'::timestamp with time zone) AND 
(created_at < '2006-09-11 00:00:00+00'::timestamp with time zone)))
)
INHERITS (test_bulletins);

--
--  Setup environment for queries. 
--
SET constraint_exclusion = on;
\pset footer off;

--
--  Do test case queries.
--
SELECT 'This query should avoid use of table test_bulletins_20060908, even with 
OLD CE code' as "Test case 1";
EXPLAIN SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
05:00:00+00'::timestamptz;

SELECT 'This query should avoid use of table test_bulletins_20060908, ONLY with 
NEW CE code' as "Test case 2";
EXPLAIN SELECT * FROM test_bulletins WHERE created_at > '2006-09-09 
05:00:00+00'::timestamptz + '0 days'::interval;

SELECT 'This query uses a stable function; it should NOT be optimized' as "Test 
case 3";
EXPLAIN SELECT * FROM test_bulletins WHERE created_at > now() - (now() - 
'2006-09-09 05:00:00+00'