10.4.7 Limits on Table Column Count and Row Size (original) (raw)

mysql> CREATE TABLE t (a VARCHAR(10000), b VARCHAR(10000),  
       c VARCHAR(10000), d VARCHAR(10000), e VARCHAR(10000),  
       f VARCHAR(10000), g VARCHAR(6000)) ENGINE=InnoDB CHARACTER SET latin1;  
ERROR 1118 (42000): 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> CREATE TABLE t (a VARCHAR(10000), b VARCHAR(10000),  
       c VARCHAR(10000), d VARCHAR(10000), e VARCHAR(10000),  
       f VARCHAR(10000), g VARCHAR(6000)) ENGINE=MyISAM CHARACTER SET latin1;  
ERROR 1118 (42000): 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  

In the following MyISAM example, changing a column to TEXT avoids the 65,535-byte row size limit and permits the operation to succeed becauseBLOB andTEXT columns only contribute 9 to 12 bytes toward the row size.

mysql> CREATE TABLE t (a VARCHAR(10000), b VARCHAR(10000),  
       c VARCHAR(10000), d VARCHAR(10000), e VARCHAR(10000),  
       f VARCHAR(10000), g TEXT(6000)) ENGINE=MyISAM CHARACTER SET latin1;  
Query OK, 0 rows affected (0.02 sec)  

The operation succeeds for an InnoDB table because changing a column toTEXT avoids the MySQL 65,535-byte row size limit, and InnoDB off-page storage of variable-length columns avoids theInnoDB row size limit.

mysql> CREATE TABLE t (a VARCHAR(10000), b VARCHAR(10000),  
       c VARCHAR(10000), d VARCHAR(10000), e VARCHAR(10000),  
       f VARCHAR(10000), g TEXT(6000)) ENGINE=InnoDB CHARACTER SET latin1;  
Query OK, 0 rows affected (0.02 sec)  
mysql> CREATE TABLE t1  
       (c1 VARCHAR(32765) NOT NULL, c2 VARCHAR(32766) NOT NULL)  
       ENGINE = InnoDB CHARACTER SET latin1;  
Query OK, 0 rows affected (0.02 sec)  

The statement to create table t2 fails because, although the column length is within the maximum length of 65,535 bytes, two additional bytes are required to record the length, which causes the row size to exceed 65,535 bytes:

mysql> CREATE TABLE t2  
       (c1 VARCHAR(65535) NOT NULL)  
       ENGINE = InnoDB CHARACTER SET latin1;  
ERROR 1118 (42000): 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  

Reducing the column length to 65,533 or less permits the statement to succeed.

mysql> CREATE TABLE t2  
       (c1 VARCHAR(65533) NOT NULL)  
       ENGINE = InnoDB CHARACTER SET latin1;  
Query OK, 0 rows affected (0.01 sec)  
mysql> CREATE TABLE t3  
       (c1 VARCHAR(32765) NULL, c2 VARCHAR(32766) NULL)  
       ENGINE = MyISAM CHARACTER SET latin1;  
ERROR 1118 (42000): 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  

For information about InnoDB NULL column storage, seeSection 17.10, “InnoDB Row Formats”.

mysql> CREATE TABLE t4 (  
       c1 CHAR(255),c2 CHAR(255),c3 CHAR(255),  
       c4 CHAR(255),c5 CHAR(255),c6 CHAR(255),  
       c7 CHAR(255),c8 CHAR(255),c9 CHAR(255),  
       c10 CHAR(255),c11 CHAR(255),c12 CHAR(255),  
       c13 CHAR(255),c14 CHAR(255),c15 CHAR(255),  
       c16 CHAR(255),c17 CHAR(255),c18 CHAR(255),  
       c19 CHAR(255),c20 CHAR(255),c21 CHAR(255),  
       c22 CHAR(255),c23 CHAR(255),c24 CHAR(255),  
       c25 CHAR(255),c26 CHAR(255),c27 CHAR(255),  
       c28 CHAR(255),c29 CHAR(255),c30 CHAR(255),  
       c31 CHAR(255),c32 CHAR(255),c33 CHAR(255)  
       ) ENGINE=InnoDB ROW_FORMAT=DYNAMIC DEFAULT CHARSET latin1;  
ERROR 1118 (42000): Row size too large (> 8126). Changing some columns to TEXT or BLOB may help.  
In current row format, BLOB prefix of 0 bytes is stored inline.