-- test.dat:
A 3 a b c
B 4 e f g h
C 1 i
D 5 j k l m n
-- test.ctl:
LOAD DATA
INFILE test.dat
INTO TABLE test WHEN col3 <> ''
FIELDS TERMINATED BY X'09' TRAILING NULLCOLS
(col1 POSITION (1), filler1 FILLER,
col3, col2 CONSTANT 1)
INTO TABLE test WHEN col3 <> ''
FIELDS TERMINATED BY X'09' TRAILING NULLCOLS
(col1 POSITION (1), filler1 FILLER,
filler2 FILLER,
col3, col2 CONSTANT 2)
INTO TABLE test WHEN col3 <> ''
FIELDS TERMINATED BY X'09' TRAILING NULLCOLS
(col1 POSITION (1), filler1 FILLER,
filler2 FILLER, filler3 FILLER,
col3, col2 CONSTANT 3)
INTO TABLE test WHEN col3 <> ''
FIELDS TERMINATED BY X'09' TRAILING NULLCOLS
(col1 POSITION (1), filler1 FILLER,
filler2 FILLER, filler3 FILLER, filler4 FILLER,
col3, col2 CONSTANT 4)
INTO TABLE test WHEN col3 <> ''
FIELDS TERMINATED BY X'09' TRAILING NULLCOLS
(col1 POSITION (1), filler1 FILLER,
filler2 FILLER, filler3 FILLER, filler4 FILLER, filler5 FILLER,
col3, col2 CONSTANT 5)
SCOTT@orcl_11g> CREATE TABLE test
2 (col1 VARCHAR2 (1),
3 col2 NUMBER,
4 col3 VARCHAR2 (1))
5 /
Table created.
SCOTT@orcl_11g> HOST SQLLDR scott/tiger CONTROL=test.ctl LOG=test.log
SCOTT@orcl_11g> COLUMN col1 FORMAT A4
SCOTT@orcl_11g> COLUMN col3 FORMAT A4
SCOTT@orcl_11g> SELECT * FROM test ORDER BY col1, col2, col3
2 /
COL1 COL2 COL3
---- ---------- ----
A 1 a
A 2 b
A 3 c
B 1 e
B 2 f
B 3 g
B 4 h
C 1 i
D 1 j
D 2 k
D 3 l
D 4 m
D 5 n
13 rows selected.
SCOTT@orcl_11g>