CREATE ICEBERG TABLE¶
Erzeugt oder ersetzt eine Apache Iceberg™-Tabelle im aktuellen/angegebenen Schema.
Syntax¶
Dieser Abschnitt bietet einen Überblick über die Syntax für alle Typen von Iceberg-Tabellen. Die Syntax zum Erstellen einer Iceberg-Tabelle unterscheidet sich erheblich, je nachdem, ob Sie Snowflake als Iceberg-Katalog oder einen externen Iceberg-Katalog verwenden.
Syntax, Parameterbeschreibungen, Nutzungshinweise und Beispiele für bestimmte Anwendungsfälle finden Sie auf den folgenden Seiten:
Snowflake als Iceberg-Katalog
Externer Iceberg-Katalog
Snowflake als Iceberg-Katalog¶
CREATE [ OR REPLACE ] ICEBERG TABLE [ IF NOT EXISTS ] <table_name> (
-- Column definition
<col_name> <col_type>
[ inlineConstraint ]
[ NOT NULL ]
[ COLLATE '<collation_specification>' ]
[ { DEFAULT <expr>
| { AUTOINCREMENT | IDENTITY }
[ { ( <start_num> , <step_num> )
| START <num> INCREMENT <num>
} ]
} ]
[ [ WITH ] MASKING POLICY <policy_name> [ USING ( <col_name> , <cond_col1> , ... ) ] ]
[ [ WITH ] PROJECTION POLICY <policy_name> ]
[ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
[ COMMENT '<string_literal>' ]
-- Additional column definitions
[ , <col_name> <col_type> [ ... ] ]
-- Out-of-line constraints
[ , outoflineConstraint [ ... ] ]
)
[ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ]
[ EXTERNAL_VOLUME = '<external_volume_name>' ]
[ CATALOG = 'SNOWFLAKE' ]
BASE_LOCATION = '<directory_for_table_files>'
[ CATALOG_SYNC = '<open_catalog_integration_name>']
[ STORAGE_SERIALIZATION_POLICY = { COMPATIBLE | OPTIMIZED } ]
[ DATA_RETENTION_TIME_IN_DAYS = <integer> ]
[ MAX_DATA_EXTENSION_TIME_IN_DAYS = <integer> ]
[ CHANGE_TRACKING = { TRUE | FALSE } ]
[ DEFAULT_DDL_COLLATION = '<collation_specification>' ]
[ COPY GRANTS ]
[ COMMENT = '<string_literal>' ]
[ [ WITH ] ROW ACCESS POLICY <policy_name> ON ( <col_name> [ , <col_name> ... ] ) ]
[ [ WITH ] AGGREGATION POLICY <policy_name> ]
[ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
Wobei:
inlineConstraint ::= [ CONSTRAINT <constraint_name> ] { UNIQUE | PRIMARY KEY | [ FOREIGN KEY ] REFERENCES <ref_table_name> [ ( <ref_col_name> ) ] } [ <constraint_properties> ]Weitere Details zu Inline-Einschränkungen finden Sie unter CREATE | ALTER TABLE … CONSTRAINT.
outoflineConstraint ::= [ CONSTRAINT <constraint_name> ] { UNIQUE [ ( <col_name> [ , <col_name> , ... ] ) ] | PRIMARY KEY [ ( <col_name> [ , <col_name> , ... ] ) ] | [ FOREIGN KEY ] [ ( <col_name> [ , <col_name> , ... ] ) ] REFERENCES <ref_table_name> [ ( <ref_col_name> [ , <ref_col_name> , ... ] ) ] } [ <constraint_properties> ]Bemerkung
Snowflake repräsentiert Spalten, die als PRIMARY KEY definiert sind, als Bezeichnerfelder in den Iceberg-Metadaten dar. Die IDs für diese Spalten werden in den Metadaten als Bezeichnerfeld-IDs eingefügt.
Snowflake erzwingt keine NOT NULL- und UNIQUE-Einschränkungen auf PRIMARY KEY-Spalten für Iceberg-Tabellen.
Weitere Details zu Out-of-Line-Einschränkungen finden Sie unter CREATE | ALTER TABLE … CONSTRAINT.
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE (Snowflake als Iceberg-Katalog).
CREATE ICEBERG TABLE … AS SELECT (auch als CTAS bezeichnet)
CREATE [ OR REPLACE ] ICEBERG TABLE <table_name> [ ( <col_name> [ <col_type> ] , <col_name> [ <col_type> ] , ... ) ] [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ] [ EXTERNAL_VOLUME = '<external_volume_name>' ] [ CATALOG = 'SNOWFLAKE' ] BASE_LOCATION = '<relative_path_from_external_volume>' [ COPY GRANTS ] [ ... ] AS SELECT <query>
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE … AS SELECT.
CREATE ICEBERG TABLE … LIKE
CREATE [ OR REPLACE ] ICEBERG TABLE <table_name> LIKE <source_table> [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ] [ COPY GRANTS ] [ ... ]
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE … LIKE.
Externer Iceberg-Katalog¶
AWS Glue
CREATE [ OR REPLACE ] ICEBERG TABLE [ IF NOT EXISTS ] <table_name>
[ EXTERNAL_VOLUME = '<external_volume_name>' ]
[ CATALOG = '<catalog_integration_name>' ]
CATALOG_TABLE_NAME = '<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>' , ... ] ) ]
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE (AWS Glue als Iceberg-Katalog).
Iceberg-Dateien im Objektspeicher
CREATE [ OR REPLACE ] ICEBERG TABLE [ IF NOT EXISTS ] <table_name>
[ EXTERNAL_VOLUME = '<external_volume_name>' ]
[ CATALOG = '<catalog_integration_name>' ]
METADATA_FILE_PATH = '<metadata_file_path>'
[ REPLACE_INVALID_CHARACTERS = { TRUE | FALSE } ]
[ COMMENT = '<string_literal>' ]
[ [ WITH ] TAG ( <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' , ... ] ) ]
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE (Iceberg-Dateien im Objektspeicher).
Delta-Dateien
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>' , ... ] ) ]
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE (Delta-Dateien im Objektspeicher).
Iceberg REST API oder Snowflake Open Catalog
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>' , ... ] ) ]
Weitere Informationen dazu finden Sie unter CREATE ICEBERG TABLE (Iceberg REST Katalog).