MySQL Innodb 存儲結(jié)構(gòu) 和 存儲Null值 用法詳解
背景:
表空間:INNODB 所有數(shù)據(jù)都存在表空間當(dāng)中(共享表空間),要是開啟innodb_file_per_table,則每張表的數(shù)據(jù)會存到單獨(dú)的一個表空間內(nèi)(獨(dú)享表空間)。
獨(dú)享表空間包括:數(shù)據(jù),索引,插入緩存,數(shù)據(jù)字典。共享表空間包括:Undo信息(不會回收<物理空間上>),雙寫緩存信息,事務(wù)信息等。
段(segment):組成表空間,有區(qū)組成。
區(qū)(extent):有64個連續(xù)的頁組成。每個頁16K,總共1M。對于大的數(shù)據(jù)段,每次最后可申請4個區(qū)。
頁(page):是INNODB 磁盤管理的單位,有行組成。
行(row):包括事務(wù)ID,回滾指針,列信息等。
目的1:
了解表空間各個頁的信息和溢出行數(shù)據(jù)存儲的信息。通過該書作者蔣承堯編寫的工具:http://code.google.com/p/david-mysql-tools/source/browse/trunk/py_innodb_page_type/
3個腳本:
py_innodb_page_info.py
View Code #! /usr/bin/env python #encoding=utf-8 import mylib from sys import argv from mylib import myargv if __name__ == '__main__': myargv = myargv(argv) if myargv.parse_cmdline() == 0: pass else: mylib.get_innodb_page_type(myargv)
mylib.py
View Code encoding=utf-8 import os import include from include import * TABLESPACE_NAME='D:\\mysql_data\\test\\t.ibd' VARIABLE_FIELD_COUNT = 1 NULL_FIELD_COUNT = 0 class myargv(object): def __init__(self, argv): self.argv = argv self.parms = {} self.tablespace = '' def parse_cmdline(self): argv = self.argv if len(argv) == 1: print 'Usage: python py_innodb_page_info.py [OPTIONS] tablespace_file' print 'For more options, use python py_innodb_page_info.py -h' return 0 while argv: if argv[0][0] == '-': if argv[0][1] == 'h': self.parms[argv[0]] = '' argv = argv[1:] break if argv[0][1] == 'v': self.parms[argv[0]] = '' argv = argv[1:] else: self.parms[argv[0]] = argv[1] argv = argv[2:] else: self.tablespace = argv[0] argv = argv[1:] if self.parms.has_key('-h'): print 'Get InnoDB Page Info' print 'Usage: python py_innodb_page_info.py [OPTIONS] tablespace_file\n' print 'The following options may be given as the first argument:' print '-h help ' print '-o output put the result to file' print '-t number thread to anayle the tablespace file' print '-v verbose mode' return 0 return 1 def mach_read_from_n(page,start_offset,length): ret = page[start_offset:start_offset+length] return ret.encode('hex') def get_innodb_page_type(myargv): f=file(myargv.tablespace,'rb') fsize = os.path.getsize(f.name)/INNODB_PAGE_SIZE ret = {} for i in range(fsize): page = f.read(INNODB_PAGE_SIZE) page_offset = mach_read_from_n(page,FIL_PAGE_OFFSET,4) page_type = mach_read_from_n(page,FIL_PAGE_TYPE,2) if myargv.parms.has_key('-v'): if page_type == '45bf': page_level = mach_read_from_n(page,FIL_PAGE_DATA+PAGE_LEVEL,2) print "page offset %s, page type <%s>, page level <%s>"%(page_offset,innodb_page_type[page_type],page_level) else: print "page offset %s, page type <%s>"%(page_offset,innodb_page_type[page_type]) if not ret.has_key(page_type): ret[page_type] = 1 else: ret[page_type] = ret[page_type] + 1 print "Total number of page: %d:"%fsize for type in ret: print "%s: %s"%(innodb_page_type[type],ret[type])
include.py
View Code #encoding=utf-8 INNODB_PAGE_SIZE = 16*1024*1024 # Start of the data on the page FIL_PAGE_DATA = 38 FIL_PAGE_OFFSET = 4 # page offset inside space FIL_PAGE_TYPE = 24 # File page type # Types of an undo log segment */ TRX_UNDO_INSERT = 1 TRX_UNDO_UPDATE = 2 # On a page of any file segment, data may be put starting from this offset FSEG_PAGE_DATA = FIL_PAGE_DATA # The offset of the undo log page header on pages of the undo log TRX_UNDO_PAGE_HDR = FSEG_PAGE_DATA PAGE_LEVEL = 26 #level of the node in an index tree; the leaf level is the level 0 */ innodb_page_type={ '0000':u'Freshly Allocated Page', '0002':u'Undo Log Page', '0003':u'File Segment inode', '0004':u'Insert Buffer Free List', '0005':u'Insert Buffer Bitmap', '0006':u'System Page', '0007':u'Transaction system Page', '0008':u'File Space Header', '0009':u'擴(kuò)展描述頁', '000a':u'Uncompressed BLOB Page', '000b':u'1st compressed BLOB Page', '000c':u'Subsequent compressed BLOB Page', '45bf':u'B-tree Node' } innodb_page_direction={ '0000': 'Unknown(0x0000)', '0001': 'Page Left', '0002': 'Page Right', '0003': 'Page Same Rec', '0004': 'Page Same Page', '0005': 'Page No Direction', 'ffff': 'Unkown2(0xffff)' } INNODB_PAGE_SIZE=1024*16 # InnoDB Page 16K
測試1:
root@localhost : test 02:26:13>create table tt(id int auto_increment,name varchar(10),age int,address varchar(20),primary key (id))engine=innodb; Query OK, 0 rows affected (0.17 sec) root@zhoujy:/var/lib/mysql/test# ls -lh tt.ibd -rw-rw---- 1 mysql mysql 96K 2012-10-17 14:26 tt.ibd
查看ibd:
root@zhoujy:/home/zhoujy/jiaoben/read_ibd# python py_innodb_page_info.py /var/lib/mysql/test/tt.ibd -v page offset 00000000, page type <File Space Header> page offset 00000001, page type <Insert Buffer Bitmap> page offset 00000002, page type <File Segment inode> page offset 00000003, page type <B-tree Node>, page level <0000> ---葉子節(jié)點(diǎn) page offset 00000000, page type <Freshly Allocated Page> page offset 00000000, page type <Freshly Allocated Page> Total number of page: 6: Freshly Allocated Page: 2 Insert Buffer Bitmap: 1 File Space Header: 1 B-tree Node: 1 File Segment inode: 1
解釋:
Total number of page: 總頁數(shù)
Freshly Allocated Page:可用頁
Insert Buffer Bitmap:插入緩存位圖頁
Insert Buffer Free List:插入緩存空閑列表頁
B-tree Node:數(shù)據(jù)頁
Uncompressed BLOB Page:二進(jìn)制大對象頁,存放溢出行的頁,即溢出頁
上面得到的信息是表初始化大小為96K,他是有 Total number of page * 16 得來的。1個數(shù)據(jù)頁,2個可用頁面。
root@localhost : test 02:42:58>insert into tt values(name,age,address) values('aaa',23,'HZZZ');
疑惑:為什么沒有申請區(qū)?區(qū)是64個連續(xù)的頁,大小1M。那么表大小也應(yīng)該是至少1M。但是現(xiàn)在只有96K(默認(rèn))。原因是因?yàn)槊總€段開始的時候,先有32個頁大小的碎片頁存放數(shù)據(jù),使用
完之后才是64頁的連續(xù)申請,最多每次可以申請4個區(qū),保證數(shù)據(jù)的順序。這里看出表大小增加是按照至少64頁的大小的空間來增加的,即1M增加。
驗(yàn)證:
填充數(shù)據(jù),寫滿這32個碎片頁,32*16 = 512K。看看是否能申請大于1M的空間。
View Code root@zhoujy:/home/zhoujy/jiaoben/read_ibd# ls -lh /var/lib/mysql/test/tt.ibd -rw-rw---- 1 mysql mysql 576K 2012-10-17 15:30 /var/lib/mysql/test/tt.ibd root@zhoujy:/home/zhoujy/jiaoben/read_ibd# python py_innodb_page_info.py /var/lib/mysql/test/tt.ibd -v page offset 00000000, page type <File Space Header> page offset 00000001, page type <Insert Buffer Bitmap> page offset 00000002, page type <File Segment inode> page offset 00000003, page type <B-tree Node>, page level <0001> page offset 00000004, page type <B-tree Node>, page level <0000> page offset 00000005, page type <B-tree Node>, page level <0000> page offset 00000006, page type <B-tree Node>, page level <0000> page offset 00000007, page type <B-tree Node>, page level <0000> page offset 00000008, page type <B-tree Node>, page level <0000> page offset 00000009, page type <B-tree Node>, page level <0000> page offset 0000000a, page type <B-tree Node>, page level <0000> page offset 0000000b, page type <B-tree Node>, page level <0000> page offset 0000000c, page type <B-tree Node>, page level <0000> page offset 0000000d, page type <B-tree Node>, page level <0000> page offset 0000000e, page type <B-tree Node>, page level <0000> page offset 0000000f, page type <B-tree Node>, page level <0000> page offset 00000010, page type <B-tree Node>, page level <0000> page offset 00000011, page type <B-tree Node>, page level <0000> page offset 00000012, page type <B-tree Node>, page level <0000> page offset 00000013, page type <B-tree Node>, page level <0000> page offset 00000014, page type <B-tree Node>, page level <0000> page offset 00000015, page type <B-tree Node>, page level <0000> page offset 00000016, page type <B-tree Node>, page level <0000> page offset 00000017, page type <B-tree Node>, page level <0000> page offset 00000018, page type <B-tree Node>, page level <0000> page offset 00000019, page type <B-tree Node>, page level <0000> page offset 0000001a, page type <B-tree Node>, page level <0000> page offset 0000001b, page type <B-tree Node>, page level <0000> page offset 0000001c, page type <B-tree Node>, page level <0000> page offset 0000001d, page type <B-tree Node>, page level <0000> page offset 0000001e, page type <B-tree Node>, page level <0000> page offset 0000001f, page type <B-tree Node>, page level <0000> page offset 00000020, page type <B-tree Node>, page level <0000> page offset 00000021, page type <B-tree Node>, page level <0000> page offset 00000022, page type <B-tree Node>, page level <0000> page offset 00000023, page type <B-tree Node>, page level <0000> Total number of page: 36: Insert Buffer Bitmap: 1 File Space Header: 1 B-tree Node: 33 File Segment inode: 1
"額外"頁:4個
page offset 00000000, page type <File Space Header> :文件頭空間頁
page offset 00000001, page type <Insert Buffer Bitmap>:插入緩存位圖頁
page offset 00000002, page type <File Segment inode>:文件段節(jié)點(diǎn)
page offset 00000003, page type <B-tree Node>, page level <0001>:根頁
碎片頁:32個
page type <B-tree Node>, page level <0000>
總共36個頁,ibd大小 576K的由來:32*16=512K(碎片頁)+ 4*16=64(額外頁),這里開始要是再插入的話,應(yīng)該申請最少1M的頁:
root@zhoujy:/home/zhoujy/jiaoben/read_ibd# ls -lh /var/lib/mysql/test/tt.ibd -rw-rw---- 1 mysql mysql 2.0M 2012-10-17 16:10 /var/lib/mysql/test/tt.ibd root@zhoujy:/home/zhoujy/jiaoben/read_ibd# python py_innodb_page_info.py /var/lib/mysql/test/tt.ibd Total number of page: 128: Freshly Allocated Page: 91 Insert Buffer Bitmap: 1 File Space Header: 1 B-tree Node: 34 File Segment inode: 1
頁從36跳到了128,因?yàn)橐呀?jīng)用完了32個碎片頁,新的頁會采用區(qū)的方式進(jìn)行空間申請。信息中看到有很多可用頁,正好說明這點(diǎn)。
▲溢出行數(shù)據(jù)存放:INNODB存儲引擎是索引組織的,即每頁中至少有兩行記錄,因此如果頁中只能存放一行記錄,INNODB會自動將行數(shù)據(jù)放到溢出頁中。當(dāng)發(fā)生溢出行的時候,實(shí)際數(shù)據(jù)保存在BLOB頁中,數(shù)據(jù)頁只保存數(shù)據(jù)的前768字節(jié)(老的文件格式),新的文件格式(Barracuda)采用完全行溢出的方式,數(shù)據(jù)頁只保存20個字節(jié)的指針,BLOB也保存所有數(shù)據(jù)。如何查看表中有溢出行數(shù)據(jù)呢?
root@localhost : test 04:52:34>create table t1 (id int,name varchar(10),memo varchar(8000))engine =innodb default charset utf8; Query OK, 0 rows affected (0.16 sec) root@localhost : test 04:53:10>insert into t1 values(1,'zjy',repeat('我',8000)); Query OK, 1 row affected (0.00 sec)
查看ibd:
root@zhoujy:/home/zhoujy/jiaoben/read_ibd# python py_innodb_page_info.py /var/lib/mysql/test/t1.ibd -v page offset 00000000, page type <File Space Header> page offset 00000001, page type <Insert Buffer Bitmap> page offset 00000002, page type <File Segment inode> page offset 00000003, page type <B-tree Node>, page level <0000> page offset 00000004, page type <Uncompressed BLOB Page> page offset 00000005, page type <Uncompressed BLOB Page> Total number of page: 6: Insert Buffer Bitmap: 1 Uncompressed BLOB Page: 2 File Space Header: 1 B-tree Node: 1 File Segment inode: 1
從信息中看到,剛才插入的一行記錄,已經(jīng)溢出了,保存到了2個BLOB頁中(<Uncompressed BLOB Page>)。因?yàn)?頁只有16K,又要存2行數(shù)據(jù),所以每行記錄最好小于8K,而上面的遠(yuǎn)遠(yuǎn)大于8K,所以被溢出了。當(dāng)然這個也不是包括特大字段,要是一張表里面有5個字段都是varchar(512)【多個varchar的總和大于8K就可以】,也會溢出:
root@localhost : test 05:08:39>create table t2 (id int,name varchar(1000),address varchar(512),company varchar(200),xx varchar(512),memo varchar(512),dem varchar(1000))engine =innodb default charset utf8; Query OK, 0 rows affected (0.17 sec) root@localhost : test 05:08:43>insert into t2 values(1,repeat('周',1000),repeat('我',500),repeat('丁',500),repeat('啊',500),repeat('噢',500),repeat('阿a',500));
1000+500+500+500+500+500=3500*3>8000字節(jié);行會被溢出:
root@zhoujy:/home/zhoujy/jiaoben/read_ibd# python py_innodb_page_info.py /var/lib/mysql/test/t2.ibd -v page offset 00000000, page type <File Space Header> page offset 00000001, page type <Insert Buffer Bitmap> page offset 00000002, page type <File Segment inode> page offset 00000003, page type <B-tree Node>, page level <0000> page offset 00000004, page type <Uncompressed BLOB Page> page offset 00000000, page type <Freshly Allocated Page> Total number of page: 6: Insert Buffer Bitmap: 1 Freshly Allocated Page: 1 File Segment inode: 1 B-tree Node: 1 File Space Header: 1 Uncompressed BLOB Page: 1
<Uncompressed BLOB Page> 頁存放真正的數(shù)據(jù),那數(shù)據(jù)頁到底存放什么?用hexdump查看:
root@zhoujy:/home/zhoujy/jiaoben/read_ibd# hexdump -C -v /var/lib/mysql/test/t1.ibd > t1.txt
查看ibd:
View Code 3082 0000c090 00 32 01 10 80 00 00 01 7a 6a 79 e6 88 91 e6 88 |.2......zjy.....| 3083 0000c0a0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3084 0000c0b0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3085 0000c0c0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3086 0000c0d0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3087 0000c0e0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3088 0000c0f0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3089 0000c100 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3090 0000c110 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3091 0000c120 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3092 0000c130 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3093 0000c140 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3094 0000c150 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3095 0000c160 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3096 0000c170 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3097 0000c180 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3098 0000c190 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3099 0000c1a0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3100 0000c1b0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3101 0000c1c0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3102 0000c1d0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3103 0000c1e0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3104 0000c1f0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3105 0000c200 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3106 0000c210 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3107 0000c220 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3108 0000c230 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3109 0000c240 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3110 0000c250 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3111 0000c260 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3112 0000c270 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3113 0000c280 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3114 0000c290 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3115 0000c2a0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3116 0000c2b0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3117 0000c2c0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3118 0000c2d0 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3119 0000c2e0 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3120 0000c2f0 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3121 0000c300 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3122 0000c310 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3123 0000c320 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3124 0000c330 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3125 0000c340 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3126 0000c350 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3127 0000c360 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 |................| 3128 0000c370 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 |................| 3129 0000c380 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 88 91 e6 |................| 3130 0000c390 88 91 e6 88 91 e6 88 91 e6 88 91 00 00 02 1c 00 |................|
文本中剛好是48行,每行16字節(jié)。48*16=768字節(jié),剛好驗(yàn)證了之前說的:數(shù)據(jù)頁只保存數(shù)據(jù)的前768字節(jié)(老的文件格式)。
總結(jié)1:
通過上面的信息,可以能清楚的知道ibd表空間各個頁的分布和利用信息以及表空間大小增加的步長;特別注意的是溢出行,一個頁中至少包含2行數(shù)據(jù),如果頁中存放的行數(shù)越多,性能就越好。
************************************
************************************
目的2:
了解表空間如何存儲數(shù)據(jù),以及對NULL值的存儲。
測試2:
在測試前先了解INNODB的存儲格式(row_format)。老格式(Antelope):Compact<默認(rèn)>,Redumdant;新格式(Barracuda):Compressed,Dynamic。
這里測試指針對默認(rèn)的存儲格式。
Compact行記錄方式如下:
|變長字段長度列表(1~2字節(jié))|NULL標(biāo)志位(1字節(jié))|記錄頭信息(5字節(jié))|RowID(6字節(jié))|事務(wù)ID(6字節(jié))|回滾指針(7字節(jié))|
上面信息除了 "NULL標(biāo)志位"[表中所有字段都定義為NOT NULL],"RowID"[表中有主鍵] ,"變長字段長度列表" [沒有變長字段] 可能不存在外,其他信息都會出現(xiàn)。所以一行數(shù)據(jù)除了列數(shù)據(jù)所占用的字段外,還需要額外18字節(jié)。
一:字段全NULL
mysql> create table mytest(t1 varchar(10),t2 varchar(10),t3 varchar(10) ,t4 varchar(10))engine=innodb charset = latin1 row_format=compact; Query OK, 0 rows affected (0.08 sec) mysql> insert into mytest values('a','bb','bb','ccc'); Query OK, 1 row affected (0.02 sec) mysql> insert into mytest values('a','ee','ee','fff'); Query OK, 1 row affected (0.01 sec) mysql> insert into mytest values('a',NULL,NULL,'fff'); Query OK, 1 row affected (0.00 sec)
測試數(shù)據(jù)準(zhǔn)備完之后,執(zhí)行shell命令:
root@zhoujy:/usr/local/mysql/test# hexdump -C -v mytest.ibd > /home/zhoujy/mytest.txt
打開mytest.txt文件找到supremum這一行:
0000c070 73 75 70 72 65 6d 75 6d 03 02 02 01 00 00 00 10 |supremum........| ----------->一行,16字節(jié) 0000c080 00 25 00 00 00 03 b9 00 00 00 00 02 49 01 82 00 |.%..........I...| 0000c090 00 01 4a 01 10 61 62 62 62 62 63 63 63 03 02 02 |..J..abbbbccc...| 0000c0a0 01 00 00 00 18 00 23 00 00 00 03 b9 01 00 00 00 |......#.........| 0000c0b0 02 49 02 83 00 00 01 4b 01 10 61 65 65 65 65 66 |.I.....K..aeeeef| 0000c0c0 66 66 03 01 06 00 00 20 ff a6 00 00 00 03 b9 02 |ff..... ........| 0000c0d0 00 00 00 02 49 03 84 00 00 01 4c 01 10 61 66 66 |....I.....L..aff| 0000c0e0 66 00 00 00 00 00 00 00 00 00 00 00 00 00 00 00 |f...............|
解釋:
第一行數(shù)據(jù):
03 02 02 01/*變長字段*/ ---- 表中4個字段類型為varchar,并且沒有NULL數(shù)據(jù),而且每個字段君小于255。
00 /*NULL標(biāo)志位,第一行沒有null的數(shù)據(jù)*/
00 00 10 00 25 /*記錄頭信息,固定5個字節(jié)*/
00 00 00 03 b9 00/*RowID,固定6個字節(jié),表沒有主鍵*/
00 00 00 02 49 01 /*事務(wù)ID,固定6個字節(jié)*/
82 00 00 01 4a 01 10 /*回滾指針,固定7個字節(jié)*/
61 62 62 62 62 63 63 63/*列的數(shù)據(jù)*/
第二行數(shù)據(jù)和第一行數(shù)據(jù)一樣(顏色匹配)。
第三行數(shù)據(jù)(有NULL值)和第一行的解釋的顏色對應(yīng)起來比較差別:
03 02 02 01 VS 03 01 ----------當(dāng)值為NULL時,變長字段列表不會占用存儲空間。 61 62 62 62 62 63 63 63 VS 61 66 66 66 --------- NULL值沒有存儲,不占空間
結(jié)論:當(dāng)值為NULL時,變長字段列表不會占用存儲空間。NULL值沒有存儲,不占空間,但是需要一個標(biāo)志位(一行一個)。
二:字段全NOT NULL
mysql> create table mytest(t1 varchar(10) NOT NULL,t2 varchar(10) NOT NULL,t3 varchar(10) NOT NULL,t4 varchar(10) NOT NULL)engine=innodb charset = latin1 row_format=compact; Query OK, 0 rows affected (0.03 sec) mysql> insert into mytest values('a','bb','bb','ccc'); Query OK, 1 row affected (0.01 sec) mysql> insert into mytest values('a','ee','ee','fff'); Query OK, 1 row affected (0.01 sec) mysql> insert into mytest values('a',NULL,NULL,'fff'); ERROR 1048 (23000): Column 't2' cannot be null
步驟和上面一樣,得到的ibd的結(jié)果是:
0000c070 73 75 70 72 65 6d 75 6d 03 02 02 01 00 00 10 00 |supremum........| 0000c080 24 00 00 00 03 b9 03 00 00 00 02 49 07 87 00 00 |$..........I....| 0000c090 01 4f 01 10 61 62 62 62 62 63 63 63 03 02 02 01 |.O..abbbbccc....| 0000c0a0 00 00 18 ff cb 00 00 00 03 b9 04 00 00 00 02 49 |...............I| 0000c0b0 08 88 00 00 01 50 01 10 61 65 65 65 65 66 66 66 |.....P..aeeeefff|
和上面比較,發(fā)現(xiàn)少了NULL的標(biāo)志位信息。
結(jié)論: NULL值會有額外的空間來存儲,即每行1字節(jié)的大小。對于相同數(shù)據(jù)的表,字段中有NULL值的表比NOT NULL的大。
三:1個NULL,和1個''的數(shù)據(jù):
mysql> create table mytest(t1 varchar(10) NOT NULL,t2 varchar(10) NOT NULL DEFAULT '',t3 varchar(10) NOT NULL ,t4 varchar(10))engine=innodb charset = latin1 row_format=compact; Query OK, 0 rows affected (0.02 sec) mysql> insert into mytest(t1,t2) values('A','BB'); Query OK, 1 row affected, 1 warning (0.01 sec)
步驟和上面一樣,得到的ibd的結(jié)果是:
0000c070 73 75 70 72 65 6d 75 6d 00 02 01 01 00 00 10 ff |supremum........| 0000c080 ef 00 00 00 43 b9 03 00 00 00 02 4a 15 90 00 00 |....C......J....| 0000c090 01 c2 01 10 41 42 42 00 00 00 00 00 00 00 00 00 |....ABB.........|
和上面2個區(qū)別主要在于變長列表和列數(shù)據(jù)這里。
結(jié)論:列數(shù)據(jù)信息里表明了 NULL數(shù)據(jù)和''數(shù)據(jù)都不占用任何空間,對于變長字段列表的信息,和一對比得出:‘'數(shù)據(jù)雖然不需要占用任何存儲空間,但是在變長字段列表里面還是需要占用一個字節(jié)<畢竟還是一個‘'值>,NULL值不需要占用”,只是NULL會有額外的一個標(biāo)志位,所以能有個優(yōu)化的說法:“數(shù)據(jù)庫表中能設(shè)置NOT NULL的就盡量設(shè)置為NOT NULL,除非確實(shí)需要NULL值得。” 在此得到了證明。
上面的測試都是針對VARCHAR的變長類型,那對于CHAR呢?
CHAR 測試:
root@localhost : test 10:33:35>create table mytest(t1 char(10),t2 char(10),t3 char(10) ,t4 char(10))engine=innodb charset = latin1 row_format=compact;Query OK, 0 rows affected (0.16 sec) root@localhost : test 10:33:59>insert into mytest values('a','bb','bb','ccc'); Query OK, 1 row affected (0.00 sec) root@localhost : test 10:34:09>insert into mytest values('a','ee','ee','fff'); Query OK, 1 row affected (0.00 sec) root@localhost : test 10:34:19>insert into mytest values('a',NULL,NULL,'fff'); Query OK, 1 row affected (0.00 sec)
打開ibd生成的文件:
0000c060 02 00 1b 69 6e 66 69 6d 75 6d 00 04 00 0b 00 00 |...infimum......| 0000c070 73 75 70 72 65 6d 75 6d 00 00 00 10 00 41 00 00 |supremum.....A..| 0000c080 00 0a f5 00 00 00 00 81 2d 07 80 00 00 00 32 01 |........-.....2.| 0000c090 10 61 20 20 20 20 20 20 20 20 20 62 62 20 20 20 |.a bb | 0000c0a0 20 20 20 20 20 62 62 20 20 20 20 20 20 20 20 63 | bb c| 0000c0b0 63 63 20 20 20 20 20 20 20 00 00 00 18 00 41 00 |cc .....A.| 0000c0c0 00 00 0a f5 01 00 00 00 81 2d 08 80 00 00 00 32 |.........-.....2| 0000c0d0 01 10 61 20 20 20 20 20 20 20 20 20 65 65 20 20 |..a ee | 0000c0e0 20 20 20 20 20 20 65 65 20 20 20 20 20 20 20 20 | ee | 0000c0f0 66 66 66 20 20 20 20 20 20 20 06 00 00 20 ff 70 |fff ... .p| 0000c100 00 00 00 0a f5 02 00 00 00 81 2d 09 80 00 00 00 |..........-.....| 0000c110 32 01 10 61 20 20 20 20 20 20 20 20 20 66 66 66 |2..a fff| 0000c120 20 20 20 20 20 20 20 00 00 00 00 00 00 00 00 00 | .........|
和一的varchar比較發(fā)現(xiàn):少了變長字段列表,但是對于char來講,需要固定長度來存儲的,存不到固定長度,也會被填充滿。如:20;并且NULL值也不需要占用存儲空間。
混合(varchar,char):
root@localhost : test 11:21:48>create table mytest(t1 int,t2 char(10),t3 varchar(10) ,t4 char(10))engine=innodb charset = latin1 row_format=compact; Query OK, 0 rows affected (0.17 sec) root@localhost : test 11:21:50>insert into mytest values(1,'a','b','c'); Query OK, 1 row affected (0.00 sec) root@localhost : test 11:22:06>insert into mytest values(11,'aa','bb','cc'); Query OK, 1 row affected (0.00 sec)
從上面的表結(jié)構(gòu)中看出:
1,變長字段列表長度:1
2,NULL標(biāo)志位:1
3,記錄頭信息:5
4,RowID:6
5,事務(wù)ID:6
6,回滾指針:7
idb的信息:
0000c070 73 75 70 72 65 6d 75 6d 01 00 00 00 10 00 33 00 |supremum......3.| 0000c080 00 00 0a f5 07 00 00 00 81 2d 1a 80 00 00 00 32 |.........-.....2| 0000c090 01 10 80 00 00 01 61 20 20 20 20 20 20 20 20 20 |......a | 0000c0a0 62 63 20 20 20 20 20 20 20 20 20 02 00 00 00 18 |bc .....| 0000c0b0 ff be 00 00 00 0a f5 08 00 00 00 81 2d 1b 80 00 |............-...| 0000c0c0 00 00 32 01 10 80 00 00 0b 61 61 20 20 20 20 20 |..2......aa | 0000c0d0 20 20 20 62 62 63 63 20 20 20 20 20 20 20 20 00 | bbcc .|
從上信息得出和之前預(yù)料的一樣:因?yàn)楸碇兄挥幸粋€varchar字段,所以,變長列表長度就只有:01
特別注意的是:各個列數(shù)據(jù)存儲的信息:t1字段為int 類型,占用4個字節(jié)的大小。第一行:80 00 00 01 就是表示 1 數(shù)字;第二行:80 00 00 0b 表示了11的數(shù)字。[select hex(11) == B ],其他的和上面的例子一樣。
上面都是latin1單字節(jié)字符集的說明,那對于多字節(jié)字符集的情況怎么樣?
root@localhost : test 11:52:10>create table mytest(id int auto_increment,t2 varchar(10),t3 varchar(10) ,t4 char(10),primary key(id))engine=innodb charset = utf8 row_format=compact; Query OK, 0 rows affected (0.17 sec) root@localhost : test 11:52:11>insert into mytest(t2,t3,t4) values('bb','bb','ccc'); Query OK, 1 row affected (0.00 sec) root@localhost : test 11:55:34>insert into mytest(t2,t3,t4) values('我們','他們','我們的'); Query OK, 1 row affected (0.00 sec)
ibd信息如下:
0000c070 73 75 70 72 65 6d 75 6d 0a 02 02 00 00 00 10 00 |supremum........| 0000c080 28 80 00 00 01 00 00 00 81 2d 27 80 00 00 00 32 |(........-'....2| 0000c090 01 10 62 62 62 62 63 63 63 20 20 20 20 20 20 20 |..bbbbccc | 0000c0a0 0a 06 06 00 00 00 18 ff c7 80 00 00 02 00 00 00 |................| 0000c0b0 81 2d 28 80 00 00 00 32 01 10 e6 88 91 e4 bb ac |.-(....2........| 0000c0c0 e4 bb 96 e4 bb ac e6 88 91 e4 bb ac e7 9a 84 20 |............... |
因?yàn)楸碛辛酥麈I,所以ROWID(6字節(jié))不見了。
特別注意的是:變長字段列表是3?表里面的varchar類型的列只有2個啊。經(jīng)測試得出:在多字節(jié)字符集的條件下,char類型被當(dāng)成可變長度的類型來處理,他們的行存儲基本沒有區(qū)別,所以這個就出現(xiàn)變長列表是3了,因?yàn)槭莡tf8字符集,占用三個字節(jié)。所以一個漢字均占用了一個頁中3個字節(jié)的空間(”我們“ :e6 88 91 e4 bb ac)。
數(shù)據(jù)列的信息:
id列的1值,應(yīng)該是 80 00 00 01,為什么這個顯示00 32 01 10,而且所有的id都是00 32 01 10。測試發(fā)現(xiàn),id為自增主鍵的時候,id的4個字節(jié)長度都是以00 32 01 10 表示。否則和前面一個例子里說的,用select HEX(X) 表示。
總結(jié)2:
上面的測試都是基于COMPACT存儲格式的,不管是varchar還是char,NULL值是不需要占用存儲空間的;特別需要注意的是Redumdant的記錄頭信息需要6個固定字節(jié);在多字節(jié)字符集的條件下,CHAR和VARCHAR的行存儲基本是沒有區(qū)別的。
到此這篇關(guān)于MySQL Innodb 存儲結(jié)構(gòu) 和 存儲Null值 用法詳解的文章就介紹到這了,更多相關(guān)MySQL Innodb 存儲結(jié)構(gòu) 存儲Null值內(nèi)容請搜索腳本之家以前的文章或繼續(xù)瀏覽下面的相關(guān)文章希望大家以后多多支持腳本之家!
相關(guān)文章
阿里云ECS云服務(wù)器(linux系統(tǒng))安裝mysql后遠(yuǎn)程連接不了(踩坑)
這篇文章主要介紹了阿里云ECS云服務(wù)器(linux系統(tǒng))安裝mysql后遠(yuǎn)程連接不了(踩坑),小編覺得挺不錯的,現(xiàn)在分享給大家,也給大家做個參考。一起跟隨小編過來看看吧2019-04-04MySQL中使用JSON存儲數(shù)據(jù)的實(shí)現(xiàn)示例
本文主要介紹了MySQL中使用JSON存儲數(shù)據(jù)的實(shí)現(xiàn)示例,我們可以在MySQL中直接存儲、查詢和操作JSON數(shù)據(jù),具有一定的參考價值,感興趣的可以了解一下2023-09-09使用mysql語句對分組結(jié)果進(jìn)行再次篩選方式
這篇文章主要介紹了使用mysql語句對分組結(jié)果進(jìn)行再次篩選方式,具有很好的參考價值,希望對大家有所幫助,如有錯誤或未考慮完全的地方,望不吝賜教2023-08-08Mysql數(shù)據(jù)庫的主從復(fù)制與讀寫分離精講教程
這篇文章主要為大家詳細(xì)介紹了Mysql數(shù)據(jù)庫的主從復(fù)制與讀寫分離的示例教程,有需要的朋友可以借鑒參考下,希望能夠有所幫助,祝大家多多進(jìn)步2021-11-11一文帶你永久擺脫Mysql時區(qū)錯誤問題(idea數(shù)據(jù)庫可視化插件配置)
在MySQL啟動時會檢查當(dāng)前系統(tǒng)的時區(qū)并根據(jù)系統(tǒng)時區(qū)設(shè)置全局參數(shù)system_time_zone的值,下面這篇文章主要給大家介紹了關(guān)于如何永久擺脫Mysql時區(qū)錯誤問題(idea數(shù)據(jù)庫可視化插件配置)的相關(guān)資料,需要的朋友可以參考下2022-08-08