Re: extract or date_part on an interval? How many e

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Bryce Nesbitt <bryce1(at)obviously(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: extract or date_part on an interval? How many e
Date: 2008-01-28 03:10:40
Message-ID: 16843.1201489840@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Bryce Nesbitt <bryce1(at)obviously(dot)com> writes:
> Hmm. Seemed so simple. But how do I get the number of years an
> interval represents? extract is clearly the wrong way:

There is nothing simple about datetime calculations, ever :-(

Let me exhibit why this particular case is not as simple as you
could wish:

regression=# select '2007-02-01'::timestamp + interval '1 year';
?column?
---------------------
2008-02-01 00:00:00
(1 row)

regression=# select '2007-02-01'::timestamp + interval '365 days';
?column?
---------------------
2008-02-01 00:00:00
(1 row)

regression=# select '2008-02-01'::timestamp + interval '1 year';
?column?
---------------------
2009-02-01 00:00:00
(1 row)

regression=# select '2008-02-01'::timestamp + interval '365 days';
?column?
---------------------
2009-01-31 00:00:00
(1 row)

That is, there isn't any fixed conversion factor between N days
and N years, so the interval datatype treats them as incommensurate.

If you're willing to settle for an approximate answer, you can
do extract(epoch from interval) and then divide by however many
seconds you want to believe are in a year. This will give various
wrong answers in various corner cases, but I'm not sure there is
a right answer.

regards, tom lane

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Bryce Nesbitt 2008-01-28 04:51:32 Re: extract or date_part on an interval? How many e
Previous Message Adrian Klaver 2008-01-28 02:56:58 Re: extract or date_part on an interval? How many e