Here is a better example that shows what I actually have in my database.
Suppose I have this table, with UTC timestamps in it:
template1=> create table test ( a timestamptz not null primary key );
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index
"test_pkey" for table "test"
CREATE TABLE
template1=> insert into test values ('2011-10-30 00:00:00'::timestamp at
time zone 'UTC');
INSERT 0 1
template1=> insert into test values ('2011-10-30 01:00:00'::timestamp at
time zone 'UTC');
INSERT 0 1
template1=> set datestyle to "postgres, postgres";
SET
template1=> select * from test;
a
------------------------------
Sun Oct 30 00:00:00 2011 UTC
Sun Oct 30 01:00:00 2011 UTC
(2 rows)
I would like to see the same values, just converted into a different
time zone. But still have timestamptz type!
So I try this:
template1=> select a at time zone 'Europe/Budapest' from test;
timezone
--------------------------
Sun Oct 30 02:00:00 2011
Sun Oct 30 02:00:00 2011
(2 rows)
Which is not good, because the zone information was lost, and so I see
identical values, but they should be different.
Casting to timestamptz doesn't help either, because casting happens
after the time zone information was lost:
template1=> select (a at time zone 'Europe/Budapest')::timestamptz from
test;
timezone
------------------------------
Sun Oct 30 02:00:00 2011 UTC
Sun Oct 30 02:00:00 2011 UTC
(2 rows)
template1=>
So how do I create a query that results in something like:
a
------------------------------
Sun Oct 30 02:00:00 2011 +0500
Sun Oct 30 02:00:00 2011 +0600
(2 rows)