Skip to content

索引最佳实践

示例表

sql
CREATE TABLE `employees` (
	`id` INT (11) NOT NULL AUTO_INCREMENT,
	`name` VARCHAR (24) NOT NULL DEFAULT '' COMMENT '姓名',
	`age` INT (11) NOT NULL DEFAULT '0' COMMENT '年龄',
	`position` VARCHAR (20) NOT NULL DEFAULT '' COMMENT '职位',
	`hire_time` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '入职时间',
	PRIMARY KEY (`id`),
	KEY `idx_name_age_position` (`name`, `age`, `position`) USING BTREE
) ENGINE = INNODB AUTO_INCREMENT = 4 DEFAULT CHARSET = utf8 COMMENT = '员工记录表';

INSERT INTO employees (
	NAME,
	age,
	position,
	hire_time
)
VALUES
	('LiLei', 22, 'manager', NOW());

INSERT INTO employees (
	NAME,
	age,
	position,
	hire_time
)
VALUES
	('HanMeimei', 23, 'dev', NOW());

INSERT INTO employees (
	NAME,
	age,
	position,
	hire_time
)
VALUES
	('Lucy', 23, 'dev', NOW());
  • 创建了 name, age, position 联合索引

全值匹配

  1. 示例一
sql
EXPLAIN SELECT * FROM employees WHERE name = 'LiLei';
  • 结果
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position74const1100null
  1. 示例 2
sql
EXPLAIN SELECT * FROM employees WHERE name= 'LiLei' AND age = 22;
  • 结果
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position78const,const1100null
  1. 示例 3
sql
EXPLAIN SELECT * FROM employees WHERE name= 'LiLei' AND age = 22 AND position='manager'
  • 结果
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position140const,const,const1100null

最左前缀法则

如果索引创建了联合索引, 那么就必须遵守最左前缀索引。具体指的就是查询从索引的最左列开始并不跳过索引中的列

  1. 案例一
sql
EXPLAIN SELECT * FROM employees WHERE name = 'Bill' and age = 31;
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position78const,const1100null
  • 备注: 走索引
  1. 案例二
sql
EXPLAIN SELECT * FROM employees WHERE age = 30 AND position = 'dev';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullALL333.33null
  • 备注: 索引失效
  1. 案例 3
sql
EXPLAIN SELECT * FROM employees WHERE position = 'manager';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullALL333.33null
  • 备注:索引失效

不在索引上做任何操作(计算、函数、类型转换),会导致索引失效转向全表扫描

sql
EXPLAIN SELECT * FROM employees WHERE left(name,3) = 'LiLei';

存储引擎不能使用索引中范围条件右边的列

sql
 EXPLAIN SELECT * FROM employees WHERE name= 'LiLei' AND age = 22 AND position ='manager';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position140const,const1100null
sql
 EXPLAIN SELECT * FROM employees WHERE name= 'LiLei' AND age > 22 AND position ='manage
r';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrangeidx_name_age_positionidx_name_age_position781100null
  • 备注: 使用了范围查询,从 key_len 可以知道 position 的索引不生效

尽量使用覆盖索引(只访问索引的查询(索引列包含查询列)),减少回表查询,减少 select * 语句

sql
EXPLAIN SELECT name,age FROM employees WHERE name= 'LiLei' AND age = 23 AND position
='manager';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position140const,const,const1100Using index
sql
EXPLAIN SELECT * FROM employees WHERE name= 'LiLei' AND age = 23 AND position
='manager';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrefidx_name_age_positionidx_name_age_position140const,const,const1100
  • 备注: Extra 的区别

mysql 在使用不等于(!=或者<>),not in ,not exists 的时候无法使用索引会导致全表扫描 < 小于、 > 大于、 <=、>= 这些,mysql 内部优化器会根据检索比例、表大小等多个因素整体评估是否使用索引

sql
EXPLAIN SELECT * FROM employees WHERE name != 'LiLei';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullALLidx_name_age_position366.67Using where

is null,is not null 一般情况下也无法使用索引

sql
EXPLAIN SELECT * FROM employees WHERE name is null
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEImpossible WHERE

like 以通配符开头('$abc...')mysql 索引失效会变成全表扫描操作

sql
EXPLAIN SELECT * FROM employees WHERE name like 'Lei%'
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullrangeidx_name_age_positionidx_name_age_position741100Using index condition
sql
EXPLAIN SELECT * FROM employees WHERE name like '%Lei'
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullALL333.33Using where
  • 问题:解决 like'%字符串%'索引不被使用的方法?

a. 使用覆盖索引,查询字段必须是建立覆盖索引字段

sql
EXPLAIN SELECT name,age,position FROM employees WHERE name like '%Lei%';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullindexidx_name_age_position140333.33Using where index

b. 如果不能使用覆盖索引则可能需要借助搜索引擎

字符串不加单引号索引失效

sql
EXPLAIN SELECT * FROM employees WHERE name = '1000';
EXPLAIN SELECT * FROM employees WHERE name = 1000;

少用 or 或 in,用它查询时,mysql 不一定使用索引,mysql 内部优化器会根据检索比例、表大小等多个因素整体评估是否使用索引,详见范围查询优化

sql
EXPLAIN SELECT * FROM employees WHERE name = 'LiLei' or name = 'HanMeimei';
idselect_typetablepartitionstypepossible_keyskeyken_lenrefrowsfilteredExtra
1SIMPLEemployeenullALLidx_name_age_position366.67Using where

范围查询优化

给年龄添加单值索引

SQL
ALTER TABLE `employees` ADD INDEX `idx_age` (`age`) USING BTREE ;
1 explain select * from employees where age >=1 and age <=2000;

没走索引原因:mysql 内部优化器会根据检索比例、表大小等多个因素整体评估是否使用索引。比如这个例子,可能是由于单次数据量查询过大导致优化器最终选择不走索引 优化方法:可以将大的范围拆分成多个小范围

SQL
explain select * from employees where age >=1 and age <=1000;
explain select * from employees where age >=1001 and age <=2000;

索引使用总结

假设 index(a,b,c)

Where 语句索引是否被使用
where a= 3Y,使用到 a
where a= 3 and b =5Y,使用到 a,b
where a = 3 and b =5 and c = 4Y,使用 a,b,c
where b = 3 或者 where b=3 and c=4 或者 c =4N
where a = 3 and c= 5使用到 a, c 不可用,b 中断了
where a = 3 and b >4 and c =5使用到 a,b, c 不能用在范围之后,b 断了
where a = 3 and b like 'kk%' and c =4Y, 使用到 a,b,b
where a=3 and b like '%kk' and c=4Y,只使用到 a
where a = 3 and b like '%kk%' and c=4Y,使用到 a
where a= 3 and b like 'k%kk' and c= 4Y,使用到了 a,b,c

like kk%相当于=常量,%kk 和%kk%相当于范围

Released under the MIT License.