Re: Problem in converting int to timestamp value - why?

From: Michael Fuhr <mike(at)fuhr(dot)org>
To: Soeren Gerlach <soeren(at)all-about-shift(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Problem in converting int to timestamp value - why?
Date: 2004-09-19 15:12:32
Message-ID: 20040919151232.GA94970@winnie.fuhr.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

On Sun, Sep 19, 2004 at 04:17:52PM +0200, Soeren Gerlach wrote:

> I've an integer column in a certain table that I need to convert into a
> timestamp value to finally get a day difference to the current date.
> >From the manual it looks like straight forward, but the following line
> is a great mistery for me:
>
> SELECT to_timestamp(to_char(20041217, '9999 99 99'), 'YYYY MM DD')
>
> results in a timestamp "2171-11-05 22:00:00" ??? The int-to-char
> conversion works well ("2004 12 17") but the to_timestamp() doesn't work
> as expected - why?

to_char() is returning a leading space:

test=> SELECT 'x' || to_char(20041217, '9999 99 99') || 'y';
?column?
---------------
x 2004 12 17y

The leading space is confusing to_timestamp():

test=> SELECT to_timestamp(' 2004 12 17', 'YYYY MM DD');
to_timestamp
---------------------
2171-11-06 06:00:00

You can tell to_timestamp() to account for the leading space or you
can tell to_char() to suppress it:

test=> SELECT to_timestamp(to_char(20041217, '9999 99 99'), ' YYYY MM DD');
to_timestamp
------------------------
2004-12-17 00:00:00-07

test=> SELECT to_timestamp(to_char(20041217, 'FM9999 99 99'), 'YYYY MM DD');
to_timestamp
------------------------
2004-12-17 00:00:00-07

--
Michael Fuhr
http://www.fuhr.org/~mfuhr/

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Greg Stark 2004-09-19 16:03:05 Re: order of row processing affects updates
Previous Message Jim J 2004-09-19 14:30:15 Re: order of row processing affects updates