上周了解了一下IBM的压缩技术,打算对比一下Oracle的表压缩技术做点研究,先讨论一下Oracle的表压缩技术.
从Oracle9iR2开始,Oracle推出了压缩表技术(table compression),用于压缩数据表中的重复数据,以节省存储空间,压缩技术倾向于在数据仓库中使用。
压缩在数据块级生效,当数据表定义为压缩时,数据库在每个数据块上保留空间存储重复数据的单个拷贝,保留空间被称为符号表(symbol table)。此后在具体行上不必再存储这些重复数据,只需要存放指向符号表相应数据的指针,存储空间因此得以节省。
关于压缩表的基本介绍,参考OTN上的文档: http://www.oracle.com/technology/oramag/oracle/04-mar/o24tech_data.Html
我们看一下简单的测试:
[oracle@jumper oracle]$ sqlplus eygle/eygle
SQL*Plus: Release 9.2.0.4.0 - ProdUCtion on Mon Jun 26 16:07:24 2006
Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.
Connected to: Oracle9i Enterprise Edition Release 9.2.0.4.0 - Production With the Partitioning option JServer Release 9.2.0.4.0 - Production
SQL> create table test (c1 varchar2(20),c2 varchar2(20));
Table created.
SQL> begin 2 for i in 1 .. 10000 loop 3 insert into test values('eygle','test'); 4 end loop; 5 end; 6 /
PL/SQL procedure successfully completed.
SQL> create table test_compress compress as select * from test;
Table created.
SQL> select table_name,COMPRESSION from user_tables where table_name like 'TEST%';
TABLE_NAME COMPRESS ------------------------------ -------- TEST DISABLED TEST_COMPRESS ENABLED
SQL> analyze table test compute statistics;
Table analyzed.
SQL> analyze table test_compress compute statistics;
Table analyzed.
我们看一下两个表的空间使用情况:
SQL> select table_name,blocks,EMPTY_BLOCKS from user_tables 2 where table_name like 'TEST%';
TABLE_NAME BLOCKS EMPTY_BLOCKS ------------------------------ ---------- ------------ TEST 28 4 TEST_COMPRESS 18 6
SQL> select (28-4)/(18-6) from dual;
(28-4)/(18-6) ------------- 2
我们看到,压缩表只使用了常规表一半的空间。
我们转储一下数据块,看一下压缩表的存储结构:
SQL> select segment_name,file_id,block_id,blocks from dba_extents 2 where segment_name='TEST_COMPRESS';
SEGMENT_NAME FILE_ID BLOCK_ID BLOCKS -------------------- ---------- ---------- ---------- TEST_COMPRESS 3 17 8 TEST_COMPRESS 3 25 8 TEST_COMPRESS 3 33 8
SQL> alter system dump datafile 3 block 20;
System altered.
找到跟踪文件:
SQL> @gettrcname.sql
TRACE_FILE_NAME ------------------------------------------------------------------- /opt/oracle/admin/eygle/udump/eygle_ora_20984.trc
查看内容,首先看一下块头信息:
data_block_dump,data header at 0xaa84e7c =============== tsiz: 0x1f80 hsiz: 0x5d2 pbl: 0x0aa84e7c bdba: 0x00c00014 76543210 flag=-0------ ntab=2 nrow=727 frre=-1 fsbo=0x5d2 fseo=0x1144 avsp=0x1a tosp=0x1a r0_9ir2=0x0 mec_kdbh9ir2=0x1 r1_9ir2=0x0 76543210 flag_9ir2=-------C fcls_9ir2[3]={ 0 32768 32768 } 0x1c:pti[0] nrow=1 offs=0 0x20:pti[1] nrow=726 offs=1 0x24:pri[0] offs=0x1f72 0x26:pri[1] offs=0x1f6d
我们看到这个Block中的ntab =2 也就是存在2张表,从下面可以找到table 0的信息:
tab 0, row 0, @0x1f72 tl: 14 fb: --H-FL-- lb: 0x0 cc: 2 col 0: [ 5] 65 79 67 6c 65 col 1: [ 4] 74 65 73 74 bindmp: 02 d6 02 cd 65 79 67 6c 65 cc 74 65 73 74
这个table 0只有一条记录,就是我们之前所说的符号表。
此后的记录才是真实数据,每条数据记录包含一个指针,指向符号表:
tab 1, row 0, @0x1f6d tl: 5 fb: --H-FL-- lb: 0x0 cc: 2 col 0: [ 5] 65 79 67 6c 65 col 1: [ 4] 74 65 73 74 bindmp: 2c 00 01 02 00 tab 1, row 1, @0x1f68 tl: 5 fb: --H-FL-- lb: 0x0 cc: 2 col 0: [ 5] 65 79 67 6c 65 col 1: [ 4] 74 65 73 74 bindmp: 2c 00 01 02 00
这里的bindmp就是指针。
关于压缩表存储结构的进一步探讨可以参考:
biti_rainy 的 关于 9iR2 的 compress table 的研究 http://www.itpub.net/showthread.PHP?threadid=197403
fuyuncat 的 数据段压缩(Data Segment Compression)浅析 http://fuyuncat.itpub.net/post/5203/45991
压缩表显然是通过CPU换取存储,存储的缩减必然导致存储和查询时压缩和解压缩的CPU消耗。 但是,I/O操作得以节约,我们看一下对以上2个表执行全表扫描的比较:
SQL> set autotrace on SQL> select count(*) from test;
COUNT(*) ---------- 10000
Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=4 Card=1) 1 0 SORT (AGGREGATE) 2 1 TABLE Access (FULL) OF 'TEST' (Cost=4 Card=10000)
Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 31 consistent gets 0 physical reads 0 redo size 379 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
SQL> select count(*) from test_compress; COUNT(*) ---------- 10000
Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=3 Card=1) 1 0 SORT (AGGREGATE) 2 1 TABLE ACCESS (FULL) OF 'TEST_COMPRESS' (Cost=3 Card=10000)
Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 17 consistent gets 0 physical reads 0 redo size 379 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 1 rows processed
压缩表的一致性读只有17,较常规表的31大大减少。
压缩表是为数据仓库设计的特性,所以并不适合OLTP系统,在发生更新时,压缩表会因行链接而迅速扩展空间使用。 请看简单测试:
SQL> update test_compress set c1='oracle' where rownum <10;
9 rows updated.
SQL> commit;
Commit complete.
SQL> analyze table test_compress compute statistics;
Table analyzed.
SQL> select table_name,blocks,EMPTY_BLOCKS from user_tables 2 where table_name like 'TEST%';
TABLE_NAME BLOCKS EMPTY_BLOCKS ------------------------------ ---------- ------------ TEST 28 4 TEST_COMPRESS 24 0
具体可以参考wanghai 的文章: compress table http://wzwanghai.spaces.MSN.com/blog/cns!56626E237AFBD116!206.entry
|