Categories:
Table, View, & Sequence DDL

CREATE TABLE

Creates a new table in the current/specified schema or replaces an existing table. A table can have multiple columns, with each column definition consisting of a name, data type, and optionally whether the column has:

  • A default value and/or requires a value (NOT NULL).
  • Any referential integrity constraints (primary key, foreign key, etc.).

In addition, this command supports the following variants:

  • CREATE TABLE … AS SELECT (creates a populated table; also referred to as CTAS)
  • CREATE TABLE … LIKE (creates an empty copy of an existing table)
  • CREATE TABLE … CLONE (creates a clone of an existing table)
See also:
ALTER TABLE , DROP TABLE , SHOW TABLES

In this Topic:

Syntax

CREATE [ OR REPLACE ] [ { [ LOCAL | GLOBAL ] TEMP[ORARY] | VOLATILE } | TRANSIENT ] TABLE [ IF NOT EXISTS ]
  <table_name>
    ( <col_name> <col_type> [ { DEFAULT <expr>
                               | { AUTOINCREMENT | IDENTITY } [ ( <start_num> , <step_num> ) | START <num> INCREMENT <num> ] } ]
                                /* AUTOINCREMENT (or IDENTITY) supported only for numeric data types (NUMBER, INT, FLOAT, etc.) */
                            [ inlineConstraint ]
      [ , <col_name> <col_type> [ ... ] ]
      [ , outoflineConstraint ]
      [ , ... ] )
  [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ]
  [ STAGE_FILE_FORMAT = ( { FORMAT_NAME = '<file_format_name>'
                           | TYPE = { CSV | JSON | AVRO | ORC | PARQUET | XML } [ formatTypeOptions ] } ) ]
  [ STAGE_COPY_OPTIONS = ( copyOptions ) ]
  [ DATA_RETENTION_TIME_IN_DAYS = <num> ]
  [ COPY GRANTS ]
  [ COMMENT = '<string_literal>' ]

Where:

inlineConstraint
inlineConstraint ::=
  [ NOT NULL ]
  [ CONSTRAINT <constraint_name> ]
  { UNIQUE | PRIMARY KEY | { [ FOREIGN KEY ] REFERENCES <ref_table_name> [ ( <ref_col_name> ) ] } }
  [ <constraint_properties> ]

For additional inline constraint details, see CREATE | ALTER TABLE … CONSTRAINT.

outoflineConstraint
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> ]

For additional out-of-line constraint details, see CREATE | ALTER TABLE … CONSTRAINT.

formatTypeOptions (type-specific)
formatTypeOptions ::=
-- If TYPE = CSV
     COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
     RECORD_DELIMITER = '<character>' | NONE
     FIELD_DELIMITER = '<character>' | NONE
     FILE_EXTENSION = '<string>'
     SKIP_HEADER = <integer>
     DATE_FORMAT = '<string>' | AUTO
     TIME_FORMAT = '<string>' | AUTO
     TIMESTAMP_FORMAT = '<string>' | AUTO
     BINARY_FORMAT = HEX | BASE64 | UTF8
     ESCAPE = '<character>' | NONE
     ESCAPE_UNENCLOSED_FIELD = '<character>' | NONE
     TRIM_SPACE = TRUE | FALSE
     FIELD_OPTIONALLY_ENCLOSED_BY = '<character>' | NONE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
     ERROR_ON_COLUMN_COUNT_MISMATCH = TRUE | FALSE
     VALIDATE_UTF8 = TRUE | FALSE
     EMPTY_FIELD_AS_NULL = TRUE | FALSE
     SKIP_BYTE_ORDER_MARK = TRUE | FALSE
     ENCODING = '<string>' | UTF8
-- If TYPE = JSON
     COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
     FILE_EXTENSION = '<string>'
     ENABLE_OCTAL = TRUE | FALSE
     ALLOW_DUPLICATE = TRUE | FALSE
     STRIP_OUTER_ARRAY = TRUE | FALSE
     STRIP_NULL_VALUES = TRUE | FALSE
     IGNORE_UTF8_ERRORS = TRUE | FALSE
     SKIP_BYTE_ORDER_MARK = TRUE | FALSE
-- If TYPE = AVRO
     COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
-- If TYPE = ORC
     -- none (no options are supported)
-- If TYPE = PARQUET
     BINARY_AS_TEXT = TRUE | FALSE
     SNAPPY_COMPRESSION = TRUE | FALSE
-- If TYPE = XML
     COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
     IGNORE_UTF8_ERRORS = TRUE | FALSE
     PRESERVE_SPACE = TRUE | FALSE
     STRIP_OUTER_ELEMENT = TRUE | FALSE
     DISABLE_SNOWFLAKE_DATA = TRUE | FALSE
     DISABLE_AUTO_CONVERT = TRUE | FALSE
     SKIP_BYTE_ORDER_MARK = TRUE | FALSE
copyOptions
copyOptions ::=
     ON_ERROR = { CONTINUE | SKIP_FILE | SKIP_FILE_<num> | SKIP_FILE_<num>% | ABORT_STATEMENT }
     SIZE_LIMIT = <num>
     PURGE = TRUE | FALSE
     RETURN_FAILED_ONLY = TRUE | FALSE
     ENFORCE_LENGTH = TRUE | FALSE
     TRUNCATECOLUMNS = TRUE | FALSE
     FORCE = TRUE | FALSE

Variant Syntax

CREATE TABLE … AS SELECT (also referred to as CTAS)

Creates a new table populated with the data returned by a query:

CREATE [ OR REPLACE ] TABLE <table_name> [ ( <col_name> [ <col_type> ] , <col_name> [ <col_type> ] , ... ) ]
  [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ]
  [ COPY GRANTS ]
  AS SELECT <query>
  [ ... ]

CREATE TABLE … LIKE

Creates a new table with the same column definitions as an existing table, but without copying data from the existing table. Column names, types, defaults, and constraints are copied to the new table:

CREATE [ OR REPLACE ] TABLE <table_name> LIKE <source_table>
  [ CLUSTER BY ( <expr> [ , <expr> , ... ] ) ]
  [ COPY GRANTS ]
  [ ... ]

CREATE TABLE … CLONE

Creates a new table with the same column definitions and containing all the existing data from the source table, without actually copying the data. This variant can also be used to clone a table at a specific time/point in the past (using Time Travel):

CREATE [ OR REPLACE ] TABLE <name> CLONE <source_table>
  [ { AT | BEFORE } { TIMESTAMP => <timestamp> | OFFSET => <time_difference> | STATEMENT => <id> } ]
  [ COPY GRANTS ]
  [ ... ]

For more details, see CREATE <object> … CLONE.

Required Parameters

name

Specifies the identifier (i.e. 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 (e.g. "My object"). Identifiers enclosed in double quotes are also case-sensitive.

For more details, see Identifier Syntax.

col_name

Specifies the column identifier (i.e. name). All the requirements for table identifiers also apply to column identifiers.

For more details, see Identifier Syntax and Reserved & Limited Keywords.

Note

In addition to the standard reserved keywords, the following keywords cannot 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

Specifies the data type for the column.

For details about the data types that can be specified for table columns, see Data Types.

Optional Parameters

TEMPORARY ... or . TRANSIENT

Specifies whether a table is temporary or transient:

TEMP[ORARY] | LOCAL TEMP[ORARY] | GLOBAL TEMP[ORARY] | VOLATILE

Specifies that the table is temporary. A temporary table persists only for the duration of the user session in which it was created and is not visible to other users. A temporary table and all its contents are dropped at the end of the session.

The synonyms and abbreviations for TEMPORARY are provided for compatibility with other databases (e.g. to prevent errors when migrating CREATE TABLE statements). Tables created with any of these keywords appear and behave identically to tables created using TEMPORARY.

TRANSIENT
Specifies that the table is transient. In contrast to temporary tables, a transient table exists until explicitly dropped and is visible to any user with the appropriate privileges. However, transient tables have a lower level of data protection than permanent tables, meaning data in a transient table might be lost in the event of a system failure. As such, transient tables should only be used for data that can be recreated externally to Snowflake.

If no value is specified, the table is permanent.

Default: No value (i.e. table is permanent)

Note

Temporary tables have some additional usage considerations with regards to naming conflicts that can occur with other tables that have the same name in the same schema. In addition, both temporary and transient tables have some storage considerations.

For more information about these and other considerations when deciding whether to create temporary or transient tables, see Working with Temporary and Transient Tables and Storage Costs for Time Travel and Fail-safe.

DEFAULT ... or . AUTOINCREMENT ...

Specifies whether a default value is automatically inserted in the column if a value is not explicitly specified via an INSERT or CREATE TABLE AS SELECT statement:

DEFAULT expr

Column default value is defined by the specified expression which can be any of the following:

  • Constant value.
  • Simple expression
  • Sequence reference (seq_name.NEXTVAL).

A simple expression is any expression that returns a scalar value; however, the expression cannot contain references to subqueries, aggregates, or window functions.

AUTOINCREMENT | IDENTITY [ ( start_num , step_num ) | START num INCREMENT num ]

Column default value starts with a specified number and each successive value automatically increments by the specified amount. These parameters can only be used with columns with numeric data types.

AUTOINCREMENT and IDENTITY are synonymous. If either is specified for a column, Snowflake utilizes a sequence to generate the values for the column. For more information about sequences, see Using Sequences.

The default value for both start and step/increment is 1.

Default: No value (the column has no default value)

Note

DEFAULT or AUTOINCREMENT are mutually exclusive; only one can be specified for a column.

CONSTRAINT ...

Defines an inline or out-of-line constraint for the specified column(s) in the table.

For syntax details, see CREATE | ALTER TABLE … CONSTRAINT. For more information about constraints, see Constraints.

CLUSTER BY ( expr [ , expr , ... ] )

Specifies one or more columns or column expressions in the table as clustering keys. These are the columns/expessions that are reclustered when an ALTER TABLE command is executed with a RECLUSTER clause. For more details, see Understanding Snowflake Table Structures.

Default: No value (no clustering keys are defined for the table)

Important

Clustering keys are not intended or recommended for all tables; they typically benefit very large (i.e. multi-terabyte) tables.

Before you specify clustering keys for a table, please read Understanding Snowflake Table Structures.

STAGE_FILE_FORMAT = ( FORMAT_NAME = 'file_format_name' ) or . STAGE_FILE_FORMAT = ( TYPE = CSV | JSON | AVRO | ORC | PARQUET | XML [ ... ] )

Specifies the file format for the table (for data loading and unloading), which can be either:

FORMAT_NAME = file_format_name
Specifies an existing named file format to use for loading/unloading data into the table. The named file format determines the format type (CSV, JSON, etc.), as well as any other format options, for data files. For more details, see CREATE FILE FORMAT.
TYPE = CSV | JSON | AVRO | ORC | PARQUET | XML [ ... ]

Specifies the type of files to load/unload into the table.

If a file format type is specified, additional format-specific options can be specified. For more details, see Format Type Options (in this topic).

Default: TYPE = CSV

Note

FORMAT_NAME and TYPE are mutually exclusive; to avoid unintended behavior, you should only specify one or the other when creating a table.

STAGE_COPY_OPTIONS = ( ... )
Specifies one (or more) options to use when loading data into the table. For more details, see Copy Options (in this topic).
DATA_RETENTION_TIME_IN_DAYS = num

Specifies the retention period for the table so that Time Travel actions (SELECT, CLONE, UNDROP) can be performed on historical data in the table. For more details, see Understanding & Using Time Travel and Working with Temporary and Transient Tables.

For a detailed description of this object-level parameter, as well as more information about object parameters, see Parameters.

Values:

  • Standard Edition: 0 or 1
  • Enterprise Edition:
    • 0 to 90 for permanent tables
    • 0 or 1 for temporary and transient tables

Default:

  • Standard Edition: 1
  • Enterprise Edition (or higher): 1 (unless a different default value was specified at the schema, database, or account level)

Note

A value of 0 effectively disables Time Travel for the table.

COPY GRANTS

Specifies to retain the access permissions from the original table when a new table is created using any of the following CREATE TABLE variants:

  • CREATE OR REPLACE TABLE
  • CREATE TABLE … LIKE
  • CREATE TABLE … CLONE

The parameter copies all permissions, except OWNERSHIP, from the existing table to the new table. By default, the role that executes the CREATE TABLE command owns the new table.

Note:

  • If the CREATE TABLE statement references more than one table (e.g. create or replace table t1 clone t2;), the COPY GRANTS clause gives precedence to the table being replaced.

  • 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 TABLE statement, with the current timestamp when the statement was executed.

  • The operation to copy grants occurs atomically in the CREATE TABLE command (i.e. within the same transaction).

COMMENT = 'string_literal'

Specifies a comment for the table.

Default: No value

Format Type Options (formatTypeOptions)

Format type options are used for loading data into and unloading data out of tables.

Depending on the file format type specified (STAGE_FILE_FORMAT = ( TYPE = ... )), you can include one or more of the following format-specific options (separated by blank spaces, commas, or new lines):

TYPE = CSV
COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
Use:

Data loading and unloading

Definition:
  • When loading data, specifies the current compression algorithm for the data file. Snowflake uses this option to detect how an already-compressed data file was compressed so that the compressed data in the file can be extracted for loading.
  • When unloading data, compresses the data file using the specified compression algorithm.
Values:
Supported Values Notes
AUTO When loading data, compression algorithm detected automatically, except for Brotli-compressed files, which cannot currently be detected automatically. When unloading data, files are automatically compressed using the default, which is gzip.
GZIP  
BZ2  
BROTLI Must be specified if loading/unloading Brotli-compressed files.
ZSTD Zstandard v0.8 (and higher) is supported.
DEFLATE Deflate-compressed files (with zlib header, RFC1950).
RAW_DEFLATE Raw Deflate-compressed files (without header, RFC1951).
NONE When loading data, indicates that the files have not been compressed. When unloading data, specifies that the unloaded files are not compressed.
Default:

AUTO

RECORD_DELIMITER = 'character' | NONE
Use:Data loading and unloading
Definition:Single character string that separates records in an input file. Accepts common escape sequences, octal values (prefixed by \\), or hex values (prefixed by 0x). Also accepts a value of NONE.
Default:New line character. Note that “new line” is logical such that \r\n will be understood as a new line for files on a Windows platform.
FIELD_DELIMITER = 'character' | NONE
Use:Data loading and unloading
Definition:Single character string that separates fields in an input file. Accepts common escape sequences, octal values, or hex values. Also accepts a value of NONE.
Default:comma (,)
FILE_EXTENSION = 'string' | NONE
Use:Data unloading only
Definition:Specifies the extension for files unloaded to a stage. Accepts any extension. The user is responsible for specifying a file extension that can be read by any desired software or services.
Default:null, meaning the file extension is determined by the format type: .csv[compression], where compression is the extension added by the compression method, if COMPRESSION is set.

Note

If the SINGLE copy option is TRUE, then the COPY command unloads a file without a file extension by default. To specify a file extension, provide a file name and extension in the internal_location or external_location path (e.g. copy into @stage/data.csv).

SKIP_HEADER = integer
Use:Data loading only
Definition:Number of lines at the start of the file to skip.

Note that SKIP_HEADER does not use the RECORD_DELIMITER or FIELD_DELIMITER values to determine what a header line is; rather, it simply skips the specified number of CRLF (Carriage Return, Line Feed)-delimited lines in the file. RECORD_DELIMITER and FIELD_DELIMITER are then used to determine the rows of data to load.

Default:0
DATE_FORMAT = 'string' | AUTO
Use:Data loading and unloading
Definition:Defines the format of date values in the data files (data loading) or table (data unloading). If a value is not specified or is AUTO, the value for the DATE_INPUT_FORMAT (data loading) or DATE_OUTPUT_FORMAT (data unloading) parameter is used.
Default:AUTO
TIME_FORMAT = 'string' | AUTO
Use:Data loading and unloading
Definition:Defines the format of time values in the data files (data loading) or table (data unloading). If a value is not specified or is AUTO, the value for the TIME_INPUT_FORMAT (data loading) or TIME_OUTPUT_FORMAT (data unloading) parameter is used.
Default:AUTO
TIMESTAMP_FORMAT = string' | AUTO
Use:Data loading and unloading
Definition:Defines the format of timestamp values in the data files (data loading) or table (data unloading). If a value is not specified or is AUTO, the value for the TIMESTAMP_INPUT_FORMAT (data loading) or TIMESTAMP_OUTPUT_FORMAT (data unloading) parameter is used.
Default:AUTO
BINARY_FORMAT = HEX | BASE64 | UTF8
Use:Data loading and unloading
Definition:Defines the encoding format for binary input or output. The option can be used when loading data into or unloading data from binary columns in a table.
Default:HEX
ESCAPE = 'character' | NONE
Use:

Data loading and unloading

Definition:

Single character string used as the escape character for any field values. Accepts common escape sequences, octal values, or hex values. Also accepts a value of NONE.

  • When loading data, specifies the escape character for enclosed fields. Specify the character used to enclose fields by setting FIELD_OPTIONALLY_ENCLOSED_BY.
  • When unloading data, if this option is set, it overrides the escape character set for ESCAPE_UNENCLOSED_FIELD.
Default:

NONE

ESCAPE_UNENCLOSED_FIELD = 'character' | NONE
Use:

Data loading and unloading

Definition:

Single character string used as the escape character for unenclosed field values only. Accepts common escape sequences, octal values, or hex values. Also accepts a value of NONE.

When unloading data, if ESCAPE is set, the escape character set for that option overrides this option.

Default:

backslash (\\)

TRIM_SPACE = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to remove white space from fields.

For example, if your external database software encloses fields in quotes, but inserts a leading space, Snowflake reads the leading space rather than the opening quotation character as the beginning of the field (i.e. the quotation marks are interpreted as part of the string of field data). Set this option to TRUE to remove undesirable spaces during the data load.

As another example, if leading or trailing spaces surround quotes that enclose strings, you can remove the surrounding spaces using this option and the quote character using the FIELD_OPTIONALLY_ENCLOSED_BY option. Note that any spaces within the quotes are preserved. For example, assuming FIELD_DELIMITER = '|' and FIELD_OPTIONALLY_ENCLOSED_BY = '"':

|"Hello world"|    /* loads as */  >Hello world<
|" Hello world "|  /* loads as */  > Hello world <
| "Hello world" |  /* loads as */  >Hello world<

(the brackets in this example are not loaded; they are used to demarcate the beginning and end of the loaded strings)

Default:

FALSE

FIELD_OPTIONALLY_ENCLOSED_BY = 'character' | NONE
Use:

Data loading and unloading

Definition:

Character used to enclose strings. Value can be NONE, single quote character ('), or double quote character ("). To use the single quote character, use the octal or hex representation (0x27) or the double single-quoted escape ('').

When a field contains this character, escape it using the same character. For example, if the value is the double quote character and a field contains the string A "B" C, escape the double quotes as follows:

A ""B"" C

Default:

NONE

NULL_IF = ( 'string1' [ , 'string2' , ... ] )
Use:

Data loading and unloading

Definition:

String used to convert to and from SQL NULL:

  • When loading data, Snowflake replaces these strings in the data load source with SQL NULL. To specify more than one string, enclose the list of strings in parentheses and use commas to separate each value.

    For example:

    NULL_IF = ('\\N', 'NULL', 'NUL', '')

    Note that this option can include empty strings and only applies to columns that are nullable.

  • When unloading data, Snowflake converts SQL NULL values to the first value in the list.

Default:

\\N (i.e. NULL, which assumes the ESCAPE_UNENCLOSED_FIELD value is \\ (default))

ERROR_ON_COLUMN_COUNT_MISMATCH = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to generate a parsing error if the number of delimited columns (i.e. fields) in an input file does not match the number of columns in the corresponding table.

If set to FALSE, an error is not generated and the load continues. If the file is successfully loaded:

  • If the input file contains records with more fields than columns in the table, the matching fields are loaded in order of occurrence in the file and the remaining fields are not loaded.
  • If the input file contains records with fewer fields than columns in the table, the non-matching columns in the table are loaded with NULL values.

This option assumes all the records within the input file are the same length (i.e. a file containing records of varying length return an error regardless of the value specified for this parameter).

Default:

TRUE

Note

When transforming data during loading (i.e. using a query as the source for the COPY command), this option is ignored. There is no requirement for your data files to have the same number and ordering of columns as your target table.

VALIDATE_UTF8 = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to validate UTF-8 character encoding in string column data.

If set to TRUE, Snowflake validates UTF-8 character encoding in string column data. When invalid UTF-8 character encoding is detected, the COPY command produces an error.

Default:

TRUE

Important

This option is provided only to ensure backward compatibility with earlier versions of Snowflake. You should not disable this option unless instructed by Snowflake Support.

EMPTY_FIELD_AS_NULL = TRUE | FALSE
Use:

Data loading and unloading

Definition:

Boolean that specifies whether to insert SQL NULL for empty fields in an input file.

If set to FALSE, Snowflake attempts to cast an empty field to the corresponding column type. An empty string is inserted into columns of type STRING. For other column types, the COPY command produces an error.

Default:

TRUE

SKIP_BYTE_ORDER_MARK = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to skip any BOM (byte order mark) present in an input file. A BOM is a character code at the beginning of a data file that defines the byte order and encoding form.

If set to FALSE, Snowflake recognizes any BOM in data files, which could result in the BOM either causing an error or being merged into the first column in the table.

Default:

TRUE

ENCODING = 'string'
Use:

Data loading only

Definition:

String (constant) that specifies the character set of the source data when loading data into a table.

Character Set ENCODING Value Supported Languages
Big5 BIG5 Traditional Chinese
EUC-JP EUCJP Japanese
EUC-KR EUCKR Korean
GB18030 GB18030 Chinese
IBM420 IBM420 Arabic
IBM424 IBM424 Hebrew
ISO-2022-CN ISO2022CN Simplified Chinese
ISO-2022-JP ISO2022JP Japanese
ISO-2022-KR ISO2022KR Korean
ISO-8859-1 ISO88591 Danish, Dutch, English, French, German, Italian, Norwegian, Portuguese, Swedish
ISO-8859-2 ISO88592 Czech, Hungarian, Polish, Romanian
ISO-8859-5 ISO88595 Russian
ISO-8859-6 ISO88596 Arabic
ISO-8859-7 ISO88597 Greek
ISO-8859-8 ISO88598 Hebrew
ISO-8859-9 ISO88599 Turkish
KOI8-R KOI8R Russian
Shift_JIS SHIFTJIS Japanese
UTF-8 UTF8 All languages
UTF-16 UTF16 All languages
UTF-16BE UTF16BE All languages
UTF-16LE UTF16LE All languages
UTF-32 UTF32 All languages
UTF-32BE UTF32BE All languages
UTF-32LE UTF32LE All languages
windows-1250 WINDOWS1250 Czech, Hungarian, Polish, Romanian
windows-1251 WINDOWS1251 Russian
windows-1252 WINDOWS1252 Danish, Dutch, English, French, German, Italian, Norwegian, Portuguese, Swedish
windows-1253 WINDOWS1253 Greek
windows-1254 WINDOWS1254 Turkish
windows-1255 WINDOWS1255 Hebrew
windows-1256 WINDOWS1256 Arabic
Default:

UTF8

Note

Snowflake stores all data internally in the UTF-8 character set. The data is converted into UTF-8 before it is loaded into Snowflake. If the VALIDATE_UTF8 file format option is TRUE, Snowflake validates the UTF-8 character encoding in string column data after it is converted from its original character encoding.

TYPE = JSON
COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
Use:

Data loading and unloading

Definition:
  • When loading data, specifies the current compression algorithm for the data file. Snowflake uses this option to detect how an already-compressed data file was compressed so that the compressed data in the file can be extracted for loading.
  • When unloading data, compresses the data file using the specified compression algorithm.
Values:
Supported Values Notes
AUTO When loading data, compression algorithm detected automatically, except for Brotli-compressed files, which cannot currently be detected automatically. When unloading data, files are automatically compressed using the default, which is gzip.
GZIP  
BZ2  
BROTLI Must be specified if loading/unloading Brotli-compressed files.
ZSTD Zstandard v0.8 (and higher) is supported.
DEFLATE Deflate-compressed files (with zlib header, RFC1950).
RAW_DEFLATE Raw Deflate-compressed files (without header, RFC1951).
NONE When loading data, indicates that the files have not been compressed. When unloading data, specifies that the unloaded files are not compressed.
Default:

AUTO

FILE_EXTENSION = 'string' | NONE
Use:Data loading and unloading
Definition:Specifies the extension for files unloaded to a stage. Accepts any extension. The user is responsible for specifying a file extension that can be read by any desired software or services.
Default:null, meaning the file extension is determined by the format type: .json[compression], where compression is the extension added by the compression method, if COMPRESSION is set.
ENABLE_OCTAL = TRUE | FALSE
Use:Data loading only
Definition:Boolean that enables parsing of octal numbers.
Default:FALSE
ALLOW_DUPLICATE = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies to allow duplicate object field names (only the last one will be preserved).
Default:FALSE
STRIP_OUTER_ARRAY = TRUE | FALSE
Use:Data loading only
Definition:Boolean that instructs the JSON parser to remove outer brackets (i.e [ ]).
Default:FALSE
STRIP_NULL_VALUES = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that instructs the JSON parser to remove object fields or array elements containing null values. For example, when set to TRUE:

Before After
[null] []
[null,null,3] [,,3]
{"a":null,"b":null,"c":123} {"c":123}
{"a":[1,null,2],"b":{"x":null,"y":88}} {"a":[1,,2],"b":{"y":88}}
Default:

FALSE

IGNORE_UTF8_ERRORS = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether UTF-8 encoding errors produce error conditions. If set to TRUE, any invalid UTF-8 sequences are silently replaced with Unicode character U+FFFD (i.e. “replacement character”).
Default:FALSE
SKIP_BYTE_ORDER_MARK = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to skip any BOM (byte order mark) present in an input file. A BOM is a character code at the beginning of a data file that defines the byte order and encoding form.

If set to FALSE, Snowflake recognizes any BOM in data files, which could result in the BOM either causing an error or being merged into the first column in the table.

Default:

TRUE

TYPE = AVRO
COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
Use:

Data loading and unloading

Definition:
  • When loading data, specifies the current compression algorithm for the data file. Snowflake uses this option to detect how an already-compressed data file was compressed so that the compressed data in the file can be extracted for loading.
  • When unloading data, compresses the data file using the specified compression algorithm.
Values:
Supported Values Notes
AUTO When loading data, compression algorithm detected automatically, except for Brotli-compressed files, which cannot currently be detected automatically. When unloading data, files are automatically compressed using the default, which is gzip.
GZIP  
BZ2  
BROTLI Must be specified if loading/unloading Brotli-compressed files.
ZSTD Zstandard v0.8 (and higher) is supported.
DEFLATE Deflate-compressed files (with zlib header, RFC1950).
RAW_DEFLATE Raw Deflate-compressed files (without header, RFC1951).
NONE When loading data, indicates that the files have not been compressed. When unloading data, specifies that the unloaded files are not compressed.
Default:

AUTO

TYPE = PARQUET
SNAPPY_COMPRESSION = TRUE | FALSE
Use:Data unloading only
Definition:Boolean that specifies whether the unloaded file(s) are compressed using the SNAPPY algorithm.
Default:TRUE
BINARY_AS_TEXT = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether to interpret columns with no defined logical data type as UTF-8 text. When set to FALSE, Snowflake interprets these columns as binary data.
Default:TRUE
TYPE = XML
COMPRESSION = AUTO | GZIP | BZ2 | BROTLI | ZSTD | DEFLATE | RAW_DEFLATE | NONE
Use:

Data loading and unloading

Definition:
  • When loading data, specifies the current compression algorithm for the data file. Snowflake uses this option to detect how an already-compressed data file was compressed so that the compressed data in the file can be extracted for loading.
  • When unloading data, compresses the data file using the specified compression algorithm.
Values:
Supported Values Notes
AUTO When loading data, compression algorithm detected automatically, except for Brotli-compressed files, which cannot currently be detected automatically. When unloading data, files are automatically compressed using the default, which is gzip.
GZIP  
BZ2  
BROTLI Must be specified if loading/unloading Brotli-compressed files.
ZSTD Zstandard v0.8 (and higher) is supported.
DEFLATE Deflate-compressed files (with zlib header, RFC1950).
RAW_DEFLATE Raw Deflate-compressed files (without header, RFC1951).
NONE When loading data, indicates that the files have not been compressed. When unloading data, specifies that the unloaded files are not compressed.
Default:

AUTO

IGNORE_UTF8_ERRORS = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether UTF-8 encoding errors produce error conditions. If set to TRUE, any invalid UTF-8 sequences are silently replaced with Unicode character U+FFFD (i.e. “replacement character”).
Default:FALSE
PRESERVE_SPACE = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether the XML parser preserves leading and trailing spaces in element content.
Default:FALSE
STRIP_OUTER_ELEMENT = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether the XML parser strips out the outer XML element, exposing 2nd level elements as separate documents.
Default:FALSE
DISABLE_SNOWFLAKE_DATA = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether the XML parser disables recognition of Snowflake semi-structured data tags.
Default:FALSE
DISABLE_AUTO_CONVERT = TRUE | FALSE
Use:Data loading only
Definition:Boolean that specifies whether the XML parser disables automatic conversion of numeric and Boolean values from text to native representation.
Default:FALSE
SKIP_BYTE_ORDER_MARK = TRUE | FALSE
Use:

Data loading only

Definition:

Boolean that specifies whether to skip any BOM (byte order mark) present in an input file. A BOM is a character code at the beginning of a data file that defines the byte order and encoding form.

If set to FALSE, Snowflake recognizes any BOM in data files, which could result in the BOM either causing an error or being merged into the first column in the table.

Default:

TRUE

Note

TYPE = ORC does not support any format type options.

Copy Options (copyOptions)

Copy options are used for loading data into and unloading data out of tables.

You can specify one or more of the following copy options (separated by blank spaces, commas, or new lines):

STAGE_COPY_OPTIONS = ( ... )
ON_ERROR = CONTINUE | SKIP_FILE | SKIP_FILE_num | SKIP_FILE_num% | ABORT_STATEMENT

String (constant) that specifies the action to perform when an error is encountered while loading data from a file:

Supported Values Notes
CONTINUE Continue loading the file.
SKIP_FILE Skip file if any errors encountered in the file.
SKIP_FILE_num (e.g. SKIP_FILE_10) Skip file when the number of errors in the file is equal to or exceeds the specified number.
SKIP_FILE_num% (e.g. SKIP_FILE_10%) Skip file when the percentage of errors in the file exceeds the specified percentage.
ABORT_STATEMENT Abort the COPY statement if any error is encountered.

Default: ABORT_STATEMENT

SIZE_LIMIT = num

Number (> 0) that specifies the maximum size (in bytes) of data to be loaded for a given COPY statement. When the threshold is exceeded, the COPY operation discontinues loading files. This option is commonly used to load a common group of files using multiple COPY statements. For each statement, the data load continues until the specified SIZE_LIMIT is exceeded, before moving on to the next statement.

For example, suppose a set of files in a stage path were each 10MB in size. If multiple COPY statements set SIZE_LIMIT to 25000000 (25MB), each would load 3 files. That is, each COPY operation would discontinue after the SIZE_LIMIT threshold was exceeded.

Note that at least one file is loaded regardless of the value specified for SIZE_LIMIT:code: unless there is no file to be loaded.

Default: null (no size limit)

PURGE = TRUE | FALSE

Boolean that specifies whether to purge the data files from the location automatically after the data is successfully loaded.

Default: FALSE

RETURN_FAILED_ONLY = TRUE | FALSE

Boolean that specifies whether to return only files that have failed to load in the statement result.

Default: FALSE

ENFORCE_LENGTH = TRUE | FALSE

Alternative syntax for TRUNCATECOLUMNS with reverse logic (for compatibility with other systems)

Boolean that specifies whether to truncate text strings that exceed the target column length:

  • If TRUE, the COPY statement produces an error if a loaded string exceeds the target column length.
  • If FALSE, strings are automatically truncated to the target column length.

Default: TRUE

Note

  • If the length of the target string column is set to the maximum (e.g. VARCHAR (16777216)), an incoming string cannot exceed this length; otherwise, the COPY command produces an error.
  • This parameter is functionally equivalent to TRUNCATECOLUMNS, but has the opposite behavior. It is provided for compatibility with other databases. It is only necessary to include one of these two parameters in a COPY statement to produce the desired output.
TRUNCATECOLUMNS = TRUE | FALSE

Alternative syntax for ENFORCE_LENGTH with reverse logic (for compatibility with other systems)

Boolean that specifies whether to truncate text strings that exceed the target column length:

  • If TRUE, strings are automatically truncated to the target column length.
  • If FALSE, the COPY statement produces an error if a loaded string exceeds the target column length.

Default: FALSE

Note

  • If the length of the target string column is set to the maximum (e.g. VARCHAR (16777216)), an incoming string cannot exceed this length; otherwise, the COPY command produces an error.
  • This parameter is functionally equivalent to ENFORCE_LENGTH, but has the opposite behavior. It is provided for compatibility with other databases. It is only necessary to include one of these two parameters in a COPY statement to produce the desired output.
FORCE = TRUE | FALSE

Boolean that specifies to load all files, regardless of whether they’ve been loaded previously and have not changed since they were loaded. Note that this option reloads files, potentially duplicating data in a table.

Default: FALSE

LOAD_UNCERTAIN_FILES = TRUE | FALSE

Boolean that specifies to load files for which the load status is unknown. The COPY command skips these files by default.

The load status is unknown if all of the following conditions are true:

  • The file’s LAST_MODIFIED date (i.e. date when the file was staged) is older than 64 days.
  • The initial set of data was loaded into the table more than 64 days earlier.
  • If the file was already loaded successfully into the table, this event occurred more than 64 days earlier.

To force the COPY command to load all files regardless of whether the load status is known, use the FORCE option instead.

For more information about load status uncertainty, see Loading Older Files.

Default: FALSE

Usage Notes

  • 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.

    Important

    Using OR REPLACE is the equivalent of using DROP TABLE on the existing table and then creating a new table with the same name; however, the dropped table is not permanently removed from the system. Instead, it is retained in Time Travel. This is important to note because dropped tables in Time Travel can be recovered, but they also contribute to data storage for your account. For more information, see Storage Costs for Time Travel and Fail-safe.

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

  • CREATE TABLE … AS SELECT (CTAS):

    • If the aliases for the column names in the SELECT list are valid column, then the column definitions are not required in the CTAS statement; if omitted, the column names and types are inferred from the underlying query:

      CREATE TABLE <table_name> AS SELECT ...
      

      Alternatively, the names can be explicitly specified using the following syntax:

      CREATE TABLE <table_name> ( <col1_name> , <col2_name> , ... ) AS SELECT ...
      

      The number of column names specified must match the number of SELECT list items in the query; the types of the columns are inferred from the types produced by the query.

    • Clustering keys can be used in a CTAS statement; however, if clustering keys are specified, column definitions are required and must be explicitly specified in the statement.

Examples

Create a simple table in the current database and insert a row in the table:

CREATE TABLE mytable (amount NUMBER);

+-------------------------------------+
| status                              |
|-------------------------------------|
| Table MYTABLE successfully created. |
+-------------------------------------+

INSERT INTO mytable VALUES(1);

SHOW TABLES like 'mytable';

+---------------------------------+---------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+
| created_on                      | name    | database_name | schema_name | kind  | comment | cluster_by | rows | bytes | owner        | retention_time |
|---------------------------------+---------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------|
| Mon, 11 Sep 2017 16:32:28 -0700 | MYTABLE | TESTDB        | PUBLIC      | TABLE |         |            |    1 |  1024 | ACCOUNTADMIN | 1              |
+---------------------------------+---------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+

DESC TABLE mytable;

+--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+
| name   | type         | kind   | null? | default | primary key | unique key | check | expression | comment |
|--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------|
| AMOUNT | NUMBER(38,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
+--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+

Create a simple table and specify comments for both the table and the column in the table:

CREATE TABLE example (col1 number comment 'a column comment') COMMENT='a table comment';

+-------------------------------------+
| status                              |
|-------------------------------------|
| Table EXAMPLE successfully created. |
+-------------------------------------+

SHOW TABLES like 'example';

+---------------------------------+---------+---------------+-------------+-------+-----------------+------------+------+-------+--------------+----------------+
| created_on                      | name    | database_name | schema_name | kind  | comment         | cluster_by | rows | bytes | owner        | retention_time |
|---------------------------------+---------+---------------+-------------+-------+-----------------+------------+------+-------+--------------+----------------|
| Mon, 11 Sep 2017 16:35:59 -0700 | EXAMPLE | TESTDB        | PUBLIC      | TABLE | a table comment |            |    0 |     0 | ACCOUNTADMIN | 1              |
+---------------------------------+---------+---------------+-------------+-------+-----------------+------------+------+-------+--------------+----------------+

DESC TABLE example;

+------+--------------+--------+-------+---------+-------------+------------+-------+------------+------------------+
| name | type         | kind   | null? | default | primary key | unique key | check | expression | comment          |
|------+--------------+--------+-------+---------+-------------+------------+-------+------------+------------------|
| COL1 | NUMBER(38,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | a column comment |
+------+--------------+--------+-------+---------+-------------+------------+-------+------------+------------------+

Create a table by selecting from an existing table:

CREATE TABLE mytable_copy (b) AS SELECT * from mytable;

DESC TABLE mytable_copy;

+------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+
| name | type         | kind   | null? | default | primary key | unique key | check | expression | comment |
|------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------|
| B    | NUMBER(38,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
+------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+

CREATE TABLE mytable_copy2 AS SELECT b+1 AS c FROM mytable_copy;

DESC TABLE mytable_copy2;

+------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+
| name | type         | kind   | null? | default | primary key | unique key | check | expression | comment |
|------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------|
| C    | NUMBER(39,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
+------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+

SELECT * FROM mytable_copy2;

+---+
| C |
|---|
| 2 |
+---+

More advanced example of creating a table by selecting from an existing table; in this example, the values in the summary_amount column in the new table are derived from two columns in the source table:

CREATE TABLE testtable-summary (name, summary_amount) AS SELECT name, amount1 + amount2 FROM testtable;

Create a table by selecting columns from a staged Parquet data file:

CREATE OR REPLACE TABLE parquet_col (
  custKey number default NULL,
  orderDate date default NULL,
  orderStatus varchar(100) default NULL,
  price varchar(255)
)
AS SELECT
  $1:o_custkey::number,
  $1:o_orderdate::date,
  $1:o_orderstatus::text,
  $1:o_totalprice::text
FROM @my_stage;

+-----------------------------------------+
| status                                  |
|-----------------------------------------|
| Table PARQUET_COL successfully created. |
+-----------------------------------------+

DESC TABLE parquet_col;

+-------------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+
| name        | type         | kind   | null? | default | primary key | unique key | check | expression | comment |
|-------------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------|
| CUSTKEY     | NUMBER(38,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
| ORDERDATE   | DATE         | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
| ORDERSTATUS | VARCHAR(100) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
| PRICE       | VARCHAR(255) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
+-------------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+

Create a table with the same column definitions as another table, but with no rows:

CREATE TABLE mytable (amount NUMBER);

INSERT INTO mytable VALUES(1);

SELECT * FROM mytable;

+--------+
| AMOUNT |
|--------|
|      1 |
+--------+

CREATE TABLE mytable_2 LIKE mytable;

DESC TABLE mytable_2;

+--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+
| name   | type         | kind   | null? | default | primary key | unique key | check | expression | comment |
|--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------|
| AMOUNT | NUMBER(38,0) | COLUMN | Y     | NULL    | N           | N          | NULL  | NULL       | NULL    |
+--------+--------------+--------+-------+---------+-------------+------------+-------+------------+---------+

SELECT * FROM mytable_2;

+--------+
| AMOUNT |
|--------|
+--------+

Specify clustering keys for a table:

CREATE TABLE mytable (date timestamp_ntz, id number, content variant) CLUSTER BY (date, id);

SHOW TABLES LIKE 'mytable';

+---------------------------------+---------+---------------+-------------+-------+---------+------------------+------+-------+--------------+----------------+
| created_on                      | name    | database_name | schema_name | kind  | comment | cluster_by       | rows | bytes | owner        | retention_time |
|---------------------------------+---------+---------------+-------------+-------+---------+------------------+------+-------+--------------+----------------|
| Mon, 11 Sep 2017 16:20:41 -0700 | MYTABLE | TESTDB        | PUBLIC      | TABLE |         | LINEAR(DATE, ID) |    0 |     0 | ACCOUNTADMIN | 1              |
+---------------------------------+---------+---------------+-------------+-------+---------+------------------+------+-------+--------------+----------------+