Entering content frame

Syntax documentation IMPORT TABLE Commands Locate the document in the library structure

You can use the Loader’s IMPORT TABLE command to control the import of application data and/or the corresponding database catalog information of the objects of a user.

You can use another instance of the IMPORT TABLE command and specify the syntax element usage_spec to speed up the import.

Prerequisites

The objects imported with an IMPORT TABLE command belong to the user who is logged on to the database instance at the time of the import.

You have either exported the required data with the corresponding EXPORT command or the data is available in the specified data format.

Syntax

<import_table_command> ::= IMPORT TABLE <table_name>
  
[<duplicates_clause>]
  (<catalog_instream_spec> <data_instream_spec>
  |<catalog_instream_spec>
  |<data_instream_spec>)
  [<package_outstream_spec>]

IMPORT TABLE <table_name>   [<duplicates_clause>]   <catalog_instream_spec>   <data_instream_spec>   [<package_outstream_spec>]

Import of the database catalog and all the application data of a table

IMPORT TABLE <table_name>   <catalog_instream_spec>   [<package_outstream_spec>]

Import of the database catalog of a table

IMPORT TABLE <table_name>   [<duplicates_clause>]   <data_instream_spec>   [<package_outstream_spec>]

Import of all the application data of a table

Another option of the IMPORT TABLE command for the data formats COMPRESSED and FORMATTED is as follows:

<import_table_spec_command> ::= IMPORT TABLE <table_spec>
  
[<duplicates_clause>]
  [<catalog_instream_spec>] 
  <data_instream_spec> <load_column_spec>... [<longfile_spec>...]
  [<usage_spec>]
  [<package_outstream_spec>]

<table_name>

Table Description

<table_spec>

Table Description

<duplicates_clause>

This syntax element cannot be selected if the data is imported as table pages (PAGE). Possible values

REJECT DUPLICATES
| IGNORE DUPLICATES
| UPDATE DUPLICATES

Default value: REJECT DUPLICATES

<catalog_instream_spec>

CATALOG <instream_spec>

<data_instream_spec>

DATA <instream_spec>

<package_outstream_spec>

PACKAGE <outstream_spec>

<instream_spec>
<outstream_spec>

Data Stream

<load_column_spec>

Column Description

<longfile_spec>

Exporting and Importing LONG Values
This syntax element cannot be selected if the data is imported as table pages (PAGE).

<usage_spec>

  PAGE WITH <valUSAGE> % USAGE
| PAGE WITH <valUSAGE> ROWS USAGE
| ROW USAGE

Default value: ROW USAGE

<valUSAGE>

Positive integer
If a percentage rate is specified this number has to be between 50 and 100.
Default value: 80

When specifying the number of rows, the length of individual table records is important.

Examples

Example

IMPORT TABLE hotel.reservation
UPDATE DUPLICATES
  CATALOG INSTREAM FILE 'reservation.catalog' DDL
  DATA INSTREAM FILE 'reservation.data' RECORDS
  PACKAGE OUTSTREAM FILE 'reservation_import.package' COMPRESSED

The application data of table RESERVATION is imported and an existing row is overwritten with the imported data record.

Example

IMPORT TABLE hotel.room
  CATALOG INSTREAM FILE ′room.catalog′ DDL
  DATA INSTREAM FILE ′room.data′ PAGES
  PACKAGE OUTSTREAM FILE ′room_import.package′ COMPRESSED

The database catalog and application data are imported into the blank table ROOM. The application data is read from the data stream in the PAGES data format and imported into the table in the PAGES format.

Example

IMPORT TABLE hotel.room
  CATALOG INSTREAM FILE 'room.catalog' DDL
  DATA INSTREAM FILE 'room.data' COMPRESSSED
    SEPARATOR ','
    DELIMITER '"'
    NULL      '?                   '
    DECIMAL   '//./'
    BOOLEAN   'TRUE/FALSE'
    TIMESTAMP ISO
    DATE      ISO
    TIME      ISO
  PAGE WITH 80 % USAGE
  PACKAGE OUTSTREAM FILE 'room_import.data' COMPRESSED

The database catalog and application data are imported into the blank table ROOM. The application data is read from the data stream in the COMPRESSED data format and imported into the database in the PAGES format with a fill level of 80 %.

Explanation

<catalog_instream_spec>, <data_instream_spec>

Depending on whether database catalog and/or application data is imported, the following data streams are required for the import:

·        Data stream with database catalog information: CATALOG <instream_spec>

·        Data stream with application data: DATA <instream_spec>

<duplicates_clause>

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 in the PAGES data format.

REJECT DUPLICATES

The new line is rejected with an error message.

IGNORE DUPLICATES

The new line is not inserted.

UPDATE DUPLICATES

The new line overwrites the existing line.

<usage_spec>

You can use the syntax rule usage_spec to specify whether data that is available in the COMPRESSED or FORMATTED format is to be imported via table pages (PAGE) or a mass INSERT (ROW). For more information see the Explanations of the  Data Formats.

Note

The performance of the import of sorted application data into a table can be controlled using usage_spec , if the table definition of the target table meets certain prerequisites. If you select PAGE WITH ... the data is entered directly into the table pages of the database instance and no log entries are written. This enables an additional performance improvement compared to the selection of ROW USAGE.

<package_outstream_spec>

You can export system table SYSLOADER.TRANSFORMATIONMODEL.

·        By specifying a data stream PACKAGE <outstream_spec> all entries of the table SYSLOADER.TRANSFORMATIONMODEL are exported to this data stream. We recommend you use this option to log the import process well.

·        If you do not specify data stream PACKAGE <outstream_spec> the system table SYSLOADER.TRANSFORMATIONMODEL is not exported.

Result

The application data and/or the database catalog are imported into the data_instream_spec and catalog_instream_spec data streams.

If necessary, all entries in the table SYSLOADER.TRANSFORMATIONMODEL are exported to the package_outstream_spec data stream.

Errors

The import cannot be completed successfully. In this case, the Loader logs the cause of the error in the log file.

The values PACKAGEGUID and CLIENTNODE are also written to the log file. The PACKAGEGUID is required if you want to restart the import.

See also:

Importing: Commands

EXPORT TABLE Commands

Log File

System Tables

 

Leaving content frame