Thread: Non-standard TIMESTAMP WITH TIME ZONE literal handling
Hello, In Jim Melton and Alan Simon's "SQL:1999 - Understanding Relational Language Components" (ISBN 1-55860-456-1), they write that the following is to be interpreted as a TIMESTAMP WITH TIME ZONE value: TIMESTAMP '2003-07-29 13:19:30.5+02:00' PostgreSQL interprets the above as a TIMESTAMP WITHOUT TIME ZONE value of '2003-07-29 13:19:30.5', i.e. it simply discards the '+02:00' part and fails to interpret it as being of TIMESTAMP WITH TIME ZONE type. Unless Melton+Simon are wrong, PostgreSQL is not completely following SQL:1999 regarding TIMESTAMP-like literal parsing. Furthermore, as Oracle behaves as Melton+Simon describes, subtle, but potentially nasty portability problems can be imagined, hurting people porting to/from Oracle. -- Greetings from Troels Arvin, Copenhagen, Denmark
Troels Arvin <troels@arvin.dk> writes: > In Jim Melton and Alan Simon's "SQL:1999 - Understanding Relational > Language Components" (ISBN 1-55860-456-1), they write that the following > is to be interpreted as a TIMESTAMP WITH TIME ZONE value: > TIMESTAMP '2003-07-29 13:19:30.5+02:00' > PostgreSQL interprets the above as a TIMESTAMP WITHOUT TIME ZONE value of > '2003-07-29 13:19:30.5', i.e. it simply discards the '+02:00' part and > fails to interpret it as being of TIMESTAMP WITH TIME ZONE type. That's true, and I think we are unlikely to change it. Postgres interprets this construct as a special case of a general datatype_name 'literal string' construction. To allow the contents of the literal to determine the datatype specification would break the general construct completely. regards, tom lane
On Thu, 7 Aug 2003, Troels Arvin wrote: > Hello, > > In Jim Melton and Alan Simon's "SQL:1999 - Understanding Relational > Language Components" (ISBN 1-55860-456-1), they write that the following > is to be interpreted as a TIMESTAMP WITH TIME ZONE value: > > TIMESTAMP '2003-07-29 13:19:30.5+02:00' > > PostgreSQL interprets the above as a TIMESTAMP WITHOUT TIME ZONE value of > '2003-07-29 13:19:30.5', i.e. it simply discards the '+02:00' part and > fails to interpret it as being of TIMESTAMP WITH TIME ZONE type. > > Unless Melton+Simon are wrong, PostgreSQL is not completely following > SQL:1999 regarding TIMESTAMP-like literal parsing. I think they're correct and we're wrong: SQL92 5.3 Syntax rules: 17)The data type of a <timestamp literal> that does not specify <time zone interval> is TIMESTAMP(P), where P is the number of digits in <seconds fraction>, if specified, and 0 otherwise. The data type of a <timestamp literal> that specifies <time zone interval> is TIMESTAMP(P) WITH TIME ZONE, where P is the number of digits in <seconds fraction>, if specified, and 0 otherwise.