Thread: TIMESTAMP with a timezone offset

TIMESTAMP with a timezone offset

From
Madison Kelly
Date:
Hi all,

   I've got a database with a column I CAST as a TIMESTAMP. The data in
the database is GMT.

   I want to say in my WHERE clause to offset the value I am giving by X
number of hours and to display the column I've cast as a timestamp
offset by the same X hours.

   I am sure this is possible, and probably fairly simple. :)

Here a simplified query I am using that currently has no TZ data:

'bar' is a timestamp from the system, 'baz' is a string from an external
source CAST as a timestamp.

SELECT
   foo,
   bar,
   CAST (baz AS TIMESTAMP) AS last_state_change
FROM
   history.table
WHERE
   bar >= '2008-12-15 14:01:09' AND foo=153;

Thanks!

Madi

Re: TIMESTAMP with a timezone offset

From
Raymond O'Donnell
Date:
On 16/12/2008 19:16, Madison Kelly wrote:
>   I want to say in my WHERE clause to offset the value I am giving by X
> number of hours and to display the column I've cast as a timestamp
> offset by the same X hours.

You could use AT TIME ZONE to shift it the required number of hours:

http://www.postgresql.org/docs/8.3/static/functions-datetime.html#FUNCTIONS-DATETIME-ZONECONVERT

I hope this helps.

Ray.


------------------------------------------------------------------
Raymond O'Donnell, Director of Music, Galway Cathedral, Ireland
rod@iol.ie
Galway Cathedral Recitals: http://www.galwaycathedral.org/recitals
------------------------------------------------------------------

Re: TIMESTAMP with a timezone offset

From
Madison Kelly
Date:
Raymond O'Donnell wrote:
> On 16/12/2008 19:16, Madison Kelly wrote:
>>   I want to say in my WHERE clause to offset the value I am giving by X
>> number of hours and to display the column I've cast as a timestamp
>> offset by the same X hours.
>
> You could use AT TIME ZONE to shift it the required number of hours:
>
> http://www.postgresql.org/docs/8.3/static/functions-datetime.html#FUNCTIONS-DATETIME-ZONECONVERT
>
> I hope this helps.
>
> Ray.

I was reading that before posting, but have not been able to get it to
work. After looking at it again I think it's because I've cast the
column I restricted in the SELECT as a 'TIMESTAMP WITHOUT TIME ZONE'. So
I ALTERed the column to be 'TIMESTAMP WITH TIME ZONE' and tried again.
However, it looks like it cast the time zone on each column to my
current time zone instead of UTC. After ALTERing the column and using
the AT TIME ZONE 'EST' it returns values five hours ahead.

So now I have another question... How can I recast a column to specify
that the current values are UTC timestamps?

Thanks!

Madi

Re: TIMESTAMP with a timezone offset

From
Tom Lane
Date:
Madison Kelly <linux@alteeve.com> writes:
> I was reading that before posting, but have not been able to get it to
> work. After looking at it again I think it's because I've cast the
> column I restricted in the SELECT as a 'TIMESTAMP WITHOUT TIME ZONE'. So
> I ALTERed the column to be 'TIMESTAMP WITH TIME ZONE' and tried again.
> However, it looks like it cast the time zone on each column to my
> current time zone instead of UTC.

Yeah, the default conversion from TS-without-TZ to TS-with-TZ assumes
that the TS-without-TZ values are in your current timezone.  You might
be able to get what you want by setting timezone to UTC temporarily
while doing the ALTER.  However, that approach might give you headaches
with inserting more data --- you might find yourself needing to keep
timezone = UTC all the time, which might create troubles elsewhere.

Another way to do it is, if you're starting from TS-without-TZ data
that you want to consider as being in UTC, is

    (ts_value AT TIME ZONE 'UTC') AT TIME ZONE 'EST'

The first conversion says "this TS-without-TZ data is in UTC, now
produce a correct TS-with-TZ from it".  And then the second one
rotates that back to local time in EST.

            regards, tom lane