Entering content frame

Procedure documentation Importing and Exporting LONG Values Locate the document in the library structure

You can use IMPORT/EXPORT TABLE and EXPORT/UPDATE COLUMNS commands to import LONG values to a target table, export them from a data stream or modify the LONG values in a table. Use the syntax rule longfile_spec to define the columns in a target table to which you want to import LONG values, or to specify from which data source you want to export them.

Syntax

<longfile_spec> ::=
  LONGFILE (<valCOLUMN_ID> | <valCOLUMN_NAME>) <longfile_code_spec>
| LONGFILE (<valCOLUMN_ID> | <valCOLUMN_NAME>) '<valFILE_NAME>' [<longfile_code_spec>]

<valCOLUMN_ID>

Column ID

<valCOLUMN_NAME>

Name of Column

<longfile_code_spec>

Code Specification

<valFILE_NAME>

Name and path of the data stream

Examples

Example

EXPORT TABLE hotel.hotel
  DATA OUTSTREAM FILE 'hotel.data'
  LONGFILE info 'hotel_info.data'

The information of the LONG columns is exported to the data stream hotel_info.data .

Explanation

The data for LONG values is stored separately from the other data in LONG data streams. These data streams are specified with the syntax rule longfile_spec. No media name can be used after the keyword LONGFILE.

If, when you are exporting LONG values, you specify more LONG data streams than there are LONG output columns in the column list, the Loader ignores the surplus LONG data streams.

·        The first syntax rule relates to exporting/importing in cases where each LONG value of a column is in a separate LONG data stream.

·        The other rule relates to exporting/importing in cases where all LONG values of a column are in one LONG data stream.

Exporting LONG Values

You can use all variants of the syntax rule to export the data.

·        Always use a column ID for the LONG column that you want to export even if a column ID is specified in the column list for this column.

·        Use the column name if the column name is specified in the column list.

When you export LONG values, you must distinguish between the following cases:

...

       1.      Each LONG value to be exported to a column is in a separate LONG data stream.

       2.      All LONG values to be exported to a column are in one LONG data stream.

1. Each LONG Value to Be Exported Is in a Separate LONG Data Stream.

In the command for exporting data, you specify the name of the LONG data stream with a number of placeholders for sequential numbering of the generated LONG data streams for each LONG column that you want to export.

If the LONG column you want to export has no value in a data record (the value is an empty character string), an empty LONG data stream is generated for this LONG value.

Using the unique media name generated in this way, the individual LONG data streams are assigned to the corresponding data record in the target table.

Note

Use a sufficient number of numeric characters at the end of the media name as a placeholder. If the upper limit is reached while the data is being exported, but there are still values left to be unloaded, the Loader generates an error message and terminates the command.

Example

EXPORT TABLE hotel.hotel
  DATA OUTSTREAM FILE 'hotel.data'
  LONGFILE info 'hotel_info.data###'

The Loader generates the data stream with the name hotel_info.data.001 for the first LONG value to be exported, the data stream hotel_info.data.002 for the second, and so on.
Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","hotel_info.data001"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","hotel_info.data002"

2. All Long Values to Be Exported Are in One Long Data Stream

In the command for exporting data, you specify the name of a data stream for each LONG column, into which each of the LONG values of this LONG column to be exported are entered.

If the LONG column you want to export has no value in a data record (the value is an empty character string), the position specification for this LONG value is generated as follows: the start position is the end position of the preceding LONG value in the column plus 1; the end position is the end position of the preceding LONG value in the column. This means that the start position is always one value larger than the end position.

The start and end position of the generated LONG value in the data stream enable the LONG values to be assigned to data records.

Example

EXPORT TABLE hotel.hotel
  DATA OUTSTREAM FILE 'hotel.data'
  LONGFILE info 'hotel_info.data'

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","1-994"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","995-1157"

Importing LONG Values

When you import LONG values, you can only use the LONGFILE <valCOLUMN_NAME>  '<valFILE_NAME>' syntax rule, since you can only use column names in the import command, and not column IDs.

When you import LONG values, you must distinguish between the following cases:

       3.      Each LONG value to be imported is in a separate LONG data stream.

       4.      All LONG values to be exported are in one LONG data stream.

1. Each LONG Value to Be Imported Is in a Separate LONG Data Stream

In the data stream, you specify the names of the data streams that contain the LONG values instead of the column values (if necessary, also entering position specifications). The entire data streams or parts of them are loaded as LONG values.

Example

The complete data stream is loaded as a LONG value.

IMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

Content of the data stream:

10","Congress","20005","155 Beechwood Str.","hotel_info.data001"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","hotel_info.data002"

ExampleParts of the data stream are imported as LONG values.

IMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","'hotel_info.data001' 1-915"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","'hotel_info.data002' 1-159"

2. All LONG Values to Be Imported Are in One LONG Data Stream

Variant 1

In the data stream, you specify the name of the data stream containing the LONG values with the start and end position of the LONG value to be imported, instead of a column value.

ExampleIMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","'hotel_info.data' 1-915"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","'hotel_info.data' 916-1074"

Variant 2

You specify the name of the data stream that contains the LONG values after the keyword LONGFILE. In the data stream itself, specify only the position specifications. Do not enter the data stream name as a prefix.

ExampleIMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

  LONGFILE info 'hotel_info.data'

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","1-915"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","916-1074"

<longfile_code_spec>

You can also specify a code attribute in the IMPORT command for all data streams that contain LONG values that are to be loaded by specifying the syntax rule longfile_code_spec . You can only enter a single code attribute for all data streams. You cannot specify a code attribute for each individual data stream that is specified.

ExampleSpecifying the code attribute ASCII

IMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

  LONGFILE info ASCII

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","'hotel_info.data001'"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","'hotel_info.data002'"

ExampleSpecifying the code attribute ASCII

IMPORT TABLE hotel.hotel
  UPDATE DUPLICATES
  DATA INSTREAM FILE 'hotel.data'
    hno      1
    name     2
    zip      3
    address  4
    info     5 CHAR DEFAULT NULL

  LONGFILE info 'hotel_info.data' ASCII

Content of the data stream:

"10","Congress","20005","155 Beechwood Str.","1-915"
"20","Long Island","11788","1499 Grove Street","?"
"30","Regency","20037","477 17th Avenue","916-1074"

 

Leaving content frame