Description
This statement creates an external table in a database.
External tables are a key feature in a database management system. Generally, the data of a table in a database is stored in the storage space of the database, while an external table has data stored in an external storage service.
When you create an external table, you need to specify the file path and file format of the data. Then, you can read the data of the external table from the external storage service. An external table is read-only. You can use it in a query statement, but you cannot perform Data Manipulation Language (DML) operations on it. You cannot define constraints or create indexes on external tables.
Syntax
CREATE EXTERNAL TABLE <table_name>
( [ <column_name> <column_type> [AS <expr>] ]
[ , <column_name> <column_type> [AS <expr>] ]
[ , ... ] )
LOCATION = '<string>'
FORMAT = (
TYPE = 'CSV'
LINE_DELIMITER = '<string>' | <expr>
FIELD_DELIMITER = '<string>' | <expr>
ESCAPE = '<character>' | <expr>
FIELD_OPTIONALLY_ENCLOSED_BY = '<character>' | <expr>
ENCODING = 'charset'
NULL_IF = ('<string>' | <expr>, '<string>' | <expr> ...)
SKIP_HEADER = <int>
SKIP_BLANK_LINES = { TRUE | FALSE }
TRIM_SPACE = { TRUE | FALSE }
EMPTY_FIELD_AS_NULL = { TRUE | FALSE }
)
[ PATTERN = '<regex_pattern>' ]
Parameters
| Parameter | Description |
|---|---|
| table_name | The name of the external table to be created. |
| column_name | The name of a column of the external table. By default, the data columns in the file and the columns of the external table are automatically matched in sequence. |
| column_type | The data type of a column of the external table. You cannot define constraints such as DEFAULT, NOT NULL, UNIQUE, CHECK, PRIMARY KEY, or FOREIGN KEY for the external table columns. |
| AS |
Manually specifies column mapping. If the sequence of columns in the file does not match that in the external table, you can specify the correspondence between a column of the external table and the Nth column in the file by using a pseudocolumn that is represented by metadata$filecol{N}. For example, c2 INT AS (metadata$filecol4) indicates that the c2 column in the external table corresponds to the fourth column in the file. Note that if you specify manual column mapping, automatic mapping relationships become invalid, and you must define mappings for all columns manually. |
| LOCATION | The path where the external table files are stored. Generally, the data files of an external table are stored in a separate directory, which can contain subdirectories. When you create an external table, the system automatically collects all files in the specified directory.
NoticeWhen you use object storage paths, separate the parameters in the object storage path with |
| FORMAT | Specifies the format of external files.
|
| PATTERN | A regular pattern string that is used to filter files in the LOCATION directory. For each file in the directory specified by LOCATION, if the file path matches the pattern string, the external table accesses the file; otherwise, the external table skips the file. By default, if this parameter is not specified, all files in the directory specified by LOCATION are accessible to the external table. The external table stores the list of files that match the LOCATION parameter value in the system tables of the database. During a scan, the external table accesses external files based on this list. |
Usage notes
- If an external file is deleted, the file no longer exists in the file list when you access the file list. In this case, the external table ignores the missing file.
- If an external file is modified, the external table accesses the latest data of the external file. If the modification of the external file conflicts with the query of the external table, the result of the query may not be as expected. Therefore, avoid modifying the external file while querying the external table.
- The external table accesses only the files listed in the file list when new files are added to the external directory. If you want to add new files to the file list of the external table, you need to update the file list of the external table.
Examples
Set the path of
secure_file_privto/home/admin/and place theextdata.csvfile, which corresponds to the external table data to be imported, in the/home/admin/testdirectory on the current locally connected OBServer node.Here is an example of setting the global secure path:
obclient> SET GLOBAL secure_file_priv = "" Query OK, 0 rows affected obclinet> \q ByeNote
After you set the
secure_file_privvariable, you must execute the\qstatement to quit and make the setting take effect.The CSV file contains the following data:
1,'Dave','Smith','dsmith@outlook.com','friend',32 2,'Xena','Johnson','xjonson@outlook.com','contact',45 3,'Fred','Jackon','fjackson@outlook.com','co-worker',19 4,'Alma','Tyler','atyler@outlook.com','friend',53Log in to the database as a user of the tenant and create an external table named
contacts.obclient> CREATE EXTERNAL TABLE contacts ( id INT, firstname VARCHAR(100), lastname VARCHAR(100), email VARCHAR(255), category CHAR(30), age NUMBER ) LOCATION = '/home/admin/test' FORMAT = ( TYPE = 'CSV' FIELD_DELIMITER = ',' FIELD_OPTIONALLY_ENCLOSED_BY ='\'' ) PATTERN = 'extdata.csv';Query data from the
contactsexternal table.obclient> SELECT * FROM contacts; +----+-----------+----------+----------------------+-----------+------+ | id | firstname | lastname | email | category | age | +----+-----------+----------+----------------------+-----------+------+ | 1 | Dave | Smith | dsmith@outlook.com | friend | 32 | | 2 | Xena | Johnson | xjonson@outlook.com | contact | 45 | | 3 | Fred | Jackon | fjackson@outlook.com | co-worker | 19 | | 4 | Alma | Tyler | atyler@outlook.com | friend | 53 | +----+-----------+----------+----------------------+-----------+------+ 4 rows in set