Conversion functions

GoogleSQL for BigQuery supports conversion functions. These data type conversions are explicit, but some conversions can happen implicitly. You can learn more about implicit and explicit conversion here.

Function list

Name Summary
CAST Convert the results of an expression to the given type.
PARSE_BIGNUMERIC Converts a STRING value to a BIGNUMERIC value.
PARSE_NUMERIC Converts a STRING value to a NUMERIC value.
SAFE_CAST Similar to the CAST function, but returns NULL when a runtime error is produced.

CAST

CAST(expression AS typename [format_clause])

Description

Cast syntax is used in a query to indicate that the result type of an expression should be converted to some other type.

When using CAST, a query can fail if GoogleSQL is unable to perform the cast. If you want to protect your queries from these types of errors, you can use SAFE_CAST.

Casts between supported types that do not successfully map from the original value to the target domain produce runtime errors. For example, casting BYTES to STRING where the byte sequence is not valid UTF-8 results in a runtime error.

Some casts can include a format clause, which provides instructions for how to conduct the cast. For example, you could instruct a cast to convert a sequence of bytes to a BASE64-encoded string instead of a UTF-8-encoded string.

The structure of the format clause is unique to each type of cast and more information is available in the section for that cast.

Examples

The following query results in "true" if x is 1, "false" for any other non-NULL value, and NULL if x is NULL.

CAST(x=1 AS STRING)

CAST AS ARRAY

CAST(expression AS ARRAY<element_type>)

Description

GoogleSQL supports casting to ARRAY. The expression parameter can represent an expression for these data types:

  • ARRAY

Conversion rules

From To Rule(s) when casting x
ARRAY ARRAY Must be the exact same array type.

CAST AS BIGNUMERIC

CAST(expression AS BIGNUMERIC)

Description

GoogleSQL supports casting to BIGNUMERIC. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 BIGNUMERIC The floating point number will round half away from zero. Casting a NaN, +inf or -inf will return an error. Casting a value outside the range of BIGNUMERIC returns an overflow error.
STRING BIGNUMERIC The numeric literal contained in the string must not exceed the maximum precision or range of the BIGNUMERIC type, or an error will occur. If the number of digits after the decimal point exceeds 38, then the resulting BIGNUMERIC value will round half away from zero to have 38 digits after the decimal point.

CAST AS BOOL

CAST(expression AS BOOL)

Description

GoogleSQL supports casting to BOOL. The expression parameter can represent an expression for these data types:

  • INT64
  • BOOL
  • STRING

Conversion rules

From To Rule(s) when casting x
INT64 BOOL Returns FALSE if x is 0, TRUE otherwise.
STRING BOOL Returns TRUE if x is "true" and FALSE if x is "false"
All other values of x are invalid and throw an error instead of casting to a boolean.
A string is case-insensitive when converting to a boolean.

CAST AS BYTES

CAST(expression AS BYTES [format_clause])

Description

GoogleSQL supports casting to BYTES. The expression parameter can represent an expression for these data types:

  • BYTES
  • STRING

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING BYTES Strings are cast to bytes using UTF-8 encoding. For example, the string "©", when cast to bytes, would become a 2-byte sequence with the hex values C2 and A9.

CAST AS DATE

CAST(expression AS DATE [format_clause])

Description

GoogleSQL supports casting to DATE. The expression parameter can represent an expression for these data types:

  • STRING
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING DATE When casting from string to date, the string must conform to the supported date literal format, and is independent of time zone. If the string expression is invalid or represents a date that is outside of the supported min/max range, then an error is produced.
TIMESTAMP DATE Casting from a timestamp to date effectively truncates the timestamp as of the default time zone.

CAST AS DATETIME

CAST(expression AS DATETIME [format_clause])

Description

GoogleSQL supports casting to DATETIME. The expression parameter can represent an expression for these data types:

  • STRING
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING DATETIME When casting from string to datetime, the string must conform to the supported datetime literal format, and is independent of time zone. If the string expression is invalid or represents a datetime that is outside of the supported min/max range, then an error is produced.
TIMESTAMP DATETIME Casting from a timestamp to datetime effectively truncates the timestamp as of the default time zone.

CAST AS FLOAT64

CAST(expression AS FLOAT64)

Description

GoogleSQL supports casting to floating point types. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
INT64 FLOAT64 Returns a close but potentially not exact floating point value.
NUMERIC FLOAT64 NUMERIC will convert to the closest floating point number with a possible loss of precision.
BIGNUMERIC FLOAT64 BIGNUMERIC will convert to the closest floating point number with a possible loss of precision.
STRING FLOAT64 Returns x as a floating point value, interpreting it as having the same form as a valid floating point literal. Also supports casts from "[+,-]inf" to [,-]Infinity, "[+,-]infinity" to [,-]Infinity, and "[+,-]nan" to NaN. Conversions are case-insensitive.

CAST AS INT64

CAST(expression AS INT64)

Description

GoogleSQL supports casting to integer types. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BOOL
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 INT64 Returns the closest integer value.
Halfway cases such as 1.5 or -0.5 round away from zero.
BOOL INT64 Returns 1 if x is TRUE, 0 otherwise.
STRING INT64 A hex string can be cast to an integer. For example, 0x123 to 291 or -0x123 to -291.

Examples

If you are working with hex strings (0x123), you can cast those strings as integers:

SELECT '0x123' as hex_value, CAST('0x123' as INT64) as hex_to_int;

/*-----------+------------*
 | hex_value | hex_to_int |
 +-----------+------------+
 | 0x123     | 291        |
 *-----------+------------*/
SELECT '-0x123' as hex_value, CAST('-0x123' as INT64) as hex_to_int;

/*-----------+------------*
 | hex_value | hex_to_int |
 +-----------+------------+
 | -0x123    | -291       |
 *-----------+------------*/

CAST AS INTERVAL

CAST(expression AS INTERVAL)

Description

GoogleSQL supports casting to INTERVAL. The expression parameter can represent an expression for these data types:

  • STRING

Conversion rules

From To Rule(s) when casting x
STRING INTERVAL When casting from string to interval, the string must conform to either ISO 8601 Duration standard or to interval literal format 'Y-M D H:M:S.F'. Partial interval literal formats are also accepted when they are not ambiguous, for example 'H:M:S'. If the string expression is invalid or represents an interval that is outside of the supported min/max range, then an error is produced.

Examples

SELECT input, CAST(input AS INTERVAL) AS output
FROM UNNEST([
  '1-2 3 10:20:30.456',
  '1-2',
  '10:20:30',
  'P1Y2M3D',
  'PT10H20M30,456S'
]) input

/*--------------------+--------------------*
 | input              | output             |
 +--------------------+--------------------+
 | 1-2 3 10:20:30.456 | 1-2 3 10:20:30.456 |
 | 1-2                | 1-2 0 0:0:0        |
 | 10:20:30           | 0-0 0 10:20:30     |
 | P1Y2M3D            | 1-2 3 0:0:0        |
 | PT10H20M30,456S    | 0-0 0 10:20:30.456 |
 *--------------------+--------------------*/

CAST AS NUMERIC

CAST(expression AS NUMERIC)

Description

GoogleSQL supports casting to NUMERIC. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • STRING

Conversion rules

From To Rule(s) when casting x
FLOAT64 NUMERIC The floating point number will round half away from zero. Casting a NaN, +inf or -inf will return an error. Casting a value outside the range of NUMERIC returns an overflow error.
STRING NUMERIC The numeric literal contained in the string must not exceed the maximum precision or range of the NUMERIC type, or an error will occur. If the number of digits after the decimal point exceeds nine, then the resulting NUMERIC value will round half away from zero. to have nine digits after the decimal point.

CAST AS RANGE

CAST(expression AS RANGE)

Description

GoogleSQL supports casting to RANGE. The expression parameter can represent an expression for these data types:

  • STRING

Conversion rules

From To Rule(s) when casting x
STRING RANGE When casting from string to range, the string must conform to the supported range literal format. If the string expression is invalid or represents a range that is outside of the supported subtype min/max range, then an error is produced.

Examples

SELECT CAST(
  '[2020-01-01, 2020-01-02)'
  AS RANGE<DATE>) AS string_to_range

/*----------------------------------------*
 | string_to_range                        |
 +----------------------------------------+
 | [DATE '2020-01-01', DATE '2020-01-02') |
 *----------------------------------------*/
SELECT CAST(
  '[2014-09-27 12:30:00.45, 2016-10-17 11:15:00.33)'
  AS RANGE<DATETIME>) AS string_to_range

/*------------------------------------------------------------------------*
 | string_to_range                                                        |
 +------------------------------------------------------------------------+
 | [DATETIME '2014-09-27 12:30:00.45', DATETIME '2016-10-17 11:15:00.33') |
 *------------------------------------------------------------------------*/
SELECT CAST(
  '[2014-09-27 12:30:00+08, 2016-10-17 11:15:00+08)'
  AS RANGE<TIMESTAMP>) AS string_to_range

-- Results depend upon where this query was executed.
/*---------------------------------------------------------------------------*
 | string_to_range                                                           |
 +---------------------------------------------------------------------------+
 | [TIMESTAMP '2014-09-27 12:30:00+08', TIMESTAMP '2016-10-17 11:15:00 UTC') |
 *---------------------------------------------------------------------------*/
SELECT CAST(
  '[UNBOUNDED, 2020-01-02)'
  AS RANGE<DATE>) AS string_to_range

/*--------------------------------*
 | string_to_range                |
 +--------------------------------+
 | [UNBOUNDED, DATE '2020-01-02') |
 *--------------------------------*/
SELECT CAST(
  '[2020-01-01, NULL)'
  AS RANGE<DATE>) AS string_to_range

/*--------------------------------*
 | string_to_range                |
 +--------------------------------+
 | [DATE '2020-01-01', UNBOUNDED) |
 *--------------------------------*/

CAST AS STRING

CAST(expression AS STRING [format_clause [AT TIME ZONE timezone_expr]])

Description

GoogleSQL supports casting to STRING. The expression parameter can represent an expression for these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BOOL
  • BYTES
  • TIME
  • DATE
  • DATETIME
  • TIMESTAMP
  • RANGE
  • INTERVAL
  • STRING

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is one of these data types:

  • INT64
  • FLOAT64
  • NUMERIC
  • BIGNUMERIC
  • BYTES
  • TIME
  • DATE
  • DATETIME
  • TIMESTAMP

The format clause for STRING has an additional optional clause called AT TIME ZONE timezone_expr, which you can use to specify a specific time zone to use during formatting of a TIMESTAMP. If this optional clause is not included when formatting a TIMESTAMP, your current time zone is used.

For more information, see the following topics:

Conversion rules

From To Rule(s) when casting x
FLOAT64 STRING Returns an approximate string representation. A returned NaN or 0 will not be signed.
BOOL STRING Returns "true" if x is TRUE, "false" otherwise.
BYTES STRING Returns x interpreted as a UTF-8 string.
For example, the bytes literal b'\xc2\xa9', when cast to a string, is interpreted as UTF-8 and becomes the unicode character "©".
An error occurs if x is not valid UTF-8.
TIME STRING Casting from a time type to a string is independent of time zone and is of the form HH:MM:SS.
DATE STRING Casting from a date type to a string is independent of time zone and is of the form YYYY-MM-DD.
DATETIME STRING Casting from a datetime type to a string is independent of time zone and is of the form YYYY-MM-DD HH:MM:SS.
TIMESTAMP STRING When casting from timestamp types to string, the timestamp is interpreted using the default time zone, UTC. The number of subsecond digits produced depends on the number of trailing zeroes in the subsecond part: the CAST function will truncate zero, three, or six digits.
INTERVAL STRING Casting from an interval to a string is of the form Y-M D H:M:S.

Examples

SELECT CAST(CURRENT_DATE() AS STRING) AS current_date

/*---------------*
 | current_date  |
 +---------------+
 | 2021-03-09    |
 *---------------*/
SELECT CAST(CURRENT_DATE() AS STRING FORMAT 'DAY') AS current_day

/*-------------*
 | current_day |
 +-------------+
 | MONDAY      |
 *-------------*/
SELECT CAST(
  TIMESTAMP '2008-12-25 00:00:00+00:00'
  AS STRING FORMAT 'YYYY-MM-DD HH24:MI:SS TZH:TZM') AS date_time_to_string

-- Results depend upon where this query was executed.
/*------------------------------*
 | date_time_to_string          |
 +------------------------------+
 | 2008-12-24 16:00:00 -08:00   |
 *------------------------------*/
SELECT CAST(
  TIMESTAMP '2008-12-25 00:00:00+00:00'
  AS STRING FORMAT 'YYYY-MM-DD HH24:MI:SS TZH:TZM'
  AT TIME ZONE 'Asia/Kolkata') AS date_time_to_string

-- Because the time zone is specified, the result is always the same.
/*------------------------------*
 | date_time_to_string          |
 +------------------------------+
 | 2008-12-25 05:30:00 +05:30   |
 *------------------------------*/
SELECT CAST(INTERVAL 3 DAY AS STRING) AS interval_to_string

/*--------------------*
 | interval_to_string |
 +--------------------+
 | 0-0 3 0:0:0        |
 *--------------------*/
SELECT CAST(
  INTERVAL "1-2 3 4:5:6.789" YEAR TO SECOND
  AS STRING) AS interval_to_string

/*--------------------*
 | interval_to_string |
 +--------------------+
 | 1-2 3 4:5:6.789    |
 *--------------------*/

CAST AS STRUCT

CAST(expression AS STRUCT)

Description

GoogleSQL supports casting to STRUCT. The expression parameter can represent an expression for these data types:

  • STRUCT

Conversion rules

From To Rule(s) when casting x
STRUCT STRUCT Allowed if the following conditions are met:
  1. The two structs have the same number of fields.
  2. The original struct field types can be explicitly cast to the corresponding target struct field types (as defined by field order, not field name).

CAST AS TIME

CAST(expression AS TIME [format_clause])

Description

GoogleSQL supports casting to TIME. The expression parameter can represent an expression for these data types:

  • STRING
  • TIME
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

Conversion rules

From To Rule(s) when casting x
STRING TIME When casting from string to time, the string must conform to the supported time literal format, and is independent of time zone. If the string expression is invalid or represents a time that is outside of the supported min/max range, then an error is produced.

CAST AS TIMESTAMP

CAST(expression AS TIMESTAMP [format_clause [AT TIME ZONE timezone_expr]])

Description

GoogleSQL supports casting to TIMESTAMP. The expression parameter can represent an expression for these data types:

  • STRING
  • DATETIME
  • TIMESTAMP

Format clause

When an expression of one type is cast to another type, you can use the format clause to provide instructions for how to conduct the cast. You can use the format clause in this section if expression is a STRING.

The format clause for TIMESTAMP has an additional optional clause called AT TIME ZONE timezone_expr, which you can use to specify a specific time zone to use during formatting. If this optional clause is not included, your current time zone is used.

Conversion rules

From To Rule(s) when casting x
STRING TIMESTAMP When casting from string to a timestamp, string_expression must conform to the supported timestamp literal formats, or else a runtime error occurs. The string_expression may itself contain a time zone.

If there is a time zone in the string_expression, that time zone is used for conversion, otherwise the default time zone, UTC, is used. If the string has fewer than six digits, then it is implicitly widened.

An error is produced if the string_expression is invalid, has more than six subsecond digits (i.e., precision greater than microseconds), or represents a time outside of the supported timestamp range.
DATE TIMESTAMP Casting from a date to a timestamp interprets date_expression as of midnight (start of the day) in the default time zone, UTC.
DATETIME TIMESTAMP Casting from a datetime to a timestamp interprets datetime_expression in the default time zone, UTC.

Most valid datetime values have exactly one corresponding timestamp in each time zone. However, there are certain combinations of valid datetime values and time zones that have zero or two corresponding timestamp values. This happens in a time zone when clocks are set forward or set back, such as for Daylight Savings Time. When there are two valid timestamps, the earlier one is used. When there is no valid timestamp, the length of the gap in time (typically one hour) is added to the datetime.

Examples

The following example casts a string-formatted timestamp as a timestamp:

SELECT CAST("2020-06-02 17:00:53.110+00:00" AS TIMESTAMP) AS as_timestamp

-- Results depend upon where this query was executed.
/*-----------------------------*
 | as_timestamp                |
 +-----------------------------+
 | 2020-06-03 00:00:53.110 UTC |
 *-----------------------------*/

The following examples cast a string-formatted date and time as a timestamp. These examples return the same output as the previous example.

SELECT CAST('06/02/2020 17:00:53.110' AS TIMESTAMP FORMAT 'MM/DD/YYYY HH24:MI:SS.FF3' AT TIME ZONE 'UTC') AS as_timestamp
SELECT CAST('06/02/2020 17:00:53.110' AS TIMESTAMP FORMAT 'MM/DD/YYYY HH24:MI:SS.FF3' AT TIME ZONE '+00') AS as_timestamp
SELECT CAST('06/02/2020 17:00:53.110 +00' AS TIMESTAMP FORMAT 'MM/DD/YYYY HH24:MI:SS.FF3 TZH') AS as_timestamp

PARSE_BIGNUMERIC

PARSE_BIGNUMERIC(string_expression)

Description

Converts a STRING to a BIGNUMERIC value.

The numeric literal contained in the string must not exceed the maximum precision or range of the BIGNUMERIC type, or an error occurs. If the number of digits after the decimal point exceeds 38, then the resulting BIGNUMERIC value rounds half away from zero to have 38 digits after the decimal point.


-- This example shows how a string with a decimal point is parsed.
SELECT PARSE_BIGNUMERIC("123.45") AS parsed;

/*--------*
 | parsed |
 +--------+
 | 123.45 |
 *--------*/

-- This example shows how a string with an exponent is parsed.
SELECT PARSE_BIGNUMERIC("123.456E37") AS parsed;

/*-----------------------------------------*
 | parsed                                  |
 +-----------------------------------------+
 | 123400000000000000000000000000000000000 |
 *-----------------------------------------*/

-- This example shows the rounding when digits after the decimal point exceeds 38.
SELECT PARSE_BIGNUMERIC("1.123456789012345678901234567890123456789") as parsed;

/*------------------------------------------*
 | parsed                                   |
 +------------------------------------------+
 | 1.12345678901234567890123456789012345679 |
 *------------------------------------------*/

This function is similar to using the CAST AS BIGNUMERIC function except that the PARSE_BIGNUMERIC function only accepts string inputs and allows the following in the string:

  • Spaces between the sign (+/-) and the number
  • Signs (+/-) after the number

Rules for valid input strings:

Rule Example Input Output
The string can only contain digits, commas, decimal points and signs. "- 12,34567,89.0" -123456789
Whitespaces are allowed anywhere except between digits. " - 12.345 " -12.345
Only digits and commas are allowed before the decimal point. " 12,345,678" 12345678
Only digits are allowed after the decimal point. "1.234 " 1.234
Use E or e for exponents. After the e, digits and a leading sign indicator are allowed. " 123.45e-1" 12.345
If the integer part is not empty, then it must contain at least one digit. " 0,.12 -" -0.12
If the string contains a decimal point, then it must contain at least one digit. " .1" 0.1
The string cannot contain more than one sign. " 0.5 +" 0.5

Return Data Type

BIGNUMERIC

Examples

This example shows an input with spaces before, after, and between the sign and the number:

SELECT PARSE_BIGNUMERIC("  -  12.34 ") as parsed;

/*--------*
 | parsed |
 +--------+
 | -12.34 |
 *--------*/

This example shows an input with an exponent as well as the sign after the number:

SELECT PARSE_BIGNUMERIC("12.34e-1-") as parsed;

/*--------*
 | parsed |
 +--------+
 | -1.234 |
 *--------*/

This example shows an input with multiple commas in the integer part of the number:

SELECT PARSE_BIGNUMERIC("  1,2,,3,.45 + ") as parsed;

/*--------*
 | parsed |
 +--------+
 | 123.45 |
 *--------*/

This example shows an input with a decimal point and no digits in the whole number part:

SELECT PARSE_BIGNUMERIC(".1234  ") as parsed;

/*--------*
 | parsed |
 +--------+
 | 0.1234 |
 *--------*/

Examples of invalid inputs

This example is invalid because the whole number part contains no digits:

SELECT PARSE_BIGNUMERIC(",,,.1234  ") as parsed;

This example is invalid because there are whitespaces between digits:

SELECT PARSE_BIGNUMERIC("1  23.4 5  ") as parsed;

This example is invalid because the number is empty except for an exponent:

SELECT PARSE_BIGNUMERIC("  e1 ") as parsed;

This example is invalid because the string contains multiple signs:

SELECT PARSE_BIGNUMERIC("  - 12.3 - ") as parsed;

This example is invalid because the value of the number falls outside the range of BIGNUMERIC:

SELECT PARSE_BIGNUMERIC("12.34E100 ") as parsed;

This example is invalid because the string contains invalid characters:

SELECT PARSE_BIGNUMERIC("$12.34") as parsed;

PARSE_NUMERIC

PARSE_NUMERIC(string_expression)

Description

Converts a STRING to a NUMERIC value.

The numeric literal contained in the string must not exceed the maximum precision or range of the NUMERIC type, or an error occurs. If the number of digits after the decimal point exceeds nine, then the resulting NUMERIC value rounds half away from zero to have nine digits after the decimal point.


-- This example shows how a string with a decimal point is parsed.
SELECT PARSE_NUMERIC("123.45") AS parsed;

/*--------*
 | parsed |
 +--------+
 | 123.45 |
 *--------*/

-- This example shows how a string with an exponent is parsed.
SELECT PARSE_NUMERIC("12.34E27") as parsed;

/*-------------------------------*
 | parsed                        |
 +-------------------------------+
 | 12340000000000000000000000000 |
 *-------------------------------*/

-- This example shows the rounding when digits after the decimal point exceeds 9.
SELECT PARSE_NUMERIC("1.0123456789") as parsed;

/*-------------*
 | parsed      |
 +-------------+
 | 1.012345679 |
 *-------------*/

This function is similar to using the CAST AS NUMERIC function except that the PARSE_NUMERIC function only accepts string inputs and allows the following in the string:

  • Spaces between the sign (+/-) and the number
  • Signs (+/-) after the number

Rules for valid input strings:

Rule Example Input Output
The string can only contain digits, commas, decimal points and signs. "- 12,34567,89.0" -123456789
Whitespaces are allowed anywhere except between digits. " - 12.345 " -12.345
Only digits and commas are allowed before the decimal point. " 12,345,678" 12345678
Only digits are allowed after the decimal point. "1.234 " 1.234
Use E or e for exponents. After the e, digits and a leading sign indicator are allowed. " 123.45e-1" 12.345
If the integer part is not empty, then it must contain at least one digit. " 0,.12 -" -0.12
If the string contains a decimal point, then it must contain at least one digit. " .1" 0.1
The string cannot contain more than one sign. " 0.5 +" 0.5

Return Data Type

NUMERIC

Examples

This example shows an input with spaces before, after, and between the sign and the number:

SELECT PARSE_NUMERIC("  -  12.34 ") as parsed;

/*--------*
 | parsed |
 +--------+
 | -12.34 |
 *--------*/

This example shows an input with an exponent as well as the sign after the number:

SELECT PARSE_NUMERIC("12.34e-1-") as parsed;

/*--------*
 | parsed |
 +--------+
 | -1.234 |
 *--------*/

This example shows an input with multiple commas in the integer part of the number:

SELECT PARSE_NUMERIC("  1,2,,3,.45 + ") as parsed;

/*--------*
 | parsed |
 +--------+
 | 123.45 |
 *--------*/

This example shows an input with a decimal point and no digits in the whole number part:

SELECT PARSE_NUMERIC(".1234  ") as parsed;

/*--------*
 | parsed |
 +--------+
 | 0.1234 |
 *--------*/

Examples of invalid inputs

This example is invalid because the whole number part contains no digits:

SELECT PARSE_NUMERIC(",,,.1234  ") as parsed;

This example is invalid because there are whitespaces between digits:

SELECT PARSE_NUMERIC("1  23.4 5  ") as parsed;

This example is invalid because the number is empty except for an exponent:

SELECT PARSE_NUMERIC("  e1 ") as parsed;

This example is invalid because the string contains multiple signs:

SELECT PARSE_NUMERIC("  - 12.3 - ") as parsed;

This example is invalid because the value of the number falls outside the range of BIGNUMERIC:

SELECT PARSE_NUMERIC("12.34E100 ") as parsed;

This example is invalid because the string contains invalid characters:

SELECT PARSE_NUMERIC("$12.34") as parsed;

SAFE_CAST

SAFE_CAST(expression AS typename [format_clause])

Description

When using CAST, a query can fail if GoogleSQL is unable to perform the cast. For example, the following query generates an error:

SELECT CAST("apple" AS INT64) AS not_a_number;

If you want to protect your queries from these types of errors, you can use SAFE_CAST. SAFE_CAST replaces runtime errors with NULLs. However, during static analysis, impossible casts between two non-castable types still produce an error because the query is invalid.

SELECT SAFE_CAST("apple" AS INT64) AS not_a_number;

/*--------------*
 | not_a_number |
 +--------------+
 | NULL         |
 *--------------*/

Some casts can include a format clause, which provides instructions for how to conduct the cast. For example, you could instruct a cast to convert a sequence of bytes to a BASE64-encoded string instead of a UTF-8-encoded string.

The structure of the format clause is unique to each type of cast and more information is available in the section for that cast.

If you are casting from bytes to strings, you can also use the function, SAFE_CONVERT_BYTES_TO_STRING. Any invalid UTF-8 characters are replaced with the unicode replacement character, U+FFFD.

Other conversion functions

You can learn more about these conversion functions elsewhere in the documentation:

Conversion function From To
ARRAY_TO_STRING ARRAY STRING
BOOL JSON BOOL
DATE Various data types DATE
DATE_FROM_UNIX_DATE INT64 DATE
DATETIME Various data types DATETIME
FLOAT64 JSON FLOAT64
FROM_BASE32 STRING BYTEs
FROM_BASE64 STRING BYTES
FROM_HEX STRING BYTES
INT64 JSON INT64
PARSE_DATE STRING DATE
PARSE_DATETIME STRING DATETIME
PARSE_JSON STRING JSON
PARSE_TIME STRING TIME
PARSE_TIMESTAMP STRING TIMESTAMP
SAFE_CONVERT_BYTES_TO_STRING BYTES STRING
STRING TIMESTAMP STRING
STRING JSON STRING
TIME Various data types TIME
TIMESTAMP Various data types TIMESTAMP
TIMESTAMP_MICROS INT64 TIMESTAMP
TIMESTAMP_MILLIS INT64 TIMESTAMP
TIMESTAMP_SECONDS INT64 TIMESTAMP
TO_BASE32 BYTES STRING
TO_BASE64 BYTES STRING
TO_HEX BYTES STRING
TO_JSON All data types JSON
TO_JSON_STRING All data types STRING