Re: Time zone offset in to_char() - Mailing list pgsql-general

From Jim Nasby
Subject Re: Time zone offset in to_char()
Date
Msg-id cc4d16e8-3263-41e1-9a82-4410c0bdd347@gmail.com
Whole thread Raw
In response to Time zone offset in to_char()  (Alban Hertroijs <a.hertroijs@nieuwestroom.nl>)
Responses Re: Time zone offset in to_char()  (Adrian Klaver <adrian.klaver@aklaver.com>)
List pgsql-general
On 1/11/24 9:06 AM, Alban Hertroijs wrote:
> I'm basically looking for a one-liner to convert a timestamptz (or a 
> timestamp w/o time zone if that turns out to be more convenient) to a 
> string format equal to what MS uses for their datetimeoffset type. I got 
> almost there with to_char(ts, 'YYYY-MM-DD HH24:MI:SS.US0 TZH:TZM'). 
> Unfortunately(?), the server lives at time zone UTC, while we need to 
> convert to both UTC and Europe/Amsterdam zones. The above always gives 
> me +00 for the TZH output, while it should be +01 now and +02 in the 
> summer...

The issue here is that timestamptz doesn't store the original timezone; 
it always converts whatever is passed in to UTC and stores that. When 
you read the timezone back, by default it will be in the timezone 
specified in the TimeZone GUC. While there's a bunch of ways you can set 
that, for what you're looking to do I don't think any of them are 
appropriate; instead you want to use either AT TIME ZONE or timezone():

create table tstz(tstz timestamptz);
insert into tstz values(now());
SHOW timezone;
  TimeZone
----------
  CST6CDT
(1 row)

select * from tstz ;
              tstz
------------------------------
  2024-01-11 17:29:00.04933-06
(1 row)

select timezone('UTC',tstz) from tstz ;
          timezone
---------------------------
  2024-01-11 23:29:00.04933
(1 row)

select tstz AT TIME ZONE 'UTC' from tstz ;
          timezone
---------------------------
  2024-01-11 23:29:00.04933
(1 row)

-- 
Jim Nasby, Data Architect, Austin TX




pgsql-general by date:

Previous
From: Tom Lane
Date:
Subject: Re: undefined symbol when installing pgcrypto on 16.1
Next
From: "Keaney, Will"
Date:
Subject: RE: Postgres 13 streaming replication standby not sending password, 'fe_sendauth: no password supplied'