MySQL进阶 - 索引使用
索引的使用包含以下8个部分内容。
- 验证索引效率
- 最左前缀法则
- 范围查询
- 索引失效情况
- SQL提示
- 覆盖索引
- 前缀索引
- 单列索引与联合索引
验证索引效率
在讲解索引的使用原则之前,先通过一个简单的案例,来验证一下索引,看看是否能够通过索引来提升数据查询性能。
在演示的时候,使用之前准备的一张表 big_data , 在这张表中准备了1000w的记录。
这张表中id为主键,有主键索引,而其他字段是没有建立索引的。我们先来查询其中的一条记录,看里面的字段情况,执行如下SQL:
mysql> select * from big_data where id = 1;
+----+-------+------+---------------+
| id | name | age | email |
+----+-------+------+---------------+
| 1 | test0 | 37 | test0@163.com |
+----+-------+------+---------------+
1 row in set (0.00 sec)
2
3
4
5
6
7
可以看到即使有1000w的数据,根据id进行数据查询,性能依然很快,因为主键id是有索引的。 那么接下来,我们再来根据 email 字段进行查询,执行如下SQL:
mysql> select * from big_data where email = 'test0@163.com';
+----+-------+------+---------------+
| id | name | age | email |
+----+-------+------+---------------+
| 1 | test0 | 37 | test0@163.com |
+----+-------+------+---------------+
1 row in set (4.38 sec)
2
3
4
5
6
7
我们可以看到根据 email 字段进行查询,查询返回了一条数据,结果耗时 4.39sec,就是因为 email 没有索引,而造成查询效率很低。
那么我们可以针对于 email 字段,建立一个索引,建立了索引之后,我们再次根据 email 进行查询,再来看一下查询耗时情况。
创建索引:
mysql> create index idx_big_data_email on big_data(email);
Query OK, 0 rows affected (46.39 sec)
Records: 0 Duplicates: 0 Warnings: 0
2
3
然后再次执行相同的SQL语句,再次查看SQL的耗时。
ysql> select * from big_data where email = 'test0@163.com';
+----+-------+------+---------------+
| id | name | age | email |
+----+-------+------+---------------+
| 1 | test0 | 37 | test0@163.com |
+----+-------+------+---------------+
1 row in set (0.02 sec)
2
3
4
5
6
7
email 字段建立了索引之后,查询性能大大提升。建立索引前后,查询耗时都不是一个数量级的。
最左前缀法则
如果索引关联了多列(联合索引),要遵守最左前缀法则,最左前缀法则指的是查询从索引的最左列开始,并且不跳过索引中的列。 如果跳跃某一列,索引将部分失效(后面的字段索引失效)。
以 tb_user 表为例,我们先来查看一下之前 tb_user 表所创建的索引。
在 tb_user 表中,有一个联合索引,这个联合索引涉及到三个字段,顺序分别为:profession,age,status。
对于最左前缀法则指的是,查询时,最左变的列必须存在,否则索引全部失效。而且中间不能跳过某一列,否则该列后面的字段索引将失效。
接下来,我们来演示几组案例,看一下具体的执行计划:
mysql> explain select * from tb_user where profession = '软件工程' and age = 31 and status= '0';
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat,idx_user_age | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------------+------+----------+-------+
1 row in set, 1 warning (0.02 sec)
mysql> explain select * from tb_user where profession = '软件工程' and age = 31;
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat,idx_user_age | idx_user_pro_age_stat | 38 | const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession = '软件工程';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | const | 4 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
而且由以上三组测试,我们也可以推测出profession字段索引长度为36、age字段索引长度为2、status字段索引长度为4。
mysql> explain select * from tb_user where age = 31 and status = '0';
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | NULL | NULL | NULL | NULL | 24 | 4.17 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where status = '0';
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | NULL | NULL | NULL | NULL | 24 | 10.00 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
而通过上面的这两组测试,我们也可以看到索引并未生效,原因是因为不满足最左前缀法则,联合索引最左边的列profession不存在。
mysql> explain select * from tb_user where profession = '软件工程' and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | const | 4 | 10.00 | Using index condition |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
上述的SQL查询时,存在profession字段,最左边的列是存在的,索引满足最左前缀法则的基本条件。但是查询时,跳过了age这个列,所以后面的列索引是不会使用的,也就是索引部分生效,所以索 引的长度就是36。
mysql> explain select * from tb_user where age = 31 and status = '0' and profession = '软件工程';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
注意 :最左前缀法则中指的最左边的列,是指在查询时,联合索引的最左边的字段(即是第一个字段)必须存在,与编写SQL时,条件编写的先后顺序无关。
范围查询
联合索引中,出现范围查询(>,<),范围查询右侧的列索引失效。
mysql> explain select * from tb_user where profession = '软件工程' and age > 30 and status = '0';
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | range | idx_user_pro_age_stat | idx_user_pro_age_stat | 38 | NULL | 2 | 10.00 | Using index condition |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
当范围查询使用> 或 < 时,走联合索引了,但是索引的长度为38,就说明范围查询右边的status字段是没有走索引的。
mysql> explain select * from tb_user where profession = '软件工程' and age >= 30 and status = '0';
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | range | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | NULL | 2 | 10.00 | Using index condition |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
当范围查询使用>= 或 <= 时,走联合索引了,但是索引的长度为42,就说明所有的字段都是走索引的。
所以,在业务允许的情况下,尽可能的使用类似于 >= 或 <= 这类的范围查询,而避免使用 > 或 <。
索引失效情况
索引列运算
不要在索引列上进行运算操作, 索引将失效。
在tb_user表中,除了前面介绍的联合索引之外,还有一个索引,是phone字段的单列索引。
A. 当根据phone字段进行等值匹配查询时, 索引生效
mysql> explain select * from tb_user where phone = '17799990015';
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | const | idx_user_phone | idx_user_phone | 35 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
B. 当根据phone字段进行函数运算操作之后,索引失效。
mysql> explain select * from tb_user where substring(phone, 10, 2) = '15';
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | NULL | NULL | NULL | NULL | 24 | 100.00 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
字符串不加引号
字符串类型字段使用时,不加引号,索引将失效。
接下来,我们通过两组示例,来看看对于字符串类型的字段,加单引号与不加单引号的区别:
第一组:
mysql> explain select * from tb_user where profession = '软件工程' and age = 31 and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession = '软件工程' and age = 31 and status = 0;
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 38 | const,const | 1 | 10.00 | Using index condition |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------+------+----------+-----------------------+
1 row in set, 2 warnings (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
第二组:
mysql> explain select * from tb_user where phone = '17799990015';
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | const | idx_user_phone | idx_user_phone | 35 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+-------+----------------+----------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where phone = 17799990015;
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | idx_user_phone | NULL | NULL | NULL | 24 | 10.00 | Using where |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
1 row in set, 3 warnings (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
经过上面两组示例,我们会明显的发现,如果字符串不加单引号,对于查询结果,没什么影响,但是数据库存在隐式类型转换,索引将失效。
模糊查询
如果仅仅是尾部模糊匹配,索引不会失效。如果是头部模糊匹配,索引失效。
接下来,我们来看一下这三条SQL语句的执行效果,查看一下其执行计划:
由于下面查询语句中,都是根据profession字段查询,符合最左前缀法则,联合索引是可以生效的,我们主要看一下,模糊查询时,%加在关键字之前,和加在关键字之后的影响。
mysql> explain select * from tb_user where profession like '软件%';
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | range | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | NULL | 4 | 100.00 | Using index condition |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.01 sec)
mysql> explain select * from tb_user where profession like '%工程';
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | NULL | NULL | NULL | NULL | 24 | 11.11 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession like '%工%';
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | NULL | NULL | NULL | NULL | 24 | 11.11 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
经过上述的测试,我们发现,在like模糊查询中,在关键字后面加%,索引可以生效。而如果在关键字前面加了%,索引将会失效。
or连接条件
用or分割开的条件, 如果or前的条件中的列有索引,而后面的列中没有索引,那么涉及的索引都不会被用到。
由于age没有索引,所以即使id、phone有索引,索引也会失效。所以需要针对于age也要建立索引。
mysql> explain select * from tb_user where id = 10 or age = 23;
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | PRIMARY | NULL | NULL | NULL | 24 | 13.75 | Using where |
+----+-------------+---------+------------+------+---------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where phone = '17799990017' or age = 23;
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | idx_user_phone | NULL | NULL | NULL | 24 | 19.00 | Using where |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
然后,我们可以对age字段建立索引。建立了索引之后,我们再次执行上述的SQL语句,看看前后执行计划的变化。
mysql> create index idx_user_age on tb_user(age);
Query OK, 0 rows affected (0.04 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> explain select * from tb_user where id = 10 or age = 23;
+----+-------------+---------+------------+-------------+----------------------+----------------------+---------+------+------+----------+------------------------------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------------+----------------------+----------------------+---------+------+------+----------+------------------------------------------------+
| 1 | SIMPLE | tb_user | NULL | index_merge | PRIMARY,idx_user_age | PRIMARY,idx_user_age | 4,2 | NULL | 3 | 100.00 | Using union(PRIMARY,idx_user_age); Using where |
+----+-------------+---------+------------+-------------+----------------------+----------------------+---------+------+------+----------+------------------------------------------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where phone = '17799990017' or age = 23;
+----+-------------+---------+------------+-------------+-----------------------------+-----------------------------+---------+------+------+----------+-------------------------------------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------------+-----------------------------+-----------------------------+---------+------+------+----------+-------------------------------------------------------+
| 1 | SIMPLE | tb_user | NULL | index_merge | idx_user_phone,idx_user_age | idx_user_phone,idx_user_age | 35,2 | NULL | 3 | 100.00 | Using union(idx_user_phone,idx_user_age); Using where |
+----+-------------+---------+------------+-------------+-----------------------------+-----------------------------+---------+------+------+----------+-------------------------------------------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
最终,我们发现,当or连接的条件,左右两侧字段都有索引时,索引才会生效。
数据分布影响
如果MySQL评估使用索引比全表更慢,则不使用索引。
mysql> explain select * from tb_user where phone >= '17799990005';
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | idx_user_phone | NULL | NULL | NULL | 24 | 79.17 | Using where |
+----+-------------+---------+------------+------+----------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where phone >= '17799990020';
+----+-------------+---------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | range | idx_user_phone | idx_user_phone | 35 | NULL | 4 | 100.00 | Using index condition |
+----+-------------+---------+------------+-------+----------------+----------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
经过测试我们发现,相同的SQL语句,只是传入的字段值不同,最终的执行计划也完全不一样,这是为什么呢?
就是因为MySQL在查询时,会评估使用索引的效率与走全表扫描的效率,如果走全表扫描更快,则放弃索引,走全表扫描。因为索引是用来索引少量数据的,如果通过索引查询返回大批量的数据,则还不如走全表扫描来的快,此时索引就会失效。
接下来,我们再来看看 is null 与 is not null 操作是否走索引。
mysql> explain select * from tb_user where profession is null;
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | const | 1 | 100.00 | Using index condition |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession is not null;
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | idx_user_pro_age_stat | NULL | NULL | NULL | 24 | 100.00 | Using where |
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
2
3
4
5
6
7
8
9
10
11
12
13
14
然后,再次执行上述的两条SQL,查看SQL语句的执行计划。
mysql> explain select * from tb_user where profession is null;
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ALL | idx_user_pro_age_stat | NULL | NULL | NULL | 24 | 100.00 | Using where |
+----+-------------+---------+------------+------+-----------------------+------+---------+------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession is not null;
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
| 1 | SIMPLE | tb_user | NULL | range | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | NULL | 1 | 100.00 | Using index condition |
+----+-------------+---------+------------+-------+-----------------------+-----------------------+---------+------+------+----------+-----------------------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
最终我们看到,一模一样的SQL语句,先后执行了两次,结果查询计划是不一样的,为什么会出现这种现象,这是和数据库的数据分布有关系。查询时MySQL会评估,走索引快,还是全表扫描快,如果全表 扫描更快,则放弃索引走全表扫描。 因此,is null 、is not null是否走索引,得具体情况具体分析,并不是固定的。
总结
- 在索引列上进行运算操作,索引将失效。如:
explain select * from tb_user where substring(phone, 10, 2) = '15';
- 字符串类型字段使用时,不加引号,索引将失效。如:
explain select * from tb_user where phone = 17799990015;
,此处phone的值没有加引号 - 模糊查询中,如果仅仅是尾部模糊匹配,索引不会是失效;如果是头部模糊匹配,索引失效。如:
explain select * from tb_user where profession like '%工程';
,前后都有 % 也会失效。 - 用 or 分割开的条件,如果 or 其中一个条件的列没有索引,那么涉及的索引都不会被用到。
- 如果 MySQL 评估使用索引比全表更慢,则不使用索引。
SQL 提示
是优化数据库的一个重要手段,简单来说,就是在SQL语句中加入一些人为的提示来达到优化操作的目的。
A. 执行SQL : explain select * from tb_user where profession = '软件工程';
B. 执行SQL,创建profession的单列索引:create index idx_user_pro on tb_user(profession);
C. 创建单列索引后,再次执行A中的SQL语句,查看执行计划,看看到底走哪个索引。
mysql> explain select * from tb_user where profession = '软件工程';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> create index idx_user_pro on tb_user(profession);
Query OK, 0 rows affected (0.03 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> explain select * from tb_user where profession = '软件工程';
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat,idx_user_pro | idx_user_pro_age_stat | 36 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+------------------------------------+-----------------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.01 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
测试结果,我们可以看到,possible_keys中 idx_user_pro_age_sta,idx_user_pro 这两个索引都可能用到,最终MySQL选择了idx_user_pro_age_sta索引。这是MySQL自动选择的结果。
那么,我们能不能在查询的时候,自己来指定使用哪个索引呢? 答案是肯定的,此时就可以借助于MySQL的SQL提示来完成。 接下来,介绍一下SQL提示。
SQL提示,是优化数据库的一个重要手段,简单来说,就是在SQL语句中加入一些人为的提示来达到优化操作的目的。
- use index: 建议MySQL使用哪一个索引完成此次查询(仅仅是建议,mysql内部还会再次进行评估)。
- ignore index: 忽略指定的索引。
- force index: 强制使用索引。
例如,使用索引:
explain select * from tb_user use index(idx_user_pro) where profession="软件工程";
不使用哪个索引:
explain select * from tb_user ignore index(idx_user_pro) where profession="软件工程";
必须使用哪个索引:
explain select * from tb_user force index(idx_user_pro) where profession="软件工程";
测试结果:
mysql> explain select * from tb_user use index(idx_user_pro) where profession="软件工程";
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro | idx_user_pro | 36 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user ignore index(idx_user_pro) where profession="软件工程";
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 36 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user force index(idx_user_pro) where profession="软件工程";
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro | idx_user_pro | 36 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+---------------+--------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
覆盖索引&回表查询
尽量使用覆盖索引(查询使用了索引,并且需要返回的列,在该索引中已经全部能找到),减少 select *。
我们来看一组SQL的执行计划,看看执行计划的差别,然后再来具体做一个解析。
explain select id, profession from tb_user where profession = '软件工程' and age =31 and status = '0';
explain select id,profession,age,status from tb_user where profession = '软件工程' and age = 31 and status = '0';
explain select id,profession,age,status,name from tb_user where profession = '软件工程' and age = 31 and status = '0';
explain select * from tb_user where profession = '软件工程' and age = 31 and status = '0';
2
3
4
执行结果:
mysql> explain select id, profession from tb_user where profession = '软件工程' and age =31 and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | Using index |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select id,profession,age,status from tb_user where profession = '软件工程' and age = 31 and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | Using index |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select id,profession,age,status,name from tb_user where profession = '软件工程' and age = 31 and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
mysql> explain select * from tb_user where profession = '软件工程' and age = 31 and status = '0';
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | ref | idx_user_pro_age_stat | idx_user_pro_age_stat | 42 | const,const,const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+------+-----------------------+-----------------------+---------+-------------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
explain 中 extra 字段含义:
using index condition
:查找使用了索引,但是需要回表查询数据
using where; using index;
:查找使用了索引,但是需要的数据都在索引列中能找到,所以不需要回表查询
- 如果在聚集索引中直接能找到对应的行,则直接返回行数据,只需要一次查询,哪怕是select *;
- 如果在辅助索引中找聚集索引,如
select id, name from xxx where name='xxx';
,也只需要通过辅助索引(name)查找到对应的id,返回name和name索引对应的id即可,只需要一次查询; - 如果是通过辅助索引查找其他字段,则需要回表查询,如
select id, name, gender from xxx where name='xxx';
所以尽量不要用select *
,容易出现回表查询,降低效率,除非有联合索引包含了所有字段
面试题:一张表,有四个字段(id, username, password, status),由于数据量大,需要对以下SQL语句进行优化,该如何进行才是最优方案:
select id, username, password from tb_user where username='itcast';
解:给username和password字段建立联合索引,则不需要回表查询,直接覆盖索引
前缀索引
当字段类型为字符串(varchar, text等)时,有时候需要索引很长的字符串,这会让索引变得很大,查询时,浪费大量的磁盘IO,影响查询效率,此时可以只降字符串的一部分前缀,建立索引,这样可以大大节约索引空间,从而提高索引效率。
语法:
create index idx_xxxx on table_name(columnn(n));
前缀长度:可以根据索引的选择性来决定,而选择性是指不重复的索引值(基数)和数据表的记录总数的比值,索引选择性越高则查询效率越高,唯一索引的选择性是1,这是最好的索引选择性,性能也是最好的。
求选择性公式:
select count(distinct email) / count(*) from tb_user;
select count(distinct substring(email, 1, 5)) / count(*) from tb_user;
2
执行结果:
mysql> select count(distinct email) / count(*) from tb_user;
+----------------------------------+
| count(distinct email) / count(*) |
+----------------------------------+
| 1.0000 |
+----------------------------------+
1 row in set (0.00 sec)
mysql> select count(distinct substring(email, 1, 5)) / count(*) from tb_user;
+---------------------------------------------------+
| count(distinct substring(email, 1, 5)) / count(*) |
+---------------------------------------------------+
| 0.9583 |
+---------------------------------------------------+
1 row in set (0.00 sec)
2
3
4
5
6
7
8
9
10
11
12
13
14
15
为tb_user表的email字段,建立长度为5的前缀索引。
mysql> create index idx_email_5 on tb_user(email(5));
Query OK, 0 rows affected (0.04 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> select * from tb_user where email = 'lvbu666@163.com';
+----+--------+-------------+-----------------+------------+------+--------+--------+---------------------+
| id | name | phone | email | profession | age | gender | status | createtime |
+----+--------+-------------+-----------------+------------+------+--------+--------+---------------------+
| 1 | 吕布 | 17799990000 | lvbu666@163.com | NULL | 23 | 1 | 6 | 2001-02-02 00:00:00 |
+----+--------+-------------+-----------------+------------+------+--------+--------+---------------------+
1 row in set (0.00 sec)
2
3
4
5
6
7
8
9
10
11
前缀索引的查询流程:
单列索引&联合索引
单列索引:即一个索引只包含单个列
联合索引:即一个索引包含了多个列
在业务场景中,如果存在多个查询条件,考虑针对于查询字段建立索引时,建议建立联合索引,而非单列索引。
单列索引情况:
mysql> explain select id, phone, name from tb_user where phone = '17799990010' and name = '韩信';
+----+-------------+---------+------------+-------+------------------------------+----------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+------------------------------+----------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | const | idx_user_phone,idx_user_name | idx_user_phone | 35 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+-------+------------------------------+----------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
通过上述执行计划我们可以看出来,在and连接的两个字段 phone、name上都是有单列索引的,但是最终mysql只会选择一个索引phone,也就是说,只能走一个字段的索引,此时是会回表查询的。
紧接着,我们再来创建一个phone和name字段的联合索引来查询一下执行计划。
mysql> create unique index idx_user_phone_name on tb_user(phone,name);
Query OK, 0 rows affected (0.04 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> explain select id, phone, name from tb_user where phone = '17799990010' and name = '韩信';
+----+-------------+---------+------------+-------+--------------------------------------------------+----------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+---------+------------+-------+--------------------------------------------------+----------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | tb_user | NULL | const | idx_user_phone,idx_user_phone_name,idx_user_name | idx_user_phone | 35 | const | 1 | 100.00 | NULL |
+----+-------------+---------+------------+-------+--------------------------------------------------+----------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
2
3
4
5
6
7
8
9
10
11
此时,查询时,就走了联合索引,而在联合索引中包含 phone、name的信息,在叶子节点下挂的是对应的主键id,所以查询是无需回表查询的。
在业务场景中,如果存在多个查询条件,考虑针对于查询字段建立索引时,建议建立联合索引,而非单列索引。
如果查询使用的是联合索引,具体的结构示意图如下:
索引设计原则
- 针对于数据量较大,且查询比较频繁的表建立索引
- 针对于常作为查询条件(where)、排序(order by)、分组(group by)操作的字段建立索引
- 尽量选择区分度高的列作为索引,尽量建立唯一索引,区分度越高,使用索引的效率越高
- 如果是字符串类型的字段,字段长度较长,可以针对于字段的特点,建立前缀索引
- 尽量使用联合索引,减少单列索引,查询时,联合索引很多时候可以覆盖索引,节省存储空间,避免回表,提高查询效率
- 要控制索引的数量,索引并不是多多益善,索引越多,维护索引结构的代价就越大,会影响增删改的效率
- 如果索引列不能存储NULL值,请在创建表时使用NOT NULL约束它。当优化器知道每列是否包含NULL值时,它可以更好地确定哪个索引最有效地用于查询