1迷帜、LIMIT 語句
分頁查詢是最常用的場景之一伯诬,但也通常也是最容易出問題的地方炼绘。比如對(duì)于下面簡單的語句,一般 DBA 想到的辦法是在 type, name, create_time 字段上加組合索引闻牡。這樣條件排序都能有效的利用到索引净赴,性能迅速提升。
SELECT *
FROM operation
WHERE type = 'SQLStats'
AND name = 'SlowLog'
ORDER BY create_time
LIMIT 1000, 10;
好吧罩润,可能90%以上的 DBA 解決該問題就到此為止玖翅。但當(dāng) LIMIT 子句變成 “LIMIT 1000000,10” 時(shí),程序員仍然會(huì)抱怨:我只取10條記錄為什么還是慢哨啃?
要知道數(shù)據(jù)庫也并不知道第1000000條記錄從什么地方開始烧栋,即使有索引也需要從頭計(jì)算一次。出現(xiàn)這種性能問題拳球,多數(shù)情形下是程序員偷懶了审姓。
在前端數(shù)據(jù)瀏覽翻頁,或者大數(shù)據(jù)分批導(dǎo)出等場景下祝峻,是可以將上一頁的最大值當(dāng)成參數(shù)作為查詢條件的魔吐。SQL 重新設(shè)計(jì)如下:
SELECT *
FROM operation
WHERE type = 'SQLStats'
AND name = 'SlowLog'
AND create_time > '2017-03-16 14:00:00'
ORDER BY create_time limit 10;
在新設(shè)計(jì)下查詢時(shí)間基本固定扎筒,不會(huì)隨著數(shù)據(jù)量的增長而發(fā)生變化。
2酬姆、隱式轉(zhuǎn)換
SQL語句中查詢變量和字段定義類型不匹配是另一個(gè)常見的錯(cuò)誤嗜桌。比如下面的語句:
mysql> explain extended SELECT *
> FROM my_balance b
> WHERE b.bpn = 14000000123
> AND b.isverified IS NULL ;
mysql> show warnings;
| Warning | 1739 | Cannot use ref access on index 'bpn' due to type or collation conversion on field 'bpn'
其中字段 bpn 的定義為 varchar(20),MySQL 的策略是將字符串轉(zhuǎn)換為數(shù)字之后再比較辞色。函數(shù)作用于表字段骨宠,索引失效。
上述情況可能是應(yīng)用程序框架自動(dòng)填入的參數(shù)相满,而不是程序員的原意〔阋冢現(xiàn)在應(yīng)用框架很多很繁雜,使用方便的同時(shí)也小心它可能給自己挖坑立美。
3匿又、關(guān)聯(lián)更新、刪除
雖然 MySQL5.6 引入了物化特性建蹄,但需要特別注意它目前僅僅針對(duì)查詢語句的優(yōu)化碌更。對(duì)于更新或刪除需要手工重寫成 JOIN。
比如下面 UPDATE 語句洞慎,MySQL 實(shí)際執(zhí)行的是循環(huán)/嵌套子查詢(DEPENDENT SUBQUERY)痛单,其執(zhí)行時(shí)間可想而知。
UPDATE operation o
SET status = 'applying'
WHERE o.id IN (SELECT id
FROM (SELECT o.id,
o.status
FROM operation o
WHERE o.group = 123
AND o.status NOT IN ( 'done' )
ORDER BY o.parent,
o.id
LIMIT 1) t);
執(zhí)行計(jì)劃:
+----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+
| 1 | PRIMARY | o | index | | PRIMARY | 8 | | 24 | Using where; Using temporary |
| 2 | DEPENDENT SUBQUERY | | | | | | | | Impossible WHERE noticed after reading const tables |
| 3 | DERIVED | o | ref | idx_2,idx_5 | idx_5 | 8 | const | 1 | Using where; Using filesort |
+----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+
重寫為 JOIN 之后拢蛋,子查詢的選擇模式從 DEPENDENT SUBQUERY 變成 DERIVED桦他,執(zhí)行速度大大加快蔫巩,從7秒降低到2毫秒谆棱。
UPDATE operation o
JOIN (SELECT o.id,
o.status
FROM operation o
WHERE o.group = 123
AND o.status NOT IN ( 'done' )
ORDER BY o.parent,
o.id
LIMIT 1) t
ON o.id = t.id
SET status = 'applying'
執(zhí)行計(jì)劃簡化為:
+----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+
| 1 | PRIMARY | | | | | | | | Impossible WHERE noticed after reading const tables |
| 2 | DERIVED | o | ref | idx_2,idx_5 | idx_5 | 8 | const | 1 | Using where; Using filesort |
+----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+
4、混合排序
MySQL 不能利用索引進(jìn)行混合排序圆仔。但在某些場景垃瞧,還是有機(jī)會(huì)使用特殊方法提升性能的。
SELECT *
FROM my_order o
INNER JOIN my_appraise a ON a.orderid = o.id
ORDER BY a.is_reply ASC,
a.appraise_time DESC
LIMIT 0, 20
執(zhí)行計(jì)劃顯示為全表掃描:
+----+-------------+-------+--------+-------------+---------+---------+---------------+---------+-+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra
+----+-------------+-------+--------+-------------+---------+---------+---------------+---------+-+
| 1 | SIMPLE | a | ALL | idx_orderid | NULL | NULL | NULL | 1967647 | Using filesort |
| 1 | SIMPLE | o | eq_ref | PRIMARY | PRIMARY | 122 | a.orderid | 1 | NULL |
+----+-------------+-------+--------+---------+---------+---------+-----------------+---------+-+
由于 is_reply 只有0和1兩種狀態(tài)坪郭,我們按照下面的方法重寫后个从,執(zhí)行時(shí)間從1.58秒降低到2毫秒。
SELECT *
FROM ((SELECT *
FROM my_order o
INNER JOIN my_appraise a
ON a.orderid = o.id
AND is_reply = 0
ORDER BY appraise_time DESC
LIMIT 0, 20)
UNION ALL
(SELECT *
FROM my_order o
INNER JOIN my_appraise a
ON a.orderid = o.id
AND is_reply = 1
ORDER BY appraise_time DESC
LIMIT 0, 20)) t
ORDER BY is_reply ASC,
appraisetime DESC
LIMIT 20;
5歪沃、EXISTS語句
MySQL 對(duì)待 EXISTS 子句時(shí)嗦锐,仍然采用嵌套子查詢的執(zhí)行方式。如下面的 SQL 語句:
SELECT *
FROM my_neighbor n
LEFT JOIN my_neighbor_apply sra
ON n.id = sra.neighbor_id
AND sra.user_id = 'xxx'
WHERE n.topic_status < 4
AND EXISTS(SELECT 1
FROM message_info m
WHERE n.id = m.neighbor_id
AND m.inuser = 'xxx')
AND n.topic_type <> 5
執(zhí)行計(jì)劃為:
+----+--------------------+-------+------+-----+------------------------------------------+---------+-------+---------+ -----+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+--------------------+-------+------+ -----+------------------------------------------+---------+-------+---------+ -----+
| 1 | PRIMARY | n | ALL | | NULL | NULL | NULL | 1086041 | Using where |
| 1 | PRIMARY | sra | ref | | idx_user_id | 123 | const | 1 | Using where |
| 2 | DEPENDENT SUBQUERY | m | ref | | idx_message_info | 122 | const | 1 | Using index condition; Using where |
+----+--------------------+-------+------+ -----+------------------------------------------+---------+-------+---------+ -----+
去掉 exists 更改為 join沪曙,能夠避免嵌套子查詢奕污,將執(zhí)行時(shí)間從1.93秒降低為1毫秒。
SELECT *
FROM my_neighbor n
INNER JOIN message_info m
ON n.id = m.neighbor_id
AND m.inuser = 'xxx'
LEFT JOIN my_neighbor_apply sra
ON n.id = sra.neighbor_id
AND sra.user_id = 'xxx'
WHERE n.topic_status < 4
AND n.topic_type <> 5
新的執(zhí)行計(jì)劃:
+----+-------------+-------+--------+ -----+------------------------------------------+---------+ -----+------+ -----+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+--------+ -----+------------------------------------------+---------+ -----+------+ -----+
| 1 | SIMPLE | m | ref | | idx_message_info | 122 | const | 1 | Using index condition |
| 1 | SIMPLE | n | eq_ref | | PRIMARY | 122 | ighbor_id | 1 | Using where |
| 1 | SIMPLE | sra | ref | | idx_user_id | 123 | const | 1 | Using where |
+----+-------------+-------+--------+ -----+------------------------------------------+---------+ -----+------+ -----+
6液走、條件下推
外部查詢條件不能夠下推到復(fù)雜的視圖或子查詢的情況有:
- 聚合子查詢碳默;
- 含有 LIMIT 的子查詢贾陷;
- UNION 或 UNION ALL 子查詢;
- 輸出字段中的子查詢嘱根;
如下面的語句髓废,從執(zhí)行計(jì)劃可以看出其條件作用于聚合子查詢之后:
SELECT *
FROM (SELECT target,
Count(*)
FROM operation
GROUP BY target) t
WHERE target = 'rm-xxxx'
+----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+
| 1 | PRIMARY | <derived2> | ref | <auto_key0> | <auto_key0> | 514 | const | 2 | Using where |
| 2 | DERIVED | operation | index | idx_4 | idx_4 | 519 | NULL | 20 | Using index |
+----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+
確定從語義上查詢條件可以直接下推后,重寫如下:
SELECT target,
Count(*)
FROM operation
WHERE target = 'rm-xxxx'
GROUP BY target
執(zhí)行計(jì)劃變?yōu)椋?/p>
+----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+
| 1 | SIMPLE | operation | ref | idx_4 | idx_4 | 514 | const | 1 | Using where; Using index |
+----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+
7该抒、提前縮小范圍
先上初始 SQL 語句:
SELECT *
FROM my_order o
LEFT JOIN my_userinfo u
ON o.uid = u.uid
LEFT JOIN my_productinfo p
ON o.pid = p.pid
WHERE ( o.display = 0 )
AND ( o.ostaus = 1 )
ORDER BY o.selltime DESC
LIMIT 0, 15
該SQL語句原意是:先做一系列的左連接慌洪,然后排序取前15條記錄。從執(zhí)行計(jì)劃也可以看出凑保,最后一步估算排序記錄數(shù)為90萬蒋譬,時(shí)間消耗為12秒。
+----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+
| 1 | SIMPLE | o | ALL | NULL | NULL | NULL | NULL | 909119 | Using where; Using temporary; Using filesort |
| 1 | SIMPLE | u | eq_ref | PRIMARY | PRIMARY | 4 | o.uid | 1 | NULL |
| 1 | SIMPLE | p | ALL | PRIMARY | NULL | NULL | NULL | 6 | Using where; Using join buffer (Block Nested Loop) |
+----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+
由于最后 WHERE 條件以及排序均針對(duì)最左主表愉适,因此可以先對(duì) my_order 排序提前縮小數(shù)據(jù)量再做左連接犯助。SQL 重寫后如下,執(zhí)行時(shí)間縮小為1毫秒左右维咸。
SELECT *
FROM (
SELECT *
FROM my_order o
WHERE ( o.display = 0 )
AND ( o.ostaus = 1 )
ORDER BY o.selltime DESC
LIMIT 0, 15
) o
LEFT JOIN my_userinfo u
ON o.uid = u.uid
LEFT JOIN my_productinfo p
ON o.pid = p.pid
ORDER BY o.selltime DESC
limit 0, 15
再檢查執(zhí)行計(jì)劃:子查詢物化后(select_type=DERIVED)參與 JOIN剂买。雖然估算行掃描仍然為90萬,但是利用了索引以及 LIMIT 子句后癌蓖,實(shí)際執(zhí)行時(shí)間變得很小瞬哼。
+----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+
| 1 | PRIMARY | <derived2> | ALL | NULL | NULL | NULL | NULL | 15 | Using temporary; Using filesort |
| 1 | PRIMARY | u | eq_ref | PRIMARY | PRIMARY | 4 | o.uid | 1 | NULL |
| 1 | PRIMARY | p | ALL | PRIMARY | NULL | NULL | NULL | 6 | Using where; Using join buffer (Block Nested Loop) |
| 2 | DERIVED | o | index | NULL | idx_1 | 5 | NULL | 909112 | Using where |
+----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+
8、中間結(jié)果集下推
再來看下面這個(gè)已經(jīng)初步優(yōu)化過的例子(左連接中的主表優(yōu)先作用查詢條件):
SELECT a.*,
c.allocated
FROM (
SELECT resourceid
FROM my_distribute d
WHERE isdelete = 0
AND cusmanagercode = '1234567'
ORDER BY salecode limit 20) a
LEFT JOIN
(
SELECT resourcesid租副, sum(ifnull(allocation, 0) * 12345) allocated
FROM my_resources
GROUP BY resourcesid) c
ON a.resourceid = c.resourcesid
那么該語句還存在其它問題嗎坐慰?不難看出子查詢 c 是全表聚合查詢,在表數(shù)量特別大的情況下會(huì)導(dǎo)致整個(gè)語句的性能下降用僧。
其實(shí)對(duì)于子查詢 c结胀,左連接最后結(jié)果集只關(guān)心能和主表 resourceid 能匹配的數(shù)據(jù)。因此我們可以重寫語句如下责循,執(zhí)行時(shí)間從原來的2秒下降到2毫秒糟港。
SELECT a.*,
c.allocated
FROM (
SELECT resourceid
FROM my_distribute d
WHERE isdelete = 0
AND cusmanagercode = '1234567'
ORDER BY salecode limit 20) a
LEFT JOIN
(
SELECT resourcesid, sum(ifnull(allocation, 0) * 12345) allocated
FROM my_resources r,
(
SELECT resourceid
FROM my_distribute d
WHERE isdelete = 0
AND cusmanagercode = '1234567'
ORDER BY salecode limit 20) a
WHERE r.resourcesid = a.resourcesid
GROUP BY resourcesid) c
ON a.resourceid = c.resourcesid
但是子查詢 a 在我們的SQL語句中出現(xiàn)了多次院仿。這種寫法不僅存在額外的開銷秸抚,還使得整個(gè)語句顯的繁雜。使用 WITH 語句再次重寫:
WITH a AS
(
SELECT resourceid
FROM my_distribute d
WHERE isdelete = 0
AND cusmanagercode = '1234567'
ORDER BY salecode limit 20)
SELECT a.*,
c.allocated
FROM a
LEFT JOIN
(
SELECT resourcesid歹垫, sum(ifnull(allocation, 0) * 12345) allocated
FROM my_resources r,
a
WHERE r.resourcesid = a.resourcesid
GROUP BY resourcesid) c
ON a.resourceid = c.resourcesid
總結(jié)
數(shù)據(jù)庫編譯器產(chǎn)生執(zhí)行計(jì)劃剥汤,決定著SQL的實(shí)際執(zhí)行方式。但是編譯器只是盡力服務(wù)排惨,所有數(shù)據(jù)庫的編譯器都不是盡善盡美的吭敢。
上述提到的多數(shù)場景,在其它數(shù)據(jù)庫中也存在性能問題若贮。了解數(shù)據(jù)庫編譯器的特性省有,才能避規(guī)其短處痒留,寫出高性能的SQL語句。
程序員在設(shè)計(jì)數(shù)據(jù)模型以及編寫SQL語句時(shí)蠢沿,要把算法的思想或意識(shí)帶進(jìn)來伸头。
編寫復(fù)雜SQL語句要養(yǎng)成使用 WITH 語句的習(xí)慣。簡潔且思路清晰的SQL語句也能減小數(shù)據(jù)庫的負(fù)擔(dān) 舷蟀。