CREATE ICEBERG TABLE (Delta files in object storage)¶

Creates or replaces an Apache Iceberg™ table in the current/specified schema using Delta table files in object storage (external cloud storage). This type of Iceberg table requires a catalog integration.

This topic refers to Iceberg tables as simply “tables” except where specifying Iceberg tables avoids confusion.

Note

Before creating a table, you must create the external volume where the Iceberg metadata and data files are stored. For instructions, see Configure an external volume.

You also need a catalog integration for the table. For more information, see Configure a catalog integration for files in object storage.

See also:

ALTER ICEBERG TABLE , DROP ICEBERG TABLE , SHOW ICEBERG TABLES , DESCRIBE ICEBERG TABLE , UNDROP ICEBERG TABLE

Syntax¶

CREATE [ OR REPLACE ] ICEBERG TABLE [ IF NOT EXISTS ] <table_name>
  [ EXTERNAL_VOLUME = '<external_volume_name>' ]
  [ CATALOG = '<catalog_integration_name>' ]
  BASE_LOCATION = '<relative_path_from_external_volume>'
  [ REPLACE_INVALID_CHARACTERS = { TRUE | FALSE } ]
  [ COMMENT = '<string_literal>' ]
  [ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
Copy

Required parameters¶

table_name

Specifies the identifier (name) for the table; must be unique for the schema in which the table is created.

In addition, the identifier must start with an alphabetic character and cannot contain spaces or special characters unless the entire identifier string is enclosed in double quotes (for example, "My object"). Identifiers enclosed in double quotes are also case-sensitive.

For more information, see Identifier requirements.

BASE_LOCATION = 'relative_path_from_external_volume'

Specifies a relative path from the table’s EXTERNAL_VOLUME location to a directory where Snowflake can access your Delta table files.

The base location must point to a directory and cannot point to a single file. It must contain the Delta transaction log subfolder (for example, my/base/location/_delta_log/).

Optional parameters¶

EXTERNAL_VOLUME = 'external_volume_name'

Specifies the identifier (name) for the external volume where the Iceberg table stores its metadata files and data in Parquet format. Iceberg metadata and manifest files store the table schema, partitions, snapshots, and other metadata.

If you don’t specify this parameter, the Iceberg table defaults to the external volume for the schema, database, or account. The schema takes precedence over the database, and the database takes precedence over the account.

CATALOG = 'catalog_integration_name'

Specifies the identifier (name) of the catalog integration for this table.

If not specified, the Iceberg table defaults to the catalog integration for the schema, database, or account. The schema takes precedence over the database, and the database takes precedence over the account.

REPLACE_INVALID_CHARACTERS = { TRUE | FALSE }

Specifies whether to replace invalid UTF-8 characters with the Unicode replacement character (ďż˝) in query results. You can only set this parameter for tables that use an external Iceberg catalog.

  • TRUE replaces invalid UTF-8 characters with the Unicode replacement character.

  • FALSE leaves invalid UTF-8 characters unchanged. Snowflake returns a user error message when it encounters invalid UTF-8 characters in a Parquet data file.

If not specified, the Iceberg table defaults to the parameter value for the schema, database, or account. The schema takes precedence over the database, and the database takes precedence over the account.

Default: FALSE

COMMENT = 'string_literal'

Specifies a comment for the table.

Default: No value

TAG ( tag_name = 'tag_value' [ , tag_name = 'tag_value' , ... ] )

Specifies the tag name and the tag string value.

The tag value is always a string, and the maximum number of characters for the tag value is 256.

For information about specifying tags in a statement, see Tag quotas for objects and columns.

Access control requirements¶

A role used to execute this SQL command must have the following privileges at a minimum:

Privilege

Object

Notes

CREATE ICEBERG TABLE

Schema

CREATE EXTERNAL VOLUME

Account

Required to create a new external volume.

USAGE

External Volume

Required to reference an existing external volume.

CREATE INTEGRATION

Account

Required to create a new catalog integration.

USAGE

Catalog integration

Required to reference an existing catalog integration.

The USAGE privilege on the parent database and schema are required to perform operations on any object in a schema.

For instructions on creating a custom role with a specified set of privileges, see Creating custom roles.

For general information about roles and privilege grants for performing SQL actions on securable objects, see Overview of Access Control.

Usage notes¶

  • Considerations for running this command:

    • If you created your external volume or catalog integration using a double-quoted identifier, you must specify the identifier exactly as created (including the double quotes) in your CREATE ICEBERG TABLE statement. Failure to include the quotes might result in an Object does not exist error (or similar type of error).

  • Considerations for Iceberg tables created from Delta table files:

    • You can use Time Travel to query Iceberg tables created from Delta table files. The table versions correspond to the individual Delta log commit files.

    • Iceberg tables are compatible with data generated by Delta Lake version 3.1 and earlier.

    • Snowflake streams aren’t supported for Iceberg tables created from Delta table files with partition columns. However, insert-only streams for tables created from Delta files without partition columns are supported.

    • Dynamic tables aren’t supported on Iceberg tables created from Delta table files.

    • Snowflake doesn’t support creating Iceberg tables from Delta table definitions in the AWS Glue Data Catalog.

    • Parquet files (data files for Delta tables) that use any of the following features or data types aren’t supported:

      • Field IDs.

      • The INTERVAL data type.

      • The DECIMAL data type with precision higher than 38.

      • LIST or MAP types with one-level or two-level representation.

      • Unsigned integer types (INT(signed = false)).

      • The FLOAT16 data type.

      For more information about Delta data types and Iceberg tables, see Delta data types.

    • Refresh operations during CREATE and ALTER … REFRESH can process a maximum of 1,000 Delta commit files per operation.

      Note

      Snowflake uses Delta checkpoint files when creating an Iceberg table. The 1,000 commit file limit only applies to commits after the latest checkpoint.

    • Generating Iceberg metadata using the SYSTEM$GET_ICEBERG_TABLE_INFORMATION function isn’t supported.

    • The following Delta Lake features aren’t currently supported: Row tracking, deletion vector files, change data files, change metadata, DataChange, CDC, protocol evolution.

  • Considerations for creating tables:

    • A schema cannot contain tables and/or views with the same name. When creating a table:

      • If a view with the same name already exists in the schema, an error is returned and the table is not created.

      • If a table with the same name already exists in the schema, an error is returned and the table is not created, unless the optional OR REPLACE keyword is included in the command.

    • CREATE OR REPLACE <object> statements are atomic. That is, when an object is replaced, the old object is deleted and the new object is created in a single transaction.

      This means that any queries concurrent with the CREATE OR REPLACE ICEBERG TABLE operation use either the old or new table version.

    • Similar to reserved keywords, ANSI-reserved function names (CURRENT_DATE, CURRENT_TIMESTAMP, etc.) cannot be used as column names.

    • Recreating a table (using the optional OR REPLACE keyword) drops its history, which makes any stream on the table stale. A stale stream is unreadable.

  • Regarding metadata:

    Attention

    Customers should ensure that no personal data (other than for a User object), sensitive data, export-controlled data, or other regulated data is entered as metadata when using the Snowflake service. For more information, see Metadata fields in Snowflake.

Examples¶

The following example command creates an Iceberg table from Delta table files in object storage.

The example specifies an external volume associated with the cloud location of the Delta table files, a catalog integration configured for Delta, and a value for the required BASE_LOCATION parameter.

CREATE ICEBERG TABLE my_delta_iceberg_table
  CATALOG = delta_catalog_integration
  EXTERNAL_VOLUME = delta_external_volume
  BASE_LOCATION = 'relative/path/from/ext/vol/';
Copy

If the Delta table uses a partitioning scheme, Snowflake automatically interprets the scheme from the Delta log.