You can execute the CREATE EXTERNAL TABLE statement to create an external table. When you create an external table, you must specify the path to the data file and the format of the data file to read data from external files.
Privilege requirements
To create an external table, the current user must have the CREATE TABLE privilege. To query the privileges of the current user, see View user privileges. If you do not have the CREATE TABLE privilege, contact the administrator to add it for you. For more information about how to add user privileges, see Modify user privileges.
Create an external table
The SQL statement for creating an external table is as follows:
CREATE EXTERNAL TABLE table_name
( col_name col_type [AS (metadata$filecol{N})]
[ , col_name col_type [AS (metadata$filecol{N})] ]
[ , ... ] )
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>' ]
The following table describes the parameters.
col_name col_type [AS (metadata$filecol{N})]: specifies the columns. You can useAS (metadata$filecol{N})to manually define column mapping.The columns supported and the data types supported in an external table are the same as those supported in a regular table in Oracle mode of OceanBase Database. For more information about the data types supported in Oracle mode of OceanBase Database, see Overview.
By default, columns in an external file are automatically mapped to columns in the external table in order. That is, the first column in the external file is mapped to the first column in the external table.
For example, in the following example, column
C1in theext_t1external table is automatically mapped to the first column in the external file; and columnC2is automatically mapped to the second column in the external file.CREATE EXTERNAL TABLE ext_t1 ( C1 int, C2 int ) LOCATION = 'oss://$ACCESS_ID:$ACCESS_KEY@$HOST/tpch_1g_data/lineitem/' FORMAT = ( TYPE = 'CSV' FIELD_DELIMITER = '|' );If the order of columns in the external file is different from that in the external table, you can use the pseudo column
metadata$filecol{N}to specify that the Nth column in the external file is mapped to the column in the external table. Note that the columns in the file are numbered starting from 1.For example, in the following example,
C1 int AS (metadata$filecol2)indicates that theC1column in theext_t2external table is mapped to the second column in the file; andC2 int AS (metadata$filecol4)indicates that theC2column in theext_t2external table is mapped to the fourth column in the external file.CREATE EXTERNAL TABLE ext_t2 ( C1 int AS (metadata$filecol2), C2 int AS (metadata$filecol4) ) LOCATION = 'oss://$ACCESS_ID:$ACCESS_KEY@$HOST/tpch_1g_data/lineitem/' FORMAT = ( TYPE = 'CSV' FIELD_DELIMITER = '|' );Notice
If you need to manually define column mapping, the automatic column mapping function will fail and all columns must be mapped manually.
LOCATION = '<string>': specifies the path where the external file is 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 this directory.Two formats are supported:
Local location format:
LOCATION = '[file://] local_file_path'local_file_path: can be a relative path or an absolute path. If you specify a relative path, the current directory must be the installation directory of OceanBase Database.Notice
In the local location format, the
secure_file_privsystem variable must be set to the directory that is the parent directory oflocal_file_path. In other words,local_file_pathmust be a subdirectory ofsecure_file_priv.For the local location format, when you use the
secure_file_privsystem variable to specify the directories that are accessible to OceanBase Database, the value ofsecure_file_privmust be the parent directory oflocal_file_path. In other words,local_file_pathmust be a subdirectory ofsecure_file_priv.The tenant-level
secure_file_privsystem variable specifies the directories that are accessible to OceanBase Database when you import data to or export data from a file. For more information aboutsecure_file_priv, see secure_file_priv.
Remote location format:
LOCATION = '{oss|cos}://$ACCESS_ID:$ACCESS_KEY@$HOST/remote_file_path'$ACCESS_ID,$ACCESS_KEY, and$HOSTare the access information required to access Alibaba Cloud OSS or Tencent Cloud COS. These sensitive access information is stored in encrypted form in the system tables of the database.Notice
When you use an object storage path, separate the parameters in the object storage path with the
&character. Make sure that the values of the parameters you entered contain only uppercase and lowercase letters, digits, and the following characters:/-_$+=and wildcard characters. If you enter characters other than the preceding ones, the setting may fail.
FORMAT: specifies the format of external files.TYPE: specifies the type of external files. Only CSV files are supported.LINE_DELIMITER: specifies the line delimiter in files. If this parameter is not specified, the default valueLINE_DELIMITER='\n'is used.FIELD_DELIMITER: specifies the field delimiter in files. If this parameter is not specified, the default valueFIELD_DELIMITER='\t'is used.ESCAPE: specifies the escape character in files. For example,ESCAPE ='*'specifies to use an asterisk (*) as the escape character, which replaces the default escape character (). If this parameter is not specified, the default valueESCAPE ='\'is used.FIELD_OPTIONALLY_ENCLOSED_BY: specifies the symbols that enclose field values in files. For example,ESCAPE = '"'specifies to enclose field values in double quotation marks. If this parameter is not specified, the default value is an empty string.ENCODING: specifies the character set encoding format of files. For more information about the character sets supported in Oracle mode of OceanBase Database, see Character sets. If this parameter is not specified, the default value UTF8MB4 is used.NULL_IF: specifies the strings that are to be treated asNULL. If this parameter is not specified, the default value is an empty string.SKIP_HEADER: specifies the number of lines to skip in the header of files. If this parameter is not specified, the default is to not skip the header.SKIP_BLANK_LINES: specifies whether to skip blank lines. If this parameter is not specified, the default value isFALSE.TRIM_SPACE: specifies whether to remove leading and trailing spaces in fields in files. If this parameter is not specified, the default value isFALSE.EMPTY_FIELD_AS_NULL: specifies whether an empty string is treated asNULL. If this parameter is not specified, the default value isFALSE.
PATTERN: specifies a regular pattern string to filter files in the directory specified byLOCATION. For each file in the directory specified byLOCATION, if the file matches the pattern string, the external table can access the file. Otherwise, the external table will skip the file. If this parameter is not specified, the external table can access all files in the directory specified byLOCATIONby default.
Assume that a data.csv file exists in the /home/admin/oceanbase/ directory on the local machine, and the file contains the following data.
1,"lin",98
2,"hei",90
3,"ali",95
On the OBServer node, the tenant administrator connects to the Oracle tenant of the cluster through the local Unix socket.
Here is an example of how to connect:
obclient -S /home/admin/oceanbase/run/sql.sock -uroot@sys -p********For more information about how to connect to OceanBase Database through a local Unix socket, see secure_file_priv.
Configure the path
/home/admin/oceanbase/that OceanBase Database can access.SET GLOBAL secure_file_priv = "/home/admin/oceanbase/";After the command is executed, you need to restart the session for the modification to take effect.
Reconnect to the database and create an external table named
ext_t3.CREATE EXTERNAL TABLE ext_t3(ID NUMBER(32), NAME VARCHAR2(30),SCORE NUMBER(32)) LOCATION = '/home/admin/oceanbase/' FORMAT = ( TYPE = 'CSV' FIELD_DELIMITER = ',' FIELD_OPTIONALLY_ENCLOSED_BY ='"' ) PATTERN = 'data.csv';
After the external table is created, you can use the SHOW CREATE TABLE statement to view the table definition, just like you do with a regular table.
SHOW CREATE TABLE ext_t3;
The query result is as follows:
+--------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| TABLE | CREATE TABLE |
+--------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| EXT_T3 | CREATE EXTERNAL TABLE "EXT_T3" (
"ID" NUMBER(32) GENERATED ALWAYS AS (METADATA$FILECOL1),
"NAME" VARCHAR2(30) GENERATED ALWAYS AS (METADATA$FILECOL2),
"SCORE" NUMBER(32) GENERATED ALWAYS AS (METADATA$FILECOL3)
)
LOCATION='file:///home/admin/oceanbase/'
PATTERN='data.csv'
FORMAT (
TYPE = 'CSV',
FIELD_DELIMITER = ',',
FIELD_OPTIONALLY_ENCLOSED_BY = '"',
ENCODING = 'utf8mb4'
)COMPRESS FOR ARCHIVE REPLICA_NUM = 1 BLOCK_SIZE = 16384 USE_BLOOM_FILTER = FALSE TABLET_SIZE = 134217728 PCTFREE = 0 |
+--------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set
You can also access the external table, just like you do with a regular table. When you query an external table, the system reads the external file through the driver of the external table and parses the file based on its format. Then, the system converts the data in the external file into the internal data types of OceanBase Database and returns the data rows. Here is an example of how to query an external table that has been created.
SELECT * FROM ext_t3;
The query result is as follows:
+----+------+-------+
| ID | NAME | SCORE |
+----+------+-------+
| 1 | lin | 98 |
| 2 | hei | 90 |
| 3 | ali | 95 |
+----+------+-------+
3 rows in set
In addition, an external table can be combined with a regular table for queries. Assume that a regular table named info exists in the current database and contains the following data:
+------+--------+------+
| NAME | SEX | AGE |
+------+--------+------+
| lin | male | 8 |
| hei | male | 9 |
| li | female | 8 |
+------+--------+------+
3 rows in set
Here is an example of how to combine the external table ext_t3 with the regular table info for queries.
SELECT info.* FROM info, ext_t3 WHERE info.name = ext_t3.name AND ext_t3.score > 90;
The query result is as follows:
+------+--------+------+
| NAME | SEX | AGE |
+------+--------+------+
| lin | male | 8 |
| li | female | 8 |
+------+--------+------+
2 rows in set
For more information about queries, see Read data.
Considerations
An external table can only be used for query operations and cannot be used for DML operations.
When you query an external table, if the external file accessed by the external table has been deleted, the system does not return an error, but returns an empty result set.
If the external storage system fails, an error is returned when you query the external table because the file managed by the external storage system cannot be accessed.
Next steps
When you create an external table, the system saves the file list that matches the specified PATTERN and is located in the path specified in LOCATION to a system table of OceanBase Database. The system uses the file list to locate external files when the system scans the external table. If you add new files to the external directory, you need to update the external table and add the new files to the file list of the external table. For more information, see Manage external files.
You can use the DROP TABLE statement to drop an external table, just like you drop a regular table. For more information, see Drop a table.