MySQL索引優(yōu)化的實際案例分析
Order by desc/asc limit M是我在mysql sql優(yōu)化中經(jīng)常遇到的一種場景,其優(yōu)化原理也非常的簡單,就是利用索引的有序性,優(yōu)化器沿著索引的順序掃描,在掃描到符合條件的M行數(shù)據(jù)后,停止掃描;看起來非常的簡單,但是我經(jīng)??吹胶芏嘈阅茌^差的sql沒有利用這個優(yōu)化規(guī)律,下面將結(jié)合一些實際的案例來分析說明:
案例一:
一條sql執(zhí)行非常的慢,執(zhí)行時間為:
root@test 02:00:44 SELECT * FROM test_order_desc WHERE END_TIME>now() ORDER BY GMT_CREATE DESC,count_num DESC LIMIT 12, 12; +---------+-----------+------------+------+---------------------+---------------------+------------------- Data1..................................................................................................... Data2..................................................................................................... +---------+-----------+------------+------+---------------------+---------------------+------------------- 12 ROWS IN SET (0.49 sec)
執(zhí)行計劃如下:
root@test_db01:53:23 EXPLAIN SELECT * FROM test_order_desc WHERE END_TIME > now() ORDER BY GMT_CREATE DESC,count_num DESC LIMIT 12, 12; +----+-------------+----------+-------+-----------------+-----------------+---------+------+--------+----- | id | select_type | TABLE | TYPE | possible_keys | KEY | key_len | REF | ROWS | Extra | +----+-------------+----------+-------+-----------------+-----------------+---------+------+--------+----- | 1 | SIMPLE | test_order_desc | range | ind_hot_endtime | ind_hot_endtime | 9 | NULL | 113549 | USING WHERE; USING filesort | +----+-------------+----------+-------+-----------------+-----------------+---------+------+--------+-----
Ind_hot_endtime索引為:
root@test_db01:52:45:SHOW INDEX FROM test_order_desc; Ind_hot_endtime(end_time,count_num)
在注意到sql中滿足過濾條件end_time>now()的有113549行,在加上剩余的條件中含有order by,這樣會造成排序的結(jié)果集非常的大,執(zhí)行非常的耗費資源;于是分析sql,在sql中包括了order by desc limit這樣的排序條件后,新增適當(dāng)?shù)乃饕凉M足排序的條件,同時由于有l(wèi)imit的限制結(jié)果集,當(dāng)掃描到滿足條件的行數(shù)后退出查詢,那么我們來看看優(yōu)化效果:
添加索引:
root@test 02:01:06:ALTER TABLE test_order_desc ADD INDEX ind_gmt_create(gmt_create,count_num); Query OK, 211945 ROWS affected (6.71 sec) Records: 211945 Duplicates: 0 Warnings: 0
再次執(zhí)行sql,觀察其執(zhí)行時間:
root@test 02:01:35: SELECT * FROM test_order_desc WHERE END_TIME > now() ORDER BY GMT_CREATE DESC,count_num DESC LIMIT 12, 12; +---------+-----------+------------+------+---------------------+---------------------+ col2................................................................................... +---------+-----------+------------+------+---------------------+---------------------+ Data1.................................................................................. Data2.................................................................................. +---------+-----------+------------+------+---------------------+---------------------+ 12 ROWS IN SET (0.00 sec)
可以看到執(zhí)行時間已經(jīng)降到了毫秒以下,查看其執(zhí)行計劃:
root@test 02:01:42: EXPLAIN SELECT * FROM test_order_desc WHERE END_TIME > now() ORDER BY GMT_CREATE DESC,count_num DESC LIMIT 12, 12; +----+-------------+----------+-------+-----------------+----------------+---------+------+------+-------------+ | id | select_type | TABLE | TYPE | possible_keys | KEY | key_len | REF | ROWS | Extra | +----+-------------+----------+-------+-----------------+----------------+---------+------+------+-------- | 1 | SIMPLE | test_order_desc | INDEX | ind_hot_endtime | ind_gmt_create | 14 | NULL | 48 | USING WHERE |
可以看到優(yōu)化器已經(jīng)選擇了ind_gmt_create索引掃描,這樣的話就避免了對結(jié)果集進行排序的過程,同時優(yōu)化器預(yù)估掃描14行數(shù)據(jù)就會得到滿足查詢條件的數(shù)據(jù)(END_TIME > now()),執(zhí)行計劃非常的理想。
root@127.0.0.1 : test_db 16:05:15: EXPLAIN SELECT b.*,a.*,k.* FROM instance b LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50;
案例二:
root@127.0.0.1 : test_db 16:05:15: EXPLAIN SELECT b.*,a.*,k.* FROM instance b LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50;
B表的idx_uid_stat_inid的索引列包括了(user_id,status,instance_no):
我們從執(zhí)行計劃上分析來看,表的連接順序為:b—>r_a—>a—>k,可以看到執(zhí)行計劃的第一行中需要掃描49212行的數(shù)據(jù),同時由于status采用的是in的方式,instance_no即使在索引中也用不上,這樣就導(dǎo)致了排序使用到了臨時表,這也是導(dǎo)致sql執(zhí)行慢的原因。我們看到sql中的最后一個排序為order by b.instance_no asc limit 37300,50,這里我們好像可以看到優(yōu)化的曙光,調(diào)整數(shù)據(jù)庫的索引以滿足B表的排序需求:
root@127.0.0.1 : test_db 16:05:04 ALTER TABLE instance ADD INDEX ind_user_id(user_id,instance_no); Query OK, 0 ROWS affected (0.56 sec)
調(diào)整索引后查看執(zhí)行計劃:
root@127.0.0.1 : test_db 16:09:42 EXPLAIN SELECT b.*,a.*,k.* FROM instance b LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50;
我們加上force index強制走我們新加的索引:
root@127.0.0.1 : test_db 16:10:24 EXPLAIN SELECT b.*,a.*,k.* FROM instance b force INDEX (ind_user_id) LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50;
可以看到在加上提示符后,使用到了我們新加的索引,掃描的行數(shù)為54580行,執(zhí)行時間:
root@127.0.0.1 : test_db 16:10:30 SELECT b.*,a.*,k.* FROM instance b force INDEX (ind_user_id) LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50; (0.49 sec)
原始的執(zhí)行時間:
root@127.0.0.1 : test_db 16:10:51: SELECT b.*,a.*,k.* FROM instance b LEFT OUTER JOIN image a ON b.image_id=a.image_id LEFT OUTER JOIN key_pair k ON b.key_pair_id=k.key_pair_id LEFT OUTER JOIN region_alias r_a ON r_a.region_no=b.region_no WHERE b.STATUS IN (1,8) AND b.user_id = 21 AND r_a.big_region_no='regeion_xx' ORDER BY b.instance_no ASC LIMIT 37300,50; (1.28 sec)
總結(jié):
Order by desc/asc limit的優(yōu)化技術(shù)有時候在你無法建立很好索引的時候,往往會得到意想不到的優(yōu)化效果,但有時候有一定的局限性,優(yōu)化器可能不會按照你既定的索引路徑掃描,優(yōu)化器需要考慮到查詢列的過濾性以及l(fā)imit的長度,當(dāng)查詢列的選擇性非常高的時候,使用sort的成本是不高的,當(dāng)查詢列的選擇性很低的時候,那么使用order by +limit的技術(shù)是很有效的。
相關(guān)文章
給mysql數(shù)據(jù)庫的字段設(shè)默認(rèn)值方式
這篇文章主要介紹了給mysql數(shù)據(jù)庫的字段設(shè)默認(rèn)值方式,具有很好的參考價值,希望對大家有所幫助,如有錯誤或未考慮完全的地方,望不吝賜教2023-10-10MySQL Limit性能優(yōu)化及分頁數(shù)據(jù)性能優(yōu)化詳解
今天小編就為大家分享一篇關(guān)于MySQL Limit性能優(yōu)化及分頁數(shù)據(jù)性能優(yōu)化詳解,小編覺得內(nèi)容挺不錯的,現(xiàn)在分享給大家,具有很好的參考價值,需要的朋友一起跟隨小編來看看吧2019-03-03mysql-5.7.42升級到mysql-8.2.0(二進制方式)
隨著數(shù)據(jù)量的增長和業(yè)務(wù)需求的變更,我們可能需要升級MySQL,本文主要介紹了mysql-5.7.42升級到mysql-8.2.0(二進制方式),具有一定的參考價值,感興趣的可以了解一下2024-03-03解析mysql中max_connections與max_user_connections的區(qū)別
本篇文章是對mysql中max_connections與max_user_connections的區(qū)別進行了詳細的分析介紹,需要的朋友參考下2013-06-06阿里云 Centos7.3安裝mysql5.7.18 rpm安裝教程
這篇文章主要介紹了阿里云 Centos7.3安裝mysql5.7.18 rpm安裝教程,需要的朋友可以參考下2017-06-06replace MYSQL字符替換函數(shù)sql語句分享(正則判斷)
最近更新網(wǎng)站發(fā)現(xiàn)一些字段的值不是預(yù)期的效果,需要替換下值,通過下面的sql語句,直接執(zhí)行就可以了2012-06-06