"=?utf-8?b?RG91ZyBHb3JsZXk=?=" <doug@xxxxxxxxx> writes: > I'm attempting to implement table partitioning with constraint exclusions, > but I'm not seeing the planner limit the plan to an appropriate set of > child tables. I'm wondering if the functions in my constraints are making > the exclusion impossible. > My constraints look like this: >    ALTER TABLE response_data.queries_response_2015w23 >      ADD CONSTRAINT queries_response_2015w23_timestamp_check >          CHECK ( >             date_part('year'::text, "timestamp"::timestamp without time zone) = 2015::double precision AND >             date_part('week'::text, "timestamp"::timestamp without time zone) = 23::double precision >          ); > And my query looks like this: >    explain select * from public.queries_response where age("timestamp"::timestamp) < '24 hours'; >    > http://www.postgresql.org/docs/9.4/static/ddl-partitioning.html gives this caveat: >    "Constraint exclusion only works when the query's WHERE clause contains >    constants (or externally supplied parameters). For example, a comparison >    against a non-immutable function such as CURRENT_TIMESTAMP cannot be >    optimized, since the planner cannot know which partition the function >    value might fall into at run time." >    > Will I likely need to replace the date_part functions with actual dates to > make this work? Well, you can't make it work like that, for sure. The planner has no clue that there's any connection between age() and date_part(). And if it did fully understand that relationship, it still would refuse to do constraint exclusion in this example, because the age() constraint is current-timestamp-dependent. It couldn't assume that now() when executing the query is the same as it was when planning the query, so it wouldn't know which partition to select. Worse still, if I'm right in guessing that the timestamp column is timestamp WITH time zone (if it isn't, why are you bothering with the casts?) then the check constraints themselves aren't immutable, because their effective behavior depends on the current setting of TimeZone. So the planner will refuse to make any deductions at all with them. You'd be much better off using child-table constraints like "timestamp" >= '2015-01-01' AND "timestamp" < '2015-01-08' because the planner can reason about them. But I'm afraid the age() technique still loses. regards, tom lane -- Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-general