Re: order by primary key slowly
Hi,
The reason the first query is faster is because it can use an index that is much smaller than the PRIMARY index. For InnoDB, all indexes will contain the primary key. Hence, it can use any index when only the primary key is selected. Also, if result is not to be sorted, it can stop scanning the index when the requested number of records have been found.
For the second query, the optimizer has two options:
1. It can use the PRIMARY index, scan it backwards, and stop after 1000010 rows. The data will then be scanned in the requested sort order, and no sorting is needed.
2. It can use the smaller index, scan all 5.5 million index entries, sort the ids, and then skip 1 million rows to pick the 10 rows it needs.
The first option takes longer than executing the first query because the PRIMARY index is much bigger than the index used for the first query. (The primary index contains all other columns of the table.) Also, a backward scan is a bit slower than a forward scan.
It is obvious that the second option takes longer than the first query since it needs to read more than 5 times as many index entries, and in addition sort all the IDs.
If there were no secondary indexes, the first query would be almost as slow as the second query. (There would still be a small difference due forward versus backward index scan.)
In other words, it is not the second query that is slow. It is the first query that is fast. ;-)
Øystein Grøvlen,
Senior Principal Software Engineer,
MySQL Group, Oracle,
Trondheim, Norway