SQL*Loader應用舉例
?
??? 昨天學習了基本的SQL*Loader操作知識,所以今天專門找了一些例子,自己測試了一下。以下的所有例子都經(jīng)過測試是可以正確實施的,不過使用這個東西的入門很簡單,但是命令的內(nèi)容卻非常多樣化,需要多實踐才能掌握其精髓,不過在同構的環(huán)境下確實比較少有這樣的機會。
1、普通裝載
?
?
LOAD DATA
INFILE *
INTO TABLE DEPT
REPLACE
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'?
(DEPTNO,
?DNAME,
?LOC
)
BEGINDATA
10,Sales,"""USA"""
20,Accounting,"Virginia,USA"
30,Consulting,Virginia
40,Finance,Virginia
50,"Finance","",Virginia --loc 列將為空
60,"Finance",,Virginia ? --loc 列將為空
注:BEGINDATA后的數(shù)值前面不能有空格
?
2、TERMINATED BY WHITESPACE 和 FIELDS TERMINATED BY x'09' 的情況
?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
REPLACE?
FIELDS TERMINATED BY WHITESPACE?
--FIELDS TERMINATED BY x'20'?
(DEPTNO,?
?DNAME,?
?LOC?
)?
BEGINDATA?
10 Sales Virginia
?
注:x'20'表示字符ASCII碼的16進制數(shù)值
?
3、指定不裝載那一列?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
REPLACE?
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'?
(DEPTNO,?
?FILLER_1 FILLER, ?--下面的 "Something Not To Be Loaded" 將不會被裝載?
?DNAME,?
?LOC?
)?
BEGINDATA?
20,Something Not To Be Loaded,Accounting,"Virginia,USA"?
?
4、position的列子
?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
REPLACE?
(DEPTNO position(1:2),?
?DNAME position(*:16), --這個字段的開始位置在前一字段的結束位置?
?LOC position(*:29),?
?ENTIRE_LINE position(1:29)?
)?
BEGINDATA
10Accounting Virginia,USA?
?
結果:10 | Accounting Vir | ginia,USA | 10Accounting Virginia,USA
?
5、使用函數(shù)日期的一種表達TRAILING NULLCOLS的使用?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT
REPLACE
FIELDS TERMINATED BY ','
TRAILING NULLCOLS
--這句的意思是將沒有對應值的列都置為null
--如果第一行改為 10,Sales,Virginia,1/5/2000,, 就不用TRAILING NULLCOLS了?
(DEPTNO,?
?DNAME "upper(:dname)", --使用函數(shù)?
?LOC "upper(:loc)",?
?LAST_UPDATED date 'dd/mm/yyyy', --日期的一種表達方式。還有'dd-mon-yyyy'等
?ENTIRE_LINE ":deptno||:dname||:loc||:last_updated"?
)?
BEGINDATA?
10,Sales,Virginia,1/5/2000?
20,Accounting,Virginia,21/6/1999?
30,Consulting,Virginia,5/1/2000?
40,Finance,Virginia,15/3/2001?
?
注:可以通過:dname類型調(diào)用函數(shù),特別注意date函數(shù)的使用。
?
6、
合并多行記錄為一行記錄
?
LOAD DATA?
INFILE *?
concatenate 3 --通過關鍵字concatenate 把幾行的記錄看成一行記錄?
INTO TABLE DEPT?
replace?
FIELDS TERMINATED BY ','?
(DEPTNO,?
?DNAME "upper(:dname)",?
?LOC "upper(:loc)",?
?LAST_UPDATED date 'dd/mm/yyyy'
)?
BEGINDATA?
10,Sales,
Virginia,
1/5/2000
?
注:例如有些文本文件以N行為一循環(huán)記錄數(shù)據(jù),則可以這樣導入。
?
?
7、使用continueif來合并記錄行
?
上例可直接使用continueif last= ','來告訴Oracle如果前一個數(shù)據(jù)以','結尾,則這個附加到上一行
?
LOAD DATA?
INFILE *?
continueif last= ','
INTO TABLE DEPT?
replace?
FIELDS TERMINATED BY ','?
(DEPTNO,?
?DNAME "upper(:dname)",?
?LOC "upper(:loc)",?
?LAST_UPDATED date 'dd/mm/yyyy'
)?
BEGINDATA?
10,Sales,
Virginia,
1/5/2000
?
注:ContinueIf還可以使用this或next選項,具體操作見文檔
8、載入每行的行號?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
replace?
(DEPTNORECNUM //載入每行的行號?
?ENTIRE_LINEPosition(1:1024)
)?
BEGINDATA?
fsdfasj ??? --自動分配行號到DEPTNO字段,此行為1?
fasdjfasdfl --自動遞增,此行為2
?
9、載入有換行符的數(shù)據(jù)
①使用一個非換行符的字符
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
REPLACE?
FIELDS TERMINATED BY ','?
TRAILING NULLCOLS?
(DEPTNO,?
DNAME "upper(:dname)",?
LOC "upper(:loc)",?
LAST_UPDATED "my_to_date( :last_updated )",?
COMMENTS "replace(:comments,'%%',chr(10))" --用replace函數(shù)轉(zhuǎn)換成換行符?
)?
BEGINDATA?
10,Sales,Virginia,01-april-2001,This is the Sales%%Office in Virginia?
20,Accounting,Virginia,13/04/2001,This is the Accounting%%Office in Virginia?
30,Consulting,Virginia,14/04/2001 12:02:02,This is the Consulting%%Office in Virginia?
40,Finance,Virginia,987268297,This is the Finance%%Office in Virginia?
注:換行的特殊字符如果使用'\n',則會在Windows編譯過程中直接換成換行符,導致無法轉(zhuǎn)換
?
②使用fix屬性
Load DATA?
INFILE demo1.dat "fix 68"?
INTO TABLE t1_a?
REPLACE?
FIELDS TERMINATED BY ','?
TRAILING NULLCOLS?
(DEPTNO,?
DNAME "upper(:dname)",?
LOC "upper(:loc)",?
LAST_UPDATED Date 'dd/mm/yyyy',
ENTIRE_LINE?
)
demo1.dat?
10,aaaab,Virginia,01/05/2001,This is the aaaab
Office in Virginia
20,aaaac,Virginia,13/04/2001,This is the aaaac
Office in Virginia
30,aaaad,Virginia,14/04/2001,This is the aaaad
Office in Virginia
40,aaaae,Virginia,16/02/2001,This is the aaaae
Office in Virginia
?
注:fix只能加在外部文件數(shù)據(jù)導入時,另外需要每行數(shù)據(jù)長度都相等。
?
--下面這種方法也一樣
Load DATA?
INFILE demo17.dat "fix 70"?
INTO TABLE t1_a?
REPLACE?
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'?
TRAILING NULLCOLS?
(DEPTNO,?
?DNAME "upper(:dname)",?
?LOC "upper(:loc)",?
?LAST_UPDATED Date 'dd/mm/yyyy',
?ENTIRE_LINE?
)
demo2.dat?
10,aaaab,Virginia,01/05/2001,"This is the aaaab
Office in Virginia"
20,aaaac,Virginia,13/04/2001,"This is the aaaac
Office in Virginia"
30,aaaad,Virginia,14/04/2001,"This is the aaaad
Office in Virginia"
40,aaaae,Virginia,16/02/2001,"This is the aaaae
Office in Virginia"
③ 使用var屬性
Load DATA?
INFILE demo17.dat "var 3"?
INTO TABLE t1_a?
REPLACE?
FIELDS TERMINATED BY ','
TRAILING NULLCOLS?
(DEPTNO,?
?DNAME "upper(:dname)",?
?LOC "upper(:loc)",?
?LAST_UPDATED Date 'dd/mm/yyyy',
?ENTIRE_LINE?
)
demo17.dat?
03510,Sales,Virginia,01/01/2001,This
03920,Accounting,Virginia,13/04/2001,Thi
04530,Consulting,Virginia,14/04/2001,This is t
07140,Finance,Virginia,14/04/2001,This is the Finance Office
in Virginia
?
注:var 3 表示前三位用于說明該條記錄的長度 (但是誰告訴我長度怎么數(shù)的?-_-|||)
?
④使用str屬性
可使用str來定義一個行結尾符?
?
計算以|\r\n 結束的值:?
select utl_raw.cast_to_raw('|'||chr(13)||chr(10)) from dual;?
結果 7C0D0A
?
Load DATA?
INFILE demo17.dat "str X'7C0D0A'"?
INTO TABLE t1_a?
REPLACE?
FIELDS TERMINATED BY ','?
TRAILING NULLCOLS?
(DEPTNO,?
?DNAME "upper(:dname)",?
?LOC "upper(:loc)",?
?LAST_UPDATED Date 'dd/mm/yyyy',
?ENTIRE_LINE?
)?
demo17.dat?
10,Sales,Virginia,01/01/2001,This is the Sales?
Office in Virginia|
20,Accounting,Virginia,13/04/2001,This is the Accounting?
Office in Virginia|
30,Consulting,Virginia,14/04/2001,This is the Consulting?
Office in Virginia|
40,Finance,Virginia,14/04/2002,This is the Finance?
Office in Virginia
?
注意:同樣需要在外部文件數(shù)據(jù)導入中使用,且最后一個不用加;另外注意不要有空格
?
10、nullif導入
?
LOAD DATA
INFILE *
INTO TABLE t1_a
REPLACE
(DEPTNO position(1:2) integer external nullif DEPTNO='1',
?--當導入deotno的值為'1'時,則該條記錄不導入
DNAME position(3:8)
)
BEGINDATA
1 10
20lg
?
注:需要注意的是在前面指定的數(shù)據(jù)類型以及后面的引號!
?
?
?
?
***********************************************************************************************
Oracle SQL*Loader
使用指南(轉(zhuǎn)載)
如何使用
SQL*Loader
工具
我們可以用
Oracle
的
sqlldr
工具來導入數(shù)據(jù)。例如
:
sqlldr scott/tiger control=loader.ctl
控制文件
(loader.ctl)
將加載一個外部數(shù)據(jù)文件
(
含分隔符
)
loader.ctl
如下
:
load data
infile 'c:\data\mydata.csv'
into table emp
fields terminated by "," optionally enclosed by '"'
(empno, empname, sal, deptno)
?
mydata.csv
如下
:
10001,"Scott Tiger", 1000, 40
10002,"Frank Naude", 500, 20
下面是一個指定記錄長度的示例控制文件。
“*”
代表數(shù)據(jù)文件與此文件同名,即在后面使用
BEGINDATA
段來標識數(shù)據(jù)。
load data
infile *
replace
into table departments
( dept position (02:05) char(4),
deptname position (08:27) char(20)
)
begindata
COSC COMPUTER SCIENCE
ENGL ENGLISH LITERATURE
MATH MATHEMATICS
POLY POLITICAL SCIENCE
?
?
Unloader
這樣的工具
Oracle
沒有提供將數(shù)據(jù)導出到一個文件的工具。但是我們可以用
SQL*Plus
的
select
及
format
數(shù)據(jù)來輸出到一個文件:
set echo off newpage 0 space 0 pagesize 0 feed off head off trimspool on
spool oradata.txt
select col1 || ',' || col2 || ',' || col3
from tab1
where col2 = 'XYZ';
spool off
?
另外,也可以使用使用
UTL_FILE PL/SQL
包處理
:
rem Remember to update initSID.ora, utl_file_dir='c:\oradata' parameter
declare
fp utl_file.file_type;
begin
fp := utl_file.fopen('c:\oradata','tab1.txt','w');
utl_file.putf(fp, '%s, %s\n', 'TextField', 55);
utl_file.fclose(fp);
end;
/
?
當然你也可以使用第三方工具,如
SQLWays ,TOAD for Quest
等。
?
?
加載可變長度或指定長度的記錄
LOAD DATA
INFILE *
INTO TABLE load_delimited_data
FIELDS TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
TRAILING NULLCOLS
(data1,
data2
)
BEGINDATA
11111,AAAAAAAAAA
22222,"A,B,C,D,"
?
下面是導入固定位置(固定長度)數(shù)據(jù)示例:
LOAD DATA
INFILE *
INTO TABLE load_positional_data
(data1 POSITION(1:5),
data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
?
跳過數(shù)據(jù)行:
可以用
"SKIP n"
關鍵字來指定導入時可以跳過多少行數(shù)據(jù)。如:
LOAD DATA
INFILE *
INTO TABLE load_positional_data
SKIP 5? --
似乎不行?需要在
DOS
層級下操作才有效
(data1 POSITION(1:5),
data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
?
導入數(shù)據(jù)時修改數(shù)據(jù):
在導入數(shù)據(jù)到數(shù)據(jù)庫時,可以修改數(shù)據(jù)。注意,這僅適合于常規(guī)導入,并不適合
direct
導入方式
.
如:
LOAD DATA
INFILE *
INTO TABLE modified_data
(rec_no "my_db_sequence.nextval",
region CONSTANT '31',
time_loaded "to_char(SYSDATE, 'HH24:MI')",
data1 POSITION(1:5) ":data1/100",
data2 POSITION(6:15) "upper(:data2)",
data3 POSITION(16:22)"to_date(:data3, 'YYMMDD')"
)
BEGINDATA
11111AAAAAAAAAA991201
22222BBBBBBBBBB990112
?
LOAD DATA
INFILE 'mail_orders.txt'
BADFILE 'bad_orders.txt'
APPEND
INTO TABLE mailing_list
FIELDS TERMINATED BY ","
(addr,
city,
state,
zipcode,
mailing_addr "decode(:mailing_addr, null, :addr, :mailing_addr)",
mailing_city "decode(:mailing_city, null, :city, :mailing_city)",
mailing_state
)
?
?
將數(shù)據(jù)導入多個表:
如
:
LOAD DATA
INFILE *
REPLACE
INTO TABLE emp
WHEN empno != ' '
( empno POSITION(1:4) INTEGER EXTERNAL,
? ename POSITION(6:15) CHAR,
? deptno POSITION(17:18) CHAR,
? mgr POSITION(20:23) INTEGER EXTERNAL
)
INTO TABLE proj
WHEN projno != ' '
( projno POSITION(25:27) INTEGER EXTERNAL,
? empno POSITION(1:4) INTEGER EXTERNAL
)
?
導入選定的記錄:
如下例:
(01)
代表第一個字符
, (30:37)
代表
30
到
37
之間的字符
:
LOAD DATA
INFILE 'mydata.dat' BADFILE 'mydata.bad' DISCARDFILE 'mydata.dis'
APPEND
INTO TABLE my_selective_table
WHEN (01) <> 'H' and (01) <> 'T' and (30:37) = '19991217'
(
region CONSTANT '31',
service_key POSITION(01:11) INTEGER EXTERNAL,
call_b_no POSITION(12:29) CHAR
)
?
導入時跳過某些字段:
可用
POSTION(x:y)
來分隔數(shù)據(jù)
.
在
Oracle8i
中可以通過指定
FILLER
字段實現(xiàn)。
FILLER
字段用來跳過、忽略導入數(shù)據(jù)文件中的字段
.
如:
LOAD DATA
TRUNCATE INTO TABLE T1
FIELDS TERMINATED BY ','
( field1,
? field2 FILLER,
? field3
)
?
導入多行記錄:
可以使用下面兩個選項之一來實現(xiàn)將多行數(shù)據(jù)導入為一個記錄
:
?
CONCATENATE: - use when SQL*Loader should combine the same number of physical records together to form one logical record.
CONTINUEIF - use if a condition indicates that multiple records should be treated as one. Eg. by having a '#' character in column 1.
?
SQL*Loader
數(shù)據(jù)的提交:
一般情況下是在導入數(shù)據(jù)文件數(shù)據(jù)后提交的。
也可以通過指定
ROWS =
參數(shù)來指定每次提交記錄數(shù)。
?
提高
SQL*Loader
的性能:
1)
一個簡單而容易忽略的問題是,沒有對導入的表使用任何索引和
/
或約束
(
主鍵
)
。如果這樣做,甚至在使用
ROWS=
參數(shù)時,會很明顯降低數(shù)據(jù)庫導入性能。
2)
可以添加
DIRECT=TRUE
來提高導入數(shù)據(jù)的性能。當然,在很多情況下,不能使用此參數(shù)。
3)
通過指定
UNRECOVERABLE
選項,可以關閉數(shù)據(jù)庫的日志。這個選項只能和
direct
一起使用。
4)
可以同時運行多個導入任務
.
?
常規(guī)導入與
direct
導入方式的區(qū)別:
常規(guī)導入可以通過使用
INSERT
語句來導入數(shù)據(jù)。
Direct
導入可以跳過數(shù)據(jù)庫的相關邏輯
(DIRECT=TRUE)
,而直接將數(shù)據(jù)導入到數(shù)據(jù)文件中。
?
***********************************************************************************************
?
?