Multi Range Read optimization

You are viewing an old version of this article. View the current version here.

Multi Range Read is an optimization aimed at improving performance for IO-bound queries that need to scan lots of rows.

In MariaDB, it is available since MariaDB 5.3, main-line MySQL has a subset of it available in MySQL 5.6.

The idea

Consider a simple range query:

MariaDB [test]> explain select * from tbl where tbl.key1 between 1000 and 2000;
+----+-------------+-------+-------+---------------+------+---------+------+------+-----------------------+
| id | select_type | table | type  | possible_keys | key  | key_len | ref  | rows | Extra                 |
+----+-------------+-------+-------+---------------+------+---------+------+------+-----------------------+
|  1 | SIMPLE      | tbl   | range | key1          | key1 | 5       | NULL |  960 | Using index condition |
+----+-------------+-------+-------+---------------+------+---------+------+------+-----------------------+

When this query is executed, disk IO access pattern will follow the red line in this figure:

no-mrr-access-pattern

Execution will hit the table rows in random places, as marked with the blue line/numbers in the figure.

When the table is sufficiently big, each table record read will need to actually go to disk (and be served from buffer pool or OS cache), and query execution will be too slow to be practical. For example, a 10,000 RPM disk drive is able to make 167 seeks per second, so in the worst case, query execution will be capped at reading about 167 records per second. SSD drives do not need to do disk seeks, so they will not be hurt as badly, however the performance will still be poor because of poor disk access locality.

Multi-Range-Read optimization aims to make disk access faster by sorting record read requests and then doing one ordered disk sweep:

mrr-access-pattern

Factsheet

Old stuff

Multi Range Read optimization provides speedup for range, ref, or eq_ref access when

  • each query enumerates lots of records (the range/ref access in question should read about 100K records or more)
  • the load is mostly IO-bound. In other words, there is a high chance that the query will hit the data that's not in disk cache or buffer pool.

Batched Key Access optimization uses MultiRangeRead functionality, so Multi Range Read must be enabled for Batched Key Access to work.

Because Multi Range Read can cause slowdowns when ran for small ranges over small tables, it is disabled by default. To enable it, use the following settings:

SET optimizer_switch='mrr=on,mrr_sort_keys=on,mrr_cost_based=off'

Switching on mrr_cost_based is currently not recommended because cost model is not sufficiently well-tuned to be practically useful.

How Multi Range Read works

Differences from MySQL

  • Key-ordered scan is a MariaDB-only development
  • EXPLAIN in MySQL shows "Using MRR", while in MariaDB it is either "Rowid-ordered scan", "Key-ordered scan", or Key-ordered Rowid-ordered scan".
  • for range access, the size of the buffer is controlled by @mrr_buffer_size variable (Original MySQL 6.0 and current MySQL 5.6 use @@read_rnd_buffer_size, which is also used to control buffer size for other algorithms)
  • [is this a difference?] When used with BKA, buffer space management is done by BKA code. It uses up to @join_buffer_size bytes per table, distributing it across its own buffers and buffers it provides to MRR.

See also

Comments

Comments loading...
Content reproduced on this site is the property of its respective owners, and this content is not reviewed in advance by MariaDB. The views, information and opinions expressed by this content do not necessarily represent those of MariaDB or any other party.