You can use the Loader’s IMPORT COLUMNS command to control the import of application data into a table.
The table exists in the database. Otherwise, it must be created before the IMPORT COLUMNS command is executed.
<import_columns_command > ::=
IMPORT COLUMNS
TABLE <table_spec> [<duplicates_clause>]
<load_column_spec>...
<data_instream_spec>
[<longfile_spec>...]
<table_spec> |
|
<duplicates_clause> |
Possible values REJECT DUPLICATES Default value: REJECT DUPLICATES |
<load_column_spec> |
|
<data_instream_spec> |
DATA <instream_spec> |
<instream_spec> |
|
<longfile_spec> |
IMPORT COLUMNS TABLE hotel.customer
UPDATE DUPLICATES
cno 1-5
CHAR
title 6-25 CHAR
DEFAULT NULL
firstname 26-45 CHAR DEFAULT NULL
name 46-55 CHAR
zip 56-75
CHAR DEFAULT NULL
address 76-100 CHAR
DATA INSTREAM FILE 'customer.data'
FORMATTED
NULL '? '
DECIMAL '//./'
BOOLEAN 'TRUE/FALSE'
TIMESTAMP ISO
DATE ISO
TIME ISO
The specified column values are imported.
IMPORT COLUMNS TABLE hotel.room
UPDATE DUPLICATES
hno 1
CHAR
type 2 CHAR
free 3 CHAR
DEFAULT NULL
price 4 CHAR
DEFAULT NULL
DATA INSTREAM FILE 'room.data'
COMPRESSED
SEPARATOR ','
DELIMITER '"'
NULL '? '
DECIMAL '//./'
BOOLEAN 'TRUE/FALSE'
TIMESTAMP ISO
DATE ISO
TIME ISO
The specified column values are imported.
The Loader generates an internal mass INSERT statement from the IMPORT COLUMNS command and then executes it.
During the import operation, all of the tables modified by this IMPORT COLUMNS command can also be read and changed by other users.
You use the DUPLICATES rule to specify how to proceed when importing data from a data stream if a row with the same key as the new row already exists in the table. This rule is only evaluated if the data is not imported into the database as table pages (PAGES).
REJECT DUPLICATES |
The new row is rejected with an error message. |
IGNORE DUPLICATES |
The new row is not inserted. |
UPDATE DUPLICATES |
The new row overwrites the existing line. |
The data in the data stream has been loaded to the target table(s). All of the changes made to the target table(s) as a result have also been written to the log area of the database instance.
If the import operation cannot be completed successfully, the Loader logs the last row that was successfully inserted in the table, the number of rows inserted, and the number of rows rejected in the log file.
See also: