Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 30.9Mb
PDF (A4) - 30.9Mb
PDF (RPM) - 29.7Mb
HTML Download (TGZ) - 7.7Mb
HTML Download (Zip) - 7.7Mb
HTML Download (RPM) - 6.6Mb
Man Pages (TGZ) - 142.3Kb
Man Pages (Zip) - 201.5Kb
Info (Gzip) - 2.9Mb
Info (Zip) - 2.9Mb


MySQL 8.0 Reference Manual  /  ...  /  Descending Indexes

Pre-General Availability Draft: 2017-04-28

9.3.12 Descending Indexes

MySQL supports descending indexes: DESC in an index definition is no longer ignored but causes storage of key values in descending order. Previously, indexes could be scanned in reverse order but at a performance penalty. A descending index can be scanned in forward order, which is more efficient. Descending indexes also make it possible for the optimizer to use multiple-column indexes when the most efficient scan order mixes ascending order for some columns and descending order for others.

Consider the following table definition, which contains two columns and four two-column index definitions for the various combinations of ascending and descending indexes on the columns:

CREATE TABLE t (
  c1 INT, c2 INT,
  INDEX idx1 (c1 ASC, c2 ASC),
  INDEX idx2 (c1 ASC, c2 DESC),
  INDEX idx3 (c1 DESC, c2 ASC),
  INDEX idx4 (c1 DESC, c2 DESC)
);

The table definition results in four distinct indexes. The optimizer can perform a forward index scan for each of the ORDER BY clauses and need not use a filesort operation:

ORDER BY c1 ASC, c2 ASC    -- optimizer can use idx1
ORDER BY c1 DESC, c2 DESC  -- optimizer can use idx4
ORDER BY c1 ASC, c2 DESC   -- optimizer can use idx2
ORDER BY c1 DESC, c2 ASC   -- optimizer can use idx3

Use of descending indexes is subject to these conditions:

  • Descending indexes are supported only for the InnoDB storage engine, with these limitations:

    • Change buffering is not supported for a secondary index if the index contains a descending index key column or if the primary key includes a descending index column.

    • The InnoDB SQL parser does not use descending indexes. For InnoDB full-text search, this means that the index required on the FTS_DOC_ID column of the indexed table cannot be defined as a descending index. For more information, see Section 16.8.9, “InnoDB FULLTEXT Indexes”.

  • Descending indexes are supported for all data types for which ascending indexes are available.

  • Descending indexes are supported for ordinary (nongenerated) and generated columns (both VIRTUAL and STORED).

  • DISTINCT can use any index containing matching columns, including descending key parts.

  • MIN()/MAX() optimization for queries that use aggregate functions but not GROUP BY does not use indexes with descending key parts.

  • Descending indexes are supported for BTREE but not HASH indexes. Descending indexes are not supported for FULLTEXT or SPATIAL indexes.

    Explicitly specified ASC and DESC designators for HASH, FULLTEXT, and SPATIAL indexes results in an error.


User Comments
Sign Up Login You must be logged in to post a comment.