当用explain查看sql的执行计划时,里面有列显示了 key_len 的值,根据这个值可以判断索引的长度,在组合索引里面可以更清楚的了解到了哪部分字段使用到了索引。下面演示中,表结构的合理性这边暂且不说,只是证明一下索引长度的计算方法。目前大部分博文是字符类型的索引长度计算方法,下面列举几个类型的索引长度计算方法:
1、整数类型
(dg1)[email protected] [mytest]> desc table_key;
+---------+-------------+------+-----+---------+-------+
| field | type | null | key | default | extra |
| id | int(11) | no | | null | |
| sid | bigint(20) | no | | 0 | |
| name | char(10) | yes | | null | |
| age | tinyint(4) | yes | | null | |
| sex | tinyint(4) | no | | null | |
| address | varchar(10) | yes | mul | null | |
rows in set (0.01 sec)
(dg1)[email protected] [mytest]>create index age_index on table_key (age);
来看看tinyint类型的索引长度,在not null 和 null 的时候 分别是1和2,tinyint字段长度为1,因为null 需要额外一个字节标记为空
(dg1)[email protected] [mytest]> explain extended select * from table_key where age=38;
+----+-------------+-----------+------+---------------+-----------+---------+-------+------+----------+-------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | extra |
| 1 | simple | table_key | ref | age_index | age_index | 1 | const | 1 | 100.00 | null |
row in set, 1 warning (0.00 sec)
(dg1)[email protected] [mytest]> alter table table_key modify age tinyint(4);
| 1 | simple | table_key | ref | age_index | age_index | 2 | const | 1 | 100.00 | null |
(dg1)[email protected] [mytest]>
看看bigint类型的索引长度,同样是 not null 和 null值的时候,分别是8和9,聪明的你应该知道了,bigint长度为8。
(dg1)[email protected] [mytest]> alter table table_key add key sid_index (sid);
query ok, 0 rows affected (0.04 sec)
records: 0 duplicates: 0 warnings: 0
(dg1)[email protected] [mytest]> desc select * from table_key where sid=6;
+----+-------------+-----------+------+---------------+-----------+---------+-------+------+-------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | extra |
| 1 | simple | table_key | ref | sid_index | sid_index | 8 | const | 1 | null |
row in set (0.00 sec)
(dg1)[email protected] [mytest]> alter table table_key modify sid bigint(20);
query ok, 0 rows affected (0.08 sec)
| 1 | simple | table_key | ref | sid_index | sid_index | 9 | const | 1 | null |
看看smallint类型索引长度,同样是 not null 和 null值的时候,分别是2和3 smallint长度为2,允许为空需要一个字节标记
(dg1)[email protected] [mytest]> alter table table_key modify sid smallint not null default 0;
query ok, 9 rows affected (0.04 sec)
records: 9 duplicates: 0 warnings: 0
| 1 | simple | table_key | ref | sid_index | sid_index | 2 | const | 1 | null |
(dg1)[email protected] [mytest]> alter table table_key modify sid smallint ;
query ok, 0 rows affected (0.07 sec)
| 1 | simple | table_key | ref | sid_index | sid_index | 3 | const | 1 | null |
看看mediumint类型索引长度,同样是 not null 和 null值的时候,分别是3和4
(dg1)[email protected] [mytest]> alter table table_key modify sid mediumint not null;
query ok, 0 rows affected (0.06 sec)
(dg1)[email protected] [mytest]> alter table table_key modify sid mediumint ;
query ok, 0 rows affected (0.06 sec)
+----+-------------+-----------+------+---------------+-----------+---------+-------+------+-------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | extra |
| 1 | simple | table_key | ref | sid_index | sid_index | 4 | const | 1 | null |
整数类型索引长度跟字段长度有关,如果允许为空,需要额外一个字节去标记为空
2.浮点数类型
表结构
create table `table_key1` (
`id` int not null auto_increment ,
`c1` float not null ,
`c2` double not null ,
`c3` decimal not null ,
`c4` date not null ,
`c5` timestamp not null on update current_timestamp ,
`c6` datetime not null ,
primary key (`id`)
)
看看float类型的索引长度,not null和null的时候,分别是4和5
(dg1)[email protected] [mytest]> desc select * from table_key1 where c1 = '3.22';
+----+-------------+------------+------+---------------+----------+---------+-------+------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | extra |
| 1 | simple | table_key1 | ref | c1_index | c1_index | 4 | const | 8 | using index condition |
(dg1)[email protected] [mytest]> alter table table_key1 modify c1 float;
query ok, 0 rows affected (0.05 sec)
| 1 | simple | table_key1 | ref | c1_index | c1_index | 5 | const | 8 | using index condition |
看看double类型的索引长度,not null和null的时候,分别是8和9
(dg1)[email protected] [mytest]> alter table table_key1 add key c2_index (c2);
(dg1)[email protected] [mytest]> desc select * from table_key1 where c2 = '3.22';
+----+-------------+------------+------+---------------+----------+---------+-------+------+-------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | extra |
| 1 | simple | table_key1 | ref | c2_index | c2_index | 8 | const | 1 | null |
(dg1)[email protected] [mytest]> alter table table_key1 modify c2 double;
query ok, 0 rows affected (0.03 sec)
| 1 | simple | table_key1 | ref | c2_index | c2_index | 9 | const | 1 | null |
(dg1)[email protected] [mytest]>
3、看看时间类型
看看date类型的索引长度,在not null和null的时候,分别是3和4
(dg1)[email protected] [mytest]> desc select * from table_key1 where c4 = '2015-05-06';
| 1 | simple | table_key1 | ref | c4_index | c4_index | 3 | const | 4 | using index condition |
row in set, 3 warnings (0.00 sec)
(dg1)[email protected] [mytest]> alter table table_key1 modify c4 date;
query ok, 0 rows affected (0.09 sec)
| 1 | simple | table_key1 | ref | c4_index | c4_index | 4 | const | 4 | using index condition |
在timestamp类型的时候索引长度,在not null 和 null的时候,分别是4和5
(dg1)[email protected] [mytest]> desc select * from table_key1 where c5 = '2015-05-06 11:23:21' ;
| 1 | simple | table_key1 | ref | c5_index | c5_index | 4 | const | 5 | using index condition |
dg1)[email protected] [mytest]> alter table table_key1 modify c5 timestamp on update current_timestamp ;
(dg1)[email protected] [mytest]> desc select * from table_key1 where c5 = '2015-05-06 110:23:21';
| 1 | simple | table_key1 | ref | c5_index | c5_index | 5 | const | 5 | using index condition |
##############################在大家认识里datetime是八个字节的长度,下面就来看看,是不是真的这样
(dg1)root@localhost [mytest]> alter table table_key1 modify c6 datetime not null;
(dg1)root@localhost [mytest]> desc select * from table_key1 where c6 = '2015-05-06 11:10:36';
| 1 | simple | table_key1 | ref | c6_index | c6_index | 5 | const | 1 | null |
(dg1)root@localhost [mytest]> alter table table_key1 modify c6 datetime null;
| 1 | simple | table_key1 | ref | c6_index | c6_index | 6 | const | 1 | null |
颠覆了我们认识,datetime不是8个字节么,下面来看一下mysql的版本,没错mysql5.6是datetime长度是5个字节
(dg1)root@localhost [mytest]> \s
--------------
mysql ver 14.14 distrib 5.6.22, for linux-glibc2.5 (x86_64) using editline wrapper
connection id: 3
current database: mytest
current user: root@localhost
ssl: not in use
current pager: stdout
using outfile: ''
using delimiter: ;
server version: 5.6.22-log mysql community server (gpl)
protocol version: 10
connection: localhost via unix socket
server characterset: gbk
db characterset: gbk
client characterset: gbk
conn. characterset: gbk
unix socket: /opt/app/mysql/mysql3307.socket
uptime: 4 min 47 sec
threads: 1 questions: 19 slow queries: 0 opens: 75 flush tables: 1 open tables: 64 queries per second avg: 0.066
(dg1)root@localhost [mytest]>
小结:在mysql5.6版本,是否还得使用timestamp类型应该是仁者见仁智者见智的问题了,datetime是五个字节,timestamp范围比较窄(1970-2037年),不排除后续版本会修改其范围值
4.字符类型
表结构,字符集是utf8
看看定长字符类型char的索引长度,在not null 和null中分别为10*3和10*3+1
(dg1)[email protected] [mytest]> alter table table_key add index name_index (name);
query ok, 0 rows affected (0.01 sec)
(dg1)[email protected] [mytest]> explain extended select * from table_key where name='zhangsan';
+----+-------------+-----------+------+---------------+------------+---------+-------+------+----------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | extra |
| 1 | simple | table_key | ref | name_index | name_index | 30 | const | 1 | 100.00 | using index condition |
(dg1)[email protected] [mytest]> alter table table_key modify name char(10);
| 1 | simple | table_key | ref | name_index | name_index | 31 | const | 1 | 100.00 | using index condition |
看看变长长字符类型varchar的索引长度,在not null 和null中分别为10*3+2和10*3+2+1
(dg1)[email protected] [mytest]> explain extended select * from table_key where address='shanghai';
+----+-------------+-----------+------+---------------+---------------+---------+-------+------+----------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | extra |
| 1 | simple | table_key | ref | address_index | address_index | 32 | const | 1 | 100.00 | using index condition |
row in set, 1 warning (0.01 sec)
(dg1)[email protected] [mytest]> alter table table_key modify address varchar(10);
query ok, 0 rows affected (0.10 sec)
| 1 | simple | table_key | ref | address_index | address_index | 33 | const | 1 | 100.00 | using index condition |
来看看复合索引的key_len,(刚才测试gbk字符集,字符集转换成gbk了)
| name | char(10) | no | | | |
| address | varchar(10) | no | mul | | |
(dg1)[email protected] [mytest]> alter table table_key drop index name_index;
(dg1)[email protected] [mytest]> alter table table_key drop index address_index;
(dg1)[email protected] [mytest]> alter table table_key add index name_address_index (name,address);
query ok, 0 rows affected (0.02 sec)
(dg1)[email protected] [mytest]> explain extended select * from table_key where address='shanghai' and name='zhangsan';
+----+-------------+-----------+------+--------------------+--------------------+---------+-------------+------+----------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | extra |
| 1 | simple | table_key | ref | name_address_index | name_address_index | 42 | const,const | 1 | 100.00 | using index condition |
看看复合索引的长度,因为能全部使用到组合索引,所以是:2*(10)+2*(20)+2=42,下面将name字段允许为空,再来看看
(dg1)[email protected] [mytest]> explain extended select * from table_key where name='zhangsan' and address='shanghai';
| 1 | simple | table_key | ref | name_address_index | name_address_index | 43 | const,const | 1 | 100.00 | using index condition |
看看复合索引的长度,因为能全部使用到组合索引,所以是:2*(10)+1+2*(20)+2=43
+----+-------------+-----------+------+--------------------+--------------------+---------+-------+------+----------+-----------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | extra |
| 1 | simple | table_key | ref | name_address_index | name_address_index | 21 | const | 1 | 100.00 | using index condition |
那么我们来看看部分使用复合索引:2*(10)+1,将address设置为允许为空,再来看看
| 1 | simple | table_key | ref | name_address_index | name_address_index | 44 | const,const | 1 | 100.00 | using index condition |
这时候key_len=2*(10)+1+2*(10)+2+1=44
总结
1.整数类型,浮点数类型,时间类型的索引长度
not null=字段本身的字段长度
null=字段本身的字段长度+1,因为需要有是否为空的标记,这个标记需要占用1个字节
datetime类型在5.6中字段长度是5个字节
2.字符类型
varchr(n)变长字段且允许null = n * ( utf8=3,gbk=2,latin1=1)+1(null)+2
varchr(n)变长字段且不允许null = n * ( utf8=3,gbk=2,latin1=1)+2
char(n)固定字段且允许null = n * ( utf8=3,gbk=2,latin1=1)+1(null)
char(n)固定字段且允许null = n * ( utf8=3,gbk=2,latin1=1)
变长字段需要额外的2个字节(varchar值保存时只保存需要的字符数,另加一个字节来记录长度(如果列声明的长度超过255,则使用两个字节),所以varcahr索引长度计算时候要加2),固定长度字段不需要额外的字节。而null都需要1个字节的额外空间,所以索引字段最好不要为null,因为null让统计更加复杂,并且需要额外的存储空间。这个结论在此得到了证实,复合索引有最左前缀的特性,如果复合索引能全部使用上,则是复合索引字段的索引长度之和,这也可以用来判定复合索引是否部分使用,还是全部使用。
<b>本文来自云栖社区合作伙伴“dbgeek”</b>