Imports data into a database table from an external file.
[ INTO ] TABLE [ owner.]table-name ... ( load-specification [, …] ) ... { FROM | USING [ CLIENT ] FILE } { 'filename-string' | filename-variable } [, …] ... [ CHECK CONSTRAINTS { ON | OFF } ] ... [ DEFAULTS { ON | OFF } ] ... [ QUOTES OFF ] ... ESCAPES OFF ... [ FORMAT { ascii | binary | bcp } ] ... [ DELIMITED BY 'string' ] ... [ STRIP { OFF | RTRIM } ] ... [ WITH CHECKPOINT { ON | OFF } ] ... [ BYTE ORDER { NATIVE | HIGH | LOW } ] ... [ LIMIT number-of-rows ] ... [ NOTIFY number-of-rows ] ... [ ON FILE ERROR { ROLLBACK | FINISH | CONTINUE } ] ... [ PREVIEW { ON | OFF } ] ... [ ROW DELIMITED BY 'delimiter-string' ] ... [ SKIP number-of-rows ] ... [ HEADER SKIP number [ HEADER DELIMITED BY 'string' ] ] ... [ WORD SKIP number ] ... [ ON PARTIAL INPUT ROW { ROLLBACK | CONTINUE } ] ... [ IGNORE CONSTRAINT constraint-type [, …] ] ... [ MESSAGE LOG ‘string’ ROW LOG ‘string’ [ ONLY LOG log-what [, …] ] ... [ LOG DELIMITED BY ‘string’ ] load-specification - (back to Syntax) { column-name [ column-spec ] | FILLER ( filler-type ) } column-spec - (back to load-specification) { ASCII ( input-width ) | BINARY [ WITH NULL BYTE ] | PREFIX { 1 | 2 | 4 } | 'delimiter-string' | DATE ( input-date-format ) | DATETIME ( input-datetime-format ) | ENCRYPTED ( data-type ‘key-string’ [, ‘algorithm-string’ ] ) | DEFAULT default-value } [ NULL ( { BLANKS | ZEROS | 'literal', …} ) filler-type - (back to load-specification) { input-width | PREFIX { 1 | 2 | 4 } | 'delimiter-string' } constraint-type - (back to Syntax) { CHECK integer | UNIQUE integer | NULL integer | FOREIGN KEYinteger | DATA VALUE integer | ALL integer } log-what - (back to Syntax) { CHECK | ALL | NULL | UNIQUE | DATA VALUE | FOREIGN KEY | WORD }
To indicate directory paths on Windows, the backslash character \ must be represented by two backslashes. Therefore, the statement to load data from the file c:\temp\input.dat into the Employees table is:
LOAD TABLE Employees FROM 'c:\\temp\\input.dat' ...
The path name is relative to the database server, not to the client application. If you are running the statement on a database server on some other computer, the directory names refers to directories on the server machine, not on the client machine. When loading a multiplex database, use absolute (fully qualified) paths in all file names. Do not use relative path names.
Because of resource constraints, SAP Sybase IQ does not guarantee that all the data can be loaded. If resource allocation fails, the entire load transaction is rolled back. The files are read one at a time, and processed in the order specified in the FROM clause. Any SKIP or LIMIT value only applies in the beginning of the load, not for each file.
The LOAD TABLE FROM clause is deprecated, but may be used to specify a file that exists on the server. This example loads data from the file a.inp on a client computer.
LOAD TABLE t1(c1,c2,filler(30)) USING CLIENT FILE 'c:\\client-data\\a.inp' QUOTES OFF ESCAPES OFF IGNORE CONSTRAINT UNIQUE 0, NULL 0 MESSAGE LOG 'c:\\client-data\\m.log' ROW LOG 'c:\\client-data\\r.log' ONLY LOG UNIQUE
When bulk loading large objects, the USING CLIENT FILE clause applies to both primary and secondary files.
The LOAD TABLE statement can load compressed client and server files in the gzip format only. Any file with an extension ".gz" or ".gzip" is assumed to be a compressed file. Named pipes or secondary files are not supported during a compressed file load. Compressed files and uncompressed files can be specified in the same LOAD TABLE statement. Each compressed file in a load is processed by one thread.
During client-side loads, the IGNORE CONSTRAINT log files are created on the client host and any error while creating the log files causes the operation to roll back.
Client-side bulk loading is supported by Interactive SQL and ODBC/JDBC clients using the Command Sequence protocol. It is not supported by clients using the TDS protocol. For data security over a network, use Transport Layer Security. To control who can use client-side bulk loads, use the secure feature (-sf) server startup switch, the ALLOW_READ_CLIENT_FILE database option, and/or the READCLIENTFILE access control.
Setting CHECK CONSTRAINTS OFF causes SAP Sybase IQ to ignore all check constraint violations. This can be useful, for example, during database rebuilding. If a table has check constraints that call user-defined functions that are not yet created, the rebuild fails unless this option is set to OFF.
The setting for the DEFAULTS option applies to all column DEFAULT values, including AUTOINCREMENT.
With QUOTES ON, column or row delimiter characters can be included in the column value. Leading and ending quote characters are assumed not to be part of the value and are excluded from the loaded data value.
To include a quote character in a value with QUOTES ON, use two quotes. For example, this line includes a value in the third column that is a single quote character:
‘123 High Street, Anytown’, ‘(715)398-2354’,’’’’
With STRIP turned on (the default), trailing blanks are stripped from values before they are inserted. Trailing blanks are stripped only for non-quoted strings. Quoted strings retain their trailing blanks. Leading blank or TAB characters are trimmed only when the setting is ON.
The data extraction facility provides options for handling quotes (TEMP_EXTRACT_QUOTES, TEMP_EXTRACT_QUOTES_ALL, and TEMP_EXTRACT_QUOTE). If you plan to extract data to be loaded into an IQ main store table and the string fields contain column or row delimiter under default ASCII extraction, use the TEMP_EXTRACT_BINARY option for the extract and the FORMAT binary and QUOTES OFF options for LOAD TABLE.
Non-SPACE text found after ending quote character for an enclosed field. SQLSTATE: QTA14 SQLCODE: -1005014L
Single or double quote mark cannot be the 1st character of column delimiter or row terminator with QUOTES option ON. SQLSTATE: QCA90 SQLCODE: -1013090L
For example, these LOAD TABLE load specifications are valid:
LOAD TABLE x( c1, c2 null(blanks), c3 ) FROM 'bcp_file.bcp' FORMAT BCP ...
LOAD TABLE x( c1 encrypted(bigint,'KEY-ONE','aes'), c2, c3 ) FROM 'bcp_file.bcp' FORMAT BCP ...
... DELIMITED BY '\x09' ...
To use the newline character as a delimiter, you can specify either the special combination '\n' or its ASCII value '\x0a'. Although you can specify up to four characters in the column-spec delimiter-string, you can specify only a single character in the DELIMITED BY clause.
With STRIP turned on (the default), SAP Sybase IQ strips trailing blanks from values before inserting them. This is effective only for VARCHAR data. STRIP OFF preserves trailing blanks.
Trailing blanks are stripped only for unquoted strings. Quoted strings retain their trailing blanks. If you do not require blank sensitivity, you can use the FILLER option as an alternative to be more specific in the number of bytes to strip, instead of all the trailing spaces. STRIP OFF is more efficient for SAP Sybase IQ, and it adheres to the ANSI standard when dealing with trailing blanks. (CHAR data is always padded, so the STRIP option only affects VARCHAR data.)
The STRIP option applies only to variable-length non-binary data and does not apply to ASCII fixed-width inserts. For example, assume this schema:
CREATE TABLE t( c1 VARCHAR(3) ); LOAD TABLE t( c1 ',' ) ........ STRIP RTRIM // trailing blanks trimmed LOAD TABLE t( c1 ',' ) ........ STRIP OFF // trailing blanks not trimmed LOAD TABLE t( c1 ASCII(3) ) ... STRIP RTRIM // trailing blanks not trimmed LOAD TABLE t( c1 ASCII(3) ) ... STRIP OFF // trailing blanks trimmed LOAD TABLE t( c1 BINARY ) ..... STRIP RTRIM // trailing blanks trimmed LOAD TABLE t( c1 BINARY ) ..... STRIP OFF // trailing blanks trimmed
Trailing blanks are always trimmed from binary data.
The default setting is OFF. If this clause is set to ON, a checkpoint is issued after successfully completing and logging the statement. If the server fails after a connection commits and before the next checkpoint, the data file used to load the table must be present for the recovery to complete successfully. However, if WITH CHECKPOINT ON is specified, and recovery is subsequently required, the data file need not be present at the time of recovery.
The data files are required, regardless of what is specified for this clause, if the database becomes corrupt and you need to use a backup and apply the current log file.
See also CONVERSION_ERROR Option [TSQL].
You cannot use this option if any input fields contain binary data. With this option, a row terminator causes any missing fields to be set to NULL. All rows must have the same row delimiters, and it must be distinct from all column delimiters. The row and field delimiter strings cannot be an initial subset of each other. For example, you cannot specify “*” as a field delimiter and “*#” as the row delimiter, but you could specify “#” as the field delimiter with that row delimiter.
If a row is missing its delimiters, SAP Sybase IQ returns an error and rolls back the entire load transaction. The only exception is the final record of a file where it rolls back that row and returns a warning message. On Windows, a row delimiter is usually indicated by the newline character followed by the carriage return character. You might need to specify this as the delimiter-string (see above for description) for either this option or FILLER.
If a row is not loaded because a word exceeds the maximum permitted size, a warning is written to the .iqmsg file. WORD size violations can be optionally logged to the MESSAGE LOG file and rejected rows logged to the ROW LOG file specified in the LOAD TABLE statement.
Partial input record skipped at EOF. SQLSTATE: QDC32 SQLSTATE: -1000232L
IGNORE CONSTRAINT NULL 50, UNIQUE 100, ALL 200
The total number of integrity constraint violations cannot exceed 200, whereas the total number of NULL and UNIQUE constraint violations cannot exceed 50 and 100, respectively. Whenever any of these limits is exceeded, the LOAD TABLE statement rolls back.
Set the IGNORE CONSTRAINT option limit to a nonzero value if you are logging the ignored integrity constraint violations. Logging an excessive number of violations affects the performance of the load
If CHECK, UNIQUE, NULL, or FOREIGN KEY is not specified in the IGNORE CONSTRAINT clause, then the load rolls back on the first occurrence of each of these types of integrity constraint violation.
If DATA VALUE is not specified in the IGNORE CONSTRAINT clause, then the load rolls back on the first occurrence of this type of integrity constraint violation, unless the database option CONVERSION_ERROR = OFF. If CONVERSION_ERROR = OFF, a warning is reported for any DATA VALUE constraint violation and the load continues.
When the load completes, an informational message regarding integrity constraint violations is logged in the .iqmsg file. This message contains the number of integrity constraint violations that occurred during the load and the number of rows that were skipped.
The number of rows (errors reported) in the MESSAGE LOG file can exceed the IGNORE CONSTRAINT option limit, because the load is performed by multiple threads running in parallel. More than one thread might report that the number of constraint violations has exceeded the specified limit.
The number of distinct errors in the MESSAGE LOG file might not exactly match the number of rows in the ROW LOG file. The difference in the number of rows is due to the parallel processing of the load described above for the MESSAGE LOG.
Various combinations of the IGNORE CONSTRAINT and MESSAGE LOG options result in different logging actions.
IGNORE CONSTRAINT Specified? |
MESSAGE LOG Specified? |
Action |
---|---|---|
yes | yes | All ignored integrity constraint violations are logged, including the user specified limit, before the rollback. |
no | yes | The first integrity constraint violation is logged before the rollback. |
yes | no | Nothing is logged. |
no | no | Nothing is logged. The first integrity constraint violation causes a rollback. |
Messages corresponding to error or warning conditions which can occur for FORMAT BCP as well as FORMAT ASCII are the same for both formats.
LOAD TABLE Products ( ID ASCII(6), FILLER(1), Name ASCII(15), FILLER(1), Description '\x09', Size ASCII(2), FILLER(1), Color '\x09', Quantity PREFIX 2, UnitPrice PREFIX 2, FILLER(2) ) FROM 'C:\\mydata\\source1.dmp' QUOTES OFF ESCAPES OFF BYTE ORDER LOW NOTIFY 1000
LOAD TABLE t1(c1,c2,filler(30)) USING CLIENT FILE 'c:\\client-data\\a.inp' QUOTES OFF ESCAPES OFF IGNORE CONSTRAINT UNIQUE 0, NULL 0 MESSAGE LOG 'c:\\client-data\\m.log' ROW LOG 'c:\\client-data\\r.log'ONLY LOG UNIQUE
LOAD TABLE product_new ( id, name, description, size, color '\x09' NULL( 'null', 'none', 'na' ), quantity PREFIX 2, unit_price PREFIX 2 ) FROM '/s1/mydata/source2.dump', '/s1/mydata/source3.dump' QUOTES OFF ESCAPES OFF FORMAT ascii DELIMITED BY '\x09' ON FILE ERROR CONTINUE ROW DELIMITED BY '\n'
load table PTAB1( ck1 ',' null ('NULL') , ck3fk2c2 ',' null ('NULL') , ck4 ',' null ('NULL') , ck5 ',' null ('NULL') , ck6c1 ',' null ('NULL') , ck6c2 ',' null ('NULL') , rid ',' null ('NULL') ) FROM 'ri_index_selfRI.inp' row delimited by '\n' LIMIT 14 SKIP 10 IGNORE CONSTRAINT UNIQUE 2, FOREIGN KEY 8 word skip 10 quotes off escapes off strip off
LOAD TABLE t1 (c1, c2, c3) FROM ‘bcp_file.bcp’ FORMAT BCP ...
LOAD TABLE t1 (c1 DEFAULT ‘12345 ’, c2, c3, filler(1)) FROM ‘LoadConst04.dat’ STRIP OFF QUOTES OFF ESCAPES OFF DELIMITED BY ‘,’;
LOAD TABLE t1 (c1, c2, c3 DEFAULT ‘10’) FROM ‘bcp_file.bcp’ FORMAT BCP QUOTES OFF ESCAPES OFF;
LOAD TABLE ...HEADER SKIP 1 HEADER DELIMITED by '&&'
LOAD TABLE ...HEADER SKIP 2
Load data into RLV-enabled table rvt1 from the BCP character file bcp_file.bcp using the FORMAT BCP load option:
LOAD TABLE rvt1 (c1, c2, c3) FROM ‘bcp_file.bcp’ FORMAT BCP ...
The LOAD TABLE statement allows efficient mass insertion into a database table from a file with ASCII or binary data.
The LOAD TABLE options also let you control load behavior when integrity constraints are violated and to log information about the violations.
You can use LOAD TABLE on a temporary table, but the temporary table must have been declared with ON COMMIT PRESERVE ROWS, or the next COMMIT removes the rows you have loaded.
LOAD TABLE supports loading of large object (LOB) data.
SAP Sybase IQ supports loading from both ASCII and binary data, and it supports both fixed- and variable-length formats. To handle all of these formats, you must supply a load-specification to tell SAP Sybase IQ what kind of data to expect from each “column” or field in the source file. The column-spec lets you define these formats:
If the data is unloaded using the extraction facility with the TEMP_EXTRACT_BINARY option set ON, you must use the BINARY WITH NULL BYTE parameter for each column when you load the binary data.
Option | Meaning |
---|---|
yyyy or YYYY yy or YY |
Represents number of year. Default is current year. |
mm or MM | Represents number of month. Always use leading zero or blank for number of the month where appropriate, for example, '05' for May. DATE value must include a month. For example, if the DATE value you enter is 1998, you receive an error. If you enter '03', SAP Sybase IQ applies the default year and day and converts it to '1998-03-01'. |
dd or DD jjj or JJJ |
Represents number of day. Default day is 01. Always use leading zeros for number of day where appropriate, for example, '01' for first day. J or j indicates a Julian day (1 to 366) of the year. |
hh HH |
Represents hour. Hour is based on 24-hour clock. Always use leading zeros or blanks for hour where appropriate, for example, '01' for 1 am. '00' is also valid value for hour of 12 a.m. |
nn |
Represents minute. Always use leading zeros for minute where appropriate, for example, '08' for 8 minutes. |
ss[.ssssss] |
Represents seconds and fraction of a second. |
aa | Represents the a.m. or p.m. designation. |
pp | Represents the p.m. designation only if needed. (This is an incompatibility with SAP Sybase IQ versions earlier than 12.0; previously, “pp” was synonymous with “aa”.) |
hh | SAP Sybase IQ assumes zero for minutes and seconds. For example, if the DATETIME value you enter is '03', SAP Sybase IQ converts it to '03:00:00.0000'. |
hh:nn or hh:mm | SAP Sybase IQ assumes zero for seconds. For example, if the time value you enter is '03:25', SAP Sybase IQ converts it to '03:25:00.0000'. |
Input data | Format specification |
---|---|
12/31/98 | DATE ('MM/DD/YY') |
19981231 | DATE ('YYYYMMDD') |
123198140150 | DATETIME ('MMDDYYhhnnss') |
14:01:50 12-31-98 | DATETIME ('hh:nn:ss MM-DD-YY') |
18:27:53 | DATETIME ('hh:nn:ss') |
12/31/98 02:01:50AM | DATETIME ('MM/DD/YY hh:nn:ssaa') |
SAP Sybase IQ has built-in load optimizations for common date, time, and datetime formats. If your data to be loaded matches one of these formats, you can significantly decrease load time by using the appropriate format.
You can also specify the date/time field as an ASCII fixed-width field (as described above) and use the FILLER(1) option to skip the column delimiter.
The NULL portion of the column-spec indicates how to treat certain input values as NULL values when loading into the table column. These characters can include BLANKS, ZEROS, or any other list of literals you define. When specifying a NULL value or reading a NULL value from the source file, the destination column must be able to contain NULLs.
ZEROS are interpreted as follows: the cell is set to NULL if (and only if) the input data (before conversion, if ASCII) is all binary zeros (and not character zeros).
If the input data is character zero, then:
NULL (ZEROS) never causes the cell to be NULL.
NULL ('0') causes the cell to be NULL.
If the input data is binary zero (all bits clear), then:
For example, if your LOAD statement includes col1 date('yymmdd') null(zeros) and the date is 000000, you receive an error indicating that 000000 cannot be converted to a DATE(4). To get LOAD TABLE to insert a NULL value in col1 when the data is 000000, either write the NULL clause as null('000000'), or modify the data to equal binary zeros and use NULL(ZEROS).
If the length of a VARCHAR cell is zero and the cell is not NULL, you get a zero-length cell. For all other data types, if the length of the cell is zero, SAP Sybase IQ inserts a NULL. This is ANSI behavior. For non-ANSI treatment of zero-length character data, set the NON_ANSI_NULL_VARCHAR database option.
Another important part of the load-specification is the FILLER option. This option indicates you want to skip over a specified field in the source input file. For example, there may be characters at the end of rows or even entire fields in the input files that you do not want to add to the table. As with the column-spec definition, FILLER specifies ASCII fixed length of bytes, variable length characters delimited by a separator, and binary fields using PREFIX bytes.
For more information on the -gl command line option, please refer Utility Guide > start_iq Database Server Startup Utility > start_iq Server Options.
LOAD TABLE also requires a write lock on the table.