Re: Querying date_time for date only ?

From: Bruce Momjian <pgman(at)candle(dot)pha(dot)pa(dot)us>
To: aarni(at)kymi(dot)com
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Querying date_time for date only ?
Date: 2005-12-22 16:01:17
Message-ID: 200512221601.jBMG1H807869@candle.pha.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Aarni Ruuhimki wrote:
> Hello List,
>
> I have a time stamp without time zone field, YYYY-MM-DD hh:mm:ss, in
> my table. I want to also find something just for a particular day
> regardless of the time.
>
> (Pg)SQL way to do this ?

Yes. You can use date_trunc():

test=> select date_trunc('day', '2004-01-04 04:02:03'::timestamp);
date_trunc
---------------------
2004-01-04 00:00:00
(1 row)

so it would be date_trunc('day', col) = '2004-01-05'. The problem with
this is that you cannot use an index unless you create an expression
index on the date_trunc() function call. Another option is to do
something like:

WHERE col >= '2004-01-04' AND col < '2004-01-05'

If the date isn't a constant, you have to use date_trunc() on those, and
add one day to the second comparison:

WHERE col >= date_trunc('day', col2) AND
col < date_trunc('day', col2) + '1 day';

--
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

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Alexander Stanier 2005-12-22 17:13:51 Re: How to increase row deletion efficiency?
Previous Message Bruce Momjian 2005-12-22 04:07:13 Re: Does VACUUM reorder tables on clustered indices