Thread: Should the optimizer optimize "current_date - interval '1 days'" (fwd)
On a very big table (a data warehouse with >10 million rows), I frequently run queries looking at the past few days. However queries like this: select count(*) from fact where dat > (current_date - interval '1 days'); never uses the index I have on "fact". (Thanks to previous queries it's now ordered by 'dat' so the correlation in pg_stats is '1'.). However if I toss on an extra where clause with a constant like select count(*) from fact where dat > (current_date - interval '1 days') and dat > '2002-05-20'; it hapily uses the index (at least for the second comparison). Should it treat my current_dat... expression as a constant and use the index? Or is there a good reason it doesn't? Thanks, Ron PS: This seems true even if I "set enable_seqscan to off". logs2=# set enable_seqscan to off; logs2=# explain logs2-# select count(*) from fact logs2-# where dat > (current_date - interval '1 days'); NOTICE: QUERY PLAN: Aggregate (cost=101265332.77..101265332.77 rows=1 width=0) -> Seq Scan on fact (cost=100000000.00..101231544.46 rows=13515325 width=0) logs2=# explain logs2-# select count(*) logs2-# from fact logs2-# where dat > (current_date - interval '1 days') logs2-# and dat > '2002-05-20'; NOTICE: QUERY PLAN: Aggregate (cost=198729.54..198729.54 rows=1 width=0) -> Index Scan using i__fact__dat on fact (cost=0.00..194279.24 rows=1780119 width=0) EXPLAIN logs2=#
Ron Mayer <ron@intervideo.com> writes: > where dat > (current_date - interval '1 days'); > never uses the index I have on "fact". I suppose dat is of type date? > Should it treat my current_dat... expression as a constant and use > the index? Or is there a good reason it doesn't? You will never get an indexscan out of that because the expression seen by the planner is where timestamp(dat) > timestamp-expression which is not compatible with an index of datatype date. You should write something that yields a date, not a timestamp, for example where dat > (current_date - 1) This should be indexable (and is, in current development sources) but in 7.2 and before you have to do additional pushups because the planner doesn't understand that current_date can be treated as a constant for the duration of a single indexscan. The standard workaround is to create a function of a signature like "days_ago(int) returns date" and mark it isCachable. This is a cheat but it works fine in interactive queries. See past discussions in the archives. regards, tom lane