Thread: max/min and index usage
We're using 8.1 - I thought such a construct was safe in pg 8.1: select max(indexed_value) from huge_table; while earlier we had to use: select indexed_value from huge_table order by indexed_value desc limit 1; seems like I was wrong: mydb=> explain analyze select indexed_value1 from mytable order by indexed_value1 desc limit 1; QUERY PLAN ----------------------------------------------------------------------------------------------------------------------------------------------------------------- Limit (cost=0.00..1.96 rows=1 width=4) (actual time=0.115..0.117 rows=1 loops=1) -> Index Scan Backward using index1 on mytable (cost=0.00..23890756.52 rows=12164924 width=4) (actual time=0.111..0.111rows=1 loops=1) Total runtime: 0.162 ms (3 rows) mydb=> explain analyze select indexed_value2 from mytable order by indexed_value2 desc limit 1; QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------- Limit (cost=0.00..0.04 rows=1 width=4) (actual time=0.128..0.130 rows=1 loops=1) -> Index Scan Backward using index2 on mytable (cost=0.00..428231.16 rows=12164924 width=4) (actual time=0.124..0.124rows=1 loops=1) Total runtime: 0.160 ms (3 rows) mydb=> explain analyze select max(indexed_value2) from mytable; QUERY PLAN ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Result (cost=0.04..0.05 rows=1 width=0) (actual time=11652.138..11652.139 rows=1 loops=1) InitPlan -> Limit (cost=0.00..0.04 rows=1 width=4) (actual time=11652.122..11652.124 rows=1 loops=1) -> Index Scan Backward using index2 on mytable (cost=0.00..428231.16 rows=12164924 width=4) (actual time=11652.117..11652.117rows=1 loops=1) Filter: (indexed_value2 IS NOT NULL) Total runtime: 11652.200 ms (6 rows) mydb=> explain analyze select max(indexed_value1) from mytable; QUERY PLAN ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Result (cost=1.96..1.97 rows=1 width=0) (actual time=713.780..713.781 rows=1 loops=1) InitPlan -> Limit (cost=0.00..1.96 rows=1 width=4) (actual time=713.767..713.770 rows=1 loops=1) -> Index Scan Backward using index1 on mytable (cost=0.00..23890756.52 rows=12164924 width=4) (actual time=713.764..713.764rows=1 loops=1) Filter: (indexed_value1 IS NOT NULL) Total runtime: 713.861 ms (6 rows)
[Tobias Brox - Wed at 04:01:56AM +0100] > We're using 8.1 - I thought such a construct was safe in pg 8.1: > > select max(indexed_value) from huge_table; > > while earlier we had to use: > > select indexed_value from huge_table order by indexed_value desc limit 1; > > seems like I was wrong: The difference is all about those NULL values ... those columns are quite sparsely populated in the table. The second query gives NULL, which is not much useful :-) However, I made a partial index to solve this problem - this query is able to use the partial index: select indexed_value from huge_table where indexed_value is not NULL order by indexed_value desc limit 1; while this one is not: select max(indexed_value) from huge_table; I guess this is a bug? :-)
Tobias Brox <tobias@nordicbet.com> writes: > We're using 8.1 - I thought such a construct was safe in pg 8.1: > select max(indexed_value) from huge_table; > while earlier we had to use: > select indexed_value from huge_table order by indexed_value desc limit 1; These are not actually exactly the same thing. In particular, I suppose your table contains a lot of nulls? regards, tom lane
[Tom Lane - Tue at 10:29:53PM -0500] > These are not actually exactly the same thing. In particular, I suppose > your table contains a lot of nulls? Yes; I'm sorry I was a bit quick with the first posting.