这里所谈论只针对B-Tree类型索引,也是MySQL用的最多最普通的索引。创建索引的时候是按照字面量的顺序创建的,这个要特别注意。在B-Tree类型索引中,索引顺序是至关重要的。
高性能索引
-
索引要小而美
-
单列索引
-
前缀索引
-
多列索引
-
选择合适的索引顺序
-
覆盖索引
-
使用索引扫描来排序
首先构造1亿条数据
参照前面写的文章造数据
索引结构如下
mysql> show index from user;+-------+------------+-------------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment |+-------+------------+-------------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+| user | 0 | PRIMARY | 1 | id | A | 92123632 | NULL | NULL | | BTREE | | || user | 1 | idx_last_first_name_age | 1 | last_name | A | 363474 | NULL | NULL | YES | BTREE | | || user | 1 | idx_last_first_name_age | 2 | first_name | A | 92123840 | NULL | NULL | YES | BTREE | | || user | 1 | idx_last_first_name_age | 3 | age | A | 87360984 | NULL | NULL | YES | BTREE | | || user | 1 | idx_phone | 1 | phone | A | 92123840 | NULL | NULL | YES | BTREE | | || user | 1 | idx_create_time | 1 | create_time | A | 88503 | NULL | NULL | YES | BTREE | | |+-------+------------+-------------------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+---------------+6 rows in set (0.00 sec)
user表一共有4个索引,包括一个主键id,2个单列索引(phone, create_time), 1个多列索引(last_name+first_name+age)
通过explain来查看使用索引情况
主要关注如下:
-
type:访问类型,性能从差到好为:
ALL -> index -> range -> ref -> eq_ref -> const,system -> NULL
-
index:使用的索引
可以使用索引的情况
单列索引全值匹配
这是最简单的方式
mysql> explain SELECT * from user where phone = '13901986429';+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------+| 1 | SIMPLE | user | NULL | ref | idx_phone | idx_phone | 14 | const | 1 | 100.00 | NULL |+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------+1 row in set, 1 warning (0.01 sec)
从type可以得知访问类型ref,使用索引key为idx_phone。
多列索引全值匹配
mysql> explain SELECT * FROM user where last_name='last_name_110' and first_name='first_name_115' and sex='F';+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------------+| 1 | SIMPLE | user | NULL | ref | idx_last_first_name_age | idx_last_first_name_age | 96 | const,const | 1 | 10.00 | Using where |+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------------+1 row in set, 1 warning (0.00 sec)
前缀索引
如果是单列索引,可以匹配列的最左前缀
mysql> explain SELECT * from user where phone like '139019864%';+----+-------------+-------+------------+-------+---------------+-----------+---------+------+------+----------+-----------------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+-------+---------------+-----------+---------+------+------+----------+-----------------------+| 1 | SIMPLE | user | NULL | range | idx_phone | idx_phone | 14 | NULL | 100 | 100.00 | Using index condition |+----+-------------+-------+------------+-------+---------------+-----------+---------+------+------+----------+-----------------------+1 row in set, 1 warning (0.01 sec)
如果是多列索引,可以从左开始组合索引
mysql> explain SELECT * FROM user where last_name='last_name_110' and first_name='first_name_115';+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------+| 1 | SIMPLE | user | NULL | ref | idx_last_first_name_age | idx_last_first_name_age | 96 | const,const | 1 | 100.00 | NULL |+----+-------------+-------+------------+------+-------------------------+-------------------------+---------+-------------+------+----------+-------+1 row in set, 1 warning (0.01 sec)
匹配索引值的范围
使用between
mysql> explain select * from user where id between 1 and 10;+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| 1 | SIMPLE | user | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 10 | 100.00 | Using where |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+1 row in set, 1 warning (0.00 sec)
使用in
mysql> explain select * from user where id in (1, 2, 3);+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| 1 | SIMPLE | user | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 3 | 100.00 | Using where |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+1 row in set, 1 warning (0.01 sec)
使用or
mysql> explain select * from user where id=1 or id=10;+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+| 1 | SIMPLE | user | NULL | range | PRIMARY | PRIMARY | 4 | NULL | 2 | 100.00 | Using where |+----+-------------+-------+------------+-------+---------------+---------+---------+------+------+----------+-------------+1 row in set, 1 warning (0.00 sec)
覆盖索引
Extra字段为Using index,可以看出返回数据只需要查索引即可,不需要回表查其他字段数据。
mysql> explain select phone from user where phone='13900123456';+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+| 1 | SIMPLE | user | NULL | ref | idx_phone | idx_phone | 14 | const | 1 | 100.00 | Using index |+----+-------------+-------+------------+------+---------------+-----------+---------+-------+------+----------+-------------+1 row in set, 1 warning (0.00 sec)
不能使用索引的情况
从type为ALL可以看出进行了全表扫描。
没有使用左前缀索引
phone是索引列,格式为’%XXX’不能是使用索引
mysql> explain SELECT * from user where phone like '%39019864%';+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| 1 | SIMPLE | user | NULL | ALL | NULL | NULL | NULL | NULL | 9698255 | 11.11 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+1 row in set, 1 warning (0.00 sec)
没有采用最左组合索引
last_name + first_name + sex联合组成了多列索引,采用最左匹配, 只有last_name,last_name + first_name,last_name + first_name + sex才能使用索引。
mysql> explain SELECT * FROM user where first_name='first_name_115' and sex='F';+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| 1 | SIMPLE | user | NULL | ALL | NULL | NULL | NULL | NULL | 9698255 | 1.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+1 row in set, 1 warning (0.00 sec)
使用函数
mysql> explain SELECT * FROM user where left(phone, 11) = '13900123456';+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+| 1 | SIMPLE | user | NULL | ALL | NULL | NULL | NULL | NULL | 9698255 | 100.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+---------+----------+-------------+1 row in set, 1 warning (0.00 sec)
用索引字段进行计算
mysql> explain select * from user where id + 1 = 2;+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+| 1 | SIMPLE | user | NULL | ALL | NULL | NULL | NULL | NULL | 92123838 | 100.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+1 row in set, 1 warning (0.00 sec)
or后面没有使用索引
mysql> explain select * from user where id=1 or age=10;+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+| 1 | SIMPLE | user | NULL | ALL | PRIMARY | NULL | NULL | NULL | 92123838 | 10.00 | Using where |+----+-------------+-------+------------+------+---------------+------+---------+------+----------+----------+-------------+1 row in set, 1 warning (0.00 sec)
索引和数据占用空间的查询
-- 查看example数据库整体大小SELECT CONCAT(table_schema,'.',table_name) AS 'Table Name', CONCAT(ROUND(table_rows/1000000,4),'M') AS 'Number of Rows', CONCAT(ROUND(data_length/(1024*1024*1024),4),'G') AS 'Data Size', CONCAT(ROUND(index_length/(1024*1024*1024),4),'G') AS 'Index Size', CONCAT(ROUND((data_length+index_length)/(1024*1024*1024),4),'G') AS'Total'FROM information_schema.TABLES WHERE table_schema = 'example';
从图可以看出,1亿条数据索引占用了9.69G,数据占用了10G,总共占用了将近20G。索引占用空间几乎和数据大小一样,因此我们需要慎用索引,在必要的情况下才使用,索引要小而美。