Steve Crawford <[email protected]> writes:
> However, extracting the epoch from current_date returns 4pm the prior day
> (i.e. 2025-11-21 00:00:00-00), in other words midnight 2025-11-21 UTC which
> seems to be inconsistent behavior:

> steve=> select to_timestamp(extract(epoch from current_date));
>       to_timestamp
> ------------------------
>  2025-11-20 16:00:00-08

The reason this is misbehaving is that there are two versions of
extract(), one for timestamp-with-timezone input and one for
timestamp-without-timezone input.  The latter applies no
timezone correction, so it won't give true Unix-epoch results
unless you are in UTC zone to start with.

By default, a date will be promoted to timestamp-without-timezone not
timestamp-with-timezone, so the above doesn't give what you want.
It'd work better with a cast to force the right interpretation:

regression=# set timezone = 'America/Los_Angeles';
SET
regression=# select to_timestamp(extract(epoch from current_date));
      to_timestamp      
------------------------
 2025-11-20 16:00:00-08
(1 row)

regression=# select to_timestamp(extract(epoch from 
current_date::timestamptz)); 
      to_timestamp      
------------------------
 2025-11-21 00:00:00-08
(1 row)

> There was a time, like version 9-dot-something, when the above queries
> performed as expected returning midnight in the current time zone but I
> haven't been able to find a change document indicating this as an expected
> change.

A bit of experimenting says the current behavior dates to 9.2.
I've not checked the release notes to see if it was documented,
but in any case it's stood for long enough now that I doubt
we'd change it.

                        regards, tom lane


Reply via email to