• Data Warehouse Service

dws
  1. Help Center
  2. Data Warehouse Service
  3. Developer Guide
  4. Data Import
  5. Concurrently Importing Data from OBS
  6. Creating an OBS Foreign Table

Creating an OBS Foreign Table

Procedure

  1. Set location of the foreign table based on the path planned in Uploading Data to OBS.
  2. Set the access keys (AK and SK). To obtain access keys, log in to the management console, click the username in the upper right corner, choose My Credential from the drop-down list, and click Access Keys. Then, you can view existing access keys or click Add Access Key to create one.
  3. Set data format parameters for the foreign table based on the formats of data to be imported. You need to collect the following source data information:

    • format: The format of the source data file in the foreign table. OBS foreign tables support CSV and TEXT formats. The default value is TEXT.
    • header: Specifies whether the data file contains a table header. Only CSV files can have headers.
    • delimiter: Delimiter specified to separate data fields in a file. If no delimiter is specified, the default one will be used.
    • For more parameters used for foreign tables, see data format parameters.

  4. Plan the error tolerance of parallel import to specify how errors are handled during the import.

    • fill_missing_fields: When the last column in a row of the source data file is empty, this parameter specifies whether to report an error or set this field in the row to NULL.
    • ignore_extra_data: When the number of columns in the source data file is greater than that specified in the foreign table, this parameter specifies whether to report an error or ignore the extra columns.
    • per node reject_limit: This parameter specifies the number of data format errors allowed on each DN. If the number of errors recorded in the error table on a DN exceeds the specified value, the import fails and an error message will be reported. This parameter is optional.
    • compatible_illegal_chars: When an illegal character is encountered, this parameter specifies whether to import an error, or convert it and proceed with the import.

      The following describes the rules for converting an invalid character:

      • \0 is converted to a space.
      • Other invalid characters are converted to question marks (?).
      • If NULL, DELIMITER, QUOTE, or ESCAPE is also set to a space or question mark, an error message such as "illegal chars conversion may confuse COPY escape 0x20" is displayed, prompting you to modify parameter settings that may cause import errors.
    • error_table_name: This parameter specifies the name of the table that records data format errors. After the parallel import, you can query this table for error details.
    • For details about the parameters, see error tolerance parameters.

  5. Create an OBS table based on the parameter settings in the preceding steps. For details about how to create a foreign table, see CREATE FOREIGN TABLE (for OBS Import and Export).

Example

The following describes the parameters required for creating a foreign table in the DWS database:

  • Data format parameter access keys (AK and SK)
    • Set access_key to the AK you have obtained.
    • Set secret_access_key to the SK you have obtained.
    NOTE:

    The values of access_key and secret_access_key are examples only.

  • Set data format parameters.
    • Set format to CSV.
    • Set encoding to UTF-8.
    • Set encrypt to 'on'.
    • Set delimiter to ','.
    • Retain the default value (double quotation marks) of quote.
    • Set null (null value in a source data file) to a null string without quotation marks.
    • Set header (whether the exported data file contains the header row) to the default value false. If the first row of the data file is not a header, retain the default value.
  • Set fault-tolerant parameters for data import.
    • Set PER NODE REJECT LIMIT to 'unlimited', indicating that all data format errors detected during data import are allowed.
    • Set LOG INTO to product_info_err, indicating that the data format errors detected during data import are recorded in the product_info_err table.
    • If fill_missing_fields is set to true and the last column of a data row in a source data file is lost, the column is replaced with NULL and no error message will be generated.
    • If ignore_extra_data is set to true and the number of columns of the source data file is greater than that defined for the foreign table, the extra columns at the end of the row are ignored and no error message will be generated.

Based on the preceding settings, the foreign table is created using the following statements:

DROP FOREIGN TABLE product_info_ext;

CREATE FOREIGN TABLE product_info_ext
(
    product_price                integer        not null,
    product_id                   char(30)       not null,
    product_time                 date           ,
    product_level                char(10)       ,
    product_name                 varchar(200)   ,
    product_type1                varchar(20)    ,
    product_type2                char(10)       ,
    product_monthly_sales_cnt    integer        ,
    product_comment_time         date           ,
    product_comment_num          integer        ,
    product_comment_content      varchar(200)                   
) 
SERVER gsmpp_server 
OPTIONS(
location 'obs://mybucket/input_data/product_info | obs://mybucket02/input_data/product_info',
FORMAT 'CSV' ,
DELIMITER ',',
encoding 'utf8',
header 'false',
ACCESS_KEY 'access_key_value_to_be_replaced',
SECRET_ACCESS_KEY 'secret_access_key_value_to_be_replaced',
fill_missing_fields 'true',
ignore_extra_data 'true'
)
READ ONLY 
LOG INTO product_info_err 
PER NODE REJECT LIMIT 'unlimited';

If the following information is displayed, the foreign table has been created:

CREATE FOREIGN TABLE