Re: Optimizing AGE()

From: "Scott Marlowe" <scott(dot)marlowe(at)gmail(dot)com>
To: "Volkan YAZICI" <yazicivo(at)ttmail(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Optimizing AGE()
Date: 2008-06-08 06:09:19
Message-ID: dcc563d10806072309i49aaa3d9g38a36834507e81f5@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Fri, Jun 6, 2008 at 7:20 AM, Volkan YAZICI <yazicivo(at)ttmail(dot)com> wrote:
> Hi,
>
> Am I wrong or AGE() always gets directed to a sequential scan?
>
> # BEGIN;
> ] SET enable_seqscan TO off;
> ] EXPLAIN ANALYZE
> ] SELECT count(1)
> ] FROM incomingmessageslog
> ] WHERE AGE(time) < '1 year';
> ] ROLLBACK;
> BEGIN
> SET
> QUERY PLAN
> ----------------------------------------------------------------------------------------------------------------------------------------
> Aggregate (cost=100000528.33..100000528.34 rows=1 width=0) (actual time=13.789..13.790 rows=1 loops=1)
> -> Seq Scan on incomingmessageslog (cost=100000000.00..100000520.00 rows=3333 width=0) (actual time=13.783..13.783 rows=0 loops=1)
> Filter: (age((('now'::text)::date)::timestamp without time zone, "time") < '1 year'::interval)
> Total runtime: 13.852 ms
> (4 rows)
>
> ROLLBACK
>
> As far as I know, AGE() can take advantage of a very simple equation for
> constant comparisons:
>
> = AGE(field) < constant_criteria
> = AGE(field, constant_ts) < constant_criteria
> = AGE(field) < constant_criteria + constant_ts
> = AGE(field) < CONSTANT_CRITERIA
>
> How much does such a hack into optimizer cost? I don't know about its
> implications but I'll really appreciate such a functionality. At the
> moment, I'm trying replace every AGE() usage in my code and it really
> feels a PITA.

Yeah, age() isn't real performent in such situations. I generally
stick to simpler date math like:

where timestampvalue < now() - interval '2 year'

which can use an index on timestampvalue

The problem with age is it's always compared to now, so there's always
gonna be some math.

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message John Smith 2008-06-09 22:57:52 Re: Performance of aggregates over set-returning functions
Previous Message Scott Marlowe 2008-06-06 17:22:27 Re: Checkpoint tuning on 8.2.4