Updated on 2025-10-23 GMT+08:00

LOAD DATA

Description

Imports data from a file to a specified table in the database.

Precautions

  • LOAD DATA requires the INSERT and DELETE permissions on tables.
  • When the enable_copy_server_files parameter is disabled, only the initial user is allowed to execute LOAD DATA. When the enable_copy_server_files parameter is enabled, a user with the SYSADMIN permission or a user who inherits the permissions of the built-in role gs_role_copy_files can execute LOAD DATA. By default, you cannot execute LOAD DATA on database configuration files, key files, certificate files, or audit logs. This prevents unauthorized users from viewing or modifying sensitive files.
  • When the enable_copy_server_files parameter is enabled, an administrator can use the GUC parameter safe_data_path to set the path where common users can import or export data. However, the path must be a subpath of safe_data_path. If the safe_data_path parameter is not set (by default), the path used by common users is not blocked.
  • If the data written to a table by executing LOAD DATA cannot be converted to the data type of the table, the import fails.
  • LOAD DATA applies only to tables but not views.
  • When LOAD DATA is used together with COPY TO, the result of the bit type may be inaccurate. To ensure that the result of the bit type is consistent with the source data when the result is exported and then imported, LOAD DATA must be used together with the SELECT INTO OUTFILE syntax.

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, data is imported from the environment where the server is located. If 'file_name' is a relative path, the default import path is the data directory.

    If LOCAL is specified and the GUC parameter m_format_behavior_compat_options contains enable_load_data_remote_transmission, data is imported from the environment where the client is located. If the GUC parameter m_format_behavior_compat_options does not contain enable_load_data_remote_transmission, data is imported from the environment where the server is located. If a relative path is specified, the default import path is the path of the database binary file, 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.
    • If m_format_behavior_compat_options contains enable_load_data_remote_transmission, LOAD DATA cannot be executed together with other SQL statements.
    • If the file to be imported is stored on the client, the GaussDB server and client (JDBC driver and ODBC driver) must be upgraded to 505.2.1.
  • 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.

  • LINES
    • STARTING BY

      Specifies the style of the starting column in the data file to be imported.

    • TERMINATED BY

      Specifies the newline character style of the imported data file.

  • 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.
  • 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

-- Prepare the files to be imported.
m_db=# CREATE TABLE load_data_tmp1(a int, b int);
m_db=# INSERT INTO load_data_tmp1 VALUES(1,1),(2,2),(3,3);
m_db=# \copy load_data_tmp1 to '/home/omm/load1.csv';
m_db=# CREATE TABLE load_data_tmp2(a int, b int);
m_db=# INSERT INTO load_data_tmp2 VALUES(1,2);
m_db=# \copy load_data_tmp2 to '/home/omm/load2.csv';
m_db=# CREATE TABLE load_data_tmp3(a int, b int);
m_db=# INSERT INTO load_data_tmp3 VALUES(4,4),(5,5);
m_db=# \copy load_data_tmp3 to '/home/omm/load3.csv';
m_db=# CREATE TABLE load_data_tmp4(a char(50));
m_db=# INSERT INTO load_data_tmp4 VALUES('"load test quote"'), ('\'load test single_quote\'');
m_db=# \copy load_data_tmp4 to '/home/omm/load4.csv';

-- Create a table.
m_db=# CREATE TABLE load_data_tbl1(load_col1 INT UNIQUE, load_col2 INT, load_col3 CHAR(10));

-- Insert a data record into the table.
m_db=# 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.
m_db=# 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'.
m_db=# SELECT * FROM load_data_tbl1 ORDER BY load_col1;
 load_col1 | load_col2 | load_col3
-----------+-----------+-----------
         0 |         0 | load0
         1 |         1 | load
         2 |         2 | load
         3 |         3 | load
(4 rows)

-- Copy data from the /home/omm/load2.csv file to the load_data_tbl table and specify IGNORE to ignore conflicts.
m_db=# 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.
m_db=# SELECT * FROM load_data_tbl1 ORDER BY load_col1;
 load_col1 | load_col2 | load_col3
-----------+-----------+-----------
         0 |         0 | load0
         1 |         1 | load
         2 |         2 | load
         3 |         3 | load
(4 rows)

-- Create a partitioned table.
m_db=# 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.
m_db=# 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.
m_db=# SELECT * FROM load_data_tbl2;
 load_col_col1 | load_col_col2
---------------+---------------
             4 |             4
             5 |             5
(2 rows)

-- Create a table.
m_db=# 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.
m_db=# 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.
m_db=# select * from load_data_tbl3;
         load_col_col1
--------------------------------
 load test quote
 'load test single_quote'
(2 rows)

-- Drop tables.
m_db=# DROP TABLE load_data_tmp1;
m_db=# DROP TABLE load_data_tmp2;
m_db=# DROP TABLE load_data_tmp3;
m_db=# DROP TABLE load_data_tmp4;
m_db=# DROP TABLE load_data_tbl1;
m_db=# DROP TABLE load_data_tbl2;
m_db=# DROP TABLE load_data_tbl3;