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 honored
   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 an 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, an explicit sort is likely to be faster than using an index
   because it requires
   less disk I/O due to following a sequential 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, 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 (table TID is treated as a tiebreaker column among
   otherwise equal entries).  This means that a forward scan of an
   index on 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 plain 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 maintaining such an index depends on how often you use queries that require a special sort ordering.