LOAD DATA
Description
Imports data from a file to a specified table in the database.
Precautions
- The LOAD DATA syntax is supported only in B-compatible mode (sql_compatibility set to 'B').
- The LOAD DATA syntax is the same as that of database B only when b_format_version is set to '5.7' and b_format_dev_version is set to 's2'.
- The GUC parameters related to the LOAD DATA syntax are the same as those of the COPY FROM syntax. For details, see Precautions.
- The LOAD DATA syntax requires the INSERT and DELETE permissions on tables.
- If the data written to a table by running LOAD DATA cannot be converted to the data type of the table, the import fails.
- LOAD DATA applies only to tables but not views.
Syntax
LOAD DATA [LOCAL] INFILE 'file_name' [REPLACE | IGNORE] INTO TABLE tbl_name [PARTITION (partition_name [, partition_name] ...)] [CHARACTER SET charset_name] [{FIELDS | COLUMNS} [TERMINATED BY 'string'] [[OPTIONALLY] ENCLOSED BY 'char'] [ESCAPED BY 'char'] ] [LINES [STARTING BY 'string'] [TERMINATED BY 'string'] ] [IGNORE number {LINES | ROWS}] [(col_name_or_user_var [, col_name_or_user_var] ...)] [SET col_name={expr | DEFAULT} [, col_name={expr | DEFAULT}] ...]
Parameters
- LOCAL
Specifies the location of the file to be imported.
If LOCAL is not specified and file_name is a relative path, data is imported to the data directory by default.
If the LOCAL parameter is specified, file_name must be set to an absolute path. If file_name is set to a relative path, data is imported to the location of the database binary file by default, that is, $GAUSSHOME/bin/.
If the imported data conflicts with the table data or the number of columns in the file is less than the number of columns in the specified table, the function of specifying LOCAL is the same as that of specifying IGNORE.
- REPLACE | IGNORE
If the data to be imported conflicts with the original data in the table, specifying REPLACE replaces the conflicting data, and specifying IGNORE skips the conflicting data and continues the import. If data conflicts occur but none of REPLACE, IGNORE, or LOCAL is specified, the import stops and an error is reported.
If the number of columns in the file is less than that in the specified table, specifying IGNORE or LOCAL will assign default values to the remaining columns. If neither IGNORE nor LOCAL is specified, an error is reported.
- PARTITION
If the table to be imported is a partitioned table, this parameter specifies a partition. If the data is inconsistent with the specified partition range, an error is reported.
- CHARACTER SET
Specifies the encoding format of a data file. The default value is the current client encoding format.
- FIELDS | COLUMNS
- TERMINATED BY
Specifies the delimiter between columns. The default value is \t.
The specified newline character cannot be the same as the delimiter.
- [OPTIONALLY] ENCLOSED BY
Specifies the quotation mark character. The default value is ''.
The OPTIONALLY parameter is optional and does not take effect.
The quotation mark can only be a single character and cannot be a character string.
- ESCAPED BY
Specifies the escape character. The default value is '\'.
The escape character can only be a single character and cannot be a character string.
- TERMINATED BY
- LINES
- STARTING BY
Specifies the style of the starting field in the data file to be imported.
- TERMINATED BY
Specifies the newline character style of the imported data file.
- STARTING BY
- IGNORE
Specifies that the first number rows of the data file are skipped during data import.
- col_name_or_user_var
Specifies an optional list of columns to be copied.
Value range: any columns. All columns will be copied if no column list is specified.
- The parameter for specifying columns cannot be used to specify a column repeatedly.
- When columns are specified using the LOAD DATA syntax, col_name_or_user_var can be specified as existing columns or user variables. If it is specified as a user variable, the GUC parameter b_format_behavior_compat_options must be set to 'enable_set_variables'.
- SET
Specifies the column value, which can be an expression or DEFAULT.
- The expression does not support column names.
- If no implicit conversion exists between the expression result type and the type of the assigned column, an error is reported.
Examples
-- Create a table. gaussdb=# CREATE TABLE load_data_tbl1(load_col1 INT UNIQUE, load_col2 INT, load_col3 CHAR(10)); -- Insert a data record into a table. gaussdb=# INSERT INTO load_data_tbl1 VALUES(0,0,'load0'); -- Copy data from the /home/omm/load1.csv file to the load_data_tbl table, specify a column name, and set the value of the load_col3 column to load. gaussdb=# LOAD DATA INFILE '/home/omm/load1.csv' INTO TABLE load_data_tbl1(load_col1, load_col2) SET load_col3 = 'load'; -- The values imported to the load_col3 column later are all load. gaussdb=# SELECT * FROM load_data_tbl1; load_col1 | load_col2 | load_col3 -----------+-----------+------------ 0 | 0 | load0 3 | 3 | load 1 | 1 | load 2 | 2 | load (4 rows) -- Copy data from the /home/omm/load2.csv file to the load_data_tbl table and specify IGNORE to ignore conflicts. gaussdb=# LOAD DATA INFILE '/home/omm/load2.csv' IGNORE INTO TABLE load_data_tbl1; -- Data in the load_data_tbl1 table remains unchanged, and conflicting data is skipped. gaussdb=# SELECT * FROM load_data_tbl1; load_col1 | load_col2 | load_col3 -----------+-----------+------------ 0 | 0 | load0 3 | 3 | load 1 | 1 | load 2 | 2 | load (4 rows) -- Create a partitioned table. gaussdb=# CREATE TABLE load_data_tbl2 ( load_col_col1 INT, load_col_col2 INT ) PARTITION BY RANGE (load_col_col2) ( PARTITION load_p1 VALUES LESS THAN(3), PARTITION load_p2 VALUES LESS THAN(9), PARTITION load_p3 VALUES LESS THAN(MAXVALUE) ); -- Copy data from the /home/omm/load3.csv file to the load_data_tbl2 table and specify a partition. gaussdb=# LOAD DATA INFILE '/home/omm/load3.csv' INTO TABLE load_data_tbl2 PARTITION (load_p2); -- Import data to the specified partition in the load_data_tbl2 table. gaussdb=# SELECT * FROM load_data_tbl2; load_col_col1 | load_col_col2 ---------------+--------------- 4 | 4 5 | 5 (2 rows) -- Create a table. gaussdb=# CREATE TABLE load_data_tbl3(load_col_col1 CHAR(30)); -- Copy data from the /home/omm/load4.csv file to the load_data_tbl3 table and specify FIELDS ENCLOSED BY. gaussdb=# LOAD DATA INFILE '/home/omm/load4.csv' INTO TABLE load_data_tbl3 FIELDS ENCLOSED BY '"'; -- The double quotation marks of "load test quote" are removed, and the single quotation marks of 'load test single_quote' are retained. gaussdb=# select * from load_data_tbl3; load_col_col1 -------------------------------- load test quote 'load test single_quote' (2 rows) -- Delete the table. gaussdb=# drop table load_data_tbl1; gaussdb=# DROP TABLE load_data_tbl2; gaussdb=# DROP TABLE load_data_tbl3;
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot