Re: Returning timestamp with timezone at specified timezone irrespective of client timezone

Поиск
Список
Период
Сортировка
От aNullValue (Drew Stemen)
Тема Re: Returning timestamp with timezone at specified timezone irrespective of client timezone
Дата
Msg-id 8616533e-6bf1-4f74-880d-d396aede800a@www.fastmail.com
обсуждение исходный текст
Ответ на Re: Returning timestamp with timezone at specified timezone irrespective of client timezone  (Ron <ronljohnsonjr@gmail.com>)
Список pgsql-general
At 2020-09-27T19:13:09-04:00, Ron <ronljohnsonjr@gmail.com> sent:
On 9/27/20 4:16 PM, aNullValue (Drew Stemen) wrote:

Hello,

I've attempted to obtain help with this problem from several other places, but numerous individuals recommended I ask this mailing list.

What I need is for the ability to return a timestamp with timezone, using the UTC offset that corresponds to a column-defined timezone, irrespective of the client/session configured timezone.

I have three columns in a table:
Timezone: 'US/Eastern'
Date: 2020-10-31
Time: 08:00

The output I'm able to find includes these possibilities:
'2020-10-31 08:00:00'
'2020-10-31 12:00:00+00'

Whereas what I actually need is:
'2020-10-31 08:00:00-05'

Using the postgresql session-level timezone configuration won't work because I need multiple timezones to be handled in a single set.

Example code follows. I'm not using to_char in the examples as I likely would in the production code, but I haven't found any way that it could be helpful here regardless.

[snip]


id |  timezone  |  loc_date  | loc_time |         tswtz          |       tswotz
----+------------+------------+----------+------------------------+---------------------
  7 | US/Central | 2020-10-31 | 08:00    | 2020-10-31 13:00:00+00 | 2020-10-31 08:00:00
  8 | US/Central | 2020-11-03 | 08:00    | 2020-11-03 14:00:00+00 | 2020-11-03 08:00:00
  5 | US/Eastern | 2020-10-31 | 08:00    | 2020-10-31 12:00:00+00 | 2020-10-31 08:00:00
  6 | US/Eastern | 2020-11-03 | 08:00    | 2020-11-03 13:00:00+00 | 2020-11-03 08:00:00
(4 rows)

What I actually need is, in example id=7, '2020-10-31 08:00:00-05'.

Is this even possible? Several people have proposed that I write a custom function to do this on a per-row basis, which... I suppose I can do... I'm just blown away that this isn't something that just works "out of the box".


Are you really asking what the TZ offset was on a specific date (Like DST or not)?


--
Angular momentum makes the world go 'round.

What it was at a specific date/time combination, yes. PostgreSQL already has that knowledge because of its ability to accurately calculate the value above in column "tswtz". It just doesn't seem to be able to output that easily.

Though I just did realize that (obviously) I can do math to arrive at the answer I need. I'm perplexed by my not having realized that long before I considered creating this thread. -_-

This is ugly and ineligant, but it seems to work:

CASE WHEN ((timezone('UTC',(l.loc_date + l.loc_time::time without time zone)) - timezone(l.timezone, l.loc_date + l.loc_time::time without time zone))::interval) > '-00:00:01' THEN
to_char((l.loc_date + l.loc_time::time without time zone),'YYYY-MM-DD HH24:MI:SS') ||'+'|| to_char((timezone('UTC',(l.loc_date + l.loc_time::time without time zone)) - timezone(l.timezone, l.loc_date + l.loc_time::time without time zone))::interval, 'HH24:MI:SS')
ELSE
to_char((l.loc_date + l.loc_time::time without time zone),'YYYY-MM-DD HH24:MI:SS') || to_char((timezone('UTC',(l.loc_date + l.loc_time::time without time zone)) - timezone(l.timezone, l.loc_date + l.loc_time::time without time zone))::interval, 'HH24:MI:SS')
END AS correct_format




В списке pgsql-general по дате отправления:

Предыдущее
От: Greg Smith
Дата:
Сообщение: Re: Returning timestamp with timezone at specified timezone irrespective of client timezone
Следующее
От: Jeremy Schneider
Дата:
Сообщение: Re: Returning timestamp with timezone at specified timezone irrespective of client timezone