SQL help for efficient time handling..

From: Rajesh Kumar Mallah <mallah(at)trade-india(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: SQL help for efficient time handling..
Date: 2003-03-22 08:02:33
Message-ID: 200303221332.33121.mallah@trade-india.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql


Hi everyone,

I have a table time_dimension loaded with 1440 records
i record for each min in 24 hrs

CREATE TABLE general.time_dimension
(
time_id integer not null ,
sql_time time(0) without time zone not null,
PRIMARY KEY (time_id),
UNIQUE (sql_time)
);

sample data is like,

tradein_clients=# SELECT * from time_dimension limit 10;
+---------+----------+
| time_id | sql_time |
+---------+----------+
| 1 | 00:00:00 |
| 2 | 00:01:00 |
| 3 | 00:02:00 |
| 4 | 00:03:00 |
| 5 | 00:04:00 |
| 6 | 00:05:00 |
| 7 | 00:06:00 |
| 8 | 00:07:00 |
| 9 | 00:08:00 |
| 10 | 00:09:00 |
+---------+----------+
(10 rows)

To get current_time_id i use a query like
SELECT time_id from time_dimension where sql_time=date_trunc('minute' , cast(now() as time without time zone) );

it works but uses seq_scan
Seq Scan on time_dimension (cost=0.00..35.00 rows=5 width=4) (actual time=4.75..8.16 rows=1 loops=1)
Filter: ((sql_time)::interval = date_trunc('minute'::text, ((now())::time without time zone)::interval))
Total runtime: 8.20 msec

whereas a query like

explain analyze SELECT time_id from time_dimension where sql_time='13:13:13';
+------------------------------------------------------------------------------------------------------------------------------------------+
| QUERY PLAN |
+------------------------------------------------------------------------------------------------------------------------------------------+
| Index Scan using time_dimension_sql_time_key on time_dimension (cost=0.00..4.82 rows=1 width=4) (actual time=0.03..0.03 rows=0 loops=1) |
| Index Cond: (sql_time = '13:13:13'::time without time zone) |
| Total runtime: 0.06 msec
--------------------------------------------------------------------------------------------------------------------------------------------
take much less.

can anyone tell be the best way to get time_id from time_dimension for current_time.

any help is appreciated.

Regds
Mallah.

--
Rajesh Kumar Mallah,
Project Manager (Development)
Infocom Network Limited, New Delhi
phone: +91(11)6152172 (221) (L) ,9811255597 (M)

Visit http://www.trade-india.com ,
India's Leading B2B eMarketplace.

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Rajesh Kumar Mallah 2003-03-22 08:45:02 Re: explain
Previous Message Popeanga Marian 2003-03-22 06:11:11 Re: explain