Thread: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
From
H Witt
Date:
select
'2025-02-03 15:04:05'::timestamptz at time zone '+08:00',
'2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'
display
|2025-02-02 23:04:05.000|2025-02-03 15:04:05.000|
Re: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
From
Tom Lane
Date:
H Witt <i5d@live.com> writes: > select > '2025-02-03 15:04:05'::timestamptz at time zone '+08:00', > '2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai' They're different because '+08:00' is read as a POSIX time zone specification, which has the opposite sign convention to what you are thinking. See https://www.postgresql.org/docs/current/datatype-datetime.html#DATATYPE-TIMEZONES and especially https://www.postgresql.org/docs/current/datetime-posix-timezone-specs.html and remember the adage "The great thing about standards is there are so many to choose from". Sadly, with only two relevant standards humanity has still managed to cover the design space of which direction from Greenwich gets the positive sign. regards, tom lane
Re: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
From
"David G. Johnston"
Date:
On Mon, Apr 28, 2025 at 7:40 PM H Witt <i5d@live.com> wrote:
select'2025-02-03 15:04:05'::timestamptz at time zone '+08:00','2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'display|2025-02-02 23:04:05.000|2025-02-03 15:04:05.000|
When you write the former you get the POSIX convention for sign meaning (+ == West). When you write the latter you get the ISO convention (+ == East)
Since people expect ISO conventions you should stick to using the zone names and forget explicit offsets (and even the abbreviations for good measure) even exist.
David J.
Re: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
From
Bruce Momjian
Date:
On Tue, Apr 29, 2025 at 02:40:45AM +0000, H Witt wrote: > select > '2025-02-03 15:04:05'::timestamptz at time zone '+08:00', > '2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai' > > display > |2025-02-02 23:04:05.000|2025-02-03 15:04:05.000| The sign is wrong in the first column: SELECT '2025-02-03 15:04:05'::timestamptz at time zone '-08:00', '2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai' ; timezone | timezone ---------------------+--------------------- 2025-02-04 04:04:05 | 2025-02-04 04:04:05 See: https://www.postgresql.org/docs/current/datetime-posix-timezone-specs.html The offset fields specify the hours, and optionally minutes and seconds, difference from UTC. They have the format hh[:mm[:ss]] optionally with a leading sign (+ or -). The positive sign is used for zones west of Greenwich. (Note that this is the opposite of the ISO-8601 sign convention used elsewhere in PostgreSQL.) hh can have one or two digits; mm and ss (if used) must have two. -- Bruce Momjian <bruce@momjian.us> https://momjian.us EDB https://enterprisedb.com Do not let urgent matters crowd out time for investment in the future.
回复: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
From
H Witt
Date:
Hi all,
Thanks for explaining. I have got it.
发件人: Bruce Momjian <bruce@momjian.us>
发送时间: 2025年4月29日 11:09
收件人: H Witt <i5d@live.com>
抄送: pgsql-novice@lists.postgresql.org <pgsql-novice@lists.postgresql.org>
主题: Re: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
发送时间: 2025年4月29日 11:09
收件人: H Witt <i5d@live.com>
抄送: pgsql-novice@lists.postgresql.org <pgsql-novice@lists.postgresql.org>
主题: Re: why at time zone tz_offset not equal tz_name? tz_name has same offset in pg_timezone_names
On Tue, Apr 29, 2025 at 02:40:45AM +0000, H Witt wrote:
> select
> '2025-02-03 15:04:05'::timestamptz at time zone '+08:00',
> '2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'
>
> display
> |2025-02-02 23:04:05.000|2025-02-03 15:04:05.000|
The sign is wrong in the first column:
SELECT
'2025-02-03 15:04:05'::timestamptz at time zone '-08:00',
'2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'
;
timezone | timezone
---------------------+---------------------
2025-02-04 04:04:05 | 2025-02-04 04:04:05
See:
https://www.postgresql.org/docs/current/datetime-posix-timezone-specs.html
The offset fields specify the hours, and optionally minutes and
seconds, difference from UTC. They have the format hh[:mm[:ss]]
optionally with a leading sign (+ or -). The positive sign is used
for zones west of Greenwich. (Note that this is the opposite of
the ISO-8601 sign convention used elsewhere in PostgreSQL.) hh
can have one or two digits; mm and ss (if used) must have two.
--
Bruce Momjian <bruce@momjian.us> https://momjian.us
EDB https://enterprisedb.com
Do not let urgent matters crowd out time for investment in the future.
> select
> '2025-02-03 15:04:05'::timestamptz at time zone '+08:00',
> '2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'
>
> display
> |2025-02-02 23:04:05.000|2025-02-03 15:04:05.000|
The sign is wrong in the first column:
SELECT
'2025-02-03 15:04:05'::timestamptz at time zone '-08:00',
'2025-02-03 15:04:05'::timestamptz at time zone 'Asia/Shanghai'
;
timezone | timezone
---------------------+---------------------
2025-02-04 04:04:05 | 2025-02-04 04:04:05
See:
https://www.postgresql.org/docs/current/datetime-posix-timezone-specs.html
The offset fields specify the hours, and optionally minutes and
seconds, difference from UTC. They have the format hh[:mm[:ss]]
optionally with a leading sign (+ or -). The positive sign is used
for zones west of Greenwich. (Note that this is the opposite of
the ISO-8601 sign convention used elsewhere in PostgreSQL.) hh
can have one or two digits; mm and ss (if used) must have two.
--
Bruce Momjian <bruce@momjian.us> https://momjian.us
EDB https://enterprisedb.com
Do not let urgent matters crowd out time for investment in the future.