Categories:

Table, View, & Sequence DDL

ALTER TABLE

Modifies the properties, columns, or constraints for an existing table.

See also:

CREATE TABLE , SHOW TABLES

In this Topic:

Syntax

ALTER TABLE [ IF EXISTS ] <name> RENAME TO <new_table_name>

ALTER TABLE [ IF EXISTS ] <name> SWAP WITH <target_table_name>

ALTER TABLE [ IF EXISTS ] <name> { clusteringAction | tableColumnAction | constraintAction  }

ALTER TABLE [ IF EXISTS ] <name> extTableColumnAction

ALTER TABLE [ IF EXISTS ] <name> searchOptimizationAction

ALTER TABLE [ IF EXISTS ] <name> SET
  [ 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 = <integer> ]
  [ MAX_DATA_EXTENSION_TIME_IN_DAYS = <integer> ]
  [ CHANGE_TRACKING = { TRUE | FALSE  } ]
  [ DEFAULT_DDL_COLLATION = '<collation_specification>' ]
  [ COMMENT = '<string_literal>' ]

ALTER TABLE [ IF EXISTS ] <name> UNSET {
                                       DATA_RETENTION_TIME_IN_DAYS     |
                                       MAX_DATA_EXTENSION_TIME_IN_DAYS |
                                       CHANGE_TRACKING                 |
                                       DEFAULT_DDL_COLLATION           |
                                       COMMENT
                                       }
                                       [ , ... ]

Where:

clusteringAction ::=
  {
     CLUSTER BY ( <expr> [ , <expr> , ... ] )
   | RECLUSTER [ MAX_SIZE = <budget_in_bytes> ] [ WHERE <condition> ]
     /* RECLUSTER is deprecated */
   | { SUSPEND | RESUME } RECLUSTER
   | DROP CLUSTERING KEY
  }
tableColumnAction ::=
  {
     ADD COLUMN <col_name> <col_type>
        [ { DEFAULT <expr> | { AUTOINCREMENT | IDENTITY } [ { ( <start_num> , <step_num> ) | START <num> INCREMENT <num> } ] } ]
                            /* AUTOINCREMENT (or IDENTITY) supported only for columns with numeric data types (NUMBER, INT, FLOAT, etc.). */
                            /* Also, if the table is not empty (i.e. rows exist in the table), only DEFAULT can be altered.               */
        [ inlineConstraint ]
   | RENAME COLUMN <col_name> TO <new_col_name>

   | ALTER | MODIFY [ ( ]
                            [ COLUMN ] <col1_name> DROP DEFAULT
                          , [ COLUMN ] <col1_name> SET DEFAULT <seq_name>.NEXTVAL
                          , [ COLUMN ] <col1_name> { [ SET ] NOT NULL | DROP NOT NULL }
                          , [ COLUMN ] <col1_name> [ [ SET DATA ] TYPE ] <type>
                          , [ COLUMN ] <col1_name> COMMENT '<string>'
                          , COLUMN <col1_name> [UN]SET MASKING POLICY <policy_name>
                        [ , [ COLUMN ] <col2_name> ... ]
                        [ , ... ]
                    [ ) ]
   | DROP [ COLUMN ] <col1_name> [, <col2_name> ... ]
  }

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

For detailed syntax and examples for altering columns, see ALTER TABLE … ALTER COLUMN. .

For detailed syntax and examples for creating/altering inline constraints, see CREATE | ALTER TABLE … CONSTRAINT.

extTableColumnAction ::=
  {
     ADD COLUMN ( <col_name> <col_type> AS <expr> )

   | RENAME COLUMN <col_name> TO <new_col_name>

   | DROP [ COLUMN ] <col1_name> [, <col2_name> ... ]
  }
constraintAction ::=
  {
     ADD outoflineConstraint
   | RENAME CONSTRAINT <constraint_name> TO <new_constraint_name>
   | { ALTER | MODIFY } { CONSTRAINT <constraint_name> | PRIMARY KEY | UNIQUE | FOREIGN KEY } ( <col_name> [ , ... ] )
                         [ [ NOT ] ENFORCED ] [ VALIDATE | NOVALIDATE ]
   | DROP { CONSTRAINT <constraint_name> | PRIMARY KEY | UNIQUE | FOREIGN KEY } ( <col_name> [ , ... ] )
                         [ CASCADE | RESTRICT ]
  }

  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 detailed syntax and examples for creating/altering out-of-line constraints, see CREATE | ALTER TABLE … CONSTRAINT.

searchOptimizationAction ::=
  {
     ADD SEARCH OPTIMIZATION
   | DROP SEARCH OPTIMIZATION
  }

For details, see Search Optimization Actions (searchOptimizationAction).

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>
     SKIP_BLANK_LINES = TRUE | FALSE
     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
     REPLACE_INVALID_CHARACTERS = 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
     DATE_FORMAT = '<string>' | AUTO
     TIME_FORMAT = '<string>' | AUTO
     TIMESTAMP_FORMAT = '<string>' | AUTO
     BINARY_FORMAT = HEX | BASE64 | UTF8
     TRIM_SPACE = TRUE | FALSE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
     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
     TRIM_SPACE = TRUE | FALSE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
-- If TYPE = ORC
     TRIM_SPACE = TRUE | FALSE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
-- If TYPE = PARQUET
     COMPRESSION = AUTO | LZO | SNAPPY | NONE
     SNAPPY_COMPRESSION = TRUE | FALSE
     BINARY_AS_TEXT = TRUE | FALSE
     TRIM_SPACE = TRUE | FALSE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
-- 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
     TRIM_SPACE = TRUE | FALSE
     NULL_IF = ( '<string>' [ , '<string>' ... ] )
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
     MATCH_BY_COLUMN_NAME = CASE_SENSITIVE | CASE_INSENSITIVE | NONE
     ENFORCE_LENGTH = TRUE | FALSE
     TRUNCATECOLUMNS = TRUE | FALSE
     FORCE = TRUE | FALSE
     LOAD_UNCERTAIN_FILES = TRUE | FALSE
     OVERWRITE = TRUE | FALSE
     SINGLE = TRUE | FALSE
     MAX_FILE_SIZE = <num>
     INCLUDE_QUERY_ID = TRUE | FALSE
     DETAILED_OUTPUT = TRUE | FALSE

Parameters

name

Identifier for the table to alter. If the identifier contains spaces or special characters, the entire string must be enclosed in double quotes. Identifiers enclosed in double quotes are also case-sensitive.

RENAME TO new_table_name

Renames the specified table with a new identifier that is not currently used by any other tables in the schema.

For more details about table identifiers, see Identifier Requirements.

When an object (table, column, etc.) is renamed, other objects that reference it must be updated with the new name.

SWAP WITH target_table_name

Swaps all content and metadata between two specified tables, including any integrity constraints defined for the tables. Also swap all access control privilege grants. The two tables are essentially renamed in a single transaction.

Note

To rename a table or swap two tables, the role used to perform the operation must have OWNERSHIP privileges on the table(s). In addition, renaming a table requires the CREATE TABLE privilege on the schema for the table.

SET ...

Specifies one (or more) properties/parameters to set for the table (separated by blank spaces, commas, or new lines):

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

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

FORMAT_NAME = file_format_name

Specifies an existing file format object to use for loading/unloading data. The specified file format object determines the format type (CSV, JSON, etc.) and other format options for data files.

Note that no additional format options are specified in the string. Instead, the named file format object defines the other file format options used for loading/unloading data. For more information, see CREATE FILE FORMAT.

TYPE = CSV | JSON | AVRO | ORC | PARQUET | XML [ ... ]

Specifies the type of files to load/unload. Additional format-specific options can be included in the string. For more details, see Format Type Options (in this topic).

Note

FORMAT_NAME and TYPE are mutually exclusive; you can only specify one or the other for a table.

STAGE_COPY_OPTIONS = ( ... )

Modifies the copy options to use when loading data from files into the table. For more details, see Copy Options (in this topic).

DATA_RETENTION_TIME_IN_DAYS = integer

Object-level parameter that modifies the retention period for the table for Time Travel. For more details, see Understanding & Using Time Travel and Working with Temporary and Transient Tables.

For a detailed description of this 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

Note

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

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.

Values

0 to 14 (i.e. 14 days) — a value of 0 disables the automatic extension of the data retention period.

Default

14

CHANGE_TRACKING = TRUE | FALSE

Specifies to enable or disable change tracking on the table.

  • TRUE enables change tracking on the table. This option adds a pair of hidden columns to the source table and begins storing change tracking metadata in the columns. These columns consume a small amount of storage.

    The change tracking metadata can be queried using the CHANGES clause for SELECT statements, or by creating and querying one or more streams on the table.

  • FALSE disables change tracking on the table. The pair of hidden columns is dropped from the table.

DEFAULT_DDL_COLLATION = 'collation_specification'

Specifies a default collation specification for any new columns added to the table.

Setting the parameter does not change the collation specification for any existing columns.

For more details about the parameter, see DEFAULT_DDL_COLLATION.

COMMENT = 'string_literal'

Adds a comment or overwrites the existing comment for the table.

UNSET ...

Specifies one (or more) properties/parameters to unset for the table, which resets them back to their defaults:

  • DATA_RETENTION_TIME_IN_DAYS

  • MAX_DATA_EXTENSION_TIME_IN_DAYS

  • CHANGE_TRACKING

  • DEFAULT_DDL_COLLATION

  • COMMENT

Note

You cannot use UNSET to reset the file format and copy options. To reset these options, you must use SET.

Clustering Actions (clusteringAction)

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

Specifies (or modifies) one or more table columns or column expressions as the clustering key for the table. These are the columns/expessions for which clustering is maintained by Automatic Clustering.

Important

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

Before you specify a clustering key for a table, please see Understanding Snowflake Table Structures.

RECLUSTER ...

Deprecated

Performs manual, incremental reclustering of a table that has a clustering key defined:

MAX_SIZE = budget_in_bytes

Deprecated — use a larger warehouse to achieve more effective manual reclustering

Specifies the upper-limit on the amount of data (in bytes) in the table to recluster.

WHERE condition

Specifies a condition or range on which to recluster data in the table.

Note

Only roles with the OWNERSHIP or INSERT privilege on a table can recluster the table.

SUSPEND | RESUME RECLUSTER

Enables or disables Automatic Clustering for the table.

DROP CLUSTERING KEY

Drops the clustering key for the table.

For more information about clustering keys and reclustering, see Understanding Snowflake Table Structures.

Table Column Actions (tableColumnAction)

ADD COLUMN col_name col_data_type [ DEFAULT | AUTOINCREMENT ... ] [ inlineConstraint ] [, ...]

Adds a new column, including optionally adding a default and/or inline constraint for the column, to the table:

This operation can be performed on multiple columns in the same command.

RENAME COLUMN col_name to new_col_name

Renames the specified column to a new name that is not currently used for any other columns in the table.

You cannot rename a column that is part of a clustering key.

When an object (table, column, etc.) is renamed, other objects that reference it must be updated with the new name.

ALTER | MODIFY [ COLUMN ] ...

Modifies one or more properties for a column. This operation can be performed on multiple columns in the same command, with the exception of modifying a column to set or unset a masking policy. For more information on this exception, see Column-level Security Limitations.

For detailed syntax and examples for altering columns, see ALTER TABLE … ALTER COLUMN.

DROP COLUMN col_name [ CASCADE | RESTRICT ]

Removes the specified column from the table.

Dropping a column is a metadata-only operation. It does not immediately re-write the micro-partition(s) and therefore does not immediately free up the space used by the column. Typically, the space within an individual micro-partition is freed the next time that the micro-partition is re-written, which is typically when a write is done either due to DML (INSERT, UPDATE, DELETE) or re-clustering.

External Table Column Actions (extTableColumnAction)

For all other external table modifications, see ALTER EXTERNAL TABLE.

ADD COLUMN ( <col_name> <col_type> AS <expr> ) [, ...]

Adds a new column to the external table.

This operation can be performed on multiple columns in the same command.

RENAME COLUMN col_name to new_col_name

Renames the specified column to a new name that is not currently used for any other columns in the external table.

DROP COLUMN col_name

Removes the specified column from the external table.

Constraint Actions (constraintAction)

ADD CONSTRAINT

Adds an out-of-line integrity constraint to one or more columns in the table. To add an inline constraint (for a column), see Column Actions (in this topic).

RENAME CONSTRAINT constraint_name TO new_constraint_name

Renames the specified constraint.

ALTER | MODIFY CONSTRAINT ...

Alters the properties for the specified constraint.

DROP CONSTRAINT constraint_name | PRIMARY KEY | UNIQUE | FOREIGN KEY ( col_name [ , ... ] ) [ CASCADE | RESTRICT ]

Drops the specified constraint for the specified column or set of columns.

For detailed syntax and examples for adding or altering constraints, see CREATE | ALTER TABLE … CONSTRAINT.

Search Optimization Actions (searchOptimizationAction)

ADD SEARCH OPTIMIZATION

Adds search optimization for the table.

Note:

  • Search optimization can be expensive to maintain, especially if the data in the table changes frequently. For more information, see Managing the Costs of the Search Optimization Service.

  • If you try to add search optimization on a materialized view, Snowflake returns an error message.

DROP SEARCH OPTIMIZATION

Removes search optimization from the table.

Note:

  • If a table has the search optimization property, then dropping the table and undropping it preserves the search optimization property.

  • Removing the search optimization property from a table and then adding it back incurs the same cost as adding it the first time.

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

One or more singlebyte or multibyte characters that separate records in an input file (data loading) or unloaded file (data unloading).

Accepts common escape sequences, octal values (prefixed by \\), or hex values (prefixed by 0x). For example, for records delimited by the thorn (Þ) character, specify the octal (\\336) or hex (0xDE) value. Also accepts a value of NONE.

The specified delimiter must be a valid UTF-8 character and not a random sequence of bytes.

Multiple-character delimiters are also supported; however, the delimiter for RECORD_DELIMITER or FIELD_DELIMITER cannot be a substring of the delimiter for the other file format option (e.g. FIELD_DELIMITER = 'aa' RECORD_DELIMITER = 'aabb'). The delimiter is limited to a maximum of 20 characters. Do not specify characters used for other file format options such as ESCAPE or ESCAPE_UNENCLOSED_FIELD.

Default
Data loading

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.

Data unloading

New line character (\n).

FIELD_DELIMITER = 'character' | NONE
Use

Data loading and unloading

Definition

One or more singlebyte or multibyte characters that separate fields in an input file (data loading) or unloaded file (data unloading).

Accepts common escape sequences, octal values (prefixed by \\), or hex values (prefixed by 0x). For example, for fields delimited by the thorn (Þ) character, specify the octal (\\336) or hex (0xDE) value. Also accepts a value of NONE.

The specified delimiter must be a valid UTF-8 character and not a random sequence of bytes.

Multiple-character delimiters are also supported; however, the delimiter for RECORD_DELIMITER or FIELD_DELIMITER cannot be a substring of the delimiter for the other file format option (e.g. FIELD_DELIMITER = 'aa' RECORD_DELIMITER = 'aabb'). The delimiter is limited to a maximum of 20 characters. Do not specify characters used for other file format options such as ESCAPE or ESCAPE_UNENCLOSED_FIELD.

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

SKIP_BLANK_LINES = TRUE | FALSE
Use

Data loading only

Definition

Boolean that specifies to skip any blank lines encountered in the data files; otherwise, blank lines produce an end-of-record error (default behavior).

Default: FALSE

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 field values. An escape character invokes an alternative interpretation on subsequent characters in a character sequence. You can use the ESCAPE character to interpret instances of the FIELD_DELIMITER, RECORD_DELIMITER, or FIELD_OPTIONALLY_ENCLOSED_BY characters in the data as literals. The escape character can also be used to escape instances of itself in the data.

Accepts common escape sequences, octal values, or hex values.

  • 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. An escape character invokes an alternative interpretation on subsequent characters in a character sequence. You can use the ESCAPE character to interpret instances of the FIELD_DELIMITER or RECORD_DELIMITER characters in the data as literals. The escape character can also be used to escape instances of itself in the data.

Accepts common escape sequences, octal values, or hex values.

Note that when unloading data, if ESCAPE is set, the escape character set for that file format 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.

  • 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 \\)

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.

REPLACE_INVALID_CHARACTERS = TRUE | FALSE
Use

Data loading only

Definition

Boolean that specifies whether to replace invalid UTF-8 characters with the Unicode replacement character ().

If set to TRUE, Snowflake replaces invalid UTF-8 characters with the Unicode replacement character.

If set to FALSE, the load operation produces an error when invalid UTF-8 character encoding is detected.

Default

FALSE

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
  • When loading data, specifies whether to insert SQL NULL for empty fields in an input file, which are represented by two successive delimiters (e.g. ,,).

    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.

  • When unloading data, this option is used in combination with FIELD_OPTIONALLY_ENCLOSED_BY. When FIELD_OPTIONALLY_ENCLOSED_BY = NONE, setting EMPTY_FIELD_AS_NULL = FALSE specifies to unload empty strings in tables to empty string values without quotes enclosing the field values.

    If set to TRUE, FIELD_OPTIONALLY_ENCLOSED_BY must specify a character to enclose strings.

Default

TRUE

SKIP_BYTE_ORDER_MARK = TRUE | FALSE
Use

Data loading only

Definition

Boolean that specifies whether to skip the BOM (byte order mark), if present in a data 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

Notes

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

For loading data from delimited files (CSV, TSV, etc.), UTF-8 is the default. . . For loading data from all other supported file formats (JSON, Avro, etc.), as well as unloading data, UTF-8 is the only supported character set.

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

DATE_FORMAT = 'string' | AUTO
Use

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Defines the format of date string values in the data files. If a value is not specified or is AUTO, the value for the DATE_INPUT_FORMAT parameter is used.

This file format option is currently a Preview Feature.

Default

AUTO

TIME_FORMAT = 'string' | AUTO
Use

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Defines the format of time string values in the data files. If a value is not specified or is AUTO, the value for the TIME_INPUT_FORMAT parameter is used.

This file format option is currently a Preview Feature.

Default

AUTO

TIMESTAMP_FORMAT = string' | AUTO
Use

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Defines the format of timestamp string values in the data files. If a value is not specified or is AUTO, the value for the TIMESTAMP_INPUT_FORMAT parameter is used.

This file format option is currently a Preview Feature.

Default

AUTO

BINARY_FORMAT = HEX | BASE64 | UTF8
Use

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Defines the encoding format for binary string values in the data files. The option can be used when loading data into binary columns in a table.

This file format option is currently a Preview Feature.

Default

HEX

TRIM_SPACE = TRUE | FALSE
Use

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Boolean that specifies whether to remove leading and trailing white space from strings.

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.

This file format option is currently a Preview Feature.

Default

FALSE

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

Data loading only

Definition

Applied only when loading JSON data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). String used to convert to and from SQL NULL. 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.

This file format option is currently a Preview Feature.

Default

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

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: .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 the BOM (byte order mark), if present in a data 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

TRIM_SPACE = TRUE | FALSE
Use

Data loading only

Definition

Applied only when loading Avro data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Boolean that specifies whether to remove leading and trailing white space from strings.

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.

This file format option is currently a Preview Feature.

Default

FALSE

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

Data loading only

Definition

Applied only when loading Avro data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). String used to convert to and from SQL NULL. 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.

This file format option is currently a Preview Feature.

Default

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

TYPE = ORC

TRIM_SPACE = TRUE | FALSE
Use

Data loading only

Definition

Applied only when loading ORC data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Boolean that specifies whether to remove leading and trailing white space from strings.

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.

This file format option is currently a Preview Feature.

Default

FALSE

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

Data loading only

Definition

Applied only when loading ORC data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). String used to convert to and from SQL NULL. 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.

This file format option is currently a Preview Feature.

Default

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

TYPE = PARQUET

COMPRESSION = AUTO | LZO | SNAPPY | NONE
Use

Data loading and unloading

Definition

  • When loading data, specifies the current compression algorithm for columns in the Parquet files.

  • When unloading data, compresses the data file using the specified compression algorithm.

Values

Supported Values

Notes

AUTO

When loading data, compression algorithm detected automatically. Supports the following compression algorithms: Brotli, gzip, Lempel–Ziv–Oberhumer (LZO), LZ4, Snappy, or Zstandard v0.8 (and higher). . When unloading data, unloaded files are compressed using the Snappy compression algorithm by default.

LZO

When unloading data, files are compressed using the Snappy algorithm by default. If unloading data to LZO-compressed files, specify this value.

SNAPPY

When unloading data, files are compressed using the Snappy algorithm by default. You can optionally specify this value.

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

SNAPPY_COMPRESSION = TRUE | FALSE
Use

Data unloading only

AUTO | Unloaded files are compressed using the Snappy compression algorithm by default. SNAPPY | May be specified if unloading Snappy-compressed files. NONE | When loading data, indicates that the files have not been compressed. When unloading data, specifies that the unloaded files are not compressed.

Definition

Boolean that specifies whether unloaded file(s) are compressed using the SNAPPY algorithm.

Note

Deprecated. Use COMPRESSION = SNAPPY instead.

Limitations

Only supported for data unloading operations.

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.

Limitations

Only supported for data loading operations.

Default

TRUE

TRIM_SPACE = TRUE | FALSE
Use

Data loading only

Definition

Applied only when loading Parquet data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Boolean that specifies whether to remove leading and trailing white space from strings.

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.

This file format option is currently a Preview Feature.

Default

FALSE

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

Data loading only

Definition

Applied only when loading Parquet data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). String used to convert to and from SQL NULL. 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.

This file format option is currently a Preview Feature.

Default

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

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

TRIM_SPACE = TRUE | FALSE
Use

Data loading only

Definition

Applied only when loading XML data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). Boolean that specifies whether to remove leading and trailing white space from strings.

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.

This file format option is currently a Preview Feature.

Default

FALSE

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

Data loading only

Definition

Applied only when loading XML data into separate columns (i.e. using the MATCH_BY_COLUMN_NAME copy option or a COPY transformation). String used to convert to and from SQL NULL. 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.

This file format option is currently a Preview Feature.

Default

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

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):

ON_ERROR = CONTINUE | SKIP_FILE | SKIP_FILE_num | SKIP_FILE_num% | ABORT_STATEMENT
Use

Data loading only

Definition

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

Values

Supported Values

Notes

CONTINUE

Continue loading the file. The COPY statement returns an error message for a maximum of one error encountered per data file. Note that the difference between the ROWS_PARSED and ROWS_LOADED column values represents the number of rows that include detected errors. However, each of these rows could include multiple errors. To view all errors in the data files, use the VALIDATION_MODE parameter or query the VALIDATE function.

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 load operation if any error is encountered in a data file. Note that the load operation is not aborted if the data file cannot be found (e.g. because it does not exist or cannot be accessed).

Default
Bulk loading using COPY

ABORT_STATEMENT

Snowpipe

SKIP_FILE

SIZE_LIMIT = num
Use

Data loading only

Definition

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 10 MB in size. If multiple COPY statements set SIZE_LIMIT to 25000000 (25 MB), 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
Use

Data loading only

Definition

Boolean that specifies whether to remove the data files from the stage automatically after the data is loaded successfully.

If this option is set to TRUE, note that a best effort is made to remove successfully loaded data files. If the purge operation fails for any reason, no error is returned currently. We recommend that you list staged files periodically (using LIST) and manually remove successfully loaded files, if any exist.

Default

FALSE

RETURN_FAILED_ONLY = TRUE | FALSE
Use

Data loading only

Definition

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

Default

FALSE

MATCH_BY_COLUMN_NAME = CASE_SENSITIVE | CASE_INSENSITIVE | NONE
Use

Data loading only

Definition

String that specifies whether to load semi-structured data into columns in the target table that match corresponding columns represented in the data.

This copy option is supported for the following data formats:

  • JSON

  • Avro

  • ORC

  • Parquet

For a column to match, the following criteria must be true:

  • The column represented in the data must have the exact same name as the column in the table. The copy option supports case sensitivity for column names. Column order does not matter.

  • The column in the table must have a data type that is compatible with the values in the column represented in the data. For example, string, number, and Boolean values can all be loaded into a variant column.

Values
CASE_SENSITIVE | CASE_INSENSITIVE

Load semi-structured data into columns in the target table that match corresponding columns represented in the data. Column names are either case-sensitive (CASE_SENSITIVE) or case-insensitive (CASE_INSENSITIVE).

The COPY operation verifies that at least one column in the target table matches a column represented in the data files. If a match is found, the values in the data files are loaded into the column or columns. If no match is found, a set of NULL values for each record in the files is loaded into the table.

Note

  • If additional non-matching columns are present in the data files, the values in these columns are not loaded.

  • If additional non-matching columns are present in the target table, the COPY operation inserts NULL values into these columns. These columns must support NULL values.

  • The COPY statement does not allow specifying a query to further transform the data during the load (i.e. COPY transformation).

NONE

The COPY operation loads the semi-structured data into a variant column or, if a query is included in the COPY statement, transforms the data.

Note

The following limitations currently apply:

  • MATCH_BY_COLUMN_NAME cannot be used with the VALIDATION_MODE parameter in a COPY statement to validate the staged data rather than load it into the target table.

  • Parquet data only. When MATCH_BY_COLUMN_NAME is set to CASE_SENSITIVE or CASE_INSENSITIVE, an empty column value (e.g. "col1": "") produces an error.

Default

NONE

ENFORCE_LENGTH = TRUE | FALSE
Use

Data loading only

Definition

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.

Currently, this copy option supports CSV data only.

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.

Default

TRUE

TRUNCATECOLUMNS = TRUE | FALSE
Use

Data loading only

Definition

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.

Currently, this copy option supports CSV data only.

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.

Default

FALSE

FORCE = TRUE | FALSE
Use

Data loading only

Definition

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
Use

Data loading only

Definition

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

OVERWRITE = TRUE | FALSE
Use

Data unloading only

Definition

Boolean that specifies whether the COPY command overwrites existing files with matching names, if any, in the location where files are stored. The option does not remove any existing files that do not match the names of the files that the COPY command unloads.

Default

FALSE

SINGLE = TRUE | FALSE
Use

Data unloading only

Definition

Boolean that specifies whether to generate a single file or multiple files. If FALSE, a filename prefix must be included in path.

Important

If SINGLE = TRUE, then COPY ignores the FILE_EXTENSION file format option and outputs a file simply named data. To specify a file extension, provide a filename and extension in the internal or external location path. For example:

COPY INTO @mystage/data.csv ...

In addition, if the COMPRESSION file format option is also explicitly set to one of the supported compression algorithms (e.g. GZIP), then the specified internal or external location path must end in a filename with the corresponding file extension (e.g. gz) so that the file can be uncompressed using the appropriate tool. For example:

COPY INTO @mystage/data.gz ...

COPY INTO @mystage/data.csv.gz ...
Default

FALSE

MAX_FILE_SIZE = num
Use

Data unloading only

Definition

Number (> 0) that specifies the upper size limit (in bytes) of each file to be generated in parallel per thread. Note that the actual file size and number of files unloaded are determined by the total amount of data and number of nodes available for parallel processing.

Snowflake utilizes parallel execution to optimize performance. The number of threads cannot be modified.

Maximum: 5 GB (Amazon S3 , Google Cloud Storage, or Microsoft Azure stage)

Note

The COPY command unloads one set of table rows at a time. If you set a very small MAX_FILE_SIZE value, the amount of data in a set of rows could exceed the specified size.

Default

16000000 (16 MB)

INCLUDE_QUERY_ID = TRUE | FALSE
Use

Data unloading only

Definition

Boolean that specifies whether to uniquely identify unloaded files by including a universally unique identifier (UUID) in the filenames of unloaded data files. This option helps ensure that concurrent COPY statements do not overwrite unloaded files accidentally.

Values

If TRUE, a UUID is added to the names of unloaded files. The UUID is the query ID of the COPY statement used to unload the data files. The UUID is a segment of the filename: <path>/data_<uuid>_<name>.<extension>.

If FALSE, then a UUID is not added to the unloaded data files.

Note

INCLUDE_QUERY_ID = TRUE is not supported when any one of the following copy options is set:

  • SINGLE = TRUE

  • OVERWRITE = TRUE

Default

FALSE

DETAILED_OUTPUT = TRUE | FALSE
Use

Data unloading only

Definition

Boolean that specifies whether the command output should describe the unload operation or the individual files unloaded as a result of the operation.

Values
  • If TRUE, the command output includes a row for each file unloaded to the specified stage. Columns show the path and name for each file, its size, and the number of rows that were unloaded to the file.

  • If FALSE, the command output consists of a single row that describes the entire unload operation. Columns show the total amount of data unloaded from tables, before and after compression (if applicable), and the total number of rows that were unloaded.

Default

FALSE

Usage Notes

  • Changes to a table are not automatically propagated to views created on that table. For example, if you drop a column in a table, and a view is defined to include that column, the view becomes invalid; the view is not adjusted to remove the column.

  • Dropping a column does not necessarily free up the column’s storage space immediately.

    • The space in each micro-partition is not reclaimed until that micro-partition is re-written. Write operations (insert, update, delete, etc.) on 1 or more rows in that micro-partition cause the micro-partition to be re-written. If you want to force space to be reclaimed, you can forcibly update every row in the table, or you can use CREATE TABLE AS ... to create a new table that contains only the columns of the old table that you want to keep, and then you can drop the old table. Either of these operations can be expensive if the remaining volume of data in the table is large.

    • If the table is protected by the Time Travel feature, the space used by the Time Travel storage is not reclaimed until the Time Travel retention period expires.

  • If a new column with a default value is added to a table with existing rows, all of the existing rows are populated with the default value.

  • Adding a new column with a default value containing a function is not currently supported. The following error is returned:

    Invalid column default expression (expr)

  • To alter a table, you must be using a role that has ownership privilege on the table.

  • Moving a table to a managed access schema (using the ALTER TABLE … RENAME TO syntax) is prohibited unless the table owner (i.e. the role that has the OWNERSHIP privilege on the table) also owns the target schema.

  • To add clustering to a table, you must also have USAGE or OWNERSHIP privileges on the schema and database that contain the table.

Examples

Rename table t1 to a1:

CREATE OR REPLACE TABLE t1(a1 number);

SHOW TABLES LIKE 't1';

---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+
           created_on            | name | database_name | schema_name | kind  | comment | cluster_by | rows | bytes | owner  | retention_time |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+
 Tue, 17 Mar 2015 16:52:33 -0700 | T1   | TESTDB        | MY_SCHEMA   | TABLE |         |            | 0    | 0     | PUBLIC | 1              |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+

ALTER TABLE t1 RENAME TO tt1;

SHOW TABLES LIKE 'tt1';

---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+
           created_on            | name | database_name | schema_name | kind  | comment | cluster_by | rows | bytes | owner  | retention_time |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+
 Tue, 17 Mar 2015 16:52:33 -0700 | TT1  | TESTDB        | MY_SCHEMA   | TABLE |         |            | 0    | 0     | PUBLIC | 1              |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------+----------------+

Swap tables t1 and t2:

CREATE OR REPLACE TABLE t1(a1 number, a2 varchar, a3 date);
CREATE OR REPLACE TABLE t2(b1 varchar);

DESC TABLE t1;

------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |       type        |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 A1   | NUMBER(38,0)      | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A2   | VARCHAR(16777216) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A3   | DATE              | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+

DESC TABLE t2;

------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |       type        |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 B1   | VARCHAR(16777216) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+

ALTER TABLE t1 SWAP WITH t2;

DESC TABLE t1;

------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |       type        |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 B1   | VARCHAR(16777216) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+

DESC TABLE t2;

------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |       type        |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 A1   | NUMBER(38,0)      | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A2   | VARCHAR(16777216) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A3   | DATE              | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+-------------------+--------+-------+---------+-------------+------------+--------+------------+---------+

Add columns to table t1, then rename a column and drop a column in the table:

CREATE OR REPLACE TABLE t1(a1 number);

DESC TABLE t1;

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

-- Add a new column to table T1
ALTER TABLE t1 ADD COLUMN a2 number;

-- Add another column with NOT NULL constraint
ALTER TABLE t1 ADD COLUMN a3 number NOT NULL;

-- Add another column with a default value and a NOT NULL constraint
ALTER TABLE t1 ADD COLUMN a4 number DEFAULT 0 NOT NULL;

DESC TABLE t1;

------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |     type     |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 A1   | NUMBER(38,0) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A2   | NUMBER(38,0) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A3   | NUMBER(38,0) | COLUMN | N     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A4   | NUMBER(38,0) | COLUMN | N     | 0       | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+

-- Rename a column in table T1
ALTER TABLE t1 RENAME COLUMN a1 TO b1;

DESC TABLE t1;

------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 name |     type     |  kind  | null? | default | primary key | unique key | check  | expression | comment |
------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+
 B1   | NUMBER(38,0) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A2   | NUMBER(38,0) | COLUMN | Y     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A3   | NUMBER(38,0) | COLUMN | N     | [NULL]  | N           | N          | [NULL] | [NULL]     | [NULL]  |
 A4   | NUMBER(38,0) | COLUMN | N     | 0       | N           | N          | [NULL] | [NULL]     | [NULL]  |
------+--------------+--------+-------+---------+-------------+------------+--------+------------+---------+

-- Drop a column from table T1
ALTER TABLE t1 DROP COLUMN a2;

DESC TABLE t1;

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

Similar to the last example, but add, rename, and drop a column in external table exttable1:

CREATE EXTERNAL TABLE exttable1(
  LOCATION=@mystage/logs/
  AUTO_REFRESH = true
  FILE_FORMAT = (TYPE = PARQUET)
  );

 DESC EXTERNAL TABLE exttable1;

 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+
 | name      | type              | kind      | null? | default | primary key | unique key | check | expression                                               | comment               |
 |-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------|
 | VALUE     | VARIANT           | COLUMN    | Y     | NULL    | N           | N          | NULL  | NULL                                                     | The value of this row |
 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+

 -- Add a new column to table EXTTABLE1
 ALTER TABLE exttable1 ADD COLUMN a1 varchar AS (value:a1::varchar);

 DESC EXTERNAL TABLE exttable1;

 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+
 | name      | type              | kind      | null? | default | primary key | unique key | check | expression                                               | comment               |
 |-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------|
 | VALUE     | VARIANT           | COLUMN    | Y     | NULL    | N           | N          | NULL  | NULL                                                     | The value of this row |
 | A1        | VARCHAR(16777216) | VIRTUAL   | Y     | NULL    | N           | N          | NULL  | TO_CHAR(GET(VALUE, 'a1'))                                | NULL                  |
 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+

 -- Rename a column in table T1
 ALTER TABLE exttable1 RENAME COLUMN a1 TO b1;

 DESC EXTERNAL TABLE exttable1;

 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+
 | name      | type              | kind      | null? | default | primary key | unique key | check | expression                                               | comment               |
 |-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------|
 | VALUE     | VARIANT           | COLUMN    | Y     | NULL    | N           | N          | NULL  | NULL                                                     | The value of this row |
 | B1        | VARCHAR(16777216) | VIRTUAL   | Y     | NULL    | N           | N          | NULL  | TO_CHAR(GET(VALUE, 'a1'))                                | NULL                  |
 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+

 -- Drop a column from table T1
 ALTER TABLE exttable1 DROP COLUMN b1;

 DESC EXTERNAL TABLE exttable1;

 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+
 | name      | type              | kind      | null? | default | primary key | unique key | check | expression                                               | comment               |
 |-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------|
 | VALUE     | VARIANT           | COLUMN    | Y     | NULL    | N           | N          | NULL  | NULL                                                     | The value of this row |
 +-----------+-------------------+-----------+-------+---------+-------------+------------+-------+----------------------------------------------------------+-----------------------+

Change the order of the clustering key for a table:

CREATE OR REPLACE TABLE T1 (id NUMBER, date TIMESTAMP_NTZ, name STRING) CLUSTER BY (id, date);

SHOW TABLES LIKE 'T1';

---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+
           created_on            | name | database_name | schema_name | kind  | comment | cluster_by | rows | bytes |    owner     | retention_time |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+
 Tue, 21 Jun 2016 15:42:12 -0700 | T1   | TESTDB        | TESTSCHEMA  | TABLE |         | (ID,DATE)  | 0    | 0     | ACCOUNTADMIN | 1              |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+

-- Change the order of the clustering key
ALTER TABLE t1 CLUSTER BY (date, id);

SHOW TABLES LIKE 'T1';

---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+
           created_on            | name | database_name | schema_name | kind  | comment | cluster_by | rows | bytes |    owner     | retention_time |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+
 Tue, 21 Jun 2016 15:42:12 -0700 | T1   | TESTDB        | TESTSCHEMA  | TABLE |         | (DATE,ID)  | 0    | 0     | ACCOUNTADMIN | 1              |
---------------------------------+------+---------------+-------------+-------+---------+------------+------+-------+--------------+----------------+