Thread: SQL timestamp to date cast

SQL timestamp to date cast

From
"Andrei Bintintan"
Date:
Hi,
 
I have the following query:
 
SELECT DISTINCT(nummer) FROM user_action WHERE datetime::date='11/11/2004' AND id_action IN (5,6,9)
 
Now, datetime has the type timestamp. How can I make an index or write different this query so that it runs faster? It really takes some time sometimes. Usually about 3-4secs. user_action has about 300k rows and increasing ~ 5-10k a day.
 
 
Explain analyze SELECT DISTINCT(nummer) FROM user_action WHERE datetime::date='11/11/2004' AND id_action IN (5,6,9)
 
Unique  (cost=18141.71..18143.72 rows=45 width=4) (actual time=418.122..418.340 rows=85 loops=1)
  ->  Sort  (cost=18141.71..18142.72 rows=402 width=4) (actual time=418.119..418.194 rows=192 loops=1)
        Sort Key: nummer
        ->  Seq Scan on user_action  (cost=0.00..18124.33 rows=402 width=4) (actual time=366.240..417.890 rows=192 loops=1)
              Filter: (((datetime)::date = '2004-11-11'::date) AND ((id_action = 5) OR (id_action = 6) OR (id_action = 9)))
Total runtime: 418.419 ms
 
Best regards.
Andy.

Re: SQL timestamp to date cast

From
Michael Fuhr
Date:
On Thu, Jan 20, 2005 at 10:52:50AM +0200, Andrei Bintintan wrote:

> SELECT DISTINCT(nummer)
> FROM user_action
> WHERE datetime::date='11/11/2004' AND id_action IN (5,6,9)
> 
> Now, datetime has the type timestamp. How can I make an index or write
> different this query so that it runs faster?

You could create an index on datetime and rewrite your queries:

CREATE INDEX user_action_datetime_idx ON user_action (datetime);

SELECT DISTINCT(nummer)
FROM user_action
WHERE datetime >= '11/11/2004' AND datetime < '11/12/2004' AND id_action IN (5,6,9);

Another possibility would be to create a functional index on datetime:

CREATE INDEX user_action_date_idx ON user_action (date(datetime));

SELECT DISTINCT(nummer)
FROM user_action
WHERE date(datetime) = '11/11/2004' AND id_action IN (5,6,9);

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


Re: SQL timestamp to date cast

From
"Andrei Bintintan"
Date:
> Another possibility would be to create a functional index on datetime:
>
> CREATE INDEX user_action_date_idx ON user_action (date(datetime));

GREAT!!! I thought it is possible but I didn't knew how to make such 
indexes. :))

Thank you !!!
Andy.

----- Original Message ----- 
From: "Michael Fuhr" <mike@fuhr.org>
To: "Andrei Bintintan" <klodoma@ar-sd.net>
Cc: <pgsql-sql@postgresql.org>
Sent: Thursday, January 20, 2005 11:33 AM
Subject: Re: [SQL] SQL timestamp to date cast


> On Thu, Jan 20, 2005 at 10:52:50AM +0200, Andrei Bintintan wrote:
>
>> SELECT DISTINCT(nummer)
>> FROM user_action
>> WHERE datetime::date='11/11/2004' AND id_action IN (5,6,9)
>>
>> Now, datetime has the type timestamp. How can I make an index or write
>> different this query so that it runs faster?
>
> You could create an index on datetime and rewrite your queries:
>
> CREATE INDEX user_action_datetime_idx ON user_action (datetime);
>
> SELECT DISTINCT(nummer)
> FROM user_action
> WHERE datetime >= '11/11/2004' AND datetime < '11/12/2004'
>  AND id_action IN (5,6,9);
>
> Another possibility would be to create a functional index on datetime:
>
> CREATE INDEX user_action_date_idx ON user_action (date(datetime));
>
> SELECT DISTINCT(nummer)
> FROM user_action
> WHERE date(datetime) = '11/11/2004' AND id_action IN (5,6,9);
>
> -- 
> Michael Fuhr
> http://www.fuhr.org/~mfuhr/
> 



Re: SQL timestamp to date cast

From
Michael Fuhr
Date:
On Thu, Jan 20, 2005 at 11:41:41AM +0200, Andrei Bintintan wrote:
> >Another possibility would be to create a functional index on datetime:
> >
> >CREATE INDEX user_action_date_idx ON user_action (date(datetime));
> 
> GREAT!!! I thought it is possible but I didn't knew how to make such 
> indexes. :))

See the "Indexes on Expressions" section in the "Indexes" chapter
of the documentation.

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