避免索引失效
索引使用
设置正确的索引
譬如在我们的
+--------+------------+------------+--------------+--------+------------+
| emp_no | birth_date | first_name | last_name | gender | hire_date |
+--------+------------+------------+--------------+--------+------------+
| 10001 | 1953-09-02 | Georgi | Facello | M | 1986-06-26 |
...
我们想找到
mysql> select * from employees where first_name = 'Chirstian';
mysql> alter table employees add index first_name (first_name);
mysql> select * from employees where first_name = 'Chirstian';
mysql> SHOW PROFILES;
+----------+------------+---------------------------------------------------------+
| Query_ID | Duration | Query |
+----------+------------+---------------------------------------------------------+
| 1 | 0.17415400 | select * from employees where first_name = 'Chirstian' |
| 2 | 1.03130100 | alter table employees add index first_name (first_name) |
| 3 | 0.00869100 | select * from employees where first_name = 'Chirstian' |
+----------+------------+---------------------------------------------------------+
遵循最左前缀匹配原则
还拿前面的(birth_date, first_name, last_name )
的组合索引。

mysql> alter table employees add index bd_fn_ln (birth_date, first_name, last_name);
下面的查询是用到索引的:
mysql> select * from employees where birth_date = '1954-05-01' and first_name = 'Chirstian' and last_name = 'Koblick';
mysql> select * from employees where birth_date = '1954-05-01' and first_name = 'Chirstian';
mysql> select * from employees where birth_date = '1954-05-01' and last_name = 'Koblick';
下面是这三个查询
mysql> explain select * from employees where birth_date = '1954-05-01' and first_name = 'Chirstian' and last_name = 'Koblick';
+----+-------------+-----------+------+---------------+----------+---------+-------------------+------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+----------+---------+-------------------+------+-----------------------+
| 1 | SIMPLE | employees | ref | bd_fn_ln | bd_fn_ln | 97 | const,const,const | 1 | Using index condition |
+----+-------------+-----------+------+---------------+----------+---------+-------------------+------+-----------------------+
1 row in set (0.00 sec)
mysql> explain select * from employees where birth_date = '1954-05-01' and first_name = 'Chirstian' ;
+----+-------------+-----------+------+---------------+----------+---------+-------------+------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+----------+---------+-------------+------+-----------------------+
| 1 | SIMPLE | employees | ref | bd_fn_ln | bd_fn_ln | 47 | const,const | 1 | Using index condition |
+----+-------------+-----------+------+---------------+----------+---------+-------------+------+-----------------------+
1 row in set (0.01 sec)
mysql> explain select * from employees where birth_date = '1954-05-01' and last_name = 'Koblick';
+----+-------------+-----------+------+---------------+----------+---------+-------+------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+----------+---------+-------+------+-----------------------+
| 1 | SIMPLE | employees | ref | bd_fn_ln | bd_fn_ln | 3 | const | 60 | Using index condition |
+----+-------------+-----------+------+---------------+----------+---------+-------+------+-----------------------+
1 row in set (0.00 sec)
虽然结果都是一条,不过前两个查询都用到了联合索引。最后一个只用到了birth_date
这一个索引,所以会在birth_date = 1954-05-01
的last_name
来找到等于Koblick
的结果。还有
而下面这个查询因为没用到组合索引的最左列,所以不会用到索引而是遍历了所有的数据,这就是最左前缀匹配:
mysql> select * from employees where first_name = 'Chirstian' and last_name = 'Koblick';
+--------+------------+------------+-----------+--------+------------+
| emp_no | birth_date | first_name | last_name | gender | hire_date |
+--------+------------+------------+-----------+--------+------------+
| 10004 | 1954-05-01 | Chirstian | Koblick | M | 1986-12-01 |
+--------+------------+------------+-----------+--------+------------+
1 row in set (0.18 sec)
mysql> explain select * from employees where first_name = 'Chirstian' and last_name = 'Koblick';
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
| 1 | SIMPLE | employees | ALL | NULL | NULL | NULL | NULL | 299468 | Using where |
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
1 row in set (0.00 sec)
不要在比较运算符左侧使用函数或进行计算
在
mysql> explain select * from employees where emp_no + 1 = 10005;
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
| 1 | SIMPLE | employees | ALL | NULL | NULL | NULL | NULL | 299468 | Using where |
+----+-------------+-----------+------+---------------+------+---------+------+--------+-------------+
1 row in set (0.11 sec)
mysql> explain select * from employees where emp_no = 10005-1;
+----+-------------+-----------+-------+---------------+---------+---------+-------+------+-------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-----------+-------+---------------+---------+---------+-------+------+-------+
| 1 | SIMPLE | employees | const | PRIMARY | PRIMARY | 4 | const | 1 | NULL |
+----+-------------+-----------+-------+---------------+---------+---------+-------+------+-------+
1 row in set (0.00 sec)
如果对索引字段进行了任何的表达式运算,那么其都会使索引功能失效,这是因为索引始终是一个
-- 对索引字段使用MySQL函数(可以对等于号后的值使用,不能对字段使用)
mysql> select * from actor where lower(first_name)='rmqchuezjthp’; -- 错误
mysql> select * from actor where first_name='rMqChueZJThP'; -- 正确
-- 隐式字符串转换(这里license字段为一个varchar类型字段)
mysql> select * from actor where license=6535; -- 错误
mysql> select * from actor where license='6535'; -- 正确
-- 对索引字段使用数学表达式
mysql> select * from actor where hash_email + 2 = 4224712734; -- 错误
mysql> select * from actor where hash_email = 4224712732; -- 正确
困难谓词
不等式
mysql> select A, B, C, D from TABLE where A=a and B>b and C>c;
于上述查询,推荐使用索引 (A, B, C, D)
或(A, C, B, D)
,如果
OR 谓词
mysql> select A, B, C from TABLE where A>a or B>b;
推荐索引
对于
IN 谓词
mysql> select A, B, C from TABLE where A in (m, n, p) and B=b;
推荐索引:(A, B),这里