SELECT* FROM operation WHERE type ='SQLStats' AND name ='SlowLog' AND create_time >'2017-03-16 14:00:00' ORDERBY create_time limit 10;
在新设计下查询时间基本固定,不会随着数据量的增长而发生变化。
2、隐式转换
SQL语句中查询变量和字段定义类型不匹配是另一个常见的错误。比如下面的语句:
1 2 3 4 5 6
mysql> explain extended SELECT* >FROM my_balance b >WHERE b.bpn =14000000123 >AND b.isverified ISNULL ; mysql>show warnings; | Warning |1739| Cannot use ref access on index 'bpn' due to type orcollation conversion on field 'bpn'
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 NOTIN ( 'done' ) ORDERBY o.parent, o.id LIMIT 1) t);
执行计划:
1 2 3 4 5 6 7
+----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+ |1|PRIMARY| o | index ||PRIMARY|8||24|Usingwhere; 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|Usingwhere; Using filesort | +----+--------------------+-------+-------+---------------+---------+---------+-------+------+-----------------------------------------------------+
UPDATE operation o JOIN (SELECT o.id, o.status FROM operation o WHERE o.group =123 AND o.status NOTIN ( 'done' ) ORDERBY o.parent, o.id LIMIT 1) t ON o.id = t.id SET status ='applying'
执行计划简化为:
1 2 3 4 5 6 7
+----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+ | 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|Usingwhere; Using filesort | +----+-------------+-------+------+---------------+-------+---------+-------+------+-----------------------------------------------------+
4、混合排序
MySQL 不能利用索引进行混合排序。但在某些场景,还是有机会使用特殊方法提升性能的。
1 2 3 4 5 6 7
SELECT* FROM my_order o INNERJOIN my_appraise a ON a.orderid = o.id ORDERBY a.is_reply ASC, a.appraise_time DESC LIMIT 0, 20
执行计划显示为全表扫描:
1 2 3 4 5 6 7
+----+-------------+-------+--------+-------------+---------+---------+---------------+---------+-+ | 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| +----+-------------+-------+--------+---------+---------+---------+-----------------+---------+-+
SELECT* FROM ((SELECT* FROM my_order o INNERJOIN my_appraise a ON a.orderid = o.id AND is_reply =0 ORDERBY appraise_time DESC LIMIT 0, 20) UNIONALL (SELECT* FROM my_order o INNERJOIN my_appraise a ON a.orderid = o.id AND is_reply =1 ORDERBY appraise_time DESC LIMIT 0, 20)) t ORDERBY is_reply ASC, appraisetime DESC LIMIT 20;
5、EXISTS语句
MySQL 对待 EXISTS 子句时,仍然采用嵌套子查询的执行方式。如下面的 SQL 语句:
1 2 3 4 5 6 7 8 9 10 11
SELECT* FROM my_neighbor n LEFTJOIN my_neighbor_apply sra ON n.id = sra.neighbor_id AND sra.user_id ='xxx' WHERE n.topic_status <4 ANDEXISTS(SELECT1 FROM message_info m WHERE n.id = m.neighbor_id AND m.inuser ='xxx') AND n.topic_type <>5
执行计划为:
1 2 3 4 5 6 7 8
+----+--------------------+-------+------+-----+------------------------------------------+---------+-------+---------+ -----+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +----+--------------------+-------+------+ -----+------------------------------------------+---------+-------+---------+ -----+ |1|PRIMARY| n |ALL||NULL|NULL|NULL|1086041|Usingwhere| |1|PRIMARY| sra |ref|| idx_user_id |123| const |1|Usingwhere| |2| DEPENDENT SUBQUERY | m |ref|| idx_message_info |122| const |1|Using index condition; Usingwhere| +----+--------------------+-------+------+ -----+------------------------------------------+---------+-------+---------+ -----+
去掉 exists 更改为 join,能够避免嵌套子查询,将执行时间从1.93秒降低为1毫秒。
1 2 3 4 5 6 7 8 9 10
SELECT* FROM my_neighbor n INNERJOIN message_info m ON n.id = m.neighbor_id AND m.inuser ='xxx' LEFTJOIN 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
新的执行计划:
1 2 3 4 5 6 7 8
+----+-------------+-------+--------+ -----+------------------------------------------+---------+ -----+------+ -----+ | 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|Usingwhere| |1| SIMPLE | sra |ref|| idx_user_id |123| const |1|Usingwhere| +----+-------------+-------+--------+ -----+------------------------------------------+---------+ -----+------+ -----+
6、条件下推
外部查询条件不能够下推到复杂的视图或子查询的情况有:
聚合子查询;
含有 LIMIT 的子查询;
UNION 或 UNION ALL 子查询;
输出字段中的子查询;
如下面的语句,从执行计划可以看出其条件作用于聚合子查询之后:
1 2 3 4 5 6
SELECT* FROM (SELECT target, Count(*) FROM operation GROUPBY target) t WHERE target ='rm-xxxx'
1 2 3 4 5 6 7
+----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+ |1|PRIMARY|<derived2>|ref|<auto_key0>|<auto_key0>|514| const |2|Usingwhere| |2| DERIVED | operation | index | idx_4 | idx_4 |519|NULL|20|Using index | +----+-------------+------------+-------+---------------+-------------+---------+-------+------+-------------+
确定从语义上查询条件可以直接下推后,重写如下:
1 2 3 4 5
SELECT target, Count(*) FROM operation WHERE target ='rm-xxxx' GROUPBY target
执行计划变为:
1 2 3 4 5 6
+----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+ |1| SIMPLE | operation |ref| idx_4 | idx_4 |514| const |1|Usingwhere; Using index | +----+-------------+-----------+------+---------------+-------+---------+-------+------+--------------------+
SELECT* FROM my_order o LEFTJOIN my_userinfo u ON o.uid = u.uid LEFTJOIN my_productinfo p ON o.pid = p.pid WHERE ( o.display =0 ) AND ( o.ostaus =1 ) ORDERBY o.selltime DESC LIMIT 0, 15
+----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+ | id | select_type |table| type | possible_keys | key | key_len |ref|rows| Extra | +----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+ |1| SIMPLE | o |ALL|NULL|NULL|NULL|NULL|909119|Usingwhere; 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|Usingwhere; Usingjoin buffer (Block Nested Loop) | +----+-------------+-------+--------+---------------+---------+---------+-----------------+--------+----------------------------------------------------+
由于最后 WHERE 条件以及排序均针对最左主表,因此可以先对 my_order 排序提前缩小数据量再做左连接。SQL 重写后如下,执行时间缩小为1毫秒左右。
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15
SELECT* FROM ( SELECT* FROM my_order o WHERE ( o.display =0 ) AND ( o.ostaus =1 ) ORDERBY o.selltime DESC LIMIT 0, 15 ) o LEFTJOIN my_userinfo u ON o.uid = u.uid LEFTJOIN my_productinfo p ON o.pid = p.pid ORDERBY o.selltime DESC limit 0, 15
+----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+ | 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|Usingwhere; Usingjoin buffer (Block Nested Loop) | |2| DERIVED | o | index |NULL| idx_1 |5|NULL|909112|Usingwhere| +----+-------------+------------+--------+---------------+---------+---------+-------+--------+----------------------------------------------------+
8、中间结果集下推
再来看下面这个已经初步优化过的例子(左连接中的主表优先作用查询条件):
1 2 3 4 5 6 7 8 9 10 11 12 13 14
SELECT a.*, c.allocated FROM ( SELECT resourceid FROM my_distribute d WHERE isdelete =0 AND cusmanagercode ='1234567' ORDERBY salecode limit 20) a LEFTJOIN ( SELECT resourcesid, sum(ifnull(allocation, 0) *12345) allocated FROM my_resources GROUPBY resourcesid) c ON a.resourceid = c.resourcesid
那么该语句还存在其它问题吗?不难看出子查询 c 是全表聚合查询,在表数量特别大的情况下会导致整个语句的性能下降。
SELECT a.*, c.allocated FROM ( SELECT resourceid FROM my_distribute d WHERE isdelete =0 AND cusmanagercode ='1234567' ORDERBY salecode limit 20) a LEFTJOIN ( SELECT resourcesid, sum(ifnull(allocation, 0) *12345) allocated FROM my_resources r, ( SELECT resourceid FROM my_distribute d WHERE isdelete =0 AND cusmanagercode ='1234567' ORDERBY salecode limit 20) a WHERE r.resourcesid = a.resourcesid GROUPBY resourcesid) c ON a.resourceid = c.resourcesid
但是子查询 a 在我们的SQL语句中出现了多次。这种写法不仅存在额外的开销,还使得整个语句显的繁杂。使用 WITH 语句再次重写:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18
WITH a AS ( SELECT resourceid FROM my_distribute d WHERE isdelete =0 AND cusmanagercode ='1234567' ORDERBY salecode limit 20) SELECT a.*, c.allocated FROM a LEFTJOIN ( SELECT resourcesid, sum(ifnull(allocation, 0) *12345) allocated FROM my_resources r, a WHERE r.resourcesid = a.resourcesid GROUPBY resourcesid) c ON a.resourceid = c.resourcesid