MySQL :: MySQL 8.0 Reference Manual :: 10.2.1.19 LIMIT Query Optimization (original) (raw)
10.2.1.19 LIMIT Query Optimization
If you need only a specified number of rows from a result set, use a LIMIT
clause in the query, rather than fetching the whole result set and throwing away the extra data.
MySQL sometimes optimizes a query that has a LIMIT_`rowcount`_
clause and noHAVING
clause:
- If you select only a few rows with
LIMIT
, MySQL uses indexes in some cases when normally it would prefer to do a full table scan. - If you combine
LIMIT_`rowcount`_
withORDER BY
, MySQL stops sorting as soon as it has found the first_rowcount
_ rows of the sorted result, rather than sorting the entire result. If ordering is done by using an index, this is very fast. If a filesort must be done, all rows that match the query without theLIMIT
clause are selected, and most or all of them are sorted, before the first_rowcount
_ are found. After the initial rows have been found, MySQL does not sort any remainder of the result set.
One manifestation of this behavior is that anORDER BY
query with and withoutLIMIT
may return rows in different order, as described later in this section. - If you combine
LIMIT_`rowcount`_
withDISTINCT
, MySQL stops as soon as it findsrowcount
unique rows. - In some cases, a
GROUP BY
can be resolved by reading the index in order (or doing a sort on the index), then calculating summaries until the index value changes. In this case,LIMIT_`rowcount`_
does not calculate any unnecessaryGROUP BY
values. - As soon as MySQL has sent the required number of rows to the client, it aborts the query unless you are using
SQL_CALC_FOUND_ROWS
. In that case, the number of rows can be retrieved withSELECT FOUND_ROWS()
. SeeSection 14.15, “Information Functions”. LIMIT 0
quickly returns an empty set. This can be useful for checking the validity of a query. It can also be employed to obtain the types of the result columns within applications that use a MySQL API that makes result set metadata available. With themysql client program, you can use the--column-type-info option to display result column types.- If the server uses temporary tables to resolve a query, it uses the
LIMIT_`rowcount`_
clause to calculate how much space is required. - If an index is not used for
ORDER BY
but aLIMIT
clause is also present, the optimizer may be able to avoid using a merge file and sort the rows in memory using an in-memoryfilesort
operation.
If multiple rows have identical values in the ORDER BY
columns, the server is free to return those rows in any order, and may do so differently depending on the overall execution plan. In other words, the sort order of those rows is nondeterministic with respect to the nonordered columns.
One factor that affects the execution plan isLIMIT
, so an ORDER BY
query with and without LIMIT
may return rows in different orders. Consider this query, which is sorted by the category
column but nondeterministic with respect to the id
andrating
columns:
mysql> SELECT * FROM ratings ORDER BY category;
+----+----------+--------+
| id | category | rating |
+----+----------+--------+
| 1 | 1 | 4.5 |
| 5 | 1 | 3.2 |
| 3 | 2 | 3.7 |
| 4 | 2 | 3.5 |
| 6 | 2 | 3.5 |
| 2 | 3 | 5.0 |
| 7 | 3 | 2.7 |
+----+----------+--------+
Including LIMIT
may affect order of rows within each category
value. For example, this is a valid query result:
mysql> SELECT * FROM ratings ORDER BY category LIMIT 5;
+----+----------+--------+
| id | category | rating |
+----+----------+--------+
| 1 | 1 | 4.5 |
| 5 | 1 | 3.2 |
| 4 | 2 | 3.5 |
| 3 | 2 | 3.7 |
| 6 | 2 | 3.5 |
+----+----------+--------+
In each case, the rows are sorted by the ORDER BY
column, which is all that is required by the SQL standard.
If it is important to ensure the same row order with and without LIMIT
, include additional columns in the ORDER BY
clause to make the order deterministic. For example, if id
values are unique, you can make rows for a givencategory
value appear inid
order by sorting like this:
mysql> SELECT * FROM ratings ORDER BY category, id;
+----+----------+--------+
| id | category | rating |
+----+----------+--------+
| 1 | 1 | 4.5 |
| 5 | 1 | 3.2 |
| 3 | 2 | 3.7 |
| 4 | 2 | 3.5 |
| 6 | 2 | 3.5 |
| 2 | 3 | 5.0 |
| 7 | 3 | 2.7 |
+----+----------+--------+
mysql> SELECT * FROM ratings ORDER BY category, id LIMIT 5;
+----+----------+--------+
| id | category | rating |
+----+----------+--------+
| 1 | 1 | 4.5 |
| 5 | 1 | 3.2 |
| 3 | 2 | 3.7 |
| 4 | 2 | 3.5 |
| 6 | 2 | 3.5 |
+----+----------+--------+
For a query with an ORDER BY
orGROUP BY
and a LIMIT
clause, the optimizer tries to choose an ordered index by default when it appears doing so would speed up query execution. Prior to MySQL 8.0.21, there was no way to override this behavior, even in cases where using some other optimization might be faster. Beginning with MySQL 8.0.21, it is possible to turn off this optimization by setting theoptimizer_switch system variable'sprefer_ordering_index flag to off
.
Example: First we create and populate a table t
as shown here:
# Create and populate a table t:
mysql> CREATE TABLE t (
-> id1 BIGINT NOT NULL,
-> id2 BIGINT NOT NULL,
-> c1 VARCHAR(50) NOT NULL,
-> c2 VARCHAR(50) NOT NULL,
-> PRIMARY KEY (id1),
-> INDEX i (id2, c1)
-> );
# [Insert some rows into table t - not shown]
Verify that theprefer_ordering_index flag is enabled:
mysql> SELECT @@optimizer_switch LIKE '%prefer_ordering_index=on%';
+------------------------------------------------------+
| @@optimizer_switch LIKE '%prefer_ordering_index=on%' |
+------------------------------------------------------+
| 1 |
+------------------------------------------------------+
Since the following query has a LIMIT
clause, we expect it to use an ordered index, if possible. In this case, as we can see from theEXPLAIN output, it uses the table's primary key.
mysql> EXPLAIN SELECT c2 FROM t
-> WHERE id2 > 3
-> ORDER BY id1 ASC LIMIT 2\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t
partitions: NULL
type: index
possible_keys: i
key: PRIMARY
key_len: 8
ref: NULL
rows: 2
filtered: 70.00
Extra: Using where
Now we disable theprefer_ordering_index flag, and re-run the same query; this time it uses the indexi
(which includes theid2
column used in theWHERE
clause), and a filesort:
mysql> SET optimizer_switch = "prefer_ordering_index=off";
mysql> EXPLAIN SELECT c2 FROM t
-> WHERE id2 > 3
-> ORDER BY id1 ASC LIMIT 2\G
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: t
partitions: NULL
type: range
possible_keys: i
key: i
key_len: 8
ref: NULL
rows: 14
filtered: 100.00
Extra: Using index condition; Using filesort