This page explains Cloud Spanner SQL expressions, including functions and operators.
Function call rules
The following rules apply to all functions unless explicitly indicated otherwise in the function description:
- For functions that accept numeric types, if one operand is a floating point operand and the other operand is another numeric type, both operands are converted to FLOAT64 before the function is evaluated.
- If an operand is
NULL
, the result isNULL
, with the exception of the IS operator. - For functions that are time zone sensitive (as indicated in the function description), the default time zone, America/Los_Angeles, is used if a time zone is not specified.
Conversion rules
"Conversion" includes, but is not limited to, casting and coercion.
- Casting is explicit conversion and uses the
CAST()
function. - Coercion is implicit conversion, which Cloud Spanner SQL performs automatically under the conditions described below.
- There is a third group of conversion
functions that have their own function
names, such as
UNIX_DATE()
.
The table below summarizes all possible CAST
and coercion possibilities for
Cloud Spanner SQL data types. "Coercion To" applies to all expressions of a
given data type (e.g. a column)
.
From Type | CAST to | Coercion To |
---|---|---|
INT64 | BOOL INT64 FLOAT64 STRING |
FLOAT64 |
FLOAT64 | INT64 FLOAT64 STRING |
|
BOOL | BOOL INT64 STRING |
|
STRING | BOOL INT64 FLOAT64 STRING BYTES DATE TIMESTAMP |
|
BYTES | BYTES STRING |
|
DATE | DATE STRING TIMESTAMP |
|
TIMESTAMP | DATE STRING TIMESTAMP |
|
ARRAY | ARRAY | |
STRUCT | STRUCT |
Casting
Syntax:
CAST(expr AS typename)
Cast syntax is used in a query to indicate that the result type of an expression should be converted to some other type.
Example:
CAST(x=1 AS STRING)
This results in "true"
if x
is 1
, "false"
for any other non-NULL
value, and NULL
if x
is NULL
.
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.
When casting an expression x
of the following types, these rules apply:
From | To | Rule(s) when casting x |
---|---|---|
INT64 | FLOAT64 | Returns a close but potentially not exact FLOAT64 value. |
INT64 | BOOL | Returns FALSE if x is 0 , TRUE otherwise. |
FLOAT64 | INT64 | Returns the closest INT64 value. Halfway cases such as 1.5 or -0.5 round away from zero. |
FLOAT64 | STRING | Returns an approximate string representation. |
BOOL | INT64 | Returns 1 if x is TRUE , 0 otherwise. |
BOOL | STRING | Returns "true" if x is TRUE , "false" otherwise. |
STRING | FLOAT64 | Returns x as a
FLOAT64
value, interpreting it as having the same form as a valid
FLOAT64
literal.Also supports casts from "inf" , "+inf" , "-inf" , and "nan" .Conversions are case-insensitive. |
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 BOOL.STRINGs are case-insensitive when converting to BOOL. |
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. |
BYTES | STRING | Returns x interpreted as a UTF-8 STRING.For example, the BYTES literal b'\xc2\xa9' , when cast to STRING, is interpreted as UTF-8 and
becomes the unicode character "©".An error occurs if x is not valid UTF-8. |
ARRAY | ARRAY | Must be the exact same ARRAY type. |
STRUCT | STRUCT | Allowed if the following conditions are met:
|
Casting hex strings to integers
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 |
+-----------+------------+
Casting date types
Cloud Spanner SQL supports casting date types to/from strings as follows:
CAST(date_expression AS STRING)
CAST(string_expression AS DATE)
Casting from a date type to a string is independent of time zone and is of the
form YYYY-MM-DD
. 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.
Casting timestamp types
Cloud Spanner SQL supports casting timestamp types to/from strings as follows:
CAST(timestamp_expression AS STRING)
CAST(string_expression AS TIMESTAMP)
When casting from timestamp types to string, the timestamp is interpreted using the default time zone, America/Los_Angeles. 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.
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
—see
time zones.
If there is a time zone in the string_expression
, that time zone is used for
conversion, otherwise the default time zone, America/Los_Angeles, 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.
Casting between date and timestamp types
Cloud Spanner SQL supports casting between date and timestamp types as follows:
CAST(date_expression AS TIMESTAMP)
CAST(timestamp_expression AS DATE)
Casting from a date to a timestamp interprets date_expression
as of midnight
(start of the day) in the default time zone, America/Los_Angeles. Casting
from a timestamp to date effectively truncates the timestamp as of the default
time zone.
Coercion
Cloud Spanner SQL coerces the result type of an expression to another type if needed to match function signatures. For example, if function func() is defined to take a single argument of type INT64 and an expression is used as an argument that has a result type of FLOAT64, then the result of the expression will be coerced to INT64 type before func() is computed.
Additional conversion functions
Cloud Spanner SQL provides the following additional conversion functions:
Aggregate functions
An aggregate function is a function that performs a calculation on a set of
values. COUNT
, MIN
and MAX
are examples of aggregate functions.
SELECT COUNT(*) as total_count, COUNT(fruit) as non_null_count,
MIN(fruit) as min, MAX(fruit) as max
FROM (SELECT NULL as fruit UNION ALL
SELECT "apple" as fruit UNION ALL
SELECT "pear" as fruit UNION ALL
SELECT "orange" as fruit)
+-------------+----------------+-------+------+
| total_count | non_null_count | min | max |
+-------------+----------------+-------+------+
| 4 | 3 | apple | pear |
+-------------+----------------+-------+------+
The following sections describe the aggregate functions that Cloud Spanner SQL supports.
ANY_VALUE
ANY_VALUE(expression)
Description
Returns any value from the input or NULL
if there are zero input rows.
Returns NULL
if expression
evaluates to
NULL
for all rows and non-NULL
value otherwise. The value
returned is non-deterministic, which means you might receive a different result
each time you use this function.
Supported Argument Types
Any
Returned Data Types
Matches the input data type.
Examples
SELECT ANY_VALUE(fruit) as any_value
FROM UNNEST(["apple", "banana", "pear"]) as fruit;
+-----------+
| any_value |
+-----------+
| apple |
+-----------+
ARRAY_AGG
ARRAY_AGG([DISTINCT] expression)
Description
Returns an ARRAY of expression
values.
Supported Argument Types
All data types except ARRAY.
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Output Element Order
The order of the elements in the output is non-deterministic, which means you might receive a different result each time you use this function.
Returned Data Types
ARRAY
If there are zero input rows, this function returns NULL
.
Examples
SELECT ARRAY_AGG(x) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;
+-------------------------+
| array_agg |
+-------------------------+
| [2, 1, -2, 3, -2, 1, 2] |
+-------------------------+
SELECT ARRAY_AGG(DISTINCT x) AS array_agg
FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x;
+---------------+
| array_agg |
+---------------+
| [2, 1, -2, 3] |
+---------------+
AVG
AVG([DISTINCT] expression)
Description
Returns the average of non-NULL
input values, or NaN
if the input contains a
NaN
.
Supported Argument Types
Any numeric input type, such as INT64. Note that, for floating point input types, the return result is non-deterministic, which means you might receive a different result each time you use this function.
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Returned Data Types
- FLOAT64
Examples
SELECT AVG(x) as avg
FROM UNNEST([0, 2, 4, 4, 5]) as x;
+-----+
| avg |
+-----+
| 3 |
+-----+
SELECT AVG(DISTINCT x) AS avg
FROM UNNEST([0, 2, 4, 4, 5]) AS x;
+------+
| avg |
+------+
| 2.75 |
+------+
BIT_AND
BIT_AND([DISTINCT] expression)
Description
Performs a bitwise AND operation on expression
and returns the result.
Supported Argument Types
- INT64
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Returned Data Types
INT64
Examples
SELECT BIT_AND(x) as bit_and FROM UNNEST([0xF001, 0x00A1]) as x;
+---------+
| bit_and |
+---------+
| 1 |
+---------+
BIT_OR
BIT_OR([DISTINCT] expression)
Description
Performs a bitwise OR operation on expression
and returns the result.
Supported Argument Types
- INT64
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Returned Data Types
INT64
Examples
SELECT BIT_OR(x) as bit_or FROM UNNEST([0xF001, 0x00A1]) as x;
+--------+
| bit_or |
+--------+
| 61601 |
+--------+
BIT_XOR
BIT_XOR([DISTINCT] expression)
Description
Performs a bitwise XOR operation on expression
and returns the result.
Supported Argument Types
- INT64
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Returned Data Types
INT64
Examples
SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([5678, 1234]) AS x;
+---------+
| bit_xor |
+---------+
| 4860 |
+---------+
SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x;
+---------+
| bit_xor |
+---------+
| 5678 |
+---------+
SELECT BIT_XOR(DISTINCT x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x;
+---------+
| bit_xor |
+---------+
| 4860 |
+---------+
COUNT
1.
COUNT(*)
2.
COUNT([DISTINCT] expression)
Description
- Returns the number of rows in the input.
- Returns the number of rows with
expression
evaluated to any value other thanNULL
.
Supported Argument Types
expression
can be any data type.
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Return Data Types
INT64
Examples
SELECT
COUNT(*) AS count_star,
COUNT(DISTINCT x) AS count_dist_x
FROM UNNEST([1, 4, 4, 5]) AS x;
+------------+--------------+
| count_star | count_dist_x |
+------------+--------------+
| 4 | 3 |
+------------+--------------+
SELECT COUNT(*) AS count_star, COUNT(x) AS count_x
FROM UNNEST([1, 4, NULL, 4, 5]) AS x;
+------------+---------+
| count_star | count_x |
+------------+---------+
| 5 | 4 |
+------------+---------+
COUNTIF
COUNTIF([DISTINCT] expression)
Description
Returns the count of TRUE
values for expression
.
Returns 0
if there are zero input rows or expression
evaluates to FALSE
for all rows.
Supported Argument Types
BOOL
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Return Data Types
INT64
Examples
SELECT COUNTIF(x<0) AS num_negative, COUNTIF(x>0) AS num_positive
FROM UNNEST([5, -2, 3, 6, -10, -7, 4, 0]) AS x;
+--------------+--------------+
| num_negative | num_positive |
+--------------+--------------+
| 3 | 4 |
+--------------+--------------+
LOGICAL_AND
LOGICAL_AND(expression)
Description
Returns the logical AND of all non-NULL
expressions. Returns NULL
if there
are zero input rows or expression
evaluates to NULL
for all rows.
Supported Argument Types
BOOL
Return Data Types
BOOL
Examples
SELECT LOGICAL_AND(x) AS logical_and FROM UNNEST([true, false, true]) AS x;
+-------------+
| logical_and |
+-------------+
| false |
+-------------+
LOGICAL_OR
LOGICAL_OR(expression)
Description
Returns the logical OR of all non-NULL
expressions. Returns NULL
if there
are zero input rows or expression
evaluates to NULL
for all rows.
Supported Argument Types
BOOL
Return Data Types
BOOL
Examples
SELECT LOGICAL_OR(x) AS logical_or FROM UNNEST([true, false, true]) AS x;
+------------+
| logical_or |
+------------+
| true |
+------------+
MAX
MAX(expression)
Description
Returns the maximum value of non-NULL
expressions. Returns NULL
if there
are zero input rows or expression
evaluates to NULL
for all rows.
Returns NaN
if the input contains a NaN
.
Supported Argument Types
Any data type except:
ARRAY
STRUCT
Return Data Types
Same as the data type used as the input values.
Examples
SELECT MAX(x) AS max
FROM UNNEST([8, 37, 4, 55]) AS x;
+-----+
| max |
+-----+
| 55 |
+-----+
MIN
MIN(expression)
Description
Returns the minimum value of non-NULL
expressions. Returns NULL
if there
are zero input rows or expression
evaluates to NULL
for all rows.
Returns NaN
if the input contains a NaN
.
Supported Argument Types
Any data type except:
ARRAY
STRUCT
Return Data Types
Same as the data type used as the input values.
Examples
SELECT MIN(x) AS min
FROM UNNEST([8, 37, 4, 55]) AS x;
+-----+
| min |
+-----+
| 4 |
+-----+
STRING_AGG
STRING_AGG([DISTINCT] expression [, delimiter])
Description
Returns a value (either STRING or BYTES) obtained by concatenating non-null values.
If a delimiter
is specified, concatenated values are separated by that
delimiter; otherwise, a comma is used as a delimiter.
Supported Argument Types
STRING BYTES
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Output Element Order
The order of the elements in the output is non-deterministic, which means you might receive a different result each time you use this function.
Return Data Types
STRING BYTES
Examples
SELECT STRING_AGG(fruit) AS string_agg
FROM UNNEST(["apple", NULL, "pear", "banana", "pear"]) AS fruit;
+------------------------+
| string_agg |
+------------------------+
| apple,pear,banana,pear |
+------------------------+
SELECT STRING_AGG(fruit, " & ") AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;
+------------------------------+
| string_agg |
+------------------------------+
| apple & pear & banana & pear |
+------------------------------+
SELECT STRING_AGG(DISTINCT fruit, " & ") AS string_agg
FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit;
+-----------------------+
| string_agg |
+-----------------------+
| apple & pear & banana |
+-----------------------+
SUM
SUM([DISTINCT] expression)
Description
Returns the sum of non-null values.
If the expression is a floating point value, the sum is non-deterministic, which means you might receive a different result each time you use this function.
Supported Argument Types
Any supported numeric data types.
Optional Clause
DISTINCT
: Each distinct value of
expression
is aggregated only once into the result.
Return Data Types
- Returns INT64 if the input is an integer.
- Returns FLOAT64 if the input is a floating point value.
Returns NULL
if the input contains only NULL
s.
Returns Inf
if the input contains Inf
.
Returns -Inf
if the input contains -Inf
.
Returns NaN
if the input contains a NaN
.
Returns NaN
if the input contains a combination of Inf
and -Inf
.
Examples
SELECT SUM(x) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;
+-----+
| sum |
+-----+
| 25 |
+-----+
SELECT SUM(DISTINCT x) AS sum
FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x;
+-----+
| sum |
+-----+
| 15 |
+-----+
Mathematical functions
All mathematical functions have the following behaviors:
- They return
NULL
if any of the input parameters isNULL
. - They return
NaN
if any of the arguments isNaN
.
ABS
ABS(X)
Description
Computes absolute value. Returns an error if the argument is an integer and the
output value cannot be represented as the same type; this happens only for the
largest negative input value, which has no positive representation. Returns
+inf
for a +/-inf
argument.
SIGN
SIGN(X)
Description
Returns -1, 0, or +1 for negative, zero and positive arguments respectively.
For floating point arguments, this function does not distinguish between
positive and negative zero. Returns NaN
for a NaN
argument.
IS_INF
IS_INF(X)
Description
Returns TRUE
if the value is positive or negative infinity. Returns
NULL
for NULL
inputs.
IS_NAN
IS_NAN(X)
Description
Returns TRUE
if the value is a NaN
value. Returns NULL
for NULL
inputs.
IEEE_DIVIDE
IEEE_DIVIDE(X, Y)
Description
Divides X by Y; this function never fails. Returns
FLOAT64
. Unlike the division operator (/),
this function does not generate errors for division by zero or overflow.
Special cases:
- If the result overflows, returns
+/-inf
. - If Y=0 and X=0, returns
NaN
. - If Y=0 and X!=0, returns
+/-inf
. - If X =
+/-inf
and Y =+/-inf
, returnsNaN
.
The behavior of IEEE_DIVIDE
is further illustrated in the table below.
Special cases for IEEE_DIVIDE
The following table lists special cases for IEEE_DIVIDE
.
Numerator Data Type (X) | Denominator Data Type (Y) | Result Value |
---|---|---|
Anything except 0 | 0 | +/-inf |
0 | 0 | NaN |
0 | NaN |
NaN |
NaN |
0 | NaN |
+/-inf |
+/-inf |
NaN |
SQRT
SQRT(X)
Description
Computes the square root of X. Generates an error if X is less than 0. Returns
+inf
if X is +inf
.
POW
POW(X, Y)
Description
Returns the value of X raised to the power of Y. If the result underflows and is not representable, then the function returns a value of zero. Returns an error if one of the following is true:
- X is a finite value less than 0 and Y is a noninteger
- X is 0 and Y is a finite value less than 0
The behavior of POW()
is further illustrated in the table below.
POWER
POWER(X, Y)
Description
Synonym of POW()
.
Special cases for POW(X, Y)
and POWER(X, Y)
The following are special cases for POW(X, Y)
and POWER(X, Y)
.
X | Y | POW(X, Y) or POWER(X, Y) |
---|---|---|
1.0 | Any value including NaN |
1.0 |
any including NaN |
0 | 1.0 |
-1.0 | +/-inf |
1.0 |
ABS(X) < 1 | -inf |
+inf |
ABS(X) > 1 | -inf |
0 |
ABS(X) < 1 | +inf |
0 |
ABS(X) > 1 | +inf |
+inf |
-inf |
Y < 0 | 0 |
-inf |
Y > 0 | -inf if Y is an odd integer, +inf otherwise |
+inf |
Y < 0 | 0 |
+inf |
Y > 0 | +inf |
EXP
EXP(X)
Description
Computes e to the power of X, also called the natural exponential function. If
the result underflows, this function returns a zero. Generates an error if the
result overflows. If X is +/-inf
, then this function returns +inf
or 0.
LN
LN(X)
Description
Computes the natural logarithm of X. Generates an error if X is less than or
equal to zero. If X is +inf
, then this function returns +inf
.
LOG
LOG(X [, Y])
Description
If only X is present, LOG
is a synonym of LN
. If Y is also present, LOG
computes the logarithm of X to base Y. Generates an error in these cases:
- X is less than or equal to zero
- Y is 1.0
- Y is less than or equal to zero.
The behavior of LOG(X, Y)
is further illustrated in the table below.
Special cases for LOG(X, Y)
X | Y | LOG(X, Y) |
---|---|---|
-inf |
Any value | NaN |
Any value | +inf |
NaN |
+inf |
0.0 Y < 1.0 | -inf |
+inf |
Y > 1.0 | +inf |
LOG10
LOG10(X)
Description
Similar to LOG
, but computes logarithm to base 10.
GREATEST
GREATEST(X1,...,XN)
Description
Returns NULL
if any of the inputs is NULL
. Otherwise, returns NaN
if any of
the inputs is NaN
. Otherwise, returns the largest value among X1,...,XN
according to the < comparison.
LEAST
LEAST(X1,...,XN)
Description
Returns NULL
if any of the inputs is NULL
. Returns NaN
if any of the
inputs is NaN
. Otherwise, returns the smallest value among X1,...,XN
according to the > comparison.
DIV
DIV(X, Y)
Description
Returns the result of integer division of X by Y. Division by zero returns an error. Division by -1 may overflow. See the table below for possible result types.
MOD
MOD(X, Y)
Description
Modulo function: returns the remainder of the division of X by Y. Returned value has the same sign as X. An error is generated if Y is 0. See the table below for possible result types.
ROUND
ROUND(X [, N])
Description
If only X is present, ROUND
rounds X to the nearest integer. If N is present,
ROUND
rounds X to N decimal places after the decimal point. If N is negative,
ROUND
will round off digits to the left of the decimal point. Rounds halfway
cases away from zero. Generates an error if overflow occurs.
TRUNC
TRUNC(X [, N])
Description
If only X is present, TRUNC
rounds X to the nearest integer whose absolute
value is not greater than the absolute value of X. If N is also present, TRUNC
behaves like ROUND(X, N)
, but always rounds towards zero and never overflows.
CEIL
CEIL(X)
Description
Returns the smallest integral value (with FLOAT64 type) that is not less than X.
CEILING
CEILING(X)
Description
Synonym of CEIL(X)
FLOOR
FLOOR(X)
Description
Returns the largest integral value (with FLOAT64 type) that is not greater than X.
Example rounding function behavior
Example behavior of Cloud Spanner SQL rounding functions:
Input "X" | ROUND(X) | TRUNC(X) | CEIL(X) | FLOOR(X) |
---|---|---|---|---|
2.0 | 2.0 | 2.0 | 2.0 | 2.0 |
2.3 | 2.0 | 2.0 | 3.0 | 2.0 |
2.8 | 3.0 | 2.0 | 3.0 | 2.0 |
2.5 | 3.0 | 2.0 | 3.0 | 2.0 |
-2.3 | -2.0 | -2.0 | -2.0 | -3.0 |
-2.8 | -3.0 | -2.0 | -2.0 | -3.0 |
-2.5 | -3.0 | -2.0 | -2.0 | -3.0 |
0 | 0 | 0 | 0 | 0 |
+/-inf |
+/-inf |
+/-inf |
+/-inf |
+/-inf |
NaN |
NaN |
NaN |
NaN |
NaN |
COS
COS(X)
Description
Computes the cosine of X where X is specified in radians. Never fails.
COSH
COSH(X)
Description
Computes the hyperbolic cosine of X where X is specified in radians. Generates an error if overflow occurs.
ACOS
ACOS(X)
Description
Computes the principal value of the inverse cosine of X. The return value is in the range [0,π]. Generates an error if X is a value outside of the range [-1, 1].
ACOSH
ACOSH(X)
Description
Computes the inverse hyperbolic cosine of X. Generates an error if X is a value less than 1.
SIN
SIN(X)
Description
Computes the sine of X where X is specified in radians. Never fails.
SINH
SINH(X)
Description
Computes the hyperbolic sine of X where X is specified in radians. Generates an error if overflow occurs.
ASIN
ASIN(X)
Description
Computes the principal value of the inverse sine of X. The return value is in the range [-π/2,π/2]. Generates an error if X is outside of the range [-1, 1].
ASINH
ASINH(X)
Description
Computes the inverse hyperbolic sine of X. Does not fail.
TAN
TAN(X)
Description
Computes the tangent of X where X is specified in radians. Generates an error if overflow occurs.
TANH
TANH(X)
Description
Computes the hyperbolic tangent of X where X is specified in radians. Does not fail.
ATAN
ATAN(X)
Description
Computes the principal value of the inverse tangent of X. The return value is in the range [-π/2,π/2]. Does not fail.
ATANH
ATANH(X)
Description
Computes the inverse hyperbolic tangent of X. Generates an error if X is outside of the range [-1, 1].
ATAN2
ATAN2(Y, X)
Description
Calculates the principal value of the inverse tangent of Y/X using the signs of the two arguments to determine the quadrant. The return value is in the range [-π,π]. The behavior of this function is further illustrated in the table below.
Special cases for ATAN2()
Y | X | ATAN2(Y, X) |
---|---|---|
NaN |
Any value | NaN |
Any value | NaN |
NaN |
0 | 0 | 0, π or -π depending on the sign of X and Y |
Finite value | -inf |
π or -π depending on the sign of Y |
Finite value | +inf |
0 |
+/-inf |
Finite value | π/2 or π/2 depending on the sign of Y |
+/-inf |
-inf |
¾π or -¾π depending on the sign of Y |
+/-inf |
+inf |
π/4 or -π/4 depending on the sign of Y |
Special cases for trigonometric and hyperbolic rounding functions
X | COS(X) | COSH(X) | ACOS(X) | ACOSH(X) | SIN(X) | SINH(X) | ASIN(X) | ASINH(X) | TAN(X) | TANH(X) | ATAN(X) | ATANH(X) |
---|---|---|---|---|---|---|---|---|---|---|---|---|
+/-inf |
NaN |
=+inf |
NaN |
=+inf |
NaN |
=+inf |
NaN |
=+inf |
NaN |
=+1.0 | π/2 | NaN |
-inf |
NaN |
=+inf |
NaN |
NaN |
NaN |
-inf |
NaN |
-inf |
NaN |
-1.0 | -π/2 | NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
NaN |
Hash functions
FARM_FINGERPRINT
FARM_FINGERPRINT(value)
Description
Computes the fingerprint of the STRING or BYTES input using the Fingerprint64
function from the
open-source FarmHash library. The output
of this function for a particular input will never change.
Return type
INT64
Examples
WITH example AS (
SELECT 1 AS x, "foo" AS y, true AS z UNION ALL
SELECT 2 AS x, "apple" AS y, false AS z UNION ALL
SELECT 3 AS x, "" AS y, true AS z
)
SELECT
*,
FARM_FINGERPRINT(CONCAT(CAST(x AS STRING), y, CAST(z AS STRING)))
AS row_fingerprint
FROM example;
+---+-------+-------+----------------------+
| x | y | z | row_fingerprint |
+---+-------+-------+----------------------+
| 1 | foo | true | -1541654101129638711 |
| 2 | apple | false | 2794438866806483259 |
| 3 | | true | -4880158226897771312 |
+---+-------+-------+----------------------+
SHA1
SHA1(input)
Description
Computes the hash of the input using the SHA-1 algorithm. The input can either be STRING or BYTES. The string version treats the input as an array of bytes.
This function returns 20 bytes.
Return type
BYTES
Example
SELECT SHA1("Hello World") as sha1;
+-----------------------------------------------------------+
| sha1 |
+-----------------------------------------------------------+
| \nMU\xa8\xd7x\xe5\x02/\xabp\x19w\xc5\xd8@\xbb\xc4\x86\xd0 |
+-----------------------------------------------------------+
SHA256
SHA256(input)
Description
Computes the hash of the input using the SHA-256 algorithm. The input can either be STRING or BYTES. The string version treats the input as an array of bytes.
This function returns 32 bytes.
Return type
BYTES
Example
SELECT SHA256("Hello World") as sha256;
SHA512
SHA512(input)
Description
Computes the hash of the input using the SHA-512 algorithm. The input can either be STRING or BYTES. The string version treats the input as an array of bytes.
This function returns 64 bytes.
Return type
BYTES
Example
SELECT SHA512("Hello World") as sha512;
String functions
These string functions work on two different values: STRING and BYTES data types. STRING values must be well-formed UTF-8.
Functions that return position values, such as STRPOS, encode those
positions as INT64. The value 1
refers to the first
character (or byte), 2
refers to the second, and so on. The value 0
indicates an invalid index. When working on
STRING types, the returned positions refer to
character positions.
All string comparisons are done byte-by-byte, without regard to Unicode canonical equivalence.
BYTE_LENGTH
BYTE_LENGTH(value)
Description
Returns the length of the value in bytes, regardless of whether the type of the value is STRING or BYTES.
Return type
INT64
Examples
WITH example AS
(SELECT "абвгд" AS characters, b"абвгд" AS bytes)
SELECT
characters,
BYTE_LENGTH(characters) AS string_example,
bytes,
BYTE_LENGTH(bytes) AS bytes_example
FROM example;
+------------+----------------+-------+---------------+
| characters | string_example | bytes | bytes_example |
+------------+----------------+-------+---------------+
| абвгд | 10 | абвгд | 10 |
+------------+----------------+-------+---------------+
CHAR_LENGTH
CHAR_LENGTH(value)
Description
Returns the length of the STRING in characters.
Return type
INT64
Examples
WITH example AS
(SELECT "абвгд" AS characters)
SELECT
characters,
CHAR_LENGTH(characters) AS char_length_example
FROM example;
+------------+---------------------+
| characters | char_length_example |
+------------+---------------------+
| абвгд | 5 |
+------------+---------------------+
CHARACTER_LENGTH
CHARACTER_LENGTH(value)
Description
Synonym for CHAR_LENGTH.
Return type
INT64
Examples
WITH example AS
(SELECT "абвгд" AS characters)
SELECT
characters,
CHARACTER_LENGTH(characters) AS char_length_example
FROM example;
+------------+---------------------+
| characters | char_length_example |
+------------+---------------------+
| абвгд | 5 |
+------------+---------------------+
CODE_POINTS_TO_BYTES
CODE_POINTS_TO_BYTES(ascii_values)
Description
Takes an array of extended ASCII code points (ARRAY of INT64) and returns BYTES.
To convert from BYTES to an array of code points, see TO_CODE_POINTS.
Return type
BYTES
Examples
The following is a basic example using CODE_POINTS_TO_BYTES
.
SELECT CODE_POINTS_TO_BYTES([65, 98, 67, 100]) AS bytes;
+-------+
| bytes |
+-------+
| AbCd |
+-------+
The following example uses a rotate-by-13 places (ROT13) algorithm to encode a string.
SELECT CODE_POINTS_TO_BYTES(ARRAY(
(SELECT
CASE
WHEN chr BETWEEN b'a' AND b'z'
THEN TO_CODE_POINTS(b'a')[offset(0)] +
MOD(code + 13 - TO_CODE_POINTS(b'a')[offset(0)],26)
WHEN chr BETWEEN b'A' AND b'Z'
THEN TO_CODE_POINTS(b'A')[offset(0)] +
MOD(code + 13 - TO_CODE_POINTS(b'A')[offset(0)],26)
ELSE code
END
FROM
(SELECT code, CODE_POINTS_TO_BYTES(ARRAY[code]) AS chr
FROM UNNEST(TO_CODE_POINTS(input)) AS code WITH OFFSET
ORDER BY OFFSET)
))) AS encoded_string
FROM UNNEST(ARRAY['Test String!']) AS input;
+----------------+
| encoded_string |
+----------------+
| Grfg Fgevat! |
+----------------+
CODE_POINTS_TO_STRING
CODE_POINTS_TO_STRING(value)
Description
Takes an array of Unicode code points (ARRAY of INT64) and returns a STRING.
To convert from a string to an array of code points, see TO_CODE_POINTS.
Return type
STRING
Example
The following is a basic example using CODE_POINTS_TO_STRING
.
SELECT CODE_POINTS_TO_STRING([65, 255, 513, 1024]) AS string;
+--------+
| string |
+--------+
| AÿȁЀ |
+--------+
The following example computes the frequency of letters in a set of words.
WITH Words AS (
SELECT word
FROM UNNEST(['foo', 'bar', 'baz', 'giraffe', 'llama']) AS word
)
SELECT
CODE_POINTS_TO_STRING([code_point]) AS letter,
COUNT(*) AS letter_count
FROM Words,
UNNEST(TO_CODE_POINTS(word)) AS code_point
GROUP BY 1
ORDER BY 2 DESC;
+--------+--------------+
| letter | letter_count |
+--------+--------------+
| a | 5 |
| f | 3 |
| r | 2 |
| b | 2 |
| l | 2 |
| o | 2 |
| g | 1 |
| z | 1 |
| e | 1 |
| m | 1 |
| i | 1 |
+--------+--------------+
CONCAT
CONCAT(value1[, ...])
Description
Concatenates one or more values into a single result.
Return type
STRING or BYTES
Examples
With Employees AS
(SELECT
"John" AS first_name,
"Doe" AS last_name
UNION ALL
SELECT
"Jane" AS first_name,
"Smith" AS last_name
UNION ALL
SELECT
"Joe" AS first_name,
"Jackson" AS last_name)
SELECT
CONCAT(first_name, " ", last_name)
AS full_name
FROM Employees;
+---------------------+
| full_name |
+---------------------+
| John Doe |
| Jane Smith |
| Joe Jackson |
+---------------------+
ENDS_WITH
ENDS_WITH(value1, value2)
Description
Takes two values. Returns TRUE if the second value is a suffix of the first.
Return type
BOOL
Examples
WITH items AS
(SELECT "apple" as item
UNION ALL
SELECT "banana" as item
UNION ALL
SELECT "orange" as item)
SELECT
ENDS_WITH(item, "e") as example
FROM items;
+---------+
| example |
+---------+
| True |
| False |
| True |
+---------+
FORMAT
Cloud Spanner SQL supports a FORMAT()
function for formatting strings. This
function is similar to the C printf
function. It produces a
STRING from a format string that contains zero or
more format specifiers, along with a variable length list of additional
arguments that matches the format specifiers. Here are some examples:
Description | Statement | Result |
---|---|---|
Simple integer | format("%d", 10) | 10 |
Integer with left blank padding | format("|%10d|", 11) | | 11| |
Integer with left zero padding | format("+%010d+", 12) | +0000000012+ |
Integer with commas | format("%'d", 123456789) | 123,456,789 |
STRING | format("-%s-", 'abcd efg') | -abcd efg- |
FLOAT64 | format("%f %E", 1.1, 2.2) | 1.100000 2.200000E+00 |
DATE | format("%t", date "2015-09-01") | 2015-09-01 |
TIMESTAMP | format("%t", timestamp "2015-09-01 12:34:56 America/Los_Angeles") | 2015‑09‑01 19:34:56+00 |
The FORMAT()
function does not provide fully customizable formatting for all
types and values, nor formatting that is sensitive to locale.
If custom formatting is necessary for a type, you must first format it using
type-specific format functions, such as FORMAT_DATE()
or FORMAT_TIMESTAMP()
.
For example:
FORMAT("date: %s!", FORMAT_DATE("%B %d, %Y", date '2015-01-02'));
Returns
date: January 02, 2015!
Syntax
The FORMAT()
syntax takes a format string and variable length list of
arguments and produces a STRING result:
FORMAT(<format_string>, ...)
The <format_string>
expression can contain zero or more format specifiers.
Each format specifier is introduced by the %
symbol, and must map to one or
more of the remaining arguments. For the most part, this is a one-to-one
mapping, except when the *
specifier is present. For example, %.*i
maps to
two arguments—a length argument and a signed integer argument. If the
number of arguments related to the format specifiers is not the same as the
number of arguments, an error occurs.
Supported format specifiers
The FORMAT()
function format specifier follows this prototype:
%[flags][width][.precision]specifier
The supported format specifiers are identified in the following table. Extensions from printf() are identified in italics.
Specifier | Description | Examples | Types |
d or i |
Decimal integer | 392 |
INT64 |
o |
Octal | 610 |
INT64* |
x |
Hexadecimal integer | 7fa |
INT64* |
X |
Hexadecimal integer (uppercase) | 7FA |
INT64* |
f |
Decimal floating point, lowercase | 392.65inf NaN |
FLOAT64 |
F |
Decimal floating point, uppercase | 392.65inf NAN |
FLOAT64 |
e |
Scientific notation (mantissa/exponent), lowercase | 3.9265e+2inf NaN |
FLOAT64 |
E |
Scientific notation (mantissa/exponent), uppercase | 3.9265E+2inf NAN |
FLOAT64 |
g |
Use the shortest representation, %e or %f | 392.65 |
FLOAT64 |
G |
Use the shortest representation, %E or %F | 392.65 |
FLOAT64 |
s |
String of characters | sample | STRING |
t |
Returns a printable string representing the value. Often looks similar to casting the argument to STRING. See %t section below. | sample 2014‑01‑01 |
<any> |
T |
Produces a string that is a valid Cloud Spanner SQL constant with a similar type to the value's type (maybe wider, or maybe string). See %T section below. | 'sample' b'bytes sample' 1234 2.3 date '2014‑01‑01' |
<any> |
% |
'%%' produces a single '%' | % | n/a |
*The specifiers o, x, and X raise an error if negative values are used.
The format specifier can optionally contain the sub-specifiers identified above in the specifier prototype.
These sub-specifiers must comply with the following specifications.
Flags
Flags | Description |
- |
Left-justify within the given field width; Right justification is the default (see width sub-specifier) |
+ |
Forces to precede the result with a plus or minus sign (+
or - ) even for positive numbers. By default, only negative numbers
are preceded with a - sign |
<space> | If no sign is going to be written, a blank space is inserted before the value |
# |
Used with o, x or X specifiers. Precedes the value with 0, 0x or 0X respectively for values different than zero |
0 |
Left-pads the number with zeroes (0) instead of spaces when padding is specified (see width sub-specifier) |
' |
Formats integers using the appropriating grouping character. For example:
This flag is only relevant for decimal, hex, and octal values. |
Flags may be specified in any order. Duplicate flags are not an error. When flags are not relevant for some element type, they are ignored.
Width
Width | Description |
<number> | Minimum number of characters to be printed. If the value to be printed is shorter than this number, the result is padded with blank spaces. The value is not truncated even if the result is larger |
* |
The width is not specified in the format string, but as an additional integer value argument preceding the argument that has to be formatted |
Precision
Precision | Description |
. <number> |
For integer specifiers (d, i, o, u, x, X): precision specifies the minimum number of digits to be written. If the value to be written is shorter than this number, the result is padded with trailing zeros. The value is not truncated even if the result is longer. A precision of 0 means that no character is written for the value 0. For a, A, e, E, f and F specifiers: this is the number of digits to be printed after the decimal point (by default, this is 6) |
.* |
The precision is not specified in the format string, but as an additional integer value argument preceding the argument that has to be formatted |
%t and %T behavior
The %t
and %T
format specifiers are defined for all types. The width,
precision, and flags act as they do for %s
: the width
is the minimum width
and the STRING will be padded to that size, and precision
is the maximum width
of content to show and the STRING will be truncated to that size, prior to
padding to width.
%t is always meant to be a readable form of the value.
%T is always a valid SQL literal of a similar type, such as a wider numeric type. The literal will not include casts or a type name, except for the special case of non-finite floating point values.
The STRING is formatted as follows:
Type | %t | %T |
NULL of any type |
NULL |
NULL |
INT64 |
123 | 123 |
FLOAT64 | 123.0 (always with .0) 123e+10 inf -inf NaN |
123.0 (always with .0) 123e+10 CAST("inf" AS <type>) CAST("-inf" AS <type>) CAST("nan" AS <type>) |
STRING | unquoted string value | quoted string literal |
BYTES | unquoted escaped bytes e.g. abc\x01\x02 |
quoted bytes literal e.g. b"abc\x01\x02" |
DATE | 2011-02-03 | DATE "2011-02-03" |
TIMESTAMP | 2011-02-03 04:05:06+00 | TIMESTAMP "2011-02-03 04:05:06+00" |
ARRAY | [value, value, ...] where values are formatted with %t |
[value, value, ...] where values are formatted with %T |
Error conditions
If a format specifier is invalid, or is not compatible with the related
argument type, or the wrong number or arguments are provided, then an error is
produced. For example, the following <format_string>
expressions are invalid:
FORMAT('%s', 1)
FORMAT('%')
NULL argument handling
A NULL
format string results in a NULL
output STRING. Any other arguments are
ignored in this case.
The function generally produces a NULL
value if a NULL
argument is present. For
example, FORMAT('%i', <NULL expression>)
produces a NULL
STRING as output.
However, there are some exceptions: if the format specifier is %t or %T (both of
which produce STRINGs that effectively match CAST and
literal value semantics), a NULL
value produces 'NULL' (without the quotes) in
the result STRING. For example, the function:
FORMAT('00-%t-00', <NULL expression>);
Returns
00-NULL-00
Additional semantic rules
FLOAT64 values can be +/-inf
or NaN
. When an argument has one of
those values, the result of the format specifiers %f
, %F
, %e
, %E
, %g
,
%G
, and %t
are inf
, -inf
, or nan
(or the same in uppercase) as
appropriate. This is consistent with how Cloud Spanner SQL casts these values
to STRING. For %T
, Cloud Spanner SQL returns quoted strings for
FLOAT64 values that don't have non-string literal
representations.
FROM_BASE64
FROM_BASE64(string_expr)
Description
Converts the base64-encoded input string_expr
into BYTES format. To convert
BYTES to a base64-encoded STRING, use TO_BASE64.
Return type
BYTES
Example
SELECT FROM_BASE64('3q2+7w==') AS byte_data;
+------------------+
| byte_data |
+------------------+
| \xde\xad\xbe\xef |
+------------------+
FROM_HEX
FROM_HEX(string)
Description
Converts a hexadecimal-encoded STRING into BYTES format. Returns an error if the
input STRING contains characters outside the range
(0..9, A..F, a..f)
. The lettercase of the characters does not matter. If the
input STRING has an odd number of characters, the function acts as if the input
has an additional leading 0
. To convert BYTES to a
hexadecimal-encoded STRING, use
TO_HEX.
Return type
BYTES
Example
WITH Input AS (
SELECT '00010203aaeeefff' AS hex_str UNION ALL
SELECT '0AF' UNION ALL
SELECT '666f6f626172'
)
SELECT hex_str, FROM_HEX(hex_str) AS bytes_str
FROM Input;
+------------------+----------------------------------+
| hex_str | bytes_str |
+------------------+----------------------------------+
| 0AF | \x00\xaf |
| 00010203aaeeefff | \x00\x01\x02\x03\xaa\xee\xef\xff |
| 666f6f626172 | foobar |
+------------------+----------------------------------+
LENGTH
LENGTH(value)
Description
Returns the length of the value. The returned value is in characters for STRING arguments and in bytes for the BYTES argument.
Return type
INT64
Examples
WITH example AS
(SELECT "абвгд" AS characters)
SELECT
characters,
LENGTH(characters) AS string_example,
LENGTH(CAST(characters AS BYTES)) AS bytes_example
FROM example;
+------------+----------------+---------------+
| characters | string_example | bytes_example |
+------------+----------------+---------------+
| абвгд | 5 | 10 |
+------------+----------------+---------------+
LPAD
LPAD(original_value, return_length[, pattern])
Description
Returns a value that consists of original_value
prepended
with pattern
. The return_length
is an INT64 that specifies the length of the
returned value. If original_value
is BYTES, return_length
is the number of
bytes. If original_value
is STRING, return_length
is the number of
characters.
The default value of pattern
is a blank space.
Both original_value
and pattern
must be the same data type.
If return_length
is less than or equal to the original_value
length, this
function returns the original_value
value, truncated to the value of
return_length
. For example, LPAD("hello world", 7);
returns "hello w"
.
If original_value
, return_length
, or pattern
is NULL, this function
returns NULL.
This function returns an error if:
return_length
is negativepattern
is empty
Return type
STRING or BYTES
Examples
SELECT t, len, FORMAT("%T", LPAD(t, len)) AS LPAD FROM UNNEST([
STRUCT('abc' AS t, 5 AS len),
('abc', 2),
('例子', 4)
]);
t | len | LPAD |
---|---|---|
abc | 5 | " abc" |
abc | 2 | "ab" |
例子 | 4 | " 例子" |
SELECT t, len, pattern, FORMAT("%T", LPAD(t, len, pattern)) AS LPAD FROM UNNEST([
STRUCT('abc' AS t, 8 AS len, 'def' AS pattern),
('abc', 5, '-'),
('例子', 5, '中文')
]);
t | len | pattern | LPAD |
---|---|---|---|
abc | 8 | def | "defdeabc" |
abc | 5 | - | "--abc" |
例子 | 5 | 中文 | "中文中例子" |
SELECT FORMAT("%T", t) AS t, len, FORMAT("%T", LPAD(t, len)) AS LPAD FROM UNNEST([
STRUCT(b'abc' AS t, 5 AS len),
(b'abc', 2),
(b'\xab\xcd\xef', 4)
]);
t | len | LPAD |
---|---|---|
b"abc" | 5 | b" abc" |
b"abc" | 2 | b"ab" |
b"\xab\xcd\xef" | 4 | b" \xab\xcd\xef" |
SELECT
FORMAT("%T", t) AS t,
len,
FORMAT("%T", pattern) AS pattern,
FORMAT("%T", LPAD(t, len, pattern)) AS LPAD
FROM UNNEST([
STRUCT(b'abc' AS t, 8 AS len, b'def' AS pattern),
(b'abc', 5, b'-'),
(b'\xab\xcd\xef', 5, b'\x00')
]);
t | len | pattern | LPAD |
---|---|---|---|
b"abc" | 8 | b"def" | b"defdeabc" |
b"abc" | 5 | b"-" | b"--abc" |
b"\xab\xcd\xef" | 5 | b"\x00" | b"\x00\x00\xab\xcd\xef" |
LOWER
LOWER(value)
Description
For STRING arguments, returns the original string with all alphabetic characters in lowercase. Mapping between lowercase and uppercase is done according to the Unicode Character Database without taking into account language-specific mappings.
For BYTES arguments, the argument is treated as ASCII text, with all bytes greater than 127 left intact.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT
"FOO" as item
UNION ALL
SELECT
"BAR" as item
UNION ALL
SELECT
"BAZ" as item)
SELECT
LOWER(item) AS example
FROM items;
+---------+
| example |
+---------+
| foo |
| bar |
| baz |
+---------+
LTRIM
LTRIM(value1[, value2])
Description
Identical to TRIM, but only removes leading characters.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT " apple " as item
UNION ALL
SELECT " banana " as item
UNION ALL
SELECT " orange " as item)
SELECT
CONCAT("#", LTRIM(item), "#") as example
FROM items;
+-------------+
| example |
+-------------+
| #apple # |
| #banana # |
| #orange # |
+-------------+
WITH items AS
(SELECT "***apple***" as item
UNION ALL
SELECT "***banana***" as item
UNION ALL
SELECT "***orange***" as item)
SELECT
LTRIM(item, "*") as example
FROM items;
+-----------+
| example |
+-----------+
| apple*** |
| banana*** |
| orange*** |
+-----------+
WITH items AS
(SELECT "xxxapplexxx" as item
UNION ALL
SELECT "yyybananayyy" as item
UNION ALL
SELECT "zzzorangezzz" as item
UNION ALL
SELECT "xyzpearxyz" as item)
SELECT
LTRIM(item, "xyz") as example
FROM items;
+-----------+
| example |
+-----------+
| applexxx |
| bananayyy |
| orangezzz |
| pearxyz |
+-----------+
REGEXP_CONTAINS
REGEXP_CONTAINS(value, regex)
Description
Returns TRUE if value
is a partial match for the regular expression,
regex
.
If the regex
argument is invalid, the function returns an error.
You can search for a full match by using ^
(beginning of text) and $
(end of
text). Due to regular expression operator precedence, it is good practice to use
parentheses around everything between ^
and $
.
Return type
BOOL
Examples
SELECT
email,
REGEXP_CONTAINS(email, r"@[a-zA-Z0-9-]+\.[a-zA-Z0-9-.]+") AS is_valid
FROM
(SELECT
["foo@example.com", "bar@example.org", "www.example.net"]
AS addresses),
UNNEST(addresses) AS email;
+-----------------+----------+
| email | is_valid |
+-----------------+----------+
| foo@example.com | true |
| bar@example.org | true |
| www.example.net | false |
+-----------------+----------+
# Performs a full match, using ^ and $. Due to regular expression operator
# precedence, it is good practice to use parentheses around everything between ^
# and $.
SELECT
email,
REGEXP_CONTAINS(email, r"^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$")
AS valid_email_address,
REGEXP_CONTAINS(email, r"^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$")
AS without_parentheses
FROM
(SELECT
["a@foo.com", "a@foo.computer", "b@bar.org", "!b@bar.org", "c@buz.net"]
AS addresses),
UNNEST(addresses) AS email;
+----------------+---------------------+---------------------+
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| a@foo.com | true | true |
| a@foo.computer | false | true |
| b@bar.org | true | true |
| !b@bar.org | false | true |
| c@buz.net | false | false |
+----------------+---------------------+---------------------+
REGEXP_EXTRACT
REGEXP_EXTRACT(value, regex)
Description
Returns the first substring in value
that matches the regular expression,
regex
. Returns NULL
if there is no match.
If the regular expression contains a capturing group, the function returns the substring that is matched by that capturing group. If the expression does not contain a capturing group, the function returns the entire matching substring.
Returns an error if:
- The regular expression is invalid
- The regular expression has more than one capturing group
Return type
STRING or BYTES
Examples
WITH email_addresses AS
(SELECT "foo@example.com" as email
UNION ALL
SELECT "bar@example.org" as email
UNION ALL
SELECT "baz@example.net" as email)
SELECT
REGEXP_EXTRACT(email, r"^[a-zA-Z0-9_.+-]+")
AS user_name
FROM email_addresses;
+-----------+
| user_name |
+-----------+
| foo |
| bar |
| baz |
+-----------+
WITH email_addresses AS
(SELECT "foo@example.com" as email
UNION ALL
SELECT "bar@example.org" as email
UNION ALL
SELECT "baz@example.net" as email)
SELECT
REGEXP_EXTRACT(email, r"^[a-zA-Z0-9_.+-]+@[a-zA-Z0-9-]+\.([a-zA-Z0-9-.]+$)")
AS top_level_domain
FROM email_addresses;
+------------------+
| top_level_domain |
+------------------+
| com |
| org |
| net |
+------------------+
REGEXP_EXTRACT_ALL
REGEXP_EXTRACT_ALL(value, regex)
Description
Returns an array of all substrings of value
that match the regular expression,
regex
.
The REGEXP_EXTRACT_ALL
function only returns non-overlapping matches. For
example, using this function to extract ana
from banana
returns only one
substring, not two.
Return type
An ARRAY of either STRINGs or BYTES
Examples
WITH code_markdown AS
(SELECT "Try `function(x)` or `function(y)`" as code)
SELECT
REGEXP_EXTRACT_ALL(code, "`(.+?)`") AS example
FROM code_markdown;
+----------------------------+
| example |
+----------------------------+
| [function(x), function(y)] |
+----------------------------+
REGEXP_REPLACE
REGEXP_REPLACE(value, regex, replacement)
Description
Returns a STRING where all substrings of value
that
match regular expression regex
are replaced with replacement
.
You can use backslashed-escaped digits (\1 to \9) within the replacement
argument to insert text matching the corresponding parenthesized group in the
regex
pattern. Use \0 to refer to the entire matching text.
The REGEXP_REPLACE
function only replaces non-overlapping matches. For
example, replacing ana
within banana
results in only one replacement, not
two.
If the regex
argument is not a valid regular expression, this function returns
an error.
Return type
STRING or BYTES
Examples
WITH markdown AS
(SELECT "# Heading" as heading
UNION ALL
SELECT "# Another heading" as heading)
SELECT
REGEXP_REPLACE(heading, r"^# ([a-zA-Z0-9\s]+$)", "<h1>\\1</h1>")
AS html
FROM markdown;
+--------------------------+
| html |
+--------------------------+
| <h1>Heading</h1> |
| <h1>Another heading</h1> |
+--------------------------+
REPLACE
REPLACE(original_value, from_value, to_value)
Description
Replaces all occurrences of from_value
with to_value
in original_value
.
If from_value
is empty, no replacement is made.
Return type
STRING or BYTES
Examples
WITH desserts AS
(SELECT "apple pie" as dessert
UNION ALL
SELECT "blackberry pie" as dessert
UNION ALL
SELECT "cherry pie" as dessert)
SELECT
REPLACE (dessert, "pie", "cobbler") as example
FROM desserts;
+--------------------+
| example |
+--------------------+
| apple cobbler |
| blackberry cobbler |
| cherry cobbler |
+--------------------+
REPEAT
REPEAT(original_value, repetitions)
Description
Returns a value that consists of original_value
, repeated.
The repetitions
parameter specifies the number of times to repeat
original_value
. Returns NULL if either original_value
or repetitions
are
NULL.
This function return an error if the repetitions
value is negative.
Return type
STRING or BYTES
Examples
SELECT t, n, REPEAT(t, n) AS REPEAT FROM UNNEST([
STRUCT('abc' AS t, 3 AS n),
('例子', 2),
('abc', null),
(null, 3)
]);
t | n | REPEAT |
---|---|---|
abc | 3 | abcabcabc |
例子 | 2 | 例子例子 |
abc | NULL | NULL |
NULL | 3 | NULL |
REVERSE
REVERSE(value)
Description
Returns the reverse of the input STRING or BYTES.
Return type
STRING or BYTES
Examples
WITH example AS (
SELECT "foo" AS sample_string, b"bar" AS sample_bytes UNION ALL
SELECT "абвгд" AS sample_string, b"123" AS sample_bytes
)
SELECT
sample_string,
REVERSE(sample_string) AS reverse_string,
sample_bytes,
REVERSE(sample_bytes) AS reverse_bytes
FROM example;
+---------------+----------------+--------------+---------------+
| sample_string | reverse_string | sample_bytes | reverse_bytes |
+---------------+----------------+--------------+---------------+
| foo | oof | bar | rab |
| абвгд | дгвба | 123 | 321 |
+---------------+----------------+--------------+---------------+
RPAD
RPAD(original_value, return_length[, pattern])
Description
Returns a value that consists of original_value
appended
with pattern
. The return_length
is an INT64 that specifies the length of the
returned value. If original_value
is BYTES, return_length
is the number of
bytes. If original_value
is STRING, return_length
is the number of
characters.
The default value of pattern
is a blank space.
Both original_value
and pattern
must be the same data type.
If return_length
is less than or equal to the original_value
length, this
function returns the original_value
value, truncated to the value of
return_length
. For example, RPAD("hello world", 7);
returns "hello w"
.
If original_value
, return_length
, or pattern
is NULL, this function
returns NULL.
This function returns an error if:
return_length
is negativepattern
is empty
Return type
STRING or BYTES
Examples
SELECT t, len, FORMAT("%T", RPAD(t, len)) AS RPAD FROM UNNEST([
STRUCT('abc' AS t, 5 AS len),
('abc', 2),
('例子', 4)
]);
t | len | RPAD |
---|---|---|
abc | 5 | "abc " |
abc | 2 | "ab" |
例子 | 4 | "例子 " |
SELECT t, len, pattern, FORMAT("%T", RPAD(t, len, pattern)) AS RPAD FROM UNNEST([
STRUCT('abc' AS t, 8 AS len, 'def' AS pattern),
('abc', 5, '-'),
('例子', 5, '中文')
]);
t | len | pattern | RPAD |
---|---|---|---|
abc | 8 | def | "abcdefde" |
abc | 5 | - | "abc--" |
例子 | 5 | 中文 | "例子中文中" |
SELECT FORMAT("%T", t) AS t, len, FORMAT("%T", RPAD(t, len)) AS RPAD FROM UNNEST([
STRUCT(b'abc' AS t, 5 AS len),
(b'abc', 2),
(b'\xab\xcd\xef', 4)
]);
t | len | RPAD |
---|---|---|
b"abc" | 5 | b"abc " |
b"abc" | 2 | b"ab" |
b"\xab\xcd\xef" | 4 | b"\xab\xcd\xef " |
SELECT
FORMAT("%T", t) AS t,
len,
FORMAT("%T", pattern) AS pattern,
FORMAT("%T", RPAD(t, len, pattern)) AS RPAD
FROM UNNEST([
STRUCT(b'abc' AS t, 8 AS len, b'def' AS pattern),
(b'abc', 5, b'-'),
(b'\xab\xcd\xef', 5, b'\x00')
]);
t | len | pattern | RPAD |
---|---|---|---|
b"abc" | 8 | b"def" | b"abcdefde" |
b"abc" | 5 | b"-" | b"abc--" |
b"\xab\xcd\xef" | 5 | b"\x00" | b"\xab\xcd\xef\x00\x00" |
RTRIM
RTRIM(value1[, value2])
Description
Identical to TRIM, but only removes trailing characters.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT "***apple***" as item
UNION ALL
SELECT "***banana***" as item
UNION ALL
SELECT "***orange***" as item)
SELECT
RTRIM(item, "*") as example
FROM items;
+-----------+
| example |
+-----------+
| ***apple |
| ***banana |
| ***orange |
+-----------+
WITH items AS
(SELECT "applexxx" as item
UNION ALL
SELECT "bananayyy" as item
UNION ALL
SELECT "orangezzz" as item
UNION ALL
SELECT "pearxyz" as item)
SELECT
RTRIM(item, "xyz") as example
FROM items;
+---------+
| example |
+---------+
| apple |
| banana |
| orange |
| pear |
+---------+
SAFE_CONVERT_BYTES_TO_STRING
SAFE_CONVERT_BYTES_TO_STRING(value)
Description
Converts a sequence of bytes to a string. Any invalid UTF-8 characters are
replaced with the Unicode replacement character, U+FFFD
.
Return type
STRING
Examples
The following statement returns the Unicode replacement character, �.
SELECT SAFE_CONVERT_BYTES_TO_STRING(b'\xc2') as safe_convert;
SPLIT
SPLIT(value[, delimiter])
Description
Splits value
using the delimiter
argument.
For STRING, the default delimiter is the comma ,
.
For BYTES, you must specify a delimiter.
Splitting on an empty delimiter produces an array of UTF-8 characters for STRING values, and an array of BYTES for BYTES values.
Splitting an empty STRING returns an ARRAY with a single empty STRING.
Return type
ARRAY of type STRING or ARRAY of type BYTES
Examples
WITH letters AS
(SELECT "a b c d" as letter_group
UNION ALL
SELECT "e f g h" as letter_group
UNION ALL
SELECT "i j k l" as letter_group)
SELECT SPLIT(letter_group, " ") as example
FROM letters;
+----------------------+
| example |
+----------------------+
| [a, b, c, d] |
| [e, f, g, h] |
| [i, j, k, l] |
+----------------------+
STARTS_WITH
STARTS_WITH(value1, value2)
Description
Takes two values. Returns TRUE if the second value is a prefix of the first.
Return type
BOOL
Examples
WITH items AS
(SELECT "foo" as item
UNION ALL
SELECT "bar" as item
UNION ALL
SELECT "baz" as item)
SELECT
STARTS_WITH(item, "b") as example
FROM items;
+---------+
| example |
+---------+
| False |
| True |
| True |
+---------+
STRPOS
STRPOS(string, substring)
Description
Returns the 1-based index of the first occurrence of substring
inside
string
. Returns 0
if substring
is not found.
Return type
INT64
Examples
WITH email_addresses AS
(SELECT
"foo@example.com" AS email_address
UNION ALL
SELECT
"foobar@example.com" AS email_address
UNION ALL
SELECT
"foobarbaz@example.com" AS email_address
UNION ALL
SELECT
"quxexample.com" AS email_address)
SELECT
STRPOS(email_address, "@") AS example
FROM email_addresses;
+---------+
| example |
+---------+
| 4 |
| 7 |
| 10 |
| 0 |
+---------+
SUBSTR
SUBSTR(value, position[, length])
Description
Returns a substring of the supplied value. The position
argument is an integer specifying the starting position of the substring, with
position = 1 indicating the first character or byte. The length
argument is the maximum number of characters for
STRING arguments, or bytes for
BYTES arguments.
If position
is negative, the function counts from the end of value
,
with -1 indicating the last character.
If position
is a position off the left end of the
STRING (position
= 0 or
position
< -LENGTH(value)
), the function starts
from position = 1. If length
exceeds the length of
value
, returns fewer than length
characters.
If length
is less than 0, the function returns an error.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT "apple" as item
UNION ALL
SELECT "banana" as item
UNION ALL
SELECT "orange" as item)
SELECT
SUBSTR(item, 2) as example
FROM items;
+---------+
| example |
+---------+
| pple |
| anana |
| range |
+---------+
WITH items AS
(SELECT "apple" as item
UNION ALL
SELECT "banana" as item
UNION ALL
SELECT "orange" as item)
SELECT
SUBSTR(item, 2, 2) as example
FROM items;
+---------+
| example |
+---------+
| pp |
| an |
| ra |
+---------+
WITH items AS
(SELECT "apple" as item
UNION ALL
SELECT "banana" as item
UNION ALL
SELECT "orange" as item)
SELECT
SUBSTR(item, -2) as example
FROM items;
+---------+
| example |
+---------+
| le |
| na |
| ge |
+---------+
TO_BASE64
TO_BASE64(bytes_expr)
Description
Converts a sequence of BYTES into a base64-encoded STRING. To convert a base64-encoded STRING into BYTES, use FROM_BASE64.
Return type
STRING
Example
SELECT TO_BASE64(b'\xde\xad\xbe\xef') AS base64_string;
+---------------+
| base64_string |
+---------------+
| 3q2+7w== |
+---------------+
TO_CODE_POINTS
TO_CODE_POINTS(value)
Description
Takes a value and returns an array of INT64.
- If
value
is a STRING, each element in the returned array represents a code point. Each code point falls within the range of [0, 0xD7FF] and [0xE000, 0x10FFFF]. - If
value
is BYTES, each element in the array is an extended ASCII character value in the range of [0, 255].
To convert from an array of code points to a STRING or BYTES, see CODE_POINTS_TO_STRING or CODE_POINTS_TO_BYTES.
Return type
ARRAY of INT64
Examples
The following example gets the code points for each element in an array of words.
SELECT word, TO_CODE_POINTS(word) AS code_points
FROM UNNEST(['foo', 'bar', 'baz', 'giraffe', 'llama']) AS word;
+---------+------------------------------------+
| word | code_points |
+---------+------------------------------------+
| foo | [102, 111, 111] |
| bar | [98, 97, 114] |
| baz | [98, 97, 122] |
| giraffe | [103, 105, 114, 97, 102, 102, 101] |
| llama | [108, 108, 97, 109, 97] |
+---------+------------------------------------+
The following example converts integer representations of BYTES to their corresponding ASCII character values.
SELECT word, TO_CODE_POINTS(word) AS bytes_value_as_integer
FROM UNNEST([b'\x00\x01\x10\xff', b'\x66\x6f\x6f']) AS word;
+------------------+------------------------+
| word | bytes_value_as_integer |
+------------------+------------------------+
| \x00\x01\x10\xff | [0, 1, 16, 255] |
| foo | [102, 111, 111] |
+------------------+------------------------+
The following example demonstrates the difference between a BYTES result and a STRING result.
SELECT TO_CODE_POINTS(b'Ā') AS b_result, TO_CODE_POINTS('Ā') AS s_result;
+------------+----------+
| b_result | s_result |
+------------+----------+
| [196, 128] | [256] |
+------------+----------+
Notice that the character, Ā, is represented as a two-byte Unicode sequence. As
a result, the BYTES version of TO_CODE_POINTS
returns an array with two
elements, while the STRING version returns an array with a single element.
TO_HEX
TO_HEX(bytes)
Description
Converts a sequence of BYTES into a hexadecimal
STRING. Converts each byte in
the STRING as two hexadecimal characters in the range
(0..9, a..f)
. To convert a hexadecimal-encoded
STRING
to BYTES, use FROM_HEX.
Return type
STRING
Example
WITH Input AS (
SELECT b'\x00\x01\x02\x03\xAA\xEE\xEF\xFF' AS byte_str UNION ALL
SELECT b'foobar'
)
SELECT byte_str, TO_HEX(byte_str) AS hex_str
FROM Input;
+----------------------------------+------------------+
| byte_string | hex_string |
+----------------------------------+------------------+
| foobar | 666f6f626172 |
| \x00\x01\x02\x03\xaa\xee\xef\xff | 00010203aaeeefff |
+----------------------------------+------------------+
TRIM
TRIM(value1[, value2])
Description
Removes all leading and trailing characters that match value2
. If
value2
is not specified, all leading and trailing whitespace characters (as
defined by the Unicode standard) are removed. If the first argument is of type
BYTES, the second argument is required.
If value2
contains more than one character or byte, the function removes all
leading or trailing characters or bytes contained in value2
.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT " apple " as item
UNION ALL
SELECT " banana " as item
UNION ALL
SELECT " orange " as item)
SELECT
CONCAT("#", TRIM(item), "#") as example
FROM items;
+----------+
| example |
+----------+
| #apple# |
| #banana# |
| #orange# |
+----------+
WITH items AS
(SELECT "***apple***" as item
UNION ALL
SELECT "***banana***" as item
UNION ALL
SELECT "***orange***" as item)
SELECT
TRIM(item, "*") as example
FROM items;
+---------+
| example |
+---------+
| apple |
| banana |
| orange |
+---------+
WITH items AS
(SELECT "xxxapplexxx" as item
UNION ALL
SELECT "yyybananayyy" as item
UNION ALL
SELECT "zzzorangezzz" as item
UNION ALL
SELECT "xyzpearxyz" as item)
SELECT
TRIM(item, "xyz") as example
FROM items;
+---------+
| example |
+---------+
| apple |
| banana |
| orange |
| pear |
+---------+
UPPER
UPPER(value)
Description
For STRING arguments, returns the original string with all alphabetic characters in uppercase. Mapping between uppercase and lowercase is done according to the Unicode Character Database without taking into account language-specific mappings.
For BYTES arguments, the argument is treated as ASCII text, with all bytes greater than 127 left intact.
Return type
STRING or BYTES
Examples
WITH items AS
(SELECT
"foo" as item
UNION ALL
SELECT
"bar" as item
UNION ALL
SELECT
"baz" as item)
SELECT
UPPER(item) AS example
FROM items;
+---------+
| example |
+---------+
| FOO |
| BAR |
| BAZ |
+---------+
JSON functions
Cloud Spanner SQL supports functions that help you retrieve data stored in JSON-formatted strings and functions that help you transform data into JSON-formatted strings.
JSON_QUERY or JSON_VALUE
JSON_QUERY(json_string_expr, json_path_string_literal)
,
which returns JSON values as STRINGs.
JSON_VALUE(json_string_expr, json_path_string_literal)
,
which returns scalar JSON values as STRINGs.
Description
The json_string_expr
parameter must be a JSON-formatted string. For example:
{"class" : {"students" : [{"name" : "Jane"}]}}
The json_path_string_literal
parameter identifies the value or values you want
to obtain from the JSON-formatted string. You construct this parameter using the
JSONPath format. As part of this format, this parameter must start
with a $
symbol, which refers to the outermost level of the JSON-formatted
string. You can identify child values using dot or surrounded by double quotes.
If the JSON object is an array, you can use brackets to specify the array index.
JSONPath | Description |
---|---|
$ | Root object or element |
. | Child operator |
[] | Subscript operator |
Both functions return NULL
if the json_path_string_literal
parameter does
not match a value in json_string_expr
. If the selected value for JSON_VALUE
is not scalar, such as an object or an array, the function returns NULL
.
If the JSONPath is invalid, these functions raise an error.
In cases where a JSON key uses invalid JSONPath characters, you can escape those characters using double quotes. For example:
SELECT JSON_VALUE('{"a.b": {"c": "world"}}', '$."a.b".c') as hello;
+-------+
| hello |
+-------+
| world |
+-------+
Examples
SELECT JSON_QUERY(json_text, '$') AS json_text_string
FROM UNNEST([
'{"class" : {"students" : [{"name" : "Jane"}]}}',
'{"class" : {"students" : []}}',
'{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'
]) AS json_text;
The above query produces the following result:
+-----------------------------------------------------------+
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[{"name":"Jane"}]}} |
| {"class":{"students":[]}} |
| {"class":{"students":[{"name":"John"},{"name":"Jamie"}]}} |
+-----------------------------------------------------------+
SELECT JSON_QUERY(json_text, '$.class.students[0]') AS first_student
FROM UNNEST([
'{"class" : {"students" : [{"name" : "Jane"}]}}',
'{"class" : {"students" : []}}',
'{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'
]) AS json_text;
The above query produces the following result:
+-----------------+
| first_student |
+-----------------+
| {"name":"Jane"} |
| NULL |
| {"name":"John"} |
+-----------------+
SELECT JSON_QUERY(json_text, '$.class.students[1].name') AS second_student_name
FROM UNNEST([
'{"class" : {"students" : [{"name" : "Jane"}]}}',
'{"class" : {"students" : []}}',
'{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'
]) AS json_text;
The above query produces the following result:
+-------------------+
| second_student |
+-------------------+
| NULL |
| NULL |
| {"first":"Jamie"} |
+-------------------+
SELECT JSON_QUERY(json_text, '$.class."students"') AS student_names
FROM UNNEST([
'{"class" : {"students" : [{"name" : "Jane"}]}}',
'{"class" : {"students" : []}}',
'{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'
]) AS json_text;
The above query produces the following result:
+------------------------------------+
| student_names |
+------------------------------------+
| [{"name":"Jane"}] |
| [] |
| [{"name":"John"},{"name":"Jamie"}] |
+------------------------------------+
SELECT JSON_QUERY('{ "name" : "Jakob", "age" : "6" }', '$.name') as json_name,
JSON_VALUE('{ "name" : "Jakob", "age" : "6" }', '$.name') as scalar_name,
JSON_QUERY('{ "name" : "Jakob", "age" : "6" }', '$.age') as json_age,
JSON_VALUE('{ "name" : "Jakob", "age" : "6" }', '$.age') as scalar;
The above query produces the following result:
+-----------+-------------+----------+--------+
| json_name | scalar_name | json_age | scalar |
+-----------+-------------+----------+--------+
| "Jakob" | Jakob | "6" | 6 |
+-----------+-------------+----------+--------+
Array functions
ARRAY
ARRAY(subquery)
Description
The ARRAY
function returns an ARRAY
with one element for each row in a
subquery.
If subquery
produces a
SQL table,
the table must have exactly one column. Each element in the output ARRAY
is
the value of the single column of a row in the table.
Constraints
- Subqueries are unordered, so the elements of the output
ARRAY
are not guaranteed to preserve any order in the source table for the subquery. However, if the subquery includes anORDER BY
clause, theARRAY
function will return anARRAY
that honors that clause. - If the subquery returns more than one column, the
ARRAY
function returns an error. - If the subquery returns an
ARRAY
typed column orARRAY
typed rows, theARRAY
function returns an error: Cloud Spanner SQL does not supportARRAY
s with elements of typeARRAY
. - If the subquery returns zero rows, the
ARRAY
function returns an emptyARRAY
. It never returns aNULL
ARRAY
.
Return type
ARRAY
Examples
SELECT ARRAY
(SELECT 1 UNION ALL
SELECT 2 UNION ALL
SELECT 3) AS new_array;
+-----------+
| new_array |
+-----------+
| [1, 2, 3] |
+-----------+
To construct an ARRAY
from a subquery that contains multiple
columns, change the subquery to use SELECT AS STRUCT
. Now
the ARRAY
function will return an ARRAY
of STRUCT
s. The ARRAY
will
contain one STRUCT
for each row in the subquery, and each of these STRUCT
s
will contain a field for each column in that row.
SELECT
ARRAY
(SELECT AS STRUCT 1, 2, 3
UNION ALL SELECT AS STRUCT 4, 5, 6) AS new_array;
+------------------------+
| new_array |
+------------------------+
| [{1, 2, 3}, {4, 5, 6}] |
+------------------------+
Similarly, to construct an ARRAY
from a subquery that contains
one or more ARRAY
s, change the subquery to use SELECT AS STRUCT
.
SELECT ARRAY
(SELECT AS STRUCT [1, 2, 3] UNION ALL
SELECT AS STRUCT [4, 5, 6]) AS new_array;
+----------------------------+
| new_array |
+----------------------------+
| [{[1, 2, 3]}, {[4, 5, 6]}] |
+----------------------------+
ARRAY_CONCAT
ARRAY_CONCAT(array_expression_1 [, array_expression_n])
Description
Concatenates one or more arrays with the same element type into a single array.
Return type
ARRAY
Examples
SELECT ARRAY_CONCAT([1, 2], [3, 4], [5, 6]) as count_to_six;
+--------------------------------------------------+
| count_to_six |
+--------------------------------------------------+
| [1, 2, 3, 4, 5, 6] |
+--------------------------------------------------+
ARRAY_LENGTH
ARRAY_LENGTH(array_expression)
Description
Returns the size of the array. Returns 0 for an empty array. Returns NULL
if
the array_expression
is NULL
.
Return type
INT64
Examples
WITH items AS
(SELECT ["coffee", NULL, "milk" ] as list
UNION ALL
SELECT ["cake", "pie"] as list)
SELECT list, ARRAY_LENGTH(list) AS size
FROM items
ORDER BY size DESC;
+---------------------------------+------+
| list | size |
+---------------------------------+------+
| [coffee, NULL, milk] | 3 |
| [cake, pie] | 2 |
+---------------------------------+------+
ARRAY_TO_STRING
ARRAY_TO_STRING(array_expression, delimiter[, null_text])
Description
Returns a concatenation of the elements in array_expression
as a STRING. The value for array_expression
can either be an array of STRING or
BYTES data types.
If the null_text
parameter is used, the function replaces any NULL
values in
the array with the value of null_text
.
If the null_text
parameter is not used, the function omits the NULL
value
and its preceding delimiter.
Examples
WITH items AS
(SELECT ["coffee", "tea", "milk" ] as list
UNION ALL
SELECT ["cake", "pie", NULL] as list)
SELECT ARRAY_TO_STRING(list, '--') AS text
FROM items;
+--------------------------------+
| text |
+--------------------------------+
| coffee--tea--milk |
| cake--pie |
+--------------------------------+
WITH items AS
(SELECT ["coffee", "tea", "milk" ] as list
UNION ALL
SELECT ["cake", "pie", NULL] as list)
SELECT ARRAY_TO_STRING(list, '--', 'MISSING') AS text
FROM items;
+--------------------------------+
| text |
+--------------------------------+
| coffee--tea--milk |
| cake--pie--MISSING |
+--------------------------------+
GENERATE_ARRAY
GENERATE_ARRAY(start_expression, end_expression[, step_expression])
Description
Returns an array of values. The start_expression
and end_expression
parameters determine the inclusive start and end of the array.
The GENERATE_ARRAY
function accepts the following data types as inputs:
- INT64
- FLOAT64
The step_expression
parameter determines the increment used to
generate array values. The default value for this parameter is 1
.
This function returns an error if step_expression
is set to 0, or if any
input is NaN
.
If any argument is NULL
, the function will return a NULL
array.
Return Data Type
ARRAY
Examples
The following returns an array of integers, with a default step of 1.
SELECT GENERATE_ARRAY(1, 5) AS example_array;
+-----------------+
| example_array |
+-----------------+
| [1, 2, 3, 4, 5] |
+-----------------+
The following returns an array using a user-specified step size.
SELECT GENERATE_ARRAY(0, 10, 3) AS example_array;
+---------------+
| example_array |
+---------------+
| [0, 3, 6, 9] |
+---------------+
The following returns an array using a negative value, -3
for its step size.
SELECT GENERATE_ARRAY(10, 0, -3) AS example_array;
+---------------+
| example_array |
+---------------+
| [10, 7, 4, 1] |
+---------------+
The following returns an array using the same value for the start_expression
and end_expression
.
SELECT GENERATE_ARRAY(4, 4, 10) AS example_array;
+---------------+
| example_array |
+---------------+
| [4] |
+---------------+
The following returns an empty array, because the start_expression
is greater
than the end_expression
, and the step_expression
value is positive.
SELECT GENERATE_ARRAY(10, 0, 3) AS example_array;
+---------------+
| example_array |
+---------------+
| [] |
+---------------+
The following returns a NULL
array because end_expression
is NULL
.
SELECT GENERATE_ARRAY(5, NULL, 1) AS example_array;
+---------------+
| example_array |
+---------------+
| NULL |
+---------------+
The following returns multiple arrays.
SELECT GENERATE_ARRAY(start, 5) AS example_array
FROM UNNEST([3, 4, 5]) AS start;
+---------------+
| example_array |
+---------------+
| [3, 4, 5] |
| [4, 5] |
| [5] |
+---------------+
GENERATE_DATE_ARRAY
GENERATE_DATE_ARRAY(start_date, end_date[, INTERVAL INT64_expr date_part])
Description
Returns an array of dates. The start_date
and end_date
parameters determine the inclusive start and end of the array.
The GENERATE_DATE_ARRAY
function accepts the following data types as inputs:
start_date
must be a DATEend_date
must be a DATEINT64_expr
must be an INT64date_part
must be either DAY, WEEK, MONTH, QUARTER, or YEAR.
The INT64_expr
parameter determines the increment used to generate dates. The
default value for this parameter is 1 day.
This function returns an error if INT64_expr
is set to 0.
Return Data Type
An ARRAY containing 0 or more DATE values.
Examples
The following returns an array of dates, with a default step of 1.
SELECT GENERATE_DATE_ARRAY('2016-10-05', '2016-10-08') AS example;
+--------------------------------------------------+
| example |
+--------------------------------------------------+
| [2016-10-05, 2016-10-06, 2016-10-07, 2016-10-08] |
+--------------------------------------------------+
The following returns an array using a user-specified step size.
SELECT GENERATE_DATE_ARRAY(
'2016-10-05', '2016-10-09', INTERVAL 2 DAY) AS example;
+--------------------------------------+
| example |
+--------------------------------------+
| [2016-10-05, 2016-10-07, 2016-10-09] |
+--------------------------------------+
The following returns an array using a negative value, -3
for its step size.
SELECT GENERATE_DATE_ARRAY('2016-10-05',
'2016-10-01', INTERVAL -3 DAY) AS example;
+--------------------------+
| example |
+--------------------------+
| [2016-10-05, 2016-10-02] |
+--------------------------+
The following returns an array using the same value for the start_date
and
end_date
.
SELECT GENERATE_DATE_ARRAY('2016-10-05',
'2016-10-05', INTERVAL 8 DAY) AS example;
+--------------+
| example |
+--------------+
| [2016-10-05] |
+--------------+
The following returns an empty array, because the start_date
is greater
than the end_date
, and the step
value is positive.
SELECT GENERATE_DATE_ARRAY('2016-10-05',
'2016-10-01', INTERVAL 1 DAY) AS example;
+---------+
| example |
+---------+
| [] |
+---------+
The following returns a NULL
array, because one of its inputs is
NULL
.
SELECT GENERATE_DATE_ARRAY('2016-10-05', NULL) AS example;
+---------+
| example |
+---------+
| NULL |
+---------+
The following returns an array of dates, using MONTH as the date_part
interval:
SELECT GENERATE_DATE_ARRAY('2016-01-01',
'2016-12-31', INTERVAL 2 MONTH) AS example;
+--------------------------------------------------------------------------+
| example |
+--------------------------------------------------------------------------+
| [2016-01-01, 2016-03-01, 2016-05-01, 2016-07-01, 2016-09-01, 2016-11-01] |
+--------------------------------------------------------------------------+
The following uses non-constant dates to generate an array.
SELECT GENERATE_DATE_ARRAY(date_start, date_end, INTERVAL 1 WEEK) AS date_range
FROM (
SELECT DATE '2016-01-01' AS date_start, DATE '2016-01-31' AS date_end
UNION ALL SELECT DATE "2016-04-01", DATE "2016-04-30"
UNION ALL SELECT DATE "2016-07-01", DATE "2016-07-31"
UNION ALL SELECT DATE "2016-10-01", DATE "2016-10-31"
) AS items;
+--------------------------------------------------------------+
| date_range |
+--------------------------------------------------------------+
| [2016-01-01, 2016-01-08, 2016-01-15, 2016-01-22, 2016-01-29] |
| [2016-04-01, 2016-04-08, 2016-04-15, 2016-04-22, 2016-04-29] |
| [2016-07-01, 2016-07-08, 2016-07-15, 2016-07-22, 2016-07-29] |
| [2016-10-01, 2016-10-08, 2016-10-15, 2016-10-22, 2016-10-29] |
+--------------------------------------------------------------+
OFFSET and ORDINAL
array_expression[OFFSET(zero_based_offset)]
array_expression[ORDINAL(one_based_offset)]
Description
Accesses an ARRAY element by position and returns the
element. OFFSET
means that the numbering starts at zero, ORDINAL
means that
the numbering starts at one.
A given array can be interpreted as either 0-based or 1-based. When accessing an
array element, you must preface the array position with OFFSET
or ORDINAL
,
respectively; there is no default behavior.
Both OFFSET
and ORDINAL
generate an error if the index is out of range.
Return type
Varies depending on the elements in the ARRAY.
Examples
WITH items AS
(SELECT ["apples", "bananas", "pears", "grapes"] as list
UNION ALL
SELECT ["coffee", "tea", "milk" ] as list
UNION ALL
SELECT ["cake", "pie"] as list)
SELECT list, list[OFFSET(1)] as offset_1, list[ORDINAL(1)] as ordinal_1
FROM items;
+----------------------------------+-----------+-----------+
| list | offset_1 | ordinal_1 |
+----------------------------------+-----------+-----------+
| [apples, bananas, pears, grapes] | bananas | apples |
| [coffee, tea, milk] | tea | coffee |
| [cake, pie] | pie | cake |
+----------------------------------+-----------+-----------+
ARRAY_REVERSE
ARRAY_REVERSE(value)
Description
Returns the input ARRAY with elements in reverse order.
Return type
ARRAY
Examples
WITH example AS (
SELECT [1, 2, 3] AS arr UNION ALL
SELECT [4, 5] AS arr UNION ALL
SELECT [] AS arr
)
SELECT
arr,
ARRAY_REVERSE(arr) AS reverse_arr
FROM example;
+-----------+-------------+
| arr | reverse_arr |
+-----------+-------------+
| [1, 2, 3] | [3, 2, 1] |
| [4, 5] | [5, 4] |
| [] | [] |
+-----------+-------------+
SAFE_OFFSET and SAFE_ORDINAL
array_expression[SAFE_OFFSET(zero_based_offset)]
array_expression[SAFE_ORDINAL(one_based_offset)]
Description
Identical to OFFSET
and ORDINAL
, except returns NULL
if the index is out
of range.
Return type
Varies depending on the elements in the ARRAY.
Example
WITH items AS
(SELECT ["apples", "bananas", "pears", "grapes"] as list
UNION ALL
SELECT ["coffee", "tea", "milk" ] as list
UNION ALL
SELECT ["cake", "pie"] as list)
SELECT list,
list[SAFE_OFFSET(3)] as safe_offset_3,
list[SAFE_ORDINAL(3)] as safe_ordinal_3
FROM items;
+----------------------------------+---------------+----------------+
| list | safe_offset_3 | safe_ordinal_3 |
+----------------------------------+---------------+----------------+
| [apples, bananas, pears, grapes] | grapes | pears |
| [coffee, tea, milk] | NULL | milk |
| [cake, pie] | NULL | NULL |
+----------------------------------+---------------+----------------+
Date functions
Cloud Spanner SQL supports the following DATE
functions.
CURRENT_DATE
CURRENT_DATE([time_zone])
Description
Returns the current date as of the specified or default timezone.
This function supports an optional time_zone
parameter. This parameter is a
string representing the timezone to use. If no timezone is specified, the
default timezone, America/Los_Angeles, is used. See
Timezone definitions for information on how to
specify a time zone.
If the time_zone
parameter evaluates to NULL
, this function returns NULL
.
Return Data Type
DATE
Example
SELECT CURRENT_DATE() as the_date;
+--------------+
| the_date |
+--------------+
| 2016-12-25 |
+--------------+
EXTRACT
EXTRACT(part FROM date_expression)
Description
Returns the value corresponding to the specified date part. The part
must
be one of:
DAYOFWEEK
: Returns values in the range [1,7] with Sunday as the first day of the week.DAY
DAYOFYEAR
WEEK
: Returns the week number of the date in the range [0, 53]. Weeks begin with Sunday, and dates prior to the first Sunday of the year are in week 0.ISOWEEK
: Returns the ISO 8601 week number of thedate_expression
.ISOWEEK
s begin on Monday. Return values are in the range [1, 53]. The firstISOWEEK
of each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year.MONTH
QUARTER
: Returns values in the range [1,4].YEAR
ISOYEAR
: Returns the ISO 8601 week-numbering year, which is the Gregorian calendar year containing the Thursday of the week to whichdate_expression
belongs.
Return Data Type
INT64
Examples
In the following example, EXTRACT
returns a value corresponding to the DAY
time part.
SELECT EXTRACT(DAY FROM DATE '2013-12-25') as the_day;
+---------+
| the_day |
+---------+
| 25 |
+---------+
In the following example, EXTRACT
returns values corresponding to different
time parts from a column of dates near the end of the year.
SELECT
date,
EXTRACT(ISOYEAR FROM date) AS isoyear,
EXTRACT(ISOWEEK FROM date) AS isoweek,
EXTRACT(YEAR FROM date) AS year,
EXTRACT(WEEK FROM date) AS week
FROM UNNEST(GENERATE_DATE_ARRAY('2015-12-23', '2016-01-09')) AS date
ORDER BY date;
+------------+---------+---------+------+------+
| date | isoyear | isoweek | year | week |
+------------+---------+---------+------+------+
| 2015-12-23 | 2015 | 52 | 2015 | 51 |
| 2015-12-24 | 2015 | 52 | 2015 | 51 |
| 2015-12-25 | 2015 | 52 | 2015 | 51 |
| 2015-12-26 | 2015 | 52 | 2015 | 51 |
| 2015-12-27 | 2015 | 52 | 2015 | 52 |
| 2015-12-28 | 2015 | 53 | 2015 | 52 |
| 2015-12-29 | 2015 | 53 | 2015 | 52 |
| 2015-12-30 | 2015 | 53 | 2015 | 52 |
| 2015-12-31 | 2015 | 53 | 2015 | 52 |
| 2016-01-01 | 2015 | 53 | 2016 | 0 |
| 2016-01-02 | 2015 | 53 | 2016 | 0 |
| 2016-01-03 | 2015 | 53 | 2016 | 1 |
| 2016-01-04 | 2016 | 1 | 2016 | 1 |
| 2016-01-05 | 2016 | 1 | 2016 | 1 |
| 2016-01-06 | 2016 | 1 | 2016 | 1 |
| 2016-01-07 | 2016 | 1 | 2016 | 1 |
| 2016-01-08 | 2016 | 1 | 2016 | 1 |
| 2016-01-09 | 2016 | 1 | 2016 | 1 |
+------------+---------+---------+------+------+
DATE
1. DATE(year, month, day)
2. DATE(timestamp_expression[, timezone])
Description
- Constructs a DATE from INT64 values representing the year, month, and day.
- Extracts the DATE from a TIMESTAMP expression. It supports an optional parameter to specify a timezone. If no timezone is specified, the default timezone, America/Los_Angeles, is used.
Return Data Type
DATE
Example
SELECT
DATE(2016, 12, 25) as date_ymd,
DATE(TIMESTAMP "2016-12-25 05:30:00+07", "America/Los_Angeles") as date_tstz;
+------------+------------+
| date_ymd | date_tstz |
+------------+------------+
| 2016-12-25 | 2016-12-24 |
+------------+------------+
DATE_ADD
DATE_ADD(date_expression, INTERVAL INT64_expr date_part)
Description
Adds a specified time interval to a DATE.
DATE_ADD
supports the following date_part
values:
DAY
WEEK
. Equivalent to 7DAY
s.MONTH
QUARTER
YEAR
Special handling is required for MONTH, QUARTER, and YEAR parts when the date is at (or near) the last day of the month. If the resulting month has fewer days than the original date's day, then the result day is the last day of the new month.
Return Data Type
DATE
Example
SELECT DATE_ADD(DATE "2008-12-25", INTERVAL 5 DAY) as five_days_later;
+--------------------+
| five_days_later |
+--------------------+
| 2008-12-30 |
+--------------------+
DATE_SUB
DATE_SUB(date_expression, INTERVAL INT64_expr date_part)
Description
Subtracts a specified time interval from a DATE.
DATE_SUB
supports the following date_part
values:
DAY
WEEK
. Equivalent to 7DAY
s.MONTH
QUARTER
YEAR
Special handling is required for MONTH, QUARTER, and YEAR parts when the date is at (or near) the last day of the month. If the resulting month has fewer days than the original date's day, then the result day is the last day of the new month.
Return Data Type
DATE
Example
SELECT DATE_SUB(DATE "2008-12-25", INTERVAL 5 DAY) as five_days_ago;
+---------------+
| five_days_ago |
+---------------+
| 2008-12-20 |
+---------------+
DATE_DIFF
DATE_DIFF(date_expression, date_expression, date_part)
Description
Returns the number of date_part
boundaries between the two date_expression
s.
If the first date occurs before the second date, then the result is
non-positive.
DATE_DIFF
supports the following date_part
values:
DAY
WEEK
This date part begins on Sunday.MONTH
QUARTER
YEAR
Return Data Type
INT64
Example
SELECT DATE_DIFF(DATE '2010-07-07', DATE '2008-12-25', DAY) as days_diff;
+-----------+
| days_diff |
+-----------+
| 559 |
+-----------+
SELECT
DATE_DIFF(DATE '2017-10-15', DATE '2017-10-14', DAY) as days_diff,
DATE_DIFF(DATE '2017-10-15', DATE '2017-10-14', WEEK) as weeks_diff;
+-----------+------------+
| days_diff | weeks_diff |
+-----------+------------+
| 1 | 1 |
+-----------+------------+
The example above shows the result of DATE_DIFF
for two days in succession.
DATE_DIFF
with the date part WEEK
returns 1 because DATE_DIFF
counts the
number of date part boundaries in this range of dates. Each WEEK
begins on
Sunday, so there is one date part boundary between Saturday, 2017-10-14
and Sunday, 2017-10-15.
DATE_TRUNC
DATE_TRUNC(date_expression, date_part)
Description
Truncates the date to the specified granularity.
DATE_TRUNC
supports the following values for date_part
:
DAY
WEEK
MONTH
QUARTER
YEAR
Return Data Type
DATE
Examples
SELECT DATE_TRUNC(DATE '2008-12-25', MONTH) as month;
+------------+
| month |
+------------+
| 2008-12-01 |
+------------+
DATE_FROM_UNIX_DATE
DATE_FROM_UNIX_DATE(INT64_expression)
Description
Interprets INT64_expression
as the number of days since 1970-01-01.
Return Data Type
DATE
Example
SELECT DATE_FROM_UNIX_DATE(14238) as date_from_epoch;
+-----------------+
| date_from_epoch |
+-----------------+
| 2008-12-25 |
+-----------------+
FORMAT_DATE
FORMAT_DATE(format_string, date_expr)
Description
Formats the date_expr
according to the specified format_string
.
See Supported Format Elements For DATE for a list of format elements that this function supports.
Return Data Type
STRING
Example
SELECT FORMAT_DATE("%x", DATE "2008-12-25") as US_format;
+------------+
| US_format |
+------------+
| 12/25/08 |
+------------+
PARSE_DATE
PARSE_DATE(format_string, date_string)
Description
Uses a format_string
and a string representation of a date to return a DATE
object.
When using PARSE_DATE
, keep the following in mind:
- Unspecified fields. Any unspecified field is initialized from
1970-01-01
. - Case insensitive names. Names, such as
Monday
,February
, and so on, are case insensitive. - Whitespace. One or more consecutive white spaces in the format string matches zero or more consecutive white spaces in the date string. In addition, leading and trailing white spaces in the date string are always allowed -- even if they are not in the format string.
- Format precedence. When two (or more) format elements have overlapping
information (for example both
%F
and%Y
affect the year), the last one generally overrides any earlier ones.
See Supported Format Elements For DATE for a list of format elements that this function supports.
Return Data Type
DATE
Example
SELECT PARSE_DATE("%x", "12/25/08") as parsed;
+------------+
| parsed |
+------------+
| 2008-12-25 |
+------------+
UNIX_DATE
UNIX_DATE(date_expression)
Description
Returns the number of days since 1970-01-01.
Return Data Type
INT64
Example
SELECT UNIX_DATE(DATE "2008-12-25") as days_from_epoch;
+-----------------+
| days_from_epoch |
+-----------------+
| 14238 |
+-----------------+
Supported Format Elements for DATE
Unless otherwise noted, DATE functions that use format strings support the following elements:
Format element | Description |
%A | The full weekday name. |
%a | The abbreviated weekday name. |
%B | The full month name. |
%b or %h | The abbreviated month name. |
%C | The century (a year divided by 100 and truncated to an integer) as a decimal number (00-99). |
%D | The date in the format %m/%d/%y. |
%d | The day of the month as a decimal number (01-31). |
%e | The day of month as a decimal number (1-31); single digits are preceded by a space. |
%F | The date in the format %Y-%m-%d. |
%G | The ISO 8601 year with century as a decimal number. Each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year. Note that %G and %Y may produce different results near Gregorian year boundaries, where the Gregorian year and ISO year can diverge. |
%g | The ISO 8601 year without century as a decimal number (00-99). Each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year. Note that %g and %y may produce different results near Gregorian year boundaries, where the Gregorian year and ISO year can diverge. |
%j | The day of the year as a decimal number (001-366). |
%m | The month as a decimal number (01-12). |
%n | A newline character. |
%t | A tab character. |
%U | The week number of the year (Sunday as the first day of the week) as a decimal number (00-53). |
%u | The weekday (Monday as the first day of the week) as a decimal number (1-7). |
%V | The week number of the year (Monday as the first day of the week) as a decimal number (01-53). If the week containing January 1 has four or more days in the new year, then it is week 1; otherwise it is week 53 of the previous year, and the next week is week 1. |
%W | The week number of the year (Monday as the first day of the week) as a decimal number (00-53). |
%w | The weekday (Sunday as the first day of the week) as a decimal number (0-6). |
%x | The date representation in MM/DD/YY format. |
%Y | The year with century as a decimal number. |
%y | The year without century as a decimal number (00-99), with an optional leading zero. Can be mixed with %C. If %C is not specified, years 00-68 are 2000s, while years 69-99 are 1900s. |
%E4Y | Four-character years (0001 ... 9999). Note that %Y produces as many characters as it takes to fully render the year. |
Timestamp functions
Cloud Spanner SQL supports the following TIMESTAMP
functions.
NOTE: These functions return a runtime error if overflow occurs; result values are bounded by the defined date and timestamp min/max values.
CURRENT_TIMESTAMP
CURRENT_TIMESTAMP()
Description
Parentheses are optional. This function handles leap seconds by smearing them
across a window of 20 hours around the inserted leap
second.
CURRENT_TIMESTAMP()
produces a TIMESTAMP value that is continuous,
non-ambiguous, has exactly 60 seconds per minute and does not repeat values over
the leap second.
Supported Input Types
Not applicable
Result Data Type
TIMESTAMP
Example
SELECT CURRENT_TIMESTAMP() as now;
+----------------------------------+
| now |
+----------------------------------+
| 2016-05-16 18:12:47.145482639+00 |
+----------------------------------+
EXTRACT
EXTRACT(part FROM timestamp_expression [AT TIME ZONE tz_spec])
Description
Returns an INT64
value that corresponds to the specified part
from
a supplied timestamp_expression
.
Allowed part
values are:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
DAYOFWEEK
DAY
DAYOFYEAR
WEEK
: Returns the week number of the date in the range [0, 53]. Weeks begin with Sunday, and dates prior to the first Sunday of the year are in week 0.ISOWEEK
: Returns the ISO 8601 week number of thedatetime_expression
.ISOWEEK
s begin on Monday. Return values are in the range [1, 53]. The firstISOWEEK
of each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year.MONTH
QUARTER
YEAR
ISOYEAR
: Returns the ISO 8601 week-numbering year, which is the Gregorian calendar year containing the Thursday of the week to whichdate_expression
belongs.DATE
Returned values truncate lower order time periods. For example, when extracting
seconds, EXTRACT
truncates the millisecond and microsecond values.
See Timezone definitions for information on how to specify a time zone.
Return Data Type
Generally
INT64
. Returns
DATE
if part
is
DATE
.
In the following example, EXTRACT
returns values corresponding to different
time parts from a column of timestamps.
WITH Timestamps AS (
SELECT TIMESTAMP '2005-01-03 12:34:56' AS timestamp UNION ALL
SELECT TIMESTAMP '2007-12-31' UNION ALL
SELECT TIMESTAMP '2009-01-01' UNION ALL
SELECT TIMESTAMP '2009-12-31' UNION ALL
SELECT TIMESTAMP '2017-01-02' UNION ALL
SELECT TIMESTAMP '2017-05-26'
)
SELECT
timestamp,
EXTRACT(ISOYEAR FROM timestamp) AS isoyear,
EXTRACT(ISOWEEK FROM timestamp) AS isoweek,
EXTRACT(YEAR FROM timestamp) AS year,
EXTRACT(WEEK FROM timestamp) AS week
FROM Timestamps
ORDER BY timestamp;
+------------------------+---------+---------+------+------+
| timestamp | isoyear | isoweek | year | week |
+------------------------+---------+---------+------+------+
| 2005-01-03 12:34:56-08 | 2005 | 1 | 2005 | 1 |
| 2007-12-31 00:00:00-08 | 2008 | 1 | 2007 | 52 |
| 2009-01-01 00:00:00-08 | 2009 | 1 | 2009 | 0 |
| 2009-12-31 00:00:00-08 | 2009 | 53 | 2009 | 52 |
| 2017-01-02 00:00:00-08 | 2017 | 1 | 2017 | 1 |
| 2017-05-26 00:00:00-07 | 2017 | 21 | 2017 | 21 |
+------------------------+---------+---------+------+------+
STRING
STRING(timestamp_expression[, timezone])
Description
Converts a timestamp_expression
to a STRING data type. Supports an optional
parameter to specify a time zone. See
Timezone definitions for information
on how to specify a time zone.
Return Data Type
STRING
TIMESTAMP
TIMESTAMP(
string_expression[, timezone] |
date_expression[, timezone] |
)
Description
string_expression[, timezone]
: Converts a STRING expression to a TIMESTAMP data type.string_expression
must include a [timestamp literal][timestamp-literals]. Ifstring_expression
includes a timezone in the timestamp literal, do not include an explicittimezone
argument.date_expression[, timezone]
: Converts a DATE object to a TIMESTAMP data type.
This function supports an optional parameter to specify a time zone. If no time zone is specified, the default time zone, America/Los_Angeles, is used.
Return Data Type
TIMESTAMP
Examples
In these examples, a time zone is specified.
SELECT CAST(
TIMESTAMP("2008-12-25 15:30:00", "America/Los_Angeles") AS STRING
) AS timestamp_str;
+------------------------+
| timestamp_str |
+------------------------+
| 2008-12-25 15:30:00-08 |
+------------------------+
SELECT CAST(
TIMESTAMP("2008-12-25 15:30:00 America/Los_Angeles") AS STRING
) AS timestamp_str_timezone;
+------------------------+
| timestamp_str_timezone |
+------------------------+
| 2008-12-25 15:30:00-08 |
+------------------------+
SELECT CAST(
TIMESTAMP(DATE "2008-12-25", "America/Los_Angeles") AS STRING
) AS timestamp_date;
+------------------------+
| timestamp_date |
+------------------------+
| 2008-12-25 00:00:00-08 |
+------------------------+
In these examples, assume that the default time zone is America/Los_Angeles.
SELECT CAST(
TIMESTAMP("2008-12-25 15:30:00") AS STRING
) AS timestamp_str;
+------------------------+
| timestamp_str |
+------------------------+
| 2008-12-25 15:30:00-08 |
+------------------------+
SELECT CAST(
TIMESTAMP(DATE "2008-12-25") AS STRING
) AS timestamp_date;
+------------------------+
| timestamp_date |
+------------------------+
| 2008-12-25 00:00:00-08 |
+------------------------+
TIMESTAMP_ADD
TIMESTAMP_ADD(timestamp_expression, INTERVAL int64_expression date_part)
Description
Adds int64_expression
units of date_part
to the timestamp, independent of
any time zone.
TIMESTAMP_ADD
supports the following values for date_part
:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
. Equivalent to 60MINUTE
s.DAY
. Equivalent to 24HOUR
s.
Return Data Types
TIMESTAMP
Example
SELECT
TIMESTAMP "2008-12-25 15:30:00 UTC" as original,
TIMESTAMP_ADD(TIMESTAMP "2008-12-25 15:30:00 UTC", INTERVAL 10 MINUTE) AS later;
+------------------------+------------------------+
| original | later |
+------------------------+------------------------+
| 2008-12-25 07:30:00-08 | 2008-12-25 07:40:00-08 |
+------------------------+------------------------+
TIMESTAMP_SUB
TIMESTAMP_SUB(timestamp_expression, INTERVAL int64_expression date_part)
Description
Subtracts int64_expression
units of date_part
from the timestamp,
independent of any time zone.
TIMESTAMP_SUB
supports the following values for date_part
:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
. Equivalent to 60MINUTE
s.DAY
. Equivalent to 24HOUR
s.
Return Data Type
TIMESTAMP
Example
SELECT
TIMESTAMP "2008-12-25 15:30:00 UTC" as original,
TIMESTAMP_SUB(TIMESTAMP "2008-12-25 15:30:00 UTC", INTERVAL 10 MINUTE) AS earlier;
+------------------------+------------------------+
| original | earlier |
+------------------------+------------------------+
| 2008-12-25 07:30:00-08 | 2008-12-25 07:20:00-08 |
+------------------------+------------------------+
TIMESTAMP_DIFF
TIMESTAMP_DIFF(timestamp_expression, timestamp_expression, date_part)
Description
Returns the number of whole specified date_part
intervals
between two timestamps. The first timestamp_expression
represents the later date; if the first
timestamp_expression
is earlier than the second
timestamp_expression
, the output is negative.
Throws an error if the computation overflows the result type, such as
if the difference in nanoseconds between the two timestamps
would overflow an INT64
value.
TIMESTAMP_DIFF
supports the following values for date_part
:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
. Equivalent to 60MINUTE
s.DAY
. Equivalent to 24HOUR
s.
Return Data Type
INT64
Example
SELECT
TIMESTAMP "2010-07-07 10:20:00 UTC" as later_timestamp,
TIMESTAMP "2008-12-25 15:30:00 UTC" as earlier_timestamp,
TIMESTAMP_DIFF(TIMESTAMP "2010-07-07 10:20:00 UTC",
TIMESTAMP "2008-12-25 15:30:00 UTC", HOUR) AS hours;
+------------------------+------------------------+-------+
| later_timestamp | earlier_timestamp | hours |
+------------------------+------------------------+-------+
| 2010-07-07 03:20:00-07 | 2008-12-25 07:30:00-08 | 13410 |
+------------------------+------------------------+-------+
In the following example, the first timestamp occurs before the second timestamp, resulting in a negative output.
SELECT TIMESTAMP_DIFF(TIMESTAMP "2018-08-14", TIMESTAMP "2018-10-14", DAY);
+---------------+
| negative_diff |
+---------------+
| -61 |
+---------------+
TIMESTAMP_TRUNC
TIMESTAMP_TRUNC(timestamp_expression, date_part[, time_zone])
Description
Truncates a timestamp to the granularity of date_part
.
TIMESTAMP_TRUNC
supports the following values for date_part
:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
DAY
WEEK
MONTH
QUARTER
YEAR
TIMESTAMP_TRUNC
function supports an optional time_zone
parameter. This
parameter applies to the following date_parts
:
MINUTE
HOUR
DAY
WEEK
MONTH
QUARTER
YEAR
Use this parameter if you want to use a time zone other than the default time zone, America/Los_Angeles, as part of the truncate operation.
When truncating a TIMESTAMP
to MINUTE
orHOUR
, TIMESTAMP_TRUNC
determines the civil time of the
TIMESTAMP
in the specified (or default) time zone
and subtracts the minutes and seconds (when truncating to HOUR) or the seconds
(when truncating to MINUTE) from that TIMESTAMP
.
While this provides intuitive results in most cases, the result is
non-intuitive near daylight savings transitions that are not hour aligned.
Return Data Type
TIMESTAMP
Examples
SELECT
TIMESTAMP_TRUNC(TIMESTAMP '2008-12-25 15:30:00', DAY, 'UTC') as utc,
TIMESTAMP_TRUNC(TIMESTAMP '2008-12-25 15:30:00', DAY, 'America/Los_Angeles') as la;
+------------------------+------------------------+
| utc | la |
+------------------------+------------------------+
| 2008-12-24 16:00:00-08 | 2008-12-25 00:00:00-08 |
+------------------------+------------------------+
FORMAT_TIMESTAMP
FORMAT_TIMESTAMP(format_string, timestamp[, time_zone])
Description
Formats a timestamp according to the specified format_string
.
See Supported Format Elements For TIMESTAMP for a list of format elements that this function supports.
Return Data Type
STRING
Example
SELECT FORMAT_TIMESTAMP("%c", TIMESTAMP "2008-12-25 15:30:00", "America/Los_Angeles")
AS formatted;
+--------------------------+
| formatted |
+--------------------------+
| Thu Dec 25 15:30:00 2008 |
+--------------------------+
SELECT FORMAT_TIMESTAMP("%b-%d-%Y", TIMESTAMP "2008-12-25 15:30:00")
AS formatted;
+-------------+
| formatted |
+-------------+
| Dec-25-2008 |
+-------------+
SELECT FORMAT_TIMESTAMP("%b %Y", TIMESTAMP "2008-12-25 15:30:00")
AS formatted;
+-------------+
| formatted |
+-------------+
| Dec 2008 |
+-------------+
PARSE_TIMESTAMP
PARSE_TIMESTAMP(format_string, string[, time_zone])
Description
Uses a format_string
and a string representation of a timestamp to return a
TIMESTAMP object.
When using PARSE_TIMESTAMP
, keep the following in mind:
- Unspecified fields. Any unspecified field is initialized from
1970-01-01 00:00:00.0
. This initialization value uses the time zone specified by the function's time zone argument, if present. If not, the initialization value uses the default time zone, America/Los_Angeles. For instance, if the year is unspecified then it defaults to1970
, and so on. - Case insensitive names. Names, such as
Monday
,February
, and so on, are case insensitive. - Whitespace. One or more consecutive white spaces in the format string matches zero or more consecutive white spaces in the timestamp string. In addition, leading and trailing white spaces in the timestamp string are always allowed -- even if they are not in the format string.
- Format precedence. When two (or more) format elements have overlapping
information (for example both
%F
and%Y
affect the year), the last one generally overrides any earlier ones, with some exceptions (see the descriptions of%s
,%C
, and%y
).
See Supported Format Elements For TIMESTAMP for a list of format elements that this function supports.
Return Data Type
TIMESTAMP
Example
SELECT PARSE_TIMESTAMP("%c", "Thu Dec 25 07:30:00 2008", "America/Los_Angeles") as parsed;
+------------------------+
| parsed |
+------------------------+
| 2008-12-25 07:30:00-08 |
+------------------------+
TIMESTAMP_SECONDS
TIMESTAMP_SECONDS(int64_expression)
Description
Interprets int64_expression
as the number of seconds since 1970-01-01 00:00:00
UTC.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_SECONDS(1230219000) as timestamp;
+------------------------+
| timestamp |
+------------------------+
| 2008-12-25 07:30:00-08 |
+------------------------+
TIMESTAMP_MILLIS
TIMESTAMP_MILLIS(int64_expression)
Description
Interprets int64_expression
as the number of milliseconds since 1970-01-01
00:00:00 UTC.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_MILLIS(1230219000000) as timestamp;
+------------------------+
| timestamp |
+------------------------+
| 2008-12-25 07:30:00-08 |
+------------------------+
TIMESTAMP_MICROS
TIMESTAMP_MICROS(int64_expression)
Description
Interprets int64_expression
as the number of microseconds since 1970-01-01
00:00:00 UTC.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_MICROS(1230219000000000) as timestamp;
+------------------------+
| timestamp |
+------------------------+
| 2008-12-25 07:30:00-08 |
+------------------------+
UNIX_SECONDS
UNIX_SECONDS(timestamp_expression)
Description
Returns the number of seconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision.
Return Data Type
INT64
Example
SELECT UNIX_SECONDS(TIMESTAMP "2008-12-25 15:30:00 UTC") as seconds;
+------------+
| seconds |
+------------+
| 1230219000 |
+------------+
UNIX_MILLIS
UNIX_MILLIS(timestamp_expression)
Description
Returns the number of milliseconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision.
Return Data Type
INT64
Example
SELECT UNIX_MILLIS(TIMESTAMP "2008-12-25 15:30:00 UTC") as millis;
+---------------+
| millis |
+---------------+
| 1230219000000 |
+---------------+
UNIX_MICROS
UNIX_MICROS(timestamp_expression)
Description
Returns the number of microseconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision.
Return Data Type
INT64
Example
SELECT UNIX_MICROS(TIMESTAMP "2008-12-25 15:30:00 UTC") as micros;
+------------------+
| micros |
+------------------+
| 1230219000000000 |
+------------------+
Supported format elements for TIMESTAMP
Unless otherwise noted, TIMESTAMP functions that use format strings support the following elements:
Format element | Description |
%A | The full weekday name. |
%a | The abbreviated weekday name. |
%B | The full month name. |
%b or %h | The abbreviated month name. |
%C | The century (a year divided by 100 and truncated to an integer) as a decimal number (00-99). |
%c | The date and time representation in the format %a %b %e %T %Y. |
%D | The date in the format %m/%d/%y. |
%d | The day of the month as a decimal number (01-31). |
%e | The day of month as a decimal number (1-31); single digits are preceded by a space. |
%F | The date in the format %Y-%m-%d. |
%G | The ISO 8601 year with century as a decimal number. Each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year. Note that %G and %Y may produce different results near Gregorian year boundaries, where the Gregorian year and ISO year can diverge. |
%g | The ISO 8601 year without century as a decimal number (00-99). Each ISO year begins on the Monday before the first Thursday of the Gregorian calendar year. Note that %g and %y may produce different results near Gregorian year boundaries, where the Gregorian year and ISO year can diverge. |
%H | The hour (24-hour clock) as a decimal number (00-23). |
%I | The hour (12-hour clock) as a decimal number (01-12). |
%j | The day of the year as a decimal number (001-366). |
%k | The hour (24-hour clock) as a decimal number (0-23); single digits are preceded by a space. |
%l | The hour (12-hour clock) as a decimal number (1-12); single digits are preceded by a space. |
%M | The minute as a decimal number (00-59). |
%m | The month as a decimal number (01-12). |
%n | A newline character. |
%P | Either am or pm. |
%p | Either AM or PM. |
%R | The time in the format %H:%M. |
%r | The 12-hour clock time using AM/PM notation. |
%S | The second as a decimal number (00-60). |
%s | The number of seconds since 1970-01-01 00:00:00 UTC. Always overrides all other format elements, independent of where %s appears in the string. If multiple %s elements appear, then the last one takes precedence. |
%T | The time in the format %H:%M:%S. |
%t | A tab character. |
%U | The week number of the year (Sunday as the first day of the week) as a decimal number (00-53). |
%u | The weekday (Monday as the first day of the week) as a decimal number (1-7). |
%V | The week number of the year (Monday as the first day of the week) as a decimal number (01-53). If the week containing January 1 has four or more days in the new year, then it is week 1; otherwise it is week 53 of the previous year, and the next week is week 1. |
%W | The week number of the year (Monday as the first day of the week) as a decimal number (00-53). |
%w | The weekday (Sunday as the first day of the week) as a decimal number (0-6). |
%X | The time representation in HH:MM:SS format. |
%x | The date representation in MM/DD/YY format. |
%Y | The year with century as a decimal number. |
%y | The year without century as a decimal number (00-99), with an optional leading zero. Can be mixed with %C. If %C is not specified, years 00-68 are 2000s, while years 69-99 are 1900s. |
%Z | The time zone name. |
%z | The offset from the Prime Meridian in the format +HHMM or -HHMM as appropriate, with positive values representing locations east of Greenwich. |
%% | A single % character. |
%Ez | RFC 3339-compatible numeric time zone (+HH:MM or -HH:MM). |
%E#S | Seconds with # digits of fractional precision. |
%E*S | Seconds with full fractional precision (a literal '*'). |
%E4Y | Four-character years (0001 ... 9999). Note that %Y produces as many characters as it takes to fully render the year. |
Timezone definitions
Certain date and timestamp functions allow you to override the default time zone
and specify a different one. You can specify a time zone by either supplying
the time zone name (for example, America/Los_Angeles
)
or time zone offset from UTC (for example, -08).
If you choose to use a time zone offset, use this format:
(+|-)H[H][:M[M]]
The following timestamps are equivalent because the time zone offset
for America/Los_Angeles
is -08
for the specified date and time.
SELECT UNIX_MILLIS(TIMESTAMP "2008-12-25 15:30:00 America/Los_Angeles") as millis;
SELECT UNIX_MILLIS(TIMESTAMP "2008-12-25 15:30:00-08:00") as millis;
Operators
Operators are represented by special characters or keywords; they do not use function call syntax. An operator manipulates any number of data inputs, also called operands, and returns a result.
Common conventions:
- Unless otherwise specified, all operators return
NULL
when one of the operands isNULL
. - All operators will throw an error if the computation result overflows.
- For all floating point operations,
+/-inf
andNaN
may only be returned if one of the operands is+/-inf
orNaN
. In other cases, an error is returned.
The following table lists all Cloud Spanner SQL operators from highest to lowest precedence, i.e. the order in which they will be evaluated within a statement.
Order of Precedence | Operator | Input Data Types | Name | Operator Arity |
---|---|---|---|---|
1 | . | STRUCT |
Member field access operator | Binary |
[ ] | ARRAY | Array position. Must be used with OFFSET or ORDINAL—see ARRAY Functions. | Binary | |
2 | - | All numeric types | Unary minus | Unary |
~ | Integer or BYTES | Bitwise not | Unary | |
3 | * | All numeric types | Multiplication | Binary |
/ | All numeric types | Division | Binary | |
4 | + | All numeric types | Addition | Binary |
- | All numeric types | Subtraction | Binary | |
5 | << | Integer or BYTES | Bitwise left-shift | Binary |
>> | Integer or BYTES | Bitwise right-shift | Binary | |
6 | & | Integer or BYTES | Bitwise and | Binary |
7 | ^ | Integer or BYTES | Bitwise xor | Binary |
8 | | | Integer or BYTES | Bitwise or | Binary |
9 (Comparison Operators) | = | Any comparable type. See Data Types for a complete list. | Equal | Binary |
< | Any comparable type. See Data Types for a complete list. | Less than | Binary | |
> | Any comparable type. See Data Types for a complete list. | Greater than | Binary | |
<= | Any comparable type. See Data Types for a complete list. | Less than or equal to | Binary | |
>= | Any comparable type. See Data Types for a complete list. | Greater than or equal to | Binary | |
!=, <> | Any comparable type. See Data Types for a complete list. | Not equal | Binary | |
[NOT] LIKE | STRING and byte | Value does [not] match the pattern specified | Binary | |
[NOT] BETWEEN | Any comparable types. See Data Types for list. | Value is [not] within the range specified | Binary | |
[NOT] IN | Any comparable types. See Data Types for list. | Value is [not] in the set of values specified | Binary | |
IS [NOT] NULL |
All | Value is [not] NULL |
Unary | |
IS [NOT] TRUE | BOOL | Value is [not] TRUE. | Unary | |
IS [NOT] FALSE | BOOL | Value is [not] FALSE. | Unary | |
10 | NOT | BOOL | Logical NOT | Unary |
11 | AND | BOOL | Logical AND | Binary |
12 | OR | BOOL | Logical OR | Binary |
Operators with the same precedence are left associative. This means that those operators are grouped together starting from the left and moving right. For example, the expression:
x AND y AND z
is interpreted as
( ( x AND y ) AND z )
The expression:
x * y / z
is interpreted as:
( ( x * y ) / z )
All comparison operators have the same priority, but comparison operators are not associative. Therefore, parentheses are required in order to resolve ambiguity. For example:
(x < y) IS FALSE
Element access operators
Operator | Syntax | Input Data Types | Result Data Type | Description |
---|---|---|---|---|
. | expression.fieldname1... | STRUCT |
Type T stored in fieldname1 | Dot operator. Can be used to access nested fields, e.g.expression.fieldname1.fieldname2... |
[ ] | array_expression [position_keyword (int_expression ) ] | See ARRAY Functions. | Type T stored in ARRAY | position_keyword is either OFFSET or ORDINAL. See ARRAY Functions for the two functions that use this operator. |
Arithmetic operators
All arithmetic operators accept input of numeric type T, and the result type has type T unless otherwise indicated in the description below:
Name | Syntax |
---|---|
Addition | X + Y |
Subtraction | X - Y |
Multiplication | X * Y |
Division | X / Y |
Unary Minus | - X |
NOTE: Divide by zero operations return an error. To return a different result, consider the IEEE_DIVIDE or SAFE_DIVIDE functions.
Result types for Addition and Multiplication:
INT64 | FLOAT64 | |
---|---|---|
INT64 | INT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Subtraction:
INT64 | FLOAT64 | |
---|---|---|
INT64 | INT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Division:
INT64 | FLOAT64 | |
---|---|---|
INT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Unary Minus:
Input Data Type | Result Data Type |
---|---|
INT64 | INT64 |
FLOAT64 | FLOAT64 |
Bitwise operators
All bitwise operators return the same type and the same length as the first operand.
Name | Syntax | Input Data Type | Description |
---|---|---|---|
Bitwise not | ~ X | Integer or BYTES | Performs logical negation on each bit, forming the ones' complement of the given binary value. |
Bitwise or | X | Y | X: Integer or BYTES
Y: Same type as X |
Takes two bit patterns of equal length and performs the logical inclusive OR operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths. |
Bitwise xor | X ^ Y | X: Integer or BYTES
Y: Same type as X |
Takes two bit patterns of equal length and performs the logical exclusive OR operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths. |
Bitwise and | X & Y | X: Integer or BYTES
Y: Same type as X |
Takes two bit patterns of equal length and performs the logical AND operation on each pair of the corresponding bits. This operator throws an error if X and Y are BYTES of different lengths. |
Left shift | X << Y | X: Integer or BYTES
Y: INT64 |
Shifts the first operand X to the left. This operator returns 0 or a byte sequence of b'\x00' if the second operand Y is greater than or equal to the bit length of the first operand X (for example, 64 if X has the type INT64). This operator throws an error if Y is negative. |
Right shift | X >> Y | X: Integer or BYTES
Y: INT64 |
Shifts the first operand X to the right. This operator does not do sign bit extension with a signed type (i.e. it fills vacant bits on the left with 0). This operator returns 0 or a byte sequence of b'\x00' if the second operand Y is greater than or equal to the bit length of the first operand X (for example, 64 if X has the type INT64). This operator throws an error if Y is negative. |
Logical operators
All logical operators allow only BOOL input.
Name | Syntax | Description |
---|---|---|
Logical NOT | NOT X | Returns FALSE if input is TRUE. Returns TRUE if input is FALSE. Returns NULL
otherwise. |
Logical AND | X AND Y | Returns FALSE if at least one input is FALSE. Returns TRUE if both X and Y
are TRUE. Returns NULL otherwise. |
Logical OR | X OR Y | Returns FALSE if both X and Y are FALSE. Returns TRUE if at least one input
is TRUE. Returns NULL otherwise. |
Comparison operators
Comparisons always return BOOL. Comparisons generally require both operands to be of the same type. If operands are of different types, and if Cloud Spanner SQL can convert the values of those types to a common type without loss of precision, Cloud Spanner SQL will generally coerce them to that common type for the comparison; Cloud Spanner SQL will generally coerce literals to the type of non-literals, where present. Comparable data types are defined in Data Types.
STRUCTs support only 4 comparison operators: equal (=), not equal (!= and <>), and IN.
The following rules apply when comparing these data types:
- FLOAT64
: All comparisons with NaN return FALSE,
except for
!=
and<>
, which return TRUE. - BOOL: FALSE is less than TRUE.
- STRING: Strings are compared codepoint-by-codepoint, which means that canonically equivalent strings are only guaranteed to compare as equal if they have been normalized first.
NULL
: The convention holds here: any operation with aNULL
input returnsNULL
.
Name | Syntax | Description |
---|---|---|
Less Than | X < Y | Returns TRUE if X is less than Y. |
Less Than or Equal To | X <= Y | Returns TRUE if X is less than or equal to Y. |
Greater Than | X > Y | Returns TRUE if X is greater than Y. |
Greater Than or Equal To | X >= Y | Returns TRUE if X is greater than or equal to Y. |
Equal | X = Y | Returns TRUE if X is equal to Y. |
Not Equal | X != Y X <> Y |
Returns TRUE if X is not equal to Y. |
BETWEEN | X [NOT] BETWEEN Y AND Z | Returns TRUE if X is [not] within the range specified. The result of "X BETWEEN Y AND Z" is equivalent to "Y <= X AND X <= Z" but X is evaluated only once in the former. |
LIKE | X [NOT] LIKE Y | Checks if the STRING in the first operand X
matches a pattern specified by the second operand Y. Expressions can contain
these characters:
|
IN | Multiple - see below | Returns FALSE if the right operand is empty. Returns NULL if the left
operand is NULL . Returns TRUE or NULL , never FALSE, if the right operand
contains NULL . Arguments on either side of IN are general expressions. Neither
operand is required to be a literal, although using a literal on the right is
most common. X is evaluated only once. |
When testing values that have a STRUCT data type for
equality, it's possible that one or more fields are NULL
. In such cases:
- If all non-NULL field values are equal, the comparison returns NULL.
- If any non-NULL field values are not equal, the comparison returns false.
The following table demonstrates how STRUCT data
types are compared when they have fields that are NULL
valued.
Struct1 | Struct2 | Struct1 = Struct2 |
---|---|---|
STRUCT(1, NULL) |
STRUCT(1, NULL) |
NULL |
STRUCT(1, NULL) |
STRUCT(2, NULL) |
FALSE |
STRUCT(1,2) |
STRUCT(1, NULL)
| NULL |
IN operators
The IN
operator supports the following syntaxes:
x [NOT] IN (y, z, ... ) # Requires at least one element
x [NOT] IN (<subquery>)
x [NOT] IN UNNEST(<array expression>) # analysis error if the expression
# does not return an ARRAY type.
Arguments on either side of the IN
operator are general expressions.
It is common to use literals on the right side expression; however, this is not
required.
The semantics of:
x IN (y, z, ...)
are defined as equivalent to:
(x = y) OR (x = z) OR ...
and the subquery and array forms are defined similarly.
x NOT IN ...
is equivalent to:
NOT(x IN ...)
The UNNEST form treats an array scan like UNNEST
in the
FROM clause:
x [NOT] IN UNNEST(<array expression>)
This form is often used with ARRAY parameters. For example:
x IN UNNEST(@array_parameter)
Note: A NULL
ARRAY will be treated equivalently to an empty ARRAY.
See the Arrays topic for more information on how to use this syntax.
When using the IN
operator, the following semantics apply:
IN
with an empty right side expression is always FALSEIN
with aNULL
left side expression and a non-empty right side expression is alwaysNULL
IN
with aNULL
in theIN
-list can only return TRUE orNULL
, never FALSENULL IN (NULL)
returnsNULL
IN UNNEST(<NULL array>)
returns FALSE (notNULL
)NOT IN
with aNULL
in theIN
-list can only return FALSE orNULL
, never TRUE
IN
can be used with multi-part keys by using the struct constructor syntax.
For example:
(Key1, Key2) IN ( (12,34), (56,78) )
(Key1, Key2) IN ( SELECT (table.a, table.b) FROM table )
See the Struct Type section of the Data Types topic for more information on this syntax.
IS operators
IS operators return TRUE or FALSE for the condition they are testing. They never
return NULL
, even for NULL
inputs, unlike the IS_INF and IS_NAN functions
defined in Mathematical Functions. If NOT is present,
the output BOOL value is inverted.
Function Syntax | Input Data Type | Result Data Type | Description |
---|---|---|---|
X IS [NOT] NULL |
Any value type | BOOL | Returns TRUE if the operand X evaluates to NULL , and returns FALSE
otherwise. |
X IS [NOT] TRUE |
BOOL | BOOL | Returns TRUE if the BOOL operand evaluates to TRUE. Returns FALSE otherwise. |
X IS [NOT] FALSE |
BOOL | BOOL | Returns TRUE if the BOOL operand evaluates to FALSE. Returns FALSE otherwise. |
Conditional expressions
Conditional expressions impose constraints on the evaluation order of their inputs. In essence, they are evaluated left to right, with short-circuiting, and only evaluate the output value that was chosen. In contrast, all inputs to regular functions are evaluated before calling the function. Short-circuiting in conditional expressions can be exploited for error handling or performance tuning.
Expression subqueries
There are four types of expression subqueries, i.e. subqueries that are used as
expressions. Expression subqueries return NULL
or a single value, as opposed to
a column or table, and must be surrounded by parentheses. For a fuller
discussion of subqueries, see
Subqueries.
Type of Subquery | Result Data Type | Description |
---|---|---|
Scalar | Any type T | A subquery in parentheses inside an expression (e.g. in the
SELECT list or WHERE clause) is interpreted as a
scalar subquery. The SELECT list in a scalar subquery must have
exactly one field. If the subquery returns exactly one row, that single value is
the scalar subquery result. If the subquery returns zero rows, the scalar
subquery value is NULL . If the subquery returns more than one row, the query
fails with a runtime error. When the subquery is written with SELECT AS
STRUCT , it can include multiple
columns, and the returned value is the constructed STRUCT. Selecting
multiple columns without using SELECT AS is an error. |
ARRAY | ARRAY | Can use SELECT AS STRUCT to
build arrays of structs, and conversely, selecting multiple columns
without using SELECT AS is an error. Returns an empty ARRAY if the
subquery returns zero rows. Never returns a NULL ARRAY. |
IN | BOOL | Occurs in an expression following the IN operator. The subquery must produce
a single column whose type is equality-compatible with the expression on the
left side of the IN operator. Returns FALSE if the subquery returns zero rows.
x IN () is equivalent to x IN (value, value, ...)
See the IN operator in
Comparison Operators
for full semantics. |
EXISTS | BOOL | Returns TRUE if the subquery produced one or more rows. Returns FALSE if the
subquery produces zero rows. Never returns NULL . Unlike all other expression
subqueries, there are no rules about the column list. Any number of columns may
be selected and it will not affect the query result. |
Examples
The following examples of expression subqueries assume that t.int_array
has
type ARRAY<INT64>
.
Type | Subquery | Result Data Type | Notes |
---|---|---|---|
Scalar | (SELECT COUNT(*) FROM t.int_array) |
INT64 | |
(SELECT DISTINCT i FROM t.int_array i) |
INT64, possibly runtime error | ||
(SELECT i FROM t.int_array i WHERE i=5) |
INT64, possibly runtime error | ||
(SELECT ARRAY_AGG(i) FROM t.int_array i) |
ARRAY | Uses the ARRAY_AGG aggregation function to return an ARRAY. | |
(SELECT 'xxx' a) |
STRING | ||
(SELECT 'xxx' a, 123 b) |
Error | Returns an error because there is more than one column | |
(SELECT AS STRUCT 'xxx' a, 123 b) |
STRUCT | ||
(SELECT AS STRUCT 'xxx' a) |
STRUCT | ||
ARRAY | ARRAY(SELECT COUNT(*) FROM t.int_array) |
ARRAY of size 1 | |
ARRAY(SELECT x FROM t) |
ARRAY | ||
ARRAY(SELECT 5 a, COUNT(*) b FROM t.int_array) |
Error | Returns an error because there is more than one column | |
ARRAY(SELECT AS STRUCT 5 a, COUNT(*) b FROM t.int_array) |
ARRAY | ||
ARRAY(SELECT AS STRUCT i FROM t.int_array i) |
ARRAY | Makes an ARRAY of one-field STRUCTs | |
ARRAY(SELECT AS STRUCT 1 x, 2, 3 x) |
ARRAY | Returns an ARRAY of STRUCTs with anonymous or duplicate fields. | |
ARRAY(SELECT AS TypeName SUM(x) a, SUM(y) b, SUM(z) c from t) |
array<TypeName> | Selecting into a named type. Assume TypeName is a STRUCT type with fields a,b,c. | |
STRUCT | (SELECT AS STRUCT 1 x, 2, 3 x) |
STRUCT | Constructs a STRUCT with anonymous or duplicate fields. |
EXISTS | EXISTS(SELECT x,y,z FROM table WHERE y=z) |
BOOL | |
NOT EXISTS(SELECT x,y,z FROM table WHERE y=z) |
BOOL | ||
IN | x IN (SELECT y FROM table WHERE z) |
BOOL | |
x NOT IN (SELECT y FROM table WHERE z) |
BOOL |
Debugging functions
Cloud Spanner SQL supports the following debugging functions.
ERROR
ERROR(error_message)
Description
Returns an error. The error_message
argument is a STRING
.
Cloud Spanner SQL treats ERROR
in the same way as any expression that may
result in an error: there is no special guarantee of evaluation order.
Return Data Type
Cloud Spanner SQL infers the return type in context.
Examples
In the following example, the query returns an error message if the value of the row does not match one of two defined values.
SELECT
CASE
WHEN value = 'foo' THEN 'Value is foo.'
WHEN value = 'bar' THEN 'Value is bar.'
ELSE ERROR(concat('Found unexpected value: ', value))
END AS new_value
FROM (
SELECT 'foo' AS value UNION ALL
SELECT 'bar' AS value UNION ALL
SELECT 'baz' AS value);
Found unexpected value: baz
In the following example, Cloud Spanner SQL may evaluate the ERROR
function
before or after the x > 0
WHERE
clause conditions and
there are no special guarantees for the ERROR
function.
SELECT *
FROM (SELECT -1 AS x)
WHERE x > 0 AND ERROR('Example error');
In the next example, the WHERE
clause evaluates an IF
condition, which
ensures that Cloud Spanner SQL only evaluates the ERROR
function if the
condition fails.
SELECT *
FROM (SELECT -1 AS x)
WHERE IF(x > 0, true, ERROR(FORMAT('Error: x must be positive but is %t', x)));'
Error: x must be positive but is -1