Re: Querying a time range across multiple partitions

From: Jeff Janes <jeff(dot)janes(at)gmail(dot)com>
To: Cal Heldenbrand <cal(at)fbsdata(dot)com>
Cc: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Re: Querying a time range across multiple partitions
Date: 2014-09-07 19:44:08
Message-ID: CAMkU=1xBhHTtMyWeLGQNfkBu2fknnyYU6-RPPZFeoU1p8dzXvQ@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Fri, Sep 5, 2014 at 10:31 AM, Cal Heldenbrand <cal(at)fbsdata(dot)com> wrote:

>
> explain analyze select time,event from logins
> where username='bob' and hash='1234' and time > current_date - interval
> '1 week';
>
> Result (cost=0.00..765.11 rows=1582 width=14)
> -> Append (cost=0.00..765.11 rows=1582 width=14)
> -> Seq Scan on logins (cost=0.00..0.00 rows=1 width=66)
> Filter: (((username)::text = 'bob'::text) AND ((hash)::text
> = '1234'::text) AND ("time" > (('now'::text)::date - '7 days'::interval)))
> -> Index Scan using logins_20100501_username_time on
> logins_20100501 logins (cost=0.01..0.48 rows=1 width=14)
> ...
>
> This shows that it's attempting to run the query against all of my 1500
> child tables.
>

I believe the problem is that the planner (which does the partition
pruning) is not willing to materialize the value of current_date, so it
can't use a specific value to prune partitions. After all, the date might
change between the planner and the executor, if you leave the plan open for
a long time, or make the call very close to midnight.

You will probably have to select the current_date (or get it from your
system, or cron, or whoever triggers the script), and then hardcode it into
the query.

Cheers,

Jeff

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Jeff Janes 2014-09-07 19:55:24 Re: Querying a time range across multiple partitions
Previous Message Jeff Janes 2014-09-07 19:28:01 Re: psql and tab-delimited output