MySQL :: MySQL 8.4 Reference Manual :: 10.2.1.16 ORDER BY Optimization (original) (raw)

10.2.1.16 ORDER BY Optimization

This section describes when MySQL can use an index to satisfy an ORDER BY clause, thefilesort operation used when an index cannot be used, and execution plan information available from the optimizer about ORDER BY.

An ORDER BY with and withoutLIMIT may return rows in different orders, as discussed in Section 10.2.1.19, “LIMIT Query Optimization”.

Use of Indexes to Satisfy ORDER BY

In some cases, MySQL may use an index to satisfy anORDER BY clause and avoid the extra sorting involved in performing a filesort operation.

The index may also be used even if the ORDER BY does not match the index exactly, as long as all unused portions of the index and all extraORDER BY columns are constants in theWHERE clause. If the index does not contain all columns accessed by the query, the index is used only if index access is cheaper than other access methods.

Assuming that there is an index on(_`keypart1`_,_`keypart2`_), the following queries may use the index to resolve theORDER BY part. Whether the optimizer actually does so depends on whether reading the index is more efficient than a table scan if columns not in the index must also be read.

SELECT * FROM t1  
  ORDER BY key_part1, key_part2;  

However, the query uses SELECT *, which may select more columns than_keypart1_ and_keypart2_. In that case, scanning an entire index and looking up table rows to find columns not in the index may be more expensive than scanning the table and sorting the results. If so, the optimizer probably does not use the index. IfSELECT * selects only the index columns, the index is used and sorting avoided.
If t1 is an InnoDB table, the table primary key is implicitly part of the index, and the index can be used to resolve theORDER BY for this query:

SELECT pk, key_part1, key_part2 FROM t1  
  ORDER BY key_part1, key_part2;  
SELECT * FROM t1  
  WHERE key_part1 = constant  
  ORDER BY key_part2;  
SELECT * FROM t1  
  ORDER BY key_part1 DESC, key_part2 DESC;  
SELECT * FROM t1  
  WHERE key_part1 = constant  
  ORDER BY key_part2 DESC;  
SELECT * FROM t1  
  ORDER BY key_part1 DESC, key_part2 ASC;  

The optimizer can use an index on (keypart1,keypart2) if_keypart1_ is descending and_keypart2_ is ascending. It can also use an index on those columns (with a backward scan) if keypart1 is ascending and keypart2 is descending. See Section 10.3.13, “Descending Indexes”.

SELECT * FROM t1  
  WHERE key_part1 > constant  
  ORDER BY key_part1 ASC;  
SELECT * FROM t1  
  WHERE key_part1 < constant  
  ORDER BY key_part1 DESC;  
SELECT * FROM t1  
  WHERE key_part1 = constant1 AND key_part2 > constant2  
  ORDER BY key_part2;  

In some cases, MySQL cannot use indexes to resolve the ORDER BY, although it may still use indexes to find the rows that match theWHERE clause. Examples:

SELECT * FROM t1 ORDER BY key1, key2;  
SELECT * FROM t1 WHERE key2=constant ORDER BY key1_part1, key1_part3;  
SELECT * FROM t1 WHERE key2=constant ORDER BY key1;  
SELECT * FROM t1 ORDER BY ABS(key);  
SELECT * FROM t1 ORDER BY -key;  

Availability of an index for sorting may be affected by the use of column aliases. Suppose that the columnt1.a is indexed. In this statement, the name of the column in the select list isa. It refers to t1.a, as does the reference to a in theORDER BY, so the index ont1.a can be used:

SELECT a FROM t1 ORDER BY a;

In this statement, the name of the column in the select list is also a, but it is the alias name. It refers to ABS(a), as does the reference to a in the ORDER BY, so the index on t1.a cannot be used:

SELECT ABS(a) AS a FROM t1 ORDER BY a;

In the following statement, the ORDER BY refers to a name that is not the name of a column in the select list. But there is a column in t1 named a, so the ORDER BY refers to t1.a and the index on t1.a can be used. (The resulting sort order may be completely different from the order forABS(a), of course.)

SELECT ABS(a) AS b FROM t1 ORDER BY a;

Previously (MySQL 8.3 and lower),GROUP BY sorted implicitly under certain conditions. In MySQL 8.4, that no longer occurs, so specifying ORDER BY NULL at the end to suppress implicit sorting (as was done previously) is no longer necessary. However, query results may differ from previous MySQL versions. To produce a given sort order, provide an ORDER BY clause.

Use of filesort to Satisfy ORDER BY

If an index cannot be used to satisfy an ORDER BY clause, MySQL performs afilesort operation that reads table rows and sorts them. A filesort constitutes an extra sorting phase in query execution.

To obtain memory for filesort operations, the optimizer allocates memory buffers incrementally as needed, up to the size indicated by thesort_buffer_size system variable. This enables users to setsort_buffer_size to larger values to speed up larger sorts, without concern for excessive memory use for small sorts. (This benefit may not occur for multiple concurrent sorts on Windows, which has a weak multithreaded malloc.)

A filesort operation uses temporary disk files as necessary if the result set is too large to fit in memory. Some types of queries are particularly suited to completely in-memory filesort operations. For example, the optimizer can usefilesort to efficiently handle in memory, without temporary files, the ORDER BY operation for queries (and subqueries) of the following form:

SELECT ... FROM single_table ... ORDER BY non_index_column [DESC] LIMIT [M,]N;

Such queries are common in web applications that display only a few rows from a larger result set. Examples:

SELECT col1, ... FROM t1 ... ORDER BY name LIMIT 10;
SELECT col1, ... FROM t1 ... ORDER BY RAND() LIMIT 15;
Influencing ORDER BY Optimization

To increase ORDER BY speed, check whether you can get MySQL to use indexes rather than an extra sorting phase. If this is not possible, try the following strategies:

ORDER BY Execution Plan Information Available

WithEXPLAIN (see Section 10.8.1, “Optimizing Queries with EXPLAIN”), you can check whether MySQL can use indexes to resolve an ORDER BY clause:

In addition, if a filesort is performed, optimizer trace output includes afilesort_summary block. For example:

"filesort_summary": {
  "rows": 100,
  "examined_rows": 100,
  "number_of_tmp_files": 0,
  "peak_memory_used": 25192,
  "sort_mode": "<sort_key, packed_additional_fields>"
}

peak_memory_used indicates the maximum memory used at any one time during the sort. This is a value up to but not necessarily as large as the value of thesort_buffer_size system variable. The optimizer allocates sort-buffer memory incrementally, beginning with a small amount and adding more as necessary, up to sort_buffer_size bytes.)

The sort_mode value provides information about the contents of tuples in the sort buffer:

EXPLAIN does not distinguish whether the optimizer does or does not perform afilesort in memory. Use of an in-memoryfilesort can be seen in optimizer trace output. Look forfilesort_priority_queue_optimization. For information about the optimizer trace, seeSection 10.15, “Tracing the Optimizer”.