From 5b68dfb06d6193945a97d5347d831aed203e167e Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Wed, 14 Feb 2007 20:47:15 +0000 Subject: [PATCH] Add some discussion of sort ordering to indices.sgml, which curiously had never touched the subject before. --- doc/src/sgml/indices.sgml | 91 +++++++++++++++++++++++++++++++++++++-- 1 file changed, 88 insertions(+), 3 deletions(-) diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml index 110cd79b9a..0a6defbf62 100644 --- a/doc/src/sgml/indices.sgml +++ b/doc/src/sgml/indices.sgml @@ -1,4 +1,4 @@ - + Indexes @@ -359,6 +359,88 @@ CREATE INDEX test2_mm_idx ON test2 (major, minor); + + Indexes and <literal>ORDER BY</> + + + index + and ORDER BY + + + + In addition to simply finding the rows to be returned by a query, + an index may be able to deliver them in a specific sorted order. + This allows a query's ORDER BY specification to be met + without a separate sorting step. Of the index types currently + supported by PostgreSQL, only B-tree + can produce sorted output — the other index types return + matching rows in an unspecified, implementation-dependent order. + + + + The planner will consider satisfying an ORDER BY specification + either by scanning any available index that matches the specification, + or by scanning the table in physical order and doing an explicit + sort. For a query that requires scanning a large fraction of the + table, the explicit sort is likely to be faster because it requires + less disk I/O due to a better-ordered access pattern. Indexes are + more useful when only a few rows need be fetched. An important + special case is ORDER BY in combination with + LIMIT n: an explicit sort will have to process + all the data to identify the first n rows, but if there is + an index matching the ORDER BY then the first n + rows can be retrieved directly, without scanning the remainder at all. + + + + By default, B-tree indexes store their entries in ascending order + with nulls last. This means that a forward scan of an index on a + column x produces output satisfying ORDER BY x + (or more verbosely, ORDER BY x ASC NULLS LAST). The + index can also be scanned backward, producing output satisfying + ORDER BY x DESC + (or more verbosely, ORDER BY x DESC NULLS FIRST, since + NULLS FIRST is the default for ORDER BY DESC). + + + + You can adjust the ordering of a B-tree index by including the + options ASC, DESC, NULLS FIRST, + and/or NULLS LAST when creating the index; for example: + +CREATE INDEX test2_info_nulls_low ON test2 (info NULLS FIRST); +CREATE INDEX test3_desc_index ON test3 (id DESC NULLS LAST); + + An index stored in ascending order with nulls first can satisfy + either ORDER BY x ASC NULLS FIRST or + ORDER BY x DESC NULLS LAST depending on which direction + it is scanned in. + + + + You might wonder why bother providing all four options, when two + options together with the possibility of backward scan would cover + all the variants of ORDER BY. In single-column indexes + the options are indeed redundant, but in multicolumn indexes they can be + useful. Consider a two-column index on (x, y): this can + satisfy ORDER BY x, y if we scan forward, or + ORDER BY x DESC, y DESC if we scan backward. + But it might be that the application frequently needs to use + ORDER BY x ASC, y DESC. There is no way to get that + ordering from a regular index, but it is possible if the index is defined + as (x ASC, y DESC) or (x DESC, y ASC). + + + + Obviously, indexes with non-default sort orderings are a fairly + specialized feature, but sometimes they can produce tremendous + speedups for certain queries. Whether it's worth keeping such an + index depends on how often you use queries that require a special + sort ordering. + + + + Combining Multiple Indexes @@ -798,7 +880,7 @@ CREATE UNIQUE INDEX tests_success_constraint ON tests (subject, target) An index definition can specify an operator class for each column of an index. -CREATE INDEX name ON table (column opclass , ...); +CREATE INDEX name ON table (column opclass sort options , ...); The operator class identifies the operators to be used by the index for that column. For example, a B-tree index on the type int4 @@ -810,7 +892,10 @@ CREATE INDEX name ON table index behavior. For example, we might want to sort a complex-number data type either by absolute value or by real part. We could do this by defining two operator classes for the data type and then selecting - the proper class when making an index. + the proper class when making an index. The operator class determines + the basic sort ordering (which can then be modified by adding sort options + ASC/DESC and/or + NULLS FIRST/NULLS LAST). -- 2.40.0