?
1、普通裝載?
2、TERMINATED BY WHITESPACE 和 FIELDS TERMINATED BY x'09' 的情況?
??
3、指定不裝載那一列?
5、使用函數(shù)日期的一種表達(dá)TRAILING NULLCOLS的使用?
6、合并多行記錄為一行記錄?
LOAD DATA?
INFILE *?
concatenate 3?--通過(guò)關(guān)鍵字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
?
9、載入有換行符的數(shù)據(jù)
①使用一個(gè)非換行符的字符
②使用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
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
④使用str屬性
?
如何使用 SQL*Loader 工具
我們可以用Oracle的sqlldr工具來(lái)導(dǎo)入數(shù)據(jù)。例如:
sqlldr scott/tiger control=loader.ctl
控制文件(loader.ctl)將加載一個(gè)外部數(shù)據(jù)文件(含分隔符)
load data
infile 'c:\data\mydata.csv'
into table emp
fields terminated by "," optionally enclosed by '"'
(empno, empname, sal, deptno)
10001,"Scott Tiger", 1000, 40
10002,"Frank Naude", 500, 20
下面是一個(gè)指定記錄長(zhǎng)度的示例控制文件。“*” 代表數(shù)據(jù)文件與此文件同名,即在后面使用BEGINDATA段來(lái)標(biāo)識(shí)數(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
Oracle沒(méi)有提供將數(shù)據(jù)導(dǎo)出到一個(gè)文件的工具。但是我們可以用SQL*Plus的select及 format 數(shù)據(jù)來(lái)輸出到一個(gè)文件:
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?
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;
/
LOAD DATA
INFILE *
INTO TABLE load_positional_data
(data1 POSITION(1:5),
?data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
可以用 "SKIP n" 關(guān)鍵字來(lái)指定導(dǎo)入時(shí)可以跳過(guò)多少行數(shù)據(jù)。如:
在導(dǎo)入數(shù)據(jù)到數(shù)據(jù)庫(kù)時(shí),可以修改數(shù)據(jù)。注意,這僅適合于常規(guī)導(dǎo)入,并不適合 direct導(dǎo)入方式.如:
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 *
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) 代表第一個(gè)字符, (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) 來(lái)分隔數(shù)據(jù). 在Oracle8i中可以通過(guò)指定 FILLER 字段實(shí)現(xiàn)。FILLER 字段用來(lái)跳過(guò)、忽略導(dǎo)入數(shù)據(jù)文件中的字段.如:
LOAD DATA
TRUNCATE INTO TABLE T1
FIELDS TERMINATED BY ','
( field1,
? field2 FILLER,
? field3
)
可以使用下面兩個(gè)選項(xiàng)之一來(lái)實(shí)現(xiàn)將多行數(shù)據(jù)導(dǎo)入為一個(gè)記錄:
一般情況下是在導(dǎo)入數(shù)據(jù)文件數(shù)據(jù)后提交的。
也可以通過(guò)指定 ROWS= 參數(shù)來(lái)指定每次提交記錄數(shù)。
1) 一個(gè)簡(jiǎn)單而容易忽略的問(wèn)題是,沒(méi)有對(duì)導(dǎo)入的表使用任何索引和/或約束(主鍵)。如果這樣做,甚至在使用ROWS=參數(shù)時(shí),會(huì)很明顯降低數(shù)據(jù)庫(kù)導(dǎo)入性能。
2) 可以添加 DIRECT=TRUE來(lái)提高導(dǎo)入數(shù)據(jù)的性能。當(dāng)然,在很多情況下,不能使用此參數(shù)。
3) 通過(guò)指定 UNRECOVERABLE選項(xiàng),可以關(guān)閉數(shù)據(jù)庫(kù)的日志。這個(gè)選項(xiàng)只能和 direct 一起使用。
4) 可以同時(shí)運(yùn)行多個(gè)導(dǎo)入任務(wù).
SQLLDR應(yīng)用舉例
?
?
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 列將為空
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
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進(jìn)制數(shù)值
??
3、指定不裝載那一列?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
REPLACE?
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'?
(DEPTNO,??
?FILLER_1 FILLER,??--下面的 "Something Not To Be Loaded" 將不會(huì)被裝載??
?DNAME,??
?LOC?
)?
BEGINDATA?
20,Something Not To Be Loaded,Accounting,"Virginia,USA"??
?
INFILE *?
INTO TABLE DEPT?
REPLACE?
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'?
(DEPTNO,??
?FILLER_1 FILLER,??--下面的 "Something Not To Be Loaded" 將不會(huì)被裝載??
?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),?--這個(gè)字段的開(kāi)始位置在前一字段的結(jié)束位置??
?LOC position(*:29),??
?ENTIRE_LINE position(1:29)?
)?
BEGINDATA?
10Accounting Virginia,USA??
?
INFILE *?
INTO TABLE DEPT?
REPLACE?
(DEPTNO position(1:2),??
?DNAME position(*:16),?--這個(gè)字段的開(kāi)始位置在前一字段的結(jié)束位置??
?LOC position(*:29),??
?ENTIRE_LINE position(1:29)?
)?
BEGINDATA?
10Accounting Virginia,USA??
?
結(jié)果:10 | Accounting Vir?| ginia,USA |?10Accounting Virginia,USA
?
5、使用函數(shù)日期的一種表達(dá)TRAILING NULLCOLS的使用?
LOAD DATA?
INFILE *?
INTO TABLE DEPT
REPLACE
FIELDS TERMINATED BY ','
TRAILING NULLCOLS
INFILE *?
INTO TABLE DEPT
REPLACE
FIELDS TERMINATED BY ','
TRAILING NULLCOLS
--這句的意思是將沒(méi)有對(duì)應(yīng)值的列都置為null
--如果第一行改為 10,Sales,Virginia,1/5/2000,, 就不用TRAILING NULLCOLS了?
(DEPTNO,??
?DNAME "upper(:dname)",?--使用函數(shù)??
?LOC "upper(:loc)",??
?LAST_UPDATED date 'dd/mm/yyyy',?--日期的一種表達(dá)方式。還有'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??
--如果第一行改為 10,Sales,Virginia,1/5/2000,, 就不用TRAILING NULLCOLS了?
(DEPTNO,??
?DNAME "upper(:dname)",?--使用函數(shù)??
?LOC "upper(:loc)",??
?LAST_UPDATED date 'dd/mm/yyyy',?--日期的一種表達(dá)方式。還有'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??
注:可以通過(guò):dname類(lèi)型調(diào)用函數(shù),特別注意date函數(shù)的使用。
?
6、合并多行記錄為一行記錄?
LOAD DATA?
INFILE *?
concatenate 3?--通過(guò)關(guān)鍵字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ù),則可以這樣導(dǎo)入。
?
?
7、使用continueif來(lái)合并記錄行
?
上例可直接使用continueif last= ','來(lái)告訴Oracle如果前一個(gè)數(shù)據(jù)以','結(jié)尾,則這個(gè)附加到上一行
?
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
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選項(xiàng),具體操作見(jiàn)文檔
8、載入每行的行號(hào)??
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
?
LOAD DATA?
INFILE *?
INTO TABLE DEPT?
replace?
(DEPTNORECNUM //載入每行的行號(hào)??
?ENTIRE_LINEPosition(1:1024)
(DEPTNORECNUM //載入每行的行號(hào)??
?ENTIRE_LINEPosition(1:1024)
)?
BEGINDATA?
fsdfasj?????--自動(dòng)分配行號(hào)到DEPTNO字段,此行為1?
fasdjfasdfl?--自動(dòng)遞增,此行為2
BEGINDATA?
fsdfasj?????--自動(dòng)分配行號(hào)到DEPTNO字段,此行為1?
fasdjfasdfl?--自動(dòng)遞增,此行為2
?
9、載入有換行符的數(shù)據(jù)
①使用一個(gè)非換行符的字符
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??
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',則會(huì)在Windows編譯過(guò)程中直接換成換行符,導(dǎo)致無(wú)法轉(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ù)導(dǎo)入時(shí),另外需要每行數(shù)據(jù)長(zhǎng)度都相等。
??
--下面這種方法也一樣
??
--下面這種方法也一樣
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 表示前三位用于說(shuō)明該條記錄的長(zhǎng)度 (但是誰(shuí)告訴我長(zhǎng)度怎么數(shù)的?-_-|||)
?
④使用str屬性
??
可使用str來(lái)定義一個(gè)行結(jié)尾符??
?
計(jì)算以|\r\n 結(jié)束的值:?
select utl_raw.cast_to_raw('|'||chr(13)||chr(10)) from dual;?
結(jié)果 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
可使用str來(lái)定義一個(gè)行結(jié)尾符??
?
計(jì)算以|\r\n 結(jié)束的值:?
select utl_raw.cast_to_raw('|'||chr(13)||chr(10)) from dual;?
結(jié)果 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ù)導(dǎo)入中使用,且最后一個(gè)不用加;另外注意不要有空格
?
10、nullif導(dǎo)入
?
LOAD DATA
INFILE *
INTO TABLE?t1_a
INFILE *
INTO TABLE?t1_a
REPLACE
(DEPTNO position(1:2) integer external nullif DEPTNO='1',
(DEPTNO position(1:2) integer external nullif DEPTNO='1',
?--當(dāng)導(dǎo)入deotno的值為'1'時(shí),則該條記錄不導(dǎo)入
?DNAME position(3:8)
)
BEGINDATA
1 10
20lg
?DNAME position(3:8)
)
BEGINDATA
1 10
20lg
?
注:需要注意的是在前面指定的數(shù)據(jù)類(lèi)型以及后面的引號(hào)!
?
?
?
?
?
?
==========================================================================================================
?
?
Oracle SQL*Loader 使用指南(轉(zhuǎn)載)
?
如何使用 SQL*Loader 工具
我們可以用Oracle的sqlldr工具來(lái)導(dǎo)入數(shù)據(jù)。例如:
sqlldr scott/tiger control=loader.ctl
控制文件(loader.ctl)將加載一個(gè)外部數(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
下面是一個(gè)指定記錄長(zhǎng)度的示例控制文件。“*” 代表數(shù)據(jù)文件與此文件同名,即在后面使用BEGINDATA段來(lái)標(biāo)識(shí)數(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沒(méi)有提供將數(shù)據(jù)導(dǎo)出到一個(gè)文件的工具。但是我們可以用SQL*Plus的select及 format 數(shù)據(jù)來(lái)輸出到一個(gè)文件:
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;
/
?
當(dāng)然你也可以使用第三方工具,如SQLWays ,TOAD for Quest等。
?
?
加載可變長(zhǎng)度或指定長(zhǎng)度的記錄
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,"
INFILE *
INTO TABLE load_delimited_data
FIELDS TERMINATED BY "," OPTIONALLY ENCLOSED BY '"'
TRAILING NULLCOLS
(data1,
?data2
)
BEGINDATA
11111,AAAAAAAAAA
22222,"A,B,C,D,"
?
下面是導(dǎo)入固定位置(固定長(zhǎng)度)數(shù)據(jù)示例:
LOAD DATA
INFILE *
INTO TABLE load_positional_data
(data1 POSITION(1:5),
?data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
?
跳過(guò)數(shù)據(jù)行:
可以用 "SKIP n" 關(guān)鍵字來(lái)指定導(dǎo)入時(shí)可以跳過(guò)多少行數(shù)據(jù)。如:
LOAD DATA
INFILE *
INTO TABLE load_positional_data
SKIP 5? --似乎不行?需要在DOS層級(jí)下操作才有效
(data1 POSITION(1:5),
?data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
INFILE *
INTO TABLE load_positional_data
SKIP 5? --似乎不行?需要在DOS層級(jí)下操作才有效
(data1 POSITION(1:5),
?data2 POSITION(6:15)
)
BEGINDATA
11111AAAAAAAAAA
22222BBBBBBBBBB
?
導(dǎo)入數(shù)據(jù)時(shí)修改數(shù)據(jù):
在導(dǎo)入數(shù)據(jù)到數(shù)據(jù)庫(kù)時(shí),可以修改數(shù)據(jù)。注意,這僅適合于常規(guī)導(dǎo)入,并不適合 direct導(dǎo)入方式.如:
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
)
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ù)導(dǎo)入多個(gè)表:
如:
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
)
?
導(dǎo)入選定的記錄:
如下例: (01) 代表第一個(gè)字符, (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
)
?
導(dǎo)入時(shí)跳過(guò)某些字段:
可用 POSTION(x:y) 來(lái)分隔數(shù)據(jù). 在Oracle8i中可以通過(guò)指定 FILLER 字段實(shí)現(xiàn)。FILLER 字段用來(lái)跳過(guò)、忽略導(dǎo)入數(shù)據(jù)文件中的字段.如:
LOAD DATA
TRUNCATE INTO TABLE T1
FIELDS TERMINATED BY ','
( field1,
? field2 FILLER,
? field3
)
?
導(dǎo)入多行記錄:
可以使用下面兩個(gè)選項(xiàng)之一來(lái)實(shí)現(xiàn)將多行數(shù)據(jù)導(dǎo)入為一個(gè)記錄:
?
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ù)的提交:
一般情況下是在導(dǎo)入數(shù)據(jù)文件數(shù)據(jù)后提交的。
也可以通過(guò)指定 ROWS= 參數(shù)來(lái)指定每次提交記錄數(shù)。
?
提高 SQL*Loader 的性能:
1) 一個(gè)簡(jiǎn)單而容易忽略的問(wèn)題是,沒(méi)有對(duì)導(dǎo)入的表使用任何索引和/或約束(主鍵)。如果這樣做,甚至在使用ROWS=參數(shù)時(shí),會(huì)很明顯降低數(shù)據(jù)庫(kù)導(dǎo)入性能。
2) 可以添加 DIRECT=TRUE來(lái)提高導(dǎo)入數(shù)據(jù)的性能。當(dāng)然,在很多情況下,不能使用此參數(shù)。
3) 通過(guò)指定 UNRECOVERABLE選項(xiàng),可以關(guān)閉數(shù)據(jù)庫(kù)的日志。這個(gè)選項(xiàng)只能和 direct 一起使用。
4) 可以同時(shí)運(yùn)行多個(gè)導(dǎo)入任務(wù).
?
常規(guī)導(dǎo)入與direct導(dǎo)入方式的區(qū)別:
常規(guī)導(dǎo)入可以通過(guò)使用 INSERT語(yǔ)句來(lái)導(dǎo)入數(shù)據(jù)。Direct導(dǎo)入可以跳過(guò)數(shù)據(jù)庫(kù)的相關(guān)邏輯(DIRECT=TRUE),而直接將數(shù)據(jù)導(dǎo)入到數(shù)據(jù)文件中。?
?
?
常規(guī)導(dǎo)入可以通過(guò)使用 INSERT語(yǔ)句來(lái)導(dǎo)入數(shù)據(jù)。Direct導(dǎo)入可以跳過(guò)數(shù)據(jù)庫(kù)的相關(guān)邏輯(DIRECT=TRUE),而直接將數(shù)據(jù)導(dǎo)入到數(shù)據(jù)文件中。?
?
?