Categories:

Conversion Functions

TRY_TO_TIMESTAMP / TRY_TO_TIMESTAMP_*¶

A special version of TO_TIMESTAMP / TO_TIMESTAMP_* that performs the same operation (i.e. converts an input expression into a timestamp), but with error-handling support (i.e. if the conversion cannot be performed, it returns a NULL value instead of raising an error).

For more information, see Error-handling Conversion Functions.

Note

TRY_TO_TIMESTAMP maps to one of the other timestamp functions, based on the TIMESTAMP_TYPE_MAPPING session parameter. The parameter default is TIMESTAMP_NTZ so TRY_TO_TIMESTAMP maps to TRY_TO_TIMESTAMP_NTZ by default.

See also:

TO_TIMESTAMP / TO_TIMESTAMP_*

Syntax¶

timestampFunction ( <string_expr> [, <format> ] )
timestampFunction ( '<integer>' )
Copy

Where:

timestampFunction ::=
    TRY_TO_TIMESTAMP | TRY_TO_TIMESTAMP_LTZ | TRY_TO_TIMESTAMP_NTZ | TRY_TO_TIMESTAMP_TZ
Copy

Arguments¶

Required:

One of:

string_expr

The argument should be a string that can be evaluated to a TIMESTAMP (TIMESTAMP_NTZ, TIMESTAMP_LTZ, or TIMESTAMP_TZ).

'integer'

An expression that evaluates to a string containing an integer, for example ‘15000000’. Depending upon the magnitude of the string, it can be interpreted as seconds, milliseconds, microseconds, or nanoseconds. For details, see the Usage Notes below.

Note

The use of quoted integers as inputs is deprecated.

Optional:

format

Format specifier for string_expr or AUTO. For more information, see Date and Time Formats in Conversion Functions.

The default is the current value of the TIMESTAMP_INPUT_FORMAT session parameter (usually AUTO).

Returns¶

The data type of the returned value is one of the TIMESTAMP data types. By default, the data type is TIMESTAMP_NTZ. You can change this by setting the session parameter TIMESTAMP_TYPE_MAPPING.

Usage Notes¶

  • If the format of the input parameter is a string that contains an integer:

    • After the string is converted to an integer, the integer is treated as a number of seconds, milliseconds, microseconds, or nanoseconds after the start of the Unix epoch (1970-01-01 00:00:00.000000000 UTC).

      • If the integer is less than 31536000000 (the number of milliseconds in a year), then the value is treated as a number of seconds.

      • If the value is greater than or equal to 31536000000 and less than 31536000000000, then the value is treated as milliseconds.

      • If the value is greater than or equal to 31536000000000 and less than 31536000000000000, then the value is treated as microseconds.

      • If the value is greater than or equal to 31536000000000000, then the value is treated as nanoseconds.

      Note

      Deprecation Warning: Future versions of Snowflake might automatically interpret stringified integer values as seconds, rather than as milliseconds, microseconds, or nanoseconds. Snowflake recommends that you call TO_DATE, TO_TIME, or TO_TIMESTAMP with strings that contain integers only when those integers are intended to be interpreted as seconds.

    • If more than one row is evaluated (for example, if the input is the column name of a table that contains more than one row), each value is examined independently to determine if the value represents seconds, milliseconds, microseconds, or nanoseconds.

Examples¶

This demonstrates usage of TRY_TO_TIMESTAMP:

SELECT TRY_TO_TIMESTAMP('2018-09-15 12:30:00'), TRY_TO_TIMESTAMP('Invalid');
+-----------------------------------------+-----------------------------+
| TRY_TO_TIMESTAMP('2018-09-15 12:30:00') | TRY_TO_TIMESTAMP('INVALID') |
|-----------------------------------------+-----------------------------|
| 2018-09-15 12:30:00.000                 | NULL                        |
+-----------------------------------------+-----------------------------+
Copy