MySQL 优化:为什么 SQL 走索引还那么慢?
mysqldumpslow -s c slow.log>/tmp/slow_report.txt
Count: 3276 Time=21.75s (71261s) Lock=0.00s (1s) Rows=0.9 (2785), xxx SELECT T.TASK_ID, T.xx, T.xx, ... FROM T_xx_TASK T WHERE N=N AND T.STATUS IN (N,N,N) AND IFNULL(T.MAX_OPEN_TIMES,N) > IFNULL(T.OPEN_TIMES,N) AND (T.CLOSE_DATE IS NULL OR T.CLOSE_DATE >= SUBDATE(NOW(),INTERVAL 'S' MINUTE)) AND T.REL_DEVTYPE = N AND T.REL_DEVID = N AND T.TASK_DATE >= 'S' AND T.TASK_DATE <= 'S' ORDER BY TASK_ID DESC LIMIT N,N
explain SELECT T.TASK_ID, T.xx, ... FROM T_xxx_TASK T WHERE 1=1 AND T.STATUS IN (1,2,3) AND IFNULL(T.MAX_OPEN_TIMES,0) > IFNULL(T.OPEN_TIMES,0) AND (T.CLOSE_DATE IS NULL OR T.CLOSE_DATE >= SUBDATE(NOW(),INTERVAL '10' MINUTE)) AND T.REL_DEVTYPE = 1 AND T.REL_DEVID = 000000025xxx AND T.TASK_DATE >= '2019-01-11' AND T.TASK_DATE <= '2019-01-11' ORDER BY TASK_ID DESC LIMIT 0,20;
show index from
T_xxx_TASK;
TASK_DATE 字段存在索引,但是选择度很低,优化器不会走这个索引,建议后续可以删除这个索引: select count(*),count(distinct TASK_DATE) from T_BIOMA_ELOCK_TASK; +------------+---------------------------+ | count(*) | count(distinct TASK_DATE) | +------------+---------------------------+ | 1161559 | 223 | +------------+---------------------------+ 在这个 sql 中 REL_DEVID 字段从命名上看选择度较高,通过下面 sql 来检验确实如此: select count(*),count(distinct REL_DEVID) from T_BIOMA_ELOCK_TASK; +----------+---------------------------+ | count(*) | count(distinct REL_DEVID) | +----------+---------------------------+ | 1161559 | 62235 | +----------+---------------------------+ 由于有排序,所以得把 task_id 也加入到新建的索引中,REL_DEVID,task_id 组合选择度 100%: select count(*),count(distinct REL_DEVID,task_id) from T_BIOMA_ELOCK_TASK; +----------+-----------------------------------+ | count(*) | count(distinct REL_DEVID,task_id) | +----------+-----------------------------------+ | 1161559 | 1161559 | +----------+-----------------------------------+
一个典型的 order by 查询的优化,添加更合适的索引可以避免性能问题: 执行计划使用索引并不意味着就能执行快。
About Me
|
........................................................................................................................ ● 本文作者:小麦苗,部分内容整理自网络,若有侵权请联系小麦苗删除 ● 本文在itpub、博客园、CSDN和个人微 信公众号( DB宝)上有同步更新 ● 本文itpub地址: http://blog.itpub.net/26736162 ● 本文博客园地址: http://www.cnblogs.com/lhrbest ● 本文CSDN地址: https://blog.csdn.net/lihuarongaini ● 本文pdf版、个人简介及小麦苗云盘地址: http://blog.itpub.net/26736162/viewspace-1624453/ ● 数据库笔试面试题库及解答: http://blog.itpub.net/26736162/viewspace-2134706/ ● DBA宝典今日头条号地址: http://www.toutiao.com/c/user/6401772890/#mid=1564638659405826 ........................................................................................................................ ● QQ群号: 230161599 、618766405 ● 微 信群:可加我微 信,我拉大家进群,非诚勿扰 ● 联系我请加QQ好友 ( 646634621 ),注明添加缘由 ● 于 2020-04-01 06:00 ~ 2020-04-30 24:00 在西安完成 ● 最新修改时间:2020-04-01 06:00 ~ 2020-04-30 24:00 ● 文章内容来源于小麦苗的学习笔记,部分整理自网络,若有侵权或不当之处还请谅解 ● 版权所有,欢迎分享本文,转载请保留出处 ........................................................................................................................ ● 小麦苗的微店: https://weidian.com/s/793741433?wfr=c&ifr=shopdetail ● 小麦苗出版的数据库类丛书: http://blog.itpub.net/26736162/viewspace-2142121/ ● 小麦苗OCP、OCM、高可用网络班: http://blog.itpub.net/26736162/viewspace-2148098/ ● 小麦苗腾讯课堂主页: https://lhr.ke.qq.com/ ........................................................................................................................ 使用 微 信客户端扫描下面的二维码来关注小麦苗的微 信公众号( DB宝)及QQ群(DBA宝典)、添加小麦苗微 信, 学习最实用的数据库技术。
........................................................................................................................ |
![]() |
|

