Обсуждение: WHERE clause with timestamp data type
The following command works great,
SELECT AVG(column) FROM table WHERE timestamp > 2007-08-23;
But when I try it with finer resolution (hour, minutes, seconds) like this, I get a syntax error
SELECT AVG(heartrate) FROM heartrates WHERE timestamp > 2007-08-23 19:48:09;
Do I need to convert from string format to total number of seconds? Any ideas on how to get this work?
Thanks!
Chirag
SELECT AVG(column) FROM table WHERE timestamp > 2007-08-23;
But when I try it with finer resolution (hour, minutes, seconds) like this, I get a syntax error
SELECT AVG(heartrate) FROM heartrates WHERE timestamp > 2007-08-23 19:48:09;
Do I need to convert from string format to total number of seconds? Any ideas on how to get this work?
Thanks!
Chirag
Chirag Patel <patelc75@yahoo.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
am Sun, dem 26.08.2007, um 21:49:29 -0700 mailte Chirag Patel folgendes: > The following command works great, > SELECT AVG(column) FROM table WHERE timestamp > 2007-08-23; > > But when I try it with finer resolution (hour, minutes, seconds) like this, I > get a syntax error > SELECT AVG(heartrate) FROM heartrates WHERE timestamp > 2007-08-23 19:48:09; Can you show us the error? > > Do I need to convert from string format to total number of seconds? Any ideas > on how to get this work? Try: "WHERE timestamp > '2007-08-23 19:48:09'::timestamp "; Btw.: bad idea to title a column 'timestamp', because this is a datatype-identifier - but it works. Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net