理想的索引 1.查询频繁 2.区分度高 3.长度小 4.尽量能覆盖常用查询字段
测试区分度和长度的比值,取合适的索引长度
mysql> select uid,name,length(name) from user order by length(name) desc limit 1;
+
| uid | name | length(name) |
+
| 1733863 | 贵州运满来物流有限公司,蔡回筠,电话13608541671 | 65 |
+
mysql> select count(distinct left(name,1)) from user;
+
| count(distinct left(name,1)) |
+
| 5638 |
+
mysql> select count(*) from user;
+
| count(*) |
+
| 305188 |
+
mysql> select count(distinct left(name,1))/count(*) from user;
+
| count(distinct left(name,1))/count(*) |
+
| 0.0185 |
+
mysql> select count(distinct left(name,2))/count(*) from user;
+
| count(distinct left(name,2))/count(*) |
+
| 0.2153 |
+
mysql> select count(distinct left(name,3))/count(*) from user;
+
| count(distinct left(name,3))/count(*) |
+
| 0.3611 |
+
...
mysql> select count(distinct left(name,65))/count(*) from user;
+
| count(distinct left(name,3))/count(*) |
+
| 1 |
+
根据图表可知,索引长度取10左右即可
mysql> alter table user add index name(name(10));
mysql> show create table user \G;
*************************** 1. row ***************************
Table: user
Create Table: CREATE TABLE `user` (
`uid` int(11) NOT NULL AUTO_INCREMENT COMMENT '用户id',
`name` varchar(32) DEFAULT NULL COMMENT '姓名',
...
PRIMARY KEY (`uid`) USING BTREE,
KEY `name` (`name`(10))
) ENGINE=InnoDB AUTO_INCREMENT=1850120 DEFAULT CHARSET=utf8 COMMENT='用户表'
mysql> explain select * from user where name='中' \G;
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: user
type: ref
possible_keys: name
key: name
key_len: 33
ref: const
rows: 3
Extra: Using where
|