From aca86479fdc81190588ac0ab1f7802b9e2031a97 Mon Sep 17 00:00:00 2001 From: Bruce Momjian Date: Wed, 19 Feb 2003 03:12:22 +0000 Subject: [PATCH] This patch adds a note to the documentation describing why the performance of min() and max() is slow when applied to the entire table, and suggesting the simple workaround most experienced Pg users eventually learn about (SELECT xyz ... ORDER BY xyz LIMIT 1). Neil Conway --- doc/src/sgml/func.sgml | 53 +++++++++++++++++++++++++++++++++++++++++- 1 file changed, 52 insertions(+), 1 deletion(-) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index fd247be28c..b81dc92387 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -1,5 +1,5 @@ @@ -7074,6 +7074,57 @@ SELECT pg_type_is_visible('myschema.widget'::regtype); used to substitute zero for null when necessary. + + + Users accustomed to working with other RDBMS products may be + surprised by the performance characteristics of certain aggregate + functions in PostgreSQL when the + aggregate is applied to the entire table (in other words, no + WHERE clause is specified). In particular, + a query like + +SELECT min(col) FROM sometable; + + will be executed by PostgreSQL using a + sequential scan of the entire table. Other database systems may + optimize queries of this form to use an index on the column, if one + is available. Similarly, the aggregate functions + max() and count() always + require a sequential scan if applied to the entire table in + PostgreSQL. + + + + PostgreSQL cannot easily implement this + optimization because it also allows for user-defined aggregate + queries. Since min(), + max(), and count() are + defined using a generic API for aggregate functions, there is no + provision for special-casing the execution of these + functions under certain circumstances. + + + + Fortunately, there is a simple workaround for + min() and max(). The + query shown below is equivalent to the query above, except that it + can take advantage of a B+-Tree index if there is one present on + the column in question. + +SELECT col FROM sometable ORDER BY col ASC LIMIT 1; + + A similar query (obtained by substituting DESC + for ASC in the query above) can be used in the + place of max()). + + + + Unfortunately, there is no similarly trivial query that can be + used to improve the performance of count() + when applied to the entire table. + + +