http://blog.163.com/eric1945@126/blog/static/16493457220113261146188/
http://dev.mysql.com/doc/refman/5.0/en/column-count-limit.html
这里有一道我YY出来的关于MySQL的题:
表设计如下
id | mediumint |
name | varchar |
问题是: MySQL5.1 , 在GBK字符环境下,这里的varchar最长能设多长?
正确答案是: 32764
那如果表设计为两个 varchar, 第一个长度设为300时,第二个varchar应该多长? --答案见本文最后面
要想搞明白是怎么算出来的,请仔细下面的解释:
官方文档上对 int 及 varchar 的说明如下:
Values
in VARCHAR columns are variable-length strings. The length can be
specified as a value from 0 to 255 before MySQL 5.0.3, and 0 to 65,535
in 5.0.3 and later versions.
看到这里,你以为上面的varchar长度是: 65535 /2=32767?
不对,因为官方文档后面又说:
In
contrast to CHAR, VARCHAR values are stored as a one-byte or two-byte
length prefix plus data. The length prefix indicates the number of bytes
in the value.
很明白了,varchar会保留一至两个字节来存放长度信息,但到底是1Byte还是2Byte?
往后看:
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.
你再来算一算varchar长度 最大为: (65535-2) /2 = 32766 ?
还是不对!
其实每一行的总长度是有限制的,即最大为65535.
Every table has a maximum row size of 65,535 bytes.
This
maximum applies to all storage engines, but a given engine might have
additional constraints that result in a lower effective maximum row
size.
所以算varchar得把id的扣除:
(65535-3-2) /2 = 32765 ?
测试一下:
root@saker 05:27:28>create table t4(id mediumint, name varchar(32765));
ERROR
1118 (42000): Row size too large. The maximum row size for the used
table type, not counting BLOBs, is 65535. You have to change some
columns to TEXT or BLOBs
用32764测试一下:
root@saker 05:27:31>create table t4(id mediumint, name varchar(32764));
Query OK, 0 rows affected (0.16 sec)
root@saker 05:27:35>desc t4;
+-------+----------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+----------------+------+-----+---------+-------+
| id | mediumint(9) | YES | | NULL | |
| name | varchar(32764) | YES | | NULL | |
+-------+----------------+------+-----+---------+-------+
这说明还保留了1至2个字节来留其它控制信息。(在文档里面我没有找到说明,所以也不知道到底是1个还是2个byte)
但我想到了一个方法来反推出来,
我把id的类型从medium改成 int ,这时id的长度就从3变为4了,如果控制字节用了2Bytes,那varchar的长度还设为32764的话,显然是要报错的。。。
root@saker 05:29:14>create table t3(id int, name varchar(32764));
Query OK, 0 rows affected (0.18 sec)
root@saker 07:01:10>desc t3;
+-------+----------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+----------------+------+-----+---------+-------+
| id | int(11) | YES | | NULL | |
| name | varchar(32764) | YES | | NULL | |
+-------+----------------+------+-----+---------+-------+
这样应该能说明,控制位只有1个字节。
下面用这个结论来计算第二个问题:
那如果表设计为两个 varchar, 第一个长度设为300时,第二个varchar应该多长?
(65535-1-2-2-300*2) /2 = 32465
测试一下:
root@saker 07:09:23>create table t1(id varchar(300), name varchar(32465));
Query OK, 0 rows affected (0.15 sec)
root@saker 07:09:26>desc t1;
+-------+----------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+----------------+------+-----+---------+-------+
| id | varchar(300) | YES | | NULL | |
| name | varchar(32465) | YES | | NULL | |
+-------+----------------+------+-----+---------+-------+
2 rows in set (0.02 sec)
多一位都不行:
root@saker 07:08:12>create table t1(id varchar(300), name varchar(32466));
ERROR
1118 (42000): Row size too large. The maximum row size for the used
table type, not counting BLOBs, is 65535. You have to change some
columns to TEXT or BLOBs
最后 把以上所有知识综合起来:
有一个表:
id int, name1 char(20), name2 varchar(100), name3 varchar(?)
算一下:
(65535-1-1-2-4-20*2-100*2) /2 = 32643
root@saker 07:16:09>create table tt(id int, name1 char(20), name2 varchar(100), name3 varchar(32643));
Query OK, 0 rows affected (0.18 sec)
root@saker 07:16:12>desc tt;
+-------+----------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+----------------+------+-----+---------+-------+
| id | int(11) | YES | | NULL | |
| name1 | char(20) | YES | | NULL | |
| name2 | varchar(100) | YES | | NULL | |
| name3 | varchar(32643) | YES | | NULL | |
+-------+----------------+------+-----+---------+-------+
4 rows in set (0.00 sec)
root@saker 07:15:08>create table tt(id int, name1 char(20), name2 varchar(100), name3 varchar(32644));
ERROR
1118 (42000): Row size too large. The maximum row size for the used
table type, not counting BLOBs, is 65535. You have to change some
columns to TEXT or BLOBs
所以设计表的时候,这个要注意了,每一行是有长度限制的。