测试环境:OS:RHEL 5.4 X86 DB:10.2.0.4 归档模式
下面是测试结论,此结论只是在本测试环境有效。
- 1,ctas与create table后insert语句产生的redo是差不多的。
- 2,ctas生成的undo远远小于create table and insert方式。
- 3,ctas生成的undo与create table后insert /*+ append */差不多。
- 4,ctas nologging方法生成的log远远小于其它的方式。
- 5,append方式并不一定能减少redo的生成,但是肯定能减少undo的生成。
- 6,append减少redo,前提是表在nologging方式下面,注意这里表上面没有索引,append只对表有效,对索引无效。
下面是详细的测试步骤
1,ctas方式生成的undo与redo
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 0
- undo change vector size 0
- SQL> create table scott.test_ctas as select * from dba_objects;
- SQL> /* Formatted on 2013/3/8 22:07:44 (QP5 v5.240.12305.39476) */
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 5794552
- undo change vector size 23812
2,ctas nologging方式生成的undo与redo
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 0
- undo change vector size 0
- SQL> create table scott.test_ctas_nologging nologging as select * from dba_objects;
- Table created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 88576
- undo change vector size 22008
- 这种方式生成的UNDO,REDO的大小都是最好的,
3,普通表与insert生成的undo与redo
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 0
- undo change vector size 0
- SQL> create table scott.test_normal as select * from dba_objects where 1=0;
- Table created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 19848
- undo change vector size 5712
- SQL> insert into scott.test_normal select * from dba_objects;
- 50350 rows created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 5725444
- undo change vector size 208092
4,普通create表与insert append方式生成的redo与undo
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 0
- undo change vector size 0
- SQL> create table scott.test_normal_append as select * from dba_objects where 1=2;
- Table created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 21224
- undo change vector size 6072
- SQL> insert /*+ append */ into scott.test_normal_append select * from dba_objects;
- 50350 rows created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 5771092
- undo change vector size 21072
5,nologging方式的create表与insert append方式生成的undo与redo
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 0
- undo change vector size 0
- SQL> create table scott.test_normal_append_nologging nologging as select * from dba_objects where 1=2;
- Table created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 37568
- undo change vector size 14204
- SQL> insert /*+ append */ into scott.test_normal_append_nologging select * from dba_objects;
- 50351 rows created.
- SQL> SELECT a.name, b.VALUE
- 2 FROM v$sysstat a, v$mystat b
- 3 WHERE a.statistic# = b.statistic#
- 4 AND a.name IN ('redo size', 'undo change vector size');
- NAME VALUE
- ---------------------------------------------------------------- ----------
- redo size 142944
- undo change vector size 46744