SQL DDL

This page describes support for creating and altering tables using SQL across various engines.

Spark SQL

Create table

You can create tables using standard CREATE TABLE syntax, which supports partitioning and passing table properties.

  1. CREATE TABLE [IF NOT EXISTS] [db_name.]table_name
  2. [(col_name data_type [COMMENT col_comment], ...)]
  3. [COMMENT table_comment]
  4. [PARTITIONED BY (col_name, ...)]
  5. [ROW FORMAT row_format]
  6. [STORED AS file_format]
  7. [LOCATION path]
  8. [TBLPROPERTIES (property_name=property_value, ...)]
  9. [AS select_statement];

SQL DDL - 图1NOTE:

For users running this tutorial locally and have a Spark-Hive(HMS) integration in their environment: If you use default database or if you don’t provide [LOCATION path] with the DDL statement, Spark will return java.io.IOException: Mkdirs failed to create file:/user/hive/warehouse/hudi_table/.hoodie error. To get around this, you can follow either of the two options mentioned below:

  1. Create a database i.e. CREATE DATABASE hudidb; and use it i.e. USE hudidb; before running the DDL statement.
  2. Or provide a path using LOCATION keyword to persist the data with the DDL statement.

Create non-partitioned table

Creating a non-partitioned table is as simple as creating a regular table.

  1. -- create a Hudi table
  2. CREATE TABLE IF NOT EXISTS hudi_table (
  3. id INT,
  4. name STRING,
  5. price DOUBLE
  6. ) USING hudi;

Create partitioned table

A partitioned table can be created by adding a partitioned by clause. Partitioning helps to organize the data into multiple folders based on the partition columns. It can also help speed up queries and index lookups by limiting the amount of metadata, index and data scanned.

  1. CREATE TABLE IF NOT EXISTS hudi_table_partitioned (
  2. id BIGINT,
  3. name STRING,
  4. dt STRING,
  5. hh STRING
  6. ) USING hudi
  7. TBLPROPERTIES (
  8. type = 'cow'
  9. )
  10. PARTITIONED BY (dt);

SQL DDL - 图2note

You can also create a table partitioned by multiple fields by supplying comma-separated field names. When creating a table partitioned by multiple fields, ensure that you specify the columns in the PARTITIONED BY clause in the same order as they appear in the CREATE TABLE schema. For example, for the above table, the partition fields should be specified as PARTITIONED BY (dt, hh).

Create table with record keys and ordering fields

As discussed here, tables track each record in the table using a record key. Hudi auto-generated a highly compressed key for each new record in the examples so far. If you want to use an existing field as the key, you can set the primaryKey option. Typically, this is also accompanied by configuring a preCombineField option to deal with out-of-order data and potential duplicate records with the same key in the incoming writes.

SQL DDL - 图3note

You can choose multiple fields as primary keys for a given table on a need basis. For eg, “primaryKey = ‘id, name’”, and this materializes a composite key of the two fields, which can be useful for exploring the table.

Here is an example of creating a table using both options. Typically, a field that denotes the time of the event or fact, e.g., order creation time, event generation time etc., is used as the preCombineField. Hudi resolves multiple versions of the same record by ordering based on this field when queries are run on the table.

  1. CREATE TABLE IF NOT EXISTS hudi_table_keyed (
  2. id INT,
  3. name STRING,
  4. price DOUBLE,
  5. ts BIGINT
  6. ) USING hudi
  7. TBLPROPERTIES (
  8. type = 'cow',
  9. primaryKey = 'id',
  10. preCombineField = 'ts'
  11. );

Create table from an external location

Often, Hudi tables are created from streaming writers like the streamer tool, which may later need some SQL statements to run on them. You can create an External table using the location statement.

  1. CREATE TABLE hudi_table_external
  2. USING hudi
  3. LOCATION 'file:///tmp/hudi_table/';

SQL DDL - 图4tip

You don’t need to specify the schema and any properties except the partitioned columns if they exist. Hudi can automatically recognize the schema and configurations.

Create Table As Select (CTAS)

Hudi supports CTAS(Create table as select) to support initial loads into Hudi tables. To ensure this is done efficiently, even for large loads, CTAS uses bulk insert as the write operation

  1. # create managed parquet table
  2. CREATE TABLE parquet_table
  3. USING parquet
  4. LOCATION 'file:///tmp/parquet_dataset/';
  5. # CTAS by loading data into Hudi table
  6. CREATE TABLE hudi_table_ctas
  7. USING hudi
  8. TBLPROPERTIES (
  9. type = 'cow',
  10. preCombineField = 'ts'
  11. )
  12. PARTITIONED BY (dt)
  13. AS SELECT * FROM parquet_table;

You can create a non-partitioned table as well

  1. # create managed parquet table
  2. CREATE TABLE parquet_table
  3. USING parquet
  4. LOCATION 'file:///tmp/parquet_dataset/';
  5. # CTAS by loading data into Hudi table
  6. CREATE TABLE hudi_table_ctas
  7. USING hudi
  8. TBLPROPERTIES (
  9. type = 'cow',
  10. preCombineField = 'ts'
  11. )
  12. AS SELECT * FROM parquet_table;

If you prefer explicitly setting the record keys, you can do so by setting primaryKey config in table properties.

  1. CREATE TABLE hudi_table_ctas
  2. USING hudi
  3. TBLPROPERTIES (
  4. type = 'cow',
  5. primaryKey = 'id'
  6. )
  7. PARTITIONED BY (dt)
  8. AS
  9. SELECT 1 AS id, 'a1' AS name, 10 AS price, 1000 AS dt;

You can also use CTAS to copy data across external locations

  1. # create managed parquet table
  2. CREATE TABLE parquet_table
  3. USING parquet
  4. LOCATION 'file:///tmp/parquet_dataset/*.parquet';
  5. # CTAS by loading data into hudi table
  6. CREATE TABLE hudi_table_ctas
  7. USING hudi
  8. LOCATION 'file:///tmp/hudi/hudi_tbl/'
  9. TBLPROPERTIES (
  10. type = 'cow'
  11. )
  12. AS SELECT * FROM parquet_table;

Create Index (Experimental)

Hudi supports creating and dropping indexes, including functional indexes, on a table.

SQL DDL - 图5note

Creating indexes through SQL is in preview in version 1.0.0-beta only. It will be generally available in version 1.0.0. Please report any issues you find either via GitHub issues or creating a JIRA.

  1. -- Create Index
  2. CREATE INDEX [IF NOT EXISTS] index_name ON [TABLE] table_name
  3. [USING index_type]
  4. (column_name1 [OPTIONS(key1=value1, key2=value2, ...)], column_name2 [OPTIONS(key1=value1, key2=value2, ...)], ...)
  5. [OPTIONS (key1=value1, key2=value2, ...)]
  6. -- Drop Index
  7. DROP INDEX [IF EXISTS] index_name ON [TABLE] table_name
  • index_name is the name of the index to be created or dropped.
  • table_name is the name of the table on which the index is created or dropped.
  • index_type is the type of the index to be created. Currently, only files, column_stats and bloom_filters is supported.
  • column_name is the name of the column on which the index is created.
  • Both index and column on which the index is created can be qualified with some options in the form of key-value pairs. We will see this with an example of functional index below.

Create Functional Index

A functional index is an index on a function of a column. It is a new addition to Hudi’s multi-modal indexing subsystem which provides faster access method and also absorb partitioning as part of the indexing system. Let us see some examples of creating a functional index.

  1. -- Create a functional index on the column `ts` (unix epoch) of the table `hudi_table` using the function `from_unixtime` with the format `yyyy-MM-dd`
  2. CREATE INDEX IF NOT EXISTS ts_datestr ON hudi_table USING column_stats(ts) OPTIONS(func='from_unixtime', format='yyyy-MM-dd');
  3. -- Create a functional index on the column `ts` (timestamp in yyyy-MM-dd HH:mm:ss) of the table `hudi_table` using the function `hour`
  4. CREATE INDEX ts_hour ON hudi_table USING column_stats(ts) options(func='hour');

Few things to note:

  • The func option is required for creating functional index, and it should be a valid Spark SQL function. Currently, only the functions that take a single column as input are supported. Some useful functions that are supported are listed below.
    • identity
    • from_unixtime
    • date_format
    • to_date
    • to_timestamp
    • year
    • month
    • day
    • hour
    • lower
    • upper
    • substring
    • regexp_extract
    • regexp_replace
    • concat
    • length
  • Please check the syntax for the above functions in the Spark SQL documentation and provide the options accordingly. For example, the format option is required for from_unixtime function.
  • UDFs are not supported.

Example of creating and using functional index

  1. -- create a Hudi table
  2. CREATE TABLE hudi_table_func_index (
  3. ts STRING,
  4. uuid STRING,
  5. rider STRING,
  6. driver STRING,
  7. fare DOUBLE,
  8. city STRING
  9. ) USING HUDI
  10. tblproperties (primaryKey = 'uuid')
  11. PARTITIONED BY (city)
  12. location 'file:///tmp/hudi_table_func_index';
  13. -- disable small file handling so the each insert creates new file --
  14. set hoodie.parquet.small.file.limit=0;
  15. INSERT INTO hudi_table_func_index VALUES ('2023-09-20 03:58:59','334e26e9-8355-45cc-97c6-c31daf0df330','rider-A','driver-K',19.10,'san_francisco');
  16. INSERT INTO hudi_table_func_index VALUES ('2023-09-19 08:46:34','e96c4396-3fad-413a-a942-4cb36106d721','rider-C','driver-M',27.70 ,'san_francisco');
  17. INSERT INTO hudi_table_func_index VALUES ('2023-09-18 17:45:31','9909a8b1-2d15-4d3d-8ec9-efc48c536a00','rider-D','driver-L',33.90 ,'san_francisco');
  18. INSERT INTO hudi_table_func_index VALUES ('2023-09-22 13:12:56','1dced545-862b-4ceb-8b43-d2a568f6616b','rider-E','driver-O',93.50,'san_francisco');
  19. INSERT INTO hudi_table_func_index VALUES ('2023-09-24 06:15:45','e3cf430c-889d-4015-bc98-59bdce1e530c','rider-F','driver-P',34.15,'sao_paulo');
  20. INSERT INTO hudi_table_func_index VALUES ('2023-09-22 15:21:36','7a84095f-737f-40bc-b62f-6b69664712d2','rider-G','driver-Q',43.40 ,'sao_paulo');
  21. INSERT INTO hudi_table_func_index VALUES ('2023-09-20 12:35:45','3eeb61f7-c2b0-4636-99bd-5d7a5a1d2c04','rider-I','driver-S',41.06 ,'chennai');
  22. INSERT INTO hudi_table_func_index VALUES ('2023-09-19 05:34:56','c8abbe79-8d89-47ea-b4ce-4d224bae5bfa','rider-J','driver-T',17.85,'chennai');
  23. -- Query with hour function filter but no idex yet --
  24. spark-sql> SELECT city, fare, rider, driver FROM hudi_table_func_index WHERE city NOT IN ('chennai') AND hour(ts) > 12;
  25. san_francisco 93.5 rider-E driver-O
  26. san_francisco 33.9 rider-D driver-L
  27. sao_paulo 43.4 rider-G driver-Q
  28. Time taken: 0.208 seconds, Fetched 3 row(s)
  29. spark-sql> EXPLAIN COST SELECT city, fare, rider, driver FROM hudi_table_func_index WHERE city NOT IN ('chennai') AND hour(ts) > 12;
  30. == Optimized Logical Plan ==
  31. Project [city#3465, fare#3464, rider#3462, driver#3463], Statistics(sizeInBytes=899.5 KiB)
  32. +- Filter ((isnotnull(city#3465) AND isnotnull(ts#3460)) AND (NOT (city#3465 = chennai) AND (hour(cast(ts#3460 as timestamp), Some(Asia/Kolkata)) > 12))), Statistics(sizeInBytes=2.5 MiB)
  33. +- Relation default.hudi_table_func_index[_hoodie_commit_time#3455,_hoodie_commit_seqno#3456,_hoodie_record_key#3457,_hoodie_partition_path#3458,_hoodie_file_name#3459,ts#3460,uuid#3461,rider#3462,driver#3463,fare#3464,city#3465] parquet, Statistics(sizeInBytes=2.5 MiB)
  34. == Physical Plan ==
  35. *(1) Project [city#3465, fare#3464, rider#3462, driver#3463]
  36. +- *(1) Filter (isnotnull(ts#3460) AND (hour(cast(ts#3460 as timestamp), Some(Asia/Kolkata)) > 12))
  37. +- *(1) ColumnarToRow
  38. +- FileScan parquet default.hudi_table_func_index[ts#3460,rider#3462,driver#3463,fare#3464,city#3465] Batched: true, DataFilters: [isnotnull(ts#3460), (hour(cast(ts#3460 as timestamp), Some(Asia/Kolkata)) > 12)], Format: Parquet, Location: HoodieFileIndex(1 paths)[file:/tmp/hudi_table_func_index], PartitionFilters: [isnotnull(city#3465), NOT (city#3465 = chennai)], PushedFilters: [IsNotNull(ts)], ReadSchema: struct<ts:string,rider:string,driver:string,fare:double>
  39. -- create the functional index --
  40. CREATE INDEX ts_hour ON hudi_table_func_index USING column_stats(ts) options(func='hour');
  41. -- query after creating the index --
  42. spark-sql> SELECT city, fare, rider, driver FROM hudi_table_func_index WHERE city NOT IN ('chennai') AND hour(ts) > 12;
  43. san_francisco 93.5 rider-E driver-O
  44. san_francisco 33.9 rider-D driver-L
  45. sao_paulo 43.4 rider-G driver-Q
  46. Time taken: 0.202 seconds, Fetched 3 row(s)
  47. spark-sql> EXPLAIN COST SELECT city, fare, rider, driver FROM hudi_table_func_index WHERE city NOT IN ('chennai') AND hour(ts) > 12;
  48. == Optimized Logical Plan ==
  49. Project [city#2970, fare#2969, rider#2967, driver#2968], Statistics(sizeInBytes=449.8 KiB)
  50. +- Filter ((isnotnull(city#2970) AND isnotnull(ts#2965)) AND (NOT (city#2970 = chennai) AND (hour(cast(ts#2965 as timestamp), Some(Asia/Kolkata)) > 12))), Statistics(sizeInBytes=1278.3 KiB)
  51. +- Relation default.hudi_table_func_index[_hoodie_commit_time#2960,_hoodie_commit_seqno#2961,_hoodie_record_key#2962,_hoodie_partition_path#2963,_hoodie_file_name#2964,ts#2965,uuid#2966,rider#2967,driver#2968,fare#2969,city#2970] parquet, Statistics(sizeInBytes=1278.3 KiB)
  52. == Physical Plan ==
  53. *(1) Project [city#2970, fare#2969, rider#2967, driver#2968]
  54. +- *(1) Filter (isnotnull(ts#2965) AND (hour(cast(ts#2965 as timestamp), Some(Asia/Kolkata)) > 12))
  55. +- *(1) ColumnarToRow
  56. +- FileScan parquet default.hudi_table_func_index[ts#2965,rider#2967,driver#2968,fare#2969,city#2970] Batched: true, DataFilters: [isnotnull(ts#2965), (hour(cast(ts#2965 as timestamp), Some(Asia/Kolkata)) > 12)], Format: Parquet, Location: HoodieFileIndex(1 paths)[file:/tmp/hudi_table_func_index], PartitionFilters: [isnotnull(city#2970), NOT (city#2970 = chennai)], PushedFilters: [IsNotNull(ts)], ReadSchema: struct<ts:string,rider:string,driver:string,fare:double>

Setting Hudi configs

There are different ways you can pass the configs for a given hudi table.

Using set command

You can use the set command to set any of Hudi’s write configs. This will apply to operations across the whole spark session.

  1. set hoodie.insert.shuffle.parallelism = 100;
  2. set hoodie.upsert.shuffle.parallelism = 100;
  3. set hoodie.delete.shuffle.parallelism = 100;

Using table properties

You can also configure table options when creating a table. This will be applied only for the table and override any SET command values.

  1. CREATE TABLE IF NOT EXISTS tableName (
  2. colName1 colType1,
  3. colName2 colType2,
  4. ...
  5. ) USING hudi
  6. TBLPROPERTIES (
  7. primaryKey = '${colName1}',
  8. type = 'cow',
  9. ${hoodie.config.key1} = '${hoodie.config.value1}',
  10. ${hoodie.config.key2} = '${hoodie.config.value2}',
  11. ....
  12. );
  13. e.g.
  14. CREATE TABLE IF NOT EXISTS hudi_table (
  15. id BIGINT,
  16. name STRING,
  17. price DOUBLE
  18. ) USING hudi
  19. TBLPROPERTIES (
  20. primaryKey = 'id',
  21. type = 'cow',
  22. hoodie.cleaner.fileversions.retained = '20',
  23. hoodie.keep.max.commits = '20'
  24. );

Table Properties

Users can set table properties while creating a table. The important table properties are discussed below.

Parameter NameDefaultDescription
typecowThe table type to create. type = ‘cow’ creates a COPY-ON-WRITE table, while type = ‘mor’ creates a MERGE-ON-READ table. Same as hoodie.datasource.write.table.type. More details can be found here
primaryKeyuuidThe primary key field names of the table separated by commas. Same as hoodie.datasource.write.recordkey.field. If this config is ignored, hudi will auto-generate primary keys. If explicitly set, primary key generation will honor user configuration.
preCombineFieldThe pre-combine field of the table. It is used for resolving the final version of the record among multiple versions. Generally, event time or another similar column will be used for ordering purposes. Hudi will be able to handle out-of-order data using the preCombine field value.

SQL DDL - 图6note

primaryKey, preCombineField, and type and other properties are case-sensitive.

Passing Lock Providers for Concurrent Writers

Hudi requires a lock provider to support concurrent writers or asynchronous table services when using OCC and NBCC (Non-Blocking Concurrency Control) concurrency mode. For NBCC mode, locking is only used to write the commit metadata file in the timeline. Writes are serialized by completion time. Users can pass these table properties into TBLPROPERTIES as well. Below is an example for a Zookeeper based configuration.

  1. -- Properties to use Lock configurations to support Multi Writers
  2. TBLPROPERTIES(
  3. hoodie.write.lock.zookeeper.url = "zookeeper",
  4. hoodie.write.lock.zookeeper.port = "2181",
  5. hoodie.write.lock.zookeeper.lock_key = "tableName",
  6. hoodie.write.lock.provider = "org.apache.hudi.client.transaction.lock.ZookeeperBasedLockProvider",
  7. hoodie.write.concurrency.mode = "optimistic_concurrency_control",
  8. hoodie.write.lock.zookeeper.base_path = "/tableName"
  9. )

Enabling Column Stats / Record Level Index for the table

Hudi provides the ability to leverage rich metadata and index about the table, speed up DMLs and queries. For e.g: collection of column statistics can be enabled to perform quick data skipping or a record-level index can be used to perform fast updates or point lookups using the following table properties.

For more, see Metadata Configurations

  1. TBLPROPERTIES(
  2. 'hoodie.metadata.index.column.stats.enable' = 'true'
  3. 'hoodie.metadata.record.index.enable' = 'true'
  4. )

Spark Alter Table

Syntax

  1. -- Alter table name
  2. ALTER TABLE oldTableName RENAME TO newTableName;
  3. -- Alter table add columns
  4. ALTER TABLE tableIdentifier ADD COLUMNS(colAndType [, colAndType]);

Examples

  1. --rename to:
  2. ALTER TABLE hudi_table RENAME TO hudi_table_renamed;
  3. --add column:
  4. ALTER TABLE hudi_table ADD COLUMNS(remark STRING);

Modifying Table Properties

Syntax

  1. -- alter table ... set|unset
  2. ALTER TABLE tableIdentifier SET|UNSET TBLPROPERTIES (table_property = 'property_value');

Examples

  1. ALTER TABLE hudi_table SET TBLPROPERTIES (hoodie.keep.max.commits = '10');
  2. ALTER TABLE hudi_table SET TBLPROPERTIES ("note" = "don't drop this table");
  3. ALTER TABLE hudi_table UNSET TBLPROPERTIES IF EXISTS (hoodie.keep.max.commits);
  4. ALTER TABLE hudi_table UNSET TBLPROPERTIES IF EXISTS ('note');

SQL DDL - 图7note

Currently, trying to change the column type may throw an error ALTER TABLE CHANGE COLUMN is not supported for changing column colName with oldColType to colName with newColType., due to an open SPARK issue

Alter config options

You can also alter the write config for a table by the ALTER TABLE SET SERDEPROPERTIES

Syntax

  1. -- alter table ... set|unset
  2. ALTER TABLE tableName SET SERDEPROPERTIES ('property' = 'property_value');

Example

  1. ALTER TABLE hudi_table SET SERDEPROPERTIES ('key1' = 'value1');

Show and drop partitions

Syntax

  1. -- Show partitions
  2. SHOW PARTITIONS tableIdentifier;
  3. -- Drop partition
  4. ALTER TABLE tableIdentifier DROP PARTITION ( partition_col_name = partition_col_val [ , ... ] );

Examples

  1. --Show partition:
  2. SHOW PARTITIONS hudi_table;
  3. --Drop partition
  4. ALTER TABLE hudi_table DROP PARTITION (dt='2021-12-09', hh='10');

Caveats

Hudi currently has the following limitations when using Spark SQL, to create/alter tables.

  • ALTER TABLE ... RENAME TO ... is not supported when using AWS Glue Data Catalog as hive metastore as Glue itself does not support table renames.
  • A new Hudi table created by Spark SQL will by default set hoodie.datasource.write.hive_style_partitioning=true, for ease of use. This can be overridden using table properties.

Create Catalog

The catalog helps to manage the SQL tables, the table can be shared among sessions if the catalog persists the table definitions. For hms mode, the catalog also supplements the hive syncing options.

Example

  1. CREATE CATALOG hoodie_catalog
  2. WITH (
  3. 'type'='hudi',
  4. 'catalog.path' = '${catalog default root path}',
  5. 'hive.conf.dir' = '${directory where hive-site.xml is located}',
  6. 'mode'='hms' -- supports 'dfs' mode that uses the DFS backend for table DDLs persistence
  7. );

Options

Option NameRequiredDefaultRemarks
catalog.pathtrueDefault path for the catalog’s table storage, the path is used to infer the table path automatically, the default table path: ${catalog.path}/${db_name}/${table_name}
default-databasefalsedefaultdefault database name
hive.conf.dirfalseThe directory where hive-site.xml is located, only valid in hms mode
modefalsedfsSupports hms mode that uses HMS to persist the table options
table.externalfalsefalseWhether to create the external table, only valid in hms mode

Create Table

You can create tables using standard FLINK SQL CREATE TABLE syntax, which supports partitioning and passing Flink options using WITH.

  1. CREATE TABLE [IF NOT EXISTS] [catalog_name.][db_name.]table_name
  2. (
  3. { <physical_column_definition>
  4. [ <table_constraint> ][ , ...n]
  5. )
  6. [COMMENT table_comment]
  7. [PARTITIONED BY (partition_column_name1, partition_column_name2, ...)]
  8. WITH (key1=val1, key2=val2, ...)

Create non-partitioned table

Creating a non-partitioned table is as simple as creating a regular table.

  1. -- create a Hudi table
  2. CREATE TABLE hudi_table(
  3. id BIGINT,
  4. name STRING,
  5. price DOUBLE
  6. )
  7. WITH (
  8. 'connector' = 'hudi',
  9. 'path' = 'file:///tmp/hudi_table',
  10. 'table.type' = 'MERGE_ON_READ'
  11. );

Create partitioned table

The following is an example of creating a Flink partitioned table.

  1. CREATE TABLE hudi_table(
  2. id BIGINT,
  3. name STRING,
  4. dt STRING,
  5. hh STRING
  6. )
  7. PARTITIONED BY (`dt`)
  8. WITH (
  9. 'connector' = 'hudi',
  10. 'path' = 'file:///tmp/hudi_table',
  11. 'table.type' = 'MERGE_ON_READ'
  12. );

Create table with record keys and ordering fields

The following is an example of creating a Flink table with record key and ordering field similarly to spark.

  1. CREATE TABLE hudi_table(
  2. id BIGINT PRIMARY KEY NOT ENFORCED,
  3. name STRING,
  4. price DOUBLE,
  5. ts BIGINT
  6. )
  7. PARTITIONED BY (`dt`)
  8. WITH (
  9. 'connector' = 'hudi',
  10. 'path' = 'file:///tmp/hudi_table',
  11. 'table.type' = 'MERGE_ON_READ',
  12. 'precombine.field' = 'ts'
  13. );

Alter Table

  1. ALTER TABLE tableA RENAME TO tableB;

Setting Hudi configs

Using table options

You can configure hoodie configs in table options when creating a table. You can refer Flink specific hoodie configs here These configs will be applied to all the operations on that table.

  1. CREATE TABLE IF NOT EXISTS tableName (
  2. colName1 colType1 PRIMARY KEY NOT ENFORCED,
  3. colName2 colType2,
  4. ...
  5. )
  6. WITH (
  7. 'connector' = 'hudi',
  8. 'path' = '${path}',
  9. ${hoodie.config.key1} = '${hoodie.config.value1}',
  10. ${hoodie.config.key2} = '${hoodie.config.value2}',
  11. ....
  12. );
  13. e.g.
  14. CREATE TABLE hudi_table(
  15. id BIGINT PRIMARY KEY NOT ENFORCED,
  16. name STRING,
  17. price DOUBLE,
  18. ts BIGINT
  19. )
  20. PARTITIONED BY (`dt`)
  21. WITH (
  22. 'connector' = 'hudi',
  23. 'path' = 'file:///tmp/hudi_table',
  24. 'table.type' = 'MERGE_ON_READ',
  25. 'precombine.field' = 'ts',
  26. 'hoodie.cleaner.fileversions.retained' = '20',
  27. 'hoodie.keep.max.commits' = '20',
  28. 'hoodie.datasource.write.hive_style_partitioning' = 'true'
  29. );

Supported Types

SparkHudiNotes
booleanboolean
byteint
shortint
integerint
longlong
datedate
timestamptimestamp
floatfloat
doubledouble
stringstring
decimaldecimal
binarybytes
arrayarray
mapmap
structstruct
charnot supported
varcharnot supported
numericnot supported
nullnot supported
objectnot supported