Timezone bugs

Lists: pgsql-hackerspgsql-patches
From: "Kevin McArthur" <postgresql-list(at)stormtide(dot)ca>
To: <pgsql-hackers(at)postgresql(dot)org>
Subject: Timezone bugs
Date: 2005-07-21 00:01:53
Message-ID: 002d01c58d87$67a057b0$0701a8c0@kdesktop
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches

There appear to be several bugs in the at time zone patch recently applied.

show timezone;
TimeZone
----------
UTC
(1 row)

select now();
now
-------------------------------
2005-07-20 23:38:57.981128+00
(1 row)

*** WORKS ***

select CURRENT_DATE + '05:00'::time at time zone 'Canada/Pacific';
?column?
------------------------
2005-07-21 05:00:00+00
(1 row)

*** BROKEN ***

select (CURRENT_DATE + '05:00'::time)::timestamp at time zone 'Canada/Pacific';
timezone
------------------------
2005-07-19 22:00:00+00
(1 row)

Wrong date _and_ time. (Ive not even got a theory about how the date gets wrong here)

select '05:00'::time at time zone 'Canada/Pacific';
timezone
-------------
22:00:00-07
(1 row)

Wrong time.

I think there's something fishy going on with internal casts.

if time has no timezone it should not imply a cast to timetz using the local timezone, instead time to at time zone should ADD timezone information to the datatype to result in a timetz though that may require the use of something like select '05:00'::time at time zone 'Canada/Pacific' on CURRENT_DATE::date to do properly.

Suggested resolution would be to allow the actual storage of named timezone descriptions like 'Canada/Pacfiic' within the timetz datatype natively instead of converting to utc for storage (which is logically invalid).

The application of this whole problem is for a VoIP network to be able to handle evening and weekend calling based on cities. Evening being after 6pm in vacouver per se. Current and historical processing of the time zone data is also a requirement.

Hope that helps.

Kevin McArthur

Director
StormTide Digital Studios Inc.


From: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
To: Kevin McArthur <postgresql-list(at)stormtide(dot)ca>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Timezone bugs
Date: 2005-07-22 03:57:35
Message-ID: 200507220357.j6M3vZI04199@candle.pha.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches


My guess is that is this commit that is causing the problem:

revision 1.110
date: 2005/06/15 00:34:08; author: momjian; state: Exp; lines: +48 -40
This patch makes it possible to use the full set of timezones when doing
"AT TIME ZONE", and not just the shorlist previously available. For
example:

SELECT CURRENT_TIMESTAMP AT TIME ZONE 'Europe/London';

works fine now. It will also obey whatever DST rules were in effect at
just that date, which the previous implementation did not.

It also supports the AT TIME ZONE on the timetz datatype. The whole
handling of DST is a bit bogus there, so I chose to make it use whatever
DST rules are in effect at the time of executig the query. not sure if
anybody is actuallyi *using* timetz though, it seems pretty
unpredictable just because of this...

Magnus Hagander

I will research it tomorrow and report back.

---------------------------------------------------------------------------

Kevin McArthur wrote:
> There appear to be several bugs in the at time zone patch recently applied.
>
>
> show timezone;
> TimeZone
> ----------
> UTC
> (1 row)
>
> select now();
> now
> -------------------------------
> 2005-07-20 23:38:57.981128+00
> (1 row)
>
>
> *** WORKS ***
>
>
> select CURRENT_DATE + '05:00'::time at time zone 'Canada/Pacific';
> ?column?
> ------------------------
> 2005-07-21 05:00:00+00
> (1 row)
>
>
> *** BROKEN ***
>
>
> select (CURRENT_DATE + '05:00'::time)::timestamp at time zone 'Canada/Pacific';
> timezone
> ------------------------
> 2005-07-19 22:00:00+00
> (1 row)
>
> Wrong date _and_ time. (Ive not even got a theory about how the date gets wrong here)
>
>
> select '05:00'::time at time zone 'Canada/Pacific';
> timezone
> -------------
> 22:00:00-07
> (1 row)
>
> Wrong time.
>
>
> I think there's something fishy going on with internal casts.
>
> if time has no timezone it should not imply a cast to timetz using the local timezone, instead time to at time zone should ADD timezone information to the datatype to result in a timetz though that may require the use of something like select '05:00'::time at time zone 'Canada/Pacific' on CURRENT_DATE::date to do properly.
>
> Suggested resolution would be to allow the actual storage of named timezone descriptions like 'Canada/Pacfiic' within the timetz datatype natively instead of converting to utc for storage (which is logically invalid).
>
> The application of this whole problem is for a VoIP network to be able to handle evening and weekend calling based on cities. Evening being after 6pm in vacouver per se. Current and historical processing of the time zone data is also a requirement.
>
> Hope that helps.
>
> Kevin McArthur
>
> Director
> StormTide Digital Studios Inc.
>
>
>

--
Bruce Momjian | http://candle.pha.pa.us
pgman(at)candle(dot)pha(dot)pa(dot)us | (610) 359-1001
+ If your life is a hard drive, | 13 Roberts Road
+ Christ can be your backup. | Newtown Square, Pennsylvania 19073


From: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
To: Kevin McArthur <postgresql-list(at)stormtide(dot)ca>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Timezone bugs
Date: 2005-07-22 05:00:45
Message-ID: 200507220500.j6M50jK07083@candle.pha.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches

Kevin McArthur wrote:
> There appear to be several bugs in the at time zone patch recently applied.
>
>
> show timezone;
> TimeZone
> ----------
> UTC
> (1 row)
>
> select now();
> now
> -------------------------------
> 2005-07-20 23:38:57.981128+00
> (1 row)
>
>
> *** WORKS ***
>
>
> select CURRENT_DATE + '05:00'::time at time zone 'Canada/Pacific';
> ?column?
> ------------------------
> 2005-07-21 05:00:00+00
> (1 row)

OK.

> *** BROKEN ***
>
>
> select (CURRENT_DATE + '05:00'::time)::timestamp at time zone 'Canada/Pacific';
> timezone
> ------------------------
> 2005-07-19 22:00:00+00
> (1 row)
>
> Wrong date _and_ time. (Ive not even got a theory about how the date gets wrong here)

What is happening here is that 2005-07-20 05:00:00 is being cast back 7
hours (Canada/Pacific offset), and that is 22:00 of the previous day.

>
>
> select '05:00'::time at time zone 'Canada/Pacific';
> timezone
> -------------
> 22:00:00-07
> (1 row)
>
> Wrong time.

Well, again 5am GMT is 22:00 Canada/Pacific, no?

---------------------------------------------------------------------------

> I think there's something fishy going on with internal casts.
>
> if time has no timezone it should not imply a cast to timetz using the
> local timezone, instead time to at time zone should ADD timezone
> information to the datatype to result in a timetz though that may
> require the use of something like select '05:00'::time at time zone
> 'Canada/Pacific' on CURRENT_DATE::date to do properly.
>
> Suggested resolution would be to allow the actual storage of named
> timezone descriptions like 'Canada/Pacfiic' within the timetz datatype
> natively instead of converting to utc for storage (which is logically
> invalid).
>
> The application of this whole problem is for a VoIP network to be able
> to handle evening and weekend calling based on cities. Evening being
> after 6pm in vacouver per se. Current and historical processing of the
> time zone data is also a requirement.
>
> Hope that helps.
>
> Kevin McArthur
>
> Director
> StormTide Digital Studios Inc.
>
>
>

--
Bruce Momjian | http://candle.pha.pa.us
pgman(at)candle(dot)pha(dot)pa(dot)us | (610) 359-1001
+ If your life is a hard drive, | 13 Roberts Road
+ Christ can be your backup. | Newtown Square, Pennsylvania 19073


From: Jeff Trout <threshar(at)torgo(dot)978(dot)org>
To: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Timezone bugs
Date: 2005-07-22 12:49:18
Message-ID: 9353B19D-69C4-4914-B37D-D74C0E131FC3@torgo.978.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches


On Jul 21, 2005, at 11:57 PM, Bruce Momjian wrote:

> works fine now. It will also obey whatever DST rules were in
effect at
> just that date, which the previous implementation did not.

Speaking of that, would the nearly passed US bill to extend daylight
savings screw up our timezone & dst things?

http://usgovinfo.about.com/od/consumerawareness/a/dstextend.htm

(nutshell summary: DST would be changed from april-oct to mar-nov)

afaik it has passed the house & senate it just needs the prez to sign
it.
--
Jeff Trout <jeff(at)jefftrout(dot)com>
http://www.jefftrout.com/
http://www.stuarthamm.net/


From: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
To: Jeff Trout <threshar(at)torgo(dot)978(dot)org>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Timezone bugs
Date: 2005-07-22 14:16:34
Message-ID: 200507221416.j6MEGYk02162@candle.pha.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches

Jeff Trout wrote:
>
> On Jul 21, 2005, at 11:57 PM, Bruce Momjian wrote:
>
> > works fine now. It will also obey whatever DST rules were in
> effect at
> > just that date, which the previous implementation did not.
>
> Speaking of that, would the nearly passed US bill to extend daylight
> savings screw up our timezone & dst things?
>
> http://usgovinfo.about.com/od/consumerawareness/a/dstextend.htm
>
> (nutshell summary: DST would be changed from april-oct to mar-nov)
>
> afaik it has passed the house & senate it just needs the prez to sign
> it.

It means we would have to update our timezone database, and perhaps
backpatch the fix to 8.0.X.

--
Bruce Momjian | http://candle.pha.pa.us
pgman(at)candle(dot)pha(dot)pa(dot)us | (610) 359-1001
+ If your life is a hard drive, | 13 Roberts Road
+ Christ can be your backup. | Newtown Square, Pennsylvania 19073


From: Andrew - Supernews <andrew+nonews(at)supernews(dot)com>
To: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Timezone bugs
Date: 2005-07-22 14:36:20
Message-ID: slrnde2134.2k2r.andrew+nonews@trinity.supernews.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches

On 2005-07-22, Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us> wrote:
>>
>> select (CURRENT_DATE + '05:00'::time)::timestamp
>> at time zone 'Canada/Pacific';
>> timezone
>> ------------------------
>> 2005-07-19 22:00:00+00
>> (1 row)
>>
> What is happening here is that 2005-07-20 05:00:00 is being cast back 7
> hours (Canada/Pacific offset), and that is 22:00 of the previous day.

Which is of course completely wrong.

Let's look at what should happen:

(date + time) = timestamp without time zone

'2005-07-20' + '05:00' = '2005-07-20 05:00:00'::timestamp

(timestamp without time zone) AT TIME ZONE 'zone'

When AT TIME ZONE is applied to a timestamp without time zone, it is
supposed to keep the _same_ calendar time and return a result of type
timestamp with time zone designating the absolute time. So in this case,
we expect the following to happen:

'2005-07-20 05:00:00' (original timestamp)
-> '2005-07-20 05:00:00-0700' (same calendar time in new zone)
-> '2005-07-20 12:00:00+0000' (convert to client timezone (UTC))

So the conversion is being done backwards, resulting in the wrong result.

--
Andrew, Supernews
http://www.supernews.com - individual and corporate NNTP services


From: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
To: andrew(at)supernews(dot)com
Cc: PostgreSQL-patches <pgsql-patches(at)postgresql(dot)org>
Subject: Re: [HACKERS] Timezone bugs
Date: 2005-07-23 02:04:50
Message-ID: 200507230204.j6N24o726343@candle.pha.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-hackers pgsql-patches


OK, tricky, but fixed --- patch attached and applied, with documentation
updates. Here is the test query:

test=> select (CURRENT_DATE + '05:00'::time)::timestamp at time zone
'Canada/Pacific';
timezone
------------------------
2005-07-22 08:00:00-04
(1 row)

I tested a bunch of others too, like:

test=> select ('2005-07-20 00:00:00'::timestamp without time zone) at
time zone 'Europe/Paris';
timezone
------------------------
2005-07-19 18:00:00-04
(1 row)

and tested that for UTC also.

It was hard to figure out how to cleanly adjust the time zone. I added
some comments explaining the process.

---------------------------------------------------------------------------

Andrew - Supernews wrote:
> On 2005-07-22, Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us> wrote:
> >>
> >> select (CURRENT_DATE + '05:00'::time)::timestamp
> >> at time zone 'Canada/Pacific';
> >> timezone
> >> ------------------------
> >> 2005-07-19 22:00:00+00
> >> (1 row)
> >>
> > What is happening here is that 2005-07-20 05:00:00 is being cast back 7
> > hours (Canada/Pacific offset), and that is 22:00 of the previous day.
>
> Which is of course completely wrong.
>
> Let's look at what should happen:
>
> (date + time) = timestamp without time zone
>
> '2005-07-20' + '05:00' = '2005-07-20 05:00:00'::timestamp
>
> (timestamp without time zone) AT TIME ZONE 'zone'
>
> When AT TIME ZONE is applied to a timestamp without time zone, it is
> supposed to keep the _same_ calendar time and return a result of type
> timestamp with time zone designating the absolute time. So in this case,
> we expect the following to happen:
>
> '2005-07-20 05:00:00' (original timestamp)
> -> '2005-07-20 05:00:00-0700' (same calendar time in new zone)
> -> '2005-07-20 12:00:00+0000' (convert to client timezone (UTC))
>
> So the conversion is being done backwards, resulting in the wrong result.
>
> --
> Andrew, Supernews
> http://www.supernews.com - individual and corporate NNTP services
>
> ---------------------------(end of broadcast)---------------------------
> TIP 2: Don't 'kill -9' the postmaster
>

--
Bruce Momjian | http://candle.pha.pa.us
pgman(at)candle(dot)pha(dot)pa(dot)us | (610) 359-1001
+ If your life is a hard drive, | 13 Roberts Road
+ Christ can be your backup. | Newtown Square, Pennsylvania 19073

Attachment Content-Type Size
unknown_filename text/plain 6.3 KB