Entering content frame

Syntax documentation EXPORT COLUMNS Commands Locate the document in the library structure

You can use this Loader command to control the process for exporting application data from database tables. You can export the values of individual columns of a table.

Prerequisites

You must have access authorization for the table(s) from which you want to export data.

Syntax

<export_columns_command> ::= EXPORT COLUMNS
  <select_expression>
  [MAP COLUMNS <output_column_list>]
  <data_outstream_spec> [<longfile_spec>...]

<select_expression>

SELECT Statement

MAP COLUMNS <output_column_list>

Description of the columns to be exported

<output_column_list>

 <output_column>
|<output_column> <output_column_list>

<output_column>

Output Column

<data_outstream_spec>

DATA <outstream_spec>

<outstream_spec>

Data Stream

<longfile_spec>

Exporting and Importing LONG Values

Examples

Example

EXPORT COLUMNS cno, title, name, firstname
  FROM hotel.customer ORDER BY name
  MAP COLUMNS
    name       1
    firstname  2
    title      3
    cno        4
  DATA OUTSTREAM FILE 'customer.data' COMPRESSED

The specified columns of the CUSTOMER table are exported.

Example

EXPORT COLUMNS cno, title, name, firstname
  FROM hotel.customer WITH LOCK ISOLATION LEVEL 0
  MAP COLUMNS
    cno        1
    title      2
    name       3
    firstname  4
  DATA OUTSTREAM FILE 'customer.data' COMPRESSED

The specified columns of the CUSTOMER table are exported. In doing so the LOCK option and isolation level 0 are set.

Example

EXPORT COLUMNS * FROM hotel.hotel
  DATA OUTSTREAM FILE 'hotel.data' FORMATTED
  LONG OUTSTREAM FILE info 'hotel_info.data'

All columns of the CUSTOMER table are exported. This is done using the FORMATTED data format.

Example

EXPORT COLUMNS * FROM hotel.room
  MAP COLUMNS
    hno        1-5
    type       6-11
    free       12-31
    price      32-39 REAL IF NULL SET '0'
  DATA OUTSTREAM FILE 'room.data' FORMATTED BINARY
    NULL       '?                   '
    DECIMAL    '///'
    BOOLEAN    'TRUE/FALSE'
    TIMESTAMP  ISO
    DATE       ISO
    TIME       ISO

The specified columns of the ROOM table are exported. This is done using the FORMATTED BINARY data format.

Explanation

You can use the EXPORT COLUMNS command to specify the columns of the table from which you wish to export the application data (DATA). When you do this, you can link several tables and specify a sort order for the exported data.

<select_expression>

You use the syntax rule select_expression to specify which columns in a table are to be exported. The database query is formulated in the same way as a SELECT statement, except the SELECT keyword is not used. All options of a SELECT statement are permitted:

·        Select the result columns and determine their order in the result table

·        Join multiple tables

·        Use qualifications to select result rows

·        Specify sort order

·        Specify locks and isolation level (WITH LOCK, see LOCK Option (lock_option))

<output_column_list>

If you specify the syntax element output_column_list, you describe the columns in a source table that are to be exported (output columns) and how the data records are represented in the data stream.

·        The columns can be in any order in the column description.

·        The column list can only contain columns from the SELECT statement or a subset of them.

·        Values are output only for those columns in the column list. If the column list contains more columns than the SELECT statement, the Loader generates an error and terminates the command.

·        If you want to assign the columns of the source table to fields of the data stream you have to use the keyword MAP COLUMNS.

·        If you have defined the COMPRESSED format for the data stream, the values of the columns to be exported are output in the order in the SELECT statement, and separated with separators.

·        If you have defined the format FORMATTED for the data stream, the values of the columns to be extracted are formatted and output in the order in the SELECT statement. The length of the individual output values depends on the defined sizes of the individual columns in the source table.

·        If the SELECT statement does not contain any column names (EXPORT COLUMNS * FROM ...), the columns are formatted according to the format of the data stream. They are output in the order specified by the database for processing the command.

Result

The application data is exported to the data stream data_outstream_spec and, if appropriate stating the long specification longfile_spec.

The application data can be reconstructed with the corresponding IMPORT command.

Errors

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

See also:

Exporting: Commands

IMPORT TABLE Commands

IMPORT COLUMN Commands

Log File

 

Leaving content frame