前言MySQL在2016年仍然保持强劲的数据库流行度增长趋势。越来越多的客户将自己的应用建立在MySQL数据库之上,甚至是从Oracle迁移到MySQL上来。但也存在部分客户在使用MySQL数据库的过程中遇到一些比如响应时间慢,CPU打满等情况。阿里云RDS专家服务团队帮助云上客户解决过很多紧急问题。现将《ApsaraDB专家诊断报告》中出现的部分常见SQL问题总结如下,供大家参考。
常见SQL错误用法
LIMIT 语句分页查询是最常用的场景之一,但也通常也是最容易出问题的地方。比如对于下面简单的语句,一般DBA想到的办法是在type, name, create_time字段上加组合索引。这样条件排序都能有效的利用到索引,性能迅速提升。SELECT * FROM operation WHERE type = 'SQLStats'
AND name = 'SlowLog'ORDER BY create_time LIMIT 1000, 10; 好吧,可能90%以上的DBA解决该问题就到此为止。但当 LIMIT 子句变成 “LIMIT 1000000,10” 时,程序员仍然会抱怨:我只取10条记录为什么还是慢?
要知道数据库也并不知道第1000000条记录从什么地方开始,即使有索引也需要从头计算一次。出现这种性能问题,多数情形下是程序员偷懒了。在前端数据浏览翻页,或者大数据分批导出等场景下,是可以将上一页的最大值当成参数作为查询条件的。SQL重新设计如下:
SELECT * FROM operation WHERE type = 'SQLStats' AND name = 'SlowLog' AND create_time > '2017-03-16 14:00:00' ORDER BY create_time limit 10;在新设计下查询时间基本固定,不会随着数据量的增长而发生变化。
隐式转换SQL语句中查询变量和字段定义类型不匹配是另一个常见的错误。比如下面的语句: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的策略是将字符串转换为数字之后再比较。函数作用于表字段,索引失效。
上述情况可能是应用程序框架自动填入的参数,而不是程序员的原意。现在应用框架很多很繁杂,使用方便的同时也小心它可能给自己挖坑。
关联更新、删除虽然MySQL5.6引入了物化特性,但需要特别注意它目前仅仅针对查询语句的优化。对于更新或删除需要手工重写成JOIN。比如下面UPDATE语句,MySQL实际执行的是循环/嵌套子查询(DEPENDENT SUBQUERY),其执行时间可想而知。
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);执行计划:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1PRIMARYoindex PRIMARY8 24Using where; Using temporary2DEPENDENT SUBQUERY Impossible WHERE noticed after reading const tables3DERIVEDorefidx_2,idx_5idx_58const1Using where; Using filesort重写为JOIN之后,子查询的选择模式从DEPENDENT SUBQUERY变成DERIVED,执行速度大大加快,从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.idSET status = 'applying' 执行计划简化为:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1PRIMARY Impossible WHERE noticed after reading const tables2DERIVEDorefidx_2,idx_5idx_58const1Using where; Using filesort 混合排序MySQL不能利用索引进行混合排序。但在某些场景,还是有机会使用特殊方法提升性能的。SELECT * FROM my_order o
INNER JOIN my_appraise a ON a.orderid = o.idORDER BY a.is_reply ASC,
a.appraise_time DESCLIMIT 0, 20 执行计划显示为全表扫描:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1SIMPLEaALLidx_orderidNULLNULLNULL1967647Using filesort1SIMPLEoeq_refPRIMARYPRIMARY122a.orderid1NULL由于is_reply只有0和1两种状态,我们按照下面的方法重写后,执行时间从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)) tORDER BY is_reply ASC,
appraisetime DESCLIMIT 20;
EXISTS语句MySQL对待EXISTS子句时,仍然采用嵌套子查询的执行方式。如下面的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执行计划为:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1PRIMARYnALL NULLNULLNULL1086041Using where1PRIMARYsraref idx_user_id123const1Using where2DEPENDENT SUBQUERYmref idx_message_info122const1Using index condition; Using where去掉exists更改为join,能够避免嵌套子查询,将执行时间从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新的执行计划:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1SIMPLEmref idx_message_info122const1Using index condition1SIMPLEneq_ref PRIMARY122ighbor_id1Using where1SIMPLEsraref idx_user_id123const1Using where 条件下推外部查询条件不能够下推到复杂的视图或子查询的情况有:聚合子查询;含有LIMIT的子查询;UNION 或UNION ALL子查询;输出字段中的子查询;如下面的语句,从执行计划可以看出其条件作用于聚合子查询之后:
SELECT * FROM (SELECT target,
Count(*) FROM operation GROUP BY target) t WHERE target = 'rm-xxxx'idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1PRIMARYref514const2Using where2DERIVEDoperationindexidx_4idx_4519NULL20Using index确定从语义上查询条件可以直接下推后,重写如下:
SELECT target,
Count(*)FROM operation WHERE target = 'rm-xxxx' GROUP BY target执行计划变为:
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1SIMPLEoperationrefidx_4idx_4514const1Using where; Using index关于MySQL外部条件不能下推的详细解释说明请参考以前文章:MySQL · 性能优化 · 条件下推到物化表
提前缩小范围先上初始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.pidWHERE ( o.display = 0 )
AND ( o.ostaus = 1 )ORDER BY o.selltime DESC LIMIT 0, 15 该SQL语句原意是:先做一系列的左连接,然后排序取前15条记录。从执行计划也可以看出,最后一步估算排序记录数为90万,时间消耗为12秒。
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1SIMPLEoALLNULLNULLNULLNULL909119Using where; Using temporary; Using filesort1SIMPLEueq_refPRIMARYPRIMARY4o.uid1NULL1SIMPLEpALLPRIMARYNULLNULLNULL6Using where; Using join buffer (Block Nested Loop)由于最后WHERE条件以及排序均针对最左主表,因此可以先对my_order排序提前缩小数据量再做左连接。SQL重写后如下,执行时间缩小为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.pidORDER BY o.selltime DESClimit 0, 15再检查执行计划:子查询物化后(select_type=DERIVED)参与JOIN。虽然估算行扫描仍然为90万,但是利用了索引以及LIMIT 子句后,实际执行时间变得很小。
idselect_typetabletypepossible_keyskeykey_lenrefrowsExtra1PRIMARYALLNULLNULLNULLNULL15Using temporary; Using filesort1PRIMARYueq_refPRIMARYPRIMARY4o.uid1NULL1PRIMARYpALLPRIMARYNULLNULLNULL6Using where; Using join buffer (Block Nested Loop)2DERIVEDoindexNULLidx_15NULL909112Using where 中间结果集下推再来看下面这个已经初步优化过的例子(左连接中的主表优先作用查询条件):SELECT a.*,
c.allocatedFROM (
SELECT resourceid FROM my_distribute d WHERE isdelete = 0 AND cusmanagercode = '1234567' ORDER BY salecode limit 20) aLEFT JOIN
( SELECT resourcesid, sum(ifnull(allocation, 0) * 12345) allocated FROM my_resources GROUP BY resourcesid) cON a.resourceid = c.resourcesid那么该语句还存在其它问题吗?不难看出子查询 c 是全表聚合查询,在表数量特别大的情况下会导致整个语句的性能下降。
其实对于子查询 c,左连接最后结果集只关心能和主表resourceid能匹配的数据。因此我们可以重写语句如下,执行时间从原来的2秒下降到2毫秒。
SELECT a.*,
c.allocatedFROM (
SELECT resourceid FROM my_distribute d WHERE isdelete = 0 AND cusmanagercode = '1234567' ORDER BY salecode limit 20) aLEFT 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) cON a.resourceid = c.resourcesid但是子查询 a 在我们的SQL语句中出现了多次。这种写法不仅存在额外的开销,还使得整个语句显的繁杂。使用WITH语句再次重写:
WITH a AS (
SELECT resourceid FROM my_distribute d WHERE isdelete = 0 AND cusmanagercode = '1234567' ORDER BY salecode limit 20)SELECT a.*,
c.allocatedFROM a LEFT JOIN
( SELECT resourcesid, sum(ifnull(allocation, 0) * 12345) allocated FROM my_resources r, a WHERE r.resourcesid = a.resourcesid GROUP BY resourcesid) cON a.resourceid = c.resourcesidAliSQL即将推出WITH语法,敬请期待。
总结数据库编译器产生执行计划,决定着SQL的实际执行方式。但是编译器只是尽力服务,所有数据库的编译器都不是尽善尽美的。上述提到的多数场景,在其它数据库中也存在性能问题。了解数据库编译器的特性,才能避规其短处,写出高性能的SQL语句。程序员在设计数据模型以及编写SQL语句时,要把算法的思想或意识带进来。编写复杂SQL语句要养成使用WITH语句的习惯。简洁且思路清晰的SQL语句也能减小数据库的负担 ^^。使用云上数据库遇到难点(不局限于SQL问题),随时寻求阿里云原厂专家服务的帮助。
