Hello all!
On PostgreSQL V7.3.2 on TRU64 I recognized the following phenomena
that a SELECT using a difference of a timestamp and an interval
in the WHERE clause does not use the index
but using a timestamp without a difference does use the index.
The semantic of both SELECT's is equal, i.e., the result is equal.
Therefore, the second way is much faster.
Any ideas?
In detail:
table:
wetter=# \d wetter
Table "public.wetter"
Column | Type | Modifiers
-----------+--------------------------+-----------
sensor_id | integer | not null
epoche | timestamp with time zone | not null
wert | real | not null
Indexes: wetter_pkey primary key btree (sensor_id, epoche),
wetter_epoche_idx btree (epoche),
wetter_sensor_id_idx btree (sensor_id)
Triggers: RI_ConstraintTrigger_45702811,
t_ins_wetter_wetterakt
Select not using index:
-----------------------
wetter=# explain select * from wetter where epoche between
'2003-05-06 06:50:54+00'::timestamp-'1 days'::interval
AND '2003-05-06 04:45:36';
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Seq Scan on wetter (cost=0.00..768644.57 rows=10253528 width=16)
Filter: ((epoche >= ('2003-05-05 06:50:54'::timestamp without time
zone)::timestamp with time zone) AND (epoche <= '2003-05-06
04:45:36+00'::timestamp with time zone))
(2 rows)
wetter=#
Select using the index:
-----------------------
explain select * from wetter where epoche between '2003-05-05 06:50:54'
AND '2003-05-06 04:45:36';
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------------------------------
Index Scan using wetter_epoche_idx on wetter (cost=0.00..5.45 rows=1
width=16)
Index Cond: ((epoche >= '2003-05-05 06:50:54+00'::timestamp with
time zone) AND (epoche <= '2003-05-06 04:45:36+00'::timestamp with time
zone))
(2 rows)
wetter=#
--
Mit freundlichen Gruessen / With best regards
Reiner Dassing