《Mysql學習MySQL中數據類型的驗證》要點:
本文介紹了Mysql學習MySQL中數據類型的驗證,希望對您有用。如果有疑問,可以聯系我們。
CHAR
MYSQL數據庫
char (M) M字符,長度是M*字符編碼長度,M最大255.
MYSQL數據庫
驗證如下:MYSQL數據庫
mysql> create table t1(name char(256)) default charset=utf8; ERROR 1074 (42000): Column length too big for column 'name' (max = 255); use BLOB or TEXT instead mysql> create table t1(name char(255)) default charset=utf8; Query OK, 0 rows affected (0.06 sec) mysql> insert into t1 values(repeat('整',255)); Query OK, 1 row affected (0.00 sec) mysql> select length(name),char_length(name) from t1; +--------------+-------------------+ | length(name) | char_length(name) | +--------------+-------------------+ | 765 | 255 | +--------------+-------------------+ 1 row in set (0.00 sec)
VARCHAR
MYSQL數據庫
VARCHAR(M),M同樣是字符,長度是M*字符編碼長度.它的限制比較特別,行的總長度不能超過65535字節.
MYSQL數據庫
mysql> create table t1(name varchar(65535)); 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 t1(name varchar(65534)); 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 t1(name varchar(65533)); 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 t1(name varchar(65532)); Query OK, 0 rows affected (0.08 sec)
注意,以上表的默認字符集是latin1,字符長度是1個字節,所以對于varchar,最大只能指定65532字節的長度.
MYSQL數據庫
如果是指定utf8,則最多只能指定21844的長度
MYSQL數據庫
mysql> create table t1(name varchar(65532)) default charset=utf8; ERROR 1074 (42000): Column length too big for column 'name' (max = 21845); use BLOB or TEXT instead mysql> create table t1(name varchar(21845)) default charset=utf8; 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 t1(name varchar(21844)) default charset=utf8; Query OK, 0 rows affected (0.07 sec)
注意:行的長度最大為65535,只是針對除blob,text以外的其它列.
MYSQL數據庫
mysql> create table t1(name varchar(65528),hiredate datetime) default charset=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 t1(name varchar(65527),hiredate datetime) default charset=latin1; Query OK, 0 rows affected (0.01 sec)
確實,datetime占了5個字節.
MYSQL數據庫
TEXT,BLOBMYSQL數據庫
mysql> create table t1(name text(255)); Query OK, 0 rows affected (0.01 sec) mysql> create table t2(name text(256)); Query OK, 0 rows affected (0.01 sec) mysql> show create table t1\G *************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t1` ( `name` tinytext ) ENGINE=InnoDB DEFAULT CHARSET=latin1 1 row in set (0.00 sec) mysql> show create table t2\G *************************** 1. row *************************** Table: t2 Create Table: CREATE TABLE `t2` ( `name` text ) ENGINE=InnoDB DEFAULT CHARSET=latin1 1 row in set (0.00 sec)
通過上面的輸出可以看出text可以定義長度,如果范圍小于28(即256)則為tinytext,如果范圍小于216(即65536),則為text, 如果小于224,為mediumtext,小于232,為longtext.
MYSQL數據庫
上述范圍均是字節數.
MYSQL數據庫
如果定義的是utf8字符集,對于text,實際上只能插入21845個字符
MYSQL數據庫
mysql> create table t1(name text) default charset=utf8; Query OK, 0 rows affected (0.01 sec) mysql> insert into t1 values(repeat('整',21846)); ERROR 1406 (22001): Data too long for column 'name' at row 1 mysql> insert into t1 values(repeat('整',21845)); Query OK, 1 row affected (0.05 sec)
DECIMAl
MYSQL數據庫
關于Decimal,官方的說法有點繞,
MYSQL數據庫
Values for DECIMAL (and NUMERIC) columns are represented using a binary format that packs nine decimal (base 10) digits into four bytes. Storage for the integer and fractional parts of each value are determined separately. Each multiple of nine digits requires four bytes, and the “leftover” digits require some fraction of four bytes. The storage required for excess digits is given by the following table.
還提供了一張對應表
MYSQL數據庫
MYSQL數據庫
對于以上這段話的解讀,有以下幾點:
MYSQL數據庫
1. 每9位需要4個字節,剩下的位數所需的空間如上所示.
MYSQL數據庫
2. 整數部分和小數部分是分開計算的.
MYSQL數據庫
譬如 Decimal(6,5),從定義可以看出,整數占1位,整數占5位,所以一共占用1+3=4個字節.
MYSQL數據庫
如何驗證呢?可通過InnoDB Table Monitor
MYSQL數據庫
如何啟動InnoDB Table Monitor,可參考:http://dev.mysql.com/doc/refman/5.7/en/innodb-enabling-monitors.html
MYSQL數據庫
mysql> create table t2(id decimal(6,5)); Query OK, 0 rows affected (0.01 sec) mysql> create table t3(id decimal(9,0)); Query OK, 0 rows affected (0.01 sec) mysql> create table t4(id decimal(8,3)); Query OK, 0 rows affected (0.01 sec) mysql> CREATE TABLE innodb_table_monitor (a INT) ENGINE=INNODB; Query OK, 0 rows affected, 1 warning (0.01 sec)
結果會輸出到錯誤日志中.
MYSQL數據庫
查看錯誤日志:
MYSQL數據庫
MYSQL數據庫
對于decimal(6,5),整數占1位,小數占5位,一共占用空間1+3=4個字節
MYSQL數據庫
對于decimal(9,0),整數部分9位,每9位需要4個字節,一共占用空間4個字節
MYSQL數據庫
對于decimal(8,3),整數占5位,小數占3位,一共占用空間3+2=5個字節.
MYSQL數據庫
至此,常用的MySQL數據類型驗證完畢~
MYSQL數據庫
對于CHAR,VARCHAR和TEXT等字符類型,M指定的都是字符的個數.對于CHAR,最大的字符數是255.對于VARCHAR,最大的字符數與字符集有關,如果字符集是latin1,則最大的字符數是65532(畢竟每一個字符只占用一個字節),對于utf8,最大的字符數是21844,因為一個字符占用三個字節.本質上,VARCHAR更多的是受到行大小的限制(最大為65535個字節).對于TEXT,不受行大小的限制,但受到自身定義的限制.
MYSQL數據庫