语句是这条
SELECT DISTINCT bank, account FROM sdb_payments WHERE status="succ";
status 上有索引,但不是主索引。
status 字段 `status` enum('succ','failed','cancel','error','progress','invalid','timeout','ready') NOT NULL DEFAULT 'ready'
我本来以为这是 一条很普通的语句,但是平均执行时间达到了接近3s 。数据量是25w ,
接着是explain
1 | SIMPLE | sdb_payments | ref | status | status | 1 | const | 123886 | Using where; Using temporary
using temporary 这个就很让人疑惑了。distinct 居然要用临时文件,在我的理解,using filesort 和using temporary 都是比较慢的操作,因为设计磁盘的io会很多。
接着是profile 详细支出。
set profiling =1;
SELECT distinct bank, account FROM sdb_payments WHERE status="succ";
show profiles;
+----------+------------+----------------------------------------------------------------------+| Query_ID | Duration | Query |+----------+------------+----------------------------------------------------------------------+| 1 | 1.20948900 | SELECT distinct bank, account FROM sdb_payments WHERE status="succ" |+----------+------------+----------------------------------------------------------------------+show proflie for query 1;
+--------------------------------+----------+
| Status | Duration |+--------------------------------+----------+| starting | 0.000060 || checking query cache for query | 0.000071 || Opening tables | 0.000021 || System lock | 0.000008 || Table lock | 0.000034 || init | 0.000140 || optimizing | 0.000019 || statistics | 0.000088 || preparing | 0.000030 || Creating tmp table | 0.000040 || executing | 0.000009 || Copying to tmp table | 2.512772 || Sending data | 0.000056 || end | 0.000007 || removing tmp table | 0.000017 || end | 0.000008 || query end | 0.000007 || freeing items | 0.000027 || storing result in query cache | 0.000275 || logging slow query | 0.000014 || logging slow query | 0.000065 || cleaning up | 0.000009 |+--------------------------------+----------+为啥会有tmp table 呢,看文档。
In most cases, a DISTINCT
clause can be considered as a special case of GROUP BY
. For example, the following two queries are equivalent:
SELECT DISTINCT c1, c2, c3 FROM t1WHERE c1 > const;SELECT c1, c2, c3 FROM t1WHERE c1 > const GROUP BY c1, c2, c3;
大多数情况下,distinct 都会转化为group by 的语句,
所以再看group by的优化:
The most general way to satisfy a GROUP BY
clause is to scan the whole table and create a new temporary table where all rows from each group are consecutive, and then use this temporary table to discover groups and apply aggregate functions (if any). In some cases, MySQL is able to do much better than that and to avoid creation of temporary tables by using index access.
通常情况下,group by会扫描整个表,然后创建一个临时表。。 这里不是很明白。在某些情况下,mysql能用所以而避免用临时表。
SELECT distinct bank, account FROM sdb_payments WHERE status="succ" 这句sql 我觉得是被优化器转化为
SELECT bank, account FROM sdb_payments WHERE status="succ" group by bank,account
这里我添加( bank,account)的联合索引,发现还是没有走索引。。
难道是我想错了?
于是再次explain ,这次加上extended ,然后 马上show warnings ,可以看到解析器是怎么解析sql 的。
Note | 1003 | select distinct `test`.`sdb_payments`.`bank` AS `bank`,`test`.`sdb_payments`.`account` AS `account` from `test`.`sdb_payments` where (`test`.`sdb_payments`.`status` = 'succ' )
想了想,应该把status 也加到索引里面去,变成(status,bank,accout),然后发现
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+--------------+------+----------------+---------+---------+-------+--------+----------+--------------------------+| 1 | SIMPLE | sdb_payments | ref | status,idx_acc | idx_acc | 1 | const | 123917 | 100.00 | Using where; Using index |速度极快。