Re: extract or date_part on an interval? How many e - Mailing list pgsql-sql

From Tom Lane
Subject Re: extract or date_part on an interval? How many e
Date
Msg-id 16843.1201489840@sss.pgh.pa.us
Whole thread Raw
In response to extract or date_part on an interval? How many e  (Bryce Nesbitt <bryce1@obviously.com>)
Responses Re: extract or date_part on an interval? How many e  (Bryce Nesbitt <bryce1@obviously.com>)
List pgsql-sql
Bryce Nesbitt <bryce1@obviously.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


pgsql-sql by date:

Previous
From: Adrian Klaver
Date:
Subject: Re: extract or date_part on an interval? How many e
Next
From: Bryce Nesbitt
Date:
Subject: Re: extract or date_part on an interval? How many e