案例
创建表的 DDL
# DDL 语句 CREATE TABLE `employees` ( `id` INT(10) NOT NULL AUTO_INCREMENT, `name` VARCHAR(24) NOT NULL DEFAULT '' COMMENT '姓名' COLLATE 'utf8_general_ci', `age` INT(10) NOT NULL DEFAULT '0' COMMENT '年龄', `position` VARCHAR(20) NOT NULL DEFAULT '' COMMENT '职位' COLLATE 'utf8_general_ci', `hire_time` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '入职时间', PRIMARY KEY (`id`) USING BTREE, INDEX `idx_name_age_position` (`name`, `age`, `position`) USING BTREE, INDEX `idx_age` (`age`) USING BTREE ) COMMENT='员工记录表'; # 随机数(随机生成员工年龄) drop function if exists `rand_num`; delimiter ;; create function `rand_num`( `start_num` integer, `end_num` integer ) returns int comment '' begin return floor(start_num + rand() * (end_num - start_num + 1)); end ;; # 随机字符串函数 drop function if exists `rand_str`; delimiter ;; create definer = `root`@`localhost` function `rand_str`( `n` int ) returns varchar(255) begin declare chars_str varchar(100) default 'abcdefghijklmnopqrstuvwxyzabcdefghijklmnopqrstuvwxyz'; declare return_str varchar(100) default ''; declare i int default 0; while i < n do set return_str = concat(return_str, substring(chars_str, floor(1 + rand() * 52), 1)); set i = i + 1; end while; return return_str; end ;; # 生成测试数据 drop procedure if exists `insert_emp`; delimiter ;; create procedure `insert_emp`( in `max_num` int(10) ) begin declare i int default 0; set autocommit = 0; repeat set i = i+1; insert into `employees` (`name`, `age`, `position`, `hire_time`) values (rand_str(6), rand_num(20, 40), 'dev', now()); until i = max_num end repeat; commit; end ;; delimiter ; call insert_emp(10000);
索引优化
索引下推
对于辅助的联合索引(name,age,position),正常情况按照最左前缀原则,SELECT * FROM employees WHERE name like 'LiLei%' AND age = 22 AND position ='manager' 这种情况只会走name字段索引,因为根据name字段过滤完,得到的索引行里的age和position是无序的,无法很好的利用索引。 在MySQL5.6之前的版本,这个查询只能在联合索引里匹配到名字是 'LiLei' 开头的索引,然后拿这些索引对应的主键逐个回表,到主键索引上找出相应的记录,再比对age和position这两个字段的值是否符合。
MySQL 5.6引入了索引下推优化,可以在索引遍历过程中,对索引中包含的所有字段先做判断,过滤掉不符合条件的记录之后再回表,可以有效的减少回表次数。使用了索引下推优化后,上面那个查询在联合索引里匹配到名字是** 'LiLei' 开头的索引之后,同时还会在索引里过滤age和position**这两个字段,拿着过滤完剩下的索引对应的主键id再回表查整行数据。
索引下推会减少回表次数,对于innodb引擎的表索引下推只能用于二级索引,innodb的主键索引(聚簇索引)树叶子节点上保存的是全行数据,所以这个时候索引下推并不会起到减少查询全行数据的效果。
为什么范围查找Mysql没有用索引下推优化?估计应该是Mysql认为范围查找过滤的结果集过大,like KK% 在绝大多数情况来看,过滤后的结果集比较小,所以这里Mysql选择给 like KK% 用了索引下推优化,当然这也不是绝对的,有时like KK% 也不一定就会走索引下推。
常见的几种场景
1、联合索引的第一个字段是范围查找不会走索引
EXPLAIN SELECT * FROM employees WHERE name > 'SAN ZHANG' AND age = 22 AND position ='dev';
结论:联合索引第一个字段就用范围查找不会走索引,mysql内部可能觉得第一个字段就用范围,结果集应该很大,回表效率不高,还不如就全表扫描
2、强制走索引
EXPLAIN SELECT * FROM employees force index(idx_name_age_position) WHERE name > 'SAN ZHANG' AND age = 22 AND position ='dev';
结论:虽然使用了强制走索引让联合索引第一个字段范围查找也走了索引,扫描的行 rows 看上去少了一点,但是最终查找效率不一定比全表扫描搞,因为回表效率不高 做一个小实验:
# 关闭查询缓存 set global query_cache_size=0; # 执行时间 0.1 秒 SELECT * FROM employees WHERE name > 'SAN ZHANG'; # 执行时间 0.15 秒 SELECT * FROM employees force index(idx_name_age_position) WHERE name > 'SAN ZHANG';;
3、覆盖索引优化
EXPLAIN SELECT name,age,position FROM employees WHERE name > 'SAN ZHANG' AND age = 22 AND position ='dev';
4、in 和 or 在数据量比较大的情况下下会走索引,在表数据记录不多的情况下会选择全表扫描
EXPLAIN SELECT name,age,position FROM employees WHERE name in ('SAN ZHANG', 'SI Li', 'MAZI WQNAG', 'LIU ZHAO') AND age = 22 AND position ='dev';
EXPLAIN SELECT name,age,position FROM employees WHERE (name = 'SAN ZHANG' or name = 'SI Li' or name = 'MAZI WQNAG' or name = 'LIU ZHAO') AND age = 22 AND position ='dev';
创建一张 employees_temp 表里面就保留少量几条记录
CREATE TABLE `employees_temp` ( `id` INT(10) NOT NULL AUTO_INCREMENT, `name` VARCHAR(24) NOT NULL DEFAULT '' COMMENT '姓名' , `age` INT(10) NOT NULL DEFAULT '0' COMMENT '年龄', `position` VARCHAR(20) NOT NULL DEFAULT '' COMMENT '职位' , `hire_time` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '入职时间', PRIMARY KEY (`id`) USING BTREE, INDEX `idx_name_age_position` (`name`, `age`, `position`) USING BTREE ) COMMENT='员工记录表'; insert into `employees_temp`(name, age, position) values ('SAN ZHANG', 23, 'dev'); insert into `employees_temp`(name, age, position) values ('SI Li', 23, 'dev'); insert into `employees_temp`(name, age, position) values ('LIU ZHAO', 26, 'dev'); insert into `employees_temp`(name, age, position) values ('LING AI', 38, 'manager');
EXPLAIN SELECT * FROM employees_temp WHERE name in ('SAN ZHANG', 'SI Li', 'MAZI WQNAG', 'LIU ZHAO') AND age = 22 AND position ='dev';
EXPLAIN SELECT * FROM employees_temp WHERE (name = 'SAN ZHANG' or name = 'SI Li' or name = 'MAZI WQNAG' or name = 'LIU ZHAO') AND age = 22 AND position ='dev';
5、like 'SAN%' 一般都会走索引
EXPLAIN SELECT name,age,position FROM employees WHERE name like 'SAN%' AND age = 22 AND position ='dev';
EXPLAIN SELECT * FROM employees WHERE name like 'SAN%' AND age = 22 AND position ='dev';
选择合适的索引
索引分析案例
EXPLAIN select * from employees where name > 'a';
如果用name索引需要遍历name字段联合索引树,然后还需要根据遍历出来的主键值去主键索引树里再去查出最终数据,成本比全表扫描还高,可以用覆盖索引优化,这样只需要遍历name字段的联合索引树就能拿到所有结果,如下:
EXPLAIN select name,age,position from employees where name > 'a' ;
EXPLAIN select * from employees where name > 'zzz' ;
Trace 工具使用
对于上面这两种 name>'a' 和 name>'zzz' 的执行结果,mysql最终是否选择走索引或者一张表涉及多个索引,mysql最终如何选择索引,我们可以用trace工具来一查究竟,开启trace工具会影响mysql性能,所以只能临时分析sql使用,用完之后立即关闭trace工具用法:
set session optimizer_trace="enabled=on",end_markers_in_json=on; --开启trace select * from employees where name > 'a' order by position; SELECT * FROM information_schema.OPTIMIZER_TRACE; 查看trace字段: { "steps": [ { "join_preparation": { --第一阶段:SQL准备阶段,格式化sql "select#": 1, "steps": [ { "expanded_query": "/* select#1 */ select `employees`.`id` AS `id`,`employees`.`name` AS `name`,`employees`.`age` AS `age`,`employees`.`position` AS `position`,`employees`.`hire_time` AS `hire_time` from `employees` where (`employees`.`name` > 'a') order by `employees`.`position`" } ] /* steps */ } /* join_preparation */ }, { "join_optimization": { --第二阶段:SQL 优化阶段 "select#": 1, "steps": [ { "condition_processing": { --条件处理 "condition": "WHERE", "original_condition": "(`employees`.`name` > 'a')", "steps": [ { "transformation": "equality_propagation", "resulting_condition": "(`employees`.`name` > 'a')" }, { "transformation": "constant_propagation", "resulting_condition": "(`employees`.`name` > 'a')" }, { "transformation": "trivial_condition_removal", "resulting_condition": "(`employees`.`name` > 'a')" } ] /* steps */ } /* condition_processing */ }, { "substitute_generated_columns": { } /* substitute_generated_columns */ }, { "table_dependencies": [ --表依赖详情 { "table": "`employees`", "row_may_be_null": false, "map_bit": 0, "depends_on_map_bits": [ ] /* depends_on_map_bits */ } ] /* table_dependencies */ }, { "ref_optimizer_key_uses": [ ] /* ref_optimizer_key_uses */ }, { "rows_estimation": [ --预估表的访问成本 { "table": "`employees`", "range_analysis": { "table_scan": { --全表扫描情况 "rows": 120085, --扫描行数 "cost": 24372 --查询成本 } /* table_scan */, "potential_range_indexes": [ --查询可能使用的索引 { "index": "PRIMARY", --主键索引 "usable": false, "cause": "not_applicable" }, { "index": "idx_name_age_position", --辅助索引 "usable": true, "key_parts": [ "name", "age", "position", "id" ] /* key_parts */ } ] /* potential_range_indexes */, "setup_range_conditions": [ ] /* setup_range_conditions */, "group_index_range": { "chosen": false, "cause": "not_group_by_or_distinct" } /* group_index_range */, "analyzing_range_alternatives": { --分析各个索引使用成本 "range_scan_alternatives": [ { "index": "idx_name_age_position", "ranges": [ "a < name" --索引使用范围 ] /* ranges */, "index_dives_for_eq_ranges": true, "rowid_ordered": false, --使用该索引获取的记录是否按照主键排序 "using_mrr": false, "index_only": false, --是否使用覆盖索引 "rows": 60042, --索引扫描的行数 "cost": 72051, --索引使用成本 "chosen": false, --是否选择该索引 "cause": "cost" } ] /* range_scan_alternatives */, "analyzing_roworder_intersect": { "usable": false, "cause": "too_few_roworder_scans" } /* analyzing_roworder_intersect */ } /* analyzing_range_alternatives */ } /* range_analysis */ } ] /* rows_estimation */ }, { "considered_execution_plans": [ { "plan_prefix": [ ] /* plan_prefix */, "table": "`employees`", "best_access_path": { --最优访问路径 "considered_access_paths": [ --最终选择的访问路径 { "rows_to_scan": 120085, "access_type": "scan", --访问类型:为 scan, 全表扫描 "resulting_rows": 120085, "cost": 24370, "chosen": true, --确定选择 "use_tmp_table": true } ] /* considered_access_paths */ } /* best_access_path */, "condition_filtering_pct": 100, "rows_for_plan": 120085, "cost_for_plan": 24370, "sort_cost": 120085, "new_cost_for_plan": 144455, "chosen": true } ] /* considered_execution_plans */ }, { "attaching_conditions_to_tables": { "original_condition": "(`employees`.`name` > 'a')", "attached_conditions_computation": [ ] /* attached_conditions_computation */, "attached_conditions_summary": [ { "table": "`employees`", "attached": "(`employees`.`name` > 'a')" } ] /* attached_conditions_summary */ } /* attaching_conditions_to_tables */ }, { "clause_processing": { "clause": "ORDER BY", "original_clause": "`employees`.`position`", "items": [ { "item": "`employees`.`position`" } ] /* items */, "resulting_clause_is_simple": true, "resulting_clause": "`employees`.`position`" } /* clause_processing */ }, { "reconsidering_access_paths_for_index_ordering": { "clause": "ORDER BY", "index_order_summary": { "table": "`employees`", "index_provides_order": false, "order_direction": "undefined", "index": "unknown", "plan_changed": false } /* index_order_summary */ } /* reconsidering_access_paths_for_index_ordering */ }, { "refine_plan": [ { "table": "`employees`" } ] /* refine_plan */ } ] /* steps */ } /* join_optimization */ }, { "join_execution": { --第三阶段: SQL 执行阶段 "select#": 1, "steps": [ { "filesort_information": [ { "direction": "asc", "table": "`employees`", "field": "position" } ] /* filesort_information */, "filesort_priority_queue_optimization": { "usable": false, "cause": "not applicable (no LIMIT)" } /* filesort_priority_queue_optimization */, "filesort_execution": [ ] /* filesort_execution */, "filesort_summary": { "rows": 120003, "examined_rows": 120003, "number_of_tmp_files": 34, "sort_buffer_size": 262056, "sort_mode": "<sort_key, packed_additional_fields>" } /* filesort_summary */ } ] /* steps */ } /* join_execution */ } ] /* steps */ } 结论:全表扫描的成本低于索引扫描,所以mysql最终选择全表扫描 select * from employees where name > 'zzz' order by position; SELECT * FROM information_schema.OPTIMIZER_TRACE; 查看trace字段可知索引扫描的成本低于全表扫描,所以mysql最终选择索引扫描 set session optimizer_trace="enabled=off"; --关闭trace