数据库系列 | MYSQL VARCHAR 类型详解
MYSQL 5.7 VARCHAR 类型详解
MYSQL 的VARCHAR 类型字段的最多能存储多少字符?模糊记得 VARCHAR 最多能存65535个字符,真的吗?
理论上,一个字符类型能存的字符数量跟选取的编码字符集和存储长度限制肯定是有关系的,字符编码长度越小,长度上限越大,能存的字符就越多。
latin1 字符集
尝试创建一个表
create table tinywan(name varchar(65535)) charset=latin1;
错误提示
mysql (none)@127.0.0.1:tinywan> show tables;
+-------------------+
| Tables_in_tinywan |
+-------------------+
0 rows in set
Time: 0.005s
mysql (none)@127.0.0.1:tinywan> create table tinywan(name varchar(65535)) charset=latin1;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
mysql (none)@127.0.0.1:tinywan> create table tinywan(name varchar(65534)) charset=latin1;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
mysql (none)@127.0.0.1:tinywan> create table tinywan(name varchar(65533)) charset=latin1;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
mysql (none)@127.0.0.1:tinywan> create table tinywan(name varchar(65532)) charset=latin1;
Query OK, 0 rows affected
Time: 0.173s
mysql (none)@127.0.0.1:tinywan>
截图
结果
“测试结果很明显,使用 latin1字符编码时varchar最多能存 65532ge字符,真的如此吗?答案是 NO!
参考文档,VARCHAR存储长度超过255的字符串时,需要使用2个字节的前缀表示存储字符串占用的存储空间长度(字节数)。
(2个字节16bit,2^16-1=65535 这也从从另一个层面解释了65535 字节这个限制)
参考MYSQL 5.7 官档:
“Values in VARCHAR columns are variable-length strings. The length can be specified as a value from 0 to 65,535. The effective maximum length of a VARCHAR is subject to the maximum row size (65,535 bytes, which is shared among all columns) and the character set used. See Section C.10.4, “Limits on Table Column Count and Row Size”.
In contrast to CHAR, VARCHAR values are stored as a 1-byte or 2-byte length prefix plus data. The length prefix indicates the number of bytes in the value. A column uses one length byte if values require no more than 255 bytes, two length bytes if values may require more than 255 bytes.
那么,65535-2 =65533
,但是 create table tinywan(name varchar(65533)) charset=latin1
依然执行失败了,why? 因为我们忽略了行格式中的 null
标志位,因为我们的表只定义了一个字段,所以标志位需要占用行的一个字节(关于``null`标志位这里不延伸)。
将name字段定义字段为not null 即可以关闭null 标志位,继续测试:
mysql (none)@127.0.0.1:tinywan> create table tinywan2(name varchar(65535) not null) charset=latin1;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
mysql (none)@127.0.0.1:tinywan> create table tinywan2(name varchar(65534) not null) charset=latin1;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
mysql (none)@127.0.0.1:tinywan> create table tinywan2(name varchar(65533) not null) charset=latin1;
Query OK, 0 rows affected
Time: 0.172s
mysql (none)@127.0.0.1:tinywan>
截图
OK!测试符合理论!
utf8mb4 字符集
那么在 utf8mb4 下最多能存多少个字符呢?
首先我们来看下试验环境的字符集和行格式相关设置,MYSQL 版本是5.7.22。数据库默认字符集是 utf8mb4
MYSQL 版本
mysql (none)@127.0.0.1:tinywan> select version();
+-----------+
| version() |
+-----------+
| 5.7.32 |
+-----------+
1 row in set
Time: 0.003s
数据库默认字符集
mysql (none)@127.0.0.1:tinywan> show variables like '%char%';
+--------------------------+----------------------------+
| Variable_name | Value |
+--------------------------+----------------------------+
| character_set_client | utf8mb4 |
| character_set_connection | utf8mb4 |
| character_set_database | utf8mb4 |
| character_set_filesystem | binary |
| character_set_results | utf8mb4 |
| character_set_server | latin1 |
| character_set_system | utf8 |
| character_sets_dir | /usr/share/mysql/charsets/ |
+--------------------------+----------------------------+
8 rows in set
Time: 0.006s
mysql (none)@127.0.0.1:tinywan>
创建一个表,指定字段长度为65535:
mysql (none)@127.0.0.1:tinywan> create table tinywan3(name varchar(65535) primary key);
(1074, "Column length too big for column 'name' (max = 16383); use BLOB or TEXT instead")
根据以上错误信息提示,字段长度最大值为16383;为什么是16383这个值,而不是其他值?首先依然是被 65,535这个行长度限制了,我们来看看官档中关于 Row size 的描述。
“Row Size Limits The maximum row size for a given table is determined by several factors: The internal representation of a MySQL table has a maximum row size limit of 65,535 bytes, even if the storage engine is capable of supporting larger rows. BLOB and TEXT columns only contribute 9 to 12 bytes toward the row size limit because their contents are stored separately from the rest of the row.
也就是说,即使你的存储引擎支持更大的行长度,但是MYSQL 依然限制 Row size为65535;
BLOB and TEXT 这两种类型字段只占用行存储的9-12个字节,其他的内容分开存储。
其次创建表时没有指定表的字符集,所以默认继承数据库字符集 utf8mb4;
在utf8mb4 编码中,字符的最大编码长度是4,比如中文;
所以为了保证存储的字符串实际存储空间小于``65535字节,字符串长度不能大于
floor(65535/4)=16383`
但是以16383长度再次创建表格,依然提示错误,why?
mysql (none)@127.0.0.1:tinywan> create table tinywan3(name varchar(16383) primary key);
(1071, 'Specified key was too long; max key length is 3072 bytes')
注意看提示信息!这次不再是提示 Column length too big ,而是 Specified key was too long
;官方描述:
“Both DYNAMIC and COMPRESSED row formats support index key prefixes up to 3072 bytes. This feature is controlled by the innodb_large_prefix configuration option, which is enabled by default. See the innodb_large_prefix option description for more information.
原来 DYNAMIC and COMPRESSED 行格式默认支持索引长度不能超过3072
字节.
而我们的 name是聚集索引,整个字段值作为索引键值,所以索引长度必然超限。
而且它还告诉我们,可通过 innodb_large_prefix这个变量来控制这个特性。
检查下我们的试验环境,行格式刚好是 dynamic :
mysql (none)@127.0.0.1:tinywan> show variables like '%format%';
+---------------------------+-------------------+
| Variable_name | Value |
+---------------------------+-------------------+
| binlog_format | ROW |
| date_format | %Y-%m-%d |
| datetime_format | %Y-%m-%d %H:%i:%s |
| default_week_format | 0 |
| innodb_default_row_format | dynamic |
| innodb_file_format | Barracuda |
| innodb_file_format_check | ON |
| innodb_file_format_max | Barracuda |
| time_format | %H:%i:%s |
+---------------------------+-------------------+
9 rows in set
Time: 0.005s
3072
字节除以 utf8mb4
的最大编码长度``4字节,在主键字段上长度上限应该是
768`,测试如下:
mysql (none)@127.0.0.1:tinywan> create table tinywan3(name varchar(769) primary key);
(1071, 'Specified key was too long; max key length is 3072 bytes')
mysql (none)@127.0.0.1:tinywan> create table tinywan3(name varchar(768) primary key);
Query OK, 0 rows affected
Time: 0.164s
mysql (none)@127.0.0.1:tinywan>
不出所料,769长度字段建表失败,768长度字段建表成功
现在抛开索引长度的限制,再次测试:
mysql (none)@127.0.0.1:tinywan> create table tinywan4(name varchar(16383) not null) charset=utf8mb4;
Query OK, 0 rows affected
Time: 0.190s
mysql (none)@127.0.0.1:tinywan>
utf8字符集
基于以上理论和实验
在utf8 编码字符集中,字符的最大编码长度是3字节,比如中文;所以如果 name作为主键,这个字段字符长度不能超过 3072/3=1024;
mysql (none)@127.0.0.1:tinywan> create table tinywan5(name varchar(1025) primary key) charset=utf8;
(1071, 'Specified key was too long; max key length is 3072 bytes')
mysql (none)@127.0.0.1:tinywan> create table tinywan5(name varchar(1024) primary key) charset=utf8;
Query OK, 0 rows affected
Time: 0.238s
在utf8 编码字符集环境中,如果不使用索引,基于验证上面的理论 65535/3= 21845:
mysql (none)@127.0.0.1:tinywan> create table tinywan32(name varchar(21845) not null) charset=utf8;
(1118, 'Row size too large. The maximum row size for the used table type, not counting BLOBs, is 65535.
This includes storage overhead, check the manual. You have to change some columns to TEXT or BLOBs')
建表语句依然报错?因为 ``"VARCHAR values are stored as a 1-byte or 2-byte length prefix plus data."` 存储空间字符串前缀需要占用2个字节,所以创建失败。
mysql (none)@127.0.0.1:tinywan> create table tinywan32(name varchar(21844) not null) charset=utf8;
Query OK, 0 rows affected
Time: 0.174s
结论
-
在 latin1
编码字符集中,VARCHAR
类型字段最多能存储65533
个字符; -
在 utf8
编码字符集中,VARCHAR
类型字段最多能存储21844
个字符; -
在 utf8mb4
编码字符集中,VARCHAR
类型字段最多能存储16383
个字符;