今天來分享幾個(gè)MySQL常見的SQL錯(cuò)誤(不當(dāng))用法。我們?cè)谧鳛橐粋€(gè)初學(xué)者時(shí)赋除,很有可能自己在寫SQL時(shí)也沒有注意到這些問題阱缓,導(dǎo)致寫出來的SQL語句效率低下,所以我們也可以自省自檢一下举农。
常見SQL錯(cuò)誤用法
- 1荆针、LIMIT 語句
分頁查詢是最常用的場(chǎng)景之一,但也通常也是最容易出問題的地方颁糟。比如對(duì)于下面簡(jiǎn)單的語句航背,一般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)出等場(chǎng)景下督函,是可以將上一頁的最大值當(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ò)誤垄分。比如下面的語句:
SELECT *
FROM operation
WHERE type = 'SQLStats'
AND name = 'SlowLog'
AND create_time > '2017-03-16 14:00:00'
ORDER BY create_time limit 10;
其中字段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ì)劃簡(jiǎn)化為:
+----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+
| 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)行混合排序篓像。但在某些場(chǎng)景动知,還是有機(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 |
+----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+
寫在最后
歡迎大家關(guān)注我的公眾號(hào)【風(fēng)平浪靜如碼】概疆,海量Java相關(guān)文章逗威,學(xué)習(xí)資料都會(huì)在里面更新,整理的資料也會(huì)放在里面岔冀。
覺得寫的還不錯(cuò)的就點(diǎn)個(gè)贊凯旭,加個(gè)關(guān)注唄!點(diǎn)關(guān)注使套,不迷路罐呼,持續(xù)更新!U旄摺嫉柴!