小菜毛毛技术分享

与大家共同成长

  BlogJava :: 首页 :: 联系 :: 聚合  :: 管理
  164 Posts :: 141 Stories :: 94 Comments :: 0 Trackbacks
Oracle的Nologging何时生效 与 批量insert加载数据速度(zt)

一 非归档模式下

D:>sqlplus "/ as sysdba"

数据库版本为9.2.0.1.0

SQL*Plus: Release 9.2.0.1.0 - Production on 星期一 8月 14 10:20:39 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.



连接到:
Oracle9i Enterprise Edition Release 9.2.0.1.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.1.0 - Production

当前session产生的redo
SQL> create or replace view redo_size
2 as
3 select value
4 from v$mystat, v$statname
5 where v$mystat.statistic# = v$statname.statistic#
6 and v$statname.name = 'redo size';

视图已建立。

授权给相应数据库schema
SQL> grant select on redo_size to liyong;

授权成功。

SQL> shutdown immediate;
数据库已经关闭。
已经卸载数据库。
ORACLE 例程已经关闭。

SQL> startup mount;
ORACLE 例程已经启动。

Total System Global Area 122755896 bytes
Fixed Size 453432 bytes
Variable Size 88080384 bytes
Database Buffers 33554432 bytes
Redo Buffers 667648 bytes
数据库装载完毕。

非归档模式
SQL> alter database noarchivelog;

数据库已更改。

SQL> alter database open;

数据库已更改。

SQL> create table redo_test as
2 select * from all_objects where 1=2;

表已创建。

SQL> select * from sys.redo_size;

VALUE
----------
59488

SQL> insert into redo_test
2 select * from all_objects;

已创建28260行。

SQL> select * from sys.redo_size;

VALUE
----------
3446080

SQL> insert /*+ append */ into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
3458156

可以看到insert /*+ append */ into方式redo产生很少.
SQL> select 3446080-59488,3458156-3446080 from dual;

3446080-59488 3458156-3446080
------------- ---------------
3386592 12076

将表redo_test置为nologging状态.
SQL> alter table redo_test nologging;

表已更改。

SQL> select * from sys.redo_size;

VALUE
----------
3460052

SQL> insert into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
6805876

SQL> insert /*+ append */ into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
6818144

非归档模式下表的nologging状态对于redo影响不大
SQL> select 6805876-3460052,6818144-6805876 from dual;

6805876-3460052 6818144-6805876
--------------- ---------------
3345824 12268


结论: 在非归档模式下通过insert /*+ append */ into方式批量加载数据可以大大减少redo产生.

二 归档模式下


SQL> shutdown immediate;
数据库已经关闭。
已经卸载数据库。
ORACLE 例程已经关闭。
SQL> startup mount;
ORACLE 例程已经启动。

Total System Global Area 122755896 bytes
Fixed Size 453432 bytes
Variable Size 88080384 bytes
Database Buffers 33554432 bytes
Redo Buffers 667648 bytes
数据库装载完毕。
SQL> alter database archivelog;

数据库已更改。

SQL> alter database open;

数据库已更改。

SQL> conn liyong
请输入口令:
已连接。


将表redo_test重新置为logging
SQL> alter table redo_test logging;

表已更改。

SQL> select * from sys.redo_size;

VALUE
----------
5172

SQL> insert into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
3351344

SQL> insert /*+ append */ into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
6659932

可以看到在归档模式下,且表的logging属性为true,insert /*+ append */ into这种方式也会纪录大量redo
SQL> select 3351344-5172,6659932-3351344 from dual;

3351344-5172 6659932-3351344
------------ ---------------
3346172 3308588


将表置为nologging

SQL> alter table redo_test nologging;

表已更改。

SQL> select * from sys.redo_size;

VALUE
----------
6661820

SQL> insert into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
10008060

SQL> insert /*+ append */ into redo_test
2 select * from all_objects;

已创建28260行。

SQL> commit;

提交完成。

SQL> select * from sys.redo_size;

VALUE
----------
10022852

可以发现在归档模式,要设置表的logging属性为false,才能通过insert /*+ append */ into大大减少redo产生.
SQL> select 10008060-6661820,10022852-10008060 from dual;

10008060-6661820 10022852-10008060
---------------- -----------------
3346240 14792

结论: 在归档模式下,要设置表的logging属性为false,
才能通过insert /*+ append */ into大大减少redo.

三 下面我们再看一下在归档模式下,几种批量insert操作的效率对比.

redo_test表有45W条记录

SQL> select count(*) from redo_test;

COUNT(*)
----------
452160


1 最常见的批量数据加载 25秒

SQL> create table insert_normal as
2 select * from redo_test where 0=2;

表已创建。

SQL> set timing on

SQL> insert into insert_normal
2 select * from redo_test;

已创建452160行。

提交完成。
已用时间: 00: 00: 25.00


2 使用insert /*+ append */ into方式(这个的原理可以参见<<批量DML操作优化建议.txt>>),但纪录redo. 17.07秒
SQL> create table insert_hwt
2 as
3 select * from redo_test where 0=2;

表已创建。
SQL> insert /*+ append */ into insert_hwt
2 select * from redo_test;

已创建452160行。

提交完成。
已用时间: 00: 00: 17.07


3 使用insert /*+ append */ into方式,且通过设置表nologging不纪录redo.

SQL> create table insert_hwt_with_nologging nologging
2 as
3 select * from redo_test where 2=0;

表已创建。

/*
或者通过
alter table table_name nologging设置
*/

SQL> insert /*+ append */ into insert_hwt_with_nologging 11.03秒
2 select * from redo_test;

已创建452160行。

提交完成。
已用时间: 00: 00: 11.03

总结:

我们看到对于批量操作,如果设置表nologging,可以大大提高性能.原因就是Oracle没有纪录DML所产生的redo.
当然,这样会影响到备份。nologging加载数据后要做数据库全备.

jolly10 发表于:2008.03.18 13:19 ::分类: ( 转载学习内容 ) ::阅读:(1097次) :: 评论 (3) :: 引用 (0)
re: Oracle的Nologging何时生效 与 批量insert加载数据速度(zt) [回复]

下面我又试了试insert into XXX values (XXX)能不能少产生redo,做了试验发现,不行的,下面的过程.
SQL> select * from v$version where rownum archive log list;
Database log mode No Archive Mode
Automatic archival Disabled
Archive destination USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence 17
Current log sequence 19

SQL> create or replace view redo_size
2 as
3 select value
4 from v$mystat, v$statname
5 where v$mystat.statistic# = v$statname.statistic#
6 and v$statname.name = 'redo size';

View created.

SQL> grant select on redo_size to ljg;

SQL> conn ljg/ljg
Connected.

SQL> create table redo_test as
2 select * from all_objects where 1=2;

SQL> CREATE OR REPLACE PROCEDURE p_loging
2 as
3 CURSOR c_a IS
4 SELECT * FROM all_objects;
5
6 BEGIN
7 FOR x IN c_a LOOP
8 INSERT INTO REDO_TEST
9 VALUES(x.OWNER, x.OBJECT_NAME, x.SUBOBJECT_NAME, x.OBJECT_ID, x.DATA_OBJE CT_ID,
10 x.OBJECT_TYPE, x.CREATED, x.LAST_DDL_TIME, x.TIMESTAMP, x.STATUS, x.TEMPORARY, x.GENERATED, x.SECONDARY);
11 END LOOP;
12 COMMIT;
13
14 END;
15 /

Procedure created.

SQL> CREATE OR REPLACE PROCEDURE p_nologing
2 as
3 CURSOR c_a IS
4 SELECT * FROM all_objects;
5
6 BEGIN
7 FOR x IN c_a LOOP
8 INSERT /*+ APPEND */ INTO REDO_TEST
9 VALUES(x.OWNER, x.OBJECT_NAME, x.SUBOBJECT_NAME, x.OBJECT_ID, x.DATA_OBJECT_ID,
10 x.OBJECT_TYPE, x.CREATED, x.LAST_DDL_TIME, x.TIMESTAMP, x.STATUS, x.TEMPORARY, x.GENERATED, x.SECONDARY);
11 END LOOP;
12 COMMIT;
13
14 END;
15 /

Procedure created.

SQL> select * from sys.redo_size;

VALUE
----------
85940

SQL> exec p_loging;

PL/SQL procedure successfully completed.

SQL> select * from sys.redo_size;

VALUE
----------
15273968

SQL> exec p_nologing;

PL/SQL procedure successfully completed.

SQL> select * from sys.redo_size;

VALUE
----------
30411272

SQL> select 15273968- 85940 logging,30411272-15273968 nologging from dual;

LOGGING NOLOGGING
---------- ----------
15188028 15137304

可以看到nologging和logging产生的redo差不多.

jolly10 评论于:2008.06.05 11:07
re: Oracle的Nologging何时生效 与 批量insert加载数据速度(zt) [回复]

下面我又试了试insert into XXX values (XXX)能不能少产生redo,做了试验发现,不行的,下面的过程.
SQL> select * from v$version where rownum archive log list;
Database log mode No Archive Mode
Automatic archival Disabled
Archive destination USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence 17
Current log sequence 19

SQL> create or replace view redo_size
2 as
3 select value
4 from v$mystat, v$statname
5 where v$mystat.statistic# = v$statname.statistic#
6 and v$statname.name = 'redo size';

View created.

SQL> grant select on redo_size to ljg;

SQL> conn ljg/ljg
Connected.

SQL> create table redo_test as
2 select * from all_objects where 1=2;

SQL> CREATE OR REPLACE PROCEDURE p_loging
2 as
3 CURSOR c_a IS
4 SELECT * FROM all_objects;
5
6 BEGIN
7 FOR x IN c_a LOOP
8 INSERT INTO REDO_TEST
9 VALUES(x.OWNER, x.OBJECT_NAME, x.SUBOBJECT_NAME, x.OBJECT_ID, x.DATA_OBJE CT_ID,
10 x.OBJECT_TYPE, x.CREATED, x.LAST_DDL_TIME, x.TIMESTAMP, x.STATUS, x.TEMPORARY, x.GENERATED, x.SECONDARY);
11 END LOOP;
12 COMMIT;
13
14 END;
15 /

Procedure created.

SQL> CREATE OR REPLACE PROCEDURE p_nologing
2 as
3 CURSOR c_a IS
4 SELECT * FROM all_objects;
5
6 BEGIN
7 FOR x IN c_a LOOP
8 INSERT /*+ APPEND */ INTO REDO_TEST
9 VALUES(x.OWNER, x.OBJECT_NAME, x.SUBOBJECT_NAME, x.OBJECT_ID, x.DATA_OBJECT_ID,
10 x.OBJECT_TYPE, x.CREATED, x.LAST_DDL_TIME, x.TIMESTAMP, x.STATUS, x.TEMPORARY, x.GENERATED, x.SECONDARY);
11 END LOOP;
12 COMMIT;
13
14 END;
15 /

Procedure created.

SQL> select * from sys.redo_size;

VALUE
----------
85940

SQL> exec p_loging;

PL/SQL procedure successfully completed.

SQL> select * from sys.redo_size;

VALUE
----------
15273968

SQL> exec p_nologing;

PL/SQL procedure successfully completed.

SQL> select * from sys.redo_size;

VALUE
----------
30411272

SQL> select 15273968- 85940 logging,30411272-15273968 nologging from dual;

LOGGING NOLOGGING
---------- ----------
15188028 15137304

可以看到nologging和logging产生的redo差不多.

jolly10 评论于:2008.06.05 11:07
re: Oracle的Nologging何时生效 与 批量insert加载数据速度(zt) [回复]

在ITPUB中问到可以用BULK COLLECT 来减少insert into values的redo.
CREATE OR REPLACE PROCEDURE p_BulkAdd
AS
TYPE Tredo_test IS TABLE OF REDO_TEST%ROWTYPE;
V_REDO_TEST Tredo_test;
BEGIN
SELECT * BULK COLLECT INTO V_REDO_TEST FROM ALL_OBJECTS;
FORALL X IN V_REDO_TEST.FIRST..V_REDO_TEST.LAST
INSERT INTO REDO_TEST VALUES V_REDO_TEST(X);
END;
/

SQL> select * from sys.redo_size;

VALUE
----------
30411272

SQL> exec p_bulkadd;

PL/SQL procedure successfully completed.

SQL> select * from sys.redo_size;

VALUE
----------
35050796

SQL> select 35050796-30411272 from dual;

35050796-30411272
-----------------
4639524

这个做的确是少了很多redo.是一个方法.

posted on 2009-12-18 13:11 小菜毛毛 阅读(6085) 评论(0)  编辑  收藏 所属分类: 数据库

只有注册用户登录后才能发表评论。


网站导航: