下面开始探讨内部存储细节 由于压缩是以block为单位的,因此在批插入的时候若数据本身不超过1 block容量是不会压缩的 (未严格证实,如下面例子, 若插入数据100条可存放在block中则不会产生压缩)
SQL> create table test1(a varchar2(20),b varchar2(20),c varchar2(20)) compress; SQL> select TABLESPACE_NAME ,EXTENT_ID ,blocks from dba_extents where segment_name = 'TEST1'; TABLESPACE_NAME EXTENT_ID BLOCKS ------------------------------ ---------- ---------- USERS 0 8 SQL> select file_id,block_id from dba_extents where segment_name = 'TEST1'; FILE_ID BLOCK_ID ---------- ---------- 11 769 SQL> insert /*+ append */ into test1 select 'AAAAAAAAAAAAAAAAAAAA','BBBBBBBBBBBBBBBBBBBB','CCCCCCCCCCCCCCCCCCCC' from dba_objects where rownum < 1001; 1000 rows created. SQL> commit; Commit complete. SQL> alter system dump datafile 11 block min 769 block max 771; System altered. trace 部分内容 data_block_dump,data header at 0xadb4674 =============== tsiz: 0x1f88 hsiz: 0x5ce pbl: 0x0adb4674 bdba: 0x02c00302 76543210 flag=-0------ ntab=2 nrow=724 frre=-1 fsbo=0x5ce fseo=0x1127 avsp=0xd tosp=0xd r0_9ir2=0x0 mec_kdbh9ir2=0x1 r1_9ir2=0x0 76543210 flag_9ir2=-------C fcls_9ir2[4]={ 0 32768 32768 32768 } 0x1e: pti[0] nrow=1 offs=0 0x22: pti[1] nrow=723 offs=1 0x26: pri[0] offs=0x1f46 0x28: pri[1] offs=0x1f41 0x2a: pri[2] offs=0x1f3c 0x2c: pri[3] offs=0x1f37 x5b6: pri[712] offs=0x115e 0x5b8: pri[713] offs=0x1159 0x5ba: pri[714] offs=0x1154 0x5bc: pri[715] offs=0x114f 0x5be: pri[716] offs=0x114a 0x5c0: pri[717] offs=0x1145 0x5c2: pri[718] offs=0x1140 0x5c4: pri[719] offs=0x113b 0x5c6: pri[720] offs=0x1136 0x5c8: pri[721] offs=0x1131 0x5ca: pri[722] offs=0x112c 0x5cc: pri[723] offs=0x1127 总记录条数724条,每条消耗5字节存储 block_row_dump: tab 0, row 0, @0x1f46 tl: 66 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 02 d3 03 dc 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 dc 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 dc 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 这部分为集中存储 tab 1, row 0, @0x1f41 tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 这里的5个字节就是实际存储内容,03 表示压缩了3个字段,估计这里最后00表示指针指向第一个存储了完全数据的 ROW 0 tab 1, row 1, @0x1f3c tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 tab 1, row 2, @0x1f37 tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 tab 1, row 3, @0x1f32 tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 tab 1, row 4, @0x1f2d tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 tab 1, row 5, @0x1f28 tl: 5 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 41 col 1: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 2: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 2c 00 01 03 00 tab 1, row 6, @0x1f23 SQL> truncate table test1;
Table truncated. SQL> conn test/test Connected. SQL> insert /*+ append */ into test1 select rownum,'BBBBBBBBBBBBBBBBBBBB','CCCCCCCCCCCCCCCCCCCC' from dba_objects where rownum < 1001; 1000 rows created. SQL> commit; Commit complete. SQL> alter system dump datafile 11 block min 769 block max 771; System altered. data_block_dump,data header at 0xadb4674 =============== tsiz: 0x1f88 hsiz: 0x5b2 pbl: 0x0adb4674 bdba: 0x02c00302 76543210 flag=-0------ ntab=2 nrow=709 frre=-1 fsbo=0x5b2 fseo=0x6e3 avsp=0xc5 tosp=0xc5 r0_9ir2=0x0 mec_kdbh9ir2=0x1 r1_9ir2=0x0 76543210 flag_9ir2=------OC fcls_9ir2[3]={ 0 32768 32768 } perm_9ir2[3]={ 2 0 1 } 这部分很要害,表示下面的实际存储字段顺序 也就是说,后面物理存储的顺序COL2,COL0,COL1对应数据字典中列的顺序应该是col0,col1,col2 0x20: pti[0] nrow=1 offs=0 0x24: pti[1] nrow=708 offs=1 0x28: pri[0] offs=0x1f5b 0x2a: pri[1] offs=0x1f54 0x2c: pri[2] offs=0x1f4d 0x2e: pri[3] offs=0x1f46 0x30: pri[4] offs=0x1f3f 0x32: pri[5] offs=0x1f38 0x34: pri[6] offs=0x1f31 0x36: pri[7] offs=0x1f2a 0x38: pri[8] offs=0x1f23 x25c: pri[282] offs=0x1571 0x25e: pri[283] offs=0x1568 0x260: pri[284] offs=0x155f 0x262: pri[285] offs=0x1556 0x264: pri[286] offs=0x154d 0x266: pri[287] offs=0x1544 0x268: pri[288] offs=0x153b 0x26a: pri[289] offs=0x1532 0x26c: pri[290] offs=0x1529 0x26e: pri[291] offs=0x1520 0x270: pri[292] offs=0x1516 block_row_dump: tab 0, row 0, @0x1f5b tl: 45 fb: --H-FL-- lb: 0x0 cc: 2 col 0: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 1: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 bindmp: 01 24 02 dc 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 dc 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 tab 1, row 0, @0x1f52 tl: 9 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 42 col 1: [20] 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 43 col 2: [ 3] 37 30 39 bindmp: 2c 00 02 02 00 cb 37 30 39 我们注重这里的02表示压缩2字段,本来的插入的rownum对应数据字典中表创建顺序最前的字段被存储在最末尾 tab 1, row 1, @0x1f49 tl: 9 fb: --H-FL-- lb: 0x0 cc: 3 col 0: [20] 42 42 42 42 42 42 42 42 42 42 42 42 4
|