欧美bbbwbbbw肥妇,免费乱码人妻系列日韩,一级黄片

MySQL中l(wèi)imit對(duì)查詢語(yǔ)句性能的影響

 更新時(shí)間:2021年09月20日 13:34:00   投稿:WDC  
我們知道,當(dāng)limit offset rows中的offset很大時(shí),會(huì)出現(xiàn)效率問(wèn)題,那么如果提高limit的執(zhí)行效率呢

一,前言 

首先說(shuō)明一下MySQL的版本:

mysql> select version();
+-----------+
| version() |
+-----------+
| 5.7.17    |
+-----------+
1 row in set (.00 sec)

表結(jié)構(gòu):

mysql> desc test;
+--------+---------------------+------+-----+---------+----------------+
| Field  | Type                | Null | Key | Default | Extra          |
+--------+---------------------+------+-----+---------+----------------+
| id     | bigint(20) unsigned | NO   | PRI | NULL    | auto_increment |
| val    | int(10) unsigned    | NO   | MUL |        |                |
| source | int(10) unsigned    | NO   |     |        |                |
+--------+---------------------+------+-----+---------+----------------+
3 rows in set (.00 sec)

id為自增主鍵,val為非唯一索引。

灌入大量數(shù)據(jù),共500萬(wàn):

mysql> select count(*) from test;
+----------+
| count(*) |
+----------+
|  5242882 |
+----------+
1 row in set (4.25 sec)

我們知道,當(dāng)limit offset rows中的offset很大時(shí),會(huì)出現(xiàn)效率問(wèn)題:

mysql> select * from test where val=4 limit 300000,5;
+---------+-----+--------+
| id      | val | source |
+---------+-----+--------+
| 3327622 |   4 |      4 |
| 3327632 |   4 |      4 |
| 3327642 |   4 |      4 |
| 3327652 |   4 |      4 |
| 3327662 |   4 |      4 |
+---------+-----+--------+
5 rows in set (15.98 sec)

為了達(dá)到相同的目的,我們一般會(huì)改寫成如下語(yǔ)句:

mysql> select * from test a inner join (select id from test where val=4 limit 300000,5) b on a.id=b.id;
+---------+-----+--------+---------+
| id      | val | source | id      |
+---------+-----+--------+---------+
| 3327622 |   4 |      4 | 3327622 |
| 3327632 |   4 |      4 | 3327632 |
| 3327642 |   4 |      4 | 3327642 |
| 3327652 |   4 |      4 | 3327652 |
| 3327662 |   4 |      4 | 3327662 |
+---------+-----+--------+---------+
5 rows in set (.38 sec)

時(shí)間相差很明顯。

為什么會(huì)出現(xiàn)上面的結(jié)果?我們看一下select * from test where val=4 limit 300000,5;的查詢過(guò)程:

查詢到索引葉子節(jié)點(diǎn)數(shù)據(jù)。

根據(jù)葉子節(jié)點(diǎn)上的主鍵值去聚簇索引上查詢需要的全部字段值。

類似于下面這張圖:

像上面這樣,需要查詢300005次索引節(jié)點(diǎn),查詢300005次聚簇索引的數(shù)據(jù),最后再將結(jié)果過(guò)濾掉前300000條,取出最后5條。MySQL耗費(fèi)了大量隨機(jī)I/O在查詢聚簇索引的數(shù)據(jù)上,而有300000次隨機(jī)I/O查詢到的數(shù)據(jù)是不會(huì)出現(xiàn)在結(jié)果集當(dāng)中的。

肯定會(huì)有人問(wèn):既然一開始是利用索引的,為什么不先沿著索引葉子節(jié)點(diǎn)查詢到最后需要的5個(gè)節(jié)點(diǎn),然后再去聚簇索引中查詢實(shí)際數(shù)據(jù)。這樣只需要5次隨機(jī)I/O,類似于下面圖片的過(guò)程:

其實(shí)我也想問(wèn)這個(gè)問(wèn)題。

證實(shí)

下面我們實(shí)際操作一下來(lái)證實(shí)上述的推論:

為了證實(shí)select * from test where val=4 limit 300000,5是掃描300005個(gè)索引節(jié)點(diǎn)和300005個(gè)聚簇索引上的數(shù)據(jù)節(jié)點(diǎn),我們需要知道MySQL有沒(méi)有辦法統(tǒng)計(jì)在一個(gè)sql中通過(guò)索引節(jié)點(diǎn)查詢數(shù)據(jù)節(jié)點(diǎn)的次數(shù)。我先試了Handler_read_*系列,很遺憾沒(méi)有一個(gè)變量能滿足條件。

我只能通過(guò)間接的方式來(lái)證實(shí):

InnoDB中有buffer pool。里面存有最近訪問(wèn)過(guò)的數(shù)據(jù)頁(yè),包括數(shù)據(jù)頁(yè)和索引頁(yè)。所以我們需要運(yùn)行兩個(gè)sql,來(lái)比較buffer pool中的數(shù)據(jù)頁(yè)的數(shù)量。預(yù)測(cè)結(jié)果是運(yùn)行select * from test a inner join (select id from test where val=4 limit 300000,5)之后,buffer pool中的數(shù)據(jù)頁(yè)的數(shù)量遠(yuǎn)遠(yuǎn)少于select * from test where val=4 limit 300000,5;對(duì)應(yīng)的數(shù)量,因?yàn)榍耙粋€(gè)sql只訪問(wèn)5次數(shù)據(jù)頁(yè),而后一個(gè)sql訪問(wèn)300005次數(shù)據(jù)頁(yè)。

mysql> select index_name,count(*) from information_schema.INNODB_BUFFER_PAGE where INDEX_NAME in('val','primary') and TABLE_NAME like '%test%' group by index_name;
Empty set (.04 sec)

可以看出,目前buffer pool中沒(méi)有關(guān)于test表的數(shù)據(jù)頁(yè)。

mysql> select * from test where val=4 limit 300000,5;
+---------+-----+--------+
| id      | val | source |
+---------+-----+--------+
| 3327622 |   4 |      4 |
| 3327632 |   4 |      4 |
| 3327642 |   4 |      4 |
| 3327652 |   4 |      4 |
| 3327662 |   4 |      4 |
+---------+-----+--------+
5 rows in set (26.19 sec)

mysql> select index_name,count(*) from information_schema.INNODB_BUFFER_PAGE where INDEX_NAME in('val','primary') and TABLE_NAME like '%test%' group by index_name;
+------------+----------+
| index_name | count(*) |
+------------+----------+
| PRIMARY    |     4098 |
| val        |      208 |
+------------+----------+
2 rows in set (.04 sec)

可以看出,此時(shí)buffer pool中關(guān)于test表有4098個(gè)數(shù)據(jù)頁(yè),208個(gè)索引頁(yè)。

select * from test a inner join (select id from test where val=4 limit 300000,5)為了防止上次試驗(yàn)的影響,我們需要清空buffer pool,重啟mysql。

mysqladmin shutdown
/usr/local/bin/mysqld_safe &
mysql> select index_name,count(*) from information_schema.INNODB_BUFFER_PAGE where INDEX_NAME in('val','primary') and TABLE_NAME like '%test%' group by index_name;
Empty set (0.03 sec)

運(yùn)行SQL:

mysql> select * from test a inner join (select id from test where val=4 limit 300000,5) b on a.id=b.id;
+---------+-----+--------+---------+
| id      | val | source | id      |
+---------+-----+--------+---------+
| 3327622 |   4 |      4 | 3327622 |
| 3327632 |   4 |      4 | 3327632 |
| 3327642 |   4 |      4 | 3327642 |
| 3327652 |   4 |      4 | 3327652 |
| 3327662 |   4 |      4 | 3327662 |
+---------+-----+--------+---------+
5 rows in set (0.09 sec)

mysql> select index_name,count(*) from information_schema.INNODB_BUFFER_PAGE where INDEX_NAME in('val','primary') and TABLE_NAME like '%test%' group by index_name;
+------------+----------+
| index_name | count(*) |
+------------+----------+
| PRIMARY    |        5 |
| val        |      390 |
+------------+----------+
2 rows in set (0.03 sec)

我們可以看明顯的看出兩者的差別:第一個(gè)sql加載了4098個(gè)數(shù)據(jù)頁(yè)到buffer pool,而第二個(gè)sql只加載了5個(gè)數(shù)據(jù)頁(yè)到buffer pool。符合我們的預(yù)測(cè)。也證實(shí)了為什么第一個(gè)sql會(huì)慢:讀取大量的無(wú)用數(shù)據(jù)行(300000),最后卻拋棄掉。

而且這會(huì)造成一個(gè)問(wèn)題:加載了很多熱點(diǎn)不是很高的數(shù)據(jù)頁(yè)到buffer pool,會(huì)造成buffer pool的污染,占用buffer pool的空間。

遇到的問(wèn)題  

為了在每次重啟時(shí)確保清空buffer pool,我們需要關(guān)閉innodb_buffer_pool_dump_at_shutdown和innodb_buffer_pool_load_at_startup,這兩個(gè)選項(xiàng)能夠控制數(shù)據(jù)庫(kù)關(guān)閉時(shí)dump出buffer pool中的數(shù)據(jù)和在數(shù)據(jù)庫(kù)開啟時(shí)載入在磁盤上備份buffer pool的數(shù)據(jù)。

參考資料:

1.https://explainextended.com/2009/10/23/mysql-order-by-limit-performance-late-row-lookups/

2.https://dev.mysql.com/doc/refman/5.7/en/innodb-information-schema-buffer-pool-tables.html

更多關(guān)于SQL執(zhí)行效率問(wèn)題請(qǐng)查看下面的相關(guān)文章

相關(guān)文章

最新評(píng)論