From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Chirag Patel <patelc75(at)yahoo(dot)com> |
Cc: | PostgreSQL Novice List <pgsql-novice(at)postgresql(dot)org> |
Subject: | Re: WHERE clause with timestamp data type |
Date: | 2007-08-27 05:10:50 |
Message-ID: | 13636.1188191450@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-novice |
Chirag Patel <patelc75(at)yahoo(dot)com> writes:
> The following command works great,
> SELECT AVG(column) FROM table WHERE timestamp > 2007-08-23;
No it doesn't. It might not actively fail, but it isn't selecting the
rows you think it is. You want this:
SELECT AVG(column) FROM table WHERE timestamp > '2007-08-23';
Comparing EXPLAIN outputs reveals what's really going on:
regression=# create table tab (col float, ts timestamp);
CREATE TABLE
regression=# explain SELECT AVG(col) FROM tab WHERE ts > 2007-08-23;
QUERY PLAN
------------------------------------------------------------
Aggregate (cost=35.81..35.82 rows=1 width=8)
-> Seq Scan on tab (cost=0.00..34.45 rows=543 width=8)
Filter: ((ts)::text > '1976'::text)
(3 rows)
regression=# explain SELECT AVG(col) FROM tab WHERE ts > '2007-08-23';
QUERY PLAN
---------------------------------------------------------------------------
Aggregate (cost=31.73..31.75 rows=1 width=8)
-> Seq Scan on tab (cost=0.00..30.38 rows=543 width=8)
Filter: (ts > '2007-08-23 00:00:00'::timestamp without time zone)
(3 rows)
[ For the archives: this is another example of why implicit casts to
text are evil ... PG 8.3 will reject the first query above, instead
of imputing a surprising meaning to it. ]
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | A. Kretschmer | 2007-08-27 05:24:23 | Re: WHERE clause with timestamp data type |
Previous Message | Chirag Patel | 2007-08-27 04:49:29 | WHERE clause with timestamp data type |