version : 5.7, from 8.2.1.14 ORDER BY Optimization
本节描述MySQL何时可以使用索引来满足ORDER BY子句,当不能使用索引时使用filesort,以及优化器中有关ORDER BY的执行计划信息。
一个order by语句对于有没有使用limit可能存在执行差异。详细内容查看8.2.1.17 LIMIT Query Optimization。
使用索引实现order by
在某些情况下,MySQL可能会使用索引来满足一个ORDER BY子句,并避免执行filesort 操作时涉及的额外排序。
虽然ORDER BY并不完全精确地匹配索引,但是索引还是会被使用,只要在WHERE子句中,所有未被使用的那部分索引(一个索引多个字段-联合索引的情况)以及所有ORDER BY字段都是一个常量就没问题,都会走到索引而不是filesort。
这里我们有一张表tx_order,
1 |
|
并且添加索引
1 |
|
在接下来的sql中分析order by对索引的使用情况。其中MySQL优化器实际执行sql是否使用索引还是表扫描取决于两者的效率。
- 下面这个sql中,优化器使用了idx_market_date索引避开了表扫描. ```` desc select market_id,create_date from tx_order.tx_order order by market_id,create_date;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index
1 |
|
desc select market_id,create_date,market_name from tx_order.tx_order order by market_id,create_date;
1 SIMPLE tx_order ALL 1671956 100 Using filesort
1 |
|
desc select id,market_id,create_date from tx_order.tx_order order by market_id,create_date;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index
1 |
|
desc select market_id,create_date from tx_order.tx_order where market_id = ‘1009’ order by create_date;
1 SIMPLE tx_order ref idx_market_date idx_market_date 33 const 170398 100 Using where; Using index
1 |
|
desc select market_id,create_date from tx_order.tx_order order by market_id desc ,create_date desc ;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index
desc select market_id,create_date from tx_order.tx_order order by market_id asc ,create_date desc ;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index; Using filesort
1 |
|
desc select market_id,create_date from tx_order.tx_order where market_id > ‘1009’ order by market_id asc;
1 SIMPLE tx_order range idx_market_date idx_market_date 33 835978 100 Using where; Using index
desc select market_id,create_date from tx_order.tx_order where market_id < ‘1009’ order by market_id desc;
1 SIMPLE tx_order range idx_market_date idx_market_date 33 230966 100 Using where; Using index
1 |
|
desc select market_id,create_date from tx_order.tx_order where market_id = ‘1009’ and create_date>’2018-01-01’ order by create_date desc;
1 SIMPLE tx_order range idx_market_date idx_market_date 39 94002 100 Using where; Using index
1 |
|
desc select market_id,create_date from tx_order.tx_order where market_id=’1009’ order by market_id ,create_date ;
1 SIMPLE tx_order ref idx_market_id,idx_market_type_create_date idx_market_id 33 const 138084 100 Using where; Using index; Using filesort
1 |
|
desc select market_id,create_date from tx_order.tx_order order by market_id asc ,create_date desc;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index; Using filesort
1 |
|
desc select mobile from tx_order.tx_order order by abs(mobile);
1 SIMPLE tx_order index idx_mobile 768 1671956 100 Using index; Using filesort
1 |
|
desc select a.market_id from tx_order.tx_order a ,tx_order_item b where a.id = b.order_id and a.market_id = ‘1009’ order by a.market_id,b.sku;
1 SIMPLE b ALL idx_order_create 1 100 Using filesort 1 SIMPLE a eq_ref PRIMARY,idx_market_date PRIMARY 8 tx_order.b.order_id 1 10.19 Using where
1 |
|
desc select market_id,create_date from tx_order.tx_order group by market_id,create_date order by create_date;
1 SIMPLE tx_order index idx_market_date idx_market_date 39 1671956 100 Using index; Using temporary; Using filesort
1 |
|
desc select mobile from tx_order.tx_order order by mobile desc ;
1 SIMPLE tx_order ALL 1671956 100 Using filesort
1 |
|
desc select abs(market_id) as aa from tx_order.tx_order order by aa;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index; Using filesort
1 |
|
desc select abs(market_id) as aa from tx_order.tx_order order by market_id;
1 SIMPLE tx_order index idx_market_date 39 1671956 100 Using index
1 |
|
desc select market_id,count(market_id) from tx_order.tx_order group by market_id order by null ;
1 |
|
desc select * from tx_order.tx_order order by market_name desc limit 10;
1 SIMPLE tx_order ALL 1671956 100 Using filesort
1 |
|
desc select market_name from tx_order.tx_order order by RAND() desc limit 10;
1 SIMPLE tx_order ALL 1671956 100 Using temporary; Using filesort
1 |
|
“filesort_summary”: { “rows”: 100, “examined_rows”: 100, “number_of_tmp_files”: 0, “sort_buffer_size”: 25192, “sort_mode”: “<sort_key, packed_additional_fields>” } ````
对于MySQL的trace,详细请参考Chapter 8 Tracing the Optimizer.
总结
想要写出高效可靠的排序查询,你需要搞明白order by大概的执行过程,这里可以参考How MySQL executes ORDER BY,Mysql 排序优化与索引使用(转)这两篇文章。
我们在写sql语句并且使用order by的时候,首先考虑满足索引条件,如果不满足那么满足内存中filesort,最坏的情况就是临时文件出现了,当然这种情况是我们最不想看到的。
同时这里要说一下我的个人经验:
- 联合索引是个好东西,能够应用到项目中的很多使用场景,详细优化可以参照8.3 Optimization and Indexes。
- sql改写,复杂的单条sql可以改写成两条或者三条,使用上索引。
- 建立好的表结构,为字段分配最合身的类型和长度。
开放过程中多去琢磨sql,多看执行计划,有效的避免慢查询,提高服务的性能。