CREATE ICEBERG TABLE (Iceberg REST catalog)¶
Creates or replaces an Apache Iceberg™ table in the current/specified schema for an Iceberg REST catalog.
Use this command for the following scenarios:
You want to use a remote Iceberg catalog that complies with the open source Apache Iceberg REST OpenAPI specification.
You want to query a table in Snowflake Open Catalog or Apache Polaris™. For more information, see Query a table in Snowflake Open Catalog using Snowflake.
You want to create an externally managed table with write support in a catalog-linked database. See CREATE ICEBERG TABLE (catalog-linked database).
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 Apache Iceberg™ REST catalogs or Configure a catalog integration for Snowflake Open Catalog.
- 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>' ]
CATALOG_TABLE_NAME = '<rest_catalog_table_name>'
[ CATALOG_NAMESPACE = '<catalog_namespace>' ]
[ REPLACE_INVALID_CHARACTERS = { TRUE | FALSE } ]
[ AUTO_REFRESH = { TRUE | FALSE } ]
[ COMMENT = '<string_literal>' ]
[ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
[ WITH CONTACT ( <purpose> = <contact_name> [ , <purpose> = <contact_name> ... ] ) ]
Variant syntax¶
CREATE ICEBERG TABLE (catalog-linked database)¶
CREATE ICEBERG TABLE [ IF NOT EXISTS ] <table_name>
[
--Column definition
<col_name> <col_type>
[ [ WITH ] MASKING POLICY <policy_name> [ USING ( <col_name> , <cond_col1> , ... ) ] ]
-- Additional column definitions
[ , <col_name> <col_type> [ ... ] ]
]
[ MAX_DATA_EXTENSION_TIME_IN_DAYS = <integer> ]
[ AUTO_REFRESH = { TRUE | FALSE } ]
[ REPLACE_INVALID_CHARACTERS = { TRUE | FALSE } ]
[ COPY GRANTS ]
[ COMMENT = '<string_literal>' ]
[ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
CREATE ICEBERG TABLE (catalog-linked database) … AS SELECT¶
CREATE ICEBERG TABLE <table_name> [ ( <col_name> [ <col_type> ] , <col_name> [ <col_type> ] , ... ) ] [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ] [ ... ] AS SELECT <query>
You can apply a masking policy to a column in a CTAS statement. Specify the masking policy after the column data type. For example:
CREATE ICEBERG TABLE <table_name> ( <col1> <data_type> [ WITH ] MASKING POLICY <policy_name> [ , ... ] ) [ ... ] AS SELECT <query>
Required parameters¶
table_name
Specifies the identifier (name) for the table in Snowflake; 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.
Note
To retrieve a list of tables or namespaces in your remote catalog, you can use the following functions:
CATALOG_TABLE_NAME = 'rest_catalog_table_name'
Specifies the table name as recognized by your external catalog. This parameter can’t be changed after you create the table.
Note
Don’t specify a namespace with the table name (
mynamespace.mytable
). To specify a namespace for this table, and override the default namespace set for the catalog integration, use the CATALOG_NAMESPACE parameter.col_name
For creating a table in a catalog-linked database (preview).
Specifies a column identifier (name). All the requirements for table identifiers also apply to column identifiers.
For more information, see Identifier requirements and Reserved & limited keywords.
Note
In addition to the standard reserved keywords, the following keywords can’t be used as column identifiers because they are reserved for ANSI-standard context functions:
CURRENT_DATE
CURRENT_ROLE
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_USER
For the list of reserved keywords, see Reserved & limited keywords.
col_type
For creating a table in a catalog-linked database (preview).
Specifies the data type for the column.
For information about the data types that can be specified for table columns, see Data types for Apache Iceberg™ tables.
Optional parameters¶
MASKING POLICY = policy_name
For creating a table in a catalog-linked database (preview).
Specifies the masking policy to set on a column. The masking policy must belong to a standard Snowflake database (not the catalog-linked database).
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 you don’t specify this parameter, 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.
CATALOG_NAMESPACE = 'catalog_namespace'
Optionally specifies the namespace (for example,
my_database
) for the REST catalog source. By specifying a namespace with the catalog integration and then at the table level, you can use a single REST catalog integration to create Iceberg tables across different databases. If you don’t specify a namespace with the table, the table uses the default catalog namespace associated with the catalog integration.If a default namespace isn’t specified with the catalog integration, you must specify the namespace for the REST catalog source to set a catalog namespace for the table.
Note
To retrieve a list of tables or namespaces in your remote catalog, you can use the following functions:
MAX_DATA_EXTENSION_TIME_IN_DAYS = integer
Object parameter that specifies the maximum number of days for which Snowflake can extend the data retention period for the table to prevent streams on the table from becoming stale.
For a detailed description of this parameter, see MAX_DATA_EXTENSION_TIME_IN_DAYS.
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
AUTO_REFRESH = { TRUE | FALSE }
Specifies whether Snowflake should automatically poll the external Iceberg catalog that is associated with the table for metadata updates.
If no value is specified for the
REFRESH_INTERVAL_SECONDS
parameter on the catalog integration, Snowflake uses a default refresh interval of 30 seconds.For more information, see automated refresh.
Default: FALSE
Note
Using AUTO_REFRESH with INFER_SCHEMA isn’t supported.
COPY GRANTS
Specifies to retain the access privileges from the original table when a new table is created using any of the following CREATE TABLE variants:
CREATE OR REPLACE TABLE
The parameter copies all privileges, except OWNERSHIP, from the existing table to the new table. The new table does not inherit any future grants defined for the object type in the schema. By default, the role that executes the CREATE TABLE statement owns the new table.
If the parameter is not included in the CREATE ICEBERG TABLE statement, then the new table does not inherit any explicit access privileges granted on the original table, but does inherit any future grants defined for the object type in the schema.
Note:
With data sharing:
If the existing table was shared to another account, the replacement table is also shared.
If the existing table was shared with your account as a data consumer, and access was further granted to other roles in the account (using
GRANT IMPORTED PRIVILEGES
on the parent database), access is also granted to the replacement table.
The SHOW GRANTS output for the replacement table lists the grantee for the copied privileges as the role that executed the CREATE ICEBERG TABLE statement, with the current timestamp when the statement was executed.
The operation to copy grants occurs atomically in the CREATE ICEBERG TABLE command (that is, within the same transaction).
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 quota for objects.
WITH CONTACT ( purpose = contact [ , purpose = contact ...] )
Associate the new object with one or more contacts.
Access control requirements¶
A role used to execute this operation 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¶
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).For creating an Iceberg table with write support (preview):
If you use a standard Snowflake database, you must first create an Iceberg table in your remote catalog. For example, you might use Spark to write an Iceberg table to Open Catalog. Don’t specify column definitions in your CREATE ICEBERG TABLE statement.
If you use a catalog-linked database, you must specify column definitions when you create the table. Alternatively, you can write to Iceberg tables that Snowflake automatically discovers in your remote catalog.
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.
The
OR REPLACE
andIF NOT EXISTS
clauses are mutually exclusive. They can’t both be used in the same statement.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¶
Create an Iceberg table that uses a remote Iceberg REST catalog¶
CREATE OR REPLACE ICEBERG TABLE my_iceberg_table
EXTERNAL_VOLUME = 'my_external_volume'
CATALOG = 'my_rest_catalog_integration'
CATALOG_TABLE_NAME = 'my_remote_table'
AUTO_REFRESH = TRUE;
Create an Iceberg table to query a table in Snowflake Open Catalog¶
This example creates an Iceberg table that you can use to Query a table in Snowflake Open Catalog using Snowflake.
CREATE ICEBERG TABLE open_catalog_iceberg_table
EXTERNAL_VOLUME = 'my_external_volume'
CATALOG = 'open_catalog_int'
CATALOG_TABLE_NAME = 'my_open_catalog_table'
AUTO_REFRESH = TRUE;
Create an Iceberg table in a catalog-linked database¶
The following example creates a writable Iceberg table in a catalog-linked database with column definitions.
USE DATABASE my_catalog_linked_db;
USE SCHEMA 'my_namespace';
CREATE OR REPLACE ICEBERG TABLE my_iceberg_table (
first_name string,
last_name string,
amount int,
create_date date
);