Files
doris/docs/zh-CN/docs/sql-manual/sql-reference/Data-Definition-Statements/Create/CREATE-EXTERNAL-TABLE.md
wangyongfeng 2d39cffa5c [doc](website)Add Doris new official website code and documents (#9977)
In order to cooperate with Doris's successful graduation from Apache, the Doris official website also needs a new look
and more powerful feature, so we decided to redesign the Doris official website.
The code and documents of the new official website are included in this PR.

Since the new website is completely rewritten, the content and structure of the project are different from the previous one. 
In particular, the directory structure of documents has changed, and the number of documents is large, so the number of 
files in this PR is very large.

In the old website,all English documents are in the en/ directory, and Chinese documents in the zh-CN/ directory,
but in the new website,the documents are split into multiple directories according to the nav.
The document's directory structure changes as follows:
```
docs (old website)
|   |—— .vuepress (library)
|   |—— en
|   |   |—— admin-manual 
│   │   |—— advanced
|   |   |—— article
|   |   |—— benchmark
|   |   |—— case-user
|   |   |—— community
|   |   |—— data-operate
|   |   |—— data-table
|   |   |—— design
|   |   |—— developer-guide
|   |   |—— downloads
|   |   |—— ecosystem
|   |   |—— faq
|   |   |—— get-starting
|   |   |—— install
|   |   |—— sql-manual
|   |   |—— summary
|   |   |___ README.md
|   |—— zh-CN
...

docs (new website)
|   |—— .vuepress (library)
|   |—— en
|   |   |—— community (unchanged, community nav)
│   │   |—— developer (new directory, developer nav)
│   │   |   |—— design (moved from en/design)
│   │   |   |__ developer-guide (moved from en/developer-guide)
|   |   |—— docs (new directory, all children directories moved from en/, document nav)
│   │   |   |—— admin-manual 
│   │   |   |—— advanced
│   │   |   |—— benchmark
│   │   |   |—— data-operate
│   │   |   |—— data-table
│   │   |   |—— ecosystem
│   │   |   |—— faq
│   │   |   |—— get-starting
│   │   |   |—— install
│   │   |   |—— sql-manual
│   │   |   |—— summary
|   |   |—— downloads (unchanged, downloads nav)
|   |   |—— userCase (moved from en/case-user, user nav)
|   |   |___ README.md
|   |—— zh-CN
...
```
2022-06-08 17:45:12 +08:00

7.1 KiB

title, language
title language
CREATE-EXTERNAL-TABLE zh-CN

CREATE-EXTERNAL-TABLE

Name

CREATE EXTERNAL TABLE

Description

此语句用来创建外部表,具体语法参阅 CREATE TABLE

主要通过 ENGINE 类型来标识是哪种类型的外部表,目前可选 MYSQL、BROKER、HIVE、ICEBERG 、HUDI

  1. 如果是 mysql,则需要在 properties 提供以下信息:

    PROPERTIES (
    	"host" = "mysql_server_host",
    	"port" = "mysql_server_port",
    	"user" = "your_user_name",
    	"password" = "your_password",
    	"database" = "database_name",
    	"table" = "table_name"
    )
    

    以及一个可选属性"charset",可以用来设置mysql连接的字符集, 默认值是"utf8"。如有需要,你可以设置为另外一个字符集"utf8mb4"。

    注意:

    • "table" 条目中的 "table_name" 是 mysql 中的真实表名。而 CREATE TABLE 语句中的 table_name 是该 mysql 表在 Doris 中的名字,可以不同。

    • 在 Doris 创建 mysql 表的目的是可以通过 Doris 访问 mysql 数据库。而 Doris 本身并不维护、存储任何 mysql 数据。

  2. 如果是 broker,表示表的访问需要通过指定的broker, 需要在 properties 提供以下信息:

    PROPERTIES (
    	"broker_name" = "broker_name",
    	"path" = "file_path1[,file_path2]",
    	"column_separator" = "value_separator"
    	"line_delimiter" = "value_delimiter"
    )
    

    另外还需要提供Broker需要的Property信息,通过BROKER PROPERTIES来传递,例如HDFS需要传入

    BROKER PROPERTIES(
      "username" = "name",
      "password" = "password"
    )
    

    这个根据不同的Broker类型,需要传入的内容也不相同

    注意:

    • "path" 中如果有多个文件,用逗号[,]分割。如果文件名中包含逗号,那么使用 %2c 来替代。如果文件名中包含 %,使用 %25 代替
    • 现在文件内容格式支持CSV,支持GZ,BZ2,LZ4,LZO(LZOP) 压缩格式。
  3. 如果是 hive,则需要在 properties 提供以下信息:

    PROPERTIES (
    	"database" = "hive_db_name",
    	"table" = "hive_table_name",
    	"hive.metastore.uris" = "thrift://127.0.0.1:9083"
    )
    

    其中 database 是 hive 表对应的库名字,table 是 hive 表的名字,hive.metastore.uris 是 hive metastore 服务地址。

  4. 如果是 iceberg,则需要在 properties 中提供以下信息:

    PROPERTIES (
    	"iceberg.database" = "iceberg_db_name",
    	"iceberg.table" = "iceberg_table_name",
    	"iceberg.hive.metastore.uris" = "thrift://127.0.0.1:9083",
    	"iceberg.catalog.type" = "HIVE_CATALOG"
    )
    

    其中 database 是 Iceberg 对应的库名; table 是 Iceberg 中对应的表名; hive.metastore.uris 是 hive metastore 服务地址; catalog.type 默认为 HIVE_CATALOG。当前仅支持 HIVE_CATALOG,后续会支持更多 Iceberg catalog 类型。

  5. 如果是 hudi,则需要在 properties 中提供以下信息:

    PROPERTIES (
    "hudi.database" = "hudi_db_in_hive_metastore",
    "hudi.table" = "hudi_table_in_hive_metastore",
    "hudi.hive.metastore.uris" = "thrift://127.0.0.1:9083"
    )
    

    其中 hudi.database 是 hive 表对应的库名字,hudi.table 是 hive 表的名字,hive.metastore.uris 是 hive metastore 服务地址。

Example

  1. 创建MYSQL外部表

    直接通过外表信息创建mysql表

    CREATE EXTERNAL TABLE example_db.table_mysql
    (
    	k1 DATE,
    	k2 INT,
    	k3 SMALLINT,
    	k4 VARCHAR(2048),
    	k5 DATETIME
    )
    ENGINE=mysql
    PROPERTIES
    (
    	"host" = "127.0.0.1",
    	"port" = "8239",
    	"user" = "mysql_user",
    	"password" = "mysql_passwd",
    	"database" = "mysql_db_test",
     "table" = "mysql_table_test",
     "charset" = "utf8mb4"
    )
    

    通过External Catalog Resource创建mysql表

    # 先创建Resource
    CREATE EXTERNAL RESOURCE "mysql_resource" 
    PROPERTIES
    (
      "type" = "odbc_catalog",
      "user" = "mysql_user",
      "password" = "mysql_passwd",
      "host" = "127.0.0.1",
       "port" = "8239"			
    );
    
    # 再通过Resource创建mysql外部表
    CREATE EXTERNAL TABLE example_db.table_mysql
    (
    	k1 DATE,
    	k2 INT,
    	k3 SMALLINT,
    	k4 VARCHAR(2048),
    	k5 DATETIME
    )
    ENGINE=mysql
    PROPERTIES
    (
    	"odbc_catalog_resource" = "mysql_resource",
    	"database" = "mysql_db_test",
    	"table" = "mysql_table_test"
    )
    
  2. 创建一个数据文件存储在HDFS上的 broker 外部表, 数据使用 "|" 分割,"\n" 换行

    CREATE EXTERNAL TABLE example_db.table_broker (
    	k1 DATE,
    	k2 INT,
    	k3 SMALLINT,
    	k4 VARCHAR(2048),
    	k5 DATETIME
    )
    ENGINE=broker
    PROPERTIES (
    	"broker_name" = "hdfs",
    	"path" = "hdfs://hdfs_host:hdfs_port/data1,hdfs://hdfs_host:hdfs_port/data2,hdfs://hdfs_host:hdfs_port/data3%2c4",
    	"column_separator" = "|",
    	"line_delimiter" = "\n"
    )
    BROKER PROPERTIES (
    	"username" = "hdfs_user",
    	"password" = "hdfs_password"
    )
    
  3. 创建一个hive外部表

    CREATE TABLE example_db.table_hive
    (
      k1 TINYINT,
      k2 VARCHAR(50),
      v INT
    )
    ENGINE=hive
    PROPERTIES
    (
      "database" = "hive_db_name",
      "table" = "hive_table_name",
      "hive.metastore.uris" = "thrift://127.0.0.1:9083"
    );
    
  4. 创建一个 Iceberg 外表

    CREATE TABLE example_db.t_iceberg 
    ENGINE=ICEBERG
    PROPERTIES (
    	"iceberg.database" = "iceberg_db",
    	"iceberg.table" = "iceberg_table",
    	"iceberg.hive.metastore.uris"  =  "thrift://127.0.0.1:9083",
    	"iceberg.catalog.type"  =  "HIVE_CATALOG"
    );
    
  5. 创建一个 Hudi 外表

    创建时不指定schema(推荐)

    CREATE TABLE example_db.t_hudi
    ENGINE=HUDI
    PROPERTIES (
    "hudi.database" = "hudi_db_in_hive_metastore",
    "hudi.table" = "hudi_table_in_hive_metastore",
    "hudi.hive.metastore.uris" = "thrift://127.0.0.1:9083"
    );
    

    创建时指定schema

    CREATE TABLE example_db.t_hudi (
       `id` int NOT NULL COMMENT "id number",
       `name` varchar(10) NOT NULL COMMENT "user name"
    )
    ENGINE=HUDI
    PROPERTIES (
    "hudi.database" = "hudi_db_in_hive_metastore",
    "hudi.table" = "hudi_table_in_hive_metastore",
    "hudi.hive.metastore.uris" = "thrift://127.0.0.1:9083"
    );
    

Keywords

CREATE, EXTERNAL, TABLE

Best Practice