Обсуждение: Problem in age on a dates interval
Hi all,
I'm using PostgreSQL 7.3.3 on i386-pc-linux-gnu, compiled by GCC gcc
(GCC) 3.3 (Debian), and I don't understand the results of the following
queries:
SELECT age('2004-05-14 16:00'::timestamp,'2004-02-18 16:00'::timestamp); age
----------------2 mons 25 days
SELECT '2004-02-18 16:00'::timestamp+'2 mons 25 days'::interval; ?column?
---------------------2004-05-13 16:00:00
In this case, the age from 2004-05-14 16:00 to 2004-02-18 16:00 is 2
mons 25 days, but if I add the age to the initial date, it returns one
day less!?
SELECT age('2004-05-26 16:00'::timestamp,'2004-02-18 16:00'::timestamp); age
---------------3 mons 8 days
SELECT '2004-02-18 16:00'::timestamp+'3 mons 8 days'::interval; ?column?
---------------------2004-05-26 16:00:00
Here, the age between 2004-05-26 16:00 and 2004-02-18 16:00 is 3 mons 8
days, and this interval added to the initial date gives the correct result!!
Best regards,
Luis Sousa
Luis,
wow.... at first I thought I had my head around a leap
year problem so I advanced your query a year....
testbed=# SELECT age('2005-05-14
16:00'::timestamp,'2005-02-18 16:00'::timestamp); age
----------------2 mons 24 days
(1 row)
testbed =# SELECT '2005-02-18 16:00'::timestamp +'2
mons 24 days'::interval; ?column?
---------------------2005-05-12 16:00:00
(1 row)
I just thought I would let you know it can get
worse..... :) I don't know how daylight savings time
is playing this problem... but I didn't expect the
problem to grow like that.
Ted
--- Luis Sousa <llsousa@ualg.pt> wrote:
> Hi all,
>
> I'm using PostgreSQL 7.3.3 on i386-pc-linux-gnu,
> compiled by GCC gcc
> (GCC) 3.3 (Debian), and I don't understand the
> results of the following
> queries:
>
>
> SELECT age('2004-05-14 16:00'::timestamp,'2004-02-18
> 16:00'::timestamp);
> age
> ----------------
> 2 mons 25 days
>
> SELECT '2004-02-18 16:00'::timestamp+'2 mons 25
> days'::interval;
> ?column?
> ---------------------
> 2004-05-13 16:00:00
>
> In this case, the age from 2004-05-14 16:00 to
> 2004-02-18 16:00 is 2
> mons 25 days, but if I add the age to the initial
> date, it returns one
> day less!?
>
> SELECT age('2004-05-26 16:00'::timestamp,'2004-02-18
> 16:00'::timestamp);
> age
> ---------------
> 3 mons 8 days
>
> SELECT '2004-02-18 16:00'::timestamp+'3 mons 8
> days'::interval;
> ?column?
> ---------------------
> 2004-05-26 16:00:00
>
> Here, the age between 2004-05-26 16:00 and
> 2004-02-18 16:00 is 3 mons 8
> days, and this interval added to the initial date
> gives the correct result!!
>
__________________________________
Do you Yahoo!?
Yahoo! Mail - 50x more storage than other providers!
http://promotions.yahoo.com/new_mail
Theodore Petrosky <tedpet5@yahoo.com> writes:
> wow.... at first I thought I had my head around a leap
> year problem so I advanced your query a year....
I think what's going on here is a difference of interpretation about
whether an "M months D days" interval means to add the months first
or the days first. For instance
2005-02-18 plus 2 months = 2005-04-18, plus 24 days = 2005-05-12
2005-02-18 plus 24 days = 2005-03-14, plus 2 months = 2005-05-14
The timestamp-plus-interval operator is evidently doing addition the
first way, but it looks like age() is calculating the difference in a
way that implicitly corresponds to the second way.
I have some vague recollection that this has come up before, but
I don't recall whether we concluded that age() needs to be changed
or not. In any case it's not risen to the top of anyone's to-do list,
because I see that age() still acts this way in CVS tip.
regards, tom lane
I worked around this problem returning the difference between the two dates, using extract doy from both. Anyway, this will cause a bug on my code when changing the year. Any ideas? Best regards, Luis Sousa Tom Lane wrote: >Theodore Petrosky <tedpet5@yahoo.com> writes: > > >>wow.... at first I thought I had my head around a leap >>year problem so I advanced your query a year.... >> >> > >I think what's going on here is a difference of interpretation about >whether an "M months D days" interval means to add the months first >or the days first. For instance > >2005-02-18 plus 2 months = 2005-04-18, plus 24 days = 2005-05-12 > >2005-02-18 plus 24 days = 2005-03-14, plus 2 months = 2005-05-14 > >The timestamp-plus-interval operator is evidently doing addition the >first way, but it looks like age() is calculating the difference in a >way that implicitly corresponds to the second way. > >I have some vague recollection that this has come up before, but >I don't recall whether we concluded that age() needs to be changed >or not. In any case it's not risen to the top of anyone's to-do list, >because I see that age() still acts this way in CVS tip. > > regards, tom lane > > > >
On Mon, Jul 19, 2004 at 10:00:50AM +0100, Luis Sousa wrote: > I worked around this problem returning the difference between the two > dates, using extract doy from both. > Anyway, this will cause a bug on my code when changing the year. Any ideas? Why don't you use the minus operator? SELECT '2004-05-14 16:00'::timestamp - '2004-02-18 16:00'::timestamp;?column? ----------86 days Or, if you need the age just in days: SELECT extract(day from '2004-05-14 16:00'::timestamp - '2004-02-18 16:00'::timestamp);date_part ----------- 86 or SELECT '2004-05-14 16:00'::date - '2004-02-18 16:00'::date;?column? ---------- 86 Note that '2004-05-14 16:00'::date is actually '2004-05-14 00:00'::date, so the last two are not always equal. > Tom Lane wrote: > > >Theodore Petrosky <tedpet5@yahoo.com> writes: > > > > > >>wow.... at first I thought I had my head around a leap > >>year problem so I advanced your query a year.... > >> > >> > > > >I think what's going on here is a difference of interpretation about > >whether an "M months D days" interval means to add the months first > >or the days first. For instance > > > >2005-02-18 plus 2 months = 2005-04-18, plus 24 days = 2005-05-12 > > > >2005-02-18 plus 24 days = 2005-03-14, plus 2 months = 2005-05-14 > > > >The timestamp-plus-interval operator is evidently doing addition the > >first way, but it looks like age() is calculating the difference in a > >way that implicitly corresponds to the second way. > > > >I have some vague recollection that this has come up before, but > >I don't recall whether we concluded that age() needs to be changed > >or not. In any case it's not risen to the top of anyone's to-do list, > >because I see that age() still acts this way in CVS tip. > > > > regards, tom lane -- Fduch M. Pravking
Yes, that's a much more clever solution than the one I used. Thanks Best regards, Luis Sousa Alexander M. Pravking wrote: >On Mon, Jul 19, 2004 at 10:00:50AM +0100, Luis Sousa wrote: > > >>I worked around this problem returning the difference between the two >>dates, using extract doy from both. >>Anyway, this will cause a bug on my code when changing the year. Any ideas? >> >> > >Why don't you use the minus operator? > >SELECT '2004-05-14 16:00'::timestamp - '2004-02-18 16:00'::timestamp; > ?column? >---------- > 86 days > >Or, if you need the age just in days: > >SELECT extract(day from '2004-05-14 16:00'::timestamp - '2004-02-18 16:00'::timestamp); > date_part >----------- > 86 > >or > >SELECT '2004-05-14 16:00'::date - '2004-02-18 16:00'::date; > ?column? >---------- > 86 > >Note that '2004-05-14 16:00'::date is actually '2004-05-14 00:00'::date, >so the last two are not always equal. > > > > >>Tom Lane wrote: >> >> >> >>>Theodore Petrosky <tedpet5@yahoo.com> writes: >>> >>> >>> >>> >>>>wow.... at first I thought I had my head around a leap >>>>year problem so I advanced your query a year.... >>>> >>>> >>>> >>>> >>>I think what's going on here is a difference of interpretation about >>>whether an "M months D days" interval means to add the months first >>>or the days first. For instance >>> >>>2005-02-18 plus 2 months = 2005-04-18, plus 24 days = 2005-05-12 >>> >>>2005-02-18 plus 24 days = 2005-03-14, plus 2 months = 2005-05-14 >>> >>>The timestamp-plus-interval operator is evidently doing addition the >>>first way, but it looks like age() is calculating the difference in a >>>way that implicitly corresponds to the second way. >>> >>>I have some vague recollection that this has come up before, but >>>I don't recall whether we concluded that age() needs to be changed >>>or not. In any case it's not risen to the top of anyone's to-do list, >>>because I see that age() still acts this way in CVS tip. >>> >>> regards, tom lane >>> >>> > > >