With most Loader commands for importing and exporting data, you can specify the external data type and the data format that the relevant field values in the data stream have or should have. The specified data format applies to the columns that have the corresponding internal database data type.
You can also define which separators and delimiters are to be used.
You can specify the data format in import and export commands for the data stream in the syntax element stream_format_spec. This data format then overrides the corresponding value that was set using the SET command.
<stream_format_spec> ::=
<bool_spec> <stream_format_spec>
| <code_spec> <stream_format_spec>
| <date_spec> <stream_format_spec>
| <delimiter_spec> <stream_format_spec>
| <int_spec> <stream_format_spec>
| <null_spec> <stream_format_spec>
| <number_spec> <stream_format_spec>
| <separator_spec> <stream_format_spec>
| <time_spec> <stream_format_spec>
| <timestamp_spec> <stream_format_spec>
| COMPRESSED <stream_format_spec> <usage_spec>
| DDL
| DTL <usage_spec>
| FORMATTED <stream_format_spec> <usage_spec>
| FORMATTED BINARY <stream_format_spec> <usage_spec>
| PAGES <stream_format_spec>
| RECORDS <stream_format_spec>
<bool_spec> |
BOOLEAN '<valVALUE_FOR_TRUE>/<valVALUE_FOR_FALSE>' |
<valVALUE_FOR_TRUE>/ |
Defines the character string for values that are true/false The character strings may have a maximum length of 10 characters. Default value: TRUE/FALSE. |
<code_spec> |
|
<date_spec> |
|
<delimiter_spec> |
DELIMITER '<valDELIMITER>' |
'<valDELIMITER>' |
DELIMITER display You can specify no character or exactly one character that originates from the 7 bit ASCII character set (only 1 byte long). A blank DELIMITER is represented by entering blank single quotation marks (‘ ‘). Default value: double quotation marks (“) |
<int_spec> |
INTEGER HILO | INTEGER LOHI |
INTEGER HILO |
The current data stream stores integers so that the byte with the lowest valency is stored first, that is, is furthest right in the binary number (the big endian). |
INTEGER LOHI |
The current data stream stores integers so that the byte with the highest valency is stored first, that is, the furthest right in the binary number (little endian, byte swap). |
<null_spec> |
NULL '<valLITERAL>' |
<valLITERAL> |
Null value representation; maximum length of 20 characters Default value: ? (a question mark and 19 spaces). |
<number_spec> |
DECIMAL '/[<t>]/<d>/' |
<t> |
Defines the character for structuring thousands Default value: no characters |
<d> |
Defines the character for separating integers from decimal places Default value: decimal point |
<separator_spec> |
SEPARATOR '<valSEPARATOR>' |
<valSEPARATOR> |
Separator for data fields You have to specify exactly one character that originates from the 7 bit ASCII character set (only 1 byte long). Default value: comma (,) |
<time_spec> |
|
<timestamp_spec> |
|
COMPRESSED |
COMPRESSED (CSV, Comma Separated Values) is a format for CHAR data in which a data line must at least be long enough to represent the data. The assignment of a data field of the data stream to a column in the table is determined by the position specification. |
<usage_spec> |
PAGE WITH <valUSAGE> % USAGE Default value: ROW USAGE |
<valUSAGE> |
Positive
integer When specifying the number of rows, the length of individual table records is important. |
DDL |
DATA DEFINITION LANGUAGE is a format that can be specified for a data stream with database catalog data. |
DTL |
DATA TRANSFORMATION LANGUAGE is a format that can be specified in the case of an export of an individual table PACKAGE <outstream_spec>. |
FORMATTED |
FORMATTED (FWV, Fixed Width, Columnar Values) is a format for plain text values in which a data line in the data stream corresponds to a data record. The assignment between data fields in the data stream and table columns is determined by the position specification. |
FORMATTED BINARY |
FORMATTED BINARY (FWV, Fixed Width, Columnar Values) is a format for binary values in which the data fields all have the same fixed length. The assignment between data fields in the data stream and table columns is determined by the position specification. Unlike the FORMATTED format, a data record does not end with an additional line break. |
PAGES |
Format that specifies that the application data is stored in pages |
RECORDS |
Database format |
EXPORT TABLE hotel.room
CATALOG OUTSTREAM FILE ′room.catalog′ DDL
DATA OUTSTREAM FILE ′room.data′ COMPRESSED
SEPARATOR ′,′
DELIMITER ′"′
NULL
′? ′
DECIMAL ′/./,/′
BOOLEAN ′TRUE/FALSE′
TIMESTAMP ISO
DATE ISO
TIME ISO
PACKAGE OUTSTREAM FILE ′room.package′
DTL ROW USAGE
This command generates a package file with the following content:
//
IMPORT TABLE "ROOM" REJECT DUPLICATES
CATALOG INSTREAM FILE 'room.catalog' DDL
DATA INSTREAM FILE
'room.data' COMPRESSED ASCII
SEPARATOR ′,′
DELIMITER ′"′
NULL
′? ′
DECIMAL ′/./,/′
BOOLEAN ′TRUE/FALSE′
TIMESTAMP ISO
DATE ISO
TIME ISO
"HNO" 1 CHAR
"TYPE" 2 CHAR
"FREE" 3 CHAR DEFAULT NULL
"PRICE" 4 CHAR DEFAULT NULL
ROW USAGE
//
The generated data file has the following content (section):
"10","double","45","200.00"
"10","single","20","135.00"
"20","double","13","100.00"
You can use the syntax rule stream_format_spec within a command for exporting and importing data to specify a range of data formats: Some of these formats shall be explained in more detail at this point. If the formats are not specified, the Loader uses the respective default values, which are specified further up in the table.
You use the syntax rule bool_spec to specify the character string that represents the BOOLEAN values in data streams to be unloaded from a database instance or to be loaded into a database instance.
You use the syntax rule delimiter_spec to specify which character is to be used to select application data in data streams with the COMPRESSED format.
If you want to load unselected data, enter a blank DELIMITER in the command.
You use the syntax rule int_spec to define the representation of integers in data streams.
You can only do this for data streams with the FORMATTED BINARY format. This specification is ignored during the export into data streams of the import from data streams in the COMPRESSED format.
If the representation specified for a data stream does not match the current computer, the values are adjusted before being exported to the data stream or imported into the database.
You use the syntax rule null_spec to specify the character string used to represent null values that were loaded from the database instance in data streams.
You use the syntax rule number_spec to specify which characters are to be used in decimal numbers to group thousands and to separate integers from decimal places.
You use the syntax rule separator_spec to specify which character is used to separate data fields in data streams that have the COMPRESSED format.
These are formats of the data stream.
For more explanations and examples for the formats COMPRESSED, FORMATTED, and FORMATTED BINARY, see COMPRESSED, FORMATTED, FORMATTED BINARY.
The database format DTL is only relevant for a package data stream PACKAGE <outstream_spec> . When you export a table you specify that the Loader is to generate an IMPORT command in the package data stream with which the specified table can be imported. You use syntax element usage_spec to specify whether the data is to be formatted as pages during the import or whether it is to be processed as lines with a mass IMPORT. This enables you, for example, to generate an IMPORT command for external data, which imports this data into a correctly defined table.
If you specify the syntax rule PAGE WITH ... for the import the data is entered directly into the table pages of the database and no log entries are written. This enables an additional performance improvement compared to the specification of the syntax rule ROW USAGE.
When you specify the rule ROW USAGE the data is entered into the database as a mass INSERT and log entries are written so that entries can be cancelled if errors occurred.
· You can only use the rule PAGE WITH… if the following prerequisites are met:
· The target table exists in the database instance.
· You have logged on to the Loader with the user who is the owner of the target table.
· The target table does not have an index.
· The target table does not have a LONG column.
· The application data in the data stream to be imported is sorted in ascending order in the sequence of the primary key of the target table.
· If the target table already contains application data, only those data records whose key values are greater than the largest key value in the target table can be inserted.
· You can use the rule PAGE WITH to define to what extent a page in a table is to be filled with data records. To do so, you can specify a percentage between 50 and 100 or define the number of rows (data records) that you want to load to each table page. If you specify a number of rows that exceeds the actual number possible, the Loader displays an error message during the import operation, indicating the maximum number of rows permitted for each table page.
If the table is not modified at all, or only slightly, it is a good idea to utilize the occupied memory by more than 80%.
· If considerable dynamic growth is anticipated for the table, it is a good idea to utilize the occupied memory by less than 80%.
If you use syntax rule PAGE WITH … please consider the following:
· When PAGE WITH is specified no log entries are written, so you must back up the new data after you have imported it. You can either back up the appropriate pages (incremental data backup) or all the data (complete data backup).
· The table is write-protected until you back up the new application data.
See also:
Concepts of the Database System, Backing Up Data