Обсуждение: SQL help for efficient time handling..

Поиск
Список
Период
Сортировка

SQL help for efficient time handling..

От
Rajesh Kumar Mallah
Дата:
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.03rows=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.



Re: SQL help for efficient time handling..

От
Popeanga Marian
Дата:
Hello Mallah,

Have you tryed this :
     SELECT  time_id from time_dimension where sql_time=cast(now() as time without time zone);

Your tabel is indexed for a time h:m:s and you should to have a where 
clause with a time value like this index is defined. Other way you will 
have a filter scan.

Rajesh Kumar Mallah wrote:

>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.03rows=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.
>
>
>  
>

-- 
Popeanga Marian
DBA Oracle
CNLO Romania



Re: SQL help for efficient time handling..

От
Rajesh Kumar Mallah
Дата:
nopes!

does not match any record..
SELECT  time_id from time_dimension where sql_time=cast( now() as time without time zone);
+---------+
| time_id |
+---------+
+---------+
(0 rows)


On Saturday 22 Mar 2003 2:15 pm, Popeanga Marian wrote:
> Hello Mallah,
> 
> Have you tryed this :
> 
>       SELECT  time_id from time_dimension where sql_time=cast(now() as time without time zone);
> 
> Your tabel is indexed for a time h:m:s and you should to have a where 
> clause with a time value like this index is defined. Other way you will 
> have a filter scan.
> 
> Rajesh Kumar Mallah wrote:
> 
> >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.03rows=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.
> >
> >
> >  
> >
> 
> -- 
> Popeanga Marian
> DBA Oracle
> CNLO Romania
> 
> 
> 
> 
> 

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



Re: SQL help for efficient time handling..

От
Popeanga Marian
Дата:
<br />           I don't see any other solution than creating differrent columns for hours, minutes and index them.<br
/><br/><br /><br /> Rajesh Kumar Mallah wrote:<br /><blockquote cite="mid200303221425.02824.mallah@trade-india.com"
type="cite"><prewrap="">nopes!
 

does not match any record..
SELECT  time_id from time_dimension where sql_time=cast( now() as time without time zone);
+---------+
| time_id |
+---------+
+---------+
(0 rows)


On Saturday 22 Mar 2003 2:15 pm, Popeanga Marian wrote: </pre><blockquote type="cite"><pre wrap="">Hello Mallah,

Have you tryed this :
     SELECT  time_id from time_dimension where sql_time=cast(now() as time without time zone);

Your tabel is indexed for a time h:m:s and you should to have a where 
clause with a time value like this index is defined. Other way you will 
have a filter scan.

Rajesh Kumar Mallah wrote:
   </pre><blockquote type="cite"><pre wrap="">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.03rows=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.


     </pre></blockquote><pre wrap="">-- 
Popeanga Marian
DBA Oracle
CNLO Romania




   </pre></blockquote><pre wrap=""> </pre></blockquote><br /><pre class="moz-signature" cols="$mailwrapcol">-- 
Popeanga Marian
DBA Oracle
CNLO Romania
</pre><br />

Re: SQL help for efficient time handling..

От
Stephan Szabo
Дата:
On Sat, 22 Mar 2003, Rajesh Kumar Mallah wrote:

> 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

How about something like:

select time_id from time_dimension where sql_time=cast(date_trunc('minute', now()) as time);



Re: SQL help for efficient time handling..

От
Дата:

Hey it Worked!! ,

tradein_clients=# explain analyze select time_id from general.time_dimension where sql_time=
cast(date_trunc('minute', now()) as time);                                                                QUERY PLAN

------------------------------------------------------------------------------------------------------------------------------------------
IndexScan using time_dimension_sql_time_key on time_dimension  (cost=0.00..3.02 rows=1 width=4)(actual time=0.06..0.06
rows=1loops=1)   Index Cond: (sql_time = (date_trunc('minute'::text, now()))::time without time zone)Total runtime:
0.11msec 
(3 rows)

tradein_clients=#


>
> On Sat, 22 Mar 2003, Rajesh Kumar Mallah wrote:
>
>> 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
>
> How about something like:
>
> select time_id from time_dimension where sql_time=
> cast(date_trunc('minute', now()) as time);
>
>
> ---------------------------(end of broadcast)--------------------------- TIP 2: you can get off
> all lists at once with the unregister command
>    (send "unregister YourEmailAddressHere" to majordomo@postgresql.org)



-----------------------------------------
Get your free web based email at trade-india.com.  "India's Leading B2B eMarketplace.!"
http://www.trade-india.com/