Thread: Epoch from age is incorrect

Epoch from age is incorrect

From
Zhihong Zhang
Date:
The epoch from following statement is incorrect,

test_db=# select extract(epoch from age(TIMESTAMP '2013-02-18 06:15:15'));
 date_part 
-----------
 272396685
(1 row)


The correct value should be

test_db=# select (extract(epoch from now()) - extract(epoch from TIMESTAMP '2013-02-18 06:15:15'));
     ?column?     
------------------
 272816228.311208
(1 row)

They are several days apart. Maybe leap years are not counted properly?

Postgresql version:

PostgreSQL 11.12 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.8.5 20150623 (Red Hat 

Let me know if you need more information. Thanks!

Zhihong

Re: Epoch from age is incorrect

From
"David G. Johnston"
Date:
On Monday, October 11, 2021, Zhihong Zhang <zhihong@gmail.com> wrote:

They are several days apart. Maybe leap years are not counted properly?

That is related.  Intervals supply integer years, months, and days (for example).  Given an integer month (or year) value there is no way to accurately compute the number of days involved (or any subfield of day) since you lack knowledge of which months (years) they are (generally).  So extracting an epoch from an interval is an inherently unwise thing to do.  Having done it, comparing its result to a timestamp epoch computation is meaningless.  If you can do the later then just do it as it will provide the expected answer while the interval epoch is inherently problematic.

David J.
 

Re: Epoch from age is incorrect

From
Bruce Momjian
Date:
On Mon, Oct 11, 2021 at 02:52:59PM -0700, David G. Johnston wrote:
> On Monday, October 11, 2021, Zhihong Zhang <zhihong@gmail.com> wrote:
> 
> 
>     They are several days apart. Maybe leap years are not counted properly?
> 
> 
> That is related.  Intervals supply integer years, months, and days (for
> example).  Given an integer month (or year) value there is no way to accurately
> compute the number of days involved (or any subfield of day) since you lack
> knowledge of which months (years) they are (generally).  So extracting an epoch
> from an interval is an inherently unwise thing to do.  Having done it,
> comparing its result to a timestamp epoch computation is meaningless.  If you
> can do the later then just do it as it will provide the expected answer while
> the interval epoch is inherently problematic.

Yes.  Also, this blog has more details:

    https://momjian.us/main/blogs/pgblog/2020.html#August_3_2020

-- 
  Bruce Momjian  <bruce@momjian.us>        https://momjian.us
  EDB                                      https://enterprisedb.com

  If only the physical world exists, free will is an illusion.




Re: Epoch from age is incorrect

From
Tom Lane
Date:
Zhihong Zhang <zhihong@gmail.com> writes:
> The epoch from following statement is incorrect,
> test_db=# select extract(epoch from age(TIMESTAMP '2013-02-18 06:15:15'));
>  date_part
> -----------
>  272396685
> (1 row)

AFAICS it's following the documented definition of epoch for intervals.

regression=# begin;
BEGIN
regression=*# select extract(epoch from age(TIMESTAMP '2013-02-18 06:15:15'));
     extract
------------------
 272223885.000000
(1 row)

regression=*# select age(TIMESTAMP '2013-02-18 06:15:15');
               age
---------------------------------
 8 years 7 mons 20 days 17:44:45
(1 row)

regression=*# select ((((8 * 365 + 7 * 30 + 20) * 24 + 17) * 60) + 44) * 60 + 45;
 ?column?
-----------
 272223885
(1 row)


age() is useful for some purposes, but this isn't one of them.
I'd recommend considering it as a human-readable approximation
rather than something to do further arithmetic with.  You'd get
more nearly the answer you probably want with

regression=*# select extract(epoch from localtimestamp - TIMESTAMP '2013-02-18 06:15:15');
     extract
------------------
 272806988.613568
(1 row)

or even more to the point,

regression=*# select extract(epoch from now() - TIMESTAMPTZ '2013-02-18 06:15:15');
     extract
------------------
 272803388.613568
(1 row)

            regards, tom lane



Re: Epoch from age is incorrect

From
Zhihong Zhang
Date:
I thought age(time) was just a shorthand for (now() - time). Apparently they yield very different results.

I will stay away from age() for our use case. Thanks for the explanation.

Zhihong


> On Oct 11, 2021, at 5:59 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
>
> Zhihong Zhang <zhihong@gmail.com> writes:
>> The epoch from following statement is incorrect,
>> test_db=# select extract(epoch from age(TIMESTAMP '2013-02-18 06:15:15'));
>> date_part
>> -----------
>> 272396685
>> (1 row)
>
> AFAICS it's following the documented definition of epoch for intervals.
>
> regression=# begin;
> BEGIN
> regression=*# select extract(epoch from age(TIMESTAMP '2013-02-18 06:15:15'));
>     extract
> ------------------
> 272223885.000000
> (1 row)
>
> regression=*# select age(TIMESTAMP '2013-02-18 06:15:15');
>               age
> ---------------------------------
> 8 years 7 mons 20 days 17:44:45
> (1 row)
>
> regression=*# select ((((8 * 365 + 7 * 30 + 20) * 24 + 17) * 60) + 44) * 60 + 45;
> ?column?
> -----------
> 272223885
> (1 row)
>
>
> age() is useful for some purposes, but this isn't one of them.
> I'd recommend considering it as a human-readable approximation
> rather than something to do further arithmetic with.  You'd get
> more nearly the answer you probably want with
>
> regression=*# select extract(epoch from localtimestamp - TIMESTAMP '2013-02-18 06:15:15');
>     extract
> ------------------
> 272806988.613568
> (1 row)
>
> or even more to the point,
>
> regression=*# select extract(epoch from now() - TIMESTAMPTZ '2013-02-18 06:15:15');
>     extract
> ------------------
> 272803388.613568
> (1 row)
>
>             regards, tom lane