sqlldr批量导入导出数据测试
sqlldr是在处理大数据量的操作中建议采用的方式,它有许多性能想关的开关,能最大程度的减少redo,undo的生成,控制数据的处理方式(insert,append,replace,truncate)
因为项目需要,对比datapump性能还是不理想,所以还是希望采用sqlldr来做。个人做了简单的测试。
根据thomas kyte的介绍,并行执行路径加载时最快的方式,能够直接写只格式化的数据块,最大限度的减少redo,undo的生成。
先写了如下的脚本。可以动态的从某个用户的表中生成元数据。
sqlplus -s $1 <<EOF
set pages 0
col object_name format a30
set linseize 10000
set feedback off
set colsep ','
spool $2.lst
select *from $2 ;
spool off;
EOF
运行后生成的数据大体如下。
[ora11g@rac1 sqlldr]$ ksh spooldata.sh n1/n1 t
370753, 10205,KU$_DOMIDX_OBJNUM_VIEW ,VIEW
370754, 10207,KU$_OPTION_OBJNUM_T ,TYPE
370755, 10208,KU$_EXPREG ,VIEW
370756, 10210,SYS_YOID0000010209$ ,TYPE
370757, 10209,KU$_OPTION_OBJNUM_VIEW ,VIEW
370758, 10211,KU$_OPTION_VIEW_OBJNUM_VIEW ,VIEW
370759, 10212,KU$_MARKER_T ,TYPE
370760, 10214,SYS_YOID0000010213$ ,TYPE
370761, 10213,KU$_MARKER_VIEW ,VIEW
370762, 10215,KU$_TABPROP_VIEW ,VIEW
370763, 10216,KU$_PFHTABPROP_VIEW ,VIEW
370764, 10217,KU$_REFPARTTABPROP_VIEW ,VIEW
370765, 10218,KU$_MVPROP_VIEW ,VIEW
370766, 10219,KU$_MVLPROP_VIEW ,VIEW
370767, 10220,KU$_TTS_VIEW ,VIEW
370768, 10221,KU$_TAB_TS_VIEW ,VIEW
370769, 10222,KU$_TTS_IND_VIEW ,VIEW
370770, 10223,KU$_IND_TS_VIEW ,VIEW
370771, 10224,KU$_CLU_TS_VIEW ,VIEW
然后准备控制文件 sqlldr.ctl,把数据从t加载到tt里面去。
load data
into table tt
fields terminated by ','
(id,object_id,object_name,object_type)
尝试导入:
[ora11g@rac1 sqlldr]$ sqlldr n1/n1 control=sqlldr.ctl data=t.lst
SQL*Loader: Release 11.2.0.3.0 - Production on Tue May 27 08:09:25 2014
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
但是没有任何的反馈。
查看自动生成的sqlldr.log
里面有如下的错误。
Column Name Position Len Term Encl Datatype
------------------------------ ---------- ----- ---- ---- ---------------------
ID FIRST * , CHARACTER
OBJECT_ID NEXT * , CHARACTER
OBJECT_NAME NEXT * , CHARACTER
OBJECT_TYPE NEXT * , CHARACTER
Record 1: Rejected - Error on table TT, column OBJECT_TYPE.
Field in data file exceeds maximum length
Record 2: Rejected - Error on table TT, column OBJECT_TYPE.
Field in data file exceeds maximum length
Record 3: Rejected - Error on table TT, column OBJECT_TYPE.
Field in data file exceeds maximum length
Record 4: Rejected - Error on table TT, column OBJECT_TYPE.
Field in data file exceeds maximum length
尝试了好一会儿,最终发现时set linesize的时候长度设置的比较大,在根据逗号','来解析的时候,最后一个字段的长度就包含了剩余的空格,最终加载的时候就会发现它的长度太大了。已经超出了表定义的长度。
这种情况,我总不能一个一个指定长度吧。
这时候想到trimspool的功能,尝试果然奏效。
spooldata.sh的脚本内容如下:
sqlplus -s $1 <<EOF
set pages 0
col object_name format a30
set linesize 10000
set trimspool on
set feedback off
set colsep ','
spool $2.lst
select *from $2 where rownum<20 ;
spool off;
EOF
再次尝试导入,就没有问题了。
[ora11g@rac1 sqlldr]$ sqlldr n1/n1 control=sqlldr.ctl data=t.lst
SQL*Loader: Release 11.2.0.3.0 - Production on Tue May 27 08:14:44 2014
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
Commit point reached - logical record count 19
到此为止,来开始看看direct方式到底有多大的性能提升
对于将近80万的数据量测试情况如下。
没有采用direct方式的时候,会有一定的频度(默认50条一次)来加载数据,耗时79秒,基本一秒一万条
Commit point reached - logical record count 793480
Commit point reached - logical record count 793544
Commit point reached - logical record count 793608
Commit point reached - logical record count 793672
Commit point reached - logical record count 793736
Commit point reached - logical record count 793800
Commit point reached - logical record count 793864
Commit point reached - logical record count 793928
Commit point reached - logical record count 793992
Commit point reached - logical record count 794056
Commit point reached - logical record count 794120
Commit point reached - logical record count 794184
Commit point reached - logical record count 794248
Commit point reached - logical record count 794312
Commit point reached - logical record count 794369
但是使用了direct=true的时候,速度明显提升,而且输出也很简单,就下面一行。耗时8秒,基本一秒10万条数据。
8s
[ora11g@rac1 sqlldr]$ sqlldr n1/n1 direct=true control=sqlldr.ctl data=t.lst
SQL*Loader: Release 11.2.0.3.0 - Production on Tue May 27 07:56:31 2014
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
Load completed - logical record count 794369.
相关推荐
Username -- Oracle数据库名 。Password -- Oracle数据库密码。Servicename -- 是Oracle服务实例名 。用参数控制文件中不指定数据文件更适于自动操作。
Username -- Oracle数据库名 。Password -- Oracle数据库密码。Servicename -- 是Oracle服务实例名 。用参数控制文件中不指定数据文件更适于自动操作。