This topic is a compilation of functions, operators, and conditional expressions.
To learn more about how to call functions, function call rules,
the SAFE
prefix, and special types of arguments,
see Function calls.
OPERATORS AND CONDITIONALS
Operators in GoogleSQL
GoogleSQL for Spanner supports 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.
When Spanner runs an operator, the operator is treated as a function. Because of this, if an operator produces an error, the error message might use the term function when referencing an operator.
Operator precedence
The following table lists all GoogleSQL 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 | Field access operator |
STRUCT PROTO JSON |
Field access operator | Binary |
Array subscript operator | ARRAY |
Array position. Must be used with OFFSET or ORDINAL —see
Array Functions
. |
Binary | |
JSON subscript operator | JSON |
Field name or array position in JSON. | Binary | |
2 | + |
All numeric types | Unary plus | Unary |
- |
All numeric types | Unary minus | Unary | |
~ |
Integer or BYTES |
Bitwise not | Unary | |
3 | * |
All numeric types | Multiplication | Binary |
/ |
All numeric types | Division | Binary | |
|| |
STRING , BYTES , or ARRAY<T> |
Concatenation operator | 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 BYTES |
Value does [not] match the pattern specified | Binary | |
[NOT] BETWEEN |
Any comparable types. See Data Types for a complete list. | Value is [not] within the range specified | Binary | |
[NOT] IN |
Any comparable types. See Data Types for a complete 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 |
For example, the logical expression:
x OR y AND z
is interpreted as:
( x OR ( y AND z ) )
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 to resolve ambiguity. For example:
(x < y) IS FALSE
Operator list
Name | Summary |
---|---|
Field access operator | Gets the value of a field. |
Array subscript operator | Gets a value from an array at a specific position. |
JSON subscript operator | Gets a value of an array element or field in a JSON expression. |
Arithmetic operators | Performs arithmetic operations. |
Bitwise operators | Performs bit manipulation. |
Logical operators |
Tests for the truth of some condition and produces TRUE ,
FALSE , or NULL .
|
Graph logical operators |
Tests for the truth of a condition in a graph and produces either
TRUE or FALSE .
|
Graph predicates |
Tests for the truth of a condition for a graph element and produces
TRUE , FALSE , or NULL .
|
IS DESTINATION predicate
|
In a graph, checks to see if a node is or isn't the destination of an edge. |
IS SOURCE predicate
|
In a graph, checks to see if a node is or isn't the source of an edge. |
PROPERTY_EXISTS predicate
|
In a graph, checks to see if a property exists for an element. |
SAME predicate
|
In a graph, determines if all graph elements in a list bind to the same node or edge. |
Comparison operators |
Compares operands and produces the results of the comparison as a
BOOL value.
|
EXISTS operator
|
Checks if a subquery produces one or more rows. |
IN operator
|
Checks for an equal value in a set of values. |
IS operators
|
Checks for the truth of a condition and produces either TRUE or
FALSE .
|
LIKE operator
|
Checks if values are like or not like one another. |
NEW operator
|
Creates a protocol buffer. |
Concatenation operator | Combines multiple values into one. |
WITH expression
|
Creates variables for re-use and produces a result expression. |
Field access operator
expression.fieldname[. ...]
Description
Gets the value of a field. Alternatively known as the dot operator. Can be
used to access nested fields. For example, expression.fieldname1.fieldname2
.
Input values:
STRUCT
PROTO
JSON
GRAPH_ELEMENT
Return type
- For
STRUCT
: SQL data type offieldname
. If a field is not found in the struct, an error is thrown. - For
PROTO
: SQL data type offieldname
. If a field is not found in the protocol buffer, an error is thrown. - For
JSON
:JSON
. If a field is not found in a JSON value, a SQLNULL
is returned. - For
GRAPH_ELEMENT
: SQL data type offieldname
. If a field (property) is not found in the graph element, an error is produced.
Example
In the following example, the field access operations are .address
and
.country
.
SELECT
STRUCT(
STRUCT('Yonge Street' AS street, 'Canada' AS country)
AS address).address.country
/*---------*
| country |
+---------+
| Canada |
*---------*/
Array subscript operator
array_expression "[" array_subscript_specifier "]"
array_subscript_specifier:
position_keyword(index)
position_keyword:
{ OFFSET | SAFE_OFFSET | ORDINAL | SAFE_ORDINAL }
Description
Gets a value from an array at a specific position.
Input values:
array_expression
: The input array.position_keyword(index)
: Determines where the index for the array should start and how out-of-range indexes are handled. The index is an integer that represents a specific position in the array.OFFSET(index)
: The index starts at zero. Produces an error if the index is out of range. To produceNULL
instead of an error, useSAFE_OFFSET(index)
.SAFE_OFFSET(index)
: The index starts at zero. ReturnsNULL
if the index is out of range.ORDINAL(index)
: The index starts at one. Produces an error if the index is out of range. To produceNULL
instead of an error, useSAFE_ORDINAL(index)
.SAFE_ORDINAL(index)
: The index starts at one. ReturnsNULL
if the index is out of range.
Return type
T
where array_expression
is ARRAY<T>
.
Examples
In following query, the array subscript operator is used to return values at
specific position in item_array
. This query also shows what happens when you
reference an index (6
) in an array that is out of range. If the SAFE
prefix
is included, NULL
is returned, otherwise an error is produced.
SELECT
["coffee", "tea", "milk"] AS item_array,
["coffee", "tea", "milk"][OFFSET(0)] AS item_offset,
["coffee", "tea", "milk"][ORDINAL(1)] AS item_ordinal,
["coffee", "tea", "milk"][SAFE_OFFSET(6)] AS item_safe_offset
/*---------------------+-------------+--------------+------------------*
| item_array | item_offset | item_ordinal | item_safe_offset |
+---------------------+-------------+--------------+------------------+
| [coffee, tea, milk] | coffee | coffee | NULL |
*---------------------+-------------+--------------+------------------*/
When you reference an index that is out of range in an array, and a positional
keyword that begins with SAFE
is not included, an error is produced.
For example:
-- Error. Array index 6 is out of bounds.
SELECT ["coffee", "tea", "milk"][OFFSET(6)] AS item_offset
JSON subscript operator
json_expression "[" array_element_id "]"
json_expression "[" field_name "]"
Description
Gets a value of an array element or field in a JSON expression. Can be used to access nested data.
Input values:
JSON expression
: TheJSON
expression that contains an array element or field to return.[array_element_id]
: AnINT64
expression that represents a zero-based index in the array. If a negative value is entered, or the value is greater than or equal to the size of the array, or the JSON expression doesn't represent a JSON array, a SQLNULL
is returned.[field_name]
: ASTRING
expression that represents the name of a field in JSON. If the field name is not found, or the JSON expression is not a JSON object, a SQLNULL
is returned.
Return type
JSON
Example
In the following example:
json_value
is a JSON expression..class
is a JSON field access..students
is a JSON field access.[0]
is a JSON subscript expression with an element offset that accesses the zeroth element of an array in the JSON value.['name']
is a JSON subscript expression with a field name that accesses a field.
SELECT json_value.class.students[0]['name'] AS first_student
FROM
UNNEST(
[
JSON '{"class" : {"students" : [{"name" : "Jane"}]}}',
JSON '{"class" : {"students" : []}}',
JSON '{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'])
AS json_value;
/*-----------------*
| first_student |
+-----------------+
| "Jane" |
| NULL |
| "John" |
*-----------------*/
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 Plus | + X |
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, Subtraction and Multiplication:
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | INT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Division:
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Unary Plus:
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
Result types for Unary Minus:
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT32 | 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
GoogleSQL supports the AND
, OR
, and NOT
logical operators.
Logical operators allow only BOOL
or NULL
input
and use three-valued logic
to produce a result. The result can be TRUE
, FALSE
, or NULL
:
x |
y |
x AND y |
x OR y |
---|---|---|---|
TRUE |
TRUE |
TRUE |
TRUE |
TRUE |
FALSE |
FALSE |
TRUE |
TRUE |
NULL |
NULL |
TRUE |
FALSE |
TRUE |
FALSE |
TRUE |
FALSE |
FALSE |
FALSE |
FALSE |
FALSE |
NULL |
FALSE |
NULL |
NULL |
TRUE |
NULL |
TRUE |
NULL |
FALSE |
FALSE |
NULL |
NULL |
NULL |
NULL |
NULL |
x |
NOT x |
---|---|
TRUE |
FALSE |
FALSE |
TRUE |
NULL |
NULL |
Examples
The examples in this section reference a table called entry_table
:
/*-------*
| entry |
+-------+
| a |
| b |
| c |
| NULL |
*-------*/
SELECT 'a' FROM entry_table WHERE entry = 'a'
-- a => 'a' = 'a' => TRUE
-- b => 'b' = 'a' => FALSE
-- NULL => NULL = 'a' => NULL
/*-------*
| entry |
+-------+
| a |
*-------*/
SELECT entry FROM entry_table WHERE NOT (entry = 'a')
-- a => NOT('a' = 'a') => NOT(TRUE) => FALSE
-- b => NOT('b' = 'a') => NOT(FALSE) => TRUE
-- NULL => NOT(NULL = 'a') => NOT(NULL) => NULL
/*-------*
| entry |
+-------+
| b |
| c |
*-------*/
SELECT entry FROM entry_table WHERE entry IS NULL
-- a => 'a' IS NULL => FALSE
-- b => 'b' IS NULL => FALSE
-- NULL => NULL IS NULL => TRUE
/*-------*
| entry |
+-------+
| NULL |
*-------*/
Graph logical operators
GoogleSQL supports the following logical operators in element pattern label expressions:
Name | Syntax | Description |
---|---|---|
NOT |
!X |
Returns TRUE if X is not included, otherwise,
returns FALSE .
|
OR |
X | Y |
Returns TRUE if either X or Y is
included, otherwise, returns FALSE .
|
AND |
X & Y |
Returns TRUE if both X and Y are
included, otherwise, returns FALSE .
|
Graph predicates
GoogleSQL supports the following graph-specific predicates in
graph expressions. A predicate can produce TRUE
, FALSE
, or NULL
.
IS DESTINATION
predicate
node IS [ NOT ] DESTINATION [ OF ] edge
Description
In a graph, checks to see if a node is or isn't the destination of an edge.
Can produce TRUE
, FALSE
, or NULL
.
Arguments:
node
: The graph pattern variable for the node element.edge
: The graph pattern variable for the edge element.
Examples
GRAPH FinGraph
MATCH (a:Account)-[transfer:Transfers]-(b:Account)
WHERE a IS DESTINATION of transfer
RETURN a.id AS a_id, b.id AS b_id
/*-------------+
| a_id | b_id |
+-------------+
| 16 | 7 |
| 16 | 7 |
| 20 | 16 |
| 7 | 20 |
| 16 | 20 |
+-------------*/
GRAPH FinGraph
MATCH (a:Account)-[transfer:Transfers]-(b:Account)
WHERE b IS DESTINATION of transfer
RETURN a.id AS a_id, b.id AS b_id
/*-------------+
| a_id | b_id |
+-------------+
| 7 | 16 |
| 7 | 16 |
| 16 | 20 |
| 20 | 7 |
| 20 | 16 |
+-------------*/
IS SOURCE
predicate
node IS [ NOT ] SOURCE [ OF ] edge
Description
In a graph, checks to see if a node is or isn't the source of an edge.
Can produce TRUE
, FALSE
, or NULL
.
Arguments:
node
: The graph pattern variable for the node element.edge
: The graph pattern variable for the edge element.
Examples
GRAPH FinGraph
MATCH (a:Account)-[transfer:Transfers]-(b:Account)
WHERE a IS SOURCE of transfer
RETURN a.id AS a_id, b.id AS b_id
/*-------------+
| a_id | b_id |
+-------------+
| 20 | 7 |
| 7 | 16 |
| 7 | 16 |
| 20 | 16 |
| 16 | 20 |
+-------------*/
GRAPH FinGraph
MATCH (a:Account)-[transfer:Transfers]-(b:Account)
WHERE b IS SOURCE of transfer
RETURN a.id AS a_id, b.id AS b_id
/*-------------+
| a_id | b_id |
+-------------+
| 7 | 20 |
| 16 | 7 |
| 16 | 7 |
| 16 | 20 |
| 20 | 16 |
+-------------*/
PROPERTY_EXISTS
predicate
PROPERTY_EXISTS(element, element_property)
Description
In a graph, checks to see if a property exists for an element.
Can produce TRUE
, FALSE
, or NULL
.
Arguments:
element
: The graph pattern variable for a node or edge element.element_property
: The name of the property to look for inelement
. The property name must refer to a property in the graph. If the property does not exist in the graph, an error is produced. The property name is resolved in a case-insensitive manner.
Example
GRAPH FinGraph
MATCH (n:Person|Account WHERE PROPERTY_EXISTS(n, name))
RETURN n.name
/*------+
| name |
+------+
| Alex |
| Dana |
| Lee |
+------*/
SAME
predicate
SAME (element, element[, element])
Description
In a graph, determines if all graph elements in a list bind to the same node or
edge. Can produce TRUE
, FALSE
, or NULL
.
Arguments:
element
: The graph pattern variable for a node or edge element.
Example
The following query checks to see if a
and b
are not the same person.
GRAPH FinGraph
MATCH (src:Account)<-[transfer:Transfers]-(dest:Account)
WHERE NOT SAME(src, dest)
RETURN src.id AS source_id, dest.id AS destination_id
/*----------------------------+
| source_id | destination_id |
+----------------------------+
| 7 | 20 |
| 16 | 7 |
| 16 | 7 |
| 16 | 20 |
| 20 | 16 |
+----------------------------*/
Comparison operators
Compares operands and produces the results of the comparison as a BOOL
value. These comparison operators are available:
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 |
LIKE |
X [NOT] LIKE Y |
See the `LIKE` operator for details. |
IN |
Multiple | See the `IN` operator for details. |
The following rules apply to operands in a comparison operator:
- The operands must be comparable.
- A comparison operator generally requires both operands to be of the same type.
- If the operands are of different types, and the values of those types can be converted to a common type without loss of precision, they are generally coerced to that common type for the comparison.
- A literal operand is generally coerced to the same data type of a non-literal operand that is part of the comparison.
- Struct operands support only these comparison operators: equal
(
=
), not equal (!=
and<>
), andIN
.
The following rules apply when comparing these data types:
- Floating point:
All comparisons with
NaN
returnFALSE
, except for!=
and<>
, which returnTRUE
. BOOL
:FALSE
is less thanTRUE
.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.JSON
: You can't compare JSON, but you can compare the values inside of JSON if you convert the values to SQL values first. For more information, seeJSON
functions.NULL
: Any operation with aNULL
input returnsNULL
.STRUCT
: When testing a struct for equality, it's possible that one or more fields areNULL
. In such cases:- If all non-
NULL
field values are equal, the comparison returnsNULL
. - If any non-
NULL
field values are not equal, the comparison returnsFALSE
.
The following table demonstrates how
STRUCT
data types are compared when they have fields that areNULL
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
- If all non-
EXISTS
operator
EXISTS ( subquery )
Description
Returns TRUE
if the subquery produces one or more rows. Returns FALSE
if
the subquery produces zero rows. Never returns NULL
. To learn more about
how you can use a subquery with EXISTS
,
see EXISTS
subqueries.
Examples
In this example, the EXISTS
operator returns FALSE
because there are no
rows in Words
where the direction is south
:
WITH Words AS (
SELECT 'Intend' as value, 'east' as direction UNION ALL
SELECT 'Secure', 'north' UNION ALL
SELECT 'Clarity', 'west'
)
SELECT EXISTS ( SELECT value FROM Words WHERE direction = 'south' ) as result;
/*--------*
| result |
+--------+
| FALSE |
*--------*/
IN
operator
The IN
operator supports the following syntax:
search_value [NOT] IN value_set
value_set:
{
(expression[, ...])
| (subquery)
| UNNEST(array_expression)
}
Description
Checks for an equal value in a set of values.
Semantic rules apply, but in general, IN
returns TRUE
if an equal value is found, FALSE
if an equal value is excluded, otherwise
NULL
. NOT IN
returns FALSE
if an equal value is found, TRUE
if an
equal value is excluded, otherwise NULL
.
search_value
: The expression that is compared to a set of values.value_set
: One or more values to compare to a search value.(expression[, ...])
: A list of expressions.(subquery)
: A subquery that returns a single column. The values in that column are the set of values. If no rows are produced, the set of values is empty.UNNEST(array_expression)
: An UNNEST operator that returns a column of values from an array expression. This is equivalent to:IN (SELECT element FROM UNNEST(array_expression) AS element)
This operator generally supports collation,
however, [NOT] IN UNNEST
does not support collation.
Semantic rules
When using the IN
operator, the following semantics apply in this order:
- Returns
FALSE
ifvalue_set
is empty. - Returns
NULL
ifsearch_value
isNULL
. - Returns
TRUE
ifvalue_set
contains a value equal tosearch_value
. - Returns
NULL
ifvalue_set
contains aNULL
. - Returns
FALSE
.
When using the NOT IN
operator, the following semantics apply in this order:
- Returns
TRUE
ifvalue_set
is empty. - Returns
NULL
ifsearch_value
isNULL
. - Returns
FALSE
ifvalue_set
contains a value equal tosearch_value
. - Returns
NULL
ifvalue_set
contains aNULL
. - Returns
TRUE
.
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)
See the Arrays topic for more information on how to use this syntax.
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 topic for more information.
Return Data Type
BOOL
Examples
You can use these WITH
clauses to emulate temporary tables for
Words
and Items
in the following examples:
WITH Words AS (
SELECT 'Intend' as value UNION ALL
SELECT 'Secure' UNION ALL
SELECT 'Clarity' UNION ALL
SELECT 'Peace' UNION ALL
SELECT 'Intend'
)
SELECT * FROM Words;
/*----------*
| value |
+----------+
| Intend |
| Secure |
| Clarity |
| Peace |
| Intend |
*----------*/
WITH
Items AS (
SELECT STRUCT('blue' AS color, 'round' AS shape) AS info UNION ALL
SELECT STRUCT('blue', 'square') UNION ALL
SELECT STRUCT('red', 'round')
)
SELECT * FROM Items;
/*----------------------------*
| info |
+----------------------------+
| {blue color, round shape} |
| {blue color, square shape} |
| {red color, round shape} |
*----------------------------*/
Example with IN
and an expression:
SELECT * FROM Words WHERE value IN ('Intend', 'Secure');
/*----------*
| value |
+----------+
| Intend |
| Secure |
| Intend |
*----------*/
Example with NOT IN
and an expression:
SELECT * FROM Words WHERE value NOT IN ('Intend');
/*----------*
| value |
+----------+
| Secure |
| Clarity |
| Peace |
*----------*/
Example with IN
, a scalar subquery, and an expression:
SELECT * FROM Words WHERE value IN ((SELECT 'Intend'), 'Clarity');
/*----------*
| value |
+----------+
| Intend |
| Clarity |
| Intend |
*----------*/
Example with IN
and an UNNEST
operation:
SELECT * FROM Words WHERE value IN UNNEST(['Secure', 'Clarity']);
/*----------*
| value |
+----------+
| Secure |
| Clarity |
*----------*/
Example with IN
and a struct:
SELECT
(SELECT AS STRUCT Items.info) as item
FROM
Items
WHERE (info.shape, info.color) IN (('round', 'blue'));
/*------------------------------------*
| item |
+------------------------------------+
| { {blue color, round shape} info } |
*------------------------------------*/
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 TRUE |
BOOL |
BOOL |
Evaluates to TRUE if X evaluates to
TRUE .
Otherwise, evaluates to FALSE .
|
X IS NOT TRUE |
BOOL |
BOOL |
Evaluates to FALSE if X evaluates to
TRUE .
Otherwise, evaluates to TRUE .
|
X IS FALSE |
BOOL |
BOOL |
Evaluates to TRUE if X evaluates to
FALSE .
Otherwise, evaluates to FALSE .
|
X IS NOT FALSE |
BOOL |
BOOL |
Evaluates to FALSE if X evaluates to
FALSE .
Otherwise, evaluates to TRUE .
|
X IS NULL |
Any value type | BOOL |
Evaluates to TRUE if X evaluates to
NULL .
Otherwise evaluates to FALSE .
|
X IS NOT NULL |
Any value type | BOOL |
Evaluates to FALSE if X evaluates to
NULL .
Otherwise evaluates to TRUE .
|
X IS UNKNOWN |
BOOL |
BOOL |
Evaluates to TRUE if X evaluates to
NULL .
Otherwise evaluates to FALSE .
|
X IS NOT UNKNOWN |
BOOL |
BOOL |
Evaluates to FALSE if X evaluates to
NULL .
Otherwise, evaluates to TRUE .
|
LIKE
operator
expression_1 [NOT] LIKE expression_2
Description
LIKE
returns TRUE
if the string in the first operand expression_1
matches a pattern specified by the second operand expression_2
,
otherwise returns FALSE
.
NOT LIKE
returns TRUE
if the string in the first operand expression_1
does not match a pattern specified by the second operand expression_2
,
otherwise returns FALSE
.
Expressions can contain these characters:
- A percent sign (
%
) matches any number of characters or bytes. - An underscore (
_
) matches a single character or byte. - You can escape
\
,_
, or%
using two backslashes. For example,\\%
. If you are using raw strings, only a single backslash is required. For example,r'\%'
.
Return type
BOOL
Examples
The following examples illustrate how you can check to see if the string in the first operand matches a pattern specified by the second operand.
-- Returns TRUE
SELECT 'apple' LIKE 'a%';
-- Returns FALSE
SELECT '%a' LIKE 'apple';
-- Returns FALSE
SELECT 'apple' NOT LIKE 'a%';
-- Returns TRUE
SELECT '%a' NOT LIKE 'apple';
-- Produces an error
SELECT NULL LIKE 'a%';
-- Produces an error
SELECT 'apple' LIKE NULL;
The following example illustrates how to search multiple patterns in an array
to find a match with the LIKE
operator:
WITH Words AS
(SELECT 'Intend with clarity.' as value UNION ALL
SELECT 'Secure with intention.' UNION ALL
SELECT 'Clarity and security.')
SELECT value
FROM Words
WHERE ARRAY_INCLUDES(['%ity%', '%and%'], pattern->(Words.value LIKE pattern));
/*------------------------+
| value |
+------------------------+
| Intend with clarity. |
| Clarity and security. |
+------------------------*/
NEW
operator
The NEW
operator only supports protocol buffers and uses the following syntax:
NEW protocol_buffer {...}
: Creates a protocol buffer using a map constructor.NEW protocol_buffer { field_name: literal_or_expression field_name { ... } repeated_field_name: [literal_or_expression, ... ] }
NEW protocol_buffer (...)
: Creates a protocol buffer using a parenthesized list of arguments.NEW protocol_buffer(field [AS alias], ...field [AS alias])
Examples
The following example uses the NEW
operator with a map constructor:
NEW Universe {
name: "Sol"
closest_planets: ["Mercury", "Venus", "Earth" ]
star {
radius_miles: 432,690
age: 4,603,000,000
}
constellations: [{
name: "Libra"
index: 0
}, {
name: "Scorpio"
index: 1
}]
all_planets: (SELECT planets FROM SolTable)
}
The following example uses the NEW
operator with a parenthesized list of
arguments:
SELECT
key,
name,
NEW googlesql.examples.music.Chart(key AS rank, name AS chart_name)
FROM
(SELECT 1 AS key, "2" AS name);
To learn more about protocol buffers in GoogleSQL, see Work with protocol buffers.
Concatenation operator
The concatenation operator combines multiple values into one.
Function Syntax | Input Data Type | Result Data Type |
---|---|---|
STRING || STRING [ || ... ] |
STRING |
STRING |
BYTES || BYTES [ || ... ] |
BYTES |
BYTES |
ARRAY<T> || ARRAY<T> [ || ... ] |
ARRAY<T> |
ARRAY<T> |
WITH
expression
WITH(variable_assignment[, ...], result_expression)
variable_assignment:
variable_name AS expression
Description
Create one or more variables. Each variable can be used in subsequent
expressions within the WITH
expression. Returns the value of
result_expression
.
variable_assignment
: Introduces a variable. The variable name must be unique within a givenWITH
expression. Each expression can reference the variables that come before it. For example, if you create variablea
, then follow it with variableb
, you can referencea
inside ofb
's expression.variable_name
: The name of the variable.expression
: The value to assign to the variable.
result_expression
: An expression that is theWITH
expression's result.result_expression
can use all of the variables defined before it.
Return Type
- The type of the
result_expression
.
Requirements and Caveats
- A given variable may only be assigned once in a given
WITH
clause. - Variables created during
WITH
may not be used in aggregate function arguments. For example,WITH(a AS ..., SUM(a))
produces an error. - Volatile expressions behave as if they are evaluated only once.
Examples
The following example first concatenates variable a
with b
, then variable
b
with c
:
SELECT WITH(a AS '123', -- a is '123'
b AS CONCAT(a, '456'), -- b is '123456'
c AS '789', -- c is '789'
CONCAT(b, c)) AS result; -- b + c is '123456789'
/*-------------*
| result |
+-------------+
| '123456789' |
*-------------*/
Aggregate function results can be stored in variables. In this example, an average is computed:
SELECT WITH(s AS SUM(input), c AS COUNT(input), s/c)
FROM UNNEST([1.0, 2.0, 3.0]) AS input;
/*---------*
| result |
+---------+
| 2.0 |
*---------*/
Variables cannot be used in aggregate function call arguments:
SELECT WITH(diff AS a - b, AVG(diff))
FROM UNNEST([
STRUCT(1 AS a, 2 AS b),
STRUCT(3 AS a, 4 AS b),
STRUCT(5 AS a, 6 AS b),
]);
-- ERROR: WITH variables like 'diff' cannot be used in aggregate or analytic
-- function arguments.
Conditional expressions in GoogleSQL
GoogleSQL for Spanner supports 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 list
Name | Summary |
---|---|
CASE expr
|
Compares the given expression to each successive WHEN clause
and produces the first result where the values are equal.
|
CASE
|
Evaluates the condition of each successive WHEN clause and
produces the first result where the condition evaluates to
TRUE .
|
COALESCE
|
Produces the value of the first non-NULL expression, if any,
otherwise NULL .
|
IF
|
If an expression evaluates to TRUE , produces a specified
result, otherwise produces the evaluation for an else result.
|
IFNULL
|
If an expression evaluates to NULL , produces a specified
result, otherwise produces the expression.
|
NULLIF
|
Produces NULL if the first expression that matches another
evaluates to TRUE , otherwise returns the first expression.
|
CASE expr
CASE expr
WHEN expr_to_match THEN result
[ ... ]
[ ELSE else_result ]
END
Description
Compares expr
to expr_to_match
of each successive WHEN
clause and returns
the first result where this comparison evaluates to TRUE
. The remaining WHEN
clauses and else_result
aren't evaluated.
If the expr = expr_to_match
comparison evaluates to FALSE
or NULL
for all
WHEN
clauses, returns the evaluation of else_result
if present; if
else_result
isn't present, then returns NULL
.
Consistent with equality comparisons elsewhere, if both
expr
and expr_to_match
are NULL
, then expr = expr_to_match
evaluates to
NULL
, which returns else_result
. If a CASE statement needs to distinguish a
NULL
value, then the alternate CASE syntax should be used.
expr
and expr_to_match
can be any type. They must be implicitly
coercible to a common supertype; equality comparisons are
done on coerced values. There may be multiple result
types. result
and
else_result
expressions must be coercible to a common supertype.
Return Data Type
Supertype of result
[, ...] and else_result
.
Example
WITH Numbers AS (
SELECT 90 as A, 2 as B UNION ALL
SELECT 50, 8 UNION ALL
SELECT 60, 6 UNION ALL
SELECT 50, 10
)
SELECT
A,
B,
CASE A
WHEN 90 THEN 'red'
WHEN 50 THEN 'blue'
ELSE 'green'
END
AS result
FROM Numbers
/*------------------*
| A | B | result |
+------------------+
| 90 | 2 | red |
| 50 | 8 | blue |
| 60 | 6 | green |
| 50 | 10 | blue |
*------------------*/
CASE
CASE
WHEN condition THEN result
[ ... ]
[ ELSE else_result ]
END
Description
Evaluates the condition of each successive WHEN
clause and returns the
first result where the condition evaluates to TRUE
; any remaining WHEN
clauses and else_result
aren't evaluated.
If all conditions evaluate to FALSE
or NULL
, returns evaluation of
else_result
if present; if else_result
isn't present, then returns NULL
.
For additional rules on how values are evaluated, see the three-valued logic table in Logical operators.
condition
must be a boolean expression. There may be multiple result
types.
result
and else_result
expressions must be implicitly coercible to a common
supertype.
Return Data Type
Supertype of result
[, ...] and else_result
.
Example
WITH Numbers AS (
SELECT 90 as A, 2 as B UNION ALL
SELECT 50, 6 UNION ALL
SELECT 20, 10
)
SELECT
A,
B,
CASE
WHEN A > 60 THEN 'red'
WHEN B = 6 THEN 'blue'
ELSE 'green'
END
AS result
FROM Numbers
/*------------------*
| A | B | result |
+------------------+
| 90 | 2 | red |
| 50 | 6 | blue |
| 20 | 10 | green |
*------------------*/
COALESCE
COALESCE(expr[, ...])
Description
Returns the value of the first non-NULL
expression, if any, otherwise
NULL
. The remaining expressions aren't evaluated. An input expression can be
any type. There may be multiple input expression types.
All input expressions must be implicitly coercible to a common
supertype.
Return Data Type
Supertype of expr
[, ...].
Examples
SELECT COALESCE('A', 'B', 'C') as result
/*--------*
| result |
+--------+
| A |
*--------*/
SELECT COALESCE(NULL, 'B', 'C') as result
/*--------*
| result |
+--------+
| B |
*--------*/
IF
IF(expr, true_result, else_result)
Description
If expr
evaluates to TRUE
, returns true_result
, else returns the
evaluation for else_result
. else_result
isn't evaluated if expr
evaluates
to TRUE
. true_result
isn't evaluated if expr
evaluates to FALSE
or
NULL
.
expr
must be a boolean expression. true_result
and else_result
must be coercible to a common supertype.
Return Data Type
Supertype of true_result
and else_result
.
Examples
SELECT
10 AS A,
20 AS B,
IF(10 < 20, 'true', 'false') AS result
/*------------------*
| A | B | result |
+------------------+
| 10 | 20 | true |
*------------------*/
SELECT
30 AS A,
20 AS B,
IF(30 < 20, 'true', 'false') AS result
/*------------------*
| A | B | result |
+------------------+
| 30 | 20 | false |
*------------------*/
IFNULL
IFNULL(expr, null_result)
Description
If expr
evaluates to NULL
, returns null_result
. Otherwise, returns
expr
. If expr
doesn't evaluate to NULL
, null_result
isn't evaluated.
expr
and null_result
can be any type and must be implicitly coercible to
a common supertype. Synonym for
COALESCE(expr, null_result)
.
Return Data Type
Supertype of expr
or null_result
.
Examples
SELECT IFNULL(NULL, 0) as result
/*--------*
| result |
+--------+
| 0 |
*--------*/
SELECT IFNULL(10, 0) as result
/*--------*
| result |
+--------+
| 10 |
*--------*/
NULLIF
NULLIF(expr, expr_to_match)
Description
Returns NULL
if expr = expr_to_match
evaluates to TRUE
, otherwise
returns expr
.
expr
and expr_to_match
must be implicitly coercible to a
common supertype, and must be comparable.
Return Data Type
Supertype of expr
and expr_to_match
.
Example
SELECT NULLIF(0, 0) as result
/*--------*
| result |
+--------+
| NULL |
*--------*/
SELECT NULLIF(10, 0) as result
/*--------*
| result |
+--------+
| 10 |
*--------*/
FUNCTIONS
Aggregate functions in GoogleSQL
GoogleSQL for Spanner supports the following general aggregate functions. To learn about the syntax for aggregate function calls, see Aggregate function calls.
Function list
Name | Summary |
---|---|
ANY_VALUE
|
Gets an expression for some row. |
ARRAY_AGG
|
Gets an array of values. |
ARRAY_CONCAT_AGG
|
Concatenates arrays and returns a single array as a result. |
AVG
|
Gets the average of non-NULL values.
|
BIT_AND
|
Performs a bitwise AND operation on an expression. |
BIT_OR
|
Performs a bitwise OR operation on an expression. |
BIT_XOR
|
Performs a bitwise XOR operation on an expression. |
COUNT
|
Gets the number of rows in the input, or the number of rows with an
expression evaluated to any value other than NULL .
|
COUNTIF
|
Gets the count of TRUE values for an expression.
|
LOGICAL_AND
|
Gets the logical AND of all non-NULL expressions.
|
LOGICAL_OR
|
Gets the logical OR of all non-NULL expressions.
|
MAX
|
Gets the maximum non-NULL value.
|
MIN
|
Gets the minimum non-NULL value.
|
STDDEV
|
An alias of the STDDEV_SAMP function.
For more information, see Statistical aggregate functions. |
STDDEV_SAMP
|
Computes the sample (unbiased) standard deviation of the values.
For more information, see Statistical aggregate functions. |
STRING_AGG
|
Concatenates non-NULL STRING or
BYTES values.
|
SUM
|
Gets the sum of non-NULL values.
|
VAR_SAMP
|
Computes the sample (unbiased) variance of the values.
For more information, see Statistical aggregate functions. |
VARIANCE
|
An alias of VAR_SAMP .
For more information, see Statistical aggregate functions. |
ANY_VALUE
ANY_VALUE(
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns expression
for some row chosen from the group. Which row is chosen is
nondeterministic, not random. Returns NULL
when the input produces no
rows. Returns NULL
when expression
or expression2
is
NULL
for all rows in the group.
ANY_VALUE
behaves as if IGNORE NULLS
is specified;
rows for which expression
is NULL
are not considered and won't be
selected.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
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 |
*-----------*/
WITH
Store AS (
SELECT 20 AS sold, "apples" AS fruit
UNION ALL
SELECT 30 AS sold, "pears" AS fruit
UNION ALL
SELECT 30 AS sold, "bananas" AS fruit
UNION ALL
SELECT 10 AS sold, "oranges" AS fruit
)
SELECT ANY_VALUE(fruit HAVING MAX sold) AS a_highest_selling_fruit FROM Store;
/*-------------------------*
| a_highest_selling_fruit |
+-------------------------+
| pears |
*-------------------------*/
WITH
Store AS (
SELECT 20 AS sold, "apples" AS fruit
UNION ALL
SELECT 30 AS sold, "pears" AS fruit
UNION ALL
SELECT 30 AS sold, "bananas" AS fruit
UNION ALL
SELECT 10 AS sold, "oranges" AS fruit
)
SELECT ANY_VALUE(fruit HAVING MIN sold) AS a_lowest_selling_fruit FROM Store;
/*-------------------------*
| a_lowest_selling_fruit |
+-------------------------+
| oranges |
*-------------------------*/
ARRAY_AGG
ARRAY_AGG(
[ DISTINCT ]
expression
[ { IGNORE | RESPECT } NULLS ]
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns an ARRAY of expression
values.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
All data types except ARRAY.
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] |
*---------------*/
SELECT ARRAY_AGG(x IGNORE NULLS) AS array_agg
FROM UNNEST([NULL, 1, -2, 3, -2, 1, NULL]) AS x;
/*-------------------*
| array_agg |
+-------------------+
| [1, -2, 3, -2, 1] |
*-------------------*/
WITH vals AS
(
SELECT 1 x, 'a' y UNION ALL
SELECT 1 x, 'b' y UNION ALL
SELECT 2 x, 'a' y UNION ALL
SELECT 2 x, 'c' y
)
SELECT x, ARRAY_AGG(y) as array_agg
FROM vals
GROUP BY x;
/*---------------*
| x | array_agg |
+---------------+
| 1 | [a, b] |
| 2 | [a, c] |
*---------------*/
ARRAY_CONCAT_AGG
ARRAY_CONCAT_AGG(
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Concatenates elements from expression
of type ARRAY
, returning a single
array as a result.
This function ignores NULL
input arrays, but respects the NULL
elements in
non-NULL
input arrays. Returns NULL
if there are zero input rows or
expression
evaluates to NULL
for all rows.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
ARRAY
Returned Data Types
ARRAY
Examples
SELECT ARRAY_CONCAT_AGG(x) AS array_concat_agg FROM (
SELECT [NULL, 1, 2, 3, 4] AS x
UNION ALL SELECT NULL
UNION ALL SELECT [5, 6]
UNION ALL SELECT [7, 8, 9]
);
/*-----------------------------------*
| array_concat_agg |
+-----------------------------------+
| [NULL, 1, 2, 3, 4, 5, 6, 7, 8, 9] |
*-----------------------------------*/
AVG
AVG(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the average of non-NULL
values in an aggregated group.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Caveats:
- If the aggregated group is empty or the argument is
NULL
for all rows in the group, returnsNULL
. - If the argument is
NaN
for any row in the group, returnsNaN
. - If the argument is
[+|-]Infinity
for any row in the group, returns either[+|-]Infinity
orNaN
. - If there is numeric overflow, produces an error.
- If a floating-point type is returned, the result is non-deterministic, which means you might receive a different result each time you use this function.
Supported Argument Types
- Any numeric input type
Returned Data Types
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | 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
[ HAVING { MAX | MIN } expression2 ]
)
Description
Performs a bitwise AND operation on expression
and returns the result.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
- INT64
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
[ HAVING { MAX | MIN } expression2 ]
)
Description
Performs a bitwise OR operation on expression
and returns the result.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
- INT64
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
[ HAVING { MAX | MIN } expression2 ]
)
Description
Performs a bitwise XOR operation on expression
and returns the result.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
- INT64
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
[ HAVING { MAX | MIN } expression2 ]
)
Description
- Returns the number of rows in the input.
- Returns the number of rows with
expression
evaluated to any value other thanNULL
.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
expression
can be any data type. If
DISTINCT
is present, expression
can only be a data type that is
groupable.
Return Data Types
INT64
Examples
You can use the COUNT
function to return the number of rows in a table or the
number of distinct values of an expression. For example:
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 |
*------------+---------*/
If you want to count the number of distinct values of an expression for which a certain condition is satisfied, this is one recipe that you can use:
COUNT(DISTINCT IF(condition, expression, NULL))
Here, IF
will return the value of expression
if condition
is TRUE
, or
NULL
otherwise. The surrounding COUNT(DISTINCT ...)
will ignore the NULL
values, so it will count only the distinct values of expression
for which
condition
is TRUE
.
For example, to count the number of distinct positive values of x
:
SELECT COUNT(DISTINCT IF(x > 0, x, NULL)) AS distinct_positive
FROM UNNEST([1, -2, 4, 1, -5, 4, 1, 3, -6, 1]) AS x;
/*-------------------*
| distinct_positive |
+-------------------+
| 3 |
*-------------------*/
Or to count the number of distinct dates on which a certain kind of event occurred:
WITH Events AS (
SELECT DATE '2021-01-01' AS event_date, 'SUCCESS' AS event_type
UNION ALL
SELECT DATE '2021-01-02' AS event_date, 'SUCCESS' AS event_type
UNION ALL
SELECT DATE '2021-01-02' AS event_date, 'FAILURE' AS event_type
UNION ALL
SELECT DATE '2021-01-03' AS event_date, 'SUCCESS' AS event_type
UNION ALL
SELECT DATE '2021-01-04' AS event_date, 'FAILURE' AS event_type
UNION ALL
SELECT DATE '2021-01-04' AS event_date, 'FAILURE' AS event_type
)
SELECT
COUNT(DISTINCT IF(event_type = 'FAILURE', event_date, NULL))
AS distinct_dates_with_failures
FROM Events;
/*------------------------------*
| distinct_dates_with_failures |
+------------------------------+
| 2 |
*------------------------------*/
COUNTIF
COUNTIF(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the count of TRUE
values for expression
. Returns 0
if there are
zero input rows, or if expression
evaluates to FALSE
or NULL
for all rows.
Since expression
must be a BOOL
, the form COUNTIF(DISTINCT ...)
is
generally not useful: there is only one distinct value of TRUE
. So
COUNTIF(DISTINCT ...)
will return 1 if expression
evaluates to TRUE
for
one or more input rows, or 0 otherwise.
Usually when someone wants to combine COUNTIF
and DISTINCT
, they
want to count the number of distinct values of an expression for which a certain
condition is satisfied. One recipe to achieve this is the following:
COUNT(DISTINCT IF(condition, expression, NULL))
Note that this uses COUNT
, not COUNTIF
; the IF
part has been moved inside.
To learn more, see the examples for COUNT
.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
BOOL
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
[ HAVING { MAX | MIN } expression2 ]
)
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.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
BOOL
Return Data Types
BOOL
Examples
LOGICAL_AND
returns FALSE
because not all of the values in the array are
less than 3.
SELECT LOGICAL_AND(x < 3) AS logical_and FROM UNNEST([1, 2, 4]) AS x;
/*-------------*
| logical_and |
+-------------+
| FALSE |
*-------------*/
LOGICAL_OR
LOGICAL_OR(
expression
[ HAVING { MAX | MIN } expression2 ]
)
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.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
BOOL
Return Data Types
BOOL
Examples
LOGICAL_OR
returns TRUE
because at least one of the values in the array is
less than 3.
SELECT LOGICAL_OR(x < 3) AS logical_or FROM UNNEST([1, 2, 4]) AS x;
/*------------*
| logical_or |
+------------+
| TRUE |
*------------*/
MAX
MAX(
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the maximum non-NULL
value in an aggregated group.
Caveats:
- If the aggregated group is empty or the argument is
NULL
for all rows in the group, returnsNULL
. - If the argument is
NaN
for any row in the group, returnsNaN
.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
Any orderable data type except for ARRAY
.
Return Data Types
The data type of the input values.
Examples
SELECT MAX(x) AS max
FROM UNNEST([8, 37, 55, 4]) AS x;
/*-----*
| max |
+-----+
| 55 |
*-----*/
MIN
MIN(
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the minimum non-NULL
value in an aggregated group.
Caveats:
- If the aggregated group is empty or the argument is
NULL
for all rows in the group, returnsNULL
. - If the argument is
NaN
for any row in the group, returnsNaN
.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
Any orderable data type except for ARRAY
.
Return Data Types
The data type of 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]
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns a value (either STRING
or BYTES
) obtained by concatenating
non-NULL
values. Returns NULL
if there are zero input rows or expression
evaluates to NULL
for all rows.
If a delimiter
is specified, concatenated values are separated by that
delimiter; otherwise, a comma is used as a delimiter.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Supported Argument Types
Either STRING
or BYTES
.
Return Data Types
Either STRING
or 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
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the sum of non-NULL
values in an aggregated group.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Caveats:
- If the aggregated group is empty or the argument is
NULL
for all rows in the group, returnsNULL
. - If the argument is
NaN
for any row in the group, returnsNaN
. - If the argument is
[+|-]Infinity
for any row in the group, returns either[+|-]Infinity
orNaN
. - If there is numeric overflow, produces an error.
- If a floating-point type is returned, the result is non-deterministic, which means you might receive a different result each time you use this function.
Supported Argument Types
- Any supported numeric data type
Return Data Types
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT64 | FLOAT64 |
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 |
*-----*/
SELECT SUM(x) AS sum
FROM UNNEST([]) AS x;
/*------*
| sum |
+------+
| NULL |
*------*/
Array functions in GoogleSQL
GoogleSQL for Spanner supports the following array functions.
Function list
Name | Summary |
---|---|
ARRAY
|
Produces an array with one element for each row in a subquery. |
ARRAY_AGG
|
Gets an array of values.
For more information, see Aggregate functions. |
ARRAY_CONCAT
|
Concatenates one or more arrays with the same element type into a single array. |
ARRAY_CONCAT_AGG
|
Concatenates arrays and returns a single array as a result.
For more information, see Aggregate functions. |
ARRAY_FILTER
|
Takes an array, filters out unwanted elements, and returns the results in a new array. |
ARRAY_FIRST
|
Gets the first element in an array. |
ARRAY_INCLUDES
|
Checks if there is an element in the array that is equal to a search value. |
ARRAY_INCLUDES_ALL
|
Checks if all search values are in an array. |
ARRAY_INCLUDES_ANY
|
Checks if any search values are in an array. |
ARRAY_IS_DISTINCT
|
Checks if an array contains no repeated elements. |
ARRAY_LAST
|
Gets the last element in an array. |
ARRAY_LENGTH
|
Gets the number of elements in an array. |
ARRAY_MAX
|
Gets the maximum non-NULL value in an array.
|
ARRAY_MIN
|
Gets the minimum non-NULL value in an array.
|
ARRAY_REVERSE
|
Reverses the order of elements in an array. |
ARRAY_SLICE
|
Produces an array containing zero or more consecutive elements from an input array. |
ARRAY_TO_STRING
|
Produces a concatenation of the elements in an array as a
STRING value.
|
ARRAY_TRANSFORM
|
Transforms the elements of an array, and returns the results in a new array. |
GENERATE_ARRAY
|
Generates an array of values in a range. |
GENERATE_DATE_ARRAY
|
Generates an array of dates in a range. |
JSON_ARRAY
|
Creates a JSON array.
For more information, see JSON functions. |
JSON_QUERY_ARRAY
|
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
or
ARRAY<JSON>
value.
For more information, see JSON functions. |
JSON_VALUE_ARRAY
|
Extracts a JSON array of scalar values and converts it to a SQL
ARRAY<STRING> value.
For more information, see JSON 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.
If subquery
produces a
value table,
then each element in the output ARRAY
is the entire corresponding row of the
value 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 that GoogleSQL 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[, ...])
Description
Concatenates one or more arrays with the same element type into a single array.
The function returns NULL
if any input argument is NULL
.
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_FILTER
ARRAY_FILTER(array_expression, lambda_expression)
lambda_expression:
{
element_alias -> boolean_expression
| (element_alias, index_alias) -> boolean_expression
}
Description
Takes an array, filters out unwanted elements, and returns the results in a new array.
array_expression
: The array to filter.lambda_expression
: Each element inarray_expression
is evaluated against the lambda expression. If the expression evaluates toFALSE
orNULL
, the element is removed from the resulting array.element_alias
: An alias that represents an array element.index_alias
: An alias that represents the zero-based offset of the array element.boolean_expression
: The predicate used to filter the array elements.
Returns NULL
if the array_expression
is NULL
.
Return type
ARRAY
Example
SELECT
ARRAY_FILTER([1 ,2, 3], e -> e > 1) AS a1,
ARRAY_FILTER([0, 2, 3], (e, i) -> e > i) AS a2;
/*-------+-------*
| a1 | a2 |
+-------+-------+
| [2,3] | [2,3] |
*-------+-------*/
ARRAY_FIRST
ARRAY_FIRST(array_expression)
Description
Takes an array and returns the first element in the array.
Produces an error if the array is empty.
Returns NULL
if array_expression
is NULL
.
Return type
Matches the data type of elements in array_expression
.
Example
SELECT ARRAY_FIRST(['a','b','c','d']) as first_element
/*---------------*
| first_element |
+---------------+
| a |
*---------------*/
ARRAY_INCLUDES
- Signature 1:
ARRAY_INCLUDES(array_to_search, search_value)
- Signature 2:
ARRAY_INCLUDES(array_to_search, lambda_expression)
Signature 1
ARRAY_INCLUDES(array_to_search, search_value)
Description
Takes an array and returns TRUE
if there is an element in the array that is
equal to the search_value.
array_to_search
: The array to search.search_value
: The element to search for in the array.
Returns NULL
if array_to_search
or search_value
is NULL
.
Return type
BOOL
Example
In the following example, the query first checks to see if 0
exists in an
array. Then the query checks to see if 1
exists in an array.
SELECT
ARRAY_INCLUDES([1, 2, 3], 0) AS a1,
ARRAY_INCLUDES([1, 2, 3], 1) AS a2;
/*-------+------*
| a1 | a2 |
+-------+------+
| false | true |
*-------+------*/
Signature 2
ARRAY_INCLUDES(array_to_search, lambda_expression)
lambda_expression: element_alias -> boolean_expression
Description
Takes an array and returns TRUE
if the lambda expression evaluates to TRUE
for any element in the array.
array_to_search
: The array to search.lambda_expression
: Each element inarray_to_search
is evaluated against the lambda expression.element_alias
: An alias that represents an array element.boolean_expression
: The predicate used to evaluate the array elements.
Returns NULL
if array_to_search
is NULL
.
Return type
BOOL
Example
In the following example, the query first checks to see if any elements that are
greater than 3 exist in an array (e > 3
). Then the query checks to see if any
any elements that are greater than 0 exist in an array (e > 0
).
SELECT
ARRAY_INCLUDES([1, 2, 3], e -> e > 3) AS a1,
ARRAY_INCLUDES([1, 2, 3], e -> e > 0) AS a2;
/*-------+------*
| a1 | a2 |
+-------+------+
| false | true |
*-------+------*/
ARRAY_INCLUDES_ALL
ARRAY_INCLUDES_ALL(array_to_search, search_values)
Description
Takes an array to search and an array of search values. Returns TRUE
if all
search values are in the array to search, otherwise returns FALSE
.
array_to_search
: The array to search.search_values
: The array that contains the elements to search for.
Returns NULL
if array_to_search
or search_values
is
NULL
.
Return type
BOOL
Example
In the following example, the query first checks to see if 3
, 4
, and 5
exists in an array. Then the query checks to see if 4
, 5
, and 6
exists in
an array.
SELECT
ARRAY_INCLUDES_ALL([1,2,3,4,5], [3,4,5]) AS a1,
ARRAY_INCLUDES_ALL([1,2,3,4,5], [4,5,6]) AS a2;
/*------+-------*
| a1 | a2 |
+------+-------+
| true | false |
*------+-------*/
ARRAY_INCLUDES_ANY
ARRAY_INCLUDES_ANY(array_to_search, search_values)
Description
Takes an array to search and an array of search values. Returns TRUE
if any
search values are in the array to search, otherwise returns FALSE
.
array_to_search
: The array to search.search_values
: The array that contains the elements to search for.
Returns NULL
if array_to_search
or search_values
is
NULL
.
Return type
BOOL
Example
In the following example, the query first checks to see if 3
, 4
, or 5
exists in an array. Then the query checks to see if 4
, 5
, or 6
exists in
an array.
SELECT
ARRAY_INCLUDES_ANY([1,2,3], [3,4,5]) AS a1,
ARRAY_INCLUDES_ANY([1,2,3], [4,5,6]) AS a2;
/*------+-------*
| a1 | a2 |
+------+-------+
| true | false |
*------+-------*/
ARRAY_IS_DISTINCT
ARRAY_IS_DISTINCT(value)
Description
Returns TRUE
if the array contains no repeated elements, using the same
equality comparison logic as SELECT DISTINCT
.
Return type
BOOL
Examples
SELECT ARRAY_IS_DISTINCT([1, 2, 3]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| true |
*-------------*/
SELECT ARRAY_IS_DISTINCT([1, 1, 1]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| false |
*-------------*/
SELECT ARRAY_IS_DISTINCT([1, 2, NULL]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| true |
*-------------*/
SELECT ARRAY_IS_DISTINCT([1, 1, NULL]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| false |
*-------------*/
SELECT ARRAY_IS_DISTINCT([1, NULL, NULL]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| false |
*-------------*/
SELECT ARRAY_IS_DISTINCT([]) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| true |
*-------------*/
SELECT ARRAY_IS_DISTINCT(NULL) AS is_distinct
/*-------------*
| is_distinct |
+-------------+
| NULL |
*-------------*/
ARRAY_LAST
ARRAY_LAST(array_expression)
Description
Takes an array and returns the last element in the array.
Produces an error if the array is empty.
Returns NULL
if array_expression
is NULL
.
Return type
Matches the data type of elements in array_expression
.
Example
SELECT ARRAY_LAST(['a','b','c','d']) as last_element
/*---------------*
| last_element |
+---------------+
| d |
*---------------*/
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
SELECT
ARRAY_LENGTH(["coffee", NULL, "milk" ]) AS size_a,
ARRAY_LENGTH(["cake", "pie"]) AS size_b;
/*--------+--------*
| size_a | size_b |
+--------+--------+
| 3 | 2 |
*--------+--------*/
ARRAY_MAX
ARRAY_MAX(input_array)
Description
Returns the maximum non-NULL
value in an array.
Caveats:
- If the array is
NULL
, empty, or contains onlyNULL
s, returnsNULL
. - If the array contains
NaN
, returnsNaN
.
Supported Argument Types
In the input array, ARRAY<T>
, T
can be an
orderable data type.
Return type
The same data type as T
in the input array.
Examples
SELECT ARRAY_MAX([8, 37, NULL, 55, 4]) as max
/*-----*
| max |
+-----+
| 55 |
*-----*/
ARRAY_MIN
ARRAY_MIN(input_array)
Description
Returns the minimum non-NULL
value in an array.
Caveats:
- If the array is
NULL
, empty, or contains onlyNULL
s, returnsNULL
. - If the array contains
NaN
, returnsNaN
.
Supported Argument Types
In the input array, ARRAY<T>
, T
can be an
orderable data type.
Return type
The same data type as T
in the input array.
Examples
SELECT ARRAY_MIN([8, 37, NULL, 4, 55]) as min
/*-----*
| min |
+-----+
| 4 |
*-----*/
ARRAY_REVERSE
ARRAY_REVERSE(value)
Description
Returns the input ARRAY
with elements in reverse order.
Return type
ARRAY
Examples
SELECT ARRAY_REVERSE([1, 2, 3]) AS reverse_arr
/*-------------*
| reverse_arr |
+-------------+
| [3, 2, 1] |
*-------------*/
ARRAY_SLICE
ARRAY_SLICE(array_to_slice, start_offset, end_offset)
Description
Returns an array containing zero or more consecutive elements from the input array.
array_to_slice
: The array that contains the elements you want to slice.start_offset
: The inclusive starting offset.end_offset
: The inclusive ending offset.
An offset can be positive or negative. A positive offset starts from the beginning of the input array and is 0-based. A negative offset starts from the end of the input array. Out-of-bounds offsets are supported. Here are some examples:
Input offset | Final offset in array | Notes |
---|---|---|
0 | ['a', 'b', 'c', 'd'] | The final offset is 0 . |
3 | ['a', 'b', 'c', 'd'] | The final offset is 3 . |
5 | ['a', 'b', 'c', 'd'] |
Because the input offset is out of bounds,
the final offset is 3 (array length - 1 ).
|
-1 | ['a', 'b', 'c', 'd'] |
Because a negative offset is used, the offset starts at the end of the
array. The final offset is 3
(array length - 1 ).
|
-2 | ['a', 'b', 'c', 'd'] |
Because a negative offset is used, the offset starts at the end of the
array. The final offset is 2
(array length - 2 ).
|
-4 | ['a', 'b', 'c', 'd'] |
Because a negative offset is used, the offset starts at the end of the
array. The final offset is 0
(array length - 4 ).
|
-5 | ['a', 'b', 'c', 'd'] |
Because the offset is negative and out of bounds, the final offset is
0 (array length - array length ).
|
Additional details:
- The input array can contain
NULL
elements.NULL
elements are included in the resulting array. - Returns
NULL
ifarray_to_slice
,start_offset
, orend_offset
isNULL
. - Returns an empty array if
array_to_slice
is empty. - Returns an empty array if the position of the
start_offset
in the array is after the position of theend_offset
.
Return type
ARRAY
Examples
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 1, 3) AS result
/*-----------*
| result |
+-----------+
| [b, c, d] |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -1, 3) AS result
/*-----------*
| result |
+-----------+
| [] |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 1, -3) AS result
/*--------*
| result |
+--------+
| [b, c] |
*--------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -1, -3) AS result
/*-----------*
| result |
+-----------+
| [] |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -3, -1) AS result
/*-----------*
| result |
+-----------+
| [c, d, e] |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 3, 3) AS result
/*--------*
| result |
+--------+
| [d] |
*--------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -3, -3) AS result
/*--------*
| result |
+--------+
| [c] |
*--------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 1, 30) AS result
/*--------------*
| result |
+--------------+
| [b, c, d, e] |
*--------------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 1, -30) AS result
/*-----------*
| result |
+-----------+
| [] |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -30, 30) AS result
/*-----------------*
| result |
+-----------------+
| [a, b, c, d, e] |
*-----------------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], -30, -5) AS result
/*--------*
| result |
+--------+
| [a] |
*--------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 5, 30) AS result
/*--------*
| result |
+--------+
| [] |
*--------*/
SELECT ARRAY_SLICE(['a', 'b', 'c', 'd', 'e'], 1, NULL) AS result
/*-----------*
| result |
+-----------+
| NULL |
*-----------*/
SELECT ARRAY_SLICE(['a', 'b', NULL, 'd', 'e'], 1, 3) AS result
/*--------------*
| result |
+--------------+
| [b, NULL, d] |
*--------------*/
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.
Return type
STRING
Examples
SELECT ARRAY_TO_STRING(['coffee', 'tea', 'milk', NULL], '--', 'MISSING') AS text
/*--------------------------------*
| text |
+--------------------------------+
| coffee--tea--milk--MISSING |
*--------------------------------*/
SELECT ARRAY_TO_STRING(['cake', 'pie', NULL], '--', 'MISSING') AS text
/*--------------------------------*
| text |
+--------------------------------+
| cake--pie--MISSING |
*--------------------------------*/
ARRAY_TRANSFORM
ARRAY_TRANSFORM(array_expression, lambda_expression)
lambda_expression:
{
element_alias -> transform_expression
| (element_alias, index_alias) -> transform_expression
}
Description
Takes an array, transforms the elements, and returns the results in a new array. The output array always has the same length as the input array.
array_expression
: The array to transform.lambda_expression
: Each element inarray_expression
is evaluated against the lambda expression. The evaluation results are returned in a new array.element_alias
: An alias that represents an array element.index_alias
: An alias that represents the zero-based offset of the array element.transform_expression
: The expression used to transform the array elements.
Returns NULL
if the array_expression
is NULL
.
Return type
ARRAY
Example
SELECT
ARRAY_TRANSFORM([1, 2, 3], e -> e + 1) AS a1,
ARRAY_TRANSFORM([1, 2, 3], (e, i) -> e + i) AS a2;
/*---------+---------*
| a1 | a2 |
+---------+---------+
| [2,3,4] | [1,3,5] |
*---------+---------*/
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
NUMERIC
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 aDATE
.end_date
must be aDATE
.INT64_expr
must be anINT64
.date_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
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] |
*--------------------------------------------------------------*/
Supplemental materials
OFFSET and ORDINAL
For information about using OFFSET
and ORDINAL
with arrays, see
Array subscript operator and Accessing array
elements.
Bit functions in GoogleSQL
GoogleSQL for Spanner supports the following bit functions.
Function list
Name | Summary |
---|---|
BIT_AND
|
Performs a bitwise AND operation on an expression.
For more information, see Aggregate functions. |
BIT_COUNT
|
Gets the number of bits that are set in an input expression. |
BIT_OR
|
Performs a bitwise OR operation on an expression.
For more information, see Aggregate functions. |
BIT_REVERSE
|
Reverses the bits in an integer. |
BIT_XOR
|
Performs a bitwise XOR operation on an expression.
For more information, see Aggregate functions. |
BIT_COUNT
BIT_COUNT(expression)
Description
The input, expression
, must be an
integer or BYTES
.
Returns the number of bits that are set in the input expression
.
For signed integers, this is the number of bits in two's complement form.
Return Data Type
INT64
Example
SELECT a, BIT_COUNT(a) AS a_bits, FORMAT("%T", b) as b, BIT_COUNT(b) AS b_bits
FROM UNNEST([
STRUCT(0 AS a, b'' AS b), (0, b'\x00'), (5, b'\x05'), (8, b'\x00\x08'),
(0xFFFF, b'\xFF\xFF'), (-2, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFE'),
(-1, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF'),
(NULL, b'\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF\xFF')
]) AS x;
/*-------+--------+---------------------------------------------+--------*
| a | a_bits | b | b_bits |
+-------+--------+---------------------------------------------+--------+
| 0 | 0 | b"" | 0 |
| 0 | 0 | b"\x00" | 0 |
| 5 | 2 | b"\x05" | 2 |
| 8 | 1 | b"\x00\x08" | 1 |
| 65535 | 16 | b"\xff\xff" | 16 |
| -2 | 63 | b"\xff\xff\xff\xff\xff\xff\xff\xfe" | 63 |
| -1 | 64 | b"\xff\xff\xff\xff\xff\xff\xff\xff" | 64 |
| NULL | NULL | b"\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff" | 80 |
*-------+--------+---------------------------------------------+--------*/
BIT_REVERSE
BIT_REVERSE(value, preserve_sign)
Description
Takes an integer value and returns its bit-reversed version. When
preserve_sign
is TRUE
, this function provides the same bit-reversal
algorithm used in bit-reversed sequence. For more information, see
Bit-reversed sequence.
If the input value is NULL
, the function returns NULL
.
Arguments:
value
: The integer to bit reverse.Sequence
only supportsINT64
.preserve_sign
:TRUE
to exclude the sign bit, otherwiseFALSE
.
Return Data Type
The same data type as value
.
Example
SELECT BIT_REVERSE(100, true) AS results
/*---------------------*
| Results |
+---------------------+
| 1369094286720630784 |
*---------------------*/
SELECT BIT_REVERSE(100, false) AS results
/*---------------------*
| Results |
+---------------------+
| 2738188573441261568 |
*---------------------*/
SELECT BIT_REVERSE(-100, true) AS results
/*----------------------*
| Results |
+----------------------+
| -7133701809754865665 |
*----------------------*/
SELECT BIT_REVERSE(-100, false) AS results
/*---------------------*
| Results |
+---------------------+
| 4179340454199820287 |
*---------------------*/
Conversion functions in GoogleSQL
GoogleSQL for Spanner supports conversion functions. These data type conversions are explicit, but some conversions can happen implicitly. You can learn more about implicit and explicit conversion here.
Function list
Name | Summary |
---|---|
ARRAY_TO_STRING
|
Produces a concatenation of the elements in an array as a
STRING value.
For more information, see Array functions. |
BOOL
|
Converts a JSON boolean to a SQL BOOL value.
For more information, see JSON functions. |
BOOL_ARRAY
|
Converts a JSON array of booleans to a
SQL ARRAY<BOOL> value.
For more information, see JSON functions. |
CAST
|
Convert the results of an expression to the given type. |
CODE_POINTS_TO_BYTES
|
Converts an array of extended ASCII code points to a
BYTES value.
For more information, see String aggregate functions. |
CODE_POINTS_TO_STRING
|
Converts an array of extended ASCII code points to a
STRING value.
For more information, see String aggregate functions. |
DATE_FROM_UNIX_DATE
|
Interprets an INT64 expression as the number of days
since 1970-01-01.
For more information, see Date functions. |
FROM_BASE32
|
Converts a base32-encoded STRING value into a
BYTES value.
For more information, see String functions. |
FROM_BASE64
|
Converts a base64-encoded STRING value into a
BYTES value.
For more information, see String functions. |
FROM_HEX
|
Converts a hexadecimal-encoded STRING value into a
BYTES value.
For more information, see String functions. |
INT64
|
Converts a JSON number to a SQL INT64 value.
For more information, see JSON functions. |
INT64_ARRAY
|
Converts a JSON array of numbers to a
SQL ARRAY<INT64> value.
For more information, see JSON functions. |
LAX_BOOL
|
Attempts to convert a JSON value to a SQL BOOL value.
For more information, see JSON functions. |
LAX_FLOAT64
|
Attempts to convert a JSON value to a
SQL FLOAT64 value.
For more information, see JSON functions. |
LAX_INT64
|
Attempts to convert a JSON value to a SQL INT64 value.
For more information, see JSON functions. |
LAX_STRING
|
Attempts to convert a JSON value to a SQL STRING value.
For more information, see JSON functions. |
PARSE_DATE
|
Converts a STRING value to a DATE value.
For more information, see Date functions. |
PARSE_JSON
|
Converts a JSON-formatted STRING value to a
JSON value.
For more information, see JSON functions. |
PARSE_TIMESTAMP
|
Converts a STRING value to a TIMESTAMP value.
For more information, see Timestamp functions. |
SAFE_CAST
|
Similar to the CAST function, but returns NULL
when a runtime error is produced.
|
SAFE_CONVERT_BYTES_TO_STRING
|
Converts a BYTES value to a STRING value and
replace any invalid UTF-8 characters with the Unicode replacement character,
U+FFFD .
For more information, see String functions. |
STRING (JSON)
|
Converts a JSON string to a SQL STRING value.
For more information, see JSON functions. |
STRING_ARRAY
|
Converts a JSON array of strings to a SQL ARRAY<STRING>
value.
For more information, see JSON functions. |
STRING (Timestamp)
|
Converts a TIMESTAMP value to a STRING value.
For more information, see Timestamp functions. |
TIMESTAMP_MICROS
|
Converts the number of microseconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
For more information, see Timestamp functions. |
TIMESTAMP_MILLIS
|
Converts the number of milliseconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
For more information, see Timestamp functions. |
TIMESTAMP_SECONDS
|
Converts the number of seconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
For more information, see Timestamp functions. |
TO_BASE32
|
Converts a BYTES value to a
base32-encoded STRING value.
For more information, see String functions. |
TO_BASE64
|
Converts a BYTES value to a
base64-encoded STRING value.
For more information, see String functions. |
TO_CODE_POINTS
|
Converts a STRING or BYTES value into an array of
extended ASCII code points.
For more information, see String functions. |
TO_HEX
|
Converts a BYTES value to a
hexadecimal STRING value.
For more information, see String functions. |
TO_JSON
|
Converts a SQL value to a JSON value.
For more information, see JSON functions. |
TO_JSON_STRING
|
Converts a JSON value to a
SQL JSON-formatted STRING value.
For more information, see JSON functions. |
UNIX_DATE
|
Converts a DATE value to the number of days since 1970-01-01.
For more information, see Date functions. |
UNIX_MICROS
|
Converts a TIMESTAMP value to the number of microseconds since
1970-01-01 00:00:00 UTC.
For more information, see Timestamp functions. |
UNIX_MILLIS
|
Converts a TIMESTAMP value to the number of milliseconds
since 1970-01-01 00:00:00 UTC.
For more information, see Timestamp functions. |
UNIX_SECONDS
|
Converts a TIMESTAMP value to the number of seconds since
1970-01-01 00:00:00 UTC.
For more information, see Timestamp functions. |
CAST
CAST(expression AS typename)
Description
Cast syntax is used in a query to indicate that the result type of an expression should be converted to some other type.
When using CAST
, a query can fail if GoogleSQL is unable to perform
the cast. If you want to protect your queries from these types of errors, you
can use SAFE_CAST.
Casts between supported types that do not successfully map from the original
value to the target domain produce runtime errors. For example, casting
BYTES
to STRING
where the byte sequence is not valid UTF-8 results in a
runtime error.
Examples
The following query results in "true"
if x
is 1
, "false"
for any other
non-NULL
value, and NULL
if x
is NULL
.
CAST(x=1 AS STRING)
CAST AS ARRAY
CAST(expression AS ARRAY<element_type>)
Description
GoogleSQL supports casting to ARRAY
. The
expression
parameter can represent an expression for these data types:
ARRAY
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
ARRAY |
ARRAY |
Must be the exact same array type. |
CAST AS BOOL
CAST(expression AS BOOL)
Description
GoogleSQL supports casting to BOOL
. The
expression
parameter can represent an expression for these data types:
INT64
BOOL
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
INT64 | BOOL |
Returns FALSE if x is 0 ,
TRUE otherwise.
|
STRING |
BOOL |
Returns TRUE if x is "true" and
FALSE if x is "false" All other values of x are invalid and throw an error instead
of casting to a boolean.A string is case-insensitive when converting to a boolean. |
CAST AS BYTES
CAST(expression AS BYTES)
Description
GoogleSQL supports casting to BYTES
. The
expression
parameter can represent an expression for these data types:
BYTES
STRING
PROTO
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRING |
BYTES |
Strings are cast to bytes using UTF-8 encoding. For example, the string "©", when cast to bytes, would become a 2-byte sequence with the hex values C2 and A9. |
PROTO |
BYTES |
Returns the proto2 wire format bytes
of x .
|
CAST AS DATE
CAST(expression AS DATE)
Description
GoogleSQL supports casting to DATE
. The expression
parameter can represent an expression for these data types:
STRING
TIMESTAMP
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRING |
DATE |
When casting from string to date, the string must conform to the supported date literal format, and is independent of time zone. If the string expression is invalid or represents a date that is outside of the supported min/max range, then an error is produced. |
TIMESTAMP |
DATE |
Casting from a timestamp to date effectively truncates the timestamp as of the default time zone. |
CAST AS ENUM
CAST(expression AS ENUM)
Description
GoogleSQL supports casting to ENUM
. The expression
parameter can represent an expression for these data types:
INT64
STRING
ENUM
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
ENUM |
ENUM |
Must have the same enum name. |
CAST AS Floating Point
CAST(expression AS FLOAT64)
CAST(expression AS FLOAT32)
Description
GoogleSQL supports casting to floating point types.
The expression
parameter can represent an expression for these data types:
INT64
FLOAT32
FLOAT64
NUMERIC
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
INT64 | Floating Point | Returns a close but potentially not exact floating point value. |
NUMERIC |
Floating Point |
NUMERIC will convert to the closest floating point number
with a possible loss of precision.
|
STRING |
Floating Point |
Returns x as a floating point value, interpreting it as
having the same form as a valid floating point literal.
Also supports casts from "[+,-]inf" to
[,-]Infinity ,
"[+,-]infinity" to [,-]Infinity , and
"[+,-]nan" to NaN .
Conversions are case-insensitive.
|
CAST AS INT64
CAST(expression AS INT64)
Description
GoogleSQL supports casting to integer types.
The expression
parameter can represent an expression for these data types:
INT64
FLOAT32
FLOAT64
NUMERIC
ENUM
BOOL
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
Floating Point | INT64 |
Returns the closest integer value. Halfway cases such as 1.5 or -0.5 round away from zero. |
BOOL |
INT64 |
Returns 1 if x is TRUE ,
0 otherwise.
|
STRING |
INT64 |
A hex string can be cast to an integer. For example,
0x123 to 291 or -0x123 to
-291 .
|
Examples
If you are working with hex strings (0x123
), you can cast those strings as
integers:
SELECT '0x123' as hex_value, CAST('0x123' as INT64) as hex_to_int;
/*-----------+------------*
| hex_value | hex_to_int |
+-----------+------------+
| 0x123 | 291 |
*-----------+------------*/
SELECT '-0x123' as hex_value, CAST('-0x123' as INT64) as hex_to_int;
/*-----------+------------*
| hex_value | hex_to_int |
+-----------+------------+
| -0x123 | -291 |
*-----------+------------*/
CAST AS NUMERIC
CAST(expression AS NUMERIC)
Description
GoogleSQL supports casting to NUMERIC
. The
expression
parameter can represent an expression for these data types:
INT64
FLOAT32
FLOAT64
NUMERIC
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
Floating Point |
NUMERIC |
The floating point number will round
half away from zero.
Casting a NaN , +inf or
-inf will return an error. Casting a value outside the range
of NUMERIC returns an overflow error.
|
STRING |
NUMERIC |
The numeric literal contained in the string must not exceed
the maximum precision or range of the NUMERIC
type, or an error will occur. If the number of digits
after the decimal point exceeds nine, then the resulting
NUMERIC value will round
half away from zero.
to have nine digits after the decimal point.
|
CAST AS PROTO
CAST(expression AS PROTO)
Description
GoogleSQL supports casting to PROTO
. The
expression
parameter can represent an expression for these data types:
STRING
BYTES
PROTO
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRING |
PROTO |
Returns the protocol buffer that results from parsing
from proto2 text format. Throws an error if parsing fails, e.g., if not all required fields are set. |
BYTES |
PROTO |
Returns the protocol buffer that results from parsing
x from the proto2 wire format.Throws an error if parsing fails, e.g., if not all required fields are set. |
PROTO |
PROTO |
Must have the same protocol buffer name. |
Example
This example references a protocol buffer called Award
.
message Award {
required int32 year = 1;
optional int32 month = 2;
repeated Type type = 3;
message Type {
optional string award_name = 1;
optional string category = 2;
}
}
SELECT
CAST(
'''
year: 2001
month: 9
type { award_name: 'Best Artist' category: 'Artist' }
type { award_name: 'Best Album' category: 'Album' }
'''
AS googlesql.examples.music.Award)
AS award_col
/*---------------------------------------------------------*
| award_col |
+---------------------------------------------------------+
| { |
| year: 2001 |
| month: 9 |
| type { award_name: "Best Artist" category: "Artist" } |
| type { award_name: "Best Album" category: "Album" } |
| } |
*---------------------------------------------------------*/
CAST AS STRING
CAST(expression AS STRING)
Description
GoogleSQL supports casting to STRING
. The
expression
parameter can represent an expression for these data types:
INT64
FLOAT32
FLOAT64
NUMERIC
ENUM
BOOL
BYTES
PROTO
DATE
TIMESTAMP
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
Floating Point | STRING |
Returns an approximate string representation. A returned
NaN or 0 will not be signed. |
BOOL |
STRING |
Returns "true" if x is TRUE ,
"false" otherwise. |
BYTES |
STRING |
Returns x interpreted as a UTF-8 string.For example, the bytes literal b'\xc2\xa9' , when cast to a string,
is interpreted as UTF-8 and becomes the unicode character "©".An error occurs if x is not valid UTF-8. |
ENUM |
STRING |
Returns the canonical enum value name of
x .If an enum value has multiple names (aliases), the canonical name/alias for that value is used. |
PROTO |
STRING |
Returns the proto2 text format representation of x . |
DATE |
STRING |
Casting from a date type to a string is independent of time zone and is
of the form YYYY-MM-DD .
|
TIMESTAMP |
STRING |
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. |
Examples
SELECT CAST(CURRENT_DATE() AS STRING) AS current_date
/*---------------*
| current_date |
+---------------+
| 2021-03-09 |
*---------------*/
CAST AS STRUCT
CAST(expression AS STRUCT)
Description
GoogleSQL supports casting to STRUCT
. The
expression
parameter can represent an expression for these data types:
STRUCT
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRUCT |
STRUCT |
Allowed if the following conditions are met:
|
CAST AS TIMESTAMP
CAST(expression AS TIMESTAMP)
Description
GoogleSQL supports casting to TIMESTAMP
. The
expression
parameter can represent an expression for these data types:
STRING
TIMESTAMP
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRING |
TIMESTAMP |
When casting from string to a timestamp, string_expression
must conform to the supported timestamp literal formats, or else a runtime
error occurs. The string_expression may itself contain a
time zone.
If there is a time zone in the string_expression , that
time zone is used for conversion, otherwise the default time zone,
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.
|
DATE |
TIMESTAMP |
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.
|
Examples
The following example casts a string-formatted timestamp as a timestamp:
SELECT CAST("2020-06-02 17:00:53.110+00:00" AS TIMESTAMP) AS as_timestamp
-- Results depend upon where this query was executed.
/*-------------------------*
| as_timestamp |
+-------------------------+
| 2020-06-03T00:00:53.11Z |
*-------------------------*/
SAFE_CAST
SAFE_CAST(expression AS typename)
Description
When using CAST
, a query can fail if GoogleSQL is unable to perform
the cast. For example, the following query generates an error:
SELECT CAST("apple" AS INT64) AS not_a_number;
If you want to protect your queries from these types of errors, you can use
SAFE_CAST
. SAFE_CAST
replaces runtime errors with NULL
s. However, during
static analysis, impossible casts between two non-castable types still produce
an error because the query is invalid.
SELECT SAFE_CAST("apple" AS INT64) AS not_a_number;
/*--------------*
| not_a_number |
+--------------+
| NULL |
*--------------*/
If you are casting from bytes to strings, you can also use the
function, SAFE_CONVERT_BYTES_TO_STRING
. Any invalid UTF-8 characters
are replaced with the unicode replacement character, U+FFFD
.
Date functions in GoogleSQL
GoogleSQL for Spanner supports the following date functions.
Function list
Name | Summary |
---|---|
CURRENT_DATE
|
Returns the current date as a DATE value.
|
DATE
|
Constructs a DATE value.
|
DATE_ADD
|
Adds a specified time interval to a DATE value.
|
DATE_DIFF
|
Gets the number of unit boundaries between two DATE values
at a particular time granularity.
|
DATE_FROM_UNIX_DATE
|
Interprets an INT64 expression as the number of days
since 1970-01-01.
|
DATE_SUB
|
Subtracts a specified time interval from a DATE value.
|
DATE_TRUNC
|
Truncates a DATE value at a particular granularity.
|
EXTRACT
|
Extracts part of a date from a DATE value.
|
FORMAT_DATE
|
Formats a DATE value according to a specified format string.
|
GENERATE_DATE_ARRAY
|
Generates an array of dates in a range.
For more information, see Array functions. |
PARSE_DATE
|
Converts a STRING value to a DATE value.
|
UNIX_DATE
|
Converts a DATE value to the number of days since 1970-01-01.
|
CURRENT_DATE
CURRENT_DATE()
CURRENT_DATE(time_zone_expression)
CURRENT_DATE
Description
Returns the current date as a DATE
object. Parentheses are optional when
called with no arguments.
This function supports the following arguments:
time_zone_expression
: ASTRING
expression that represents a time zone. If no time zone is specified, the default time zone, America/Los_Angeles, is used. If this expression is used and it evaluates toNULL
, this function returnsNULL
.
The current date is recorded at the start of the query statement which contains this function, not when this specific function is evaluated.
Return Data Type
DATE
Examples
The following query produces the current date in the default time zone:
SELECT CURRENT_DATE() AS the_date;
/*--------------*
| the_date |
+--------------+
| 2016-12-25 |
*--------------*/
The following queries produce the current date in a specified time zone:
SELECT CURRENT_DATE('America/Los_Angeles') AS the_date;
/*--------------*
| the_date |
+--------------+
| 2016-12-25 |
*--------------*/
SELECT CURRENT_DATE('-08') AS the_date;
/*--------------*
| the_date |
+--------------+
| 2016-12-25 |
*--------------*/
The following query produces the current date in the default time zone. Parentheses are not needed if the function has no arguments.
SELECT CURRENT_DATE AS the_date;
/*--------------*
| the_date |
+--------------+
| 2016-12-25 |
*--------------*/
DATE
DATE(year, month, day)
DATE(timestamp_expression)
DATE(timestamp_expression, time_zone_expression)
Description
Constructs or extracts a date.
This function supports the following arguments:
year
: TheINT64
value for year.month
: TheINT64
value for month.day
: TheINT64
value for day.timestamp_expression
: ATIMESTAMP
expression that contains the date.time_zone_expression
: ASTRING
expression that represents a time zone. If no time zone is specified withtimestamp_expression
, the default time zone, 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_expression 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 resulting date is the last date of that 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_DIFF
DATE_DIFF(end_date, start_date, granularity)
Description
Gets the number of unit boundaries between two DATE
values (end_date
-
start_date
) at a particular time granularity.
Definitions
start_date
: The startingDATE
value.end_date
: The endingDATE
value.granularity
: The date part that represents the granularity. This can be:DAY
WEEK
This date part begins on Sunday.ISOWEEK
: Uses ISO 8601 week boundaries. ISO weeks begin on Monday.MONTH
QUARTER
YEAR
ISOYEAR
: Uses the ISO 8601 week-numbering year boundary. The ISO year boundary is the Monday of the first week whose Thursday belongs to the corresponding Gregorian calendar year.
Details
If end_date
is earlier than start_date
, the output is negative.
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.
The following example shows the result of DATE_DIFF
for two dates in different
years. DATE_DIFF
with the date part YEAR
returns 3 because it counts the
number of Gregorian calendar year boundaries between the two dates. DATE_DIFF
with the date part ISOYEAR
returns 2 because the second date belongs to the
ISO year 2015. The first Thursday of the 2015 calendar year was 2015-01-01, so
the ISO year 2015 begins on the preceding Monday, 2014-12-29.
SELECT
DATE_DIFF('2017-12-30', '2014-12-30', YEAR) AS year_diff,
DATE_DIFF('2017-12-30', '2014-12-30', ISOYEAR) AS isoyear_diff;
/*-----------+--------------*
| year_diff | isoyear_diff |
+-----------+--------------+
| 3 | 2 |
*-----------+--------------*/
The following example shows the result of DATE_DIFF
for two days in
succession. The first date falls on a Monday and the second date falls on a
Sunday. DATE_DIFF
with the date part WEEK
returns 0 because this date part
uses weeks that begin on Sunday. DATE_DIFF
with the date part ISOWEEK
returns 1 because ISO weeks begin on Monday.
SELECT
DATE_DIFF('2017-12-18', '2017-12-17', WEEK) AS week_diff,
DATE_DIFF('2017-12-18', '2017-12-17', ISOWEEK) AS isoweek_diff;
/*-----------+--------------*
| week_diff | isoweek_diff |
+-----------+--------------+
| 0 | 1 |
*-----------+--------------*/
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 |
*-----------------+*/
DATE_SUB
DATE_SUB(date_expression, INTERVAL int64_expression 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 resulting date is the last date of that 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_TRUNC
DATE_TRUNC(date_value, date_granularity)
Description
Truncates a DATE
value at a particular granularity.
Definitions
date_value
: ADATE
value to truncate.date_granularity
: The truncation granularity for aDATE
value. Date granularities can be used.
Date granularity definitions
DAY
: The day in the Gregorian calendar year that contains the value to truncate.WEEK
: The first day in the week that contains the value to truncate. Weeks begin on Sundays.WEEK
is equivalent toWEEK(SUNDAY)
.ISOWEEK
: The first day in the ISO 8601 week that contains the value to truncate. The ISO week begins on Monday. The first ISO week of each ISO year contains the first Thursday of the corresponding Gregorian calendar year.MONTH
: The first day in the month that contains the value to truncate.QUARTER
: The first day in the quarter that contains the value to truncate.YEAR
: The first day in the year that contains the value to truncate.ISOYEAR
: The first day in the ISO 8601 week-numbering year that contains the value to truncate. The ISO year is the Monday of the first week where Thursday belongs to the corresponding Gregorian calendar year.
Details
The resulting value is always rounded to the beginning of granularity
.
Return Data Type
DATE
Examples
SELECT DATE_TRUNC(DATE '2008-12-25', MONTH) AS month;
/*------------*
| month |
+------------+
| 2008-12-01 |
*------------*/
In the following example, the original date_expression
is in the Gregorian
calendar year 2015. However, DATE_TRUNC
with the ISOYEAR
date part
truncates the date_expression
to the beginning of the ISO year, not the
Gregorian calendar year. The first Thursday of the 2015 calendar year was
2015-01-01, so the ISO year 2015 begins on the preceding Monday, 2014-12-29.
Therefore the ISO year boundary preceding the date_expression
2015-06-15 is
2014-12-29.
SELECT
DATE_TRUNC('2015-06-15', ISOYEAR) AS isoyear_boundary,
EXTRACT(ISOYEAR FROM DATE '2015-06-15') AS isoyear_number;
/*------------------+----------------*
| isoyear_boundary | isoyear_number |
+------------------+----------------+
| 2014-12-29 | 2015 |
*------------------+----------------*/
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
date 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
date 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 |
*------------+---------+---------+------+------*/
FORMAT_DATE
FORMAT_DATE(format_string, date_expr)
Description
Formats a DATE
value according to a specified format string.
Definitions
format_string
: ASTRING
value that contains the format elements to use withdate_expr
.date_expr
: ADATE
value that represents the date to format.
Return Data Type
STRING
Examples
SELECT FORMAT_DATE('%x', DATE '2008-12-25') AS US_format;
/*------------*
| US_format |
+------------+
| 12/25/08 |
*------------*/
SELECT FORMAT_DATE('%b-%d-%Y', DATE '2008-12-25') AS formatted;
/*-------------*
| formatted |
+-------------+
| Dec-25-2008 |
*-------------*/
SELECT FORMAT_DATE('%b %Y', DATE '2008-12-25') AS formatted;
/*-------------*
| formatted |
+-------------+
| Dec 2008 |
*-------------*/
PARSE_DATE
PARSE_DATE(format_string, date_string)
Description
Converts a STRING
value to a DATE
value.
Definitions
format_string
: ASTRING
value that contains the format elements to use withdate_string
.date_string
: ASTRING
value that represents the date to parse.
Details
Each element in date_string
must have a corresponding element in
format_string
. The location of each element in format_string
must match the
location of each element in date_string
.
-- This works because elements on both sides match.
SELECT PARSE_DATE('%A %b %e %Y', 'Thursday Dec 25 2008');
-- This produces an error because the year element is in different locations.
SELECT PARSE_DATE('%Y %A %b %e', 'Thursday Dec 25 2008');
-- This produces an error because one of the year elements is missing.
SELECT PARSE_DATE('%A %b %e', 'Thursday Dec 25 2008');
-- This works because %F can find all matching elements in date_string.
SELECT PARSE_DATE('%F', '2000-12-30');
The format string fully supports most format elements except for
%g
, %G
, %j
, %u
, %U
, %V
, %w
, and %W
.
When using PARSE_DATE
, keep the following in mind:
- Unspecified fields. Any unspecified field is initialized from
1970-01-01
. - Case insensitivity. 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.
Return Data Type
DATE
Examples
This example converts a MM/DD/YY
formatted string to a DATE
object:
SELECT PARSE_DATE('%x', '12/25/08') AS parsed;
/*------------*
| parsed |
+------------+
| 2008-12-25 |
*------------*/
This example converts a YYYYMMDD
formatted string to a DATE
object:
SELECT PARSE_DATE('%Y%m%d', '20081225') 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 |
*-----------------*/
Debugging functions in GoogleSQL
GoogleSQL for Spanner supports the following debugging functions.
Function list
Name | Summary |
---|---|
ERROR
|
Produces an error with a custom error message. |
ERROR
ERROR(error_message)
Description
Returns an error.
Definitions
error_message
: ASTRING
value that represents the error message to produce. Any whitespace characters beyond a single space are trimmed from the results.
Details
ERROR
is treated like any other expression that may
result in an error: there is no special guarantee of evaluation order.
Return Data Type
GoogleSQL infers the return type in context.
Examples
In the following example, the query produces an error message:
-- ERROR: Show this error message (while evaluating error("Show this error message"))
SELECT ERROR('Show this error message')
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, GoogleSQL 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 GoogleSQL 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
GQL functions
GoogleSQL for Spanner supports the following GQL functions:
Function list
Name | Summary |
---|---|
DESTINATION_NODE_ID
|
Gets a unique identifier of a graph edge's destination node. |
ELEMENT_ID
|
Gets a graph element's unique identifier. |
LABELS
|
Gets the labels associated with a graph element. |
PROPERTY_NAMES
|
Gets the property names associated with a graph element. |
SOURCE_NODE_ID
|
Gets a unique identifier of a graph edge's source node. |
DESTINATION_NODE_ID
DESTINATION_NODE_ID(edge_element)
Description
Gets a unique identifier of a graph edge's destination node. The unique identifier is only valid for the scope of the query where it is obtained.
Arguments
edge_element
: AGRAPH_ELEMENT
value that represents an edge.
Details
Returns NULL
if edge_element
is NULL
.
Return type
STRING
Examples
GRAPH FinGraph
MATCH (:Person)-[o:Owns]->(a:Account)
RETURN a.id AS account_id, DESTINATION_NODE_ID(o) AS destination_node_id
/*------------------------------------------+
|account_id | destination_node_id |
+-----------|------------------------------+
| 7 | mUZpbkdyYXBoLkFjY291bnQAeJEO |
| 16 | mUZpbkdyYXBoLkFjY291bnQAeJEg |
| 20 | mUZpbkdyYXBoLkFjY291bnQAeJEo |
+------------------------------------------*/
Note that the actual identifiers obtained may be different from what's shown above.
ELEMENT_ID
ELEMENT_ID(element)
Description
Gets a graph element's unique identifier. The unique identifier is only valid for the scope of the query where it is obtained.
Arguments
element
: AGRAPH_ELEMENT
value.
Details
Returns NULL
if element
is NULL
.
Return type
STRING
Examples
GRAPH FinGraph
MATCH (p:Person)-[o:Owns]->(:Account)
RETURN p.name AS name, ELEMENT_ID(p) AS node_element_id, ELEMENT_ID(o) AS edge_element_id
/*--------------------------------------------------------------------------------------------------------------------------------------------+
| name | node_element_id | edge_element_id . |
+------|------------------------------|------------------------------------------------------------------------------------------------------+
| Alex | mUZpbkdyYXBoLlBlcnNvbgB4kQI= | mUZpbkdyYXBoLlBlcnNvbk93bkFjY291bnQAeJECkQ6ZRmluR3JhcGguUGVyc29uAHiRAplGaW5HcmFwaC5BY2NvdW50AHiRDg== |
| Dana | mUZpbkdyYXBoLlBlcnNvbgB4kQQ= | mUZpbkdyYXBoLlBlcnNvbk93bkFjY291bnQAeJEGkSCZRmluR3JhcGguUGVyc29uAHiRBplGaW5HcmFwaC5BY2NvdW50AHiRIA== |
| Lee | mUZpbkdyYXBoLlBlcnNvbgB4kQY= | mUZpbkdyYXBoLlBlcnNvbk93bkFjY291bnQAeJEEkSiZRmluR3JhcGguUGVyc29uAHiRBJlGaW5HcmFwaC5BY2NvdW50AHiRKA== |
+--------------------------------------------------------------------------------------------------------------------------------------------*/
Note that the actual identifiers obtained may be different from what's shown above.
LABELS
LABELS(element)
Description
Gets the labels associated with a graph element and preserves the original case of each label.
Arguments
element
: AGRAPH_ELEMENT
value.
Details
Returns NULL
if element
is NULL
.
Return type
ARRAY<STRING>
Examples
GRAPH FinGraph
MATCH (n:Person|Account)
RETURN LABELS(n) AS label, n.id
/*----------------+
| label | id |
+----------------+
| [Account] | 7 |
| [Account] | 16 |
| [Account] | 20 |
| [Person] | 1 |
| [Person] | 2 |
| [Person] | 3 |
+----------------*/
PROPERTY_NAMES
PROPERTY_NAMES(element)
Description
Gets the name of each property associated with a graph element and preserves the original case of each name.
Arguments
element
: AGRAPH_ELEMENT
value.
Details
Returns NULL
if element
is NULL
.
Return type
ARRAY<STRING>
Examples
GRAPH FinGraph
MATCH (n:Person|Account)
RETURN PROPERTY_NAMES(n) AS property_names, n.id
/*-----------------------------------------------+
| label | id |
+-----------------------------------------------+
| [create_time, id, is_blocked, nick_name] | 7 |
| [create_time, id, is_blocked, nick_name] | 16 |
| [create_time, id, is_blocked, nick_name] | 20 |
| [birthday, city, country, id, name] | 1 |
| [birthday, city, country, id, name] | 2 |
| [birthday, city, country, id, name] | 3 |
+-----------------------------------------------*/
SOURCE_NODE_ID
SOURCE_NODE_ID(edge_element)
Description
Gets a unique identifier of a graph edge's source node. The unique identifier is only valid for the scope of the query where it is obtained.
Arguments
edge_element
: AGRAPH_ELEMENT
value that represents an edge.
Details
Returns NULL
if edge_element
is NULL
.
Return type
STRING
Examples
GRAPH FinGraph
MATCH (p:Person)-[o:Owns]->(:Account)
RETURN p.name AS name, SOURCE_NODE_ID(o) AS source_node_id
/*-------------------------------------+
| name | source_node_id |
+------|------------------------------+
| Alex | mUZpbkdyYXBoLlBlcnNvbgB4kQI= |
| Dana | mUZpbkdyYXBoLlBlcnNvbgB4kQQ= |
| Lee | mUZpbkdyYXBoLlBlcnNvbgB4kQY= |
+-------------------------------------*/
Note that the actual identifiers obtained may be different from what's shown above.
Hash functions in GoogleSQL
GoogleSQL for Spanner supports the following hash functions.
Function list
Name | Summary |
---|---|
FARM_FINGERPRINT
|
Computes the fingerprint of a STRING or
BYTES value, using the FarmHash Fingerprint64 algorithm.
|
SHA1
|
Computes the hash of a STRING or
BYTES value, using the SHA-1 algorithm.
|
SHA256
|
Computes the hash of a STRING or
BYTES value, using the SHA-256 algorithm.
|
SHA512
|
Computes the hash of a STRING or
BYTES value, using the SHA-512 algorithm.
|
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;
-- Note that the result of SHA1 is of type BYTES, displayed as a base64-encoded string.
/*------------------------------*
| sha1 |
+------------------------------+
| Ck1VqNd45QIvq3AZd8XYQLvEhtA= |
*------------------------------*/
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;
JSON functions in GoogleSQL
GoogleSQL for Spanner supports the following functions, which can retrieve and transform JSON data.
Categories
The JSON functions are grouped into the following categories based on their behavior:
Category | Functions | Description |
Extractors |
JSON_QUERY JSON_VALUE JSON_QUERY_ARRAY JSON_VALUE_ARRAY |
Functions that extract JSON data. |
Lax converters |
LAX_BOOL LAX_FLOAT64 LAX_INT64 LAX_STRING |
Functions that flexibly convert a JSON value to a SQL value without returning errors. |
Converters |
BOOL BOOL_ARRAY FLOAT64 FLOAT64_ARRAY FLOAT32 FLOAT32_ARRAY INT64 INT64_ARRAY STRING STRING_ARRAY |
Functions that convert a JSON value to a SQL value. |
Other converters |
PARSE_JSON TO_JSON SAFE_TO_JSON TO_JSON_STRING |
Other conversion functions from or to JSON. |
Constructors |
JSON_ARRAY JSON_OBJECT |
Functions that create JSON. |
Accessors |
JSON_TYPE |
Functions that provide access to JSON properties. |
Function list
Name | Summary |
---|---|
BOOL
|
Converts a JSON boolean to a SQL BOOL value.
|
BOOL_ARRAY
|
Converts a JSON array of booleans to a
SQL ARRAY<BOOL> value.
|
FLOAT64
|
Converts a JSON number to a SQL
FLOAT64 value.
|
FLOAT64_ARRAY
|
Converts a JSON array of numbers to a SQL ARRAY<FLOAT64> value. |
FLOAT32
|
Converts a JSON number to a SQL FLOAT32 value. |
FLOAT32_ARRAY
|
Converts a JSON array of numbers to a SQL ARRAY<FLOAT32> value. |
INT64
|
Converts a JSON number to a SQL INT64 value.
|
INT64_ARRAY
|
Converts a JSON array of numbers to a
SQL ARRAY<INT64> value.
|
JSON_ARRAY
|
Creates a JSON array. |
JSON_OBJECT
|
Creates a JSON object. |
JSON_QUERY
|
Extracts a JSON value and converts it to a SQL
JSON-formatted STRING
or
JSON
value.
|
JSON_QUERY_ARRAY
|
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
or
ARRAY<JSON>
value.
|
JSON_TYPE
|
Gets the JSON type of the outermost JSON value and converts the name of
this type to a SQL STRING value.
|
JSON_VALUE
|
Extracts a JSON scalar value and converts it to a SQL
STRING value.
|
JSON_VALUE_ARRAY
|
Extracts a JSON array of scalar values and converts it to a SQL
ARRAY<STRING> value.
|
LAX_BOOL
|
Attempts to convert a JSON value to a SQL BOOL value.
|
LAX_FLOAT64
|
Attempts to convert a JSON value to a
SQL FLOAT64 value.
|
LAX_INT64
|
Attempts to convert a JSON value to a SQL INT64 value.
|
LAX_STRING
|
Attempts to convert a JSON value to a SQL STRING value.
|
PARSE_JSON
|
Converts a JSON-formatted STRING value to a
JSON value.
|
SAFE_TO_JSON
|
Similar to the `TO_JSON` function, but for each unsupported field in the input argument, produces a JSON null instead of an error. |
STRING (JSON)
|
Converts a JSON string to a SQL STRING value.
|
STRING_ARRAY
|
Converts a JSON array of strings to a SQL ARRAY<STRING>
value.
|
TO_JSON
|
Converts a SQL value to a JSON value. |
TO_JSON_STRING
|
Converts a JSON value to a
SQL JSON-formatted STRING value.
|
BOOL
BOOL(json_expr)
Description
Converts a JSON boolean to a SQL BOOL
value.
Arguments:
json_expr
: JSON. For example:JSON 'true'
If the JSON value is not a boolean, an error is produced. If the expression is SQL
NULL
, the function returns SQLNULL
.
Return type
BOOL
Examples
SELECT BOOL(JSON 'true') AS vacancy;
/*---------*
| vacancy |
+---------+
| true |
*---------*/
SELECT BOOL(JSON_QUERY(JSON '{"hotel class": "5-star", "vacancy": true}', "$.vacancy")) AS vacancy;
/*---------*
| vacancy |
+---------+
| true |
*---------*/
The following examples show how invalid requests are handled:
-- An error is thrown if JSON is not of type bool.
SELECT BOOL(JSON '123') AS result; -- Throws an error
SELECT BOOL(JSON 'null') AS result; -- Throws an error
SELECT SAFE.BOOL(JSON '123') AS result; -- Returns a SQL NULL
BOOL_ARRAY
BOOL_ARRAY(json_expr)
Description
Converts a JSON array of booleans to a SQL ARRAY<BOOL>
value.
Arguments:
json_expr
: JSON. For example:JSON '[true]'
If the JSON value is not an array of booleans, an error is produced. If the expression is SQL
NULL
, the function returns SQLNULL
.
Return type
ARRAY<BOOL>
Examples
SELECT BOOL_ARRAY(JSON '[true, false]') AS vacancies;
/*---------------*
| vacancies |
+---------------+
| [true, false] |
*---------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not an array of booleans.
SELECT BOOL_ARRAY(JSON '[123]') AS result; -- Throws an error
SELECT BOOL_ARRAY(JSON '[null]') AS result; -- Throws an error
SELECT BOOL_ARRAY(JSON 'null') AS result; -- Throws an error
FLOAT64
FLOAT64(
json_expr
[, wide_number_mode => { 'exact' | 'round' } ]
)
Description
Converts a JSON number to a SQL FLOAT64
value.
Arguments:
json_expr
: JSON. For example:JSON '9.8'
If the JSON value is not a number, an error is produced. If the expression is a SQL
NULL
, the function returns SQLNULL
.wide_number_mode
: A named argument with aSTRING
value. Defines what happens with a number that can't be represented as aFLOAT64
without loss of precision. This argument accepts one of the two case-sensitive values:exact
: The function fails if the result cannot be represented as aFLOAT64
without loss of precision.round
(default): The numeric value stored in JSON will be rounded toFLOAT64
. If such rounding is not possible, the function fails.
Return type
FLOAT64
Examples
SELECT FLOAT64(JSON '9.8') AS velocity;
/*----------*
| velocity |
+----------+
| 9.8 |
*----------*/
SELECT FLOAT64(JSON_QUERY(JSON '{"vo2_max": 39.1, "age": 18}', "$.vo2_max")) AS vo2_max;
/*---------*
| vo2_max |
+---------+
| 39.1 |
*---------*/
SELECT FLOAT64(JSON '18446744073709551615', wide_number_mode=>'round') as result;
/*------------------------*
| result |
+------------------------+
| 1.8446744073709552e+19 |
*------------------------*/
SELECT FLOAT64(JSON '18446744073709551615') as result;
/*------------------------*
| result |
+------------------------+
| 1.8446744073709552e+19 |
*------------------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if JSON is not of type FLOAT64.
SELECT FLOAT64(JSON '"strawberry"') AS result;
SELECT FLOAT64(JSON 'null') AS result;
-- An error is thrown because `wide_number_mode` is case-sensitive and not "exact" or "round".
SELECT FLOAT64(JSON '123.4', wide_number_mode=>'EXACT') as result;
SELECT FLOAT64(JSON '123.4', wide_number_mode=>'exac') as result;
-- An error is thrown because the number cannot be converted to DOUBLE without loss of precision
SELECT FLOAT64(JSON '18446744073709551615', wide_number_mode=>'exact') as result;
-- Returns a SQL NULL
SELECT SAFE.FLOAT64(JSON '"strawberry"') AS result;
FLOAT64_ARRAY
FLOAT64_ARRAY(
json_expr
[, wide_number_mode => { 'exact' | 'round' } ]
)
Description
Converts a JSON array of numbers to a SQL ARRAY<FLOAT64>
value.
Arguments:
json_expr
: JSON. For example:JSON '[9.8]'
If the JSON value is not an array of numbers, an error is produced. If the expression is a SQL
NULL
, the function returns SQLNULL
.wide_number_mode
: A named argument that takes aSTRING
value. Defines what happens with a number that can't be represented as aFLOAT64
without loss of precision. This argument accepts one of the two case-sensitive values:exact
: The function fails if the result cannot be represented as aFLOAT64
without loss of precision.round
(default): The numeric value stored in JSON will be rounded toFLOAT64
. If such rounding is not possible, the function fails.
Return type
ARRAY<FLOAT64>
Examples
SELECT FLOAT64_ARRAY(JSON '[9, 9.8]') AS velocities;
/*-------------*
| velocities |
+-------------+
| [9.0, 9.8] |
*-------------*/
SELECT FLOAT64_ARRAY(JSON '[18446744073709551615]', wide_number_mode=>'round') as result;
/*--------------------------*
| result |
+--------------------------+
| [1.8446744073709552e+19] |
*--------------------------*/
SELECT FLOAT64_ARRAY(JSON '[18446744073709551615]') as result;
/*--------------------------*
| result |
+--------------------------+
| [1.8446744073709552e+19] |
*--------------------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not an array of numbers.
SELECT FLOAT64_ARRAY(JSON '["strawberry"]') AS result;
SELECT FLOAT64_ARRAY(JSON '[null]') AS result;
SELECT FLOAT64_ARRAY(JSON 'null') AS result;
-- An error is thrown because `wide_number_mode` is case-sensitive and not "exact" or "round".
SELECT FLOAT64_ARRAY(JSON '[123.4]', wide_number_mode=>'EXACT') as result;
SELECT FLOAT64_ARRAY(JSON '[123.4]', wide_number_mode=>'exac') as result;
-- An error is thrown because the number cannot be converted to DOUBLE without loss of precision
SELECT FLOAT64_ARRAY(JSON '[18446744073709551615]', wide_number_mode=>'exact') as result;
FLOAT32
FLOAT32(
json_expr
[, [ wide_number_mode => ] { 'exact' | 'round' } ]
)
Description
Converts a JSON number to a SQL FLOAT32
value.
Arguments:
json_expr
: JSON. For example:JSON '9.8'
If the JSON value is not a number, an error is produced. If the expression is a SQL
NULL
, the function returns SQLNULL
.wide_number_mode
: A named argument with aSTRING
value. Defines what happens with a number that cannot be represented as aFLOAT32
without loss of precision. This argument accepts one of the two case-sensitive values:exact
: The function fails if the result cannot be represented as aFLOAT32
without loss of precision.round
(default): The numeric value stored in JSON will be rounded toFLOAT32
. If such rounding is not possible, the function fails.
Return type
FLOAT32
Examples
SELECT FLOAT32(JSON '9.8') AS velocity;
/*----------*
| velocity |
+----------+
| 9.8 |
*----------*/
SELECT FLOAT32(JSON_QUERY(JSON '{"vo2_max": 39.1, "age": 18}', "$.vo2_max")) AS vo2_max;
/*---------*
| vo2_max |
+---------+
| 39.1 |
*---------*/
SELECT FLOAT32(JSON '16777217', wide_number_mode=>'round') as result;
/*------------*
| result |
+------------+
| 16777216.0 |
*------------*/
SELECT FLOAT32(JSON '16777216') as result;
/*------------*
| result |
+------------+
| 16777216.0 |
*------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if JSON is not of type FLOAT32.
SELECT FLOAT32(JSON '"strawberry"') AS result;
SELECT FLOAT32(JSON 'null') AS result;
-- An error is thrown because `wide_number_mode` is case-sensitive and not "exact" or "round".
SELECT FLOAT32(JSON '123.4', wide_number_mode=>'EXACT') as result;
SELECT FLOAT32(JSON '123.4', wide_number_mode=>'exac') as result;
-- An error is thrown because the number cannot be converted to FLOAT without loss of precision
SELECT FLOAT32(JSON '16777217', wide_number_mode=>'exact') as result;
-- Returns a SQL NULL
SELECT SAFE.FLOAT32(JSON '"strawberry"') AS result;
FLOAT32_ARRAY
FLOAT32_ARRAY(
json_expr
[, wide_number_mode => { 'exact' | 'round' } ]
)
Description
Converts a JSON array of numbers to a SQL ARRAY<FLOAT32>
value.
Arguments:
json_expr
: JSON. For example:JSON '[9.8]'
If the JSON value is not an array of numbers, an error is produced. If the expression is a SQL
NULL
, the function returns SQLNULL
.wide_number_mode
: A named argument with aSTRING
value. Defines what happens with a number that can't be represented as aFLOAT32
without loss of precision. This argument accepts one of the two case-sensitive values:exact
: The function fails if the result cannot be represented as aFLOAT32
without loss of precision.round
(default): The numeric value stored in JSON will be rounded toFLOAT32
. If such rounding is not possible, the function fails.
Return type
ARRAY<FLOAT32>
Examples
SELECT FLOAT32_ARRAY(JSON '[9, 9.8]') AS velocities;
/*-------------*
| velocities |
+-------------+
| [9.0, 9.8] |
*-------------*/
SELECT FLOAT32_ARRAY(JSON '[16777217]', wide_number_mode=>'round') as result;
/*--------------*
| result |
+--------------+
| [16777216.0] |
*--------------*/
SELECT FLOAT32_ARRAY(JSON '[16777216]') as result;
/*--------------*
| result |
+--------------+
| [16777216.0] |
*--------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not an array of numbers in FLOAT32 domain.
SELECT FLOAT32_ARRAY(JSON '["strawberry"]') AS result;
SELECT FLOAT32_ARRAY(JSON '[null]') AS result;
SELECT FLOAT32_ARRAY(JSON 'null') AS result;
-- An error is thrown because `wide_number_mode` is case-sensitive and not "exact" or "round".
SELECT FLOAT32_ARRAY(JSON '[123.4]', wide_number_mode=>'EXACT') as result;
SELECT FLOAT32_ARRAY(JSON '[123.4]', wide_number_mode=>'exac') as result;
-- An error is thrown because the number cannot be converted to FLOAT without loss of precision
SELECT FLOAT32_ARRAY(JSON '[16777217]', wide_number_mode=>'exact') as result;
INT64
INT64(json_expr)
Description
Converts a JSON number to a SQL INT64
value.
Arguments:
json_expr
: JSON. For example:JSON '999'
If the JSON value is not a number, or the JSON number is not in the SQL
INT64
domain, an error is produced. If the expression is SQLNULL
, the function returns SQLNULL
.
Return type
INT64
Examples
SELECT INT64(JSON '2005') AS flight_number;
/*---------------*
| flight_number |
+---------------+
| 2005 |
*---------------*/
SELECT INT64(JSON_QUERY(JSON '{"gate": "A4", "flight_number": 2005}', "$.flight_number")) AS flight_number;
/*---------------*
| flight_number |
+---------------+
| 2005 |
*---------------*/
SELECT INT64(JSON '10.0') AS score;
/*-------*
| score |
+-------+
| 10 |
*-------*/
The following examples show how invalid requests are handled:
-- An error is thrown if JSON is not a number or cannot be converted to a 64-bit integer.
SELECT INT64(JSON '10.1') AS result; -- Throws an error
SELECT INT64(JSON '"strawberry"') AS result; -- Throws an error
SELECT INT64(JSON 'null') AS result; -- Throws an error
SELECT SAFE.INT64(JSON '"strawberry"') AS result; -- Returns a SQL NULL
INT64_ARRAY
INT64_ARRAY(json_expr)
Description
Converts a JSON array of numbers to a SQL INT64_ARRAY
value.
Arguments:
json_expr
: JSON. For example:JSON '[999]'
If the JSON value is not an array of numbers, or the JSON numbers are not in the SQL
INT64
domain, an error is produced. If the expression is SQLNULL
, the function returns SQLNULL
.
Return type
ARRAY<INT64>
Examples
SELECT INT64_ARRAY(JSON '[2005, 2003]') AS flight_numbers;
/*----------------*
| flight_numbers |
+----------------+
| [2005, 2003] |
*----------------*/
SELECT INT64_ARRAY(JSON '[10.0]') AS scores;
/*--------*
| scores |
+--------+
| [10] |
*--------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not an array of numbers in INT64 domain.
SELECT INT64_ARRAY(JSON '[10.1]') AS result; -- Throws an error
SELECT INT64_ARRAY(JSON '["strawberry"]') AS result; -- Throws an error
SELECT INT64_ARRAY(JSON '[null]') AS result; -- Throws an error
SELECT INT64_ARRAY(JSON 'null') AS result; -- Throws an error
JSON_ARRAY
JSON_ARRAY([value][, ...])
Description
Creates a JSON array from zero or more SQL values.
Arguments:
value
: A JSON encoding-supported value to add to a JSON array.
Return type
JSON
Examples
The following query creates a JSON array with one value in it:
SELECT JSON_ARRAY(10) AS json_data
/*-----------*
| json_data |
+-----------+
| [10] |
*-----------*/
You can create a JSON array with an empty JSON array in it. For example:
SELECT JSON_ARRAY([]) AS json_data
/*-----------*
| json_data |
+-----------+
| [[]] |
*-----------*/
SELECT JSON_ARRAY(10, 'foo', NULL) AS json_data
/*-----------------*
| json_data |
+-----------------+
| [10,"foo",null] |
*-----------------*/
SELECT JSON_ARRAY(STRUCT(10 AS a, 'foo' AS b)) AS json_data
/*----------------------*
| json_data |
+----------------------+
| [{"a":10,"b":"foo"}] |
*----------------------*/
SELECT JSON_ARRAY(10, ['foo', 'bar'], [20, 30]) AS json_data
/*----------------------------*
| json_data |
+----------------------------+
| [10,["foo","bar"],[20,30]] |
*----------------------------*/
SELECT JSON_ARRAY(10, [JSON '20', JSON '"foo"']) AS json_data
/*-----------------*
| json_data |
+-----------------+
| [10,[20,"foo"]] |
*-----------------*/
You can create an empty JSON array. For example:
SELECT JSON_ARRAY() AS json_data
/*-----------*
| json_data |
+-----------+
| [] |
*-----------*/
JSON_OBJECT
- Signature 1:
JSON_OBJECT([json_key, json_value][, ...])
- Signature 2:
JSON_OBJECT(json_key_array, json_value_array)
Signature 1
JSON_OBJECT([json_key, json_value][, ...])
Description
Creates a JSON object, using key-value pairs.
Arguments:
json_key
: ASTRING
value that represents a key.json_value
: A JSON encoding-supported value.
Details:
- If two keys are passed in with the same name, only the first key-value pair is preserved.
- The order of key-value pairs is not preserved.
- If
json_key
isNULL
, an error is produced.
Return type
JSON
Examples
You can create an empty JSON object by passing in no JSON keys and values. For example:
SELECT JSON_OBJECT() AS json_data
/*-----------*
| json_data |
+-----------+
| {} |
*-----------*/
You can create a JSON object by passing in key-value pairs. For example:
SELECT JSON_OBJECT('foo', 10, 'bar', TRUE) AS json_data
/*-----------------------*
| json_data |
+-----------------------+
| {"bar":true,"foo":10} |
*-----------------------*/
SELECT JSON_OBJECT('foo', 10, 'bar', ['a', 'b']) AS json_data
/*----------------------------*
| json_data |
+----------------------------+
| {"bar":["a","b"],"foo":10} |
*----------------------------*/
SELECT JSON_OBJECT('a', NULL, 'b', JSON 'null') AS json_data
/*---------------------*
| json_data |
+---------------------+
| {"a":null,"b":null} |
*---------------------*/
SELECT JSON_OBJECT('a', 10, 'a', 'foo') AS json_data
/*-----------*
| json_data |
+-----------+
| {"a":10} |
*-----------*/
WITH Items AS (SELECT 'hello' AS key, 'world' AS value)
SELECT JSON_OBJECT(key, value) AS json_data FROM Items
/*-------------------*
| json_data |
+-------------------+
| {"hello":"world"} |
*-------------------*/
An error is produced if a SQL NULL
is passed in for a JSON key.
-- Error: A key cannot be NULL.
SELECT JSON_OBJECT(NULL, 1) AS json_data
An error is produced if the number of JSON keys and JSON values don't match:
-- Error: No matching signature for function JSON_OBJECT for argument types:
-- STRING, INT64, STRING
SELECT JSON_OBJECT('a', 1, 'b') AS json_data
Signature 2
JSON_OBJECT(json_key_array, json_value_array)
Creates a JSON object, using an array of keys and values.
Arguments:
json_key_array
: An array of zero or moreSTRING
keys.json_value_array
: An array of zero or more JSON encoding-supported values.
Details:
- If two keys are passed in with the same name, only the first key-value pair is preserved.
- The order of key-value pairs is not preserved.
- The number of keys must match the number of values, otherwise an error is produced.
- If any argument is
NULL
, an error is produced. - If a key in
json_key_array
isNULL
, an error is produced.
Return type
JSON
Examples
You can create an empty JSON object by passing in an empty array of keys and values. For example:
SELECT JSON_OBJECT(CAST([] AS ARRAY<STRING>), []) AS json_data
/*-----------*
| json_data |
+-----------+
| {} |
*-----------*/
You can create a JSON object by passing in an array of keys and an array of values. For example:
SELECT JSON_OBJECT(['a', 'b'], [10, NULL]) AS json_data
/*-------------------*
| json_data |
+-------------------+
| {"a":10,"b":null} |
*-------------------*/
SELECT JSON_OBJECT(['a', 'b'], [JSON '10', JSON '"foo"']) AS json_data
/*--------------------*
| json_data |
+--------------------+
| {"a":10,"b":"foo"} |
*--------------------*/
SELECT
JSON_OBJECT(
['a', 'b'],
[STRUCT(10 AS id, 'Red' AS color), STRUCT(20 AS id, 'Blue' AS color)])
AS json_data
/*------------------------------------------------------------*
| json_data |
+------------------------------------------------------------+
| {"a":{"color":"Red","id":10},"b":{"color":"Blue","id":20}} |
*------------------------------------------------------------*/
SELECT
JSON_OBJECT(
['a', 'b'],
[TO_JSON(10), TO_JSON(['foo', 'bar'])])
AS json_data
/*----------------------------*
| json_data |
+----------------------------+
| {"a":10,"b":["foo","bar"]} |
*----------------------------*/
The following query groups by id
and then creates an array of keys and
values from the rows with the same id
:
WITH
Fruits AS (
SELECT 0 AS id, 'color' AS json_key, 'red' AS json_value UNION ALL
SELECT 0, 'fruit', 'apple' UNION ALL
SELECT 1, 'fruit', 'banana' UNION ALL
SELECT 1, 'ripe', 'true'
)
SELECT JSON_OBJECT(ARRAY_AGG(json_key), ARRAY_AGG(json_value)) AS json_data
FROM Fruits
GROUP BY id
/*----------------------------------*
| json_data |
+----------------------------------+
| {"color":"red","fruit":"apple"} |
| {"fruit":"banana","ripe":"true"} |
*----------------------------------*/
An error is produced if the size of the JSON keys and values arrays don't match:
-- Error: The number of keys and values must match.
SELECT JSON_OBJECT(['a', 'b'], [10]) AS json_data
An error is produced if the array of JSON keys or JSON values is a SQL NULL
.
-- Error: The keys array cannot be NULL.
SELECT JSON_OBJECT(CAST(NULL AS ARRAY<STRING>), [10, 20]) AS json_data
-- Error: The values array cannot be NULL.
SELECT JSON_OBJECT(['a', 'b'], CAST(NULL AS ARRAY<INT64>)) AS json_data
JSON_QUERY
JSON_QUERY(json_string_expr, json_path)
JSON_QUERY(json_expr, json_path)
Description
Extracts a JSON value and converts it to a SQL
JSON-formatted STRING
or
JSON
value.
This function uses double quotes to escape invalid
JSONPath characters in JSON keys. For example: "a.b"
.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'{"class": {"students": [{"name": "Jane"}]}}'
Extracts a SQL
NULL
when a JSON-formatted stringnull
is encountered. For example:SELECT JSON_QUERY("null", "$") -- Returns a SQL NULL
json_expr
: JSON. For example:JSON '{"class": {"students": [{"name": "Jane"}]}}'
Extracts a JSON
null
when a JSONnull
is encountered.SELECT JSON_QUERY(JSON 'null', "$") -- Returns a JSON 'null'
json_path
: The JSONPath. This identifies the data that you want to obtain from the input.
There are differences between the JSON-formatted string and JSON input types. For details, see Differences between the JSON and JSON-formatted STRING types.
Return type
json_string_expr
: A JSON-formattedSTRING
json_expr
:JSON
Examples
In the following example, JSON data is extracted and returned as JSON.
SELECT
JSON_QUERY(
JSON '{"class": {"students": [{"id": 5}, {"id": 12}]}}',
'$.class') AS json_data;
/*-----------------------------------*
| json_data |
+-----------------------------------+
| {"students":[{"id":5},{"id":12}]} |
*-----------------------------------*/
In the following examples, JSON data is extracted and returned as JSON-formatted strings.
SELECT
JSON_QUERY('{"class": {"students": [{"name": "Jane"}]}}', '$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[{"name":"Jane"}]}} |
*-----------------------------------------------------------*/
SELECT JSON_QUERY('{"class": {"students": []}}', '$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[]}} |
*-----------------------------------------------------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "John"},{"name": "Jamie"}]}}',
'$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[{"name":"John"},{"name":"Jamie"}]}} |
*-----------------------------------------------------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "Jane"}]}}',
'$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| {"name":"Jane"} |
*-----------------*/
SELECT
JSON_QUERY('{"class": {"students": []}}', '$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| NULL |
*-----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| {"name":"John"} |
*-----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "Jane"}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": []}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "John"}, {"name": null}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| "Jamie" |
*----------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "Jane"}]}}',
'$.class."students"') AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [{"name":"Jane"}] |
*------------------------------------*/
SELECT
JSON_QUERY(
'{"class": {"students": []}}',
'$.class."students"') AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [] |
*------------------------------------*/
SELECT
JSON_QUERY(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$.class."students"') AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [{"name":"John"},{"name":"Jamie"}] |
*------------------------------------*/
SELECT JSON_QUERY('{"a": null}', "$.a"); -- Returns a SQL NULL
SELECT JSON_QUERY('{"a": null}', "$.b"); -- Returns a SQL NULL
SELECT JSON_QUERY(JSON '{"a": null}', "$.a"); -- Returns a JSON 'null'
SELECT JSON_QUERY(JSON '{"a": null}', "$.b"); -- Returns a SQL NULL
JSON_QUERY_ARRAY
JSON_QUERY_ARRAY(json_string_expr[, json_path])
JSON_QUERY_ARRAY(json_expr[, json_path])
Description
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
or
ARRAY<JSON>
value.
In addition, this function uses double quotes to escape invalid
JSONPath characters in JSON keys. For example: "a.b"
.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'["a", "b", {"key": "c"}]'
json_expr
: JSON. For example:JSON '["a", "b", {"key": "c"}]'
json_path
: The JSONPath. This identifies the data that you want to obtain from the input. If this optional parameter is not provided, then the JSONPath$
symbol is applied, which means that all of the data is analyzed.
There are differences between the JSON-formatted string and JSON input types. For details, see Differences between the JSON and JSON-formatted STRING types.
Return type
json_string_expr
:ARRAY<JSON-formatted STRING>
json_expr
:ARRAY<JSON>
Examples
This extracts items in JSON to an array of JSON
values:
SELECT JSON_QUERY_ARRAY(
JSON '{"fruits": ["apples", "oranges", "grapes"]}', '$.fruits'
) AS json_array;
/*---------------------------------*
| json_array |
+---------------------------------+
| ["apples", "oranges", "grapes"] |
*---------------------------------*/
This extracts the items in a JSON-formatted string to a string array:
SELECT JSON_QUERY_ARRAY('[1, 2, 3]') AS string_array;
/*--------------*
| string_array |
+--------------+
| [1, 2, 3] |
*--------------*/
This extracts a string array and converts it to an integer array:
SELECT ARRAY(
SELECT CAST(integer_element AS INT64)
FROM UNNEST(
JSON_QUERY_ARRAY('[1, 2, 3]','$')
) AS integer_element
) AS integer_array;
/*---------------*
| integer_array |
+---------------+
| [1, 2, 3] |
*---------------*/
This extracts string values in a JSON-formatted string to an array:
-- Doesn't strip the double quotes
SELECT JSON_QUERY_ARRAY('["apples", "oranges", "grapes"]', '$') AS string_array;
/*---------------------------------*
| string_array |
+---------------------------------+
| ["apples", "oranges", "grapes"] |
*---------------------------------*/
-- Strips the double quotes
SELECT ARRAY(
SELECT JSON_VALUE(string_element, '$')
FROM UNNEST(JSON_QUERY_ARRAY('["apples", "oranges", "grapes"]', '$')) AS string_element
) AS string_array;
/*---------------------------*
| string_array |
+---------------------------+
| [apples, oranges, grapes] |
*---------------------------*/
This extracts only the items in the fruit
property to an array:
SELECT JSON_QUERY_ARRAY(
'{"fruit": [{"apples": 5, "oranges": 10}, {"apples": 2, "oranges": 4}], "vegetables": [{"lettuce": 7, "kale": 8}]}',
'$.fruit'
) AS string_array;
/*-------------------------------------------------------*
| string_array |
+-------------------------------------------------------+
| [{"apples":5,"oranges":10}, {"apples":2,"oranges":4}] |
*-------------------------------------------------------*/
These are equivalent:
SELECT JSON_QUERY_ARRAY('{"fruits": ["apples", "oranges", "grapes"]}', '$.fruits') AS string_array;
SELECT JSON_QUERY_ARRAY('{"fruits": ["apples", "oranges", "grapes"]}', '$."fruits"') AS string_array;
-- The queries above produce the following result:
/*---------------------------------*
| string_array |
+---------------------------------+
| ["apples", "oranges", "grapes"] |
*---------------------------------*/
In cases where a JSON key uses invalid JSONPath characters, you can escape those
characters using double quotes: " "
. For example:
SELECT JSON_QUERY_ARRAY('{"a.b": {"c": ["world"]}}', '$."a.b".c') AS hello;
/*-----------*
| hello |
+-----------+
| ["world"] |
*-----------*/
The following examples show how invalid requests and empty arrays are handled:
-- An error is returned if you provide an invalid JSONPath.
SELECT JSON_QUERY_ARRAY('["foo", "bar", "baz"]', 'INVALID_JSONPath') AS result;
-- If the JSONPath does not refer to an array, then NULL is returned.
SELECT JSON_QUERY_ARRAY('{"a": "foo"}', '$.a') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a key that does not exist is specified, then the result is NULL.
SELECT JSON_QUERY_ARRAY('{"a": "foo"}', '$.b') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- Empty arrays in JSON-formatted strings are supported.
SELECT JSON_QUERY_ARRAY('{"a": "foo", "b": []}', '$.b') AS result;
/*--------*
| result |
+--------+
| [] |
*--------*/
JSON_TYPE
JSON_TYPE(json_expr)
Description
Gets the JSON type of the outermost JSON value and converts the name of
this type to a SQL STRING
value. The names of these JSON types can be
returned: object
, array
, string
, number
, boolean
, null
Arguments:
json_expr
: JSON. For example:JSON '{"name": "sky", "color": "blue"}'
If this expression is SQL
NULL
, the function returns SQLNULL
. If the extracted JSON value is not a valid JSON type, an error is produced.
Return type
STRING
Examples
SELECT json_val, JSON_TYPE(json_val) AS type
FROM
UNNEST(
[
JSON '"apple"',
JSON '10',
JSON '3.14',
JSON 'null',
JSON '{"city": "New York", "State": "NY"}',
JSON '["apple", "banana"]',
JSON 'false'
]
) AS json_val;
/*----------------------------------+---------*
| json_val | type |
+----------------------------------+---------+
| "apple" | string |
| 10 | number |
| 3.14 | number |
| null | null |
| {"State":"NY","city":"New York"} | object |
| ["apple","banana"] | array |
| false | boolean |
*----------------------------------+---------*/
JSON_VALUE
JSON_VALUE(json_string_expr[, json_path])
JSON_VALUE(json_expr[, json_path])
Description
Extracts a JSON scalar value and converts it to a SQL STRING
value.
In addition, this function:
- Removes the outermost quotes and unescapes the values.
- Returns a SQL
NULL
if a non-scalar value is selected. - Uses double quotes to escape invalid JSONPath characters
in JSON keys. For example:
"a.b"
.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'{"name": "Jakob", "age": "6"}'
json_expr
: JSON. For example:JSON '{"name": "Jane", "age": "6"}'
json_path
: The JSONPath. This identifies the data that you want to obtain from the input. If this optional parameter is not provided, then the JSONPath$
symbol is applied, which means that all of the data is analyzed.If
json_path
returns a JSONnull
or a non-scalar value (in other words, ifjson_path
refers to an object or an array), then a SQLNULL
is returned.
There are differences between the JSON-formatted string and JSON input types. For details, see Differences between the JSON and JSON-formatted STRING types.
Return type
STRING
Examples
In the following example, JSON data is extracted and returned as a scalar value.
SELECT JSON_VALUE(JSON '{"name": "Jakob", "age": "6" }', '$.age') AS scalar_age;
/*------------*
| scalar_age |
+------------+
| 6 |
*------------*/
The following example compares how results are returned for the JSON_QUERY
and JSON_VALUE
functions.
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_age;
/*-----------+-------------+----------+------------*
| json_name | scalar_name | json_age | scalar_age |
+-----------+-------------+----------+------------+
| "Jakob" | Jakob | "6" | 6 |
*-----------+-------------+----------+------------*/
SELECT JSON_QUERY('{"fruits": ["apple", "banana"]}', '$.fruits') AS json_query,
JSON_VALUE('{"fruits": ["apple", "banana"]}', '$.fruits') AS json_value;
/*--------------------+------------*
| json_query | json_value |
+--------------------+------------+
| ["apple","banana"] | NULL |
*--------------------+------------*/
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 |
*-------*/
JSON_VALUE_ARRAY
JSON_VALUE_ARRAY(json_string_expr[, json_path])
JSON_VALUE_ARRAY(json_expr[, json_path])
Description
Extracts a JSON array of scalar values and converts it to a SQL
ARRAY<STRING>
value.
In addition, this function:
- Removes the outermost quotes and unescapes the values.
- Returns a SQL
NULL
if the selected value is not an array or not an array containing only scalar values. - Uses double quotes to escape invalid JSONPath characters
in JSON keys. For example:
"a.b"
.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'["apples", "oranges", "grapes"]'
json_expr
: JSON. For example:JSON '["apples", "oranges", "grapes"]'
json_path
: The JSONPath. This identifies the data that you want to obtain from the input. If this optional parameter is not provided, then the JSONPath$
symbol is applied, which means that all of the data is analyzed.
There are differences between the JSON-formatted string and JSON input types. For details, see Differences between the JSON and JSON-formatted STRING types.
Caveats:
- A JSON
null
in the input array produces a SQLNULL
as the output for that JSONnull
. - If a JSONPath matches an array that contains scalar objects and a JSON
null
, then the output is an array of the scalar objects and a SQLNULL
.
Return type
ARRAY<STRING>
Examples
This extracts items in JSON to a string array:
SELECT JSON_VALUE_ARRAY(
JSON '{"fruits": ["apples", "oranges", "grapes"]}', '$.fruits'
) AS string_array;
/*---------------------------*
| string_array |
+---------------------------+
| [apples, oranges, grapes] |
*---------------------------*/
The following example compares how results are returned for the
JSON_QUERY_ARRAY
and JSON_VALUE_ARRAY
functions.
SELECT JSON_QUERY_ARRAY('["apples", "oranges"]') AS json_array,
JSON_VALUE_ARRAY('["apples", "oranges"]') AS string_array;
/*-----------------------+-------------------*
| json_array | string_array |
+-----------------------+-------------------+
| ["apples", "oranges"] | [apples, oranges] |
*-----------------------+-------------------*/
This extracts the items in a JSON-formatted string to a string array:
-- Strips the double quotes
SELECT JSON_VALUE_ARRAY('["foo", "bar", "baz"]', '$') AS string_array;
/*-----------------*
| string_array |
+-----------------+
| [foo, bar, baz] |
*-----------------*/
This extracts a string array and converts it to an integer array:
SELECT ARRAY(
SELECT CAST(integer_element AS INT64)
FROM UNNEST(
JSON_VALUE_ARRAY('[1, 2, 3]', '$')
) AS integer_element
) AS integer_array;
/*---------------*
| integer_array |
+---------------+
| [1, 2, 3] |
*---------------*/
These are equivalent:
SELECT JSON_VALUE_ARRAY('{"fruits": ["apples", "oranges", "grapes"]}', '$.fruits') AS string_array;
SELECT JSON_VALUE_ARRAY('{"fruits": ["apples", "oranges", "grapes"]}', '$."fruits"') AS string_array;
-- The queries above produce the following result:
/*---------------------------*
| string_array |
+---------------------------+
| [apples, oranges, grapes] |
*---------------------------*/
In cases where a JSON key uses invalid JSONPath characters, you can escape those
characters using double quotes: " "
. For example:
SELECT JSON_VALUE_ARRAY('{"a.b": {"c": ["world"]}}', '$."a.b".c') AS hello;
/*---------*
| hello |
+---------+
| [world] |
*---------*/
The following examples explore how invalid requests and empty arrays are handled:
-- An error is thrown if you provide an invalid JSONPath.
SELECT JSON_VALUE_ARRAY('["foo", "bar", "baz"]', 'INVALID_JSONPath') AS result;
-- If the JSON-formatted string is invalid, then NULL is returned.
SELECT JSON_VALUE_ARRAY('}}', '$') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If the JSON document is NULL, then NULL is returned.
SELECT JSON_VALUE_ARRAY(NULL, '$') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a JSONPath does not match anything, then the output is NULL.
SELECT JSON_VALUE_ARRAY('{"a": ["foo", "bar", "baz"]}', '$.b') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a JSONPath matches an object that is not an array, then the output is NULL.
SELECT JSON_VALUE_ARRAY('{"a": "foo"}', '$') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a JSONPath matches an array of non-scalar objects, then the output is NULL.
SELECT JSON_VALUE_ARRAY('{"a": [{"b": "foo", "c": 1}, {"b": "bar", "c": 2}], "d": "baz"}', '$.a') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a JSONPath matches an array of mixed scalar and non-scalar objects,
-- then the output is NULL.
SELECT JSON_VALUE_ARRAY('{"a": [10, {"b": 20}]', '$.a') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
-- If a JSONPath matches an empty JSON array, then the output is an empty array instead of NULL.
SELECT JSON_VALUE_ARRAY('{"a": "foo", "b": []}', '$.b') AS result;
/*--------*
| result |
+--------+
| [] |
*--------*/
-- In the following query, the JSON null input is returned as a
-- SQL NULL in the output.
SELECT JSON_VALUE_ARRAY('["world", null, 1]') AS result;
/*------------------*
| result |
+------------------+
| [world, NULL, 1] |
*------------------*/
LAX_BOOL
LAX_BOOL(json_expr)
Description
Attempts to convert a JSON value to a SQL BOOL
value.
Arguments:
json_expr
: JSON. For example:JSON 'true'
Details:
- If
json_expr
is SQLNULL
, the function returns SQLNULL
. - See the conversion rules in the next section for additional
NULL
handling.
Conversion rules
From JSON type | To SQL BOOL |
---|---|
boolean |
If the JSON boolean is true , returns TRUE .
Otherwise, returns FALSE .
|
string |
If the JSON string is 'true' , returns TRUE .
If the JSON string is 'false' , returns FALSE .
If the JSON string is any other value or has whitespace in it,
returns NULL .
This conversion is case-insensitive.
|
number |
If the JSON number is a representation of 0 ,
returns FALSE . Otherwise, returns TRUE .
|
other type or null | NULL |
Return type
BOOL
Examples
Example with input that is a JSON boolean:
SELECT LAX_BOOL(JSON 'true') AS result;
/*--------*
| result |
+--------+
| true |
*--------*/
Examples with inputs that are JSON strings:
SELECT LAX_BOOL(JSON '"true"') AS result;
/*--------*
| result |
+--------+
| TRUE |
*--------*/
SELECT LAX_BOOL(JSON '"true "') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
SELECT LAX_BOOL(JSON '"foo"') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
Examples with inputs that are JSON numbers:
SELECT LAX_BOOL(JSON '10') AS result;
/*--------*
| result |
+--------+
| TRUE |
*--------*/
SELECT LAX_BOOL(JSON '0') AS result;
/*--------*
| result |
+--------+
| FALSE |
*--------*/
SELECT LAX_BOOL(JSON '0.0') AS result;
/*--------*
| result |
+--------+
| FALSE |
*--------*/
SELECT LAX_BOOL(JSON '-1.1') AS result;
/*--------*
| result |
+--------+
| TRUE |
*--------*/
LAX_FLOAT64
LAX_FLOAT64(json_expr)
Description
Attempts to convert a JSON value to a
SQL FLOAT64
value.
Arguments:
json_expr
: JSON. For example:JSON '9.8'
Details:
- If
json_expr
is SQLNULL
, the function returns SQLNULL
. - See the conversion rules in the next section for additional
NULL
handling.
Conversion rules
From JSON type | To SQL FLOAT64 |
---|---|
boolean |
NULL
|
string |
If the JSON string represents a JSON number, parses it as
a
JSON number, and then safe casts the result as a
FLOAT64 value.
If the JSON string can't be converted, returns NULL .
|
number |
Casts the JSON number as a
FLOAT64 value.
Large JSON numbers are rounded.
|
other type or null | NULL |
Return type
FLOAT64
Examples
Examples with inputs that are JSON numbers:
SELECT LAX_FLOAT64(JSON '9.8') AS result;
/*--------*
| result |
+--------+
| 9.8 |
*--------*/
SELECT LAX_FLOAT64(JSON '9') AS result;
/*--------*
| result |
+--------+
| 9.0 |
*--------*/
SELECT LAX_FLOAT64(JSON '9007199254740993') AS result;
/*--------------------*
| result |
+--------------------+
| 9007199254740992.0 |
*--------------------*/
SELECT LAX_FLOAT64(JSON '1e100') AS result;
/*--------*
| result |
+--------+
| 1e+100 |
*--------*/
Examples with inputs that are JSON booleans:
SELECT LAX_FLOAT64(JSON 'true') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
SELECT LAX_FLOAT64(JSON 'false') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
Examples with inputs that are JSON strings:
SELECT LAX_FLOAT64(JSON '"10"') AS result;
/*--------*
| result |
+--------+
| 10.0 |
*--------*/
SELECT LAX_FLOAT64(JSON '"1.1"') AS result;
/*--------*
| result |
+--------+
| 1.1 |
*--------*/
SELECT LAX_FLOAT64(JSON '"1.1e2"') AS result;
/*--------*
| result |
+--------+
| 110.0 |
*--------*/
SELECT LAX_FLOAT64(JSON '"9007199254740993"') AS result;
/*--------------------*
| result |
+--------------------+
| 9007199254740992.0 |
*--------------------*/
SELECT LAX_FLOAT64(JSON '"+1.5"') AS result;
/*--------*
| result |
+--------+
| 1.5 |
*--------*/
SELECT LAX_FLOAT64(JSON '"NaN"') AS result;
/*--------*
| result |
+--------+
| NaN |
*--------*/
SELECT LAX_FLOAT64(JSON '"Inf"') AS result;
/*----------*
| result |
+----------+
| Infinity |
*----------*/
SELECT LAX_FLOAT64(JSON '"-InfiNiTY"') AS result;
/*-----------*
| result |
+-----------+
| -Infinity |
*-----------*/
SELECT LAX_FLOAT64(JSON '"foo"') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
LAX_INT64
LAX_INT64(json_expr)
Description
Attempts to convert a JSON value to a SQL INT64
value.
Arguments:
json_expr
: JSON. For example:JSON '999'
Details:
- If
json_expr
is SQLNULL
, the function returns SQLNULL
. - See the conversion rules in the next section for additional
NULL
handling.
Conversion rules
From JSON type | To SQL INT64 |
---|---|
boolean |
If the JSON boolean is true , returns 1 .
If false , returns 0 .
|
string |
If the JSON string represents a JSON number, parses it as
a
JSON number, and then safe casts the results as an
INT64 value.
If the JSON string can't be converted, returns NULL .
|
number |
Casts the JSON number as an INT64 value.
If the JSON number can't be converted, returns NULL .
|
other type or null | NULL |
Return type
INT64
Examples
Examples with inputs that are JSON numbers:
SELECT LAX_INT64(JSON '10') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
SELECT LAX_INT64(JSON '10.0') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
SELECT LAX_INT64(JSON '1.1') AS result;
/*--------*
| result |
+--------+
| 1 |
*--------*/
SELECT LAX_INT64(JSON '3.5') AS result;
/*--------*
| result |
+--------+
| 4 |
*--------*/
SELECT LAX_INT64(JSON '1.1e2') AS result;
/*--------*
| result |
+--------+
| 110 |
*--------*/
SELECT LAX_INT64(JSON '1e100') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
Examples with inputs that are JSON booleans:
SELECT LAX_INT64(JSON 'true') AS result;
/*--------*
| result |
+--------+
| 1 |
*--------*/
SELECT LAX_INT64(JSON 'false') AS result;
/*--------*
| result |
+--------+
| 0 |
*--------*/
Examples with inputs that are JSON strings:
SELECT LAX_INT64(JSON '"10"') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
SELECT LAX_INT64(JSON '"1.1"') AS result;
/*--------*
| result |
+--------+
| 1 |
*--------*/
SELECT LAX_INT64(JSON '"1.1e2"') AS result;
/*--------*
| result |
+--------+
| 110 |
*--------*/
SELECT LAX_INT64(JSON '"+1.5"') AS result;
/*--------*
| result |
+--------+
| 2 |
*--------*/
SELECT LAX_INT64(JSON '"1e100"') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
SELECT LAX_INT64(JSON '"foo"') AS result;
/*--------*
| result |
+--------+
| NULL |
*--------*/
LAX_STRING
LAX_STRING(json_expr)
Description
Attempts to convert a JSON value to a SQL STRING
value.
Arguments:
json_expr
: JSON. For example:JSON '"name"'
Details:
- If
json_expr
is SQLNULL
, the function returns SQLNULL
. - See the conversion rules in the next section for additional
NULL
handling.
Conversion rules
From JSON type | To SQL STRING |
---|---|
boolean |
If the JSON boolean is true , returns 'true' .
If false , returns 'false' .
|
string |
Returns the JSON string as a STRING value.
|
number |
Returns the JSON number as a STRING value.
|
other type or null | NULL |
Return type
STRING
Examples
Examples with inputs that are JSON strings:
SELECT LAX_STRING(JSON '"purple"') AS result;
/*--------*
| result |
+--------+
| purple |
*--------*/
SELECT LAX_STRING(JSON '"10"') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
Examples with inputs that are JSON booleans:
SELECT LAX_STRING(JSON 'true') AS result;
/*--------*
| result |
+--------+
| true |
*--------*/
SELECT LAX_STRING(JSON 'false') AS result;
/*--------*
| result |
+--------+
| false |
*--------*/
Examples with inputs that are JSON numbers:
SELECT LAX_STRING(JSON '10.0') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
SELECT LAX_STRING(JSON '10') AS result;
/*--------*
| result |
+--------+
| 10 |
*--------*/
SELECT LAX_STRING(JSON '1e100') AS result;
/*--------*
| result |
+--------+
| 1e+100 |
*--------*/
PARSE_JSON
PARSE_JSON(
json_string_expr
[, wide_number_mode => { 'exact' | 'round' } ]
)
Description
Converts a JSON-formatted STRING
value to a JSON
value.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'{"class": {"students": [{"name": "Jane"}]}}'
wide_number_mode
: A named argument with aSTRING
value. Determines how to handle numbers that can't be stored in aJSON
value without the loss of precision. If used,wide_number_mode
must include one of the following values:exact
(default): Only accept numbers that can be stored without loss of precision. If a number that cannot be stored without loss of precision is encountered, the function throws an error.round
: If a number that cannot be stored without loss of precision is encountered, attempt to round it to a number that can be stored without loss of precision. If the number cannot be rounded, the function throws an error.
If a number appears in a JSON object or array, the
wide_number_mode
argument is applied to the number in the object or array.
Numbers from the following domains can be stored in JSON without loss of precision:
- 64-bit signed/unsigned integers, such as
INT64
FLOAT64
Return type
JSON
Examples
In the following example, a JSON-formatted string is converted to JSON
.
SELECT PARSE_JSON('{"coordinates": [10, 20], "id": 1}') AS json_data;
/*--------------------------------*
| json_data |
+--------------------------------+
| {"coordinates":[10,20],"id":1} |
*--------------------------------*/
The following queries fail because:
- The number that was passed in cannot be stored without loss of precision.
wide_number_mode=>'exact'
is used implicitly in the first query and explicitly in the second query.
SELECT PARSE_JSON('{"id": 922337203685477580701}') AS json_data; -- fails
SELECT PARSE_JSON('{"id": 922337203685477580701}', wide_number_mode=>'exact') AS json_data; -- fails
The following query rounds the number to a number that can be stored in JSON.
SELECT PARSE_JSON('{"id": 922337203685477580701}', wide_number_mode=>'round') AS json_data;
/*------------------------------*
| json_data |
+------------------------------+
| {"id":9.223372036854776e+20} |
*------------------------------*/
You can also use valid JSON-formatted strings that don't represent name/value pairs. For example:
SELECT PARSE_JSON('6') AS json_data;
/*------------------------------*
| json_data |
+------------------------------+
| 6 |
*------------------------------*/
SELECT PARSE_JSON('"red"') AS json_data;
/*------------------------------*
| json_data |
+------------------------------+
| "red" |
*------------------------------*/
SAFE_TO_JSON
SAFE_TO_JSON(sql_value)
Description
Similar to the TO_JSON
function, but for each unsupported field in the
input argument, produces a JSON null instead of an error.
Arguments:
sql_value
: The SQL value to convert to a JSON value. You can review the GoogleSQL data types that this function supports and their JSON encodings.
Return type
JSON
Example
The following queries are functionally the same, except that SAFE_TO_JSON
produces a JSON null instead of an error when a hypothetical unsupported
data type is encountered:
-- Produces a JSON null.
SELECT SAFE_TO_JSON(CAST(b'' AS UNSUPPORTED_TYPE)) as result;
-- Produces an error.
SELECT TO_JSON(CAST(b'' AS UNSUPPORTED_TYPE), stringify_wide_numbers=>TRUE) as result;
In the following query, the value for ut
is ignored because the value is an
unsupported type:
SELECT SAFE_TO_JSON(STRUCT(CAST(b'' AS UNSUPPORTED_TYPE) AS ut) AS result;
/*--------------*
| result |
+--------------+
| {"ut": null} |
*--------------*/
The following array produces a JSON null instead of an error because the data type for the array is not supported.
SELECT SAFE_TO_JSON([
CAST(b'' AS UNSUPPORTED_TYPE),
CAST(b'' AS UNSUPPORTED_TYPE),
CAST(b'' AS UNSUPPORTED_TYPE),
]) AS result;
/*------------*
| result |
+------------+
| null |
*------------*/
STRING
STRING(json_expr)
Description
Converts a JSON string to a SQL STRING
value.
Arguments:
json_expr
: JSON. For example:JSON '"purple"'
If the JSON value is not a string, an error is produced. If the expression is SQL
NULL
, the function returns SQLNULL
.
Return type
STRING
Examples
SELECT STRING(JSON '"purple"') AS color;
/*--------*
| color |
+--------+
| purple |
*--------*/
SELECT STRING(JSON_QUERY(JSON '{"name": "sky", "color": "blue"}', "$.color")) AS color;
/*-------*
| color |
+-------+
| blue |
*-------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not of type string.
SELECT STRING(JSON '123') AS result; -- Throws an error
SELECT STRING(JSON 'null') AS result; -- Throws an error
SELECT SAFE.STRING(JSON '123') AS result; -- Returns a SQL NULL
STRING_ARRAY
STRING_ARRAY(json_expr)
Description
Converts a JSON array of strings to a SQL ARRAY<STRING>
value.
Arguments:
json_expr
: JSON. For example:JSON '["purple", "blue"]'
If the JSON value is not an array of strings, an error is produced. If the expression is SQL
NULL
, the function returns SQLNULL
.
Return type
ARRAY<STRING>
Examples
SELECT STRING_ARRAY(JSON '["purple", "blue"]') AS colors;
/*----------------*
| colors |
+----------------+
| [purple, blue] |
*----------------*/
The following examples show how invalid requests are handled:
-- An error is thrown if the JSON is not an array of strings.
SELECT STRING_ARRAY(JSON '[123]') AS result; -- Throws an error
SELECT STRING_ARRAY(JSON '[null]') AS result; -- Throws an error
SELECT STRING_ARRAY(JSON 'null') AS result; -- Throws an error
TO_JSON
TO_JSON(
sql_value
[, stringify_wide_numbers => { TRUE | FALSE } ]
)
Description
Converts a SQL value to a JSON value.
Arguments:
sql_value
: The SQL value to convert to a JSON value. You can review the GoogleSQL data types that this function supports and their JSON encodings here.stringify_wide_numbers
: A named argument that's eitherTRUE
orFALSE
(default).- If
TRUE
, numeric values outside of theFLOAT64
type domain are encoded as strings. - If
FALSE
(default), numeric values outside of theFLOAT64
type domain are not encoded as strings, but are stored as JSON numbers. If a numerical value cannot be stored in JSON without loss of precision, an error is thrown.
The following numerical data types are affected by the
stringify_wide_numbers
argument:- If
INT64
NUMERIC
If one of these numerical data types appears in a container data type such as an
ARRAY
orSTRUCT
, thestringify_wide_numbers
argument is applied to the numerical data types in the container data type.
Return type
JSON
Examples
In the following example, the query converts rows in a table to JSON values.
With CoordinatesTable AS (
(SELECT 1 AS id, [10, 20] AS coordinates) UNION ALL
(SELECT 2 AS id, [30, 40] AS coordinates) UNION ALL
(SELECT 3 AS id, [50, 60] AS coordinates))
SELECT TO_JSON(t) AS json_objects
FROM CoordinatesTable AS t;
/*--------------------------------*
| json_objects |
+--------------------------------+
| {"coordinates":[10,20],"id":1} |
| {"coordinates":[30,40],"id":2} |
| {"coordinates":[50,60],"id":3} |
*--------------------------------*/
In the following example, the query returns a large numerical value as a JSON string.
SELECT TO_JSON(9007199254740993, stringify_wide_numbers=>TRUE) as stringify_on;
/*--------------------*
| stringify_on |
+--------------------+
| "9007199254740993" |
*--------------------*/
In the following example, both queries return a large numerical value as a JSON number.
SELECT TO_JSON(9007199254740993, stringify_wide_numbers=>FALSE) as stringify_off;
SELECT TO_JSON(9007199254740993) as stringify_off;
/*------------------*
| stringify_off |
+------------------+
| 9007199254740993 |
*------------------*/
In the following example, only large numeric values are converted to JSON strings.
With T1 AS (
(SELECT 9007199254740993 AS id) UNION ALL
(SELECT 2 AS id))
SELECT TO_JSON(t, stringify_wide_numbers=>TRUE) AS json_objects
FROM T1 AS t;
/*---------------------------*
| json_objects |
+---------------------------+
| {"id":"9007199254740993"} |
| {"id":2} |
*---------------------------*/
In this example, the values 9007199254740993
(INT64
)
and 2.1
(FLOAT64
) are converted
to the common supertype FLOAT64
, which is not
affected by the stringify_wide_numbers
argument.
With T1 AS (
(SELECT 9007199254740993 AS id) UNION ALL
(SELECT 2.1 AS id))
SELECT TO_JSON(t, stringify_wide_numbers=>TRUE) AS json_objects
FROM T1 AS t;
/*------------------------------*
| json_objects |
+------------------------------+
| {"id":9.007199254740992e+15} |
| {"id":2.1} |
*------------------------------*/
TO_JSON_STRING
TO_JSON_STRING(json_expr)
Description
Converts a JSON value to a SQL JSON-formatted STRING
value.
Arguments:
json_expr
: JSON. For example:JSON '{"class": {"students": [{"name": "Jane"}]}}'
Return type
A JSON-formatted STRING
Example
Convert a JSON value to a JSON-formatted STRING
value.
SELECT TO_JSON_STRING(JSON '{"id": 1, "coordinates": [10, 20]}') AS json_string
/*--------------------------------*
| json_string |
+--------------------------------+
| {"coordinates":[10,20],"id":1} |
*--------------------------------*/
Supplemental materials
Differences between the JSON and JSON-formatted STRING types
Many JSON functions accept two input types:
JSON
typeSTRING
type
The STRING
version of the extraction functions behaves differently than the
JSON
version, mainly because JSON
type values are always validated whereas
JSON-formatted STRING
type values are not.
Non-validation of STRING
inputs
The following STRING
is invalid JSON because it is missing a trailing }
:
{"hello": "world"
The JSON function reads the input from the beginning and stops as soon as the field to extract is found, without reading the remainder of the input. A parsing error is not produced.
With the JSON
type, however, JSON '{"hello": "world"'
returns a parsing
error.
For example:
SELECT JSON_VALUE('{"hello": "world"', "$.hello") AS hello;
/*-------*
| hello |
+-------+
| world |
*-------*/
SELECT JSON_VALUE(JSON '{"hello": "world"', "$.hello") AS hello;
-- An error is returned: Invalid JSON literal: syntax error while parsing
-- object - unexpected end of input; expected '}'
No strict validation of extracted values
In the following examples, duplicated keys are not removed when using a
JSON-formatted string. Similarly, keys order is preserved. For the JSON
type, JSON '{"key": 1, "key": 2}'
will result in JSON '{"key":1}'
during
parsing.
SELECT JSON_QUERY('{"key": 1, "key": 2}', "$") AS string;
/*-------------------*
| string |
+-------------------+
| {"key":1,"key":2} |
*-------------------*/
SELECT JSON_QUERY(JSON '{"key": 1, "key": 2}', "$") AS json;
/*-----------*
| json |
+-----------+
| {"key":1} |
*-----------*/
JSON null
When using a JSON-formatted STRING
type in a JSON function, a JSON null
value is extracted as a SQL NULL
value.
When using a JSON type in a JSON function, a JSON null
value returns a JSON
null
value.
WITH t AS (
SELECT '{"name": null}' AS json_string, JSON '{"name": null}' AS json)
SELECT JSON_QUERY(json_string, "$.name") AS name_string,
JSON_QUERY(json_string, "$.name") IS NULL AS name_string_is_null,
JSON_QUERY(json, "$.name") AS name_json,
JSON_QUERY(json, "$.name") IS NULL AS name_json_is_null
FROM t;
/*-------------+---------------------+-----------+-------------------*
| name_string | name_string_is_null | name_json | name_json_is_null |
+-------------+---------------------+-----------+-------------------+
| NULL | true | null | false |
*-------------+---------------------+-----------+-------------------*/
JSON encodings
You can encode a SQL value as a JSON value with the following functions:
TO_JSON
JSON_ARRAY
(usesTO_JSON
encoding)JSON_OBJECT
(usesTO_JSON
encoding)
The following SQL to JSON encodings are supported:
From SQL | To JSON | Examples |
---|---|---|
NULL |
null |
SQL input: NULL JSON output: null
|
BOOL | boolean |
SQL input: TRUE JSON output: true SQL input: FALSE JSON output: false |
INT64 |
number or string
If the
If the |
SQL input: 9007199254740992 JSON output: 9007199254740992 SQL input: 9007199254740993 JSON output: 9007199254740993 SQL input with stringify_wide_numbers=>TRUE: 9007199254740992 JSON output: 9007199254740992 SQL input with stringify_wide_numbers=>TRUE: 9007199254740993 JSON output: "9007199254740993" |
NUMERIC |
number or string
If the |
SQL input: -1 JSON output: -1 SQL input: 0 JSON output: 0 SQL input: 9007199254740993 JSON output: 9007199254740993 SQL input: 123.56 JSON output: 123.56 SQL input with stringify_wide_numbers=>TRUE: 9007199254740993 JSON output: "9007199254740993" SQL input with stringify_wide_numbers=>TRUE: 123.56 JSON output: 123.56 |
FLOAT64 |
number or string
|
SQL input: 1.0 JSON output: 1 SQL input: 9007199254740993 JSON output: 9007199254740993 SQL input: "+inf" JSON output: "Infinity" SQL input: "-inf" JSON output: "-Infinity" SQL input: "NaN" JSON output: "NaN" |
STRING |
string
Encoded as a string, escaped according to the JSON standard.
Specifically, |
SQL input: "abc" JSON output: "abc" SQL input: "\"abc\"" JSON output: "\"abc\"" |
BYTES |
string Uses RFC 4648 Base64 data encoding. |
SQL input: b"Google" JSON output: "R29vZ2xl" |
ENUM |
string Invalid enum values are encoded as their number, such as 0 or 42. |
SQL input: Color.Red JSON output: "Red" |
DATE | string |
SQL input: DATE '2017-03-06' JSON output: "2017-03-06" |
TIMESTAMP |
string Encoded as ISO 8601 date and time, where T separates the date and time and Z (Zulu/UTC) represents the time zone. |
SQL input: TIMESTAMP '2017-03-06 12:34:56.789012' JSON output: "2017-03-06T12:34:56.789012Z" |
JSON |
data of the input JSON |
SQL input: JSON '{"item": "pen", "price": 10}' JSON output: {"item":"pen", "price":10} SQL input: [1, 2, 3] JSON output: [1, 2, 3] |
ARRAY |
array Can contain zero or more elements. |
SQL input: ["red", "blue", "green"] JSON output: ["red","blue","green"] SQL input: [1, 2, 3] JSON output: [1,2,3] |
STRUCT |
object The object can contain zero or more key-value pairs. Each value is formatted according to its type.
For
Anonymous fields are represented with
Invalid UTF-8 field names might result in unparseable JSON. String
values are escaped according to the JSON standard. Specifically,
|
SQL input: STRUCT(12 AS purchases, TRUE AS inStock) JSON output: {"inStock": true,"purchases":12} |
PROTO |
object The object can contain zero or more key-value pairs. Each value is formatted according to its type.
Field names with underscores are converted to camel case in accordance
with
protobuf json conversion. Field values are formatted according to
protobuf json conversion. If a
|
SQL input: NEW Item(12 AS purchases,TRUE AS in_Stock) JSON output: {"purchases":12,"inStock": true} |
GRAPH_ELEMENT |
object The object can contain zero or more key-value pairs. Each value is formatted according to its type.
For
|
SQL:
GRAPH FinGraph MATCH (p:Person WHERE p.name = 'Dana') RETURN TO_JSON(p) AS dana_json; JSON output (truncated): {"identifier":"ZGFuYQ==","kind":"node","labels":["Person"],"properties":{"id":2,"name":"Dana"}} |
JSONPath format
With the JSONPath format, you can identify the values you want to obtain from a JSON-formatted string.
If a key in a JSON functions contains a JSON format operator, refer to each JSON function for how to escape them.
A JSON function returns NULL
if the JSONPath format does not match a value in
a JSON-formatted string. If the selected value for a scalar function is not
scalar, such as an object or an array, the function returns NULL
. If the
JSONPath format is invalid, an error is produced.
Operators for JSONPath
The JSONPath format supports these operators:
Operator | Description | Examples |
---|---|---|
$ |
Root object or element. The JSONPath format must start with this operator, which refers to the outermost level of the JSON-formatted string. |
JSON-formatted string:
JSON path:
JSON result: |
. |
Child operator. You can identify child values using dot-notation. |
JSON-formatted string:
JSON path:
JSON result: |
[] |
Subscript operator. If the object is a JSON array, you can use brackets to specify the array index. |
JSON-formatted string:
JSON path:
JSON result: |
Mathematical functions in GoogleSQL
GoogleSQL for Spanner supports 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
.
Categories
Category | Functions |
---|---|
Trigonometric |
ACOS
ACOSH
ASIN
ASINH
ATAN
ATAN2
ATANH
COS
COSH
SIN
SINH
TAN
TANH
|
Exponential and logarithmic |
EXP
LN
LOG
LOG10
|
Rounding and truncation |
CEIL
CEILING
FLOOR
ROUND
TRUNC
|
Power and root |
POW
POWER
SQRT
|
Sign |
ABS
SIGN
|
Distance |
APPROX_DOT_PRODUCT
APPROX_COSINE_DISTANCE
APPROX_EUCLIDEAN_DISTANCE
DOT_PRODUCT
COSINE_DISTANCE
EUCLIDEAN_DISTANCE
|
Comparison |
GREATEST
LEAST
|
Arithmetic and error handling |
DIV
IEEE_DIVIDE
IS_INF
IS_NAN
MOD
SAFE_ADD
SAFE_DIVIDE
SAFE_MULTIPLY
SAFE_NEGATE
SAFE_SUBTRACT
|
Function list
Name | Summary |
---|---|
ABS
|
Computes the absolute value of X .
|
ACOS
|
Computes the inverse cosine of X .
|
ACOSH
|
Computes the inverse hyperbolic cosine of X .
|
APPROX_COSINE_DISTANCE
|
Computes the approximate cosine distance between two vectors. |
APPROX_DOT_PRODUCT
|
Computes the approximate dot product of two vectors. |
APPROX_EUCLIDEAN_DISTANCE
|
Computes the approximate Euclidean distance between two vectors. |
ASIN
|
Computes the inverse sine of X .
|
ASINH
|
Computes the inverse hyperbolic sine of X .
|
ATAN
|
Computes the inverse tangent of X .
|
ATAN2
|
Computes the inverse tangent of X/Y , using the signs of
X and Y to determine the quadrant.
|
ATANH
|
Computes the inverse hyperbolic tangent of X .
|
AVG
|
Gets the average of non-NULL values.
For more information, see Aggregate functions. |
CEIL
|
Gets the smallest integral value that is not less than X .
|
CEILING
|
Synonym of CEIL .
|
COS
|
Computes the cosine of X .
|
COSH
|
Computes the hyperbolic cosine of X .
|
COSINE_DISTANCE
|
Computes the cosine distance between two vectors. |
DIV
|
Divides integer X by integer Y .
|
DOT_PRODUCT
|
Computes the dot product of two vectors. |
EXP
|
Computes e to the power of X .
|
EUCLIDEAN_DISTANCE
|
Computes the Euclidean distance between two vectors. |
FLOOR
|
Gets the largest integral value that is not greater than X .
|
GREATEST
|
Gets the greatest value among X1,...,XN .
|
IEEE_DIVIDE
|
Divides X by Y , but does not generate errors for
division by zero or overflow.
|
IS_INF
|
Checks if X is positive or negative infinity.
|
IS_NAN
|
Checks if X is a NaN value.
|
LEAST
|
Gets the least value among X1,...,XN .
|
LN
|
Computes the natural logarithm of X .
|
LOG
|
Computes the natural logarithm of X or the logarithm of
X to base Y .
|
LOG10
|
Computes the natural logarithm of X to base 10.
|
MAX
|
Gets the maximum non-NULL value.
For more information, see Aggregate functions. |
MOD
|
Gets the remainder of the division of X by Y .
|
POW
|
Produces the value of X raised to the power of Y .
|
POWER
|
Synonym of POW .
|
ROUND
|
Rounds X to the nearest integer or rounds X
to N decimal places after the decimal point.
|
SAFE_ADD
|
Equivalent to the addition operator (X + Y ), but returns
NULL if overflow occurs.
|
SAFE_DIVIDE
|
Equivalent to the division operator (X / Y ), but returns
NULL if an error occurs.
|
SAFE_MULTIPLY
|
Equivalent to the multiplication operator (X * Y ),
but returns NULL if overflow occurs.
|
SAFE_NEGATE
|
Equivalent to the unary minus operator (-X ), but returns
NULL if overflow occurs.
|
SAFE_SUBTRACT
|
Equivalent to the subtraction operator (X - Y ), but
returns NULL if overflow occurs.
|
SIGN
|
Produces -1 , 0, or +1 for negative, zero, and positive arguments respectively. |
SIN
|
Computes the sine of X .
|
SINH
|
Computes the hyperbolic sine of X .
|
SQRT
|
Computes the square root of X .
|
SUM
|
Gets the sum of non-NULL values.
For more information, see Aggregate functions. |
TAN
|
Computes the tangent of X .
|
TANH
|
Computes the hyperbolic tangent of X .
|
TRUNC
|
Rounds a number like ROUND(X) or ROUND(X, N) ,
but always rounds towards zero and never overflows.
|
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.
X | ABS(X) |
---|---|
25 | 25 |
-25 | 25 |
+inf |
+inf |
-inf |
+inf |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
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].
If X is NUMERIC
then, the output is FLOAT64
.
X | ACOS(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
X < -1 | Error |
X > 1 | Error |
ACOSH
ACOSH(X)
Description
Computes the inverse hyperbolic cosine of X. Generates an error if X is a value less than 1.
If X is NUMERIC
then, the output is FLOAT64
.
X | ACOSH(X) |
---|---|
+inf |
+inf |
-inf |
NaN |
NaN |
NaN |
X < 1 | Error |
APPROX_COSINE_DISTANCE
APPROX_COSINE_DISTANCE(vector1, vector2, options=>value)
Description
Computes the approximate cosine distance between two vectors.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.options
: A named argument with a value that represents a Spanner-specific optimization.value
must be the following:JSON'{"num_leaves_to_search": INT}'
This option specifies the approximate nearest neighbors (ANN) algorithm configuration used in your query. The total number of leaves is specified when you create your vector index. For this argument, we recommend using a number that is 1% the total number of leaves defined in the
CREATE VECTOR INDEX
statement. The number of leaves to search is defined by thenum_leaves_to_search
option for both 2-level and 3-level trees.If an unsupported option is provided, an error is produced.
Details
APPROX_COSINE_DISTANCE
approximates the
COSINE_DISTANCE
between the given vectors. Approximation
typically occurs when using specific indexing strategies that precompute
clustering.
Query results across invocations aren't guaranteed to repeat.
You can add a filter such as WHERE s.id = 42
to your query. However, that
might lead to poor recall problems because the WHERE
filter happens after
internal limits are applied. To mitigate this issue, you can increase the
value of the num_of_leaves_to_search
option.
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can't be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
. If a zero vector is encountered, an error is produced.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Limitations
- The function can only be used to sort vectors in a table with an
ORDER BY
clause. - The function output must be the only ordering key in the
ORDER BY
clause. - The
ORDER BY
clause must be followed by aLIMIT
clause. - One of the function arguments must directly reference an embedding column, and the other must be a constant expression, such as a query parameter reference.
You can't use the function in the following ways:
In a
WHERE
,ON
, orGROUP BY
clause.In a
SELECT
clause unless it is for ordering results in a laterORDER BY
clause.As the input of another expression.
In your query, you must specify a vector index by using the
force_index
query hint.
Return type
FLOAT64
Examples
In the following example, vectors are used to compute the approximate cosine distance:
In the following example, up to 1000 leaves in the vector index are searched to produce the approximate nearest two vectors using cosine distance:
SELECT FirstName, LastName
FROM Singers@{FORCE_INDEX=Singer_vector_index} AS s
ORDER BY APPROX_COSINE_DISTANCE(@queryVector, s.embedding, options=>JSON'{"num_leaves_to_search": 1000}')
LIMIT 2;
/*-----------+------------*
| FirstName | LastName |
+-----------+------------+
| Marc | Richards |
| Catalina | Smith |
*-----------+------------*/
APPROX_DOT_PRODUCT
APPROX_DOT_PRODUCT(vector1, vector2, options=>value)
Description
Computes the approximate dot product of two vectors.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.options
: A named argument with a value that represents a Spanner-specific optimization.value
must be the following:JSON'{"num_leaves_to_search": INT}'
This option specifies the approximate nearest neighbors (ANN) algorithm configuration used in your query. The total number of leaves is specified when you create your vector index. For this argument, we recommend using a number that is 1% the total number of leaves defined in the
CREATE VECTOR INDEX
statement. The number of leaves to search is defined by thenum_leaves_to_search
option for both 2-level and 3-level trees.If an unsupported option is provided, an error is produced.
Details
APPROX_DOT_PRODUCT
approximates the DOT_PRODUCT
between two
vectors. Approximation typically occurs when using specific indexing strategies
that precompute clustering.
Query results across invocations aren't guaranteed to repeat.
You can add a filter such as WHERE s.id = 42
to your query. However, that
might lead to poor recall problems because the WHERE
filter happens after
internal limits are applied. To mitigate this issue, you can increase the
value of the num_of_leaves_to_search
option.
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:INT64
FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Limitations
- The function can only be used to sort vectors in a table with an
ORDER BY
clause. - The function output must be the only ordering key in the
ORDER BY
clause. - The
ORDER BY
clause must be followed by aLIMIT
clause. - One of the function arguments must directly reference an embedding column, and the other must be a constant expression, such as a query parameter reference.
You can't use the function in the following ways:
In a
WHERE
,ON
, orGROUP BY
clause.In a
SELECT
clause unless it is for ordering results in a laterORDER BY
clause.As the input of another expression.
In your query, you must specify a vector index by using the
force_index
query hint.
Return type
FLOAT64
Examples
In the following example, up to 1000 leaves in the vector index are searched to produce the approximate nearest two vectors using dot product distance:
SELECT FirstName, LastName
FROM Singers@{FORCE_INDEX=Singer_vector_index} AS s
ORDER BY APPROX_DOT_PRODUCT(@queryVector, s.embedding, options=>JSON'{"num_leaves_to_search": 1000}')
LIMIT 2;
/*-----------+------------*
| FirstName | LastName |
+-----------+------------+
| Marc | Richards |
| Catalina | Smith |
*-----------+------------*/
APPROX_EUCLIDEAN_DISTANCE
APPROX_EUCLIDEAN_DISTANCE(vector1, vector2, options=>value)
Description
Computes the approximate Euclidean distance between two vectors.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.options
: A named argument with a value that represents a Spanner-specific optimization.value
must be the following:JSON'{"num_leaves_to_search": INT}'
This option specifies the approximate nearest neighbors (ANN) algorithm configuration used in your query. The total number of leaves is specified when you create your vector index. For this argument, we recommend using a number that is 1% the total number of leaves defined in the
CREATE VECTOR INDEX
statement. The number of leaves to search is defined by thenum_leaves_to_search
option for both 2-level and 3-level trees.If an unsupported option is provided, an error is produced.
Details
APPROX_EUCLIDEAN_DISTANCE
approximates the
EUCLIDEAN_DISTANCE
between two vectors. Approximation
typically occurs when using specific indexing strategies that precompute
clustering.
Query results across invocations aren't guaranteed to repeat.
You can add a filter such as WHERE s.id = 42
to your query. However, that
might lead to poor recall problems because the WHERE
filter happens after
internal limits are applied. To mitigate this issue, you can increase the
value of the num_of_leaves_to_search
option.
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Limitations
- The function can only be used to sort vectors in a table with an
ORDER BY
clause. - The function output must be the only ordering key in the
ORDER BY
clause. - The
ORDER BY
clause must be followed by aLIMIT
clause. - One of the function arguments must directly reference an embedding column, and the other must be a constant expression, such as a query parameter reference.
You can't use the function in the following ways:
In a
WHERE
,ON
, orGROUP BY
clause.In a
SELECT
clause unless it is for ordering results in a laterORDER BY
clause.As the input of another expression.
In your query, you must specify a vector index by using the
force_index
query hint.
Return type
FLOAT64
Examples
In the following example, vectors are used to compute the approximate Euclidean distance:
In the following example, up to 1000 leaves in the vector index are searched to produce the approximate nearest two vectors using Euclidean distance:
SELECT FirstName, LastName
FROM Singers@{FORCE_INDEX=Singer_vector_index} AS s
ORDER BY APPROX_EUCLIDEAN_DISTANCE(@queryVector, 0.1], s.embedding, options=>JSON'{"num_leaves_to_search": 1000}')
LIMIT 2;
/*-----------+------------*
| FirstName | LastName |
+-----------+------------+
| Marc | Richards |
| Catalina | Smith |
*-----------+------------*/
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].
If X is NUMERIC
then, the output is FLOAT64
.
X | ASIN(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
X < -1 | Error |
X > 1 | Error |
ASINH
ASINH(X)
Description
Computes the inverse hyperbolic sine of X. Does not fail.
If X is NUMERIC
then, the output is FLOAT64
.
X | ASINH(X) |
---|---|
+inf |
+inf |
-inf |
-inf |
NaN |
NaN |
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.
If X is NUMERIC
then, the output is FLOAT64
.
X | ATAN(X) |
---|---|
+inf |
π/2 |
-inf |
-π/2 |
NaN |
NaN |
ATAN2
ATAN2(X, Y)
Description
Calculates the principal value of the inverse tangent of X/Y using the signs of the two arguments to determine the quadrant. The return value is in the range [-π,π].
If Y is NUMERIC
then, the output is FLOAT64
.
X | Y | ATAN2(X, Y) |
---|---|---|
NaN |
Any value | NaN |
Any value | NaN |
NaN |
0.0 | 0.0 | 0.0 |
Positive Finite value | -inf |
π |
Negative Finite value | -inf |
-π |
Finite value | +inf |
0.0 |
+inf |
Finite value | π/2 |
-inf |
Finite value | -π/2 |
+inf |
-inf |
¾π |
-inf |
-inf |
-¾π |
+inf |
+inf |
π/4 |
-inf |
+inf |
-π/4 |
ATANH
ATANH(X)
Description
Computes the inverse hyperbolic tangent of X. Generates an error if X is outside of the range (-1, 1).
If X is NUMERIC
then, the output is FLOAT64
.
X | ATANH(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
X < -1 | Error |
X > 1 | Error |
CEIL
CEIL(X)
Description
Returns the smallest integral value that is not less than X.
X | CEIL(X) |
---|---|
2.0 | 2.0 |
2.3 | 3.0 |
2.8 | 3.0 |
2.5 | 3.0 |
-2.3 | -2.0 |
-2.8 | -2.0 |
-2.5 | -2.0 |
0 | 0 |
+inf |
+inf |
-inf |
-inf |
NaN |
NaN |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
CEILING
CEILING(X)
Description
Synonym of CEIL(X)
COS
COS(X)
Description
Computes the cosine of X where X is specified in radians. Never fails.
X | COS(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
COSH
COSH(X)
Description
Computes the hyperbolic cosine of X where X is specified in radians. Generates an error if overflow occurs.
If X is NUMERIC
then, the output is FLOAT64
.
X | COSH(X) |
---|---|
+inf |
+inf |
-inf |
+inf |
NaN |
NaN |
COSINE_DISTANCE
COSINE_DISTANCE(vector1, vector2)
Description
Computes the cosine distance between two vectors.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.
Details
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can't be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
. If a zero vector is encountered, an error is produced.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Return type
FLOAT64
Examples
In the following example,vectors are used to compute the cosine distance:
SELECT COSINE_DISTANCE([1.0, 2.0], [3.0, 4.0]) AS results;
/*----------*
| results |
+----------+
| 0.016130 |
*----------*/
The ordering of numeric values in a vector doesn't impact the results produced by this function. For example these queries produce the same results even though the numeric values in each vector is in a different order:
SELECT COSINE_DISTANCE([1.0, 2.0], [3.0, 4.0]) AS results;
SELECT COSINE_DISTANCE([2.0, 1.0], [4.0, 3.0]) AS results;
/*----------*
| results |
+----------+
| 0.016130 |
*----------*/
In the following example, the function can't compute cosine distance against the first vector, which is a zero vector:
-- ERROR
SELECT COSINE_DISTANCE([0.0, 0.0], [3.0, 4.0]) AS results;
Both vectors must have the same dimensions. If not, an error is produced. In the following example, the first vector has two dimensions and the second vector has three:
-- ERROR
SELECT COSINE_DISTANCE([9.0, 7.0], [8.0, 4.0, 5.0]) AS results;
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. If
both inputs are NUMERIC
and the result is overflow,
then it returns a numeric overflow
error.
X | Y | DIV(X, Y) |
---|---|---|
20 | 4 | 5 |
12 | -7 | -1 |
20 | 3 | 6 |
0 | 20 | 0 |
20 | 0 | Error |
Return Data Type
The return data type is determined by the argument types with the following table.
INPUT | INT64 | NUMERIC |
---|---|---|
INT64 | INT64 | NUMERIC |
NUMERIC | NUMERIC | NUMERIC |
DOT_PRODUCT
DOT_PRODUCT(vector1, vector2)
Description
Computes the dot product of two vectors. The dot product is computed by summing the product of corresponding vector elements.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.
Details
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:INT64
FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Return type
FLOAT64
Examples
SELECT DOT_PRODUCT([100], [200]) AS results
/*---------*
| results |
+---------+
| 20000 |
*---------*/
SELECT DOT_PRODUCT([100, 10], [200, 6]) AS results
/*---------*
| results |
+---------+
| 20060 |
*---------*/
SELECT DOT_PRODUCT([100, 10, 1], [200, 6, 2]) AS results
/*---------*
| results |
+---------+
| 20062 |
*---------*/
SELECT DOT_PRODUCT([], []) AS results
/*---------*
| results |
+---------+
| 0 |
*---------*/
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.
X | EXP(X) |
---|---|
0.0 | 1.0 |
+inf |
+inf |
-inf |
0.0 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
EUCLIDEAN_DISTANCE
EUCLIDEAN_DISTANCE(vector1, vector2)
Description
Computes the Euclidean distance between two vectors.
Definitions
vector1
: A vector that is represented by anARRAY<T>
value.vector2
: A vector that is represented by anARRAY<T>
value.
Details
ARRAY<T>
can be used to represent a vector. Each zero-based index in this array represents a dimension. The value for each element in this array represents a magnitude.T
can represent the following and must be the same for both vectors:FLOAT32
FLOAT64
In the following example vector, there are four dimensions. The magnitude is
10.0
for dimension0
,55.0
for dimension1
,40.0
for dimension2
, and34.0
for dimension3
:[10.0, 55.0, 40.0, 34.0]
Both vectors in this function must share the same dimensions, and if they don't, an error is produced.
A vector can be a zero vector. A vector is a zero vector if it has no dimensions or all dimensions have a magnitude of
0
, such as[]
or[0.0, 0.0]
.An error is produced if a magnitude in a vector is
NULL
.If a vector is
NULL
,NULL
is returned.
Return type
FLOAT64
Examples
In the following example, vectors are used to compute the Euclidean distance:
SELECT EUCLIDEAN_DISTANCE([1.0, 2.0], [3.0, 4.0]) AS results;
/*----------*
| results |
+----------+
| 2.828 |
*----------*/
The ordering of magnitudes in a vector doesn't impact the results produced by this function. For example these queries produce the same results even though the magnitudes in each vector is in a different order:
SELECT EUCLIDEAN_DISTANCE([1.0, 2.0], [3.0, 4.0]);
SELECT EUCLIDEAN_DISTANCE([2.0, 1.0], [4.0, 3.0]);
/*----------*
| results |
+----------+
| 2.828 |
*----------*/
Both vectors must have the same dimensions. If not, an error is produced. In the following example, the first vector has two dimensions and the second vector has three:
-- ERROR
SELECT EUCLIDEAN_DISTANCE([9.0, 7.0], [8.0, 4.0, 5.0]) AS results;
FLOOR
FLOOR(X)
Description
Returns the largest integral value that is not greater than X.
X | FLOOR(X) |
---|---|
2.0 | 2.0 |
2.3 | 2.0 |
2.8 | 2.0 |
2.5 | 2.0 |
-2.3 | -3.0 |
-2.8 | -3.0 |
-2.5 | -3.0 |
0 | 0 |
+inf |
+inf |
-inf |
-inf |
NaN |
NaN |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
GREATEST
GREATEST(X1,...,XN)
Description
Returns the greatest value among X1,...,XN
. If any argument is NULL
, returns
NULL
. Otherwise, in the case of floating-point arguments, if any argument is
NaN
, returns NaN
. In all other cases, returns the value among X1,...,XN
that has the greatest value according to the ordering used by the ORDER BY
clause. The arguments X1, ..., XN
must be coercible to a common supertype, and
the supertype must support ordering.
X1,...,XN | GREATEST(X1,...,XN) |
---|---|
3,5,1 | 5 |
Return Data Types
Data type of the input values.
IEEE_DIVIDE
IEEE_DIVIDE(X, Y)
Description
Divides X by Y; this function never fails. Returns
FLOAT64
unless
both X and Y are FLOAT32
, in which case it returns
FLOAT32
. Unlike the division operator (/),
this function does not generate errors for division by zero or overflow.
X | Y | IEEE_DIVIDE(X, Y) |
---|---|---|
20.0 | 4.0 | 5.0 |
0.0 | 25.0 | 0.0 |
25.0 | 0.0 | +inf |
-25.0 | 0.0 | -inf |
0.0 | 0.0 | NaN |
0.0 | NaN |
NaN |
NaN |
0.0 | NaN |
+inf |
+inf |
NaN |
-inf |
-inf |
NaN |
IS_INF
IS_INF(X)
Description
Returns TRUE
if the value is positive or negative infinity.
Returns FALSE
for NUMERIC
inputs since NUMERIC
cannot be INF
.
X | IS_INF(X) |
---|---|
+inf |
TRUE |
-inf |
TRUE |
25 | FALSE |
IS_NAN
IS_NAN(X)
Description
Returns TRUE
if the value is a NaN
value.
Returns FALSE
for NUMERIC
inputs since
NUMERIC
cannot be NaN
.
X | IS_NAN(X) |
---|---|
NaN |
TRUE |
25 | FALSE |
LEAST
LEAST(X1,...,XN)
Description
Returns the least value among X1,...,XN
. If any argument is NULL
, returns
NULL
. Otherwise, in the case of floating-point arguments, if any argument is
NaN
, returns NaN
. In all other cases, returns the value among X1,...,XN
that has the least value according to the ordering used by the ORDER BY
clause. The arguments X1, ..., XN
must be coercible to a common supertype, and
the supertype must support ordering.
X1,...,XN | LEAST(X1,...,XN) |
---|---|
3,5,1 | 1 |
Return Data Types
Data type of the input values.
LN
LN(X)
Description
Computes the natural logarithm of X. Generates an error if X is less than or equal to zero.
X | LN(X) |
---|---|
1.0 | 0.0 |
+inf |
+inf |
X <= 0 |
Error |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
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.
X | Y | LOG(X, Y) |
---|---|---|
100.0 | 10.0 | 2.0 |
-inf |
Any value | NaN |
Any value | +inf |
NaN |
+inf |
0.0 < Y < 1.0 | -inf |
+inf |
Y > 1.0 | +inf |
X <= 0 | Any value | Error |
Any value | Y <= 0 | Error |
Any value | 1.0 | Error |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
LOG10
LOG10(X)
Description
Similar to LOG
, but computes logarithm to base 10.
X | LOG10(X) |
---|---|
100.0 | 2.0 |
-inf |
NaN |
+inf |
+inf |
X <= 0 | Error |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
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.
X | Y | MOD(X, Y) |
---|---|---|
25 | 12 | 1 |
25 | 0 | Error |
Return Data Type
The return data type is determined by the argument types with the following table.
INPUT | INT64 | NUMERIC |
---|---|---|
INT64 | INT64 | NUMERIC |
NUMERIC | NUMERIC | NUMERIC |
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.
X | Y | POW(X, Y) |
---|---|---|
2.0 | 3.0 | 8.0 |
1.0 | Any value including NaN |
1.0 |
Any value including NaN |
0 | 1.0 |
-1.0 | +inf |
1.0 |
-1.0 | -inf |
1.0 |
ABS(X) < 1 | -inf |
+inf |
ABS(X) > 1 | -inf |
0.0 |
ABS(X) < 1 | +inf |
0.0 |
ABS(X) > 1 | +inf |
+inf |
-inf |
Y < 0 | 0.0 |
-inf |
Y > 0 | -inf if Y is an odd integer, +inf otherwise |
+inf |
Y < 0 | 0 |
+inf |
Y > 0 | +inf |
Finite value < 0 | Non-integer | Error |
0 | Finite value < 0 | Error |
Return Data Type
The return data type is determined by the argument types with the following table.
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
POWER
POWER(X, Y)
Description
Synonym of POW(X, Y)
.
ROUND
ROUND(X [, N])
Description
If only X is present, rounds X to the nearest integer. If N is present, rounds X to N decimal places after the decimal point. If N is negative, rounds off digits to the left of the decimal point. Rounds halfway cases away from zero. Generates an error if overflow occurs.
Expression | Return Value |
---|---|
ROUND(2.0) |
2.0 |
ROUND(2.3) |
2.0 |
ROUND(2.8) |
3.0 |
ROUND(2.5) |
3.0 |
ROUND(-2.3) |
-2.0 |
ROUND(-2.8) |
-3.0 |
ROUND(-2.5) |
-3.0 |
ROUND(0) |
0 |
ROUND(+inf) |
+inf |
ROUND(-inf) |
-inf |
ROUND(NaN) |
NaN |
ROUND(123.7, -1) |
120.0 |
ROUND(1.235, 2) |
1.24 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
SAFE_ADD
SAFE_ADD(X, Y)
Description
Equivalent to the addition operator (+
), but returns
NULL
if overflow occurs.
X | Y | SAFE_ADD(X, Y) |
---|---|---|
5 | 4 | 9 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | INT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
SAFE_DIVIDE
SAFE_DIVIDE(X, Y)
Description
Equivalent to the division operator (X / Y
), but returns
NULL
if an error occurs, such as a division by zero error.
X | Y | SAFE_DIVIDE(X, Y) |
---|---|---|
20 | 4 | 5 |
0 | 20 | 0 |
20 | 0 | NULL |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
SAFE_MULTIPLY
SAFE_MULTIPLY(X, Y)
Description
Equivalent to the multiplication operator (*
), but returns
NULL
if overflow occurs.
X | Y | SAFE_MULTIPLY(X, Y) |
---|---|---|
20 | 4 | 80 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | INT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
SAFE_NEGATE
SAFE_NEGATE(X)
Description
Equivalent to the unary minus operator (-
), but returns
NULL
if overflow occurs.
X | SAFE_NEGATE(X) |
---|---|
+1 | -1 |
-1 | +1 |
0 | 0 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
SAFE_SUBTRACT
SAFE_SUBTRACT(X, Y)
Description
Returns the result of Y subtracted from X.
Equivalent to the subtraction operator (-
), but returns
NULL
if overflow occurs.
X | Y | SAFE_SUBTRACT(X, Y) |
---|---|---|
5 | 4 | 1 |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
INT64 | INT64 | NUMERIC | FLOAT64 | FLOAT64 |
NUMERIC | NUMERIC | NUMERIC | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
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.
X | SIGN(X) |
---|---|
25 | +1 |
0 | 0 |
-25 | -1 |
NaN | NaN |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
SIN
SIN(X)
Description
Computes the sine of X where X is specified in radians. Never fails.
X | SIN(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
SINH
SINH(X)
Description
Computes the hyperbolic sine of X where X is specified in radians. Generates an error if overflow occurs.
If X is NUMERIC
then, the output is FLOAT64
.
X | SINH(X) |
---|---|
+inf |
+inf |
-inf |
-inf |
NaN |
NaN |
SQRT
SQRT(X)
Description
Computes the square root of X. Generates an error if X is less than 0.
X | SQRT(X) |
---|---|
25.0 |
5.0 |
+inf |
+inf |
X < 0 |
Error |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
TAN
TAN(X)
Description
Computes the tangent of X where X is specified in radians. Generates an error if overflow occurs.
X | TAN(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
TANH
TANH(X)
Description
Computes the hyperbolic tangent of X where X is specified in radians. Does not fail.
If X is NUMERIC
then, the output is FLOAT64
.
X | TANH(X) |
---|---|
+inf |
1.0 |
-inf |
-1.0 |
NaN |
NaN |
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.
X | TRUNC(X) |
---|---|
2.0 | 2.0 |
2.3 | 2.0 |
2.8 | 2.0 |
2.5 | 2.0 |
-2.3 | -2.0 |
-2.8 | -2.0 |
-2.5 | -2.0 |
0 | 0 |
+inf |
+inf |
-inf |
-inf |
NaN |
NaN |
Return Data Type
INPUT | INT64 | NUMERIC | FLOAT32 | FLOAT64 |
---|---|---|---|---|
OUTPUT | FLOAT64 | NUMERIC | FLOAT64 | FLOAT64 |
Machine learning functions in GoogleSQL
GoogleSQL for Spanner supports the following machine learning (ML) functions.
Function list
Name | Summary |
---|---|
ML.PREDICT
|
Apply ML computations defined by a model to each row of an input relation. |
ML.PREDICT
ML.PREDICT(input_model, input_relation[, model_parameters])
input_model:
MODEL model_name
input_relation:
{ input_table | input_subquery }
input_table:
TABLE table_name
model_parameters:
STRUCT(parameter_value AS parameter_name[, ...])
Description
ML.PREDICT
is a table-valued function that helps to access registered
machine learning (ML) models and use them to generate ML predictions.
This function applies ML computations defined by a model to each row of an
input relation, and then, it returns the results of the predictions.
Supported Argument Types
input_model
: The model to use for predictions. Replacemodel_name
with the name of the model. To create a model, see CREATE_MODEL.input_relation
: A table or subquery upon which to apply ML computations. The set of columns of the input relation must include all input columns of the input model; otherwise, the input won't have enough data to generate predictions and the query won't compile. Additionally, the set can also include arbitrary pass-through columns that will be included in the output. The order of the columns in the input relation doesn't matter. The columns of the input relation and model must be coercible.input_table
: The table containing the input data for predictions, for example, a set of features. Replacetable_name
with the name of the table.input_subquery
: The subquery that's used to generate the prediction input data.model_parameters
: ASTRUCT
value that contains parameters supported bymodel_name
. These parameters are passed to the model inference.
Return Type
A table with the following columns:
- Model outputs
- Pass-through columns from the input relation
Examples
The examples in this section reference a model called DiamondAppraise
and
an input table called Diamonds
with the following columns:
DiamondAppraise
model:Input columns Output columns value FLOAT64
value FLOAT64
carat FLOAT64
lower_bound FLOAT64
cut STRING
upper_bound FLOAT64
color STRING(1)
Diamonds
table:Columns Id INT64
Carat FLOAT64
Cut STRING
Color STRING
The following query predicts the value of a diamond based on the diamond's carat, cut, and color.
SELECT id, color, value
FROM ML.PREDICT(MODEL DiamondAppraise, TABLE Diamonds);
+----+-------+-------+
| id | color | value |
+----+-------+-------+
| 1 | I | 280 |
| 2 | G | 447 |
+----+-------+-------+
You can include model-specific parameters. For example, in the following query,
the maxOutputTokens
parameter specifies that content
, the model inference,
can contain 10 or fewer tokens. This query succeeds because the model
TextBison
contains a parameter called maxOutputTokens
.
SELECT prompt, content
FROM ML.PREDICT(
MODEL TextBison,
(SELECT "Is 13 prime?" as prompt), STRUCT(10 AS maxOutputTokens));
+----------------+---------------------+
| prompt | content |
+----------------+---------------------+
| "Is 13 prime?" | "Yes, 13 is prime." |
+----------------+---------------------+
You can use ML.PREDICT
in any DQL/DML statements, such as INSERT
or
UPDATE
. For example:
INSERT INTO AppraisedDiamond (id, color, carat, value)
SELECT
1 AS id,
color,
carat,
value
FROM
ML.PREDICT(MODEL DiamondAppraise,
(
SELECT
@carat AS carat,
@cut AS cut,
@color AS color
));
Net functions in GoogleSQL
GoogleSQL for Spanner supports the following Net functions.
Function list
Name | Summary |
---|---|
NET.HOST
|
Gets the hostname from a URL. |
NET.IP_FROM_STRING
|
Converts an IPv4 or IPv6 address from a STRING value to
a BYTES value in network byte order.
|
NET.IP_NET_MASK
|
Gets a network mask. |
NET.IP_TO_STRING
|
Converts an IPv4 or IPv6 address from a BYTES value in
network byte order to a STRING value.
|
NET.IP_TRUNC
|
Converts a BYTES IPv4 or IPv6 address in
network byte order to a BYTES subnet address.
|
NET.IPV4_FROM_INT64
|
Converts an IPv4 address from an INT64 value to a
BYTES value in network byte order.
|
NET.IPV4_TO_INT64
|
Converts an IPv4 address from a BYTES value in network
byte order to an INT64 value.
|
NET.PUBLIC_SUFFIX
|
Gets the public suffix from a URL. |
NET.REG_DOMAIN
|
Gets the registered or registrable domain from a URL. |
NET.SAFE_IP_FROM_STRING
|
Similar to the NET.IP_FROM_STRING , but returns
NULL instead of producing an error if the input is invalid.
|
NET.HOST
NET.HOST(url)
Description
Takes a URL as a STRING
value and returns the host. For best results, URL
values should comply with the format as defined by
RFC 3986. If the URL value does not comply
with RFC 3986 formatting, this function makes a best effort to parse the input
and return a relevant result. If the function cannot parse the input, it
returns NULL
.
Return Data Type
STRING
Example
SELECT
FORMAT("%T", input) AS input,
description,
FORMAT("%T", NET.HOST(input)) AS host,
FORMAT("%T", NET.PUBLIC_SUFFIX(input)) AS suffix,
FORMAT("%T", NET.REG_DOMAIN(input)) AS domain
FROM (
SELECT "" AS input, "invalid input" AS description
UNION ALL SELECT "http://abc.xyz", "standard URL"
UNION ALL SELECT "//user:password@a.b:80/path?query",
"standard URL with relative scheme, port, path and query, but no public suffix"
UNION ALL SELECT "https://[::1]:80", "standard URL with IPv6 host"
UNION ALL SELECT "http://例子.卷筒纸.中国", "standard URL with internationalized domain name"
UNION ALL SELECT " www.Example.Co.UK ",
"non-standard URL with spaces, upper case letters, and without scheme"
UNION ALL SELECT "mailto:?to=&subject=&body=", "URI rather than URL--unsupported"
);
input | description | host | suffix | domain |
---|---|---|---|---|
"" | invalid input | NULL | NULL | NULL |
"http://abc.xyz" | standard URL | "abc.xyz" | "xyz" | "abc.xyz" |
"//user:password@a.b:80/path?query" | standard URL with relative scheme, port, path and query, but no public suffix | "a.b" | NULL | NULL |
"https://[::1]:80" | standard URL with IPv6 host | "[::1]" | NULL | NULL |
"http://例子.卷筒纸.中国" | standard URL with internationalized domain name | "例子.卷筒纸.中国" | "中国" | "卷筒纸.中国" |
" www.Example.Co.UK " | non-standard URL with spaces, upper case letters, and without scheme | "www.Example.Co.UK" | "Co.UK" | "Example.Co.UK" |
"mailto:?to=&subject=&body=" | URI rather than URL--unsupported | "mailto" | NULL | NULL |
NET.IP_FROM_STRING
NET.IP_FROM_STRING(addr_str)
Description
Converts an IPv4 or IPv6 address from text (STRING) format to binary (BYTES) format in network byte order.
This function supports the following formats for addr_str
:
- IPv4: Dotted-quad format. For example,
10.1.2.3
. - IPv6: Colon-separated format. For example,
1234:5678:90ab:cdef:1234:5678:90ab:cdef
. For more examples, see the IP Version 6 Addressing Architecture.
This function does not support CIDR notation, such as 10.1.2.3/32
.
If this function receives a NULL
input, it returns NULL
. If the input is
considered invalid, an OUT_OF_RANGE
error occurs.
Return Data Type
BYTES
Example
SELECT
addr_str, FORMAT("%T", NET.IP_FROM_STRING(addr_str)) AS ip_from_string
FROM UNNEST([
'48.49.50.51',
'::1',
'3031:3233:3435:3637:3839:4041:4243:4445',
'::ffff:192.0.2.128'
]) AS addr_str;
/*---------------------------------------------------------------------------------------------------------------*
| addr_str | ip_from_string |
+---------------------------------------------------------------------------------------------------------------+
| 48.49.50.51 | b"0123" |
| ::1 | b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x01" |
| 3031:3233:3435:3637:3839:4041:4243:4445 | b"0123456789@ABCDE" |
| ::ffff:192.0.2.128 | b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\xff\xff\xc0\x00\x02\x80" |
*---------------------------------------------------------------------------------------------------------------*/
NET.IP_NET_MASK
NET.IP_NET_MASK(num_output_bytes, prefix_length)
Description
Returns a network mask: a byte sequence with length equal to num_output_bytes
,
where the first prefix_length
bits are set to 1 and the other bits are set to
0. num_output_bytes
and prefix_length
are INT64.
This function throws an error if num_output_bytes
is not 4 (for IPv4) or 16
(for IPv6). It also throws an error if prefix_length
is negative or greater
than 8 * num_output_bytes
.
Return Data Type
BYTES
Example
SELECT x, y, FORMAT("%T", NET.IP_NET_MASK(x, y)) AS ip_net_mask
FROM UNNEST([
STRUCT(4 as x, 0 as y),
(4, 20),
(4, 32),
(16, 0),
(16, 1),
(16, 128)
]);
/*--------------------------------------------------------------------------------*
| x | y | ip_net_mask |
+--------------------------------------------------------------------------------+
| 4 | 0 | b"\x00\x00\x00\x00" |
| 4 | 20 | b"\xff\xff\xf0\x00" |
| 4 | 32 | b"\xff\xff\xff\xff" |
| 16 | 0 | b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00" |
| 16 | 1 | b"\x80\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00" |
| 16 | 128 | b"\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff\xff" |
*--------------------------------------------------------------------------------*/
NET.IP_TO_STRING
NET.IP_TO_STRING(addr_bin)
Description Converts an IPv4 or IPv6 address from binary (BYTES) format in network byte order to text (STRING) format.
If the input is 4 bytes, this function returns an IPv4 address as a STRING. If the input is 16 bytes, it returns an IPv6 address as a STRING.
If this function receives a NULL
input, it returns NULL
. If the input has
a length different from 4 or 16, an OUT_OF_RANGE
error occurs.
Return Data Type
STRING
Example
SELECT FORMAT("%T", x) AS addr_bin, NET.IP_TO_STRING(x) AS ip_to_string
FROM UNNEST([
b"0123",
b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x01",
b"0123456789@ABCDE",
b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\xff\xff\xc0\x00\x02\x80"
]) AS x;
/*---------------------------------------------------------------------------------------------------------------*
| addr_bin | ip_to_string |
+---------------------------------------------------------------------------------------------------------------+
| b"0123" | 48.49.50.51 |
| b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x01" | ::1 |
| b"0123456789@ABCDE" | 3031:3233:3435:3637:3839:4041:4243:4445 |
| b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\xff\xff\xc0\x00\x02\x80" | ::ffff:192.0.2.128 |
*---------------------------------------------------------------------------------------------------------------*/
NET.IP_TRUNC
NET.IP_TRUNC(addr_bin, prefix_length)
Description
Takes addr_bin
, an IPv4 or IPv6 address in binary (BYTES) format in network
byte order, and returns a subnet address in the same format. The result has the
same length as addr_bin
, where the first prefix_length
bits are equal to
those in addr_bin
and the remaining bits are 0.
This function throws an error if LENGTH(addr_bin)
is not 4 or 16, or if
prefix_len
is negative or greater than LENGTH(addr_bin) * 8
.
Return Data Type
BYTES
Example
SELECT
FORMAT("%T", x) as addr_bin, prefix_length,
FORMAT("%T", NET.IP_TRUNC(x, prefix_length)) AS ip_trunc
FROM UNNEST([
STRUCT(b"\xAA\xBB\xCC\xDD" as x, 0 as prefix_length),
(b"\xAA\xBB\xCC\xDD", 11), (b"\xAA\xBB\xCC\xDD", 12),
(b"\xAA\xBB\xCC\xDD", 24), (b"\xAA\xBB\xCC\xDD", 32),
(b'0123456789@ABCDE', 80)
]);
/*-----------------------------------------------------------------------------*
| addr_bin | prefix_length | ip_trunc |
+-----------------------------------------------------------------------------+
| b"\xaa\xbb\xcc\xdd" | 0 | b"\x00\x00\x00\x00" |
| b"\xaa\xbb\xcc\xdd" | 11 | b"\xaa\xa0\x00\x00" |
| b"\xaa\xbb\xcc\xdd" | 12 | b"\xaa\xb0\x00\x00" |
| b"\xaa\xbb\xcc\xdd" | 24 | b"\xaa\xbb\xcc\x00" |
| b"\xaa\xbb\xcc\xdd" | 32 | b"\xaa\xbb\xcc\xdd" |
| b"0123456789@ABCDE" | 80 | b"0123456789\x00\x00\x00\x00\x00\x00" |
*-----------------------------------------------------------------------------*/
NET.IPV4_FROM_INT64
NET.IPV4_FROM_INT64(integer_value)
Description
Converts an IPv4 address from integer format to binary (BYTES) format in network
byte order. In the integer input, the least significant bit of the IP address is
stored in the least significant bit of the integer, regardless of host or client
architecture. For example, 1
means 0.0.0.1
, and 0x1FF
means 0.0.1.255
.
This function checks that either all the most significant 32 bits are 0, or all
the most significant 33 bits are 1 (sign-extended from a 32-bit integer).
In other words, the input should be in the range [-0x80000000, 0xFFFFFFFF]
;
otherwise, this function throws an error.
This function does not support IPv6.
Return Data Type
BYTES
Example
SELECT x, x_hex, FORMAT("%T", NET.IPV4_FROM_INT64(x)) AS ipv4_from_int64
FROM (
SELECT CAST(x_hex AS INT64) x, x_hex
FROM UNNEST(["0x0", "0xABCDEF", "0xFFFFFFFF", "-0x1", "-0x2"]) AS x_hex
);
/*-----------------------------------------------*
| x | x_hex | ipv4_from_int64 |
+-----------------------------------------------+
| 0 | 0x0 | b"\x00\x00\x00\x00" |
| 11259375 | 0xABCDEF | b"\x00\xab\xcd\xef" |
| 4294967295 | 0xFFFFFFFF | b"\xff\xff\xff\xff" |
| -1 | -0x1 | b"\xff\xff\xff\xff" |
| -2 | -0x2 | b"\xff\xff\xff\xfe" |
*-----------------------------------------------*/
NET.IPV4_TO_INT64
NET.IPV4_TO_INT64(addr_bin)
Description
Converts an IPv4 address from binary (BYTES) format in network byte order to
integer format. In the integer output, the least significant bit of the IP
address is stored in the least significant bit of the integer, regardless of
host or client architecture. For example, 1
means 0.0.0.1
, and 0x1FF
means
0.0.1.255
. The output is in the range [0, 0xFFFFFFFF]
.
If the input length is not 4, this function throws an error.
This function does not support IPv6.
Return Data Type
INT64
Example
SELECT
FORMAT("%T", x) AS addr_bin,
FORMAT("0x%X", NET.IPV4_TO_INT64(x)) AS ipv4_to_int64
FROM
UNNEST([b"\x00\x00\x00\x00", b"\x00\xab\xcd\xef", b"\xff\xff\xff\xff"]) AS x;
/*-------------------------------------*
| addr_bin | ipv4_to_int64 |
+-------------------------------------+
| b"\x00\x00\x00\x00" | 0x0 |
| b"\x00\xab\xcd\xef" | 0xABCDEF |
| b"\xff\xff\xff\xff" | 0xFFFFFFFF |
*-------------------------------------*/
NET.PUBLIC_SUFFIX
NET.PUBLIC_SUFFIX(url)
Description
Takes a URL as a STRING
value and returns the public suffix (such as com
,
org
, or net
). A public suffix is an ICANN domain registered at
publicsuffix.org. For best results, URL values
should comply with the format as defined by
RFC 3986. If the URL value does not comply
with RFC 3986 formatting, this function makes a best effort to parse the input
and return a relevant result.
This function returns NULL
if any of the following is true:
- It cannot parse the host from the input;
- The parsed host contains adjacent dots in the middle (not leading or trailing);
- The parsed host does not contain any public suffix.
Before looking up the public suffix, this function temporarily normalizes the host by converting uppercase English letters to lowercase and encoding all non-ASCII characters with Punycode. The function then returns the public suffix as part of the original host instead of the normalized host.
Return Data Type
STRING
Example
SELECT
FORMAT("%T", input) AS input,
description,
FORMAT("%T", NET.HOST(input)) AS host,
FORMAT("%T", NET.PUBLIC_SUFFIX(input)) AS suffix,
FORMAT("%T", NET.REG_DOMAIN(input)) AS domain
FROM (
SELECT "" AS input, "invalid input" AS description
UNION ALL SELECT "http://abc.xyz", "standard URL"
UNION ALL SELECT "//user:password@a.b:80/path?query",
"standard URL with relative scheme, port, path and query, but no public suffix"
UNION ALL SELECT "https://[::1]:80", "standard URL with IPv6 host"
UNION ALL SELECT "http://例子.卷筒纸.中国", "standard URL with internationalized domain name"
UNION ALL SELECT " www.Example.Co.UK ",
"non-standard URL with spaces, upper case letters, and without scheme"
UNION ALL SELECT "mailto:?to=&subject=&body=", "URI rather than URL--unsupported"
);
input | description | host | suffix | domain |
---|---|---|---|---|
"" | invalid input | NULL | NULL | NULL |
"http://abc.xyz" | standard URL | "abc.xyz" | "xyz" | "abc.xyz" |
"//user:password@a.b:80/path?query" | standard URL with relative scheme, port, path and query, but no public suffix | "a.b" | NULL | NULL |
"https://[::1]:80" | standard URL with IPv6 host | "[::1]" | NULL | NULL |
"http://例子.卷筒纸.中国" | standard URL with internationalized domain name | "例子.卷筒纸.中国" | "中国" | "卷筒纸.中国" |
" www.Example.Co.UK " | non-standard URL with spaces, upper case letters, and without scheme | "www.Example.Co.UK" | "Co.UK" | "Example.Co.UK |
"mailto:?to=&subject=&body=" | URI rather than URL--unsupported | "mailto" | NULL | NULL |
NET.REG_DOMAIN
NET.REG_DOMAIN(url)
Description
Takes a URL as a string and returns the registered or registrable domain (the public suffix plus one preceding label), as a string. For best results, URL values should comply with the format as defined by RFC 3986. If the URL value does not comply with RFC 3986 formatting, this function makes a best effort to parse the input and return a relevant result.
This function returns NULL
if any of the following is true:
- It cannot parse the host from the input;
- The parsed host contains adjacent dots in the middle (not leading or trailing);
- The parsed host does not contain any public suffix;
- The parsed host contains only a public suffix without any preceding label.
Before looking up the public suffix, this function temporarily normalizes the host by converting uppercase English letters to lowercase and encoding all non-ASCII characters with Punycode. The function then returns the registered or registerable domain as part of the original host instead of the normalized host.
Return Data Type
STRING
Example
SELECT
FORMAT("%T", input) AS input,
description,
FORMAT("%T", NET.HOST(input)) AS host,
FORMAT("%T", NET.PUBLIC_SUFFIX(input)) AS suffix,
FORMAT("%T", NET.REG_DOMAIN(input)) AS domain
FROM (
SELECT "" AS input, "invalid input" AS description
UNION ALL SELECT "http://abc.xyz", "standard URL"
UNION ALL SELECT "//user:password@a.b:80/path?query",
"standard URL with relative scheme, port, path and query, but no public suffix"
UNION ALL SELECT "https://[::1]:80", "standard URL with IPv6 host"
UNION ALL SELECT "http://例子.卷筒纸.中国", "standard URL with internationalized domain name"
UNION ALL SELECT " www.Example.Co.UK ",
"non-standard URL with spaces, upper case letters, and without scheme"
UNION ALL SELECT "mailto:?to=&subject=&body=", "URI rather than URL--unsupported"
);
input | description | host | suffix | domain |
---|---|---|---|---|
"" | invalid input | NULL | NULL | NULL |
"http://abc.xyz" | standard URL | "abc.xyz" | "xyz" | "abc.xyz" |
"//user:password@a.b:80/path?query" | standard URL with relative scheme, port, path and query, but no public suffix | "a.b" | NULL | NULL |
"https://[::1]:80" | standard URL with IPv6 host | "[::1]" | NULL | NULL |
"http://例子.卷筒纸.中国" | standard URL with internationalized domain name | "例子.卷筒纸.中国" | "中国" | "卷筒纸.中国" |
" www.Example.Co.UK " | non-standard URL with spaces, upper case letters, and without scheme | "www.Example.Co.UK" | "Co.UK" | "Example.Co.UK" |
"mailto:?to=&subject=&body=" | URI rather than URL--unsupported | "mailto" | NULL | NULL |
NET.SAFE_IP_FROM_STRING
NET.SAFE_IP_FROM_STRING(addr_str)
Description
Similar to NET.IP_FROM_STRING
, but returns NULL
instead of throwing an error if the input is invalid.
Return Data Type
BYTES
Example
SELECT
addr_str,
FORMAT("%T", NET.SAFE_IP_FROM_STRING(addr_str)) AS safe_ip_from_string
FROM UNNEST([
'48.49.50.51',
'::1',
'3031:3233:3435:3637:3839:4041:4243:4445',
'::ffff:192.0.2.128',
'48.49.50.51/32',
'48.49.50',
'::wxyz'
]) AS addr_str;
/*---------------------------------------------------------------------------------------------------------------*
| addr_str | safe_ip_from_string |
+---------------------------------------------------------------------------------------------------------------+
| 48.49.50.51 | b"0123" |
| ::1 | b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\x01" |
| 3031:3233:3435:3637:3839:4041:4243:4445 | b"0123456789@ABCDE" |
| ::ffff:192.0.2.128 | b"\x00\x00\x00\x00\x00\x00\x00\x00\x00\x00\xff\xff\xc0\x00\x02\x80" |
| 48.49.50.51/32 | NULL |
| 48.49.50 | NULL |
| ::wxyz | NULL |
*---------------------------------------------------------------------------------------------------------------*/
Protocol buffer functions in GoogleSQL
GoogleSQL for Spanner supports the following protocol buffer functions.
Function list
Name | Summary |
---|---|
REPLACE_FIELDS
|
Replaces the values in one or more protocol buffer fields. |
REPLACE_FIELDS
REPLACE_FIELDS(proto_expression, value AS field_path [, ... ])
Description
Returns a copy of a protocol buffer, replacing the values in one or more fields.
field_path
is a delimited path to the protocol buffer field that is replaced.
When using replace_fields
, the following limitations apply:
- If
value
isNULL
, it un-setsfield_path
or returns an error if the last component offield_path
is a required field. - Replacing subfields will succeed only if the message containing the field is set.
- Replacing subfields of repeated field isn't allowed.
- A repeated field can be replaced with an
ARRAY
value.
Return type
Type of proto_expression
Examples
The following example uses protocol buffer messages Book
and BookDetails
.
message Book {
required string title = 1;
repeated string reviews = 2;
optional BookDetails details = 3;
};
message BookDetails {
optional string author = 1;
optional int32 chapters = 2;
};
This statement replaces the values of the field title
and subfield chapters
of proto type Book
. Note that field details
must be set for the statement
to succeed.
SELECT REPLACE_FIELDS(
NEW Book(
"The Hummingbird" AS title,
NEW BookDetails(10 AS chapters) AS details),
"The Hummingbird II" AS title,
11 AS details.chapters)
AS proto;
/*-----------------------------------------------------------------------------*
| proto |
+-----------------------------------------------------------------------------+
|{title: "The Hummingbird II" details: {chapters: 11 }} |
*-----------------------------------------------------------------------------*/
The function can replace value of repeated fields.
SELECT REPLACE_FIELDS(
NEW Book("The Hummingbird" AS title,
NEW BookDetails(10 AS chapters) AS details),
["A good read!", "Highly recommended."] AS reviews)
AS proto;
/*-----------------------------------------------------------------------------*
| proto |
+-----------------------------------------------------------------------------+
|{title: "The Hummingbird" review: "A good read" review: "Highly recommended."|
| details: {chapters: 10 }} |
*-----------------------------------------------------------------------------*/
The function can also set a field to NULL
.
SELECT REPLACE_FIELDS(
NEW Book("The Hummingbird" AS title,
NEW BookDetails(10 AS chapters) AS details),
NULL AS details)
AS proto;
/*-----------------------------------------------------------------------------*
| proto |
+-----------------------------------------------------------------------------+
|{title: "The Hummingbird" } |
*-----------------------------------------------------------------------------*/
Search functions in GoogleSQL
GoogleSQL for Spanner supports the following search functions.
Categories
The search functions are grouped into the following categories, based on their behavior:
Category | Functions | Description |
---|---|---|
Indexing |
TOKEN TOKENIZE_BOOL TOKENIZE_FULLTEXT TOKENIZE_NGRAMS TOKENIZE_NUMBER TOKENIZE_SUBSTRING TOKENLIST_CONCAT |
Functions that you can use to create search indexes. |
Retrieval and presentation |
SCORE SCORE_NGRAMS SEARCH SEARCH_NGRAMS SEARCH_SUBSTRING SNIPPET |
Functions that you can use to search for data, score the search result, or format the search result. |
Debugging |
DEBUG_TOKENLIST |
Functions that you can use for debugging. |
Function list
Name | Summary |
---|---|
DEBUG_TOKENLIST
|
Displays a human-readable representation of tokens present in the TOKENLIST value for debugging purposes. |
SCORE
|
Calculates a relevance score of a TOKENLIST for a full-text
search query. The higher the score, the stronger the match.
|
SCORE_NGRAMS
|
Calculates a relevance score of a TOKENLIST for a fuzzy search.
The higher the score, the stronger the match.
|
SEARCH
|
Returns TRUE if a full-text search query matches tokens. |
SEARCH_NGRAMS
|
Checks whether enough n-grams match the tokens in a fuzzy search. |
SEARCH_SUBSTRING
|
Returns TRUE if a substring query matches tokens. |
SNIPPET
|
Gets a list of snippets that match a full-text search query. |
TOKEN
|
Constructs an exact match TOKENLIST value by tokenizing a
BYTE or STRING value verbatim to accelerate
exact match expressions in SQL. |
TOKENIZE_BOOL
|
Constructs a boolean TOKENLIST value by tokenizing a
BOOL value to accelerate boolean match expressions in SQL.
|
TOKENIZE_FULLTEXT
|
Constructs a full-text TOKENLIST value by tokenizing text
for full-text matching. |
TOKENIZE_NGRAMS
|
Constructs an n-gram TOKENLIST value by tokenizing
a STRING value for matching n-grams.
|
TOKENIZE_NUMBER
|
Constructs a numeric TOKENLIST value by tokenizing numeric
values to accelerate numeric comparison expressions in SQL.
|
TOKENIZE_SUBSTRING
|
Constructs a substring TOKENLIST value by tokenizing text for
substring matching. |
DEBUG_TOKENLIST
DEBUG_TOKENLIST(tokenlist)
Description
Displays a human-readable representation of tokens present in a TOKENLIST
value for debugging purposes.
Definitions
tokenlist
: TheTOKENLIST
value to display.
Details
The output of this function is dependent on the source of the TOKENLIST
value
provided as input.
Return type
STRING
Examples
The following query illustrates how attributes and positions are represented:
- In
hello(boundary)
,hello
is the text of the token andboundary
is an attribute of the token. - Token
db
has no attributes. - In
[#world, world](boundary)
,#world
andworld
are both tokens added to the tokenlist, at the same position.boundary
is the attribute for both of them. This can match either#world
orworld
query terms.
SELECT DEBUG_TOKENLIST(TOKENIZE_FULLTEXT('Hello DB #World')) AS Result;
/*------------------------------------------------+
| Result |
+------------------------------------------------+
| hello(boundary), db, [#world, world](boundary) |
+------------------------------------------------*/
The following query illustrates how equality and range are represented:
==1
and==10
represent equality tokens for1
and10
.[1, 1]
represents a range token with1
as the lower bound and1
as the upper bound.
SELECT DEBUG_TOKENLIST(TOKENIZE_NUMBER([1, 10], min=> 1, max=>10)) AS Result;
/*--------------------------------------------------------------------------------+
| Result |
+--------------------------------------------------------------------------------+
| ==1, ==10, [1, 1], [1, 2], [1, 4], [1, 8], [9, 10], [9, 12], [9, 16], [10, 10] |
+--------------------------------------------------------------------------------*/
SCORE
SCORE(
tokens,
raw_search_query
[, language_tag => value ]
[, enhance_query => { TRUE | FALSE } ]
[, options => value ]
)
Description
Calculates a relevance score of a TOKENLIST
for a full-text search query. The
higher the score, the stronger the match.
Definitions
tokens
: ATOKENLIST
value that represents a list of full-text tokens.raw_search_query
: ASTRING
value that represents a raw search query.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forraw_search_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.enhance_query
: A named argument with aBOOL
value. The value determines whether to enhance the search query. For example, ifenhance_query
is enabled, a search query containing the termclassic
can expand to include similar terms such asclassical
. The search query isn't enhanced if theenhance_query
call takes longer than the timeout.If
TRUE
, the search query is enhanced to improve search quality.If
FALSE
(default), the search query isn't enhanced.
options
: A named argument with aJSON
value. The value represents the fine-tuning for the search scoring.bigram_weight
: A multiplier for bigrams, which have matching terms adjacent to each other. The default is 2.0.idf_weight
: A multiplier for term commonality. Hits on rare terms will score relatively higher than hits on common terms. The default is 1.0.token_category_weights
: A multiplier for each HTML category. The available categories are:small
,medium
,large
,title
.
Details
- This function must reference a full-text
TOKENLIST
column in a table that is also indexed in a search index. To add a full-textTOKENLIST
column to a table and to a search index, see the examples for this function. - This function requires the
SEARCH
function in the same SQL query. - This function returns
0
whentokens
orraw_search_query
isNULL
.
Return type
FLOAT64
Examples
The following examples reference a table called Albums
and a search index
called AlbumsIndex
.
The Albums
table contains a column called DescriptionTokens
, which tokenizes
the input added to the Description
column, and then saves those tokens in the
DescriptionTokens
column. Finally, AlbumsIndex
indexes DescriptionTokens
.
Once DescriptionTokens
is indexed, it can be used with the SCORE
function.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionTokens TOKENLIST AS (TOKENIZE_FULLTEXT(Description)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionTokens);
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 1, 'classical album');
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 2, 'classical and rock album');
The following query searches the column called Description
for a token called
classical album
. If this token is found for singer ID 1
, the matching
Description
are returned with the corresponding score. Both classical album
and classical and rock album
have the terms classical
and album
, but the
first one has a higher score because the terms are adjacent.
SELECT
a.Description, SCORE(a.DescriptionTokens, 'classical album') AS Score
FROM
Albums a
WHERE
SEARCH(a.DescriptionTokens, 'classical album');
/*--------------------------+---------------------*
| Description | Score |
+--------------------------+---------------------+
| classical album | 1.2818930149078369 |
| classical and rock album | 0.50003194808959961 |
*--------------------------+---------------------*/
The following query is like the previous one. However, scores are boosted more
with bigram_weight
on adjacent positions.
SELECT
a.Description,
SCORE(
a.DescriptionTokens,
'classical album',
options=>JSON '{"bigram_weight": 3.0}'
) AS Score
FROM Albums a
WHERE SEARCH(a.DescriptionTokens, 'classical album');
/*--------------------------+---------------------*
| Description | Score |
+--------------------------+---------------------+
| classical album | 1.7417128086090088 |
| classical and rock album | 0.50003194808959961 |
*--------------------------+---------------------*/
The following query uses SCORE
in the ORDER BY
clause to get the row with
the highest score.
SELECT a.Description
FROM Albums a
WHERE SEARCH(a.DescriptionTokens, 'classical album')
ORDER BY SCORE(a.DescriptionTokens, 'classical album') DESC
LIMIT 1;
/*--------------------------*
| Description |
+--------------------------+
| classical album |
*--------------------------*/
SCORE_NGRAMS
SCORE_NGRAMS(
tokens,
ngrams_query
[, language_tag => value ]
[, algorithm => value ]
)
Description
Calculates a relevance score of a TOKENLIST
for a fuzzy search. The higher
the score, the stronger the match.
Definitions
tokens
: ATOKENLIST
value that contains a list of ngrams tokens. You can generate aTOKENLIST
using eitherTOKENIZE_SUBSTRING
orTOKENIZE_NGRAMS
, which tokenizes the source column directly.TOKENLIST
generated from an expression isn't supported for scoring, for example,TOKENIZE_SUBSTRING(REGEXP_REPLACE(col, 'foo', 'bar))
.ngrams_query
: ASTRING
value that represents a fuzzy search query.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forngrams_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.algorithm
: A named argument with aSTRING
value. The value specifies the scoring algorithm for the fuzzy search. The default value for this argument istrigrams
, and currently it's the only supported algorithm.trigrams
: Generates trigrams (n-grams with size 3) without duplication from the query, then also generates trigrams without duplication from the source column of thetokens
. Matches are an intersection between query trigrams and source trigrams. The score is roughly calculated as(match_count / (query_trigrams + source_trigrams - match_count))
.
Details
- This function returns
0
whentokens
orngrams_query
isNULL
. - Unlike
SEARCH_NGRAMS
, this function requires access to the source column oftokens
. Therefore, it is often advantageous to include the source column inSEARCH INDEX
'sSTORING
clause, to avoid a join with the base table. Please see index-only scans.
Return type
FLOAT64
Examples
The following examples reference a table called Albums
and a search index
called AlbumsIndex
.
The Albums
table contains a column DescriptionSubstrTokens
which tokenizes
Description
column using TOKENIZE_SUBSTRING
. Finally, AlbumsIndex
stores
Description
, so that the query below does not have to join with the base
table.
CREATE TABLE Albums (
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionSubstrTokens TOKENLIST AS
(TOKENIZE_SUBSTRING(Description, ngram_size_max=>3)) HIDDEN
) PRIMARY KEY (AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionSubstrTokens)
STORING(Description);
INSERT INTO Albums (AlbumId, Description) VALUES (1, 'rock album');
INSERT INTO Albums (AlbumId, Description) VALUES (2, 'classical album');
The following query scores Description
with clasic albun
, which is
misspelled.
SELECT
a.Description, SCORE_NGRAMS(a.DescriptionSubstrTokens, 'clasic albun') AS Score
FROM
Albums a
/*-----------------+---------------------*
| Description | Score |
+-----------------+---------------------+
| rock album | 0.14285714285714285 |
| classical album | 0.38095238095238093 |
*-----------------+---------------------*/
The following query uses SCORE_NGRAMS
in the ORDER BY
clause to produce the
row with the highest score.
SELECT a.Description
FROM Albums a
WHERE SEARCH_NGRAMS(a.DescriptionSubstrTokens, 'clasic albun')
ORDER BY SCORE_NGRAMS(a.DescriptionSubstrTokens, 'clasic albun') DESC
LIMIT 1
/*-----------------*
| Description |
+-----------------+
| classical album |
*-----------------*/
SEARCH
SEARCH(
tokens,
raw_search_query
[, language_tag => value]
[, enhance_query => { TRUE | FALSE }]
)
Description
Returns TRUE
if a full-text search query matches tokens.
Definitions
tokens
: ATOKENLIST
value that is a list of full-text tokens.raw_search_query
: ASTRING
value that is a raw search query. The raw query is written using a domain-specific language (DSL) called rquery. For an overview of rquery, see rquery syntax overview. For rquery syntax rules, see rquery syntax.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forraw_search_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.enhance_query
: A named argument with aBOOL
value. The value determines whether to enhance the search query. For example, ifenhance_query
is enabled, a search query containing the termclassic
can expand to include similar terms such asclassical
. The search query isn't enhanced if theenhance_query
call takes longer than the timeout.If
TRUE
, the search query is enhanced to improve search quality.If
FALSE
(default), the search query isn't enhanced.
Details
- Returns
TRUE
if a TOKENLISTtokens
is a match forraw_search_query
. - This function must reference a full-text
TOKENLIST
column in a table that is also indexed in a search index. To add a full-textTOKENLIST
column to a table and to a search index, see the examples for this function. - This function returns
NULL
whentokens
orraw_search_query
isNULL
. - This function can only be used in the
WHERE
clause of a SQL query.
rquery syntax
The rquery syntax rules are as follows:
- Multiple terms imply
AND
. For example, "big time" is equivalent tobig AND time
. The
OR
operator implies disjunction between two terms, such asbig OR time
. The predicateSEARCH(tl, 'big time OR fast car')
is equivalent to:SEARCH(tl, 'big') AND (SEARCH(tl, 'time') OR SEARCH(tl, 'fast')) AND SEARCH(tl, 'car');
OR
only applies to the two adjacent terms so the search expressionbig time OR fast car
searches for all the documents that have the termsbig
andcar
and eithertime
orfast
.The OR
operator is case sensitive.The pipe character (
|
) is a shortcut forOR
.Double quotes mean a phrase search. For example, the rquery
"fast car"
matches "You got a fast car", but doesn't match "driving fast in my car".The
AROUND
operator matches terms that are within a certain distance of each other, and in the same order (the default is five tokens). For example, the rqueryfast AROUND car
matches "driving fast in my car", but doesn't match "driving fast in his small shiny metal Italian car". The default is to match terms separated by, at most, five positions. To adjust the distance, pass an argument to theAROUND
operator. supports two syntaxes forAROUND
:fast AROUND(10) car
fast AROUND 10 car
The
AROUND
operator is case sensitive.Negation of a single term is expressed with a dash (
-
). For example-dog
matches all documents that don't contain the termdog
.Punctuation is generally ignored. For example, "Fast Car!" is equivalent to "Fast Car". For more information, see the
TOKENIZE_FULLTEXT
punctuation rules.Search is case insensitive. For example, "Fast Car" matches "fast car".
The following table explains the meaning of various rquery strings:
rquery | Explanation |
---|---|
Miles Davis |
Matches documents that contain both terms "Miles" and "Davis". |
Miles OR Davis |
Matches documents that contain at least one of the terms "Miles" and "Davis". |
-Davis |
Matches all documents that don't contain the term "Davis". |
"Miles Davis" -"Miles Jaye" |
Matches documents that contain two adjacent terms "Miles" and "Davis", but don't contain adjacent "Miles" and "Jaye". For example, this query matches "I saw Miles Davis last night and Jaye earlier today", but doesn't match "I saw Miles Davis and Miles Jaye perform together". |
Davis|Jaye |
This is the same as Davis OR Jaye. |
and OR or |
Matches documents that have either the term "and" or the term "or" (the OR operator must be upper case) |
Return type
BOOL
Examples
The following examples reference a table called Albums
and a search index
called AlbumsIndex
.
The Albums
table contains a column called DescriptionTokens
, which tokenizes
the Description
column using TOKENIZE_FULLTEXT
, and then saves those tokens
in the DescriptionTokens
column. Finally, AlbumsIndex
indexes
DescriptionTokens
. Once DescriptionTokens
is indexed, it can be used with
the SEARCH
function.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionTokens TOKENLIST AS (TOKENIZE_FULLTEXT(Description)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionTokens)
PARTITION BY SingerId;
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 1, 'rock album');
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 2, 'classical album');
The following query searches the column called Description
for a token called
classical
. If this token is found for singer ID 1
, the matching rows are
returned.
SELECT a.AlbumId, a.Description
FROM Albums a
WHERE a.SingerId = 1 AND SEARCH(a.DescriptionTokens, 'classical');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
*---------------------------*/
The following query is like the previous one. However, if Description
contains
the classical
or rock
token, the matching rows are returned.
SELECT a.AlbumId, a.Description
FROM Albums a
WHERE a.SingerId = 1 AND SEARCH(a.DescriptionTokens, 'classical OR rock');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
| 1 | rock album |
*---------------------------*/
The following query is like the previous ones. However, if Description
contains the classic
and albums
token, the matching rows are returned. When
enhance_query
is enabled, it includes similar matches of classical
and
album
.
SELECT a.AlbumId, a.Description
FROM Albums a
WHERE a.SingerId = 1 AND SEARCH(a.DescriptionTokens, 'classic albums', enhance_query => TRUE);
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
*---------------------------*/
SEARCH_NGRAMS
SEARCH_NGRAMS(
tokens,
ngrams_query
[, language_tag => value ]
[, min_ngrams => value ]
[, min_ngrams_percent => value ]
)
Description
Checks whether enough n-grams match the tokens in a fuzzy search.
Definitions
tokens
: ATOKENLIST
value that contains a list of n-grams. It must be aTOKENLIST
generated by eitherTOKENIZE_SUBSTRING
orTOKENIZE_NGRAMS
.ngrams_query
: ASTRING
value that represents a fuzzy search query. This function generates ngram query terms from this value, usingtokens
'sngram_size_max
as ngram size, or query as is if the query is shorter thanngram_size_max
. Then the function looks for those ngrams intokens
. Whentokens
is generated byTOKENIZE_SUBSTRING
,ngrams_query
value is broken into words first, then n-grams are generated from the each word.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forngrams_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.min_ngrams
: A named argument with anINT64
value. The value specifies the minimum number of n-grams inngrams_query
that have to match in order forSEARCH_NGRAMS
to returntrue
. This only counts distinct n-grams and ignores repeating n-grams. The default value for this argument is2
.min_ngrams_percent
: A named argument with aFLOAT64
value. The value specifies the minimum percentage of n-grams inngrams_query
that have to match in order forSEARCH_NGRAMS
to returntrue
. This only counts distinct n-grams and ignores repeating n-grams.
Details
- This function must reference a substring or n-grams
TOKENLIST
column in a table that is also indexed in a search index. - This function returns
NULL
whentokens
orngrams_query
isNULL
. - This function returns
false
if the length ofngrams_query
is smaller thanngram_size_min
oftokens
. - This function can only be used in the
WHERE
clause of a SQL query.
Return type
BOOL
Examples
The following examples reference a table called Albums
and a search index
called AlbumsIndex
.
The Albums
table contains columns DescriptionSubstrTokens
and
DescriptionNgramsTokens
which tokenize a Description
column using
TOKENIZE_SUBSTRING
and TOKENIZE_NGRAMS
, respectively. Finally, AlbumsIndex
indexes DescriptionSubstrTokens
and DescriptionNgramsTokens
.
CREATE TABLE Albums (
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionSubstrTokens TOKENLIST AS
(TOKENIZE_SUBSTRING(Description, ngram_size_min=>3, ngram_size_max=>3)) HIDDEN,
DescriptionNgramsTokens TOKENLIST AS
(TOKENIZE_NGRAMS(Description, ngram_size_min=>3, ngram_size_max=>3)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionSubstrTokens, DescriptionNgramsTokens);
INSERT INTO Albums (AlbumId, Description) VALUES (1, 'rock album');
INSERT INTO Albums (AlbumId, Description) VALUES (2, 'classical album');
INSERT INTO Albums (AlbumId, Description) VALUES (3, 'last note');
The following query searches the column Description
for clasic
. The query
is misspelled, so querying with
SEARCH_SUBSTRING(a.DescriptionSubstrTokens, 'clasic')
doesn't return a row,
but the n-grams search is able to find similar matches.
SEARCH_NGRAMS
first transforms the query clasic
into n-grams of size 3 (the
value of DescriptionSubstrTokens
's ngram_size_max
), producing
['asi', 'cla', 'las', 'sic']
. Then it finds rows that have at least two of
these n-grams (the default value for min_ngrams
) in the
DescriptionSubstrTokens
column.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
SEARCH_NGRAMS(a.DescriptionSubstrTokens, 'clasic');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
*---------------------------*/
If we change the min_ngrams
to 1, then the query will also return the row with
last
which has one n-gram match with las
. This example illustrates the
decreased relevancy of the returned results when this parameter is set low.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
SEARCH_NGRAMS(a.DescriptionSubstrTokens, 'clasic', min_ngrams=>1);
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
| 3 | last notes |
*---------------------------*/
The following query searches the column Description
for clasic albun
. As the
DescriptionSubstrTokens
is tokenized by TOKENIZE_SUBSTRING
, the query is
segmented into ['clasic', 'albun']
first, then n-gram tokens are generated
from those words, producing the following:
['alb', 'asi', 'bun', 'cla', 'las', 'lbu', 'sic']
.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
SEARCH_NGRAMS(a.DescriptionSubstrTokens, 'clasic albun');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
| 1 | rock album |
*---------------------------*/
The following query searches the column Description
for l al
, but using the
DescriptionNgramsTokens
this time. As the DescriptionNgramsTokens
is
generated by TOKENIZE_NGRAMS
, there is no splitting into words before making
n-gram tokens, so the query n-gram tokens are generated as the following:
['%20al', 'l%20a']
.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
SEARCH_NGRAMS(a.DescriptionNgramsTokens, 'l al');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
*---------------------------*/
SEARCH_SUBSTRING
SEARCH_SUBSTRING(
tokens,
substring_query
[, language_tag => value ]
[, relative_search_type => value ]
)
Description
Returns TRUE
if a substring query matches tokens.
Definitions
tokens
: ATOKENLIST
value that is a list of substring tokens.substring_query
: ASTRING
value that represents a substring query.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forsubstring_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.relative_search_type
: A named argument with aSTRING
value. The value refines the substring search result. To use a givenrelative_search_type
, the substringTOKENLIST
must have been generated with the corresponding type in itsTOKENIZE_SUBSTRING
relative_search_types
argument. We support these relative search types:phrase
: The substring query terms must appear adjacent to one another and in order in the tokenized value (the value that was tokenized to produce thetokens
argument).value_prefix
: The substring query terms must be found at the start of tokenized value.value_suffix
: The substring query terms must be found at the end of tokenized value.word_prefix
: The substring query terms must be found at the start of a word in the tokenized value.word_suffix
: The substring query terms must be found at the end of a word in the tokenized value.
Details
- Returns
TRUE
iftokens
is a match forsubstring_query
. - This function must reference a substring
TOKENLIST
column in a table that is also indexed in a search index. To add a substringTOKENLIST
column to a table and to a search index, see the examples for this function. - This function returns
NULL
whentokens
orsubstring_query
isNULL
. - This function can only be used in the
WHERE
clause of a SQL query.
Return type
BOOL
Examples
The following examples reference a table called Albums
and a search index
called AlbumsIndex
.
The Albums
table contains a column called DescriptionSubstrTokens
, which
tokenizes the input added to the Description
column using
TOKENIZE_SUBSTRING
, and then saves those substring tokens in the
DescriptionSubstrTokens
column. Finally, AlbumsIndex
indexes
DescriptionSubstrTokens
. Once DescriptionSubstrTokens
is indexed, it can be
used with the SEARCH_SUBSTRING
function.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionSubstrTokens TOKENLIST AS (TOKENIZE_SUBSTRING(Description, support_relative_search=>TRUE)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionSubstrTokens)
PARTITION BY SingerId;
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 1, 'rock album');
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 2, 'classical album');
The following query searches the column called Description
for a token called
ssic
. If this token is found for singer ID 1
, the matching rows are
returned.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
a.SingerId = 1 AND SEARCH_SUBSTRING(a.DescriptionSubstrTokens, 'ssic');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
*---------------------------*/
The following query searches the column called Description
for a token called
both lbu
and oc
. If these tokens are found for singer ID 1
, the matching
rows are returned.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
a.SingerId = 1 AND SEARCH_SUBSTRING(a.DescriptionSubstrTokens, 'lbu oc');
/*-----------------------*
| AlbumId | Description |
+-----------------------+
| 1 | rock album |
*-----------------------*/
The following query searches the column called Description
for a token called
al
at the start of a word. If this token is found for singer ID 1
, the
matching rows are returned.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
a.SingerId = 1 AND SEARCH_SUBSTRING(a.DescriptionSubstrTokens, 'al', relative_search_type=>'word_prefix');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| 2 | classical album |
| 1 | rock album |
*---------------------------*/
The following query searches the column called Description
for a token called
al
at the start of tokens. If this token is found for singer ID 1
, the
matching rows are returned. Because there are no matches, no rows are returned.
SELECT
a.AlbumId, a.Description
FROM
Albums a
WHERE
a.SingerId = 1 AND SEARCH_SUBSTRING(a.DescriptionSubstrTokens, 'al', relative_search_type=>'value_prefix');
/*---------------------------*
| AlbumId | Description |
+---------------------------+
| | |
*---------------------------*/
SNIPPET
SNIPPET(
data_to_search,
raw_search_query
[, language_tag => value ]
[, enhance_query => { TRUE | FALSE } ]
[, max_snippet_width => value ]
[, max_snippets => value ]
[, content_type => value ]
)
Description
Gets a list of snippets that match a full-text search query.
Definitions
data_to_search
: ASTRING
value that represents the data to search over.raw_search_query
: ASTRING
value that represents the terms of a raw search query.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forraw_search_query
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.max_snippets
: A named argument with anINT64
value. The value represents the maximum number of output snippets to produce.max_snippet_width
: A named argument with anINT64
value. The value represents the width of the output snippet. The width is measured by the estimated number of average proportional-width characters. For example, a wide character like 'M' will use up more space than a narrow character like 'i'.enhance_query
: A named argument with aBOOL
value. The value determines whether to enhance the search query. For example, ifenhance_query
is enabled, a search query containing the termclassic
can expand to include similar terms such asclassical
. The search query isn't enhanced if theenhance_query
call takes longer than the timeout.If
TRUE
, the search query is enhanced to improve search quality.If
FALSE
(default), the search query isn't enhanced.
content_type
: A named argument with aSTRING
value. The value represents the mime type of the content. Currently,"text/html"
is supported for this function.
Details
Each snippet contains a matching substring of the data_to_search
, and a list
of highlights for the location of matching terms.
This function returns NULL
when data_to_search
or raw_search_query
is
NULL
.
Return type
JSON
The JSON
value has this format and definitions:
{
"snippets":[
{
"highlights":[
{
"end_position": json_number,
"start_position": json_number
},
]
"snippet": json_string
}
]
}
snippets
: A JSON object that contains snippets fromdata_to_search
. These are snippets of text forraw_search_query
from the provideddata_to_search
argument.highlights
: A JSON array that contains the position of each search term found insnippet
.begin
: A JSON number that represents the position of a search term's first character insnippet
.end
: A JSON number that represents the position of a search term's final character insnippet
.snippet
: A JSON string that represents an individual snippet fromsnippets
.
Examples
The following query produces a single snippet, Rock albums rock.
with two
highlighted positions for the matching raw search query term, rock
:
SELECT SNIPPET('Rock albums rock.', 'rock') AS Snippet
/*---------------------------------------------------*
| Snippet |
+---------------------------------------------------+
| {"snippets":[ |
| {"highlights":[ |
| {"begin":1, "end":5}, |
| {"begin":13,"end":17} |
| ], "snippet":"Rock albums rock."} |
| ]} |
*---------------------------------------------------*/
TOKEN
TOKEN(value_to_tokenize)
Description
Constructs an exact match TOKENLIST
value by tokenizing a BYTE
or STRING
value verbatim to accelerate exact match expressions in SQL.
Definitions
value_to_tokenize
: ABYTE
,ARRAY<BYTE>
,STRING
orARRAY<STRING>
value to tokenize for searching with exact match expressions.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
.
Return type
TOKENLIST
Examples
The Albums
table contains a column called SingerNameToken
and
SongTitlesToken
, which tokenizes the SingerName
and SongTitles
columns
respectively using the TOKEN
function. Finally, AlbumsIndex
indexes
SingerNameToken
and SongTitlesToken
, which makes it possible for
Spanner to use the index to accelerate exact-match expressions in SQL.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
SingerName STRING(MAX),
SingerNameToken TOKENLIST AS (TOKEN(SingerName)) HIDDEN,
SongTitles ARRAY<STRING(MAX)>,
SongTitlesToken TOKENLIST AS (TOKEN(SongTitles)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(SingerNameToken, SongTitlesToken);
-- For example, the INSERT statement below generates SingerNameToken of
-- 'Catalina Smith', and SongTitlesToken of
-- ['Starting Again', 'The Second Title'].
INSERT INTO Albums (SingerId, AlbumId, SingerName, SongTitles)
VALUES (1, 1, 'Catalina Smith', ['Starting Again', 'The Second Time']);
The following query finds the column SingerName
is equal to Catalina Smith
.
The query optimizer could choose to accelerate the condition using AlbumsIndex
with SingerNameToken
. Optionally, the query can provide
@{force_index = AlbumsIndex}
to force the optimizer to use AlbumsIndex
.
SELECT a.AlbumId
FROM Albums @{force_index = AlbumsIndex} a
WHERE a.SingerName = 'Catalina Smith';
/*---------*
| AlbumId |
+---------+
| 1 |
*---------*/
The following query is like the previous ones. However, this time the query
searches for SongTitles
that contain the string Starting Again
. Array
conditions should use ARRAY_INCLUDES
, ARRAY_INCLUDES_ANY
or
ARRAY_INCLUDES_ALL
functions to be eligible for using a search index for
acceleration.
SELECT a.AlbumId
FROM Albums a
WHERE ARRAY_INCLUDES(a.SongTitles, 'Starting Again');
/*---------*
| AlbumId |
+---------+
| 1 |
*---------*/
TOKENIZE_BOOL
TOKENIZE_BOOL(value_to_tokenize)
Description
Constructs a boolean TOKENLIST
value by tokenizing a BOOL
value to
accelerate boolean match expressions in SQL.
Definitions
value_to_tokenize
: ABOOL
orARRAY<BOOL>
value to tokenize for boolean match.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
.
Return type
TOKENLIST
Examples
The Albums
table contains a column called IsAwardedToken
, which tokenizes
the IsAwarded
column using TOKENIZE_BOOL
function. Finally, AlbumsIndex
indexes IsAwardedToken
, which makes it possible for Spanner
to use the index to accelerate boolean-match expressions in SQL.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
IsAwarded BOOL,
IsAwardedToken TOKENLIST AS (TOKENIZE_BOOL(IsAwarded)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(IsAwardedToken);
-- IsAwarded with TRUE generates IsAwardedToken with value 'y'.
INSERT INTO Albums (SingerId, AlbumId, IsAwarded) VALUES (1, 1, TRUE);
-- IsAwarded with FALSE generates IsAwardedToken with value 'n'.
INSERT INTO Albums (SingerId, AlbumId, IsAwarded) VALUES (1, 2, FALSE);
-- NULL IsAwarded generates IsAwardedToken with value NULL.
INSERT INTO Albums (SingerId, AlbumId) VALUES (1, 3);
The following query finds the column IsAwarded
is equal to TRUE
. The query
optimizer could choose to accelerate the condition using AlbumsIndex
with
IsAwardedToken
. Optionally, the query can provide
@{force_index = AlbumsIndex}
to force the optimizer to use AlbumsIndex
.
SELECT a.AlbumId
FROM Albums @{force_index = AlbumsIndex} a
WHERE IsAwarded = TRUE;
TOKENIZE_FULLTEXT
TOKENIZE_FULLTEXT(
value_to_tokenize
[, language_tag => value ]
[, content_type => { "text/plain" | "text/html" } ]
[, token_category => { "small" | "medium" | "large" | "title" } ]
)
Description
Constructs a full-text TOKENLIST
value by tokenizing text for full-text
matching.
Definitions
value_to_tokenize
: ASTRING
orARRAY<STRING>
value to tokenize for full-text search.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forvalue_to_tokenize
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.content_type
: A named argument with aSTRING
value. Indicates the MIME type ofvalue
. This can be:"text/plain"
(default):value
contains plain text. All tokens are assigned to the small token category."text/html"
:value
contains HTML. The HTML tags are removed. HTML-escaped entities are replaced with their unescaped equivalents (for example,<
becomes<
). A token category is assigned to each token depending on its prominence in the HTML. For example, bolded text or text in a<h1>
tag might have higher prominence than normal text and thus might be placed into a different token category.We use token categories during scoring to boost the weight of high-prominence tokens.
token_category
: A named argument with aSTRING
value. Sets or overrides the token importance signals detected by the tokenizer and used by the scorer. Useful for cases where two or more tokenlists will be combined withTOKENLIST_CONCAT
and one of the input columns is known to have higher or lower than usual importance.Allowed values:
"small"
: The category with the lowest importance."medium"
: The category with the second lowest importance."large"
: The category with the second highest importance."title"
: The category with the highest importance.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
.
Return type
TOKENLIST
Examples
In the following example, a TOKENLIST
column is created using the
TOKENIZE_FULLTEXT
function:
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Title STRING(MAX),
Description STRING(MAX),
DescriptionTokens TOKENLIST AS (TOKENIZE_FULLTEXT(Description)) HIDDEN,
TitleTokens TOKENLIST AS (
TOKENIZE_FULLTEXT(Title, token_category=>"title")) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
-- DescriptionTokens is generated from the Description value, using the
-- TOKENIZE_FULLTEXT function. For example, the following INSERT statement
-- generates DescriptionTokens with the tokens ['rock', 'album']. TitleTokens
-- will contain ['abbey', 'road'] and these tokens will be assigned to the
-- "title" token category.
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 1, 'rock album');
-- Capitalization and delimiters are removed during tokenization. For example,
-- the following INSERT statement generates DescriptionTokens with the tokens
-- ['classical', 'albums'].
INSERT INTO Albums (SingerId, AlbumId, Description) VALUES (1, 1, 'Classical, Albums.');
To query a full-text TOKENLIST
column, see the
SEARCH function.
TOKENIZE_NGRAMS
TOKENIZE_NGRAMS(
value_to_tokenize
[, ngram_size_min => value ]
[, ngram_size_max => value ]
[, remove_diacritics => { TRUE | FALSE } ]
)
Description
Constructs an n-gram TOKENLIST
value by tokenizing a STRING
value for
matching n-grams.
Definitions
value_to_tokenize
: ASTRING
value to tokenize for the n-gram match.remove_diacritics
: A named argument with aBOOL
value. IfTRUE
, the diacritics is removed fromvalue_to_tokenize
before indexing. This is useful when you want to search a substring or ngram, regardless of diacritics. When a search query is called on aTOKENLIST
value withremove_diacritics
set asTRUE
, the diacritics will also be removed at query time from the search queries.ngram_size_min
: A named argument with anINT64
value. The value is the minimum length of the n-gram tokens to generate. The default value for this argument is1
. This argument must be less than or equal tongram_size_max
.Queries or
TOKENLIST
s generated from input values shorter thanngram_size_min
never match anything, since no n-grams are generated for such queries or values.We recommend tuning
ngram_size_min
only when the developer controls the queries and can ensure that the minimum query length is at leastngram_size_min
.ngram_size_max
: A named argument with anINT64
value. The value is the maximum size of each n-gram token to generate. A larger value can improve retrieval performance by reducing the number of non-matching records that have any given n-gram. However, larger values can substantially increase index sizes and write costs.When using the
SEARCH_NGRAMS
function,ngram_size_max
is the length of n-grams shared between the query and the value that are counted when deciding whether a value reaches themin_ngrams
ormin_ngrams_percent
threshold. For more information, seeSEARCH_NGRAMS
.The default value for this argument is
4
.When using the
TOKENLIST
result with theSEARCH_NGRAMS
function, we recommend setting this value to3
.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
.
Return type
TOKENLIST
Examples
In the following example, a TOKENLIST
column is created using the
TOKENIZE_NGRAMS
function. The INSERT
generates a TOKENLIST
which contains
two sets of tokens. First, the whole string is broken up into n-grams with a
length in the range [ngram_size_min, ngram_size_max-1]
. Capitalization and
whitespace are preserved in the n-grams. These n-grams are placed in the first
position in the tokenlist.
[" ", " M", " Me", "vy ", "y ", "y M", H, He, Hea, Heav, ...], ...
Second, any n-grams with length equal to ngram_size_max
are stored in
sequence, with the first of these in the same position as the smaller n-grams.
(In this example, the Heav
token is in the first position.)
..., eavy, "avy ", "vy M", "y Me", " Met", Meta, etal
CREATE TABLE Albums (
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionNgramTokens TOKENLIST AS (TOKENIZE_NGRAMS(Description)) HIDDEN
) PRIMARY KEY (AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(DescriptionNgramTokens);
INSERT INTO Albums (AlbumId, Description) VALUES (1, 'Heavy Metal');
To query an n-gram TOKENLIST
column, see the
SEARCH_NGRAMS function.
TOKENIZE_NUMBER
TOKENIZE_NUMBER(
value_to_tokenize,
[, comparison_type => { "all" | "equality" } ]
[, algorithm => { "logtree" | "prefixtree" | "floatingpoint" } ]
[, min => value ]
[, max => value ]
[, granularity => value ]
[, tree_base => value ]
[, precision => value ]
)
Description
Constructs a numeric TOKENLIST
value by tokenizing numeric values to
accelerate numeric comparison expressions in SQL.
Definitions
value_to_tokenize
: AnINT64
,FLOAT32
,FLOAT64
orARRAY
of these types to tokenize for numeric comparison expressions.comparison_type
: A named argument with aSTRING
value. The value represents the type of comparison to use for numeric expressions. Set toequality
to save space if equality is only required comparison. Default isall
.algorithm
: A named argument with aSTRING
value. The value indicates the indexing algorithm to use. Supported algorithms are limited, depending on the type of value being indexed. The default islogtree
.FLOAT32
orFLOAT64
must not use default. They should specify the algorithm and must also usemin
andmax
when using thelogtree
orprefixtree
algorithms.logtree
: Use for indexing uniformly distributed data.min
andmax
must be specified ifvalue_to_tokenize
isFLOAT32
orFLOAT64
.prefixtree
: Use when indexing exponentially distributed data and when query predicate is of the form "@param > number
" or "@param >= number
" (ranges without an upper bound). Compared tologtree
, this algorithm generates fewer index tokens for small numbers. For queries where theWHERE
clause contains the predicate previously described,prefixtree
generates fewer query tokens, which can improve performance.min
andmax
must be specified ifvalue_to_tokenize
isFLOAT32
orFLOAT64
.floatingpoint
: Use for indexingFLOAT32
orFLOAT64
values where the indexed data and queries often contain fractions. When tokenizingFLOAT32
orFLOAT64
usinglogtree
orprefixtree
,TOKENIZE_NUMBER
might lose precision as the count ofgranularity
buckets in themin
tomax
range approaches the maximum resolution of floating point numbers. This can make queries less efficient, but it doesn't cause incorrect behavior. This loss of precision doesn't happen with thefloatingpoint
algorithm if theprecision
argument is set high enough. However, thefloatingpoint
algorithm generates more index tokens whenprecision
is set to a larger value.
min
: A named argument with the same type asvalue_to_tokenize
. Values less thanmin
are indexed in the same index bucket. This will not cause incorrect results, but may cause significant over-retrieval for queries with a range that includes values lesser thanmin
. Don't usemin
whencomparison_type
isequality
.max
: A named argument with the same type asvalue_to_tokenize
. Values greater thanmax
are indexed in the same index bucket. This doesn't cause incorrect results, but might cause significant over-retrieval for queries with a range that includes values greater than themax
. Don't usemax
whencomparison_type
isequality
.granularity
: A named argument with the same type asvalue_to_tokenize
. The value represents the width of each indexing bucket. Values in the same bucket are indexed together, so larger buckets are more storage efficient, but may cause over-retrieval, causing high latency during query execution.granularity
is only allowed whenalgorithm
islogtree
orprefixtree
.tree_base
: A named argument with anINT64
value. The value is the numerical base of a tree for tree-based algorithms.For example, the value of
2
means that each tree token represents some power-of-two number of buckets. In the case of a value indexed in the 1024th bucket, there is a token for [1024,1024], then a token for [1024,1025], then a token for [1024, 1027], and so on.Increasing
tree_base
reduces the required number of index tokens and increases the required number of query tokens.The default value is 2.
tree_base
is only allowed whenalgorithm
islogtree
orprefixtree
.precision
: A named argument with anINT64
value. Reducing the precision reduces the number of index tokens, but increases over-retrieval when queries specify ranges with a high number of significant digits. The default value is 15.precision
is only allowed whenalgorithm
isfloatingpoint
.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
. - The
tree_base
parameter controls the width of each tree bucket in thelogtree
andprefixtree
algorithms. Both algorithms generate tokens representing nodes in abase
-ary tree where the width of a node isbasedistance_from_leaf
. The algorithms differ in thatprefixtree
omits some of the tree nodes in favor of greater-than tokens that accelerate greater-than queries. When a larger base is selected, fewer index tokens are generated. However, largerbase
values increase the maximum number of query tokens required. - Numbers that fall outside of the
[min, max]
range are all indexed into two buckets: one for all numbers less thanmin
, and the other for all numbers greater thanmax
. This might cause significant over-retrieval (retrieval of too many candidate results) when the range requested by the query also includes numbers outside of the range. For this reason, setmin
andmax
to the narrowest possible values that encompass all input numbers. Like all tokenization configurations, changing themin
andmax
values requires a rebuild of the numeric index, so leave room to grow if the final domain of a column isn't known. The problem of over-retrieval is not a correctness problem as all potential matches are checked against non-bucketized numbers at the end of the search process; it's only a potential efficiency issue. - The
granularity
argument controls the rate of downsampling that's applied to numbers before they are indexed in the tree-based algorithms. Before each number is tokenized, it's sorted into buckets with a width equal togranularity
. All the numbers in the samegranularity
bucket get the same tokens. This means that over-retrieval might occur if the granularity value is set to anything other than 1 for integral numbers. Over retrieval is always possible forFLOAT64
numbers. It also means that if numeric values change by a small amount, most of their tokens don't need to be reindexed. Using agranularity
higher than 1 also reduces the number of tokens that the algorithm needs to generate, but the effect is less significant than the effect of increasing thebase
. Therefore, we recommend that 'granularity' is set to 1.
Return type
TOKENLIST
Examples
The Albums
table contains a column called the RatingTokens
, which tokenizes
the Rating
column using the TOKENIZE_NUMBER
function. Finally, AlbumsIndex
indexes RatingTokens
, which makes it possible for Spanner
to use the index to accelerate numeric comparison expressions in SQL.
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Rating INT64,
RatingTokens TOKENLIST AS (TOKENIZE_NUMBER(Rating)) HIDDEN,
TrackRating ARRAY<INT64>,
TrackRatingTokens TOKENLIST AS (TOKENIZE_NUMBER(TrackRating)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
CREATE SEARCH INDEX AlbumsIndex ON Albums(RatingTokens, TrackRatingTokens);
-- RatingTokens and TrackRatingTokens are generated from Rating and TrackRating
-- values, respectively, using the TOKENIZE_NUMBER function.
INSERT INTO Albums (SingerId, AlbumId, Rating, TrackRating) VALUES (1, 1, 2, [2, 3]);
INSERT INTO Albums (SingerId, AlbumId, Rating, TrackRating) VALUES (1, 2, 5, [3, 5]);
The following query finds rows in which the column Rating
is equal to 5
. The
query optimizer might choose to accelerate the condition using AlbumsIndex
with RatingTokens
. Optionally, the query can provide
@{force_index = AlbumsIndex}
to force the optimizer to use AlbumsIndex
.
SELECT a.AlbumId
FROM Albums @{force_index = AlbumsIndex} a
WHERE a.Rating = 5;
/*---------*
| AlbumId |
+---------+
| 2 |
*---------*/
The following query is like the previous one. However, the condition is on the
array column of TrackRating
this time. Array conditions should use
ARRAY_INCLUDES
, ARRAY_INCLUDES_ANY
or ARRAY_INCLUDES_ALL
functions to be
eligible for using a search index for acceleration.
SELECT a.AlbumId
FROM Albums a
WHERE ARRAY_INCLUDES_ALL(a.TrackRating, [2, 3]);
/*---------*
| AlbumId |
+---------+
| 1 |
*---------*/
SELECT a.AlbumId
FROM Albums a
WHERE ARRAY_INCLUDES_ANY(a.TrackRating, [3, 4, 5]);
/*---------*
| AlbumId |
+---------+
| 1 |
| 2 |
*---------*/
The following query is like the previous ones. However, the condition is range
this time. This query can also be accelerated, as default comparison_type
is
all
which covers both equality
and range
comparisons.
SELECT a.AlbumId
FROM Albums a
WHERE a.Rating >= 2;
/*---------*
| AlbumId |
+---------+
| 1 |
| 2 |
*---------*/
TOKENIZE_SUBSTRING
TOKENIZE_SUBSTRING(
value_to_tokenize
[, language_tag => value ]
[, ngram_size_min => value ]
[, ngram_size_max => value ]
[, relative_search_types => value ]
[, content_type => { "text/plain" | "text/html" } ]
[, remove_diacritics => { TRUE | FALSE } ]
[, short_tokens_only_for_anchors => {TRUE | FALSE } ]
)
Description
Constructs a substring TOKENLIST
value, which tokenizes text for substring
matching.
Definitions
value_to_tokenize
: ASTRING
orARRAY<STRING>
value to tokenize for a substring search.language_tag
: A named argument with aSTRING
value. The value contains an IETF BCP 47 language tag. You can use this tag to specify the language forvalue_to_tokenize
. If the value for this argument isNULL
, this function doesn't use a specific language. If this argument is not specified,NULL
is used by default.relative_search_types
: A named argument with anARRAY<STRING>
value. The value determines whichTOKENIZE_SUBSTRING
relative search types are supported. See SEARCH_SUBSTRING for a list of the different relative search types.In addition to the relative search types from
SEARCH_SUBSTRING
, TOKENIZE_SUBSTRING accepts a special flag,all
, which means that all relative search types are supported.If this argument is not used, then no relative search tokens are generated for the resulting
TOKENLIST
value.Setting this value causes extra anchor tokens to be generated to enable relative searches. A given relative search type can only be used in a query if that type, or
all
, is present in therelative_search_types
argument. By default,relative_search_types
is empty.content_type
: A named argument with aSTRING
value. Indicates the MIME type ofvalue
. This can be:"text/plain"
(default):value
contains plain text. All tokens are assigned to the small token category."text/html"
:value
contains HTML. The HTML tags are removed. HTML-escaped entities are replaced with their unescaped equivalents (for example,<
becomes<
). A token category is assigned to each token depending on its prominence in the HTML. For example, bolded text or text in a<h1>
tag might have higher prominence than normal text and thus might be placed into a different token category.We use token categories during scoring to boost the weight of high-prominence tokens.
remove_diacritics
: A named argument with aBOOL
value. IfTRUE
, the diacritics is removed fromvalue_to_tokenize
before indexing. This is useful when you want to search a substring or ngram, regardless of diacritics. When a search query is called on aTOKENLIST
value withremove_diacritics
set asTRUE
, the diacritics will also be removed at query time from the search queries.ngram_size_min
: A named argument with anINT64
value. The value is the minimum length of the n-gram tokens to generate. The default value for this argument is1
. This argument must be less than or equal tongram_size_max
.Whole words that are shorter than
ngram_size_min
ignore this argument and are emitted regardless of how short they are.SEARCH_SUBSTRING
can retrieve values containing such words, but only if the query text exactly matches the whole word.ngram_size_max
: A named argument with anINT64
value. The value is the maximum size of each n-gram token to generate. A larger value can improve retrieval performance by reducing the number of non-matching records that have any given n-gram. However, larger values can substantially increase index sizes and write costs.When using the
SEARCH_NGRAMS
function,ngram_size_max
is the length of n-grams shared between the query and the value that are counted when deciding whether a value reaches themin_ngrams
ormin_ngrams_percent
threshold. For more information, seeSEARCH_NGRAMS
.The default value for this argument is
4
.When using the
TOKENLIST
result with theSEARCH_NGRAMS
function, we recommend setting this value to3
.When using the
TOKENLIST
result withSEARCH_SUBSTRING
, we recommend not tuning this value unless retrieval performance problems related to excessively common n-grams are detected.short_tokens_only_for_anchors
: A named argument with aBOOL
value. If true, theTOKENLIST
emitted by this function does not contain short n-grams — those with sizes less thanngram_size_max
— except when those n-grams are part of one of the anchors used to support the prefix and suffixrelative_search_types
settings. The default value isFALSE
.Setting this to
TRUE
can reduce the number of n-grams generated. However, it causesSEARCH_SUBSTRING
to returnFALSE
for short query terms whenrelative_search_types
is not one of the prefix or suffix modes. Therefore, we recommend setting this only whenrelative_search_types
will always be set to a prefix or suffix mode.
Details
- This function returns
NULL
whenvalue_to_tokenize
isNULL
.
Return type
TOKENLIST
Example
In the following example, a TOKENLIST
column is created using the
TOKENIZE_SUBSTRING
function. The INSERT
generates a TOKENLIST
which
contains two sets of tokens. First, each word is broken up into n-grams with a
length in the range [ngram_size_min, ngram_size_max-1]
, and any whole words
with a length shorter than that ngram_size_max
. All of these tokens are placed
in the first position in the tokenlist.
[a, al, av, avy, e, ea, eav, et, eta, h, he, hea, ...], ...
Second, any n-grams with length equal to ngram_size_max
are stored in
subsequent positions. These tokens are used when searching for words larger than
the maximum ngram size.
..., heav, eavy, <gap(1)>, meta, etal
CREATE TABLE Albums (
SingerId INT64 NOT NULL,
AlbumId INT64 NOT NULL,
Description STRING(MAX),
DescriptionSubstrTokens TOKENLIST
AS (TOKENIZE_SUBSTRING(Description, ngram_size_min=>1, ngram_size_max=>4)) HIDDEN
) PRIMARY KEY (SingerId, AlbumId);
INSERT INTO Albums (SingerId, AlbumId, Description)
VALUES (1, 1, 'Heavy Metal');
To query a substring TOKENLIST
column, see the
SEARCH_SUBSTRING or
SEARCH_NGRAMS function.
Sequence functions in GoogleSQL
GoogleSQL for Spanner supports the following sequence functions.
Function list
Name | Summary |
---|---|
GET_INTERNAL_SEQUENCE_STATE
|
Gets the current sequence internal counter before bit reversal. |
GET_NEXT_SEQUENCE_VALUE
|
Takes in a sequence identifier and returns the next value. This function is only allowed in read-write transactions. |
GET_INTERNAL_SEQUENCE_STATE
GET_INTERNAL_SEQUENCE_STATE(SEQUENCE sequence_identifier)
Description
Gets the current sequence internal counter before bit reversal. This function is
useful for import or export, and migrations. If GET_NEXT_SEQUENCE_VALUE
is
never called on the sequence, then this function returns NULL
.
Arguments
sequence_identifier
: The ID for the sequence.
Return Data Type
INT64
Example
SELECT GET_NEXT_SEQUENCE_VALUE(SEQUENCE MySequence) AS next_value;
/*---------------------*
| next_value |
+---------------------+
| 5980780305148018688 |
*---------------------*/
SELECT GET_INTERNAL_SEQUENCE_STATE(SEQUENCE MySequence) AS sequence_state;
/*----------------*
| sequence_state |
+----------------+
| 399 |
*----------------*/
GET_NEXT_SEQUENCE_VALUE
GET_NEXT_SEQUENCE_VALUE(SEQUENCE sequence_identifier)
Description
Gets the next integer in a sequence.
Arguments
sequence_identifier
: The ID for the sequence.
Return Data Type
INT64
Example
Create a table where its key column uses the sequence as a default value.
CREATE TABLE Singers (
SingerId INT64 DEFAULT (GET_NEXT_SEQUENCE_VALUE(SEQUENCE MySequence)),
a STRING(MAX),
) PRIMARY KEY (SingerId);
Obtain a sequence value in a read-write transaction and use it in an INSERT statement.
SELECT GET_NEXT_SEQUENCE_VALUE(SEQUENCE MySequence) as next_id;
INSERT INTO Singers(SingerId, a) VALUES (next_id, 1);
Use the sequence functions independently in the GoogleSQL DML.
INSERT INTO Singers (SingerId) VALUES (GET_NEXT_SEQUENCE_VALUE(SEQUENCE MySequence);
Statistical aggregate functions in GoogleSQL
GoogleSQL for Spanner supports statistical aggregate functions. To learn about the syntax for aggregate function calls, see Aggregate function calls.
Function list
Name | Summary |
---|---|
STDDEV
|
An alias of the STDDEV_SAMP function.
|
STDDEV_SAMP
|
Computes the sample (unbiased) standard deviation of the values. |
VAR_SAMP
|
Computes the sample (unbiased) variance of the values. |
VARIANCE
|
An alias of VAR_SAMP .
|
STDDEV
STDDEV(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
An alias of STDDEV_SAMP.
STDDEV_SAMP
STDDEV_SAMP(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the sample (unbiased) standard deviation of the values. The return
result is between 0
and +Inf
.
All numeric types are supported. If the
input is NUMERIC
then the internal aggregation is
stable with the final output converted to a FLOAT64
.
Otherwise the input is converted to a FLOAT64
before aggregation, resulting in a potentially unstable result.
This function ignores any NULL
inputs. If there are fewer than two non-NULL
inputs, this function returns NULL
.
NaN
is produced if:
- Any input value is
NaN
- Any input value is positive infinity or negative infinity.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Return Data Type
FLOAT64
Examples
SELECT STDDEV_SAMP(x) AS results FROM UNNEST([10, 14, 18]) AS x
/*---------*
| results |
+---------+
| 4 |
*---------*/
SELECT STDDEV_SAMP(x) AS results FROM UNNEST([10, 14, NULL]) AS x
/*--------------------*
| results |
+--------------------+
| 2.8284271247461903 |
*--------------------*/
SELECT STDDEV_SAMP(x) AS results FROM UNNEST([10, NULL]) AS x
/*---------*
| results |
+---------+
| NULL |
*---------*/
SELECT STDDEV_SAMP(x) AS results FROM UNNEST([NULL]) AS x
/*---------*
| results |
+---------+
| NULL |
*---------*/
SELECT STDDEV_SAMP(x) AS results FROM UNNEST([10, 14, CAST('Infinity' as FLOAT64)]) AS x
/*---------*
| results |
+---------+
| NaN |
*---------*/
VAR_SAMP
VAR_SAMP(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
Returns the sample (unbiased) variance of the values. The return result is
between 0
and +Inf
.
All numeric types are supported. If the
input is NUMERIC
then the internal aggregation is
stable with the final output converted to a FLOAT64
.
Otherwise the input is converted to a FLOAT64
before aggregation, resulting in a potentially unstable result.
This function ignores any NULL
inputs. If there are fewer than two non-NULL
inputs, this function returns NULL
.
NaN
is produced if:
- Any input value is
NaN
- Any input value is positive infinity or negative infinity.
To learn more about the optional aggregate clauses that you can pass into this function, see Aggregate function calls.
Return Data Type
FLOAT64
Examples
SELECT VAR_SAMP(x) AS results FROM UNNEST([10, 14, 18]) AS x
/*---------*
| results |
+---------+
| 16 |
*---------*/
SELECT VAR_SAMP(x) AS results FROM UNNEST([10, 14, NULL]) AS x
/*---------*
| results |
+---------+
| 8 |
*---------*/
SELECT VAR_SAMP(x) AS results FROM UNNEST([10, NULL]) AS x
/*---------*
| results |
+---------+
| NULL |
*---------*/
SELECT VAR_SAMP(x) AS results FROM UNNEST([NULL]) AS x
/*---------*
| results |
+---------+
| NULL |
*---------*/
SELECT VAR_SAMP(x) AS results FROM UNNEST([10, 14, CAST('Infinity' as FLOAT64)]) AS x
/*---------*
| results |
+---------+
| NaN |
*---------*/
VARIANCE
VARIANCE(
[ DISTINCT ]
expression
[ HAVING { MAX | MIN } expression2 ]
)
Description
An alias of VAR_SAMP.
String functions in GoogleSQL
GoogleSQL for Spanner supports 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 position. 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.
Function list
Name | Summary |
---|---|
ARRAY_TO_STRING
|
Produces a concatenation of the elements in an array as a
STRING value.
For more information, see Array functions. |
BYTE_LENGTH
|
Gets the number of BYTES in a STRING or
BYTES value.
|
CHAR_LENGTH
|
Gets the number of characters in a STRING value.
|
CHARACTER_LENGTH
|
Synonym for CHAR_LENGTH .
|
CODE_POINTS_TO_BYTES
|
Converts an array of extended ASCII code points to a
BYTES value.
|
CODE_POINTS_TO_STRING
|
Converts an array of extended ASCII code points to a
STRING value.
|
CONCAT
|
Concatenates one or more STRING or BYTES
values into a single result.
|
ENDS_WITH
|
Checks if a STRING or BYTES value is the suffix
of another value.
|
FORMAT
|
Formats data and produces the results as a STRING value.
|
FROM_BASE32
|
Converts a base32-encoded STRING value into a
BYTES value.
|
FROM_BASE64
|
Converts a base64-encoded STRING value into a
BYTES value.
|
FROM_HEX
|
Converts a hexadecimal-encoded STRING value into a
BYTES value.
|
LAX_STRING
|
Attempts to convert a JSON value to a SQL STRING value.
For more information, see JSON functions. |
LENGTH
|
Gets the length of a STRING or BYTES value.
|
LOWER
|
Formats alphabetic characters in a STRING value as
lowercase.
Formats ASCII characters in a BYTES value as
lowercase.
|
LPAD
|
Prepends a STRING or BYTES value with a pattern.
|
LTRIM
|
Identical to the TRIM function, but only removes leading
characters.
|
NORMALIZE
|
Case-sensitively normalizes the characters in a STRING value.
|
NORMALIZE_AND_CASEFOLD
|
Case-insensitively normalizes the characters in a STRING value.
|
REGEXP_CONTAINS
|
Checks if a value is a partial match for a regular expression. |
REGEXP_EXTRACT
|
Produces a substring that matches a regular expression. |
REGEXP_EXTRACT_ALL
|
Produces an array of all substrings that match a regular expression. |
REGEXP_REPLACE
|
Produces a STRING value where all substrings that match a
regular expression are replaced with a specified value.
|
REPEAT
|
Produces a STRING or BYTES value that consists of
an original value, repeated.
|
REPLACE
|
Replaces all occurrences of a pattern with another pattern in a
STRING or BYTES value.
|
REVERSE
|
Reverses a STRING or BYTES value.
|
RPAD
|
Appends a STRING or BYTES value with a pattern.
|
RTRIM
|
Identical to the TRIM function, but only removes trailing
characters.
|
SAFE_CONVERT_BYTES_TO_STRING
|
Converts a BYTES value to a STRING value and
replace any invalid UTF-8 characters with the Unicode replacement character,
U+FFFD .
|
SOUNDEX
|
Gets the Soundex codes for words in a STRING value.
|
SPLIT
|
Splits a STRING or BYTES value, using a delimiter.
|
STARTS_WITH
|
Checks if a STRING or BYTES value is a
prefix of another value.
|
STRING (JSON)
|
Converts a JSON string to a SQL STRING value.
For more information, see JSON functions. |
STRING_ARRAY
|
Converts a JSON array of strings to a SQL ARRAY<STRING>
value.
For more information, see JSON functions. |
STRING (Timestamp)
|
Converts a TIMESTAMP value to a STRING value.
For more information, see Timestamp functions. |
STRING_AGG
|
Concatenates non-NULL STRING or
BYTES values.
For more information, see Aggregate functions. |
STRPOS
|
Finds the position of the first occurrence of a subvalue inside another value. |
SUBSTR
|
Gets a portion of a STRING or BYTES value.
|
TO_BASE32
|
Converts a BYTES value to a
base32-encoded STRING value.
|
TO_BASE64
|
Converts a BYTES value to a
base64-encoded STRING value.
|
TO_CODE_POINTS
|
Converts a STRING or BYTES value into an array of
extended ASCII code points.
|
TO_HEX
|
Converts a BYTES value to a
hexadecimal STRING value.
|
TRIM
|
Removes the specified leading and trailing Unicode code points or bytes
from a STRING or BYTES value.
|
UPPER
|
Formats alphabetic characters in a STRING value as
uppercase.
Formats ASCII characters in a BYTES value as
uppercase.
|
BYTE_LENGTH
BYTE_LENGTH(value)
Description
Gets the number of BYTES
in a STRING
or BYTES
value,
regardless of whether the value is a STRING
or BYTES
type.
Return type
INT64
Examples
SELECT BYTE_LENGTH('абвгд') AS string_example;
/*----------------*
| string_example |
+----------------+
| 10 |
*----------------*/
SELECT BYTE_LENGTH(b'абвгд') AS bytes_example;
/*----------------*
| bytes_example |
+----------------+
| 10 |
*----------------*/
CHAR_LENGTH
CHAR_LENGTH(value)
Description
Gets the number of characters in a STRING
value.
Return type
INT64
Examples
SELECT CHAR_LENGTH('абвгд') AS char_length;
/*-------------*
| char_length |
+-------------+
| 5 |
*------------ */
CHARACTER_LENGTH
CHARACTER_LENGTH(value)
Description
Synonym for CHAR_LENGTH.
Return type
INT64
Examples
SELECT
'абвгд' AS characters,
CHARACTER_LENGTH('абвгд') AS char_length_example
/*------------+---------------------*
| characters | char_length_example |
+------------+---------------------+
| абвгд | 5 |
*------------+---------------------*/
CODE_POINTS_TO_BYTES
CODE_POINTS_TO_BYTES(ascii_code_points)
Description
Takes an array of extended ASCII
code points
as ARRAY<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;
-- Note that the result of CODE_POINTS_TO_BYTES is of type BYTES, displayed as a base64-encoded string.
-- In BYTES format, b'AbCd' is the result.
/*----------*
| bytes |
+----------+
| QWJDZA== |
*----------*/
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;
-- Note that the result of CODE_POINTS_TO_BYTES is of type BYTES, displayed as a base64-encoded string.
-- In BYTES format, b'Grfg Fgevat!' is the result.
/*------------------*
| encoded_string |
+------------------+
| R3JmZyBGZ2V2YXQh |
*------------------*/
CODE_POINTS_TO_STRING
CODE_POINTS_TO_STRING(unicode_code_points)
Description
Takes an array of Unicode code points
as ARRAY<INT64>
and returns a STRING
.
To convert from a string to an array of code points, see TO_CODE_POINTS.
Return type
STRING
Examples
The following are basic examples using CODE_POINTS_TO_STRING
.
SELECT CODE_POINTS_TO_STRING([65, 255, 513, 1024]) AS string;
/*--------*
| string |
+--------+
| AÿȁЀ |
*--------*/
SELECT CODE_POINTS_TO_STRING([97, 0, 0xF9B5]) AS string;
/*--------*
| string |
+--------+
| a例 |
*--------*/
SELECT CODE_POINTS_TO_STRING([65, 255, NULL, 1024]) AS string;
/*--------*
| string |
+--------+
| NULL |
*--------*/
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 STRING
or BYTE
values into a single result.
The function returns NULL
if any input argument is NULL
.
Return type
STRING
or BYTES
Examples
SELECT CONCAT('T.P.', ' ', 'Bar') as author;
/*---------------------*
| author |
+---------------------+
| T.P. Bar |
*---------------------*/
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(value, suffix)
Description
Takes two STRING
or BYTES
values. Returns TRUE
if suffix
is a suffix of value
.
Return type
BOOL
Examples
SELECT ENDS_WITH('apple', 'e') as example
/*---------*
| example |
+---------+
| True |
*---------*/
FORMAT
FORMAT(format_string_expression, data_type_expression[, ...])
Description
FORMAT
formats a data type expression as a string.
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. In general, 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.data_type_expression
: The value to format as a string. This can be any GoogleSQL data type.
Return type
STRING
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:
SELECT FORMAT('date: %s!', FORMAT_DATE('%B %d, %Y', date '2015-01-02'));
Returns
date: January 02, 2015!
Supported format specifiers
%[flags][width][.precision]specifier
A format specifier adds formatting when casting a value to a string. It can optionally contain these sub-specifiers:
Additional information about format specifiers:
- %g and %G behavior
- %p and %P behavior
- %t and %T behavior
- Error conditions
- NULL argument handling
- Additional semantic rules
Format specifiers
Specifier | Description | Examples | Types |
d or i |
Decimal integer | 392 |
INT64 |
o |
Octal
Note: If an INT64 value is negative, an error is produced.
|
610 |
INT64 |
x |
Hexadecimal integer
Note: If an INT64 value is negative, an error is produced.
|
7fa |
INT64 |
X |
Hexadecimal integer (uppercase)
Note: If an INT64 value is negative, an error is produced.
|
7FA |
INT64 |
f |
Decimal notation, in [-](integer part).(fractional part) for finite values, and in lowercase for non-finite values | 392.650000 inf nan |
NUMERIC FLOAT32 FLOAT64 |
F |
Decimal notation, in [-](integer part).(fractional part) for finite values, and in uppercase for non-finite values | 392.650000 INF NAN |
NUMERIC FLOAT32 FLOAT64 |
e |
Scientific notation (mantissa/exponent), lowercase | 3.926500e+02 inf nan |
NUMERIC FLOAT32 FLOAT64 |
E |
Scientific notation (mantissa/exponent), uppercase | 3.926500E+02 INF NAN |
NUMERIC FLOAT32 FLOAT64 |
g |
Either decimal notation or scientific notation, depending on the input value's exponent and the specified precision. Lowercase. See %g and %G behavior for details. | 392.65 3.9265e+07 inf nan |
NUMERIC FLOAT32 FLOAT64 |
G |
Either decimal notation or scientific notation, depending on the input value's exponent and the specified precision. Uppercase. See %g and %G behavior for details. |
392.65 3.9265E+07 INF NAN |
NUMERIC FLOAT32 FLOAT64 |
p |
Produces a one-line printable string representing a protocol buffer or JSON. See %p and %P behavior. |
year: 2019 month: 10 {"month":10,"year":2019} |
JSON PROTO |
P |
Produces a multi-line printable string representing a protocol buffer or JSON. See %p and %P behavior. |
year: 2019 month: 10 { "month": 10, "year": 2019 } |
JSON PROTO |
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 and %T behavior.
|
sample 2014‑01‑01 |
Any type |
T |
Produces a string that is a valid GoogleSQL constant with a similar type to the value's type (maybe wider, or maybe string). See %t and %T behavior. |
'sample' b'bytes sample' 1234 2.3 date '2014‑01‑01' |
Any type |
% |
'%%' produces a single '%' | % | n/a |
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 |
# |
|
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> |
|
.* |
The precision is not specified in the format string, but as an additional integer value argument preceding the argument that has to be formatted |
%g and %G behavior
The %g
and %G
format specifiers choose either the decimal notation (like
the %f
and %F
specifiers) or the scientific notation (like the %e
and %E
specifiers), depending on the input value's exponent and the specified
precision.
Let p stand for the specified precision (defaults to 6; 1 if the specified precision is less than 1). The input value is first converted to scientific notation with precision = (p - 1). If the resulting exponent part x is less than -4 or no less than p, the scientific notation with precision = (p - 1) is used; otherwise the decimal notation with precision = (p - 1 - x) is used.
Unless #
flag is present, the trailing zeros after the decimal point
are removed, and the decimal point is also removed if there is no digit after
it.
%p and %P behavior
The %p
format specifier produces a one-line printable string. The %P
format specifier produces a multi-line printable string. You can use these
format specifiers with the following data types:
Type | %p | %P |
PROTO |
PROTO input: message ReleaseDate { required int32 year = 1 [default=2019]; required int32 month = 2 [default=10]; } Produces a one-line printable string representing a protocol buffer: year: 2019 month: 10 |
PROTO input: message ReleaseDate { required int32 year = 1 [default=2019]; required int32 month = 2 [default=10]; } Produces a multi-line printable string representing a protocol buffer: year: 2019 month: 10 |
JSON |
JSON input: JSON ' { "month": 10, "year": 2019 } ' Produces a one-line printable string representing JSON: {"month":10,"year":2019} |
JSON input: JSON ' { "month": 10, "year": 2019 } ' Produces a multi-line printable string representing JSON: { "month": 10, "year": 2019 } |
%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.
The %t
specifier is always meant to be a readable form of the value.
The %T
specifier 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 |
NUMERIC | 123.0 (always with .0) | NUMERIC "123.0" |
FLOAT32, 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" |
BOOL | boolean value | boolean value |
ENUM | EnumName | "EnumName" |
DATE | 2011-02-03 | DATE "2011-02-03" |
TIMESTAMP | 2011-02-03 04:05:06+00 | TIMESTAMP "2011-02-03 04:05:06+00" |
PROTO | one-line printable string representing a protocol buffer. | quoted string literal with one-line printable string representing a protocol buffer. |
ARRAY | [value, value, ...] where values are formatted with %t |
[value, value, ...] where values are formatted with %T |
JSON |
one-line printable string representing JSON.{"name":"apple","stock":3} |
one-line printable string representing a JSON literal.JSON '{"name":"apple","stock":3}' |
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 STRING
s 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
and
FLOAT32
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
GoogleSQL casts these values to STRING
. For %T
,
GoogleSQL returns quoted strings for
FLOAT64
values that don't have non-string literal
representations.
FROM_BASE32
FROM_BASE32(string_expr)
Description
Converts the base32-encoded input string_expr
into BYTES
format. To convert
BYTES
to a base32-encoded STRING
, use TO_BASE32.
Return type
BYTES
Example
SELECT FROM_BASE32('MFRGGZDF74======') AS byte_data;
-- Note that the result of FROM_BASE32 is of type BYTES, displayed as a base64-encoded string.
/*-----------*
| byte_data |
+-----------+
| YWJjZGX/ |
*-----------*/
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][string-link-to-base64].
There are several base64 encodings in common use that vary in exactly which
alphabet of 65 ASCII characters are used to encode the 64 digits and padding.
See RFC 4648 for details. This
function expects the alphabet [A-Za-z0-9+/=]
.
Return type
BYTES
Example
SELECT FROM_BASE64('/+A=') AS byte_data;
-- Note that the result of FROM_BASE64 is of type BYTES, displayed as a base64-encoded string.
/*-----------*
| byte_data |
+-----------+
| /+A= |
*-----------*/
To work with an encoding using a different base64 alphabet, you might need to
compose FROM_BASE64
with the REPLACE
function. For instance, the
base64url
url-safe and filename-safe encoding commonly used in web programming
uses -_=
as the last characters rather than +/=
. To decode a
base64url
-encoded string, replace -
and _
with +
and /
respectively.
SELECT FROM_BASE64(REPLACE(REPLACE('_-A=', '-', '+'), '_', '/')) AS binary;
-- Note that the result of FROM_BASE64 is of type BYTES, displayed as a base64-encoded string.
/*--------*
| binary |
+--------+
| /+A= |
*--------*/
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;
-- Note that the result of FROM_HEX is of type BYTES, displayed as a base64-encoded string.
/*------------------+--------------*
| hex_str | bytes_str |
+------------------+--------------+
| 0AF | AAECA6ru7/8= |
| 00010203aaeeefff | AK8= |
| 666f6f626172 | Zm9vYmFy |
*------------------+--------------*/
LENGTH
LENGTH(value)
Description
Returns the length of the STRING
or BYTES
value. The returned
value is in characters for STRING
arguments and in bytes for the BYTES
argument.
Return type
INT64
Examples
SELECT
LENGTH('абвгд') AS string_example,
LENGTH(CAST('абвгд' AS BYTES)) AS bytes_example;
/*----------------+---------------*
| string_example | bytes_example |
+----------------+---------------+
| 5 | 10 |
*----------------+---------------*/
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
SELECT
LOWER('FOO BAR BAZ') AS example
FROM items;
/*-------------*
| example |
+-------------+
| foo bar baz |
*-------------*/
LPAD
LPAD(original_value, return_length[, pattern])
Description
Returns a STRING
or BYTES
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 of type
BYTES
, return_length
is the number of bytes. If original_value
is
of type 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 FORMAT('%T', LPAD('c', 5)) AS results
/*---------*
| results |
+---------+
| " c" |
*---------*/
SELECT LPAD('b', 5, 'a') AS results
/*---------*
| results |
+---------+
| aaaab |
*---------*/
SELECT LPAD('abc', 10, 'ghd') AS results
/*------------*
| results |
+------------+
| ghdghdgabc |
*------------*/
SELECT LPAD('abc', 2, 'd') AS results
/*---------*
| results |
+---------+
| ab |
*---------*/
SELECT FORMAT('%T', LPAD(b'abc', 10, b'ghd')) AS results
/*---------------*
| results |
+---------------+
| b"ghdghdgabc" |
*---------------*/
LTRIM
LTRIM(value1[, value2])
Description
Identical to TRIM, but only removes leading characters.
Return type
STRING
or BYTES
Examples
SELECT CONCAT('#', LTRIM(' apple '), '#') AS example
/*-------------*
| example |
+-------------+
| #apple # |
*-------------*/
SELECT LTRIM('***apple***', '*') AS example
/*-----------*
| example |
+-----------+
| apple*** |
*-----------*/
SELECT LTRIM('xxxapplexxx', 'xyz') AS example
/*-----------*
| example |
+-----------+
| applexxx |
*-----------*/
NORMALIZE
NORMALIZE(value[, normalization_mode])
Description
Takes a string value and returns it as a normalized string. If you do not
provide a normalization mode, NFC
is used.
Normalization is used to ensure that two strings are equivalent. Normalization is often used in situations in which two strings render the same on the screen but have different Unicode code points.
NORMALIZE
supports four optional normalization modes:
Value | Name | Description |
---|---|---|
NFC |
Normalization Form Canonical Composition | Decomposes and recomposes characters by canonical equivalence. |
NFKC |
Normalization Form Compatibility Composition | Decomposes characters by compatibility, then recomposes them by canonical equivalence. |
NFD |
Normalization Form Canonical Decomposition | Decomposes characters by canonical equivalence, and multiple combining characters are arranged in a specific order. |
NFKD |
Normalization Form Compatibility Decomposition | Decomposes characters by compatibility, and multiple combining characters are arranged in a specific order. |
Return type
STRING
Examples
The following example normalizes different language characters:
SELECT
NORMALIZE('\u00ea') as a,
NORMALIZE('\u0065\u0302') as b,
NORMALIZE('\u00ea') = NORMALIZE('\u0065\u0302') as normalized;
/*---+---+------------*
| a | b | normalized |
+---+---+------------+
| ê | ê | TRUE |
*---+---+------------*/
The following examples normalize different space characters:
SELECT NORMALIZE('Raha\u2004Mahan', NFKC) AS normalized_name
/*-----------------*
| normalized_name |
+-----------------+
| Raha Mahan |
*-----------------*/
SELECT NORMALIZE('Raha\u2005Mahan', NFKC) AS normalized_name
/*-----------------*
| normalized_name |
+-----------------+
| Raha Mahan |
*-----------------*/
SELECT NORMALIZE('Raha\u2006Mahan', NFKC) AS normalized_name
/*-----------------*
| normalized_name |
+-----------------+
| Raha Mahan |
*-----------------*/
SELECT NORMALIZE('Raha Mahan', NFKC) AS normalized_name
/*-----------------*
| normalized_name |
+-----------------+
| Raha Mahan |
*-----------------*/
NORMALIZE_AND_CASEFOLD
NORMALIZE_AND_CASEFOLD(value[, normalization_mode])
Description
Takes a string value and returns it as a normalized string. If you do not
provide a normalization mode, NFC
is used.
Normalization is used to ensure that two strings are equivalent. Normalization is often used in situations in which two strings render the same on the screen but have different Unicode code points.
Case folding is used for the caseless
comparison of strings. If you need to compare strings and case should not be
considered, use NORMALIZE_AND_CASEFOLD
, otherwise use
NORMALIZE
.
NORMALIZE_AND_CASEFOLD
supports four optional normalization modes:
Value | Name | Description |
---|---|---|
NFC |
Normalization Form Canonical Composition | Decomposes and recomposes characters by canonical equivalence. |
NFKC |
Normalization Form Compatibility Composition | Decomposes characters by compatibility, then recomposes them by canonical equivalence. |
NFD |
Normalization Form Canonical Decomposition | Decomposes characters by canonical equivalence, and multiple combining characters are arranged in a specific order. |
NFKD |
Normalization Form Compatibility Decomposition | Decomposes characters by compatibility, and multiple combining characters are arranged in a specific order. |
Return type
STRING
Examples
SELECT
NORMALIZE('The red barn') = NORMALIZE('The Red Barn') AS normalized,
NORMALIZE_AND_CASEFOLD('The red barn')
= NORMALIZE_AND_CASEFOLD('The Red Barn') AS normalized_with_case_folding;
/*------------+------------------------------*
| normalized | normalized_with_case_folding |
+------------+------------------------------+
| FALSE | TRUE |
*------------+------------------------------*/
SELECT
'\u2168' AS a,
'IX' AS b,
NORMALIZE_AND_CASEFOLD('\u2168', NFD)=NORMALIZE_AND_CASEFOLD('IX', NFD) AS nfd,
NORMALIZE_AND_CASEFOLD('\u2168', NFC)=NORMALIZE_AND_CASEFOLD('IX', NFC) AS nfc,
NORMALIZE_AND_CASEFOLD('\u2168', NFKD)=NORMALIZE_AND_CASEFOLD('IX', NFKD) AS nkfd,
NORMALIZE_AND_CASEFOLD('\u2168', NFKC)=NORMALIZE_AND_CASEFOLD('IX', NFKC) AS nkfc;
/*---+----+-------+-------+------+------*
| a | b | nfd | nfc | nkfd | nkfc |
+---+----+-------+-------+------+------+
| Ⅸ | IX | false | false | true | true |
*---+----+-------+-------+------+------*/
SELECT
'\u0041\u030A' AS a,
'\u00C5' AS b,
NORMALIZE_AND_CASEFOLD('\u0041\u030A', NFD)=NORMALIZE_AND_CASEFOLD('\u00C5', NFD) AS nfd,
NORMALIZE_AND_CASEFOLD('\u0041\u030A', NFC)=NORMALIZE_AND_CASEFOLD('\u00C5', NFC) AS nfc,
NORMALIZE_AND_CASEFOLD('\u0041\u030A', NFKD)=NORMALIZE_AND_CASEFOLD('\u00C5', NFKD) AS nkfd,
NORMALIZE_AND_CASEFOLD('\u0041\u030A', NFKC)=NORMALIZE_AND_CASEFOLD('\u00C5', NFKC) AS nkfc;
/*---+----+-------+-------+------+------*
| a | b | nfd | nfc | nkfd | nkfc |
+---+----+-------+-------+------+------+
| Å | Å | true | true | true | true |
*---+----+-------+-------+------+------*/
REGEXP_CONTAINS
REGEXP_CONTAINS(value, regexp)
Description
Returns TRUE
if value
is a partial match for the regular expression,
regexp
.
If the regexp
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
The following queries check to see if an email is valid:
SELECT
'foo@example.com' AS email,
REGEXP_CONTAINS('foo@example.com', r'@[a-zA-Z0-9-]+\.[a-zA-Z0-9-.]+') AS is_valid
/*-----------------+----------*
| email | is_valid |
+-----------------+----------+
| foo@example.com | TRUE |
*-----------------+----------*/
```
```sql
SELECT
'www.example.net' AS email,
REGEXP_CONTAINS('www.example.net', r'@[a-zA-Z0-9-]+\.[a-zA-Z0-9-.]+') AS is_valid
/*-----------------+----------*
| email | is_valid |
+-----------------+----------+
| www.example.net | FALSE |
*-----------------+----------*/
```
The following queries check to see if an email is valid. They
perform a full match, using `^` and `$`. Due to regular expression operator
precedence, it is good practice to use parentheses around everything between `^`
and `$`.
```sql
SELECT
'a@foo.com' AS email,
REGEXP_CONTAINS('a@foo.com', r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$') AS valid_email_address,
REGEXP_CONTAINS('a@foo.com', r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$') AS without_parentheses;
/*----------------+---------------------+---------------------*
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| a@foo.com | true | true |
*----------------+---------------------+---------------------*/
SELECT
'a@foo.computer' AS email,
REGEXP_CONTAINS('a@foo.computer', r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$') AS valid_email_address,
REGEXP_CONTAINS('a@foo.computer', r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$') AS without_parentheses;
/*----------------+---------------------+---------------------*
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| a@foo.computer | false | true |
*----------------+---------------------+---------------------*/
SELECT
'b@bar.org' AS email,
REGEXP_CONTAINS('b@bar.org', r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$') AS valid_email_address,
REGEXP_CONTAINS('b@bar.org', r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$') AS without_parentheses;
/*----------------+---------------------+---------------------*
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| b@bar.org | true | true |
*----------------+---------------------+---------------------*/
SELECT
'!b@bar.org' AS email,
REGEXP_CONTAINS('!b@bar.org', r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$') AS valid_email_address,
REGEXP_CONTAINS('!b@bar.org', r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$') AS without_parentheses;
/*----------------+---------------------+---------------------*
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| !b@bar.org | false | true |
*----------------+---------------------+---------------------*/
SELECT
'c@buz.net' AS email,
REGEXP_CONTAINS('c@buz.net', r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$') AS valid_email_address,
REGEXP_CONTAINS('c@buz.net', r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$') AS without_parentheses;
/*----------------+---------------------+---------------------*
| email | valid_email_address | without_parentheses |
+----------------+---------------------+---------------------+
| c@buz.net | false | false |
*----------------+---------------------+---------------------*/
REGEXP_EXTRACT
REGEXP_EXTRACT(value, regexp)
Description
Returns the first substring in value
that matches the
re2 regular expression,
regexp
. Returns NULL
if there is no match.
If the regular expression contains a capturing group ((...)
), and there is a
match for that capturing group, that match is returned. If there
are multiple matches for a capturing group, the first match is returned.
Returns an error if:
- The regular expression is invalid
- The regular expression has more than one capturing group
Return type
STRING
or BYTES
Examples
SELECT REGEXP_EXTRACT('foo@example.com', r'^[a-zA-Z0-9_.+-]+') AS user_name
/*-----------*
| user_name |
+-----------+
| foo |
*-----------*/
SELECT REGEXP_EXTRACT('foo@example.com', r'^[a-zA-Z0-9_.+-]+@[a-zA-Z0-9-]+\.([a-zA-Z0-9-.]+$)')
/*------------------*
| top_level_domain |
+------------------+
| com |
*------------------*/
SELECT
REGEXP_EXTRACT('ab', '.b') AS result_a,
REGEXP_EXTRACT('ab', '(.)b') AS result_b,
REGEXP_EXTRACT('xyztb', '(.)+b') AS result_c,
REGEXP_EXTRACT('ab', '(z)?b') AS result_d
/*-------------------------------------------*
| result_a | result_b | result_c | result_d |
+-------------------------------------------+
| ab | a | t | NULL |
*-------------------------------------------*/
REGEXP_EXTRACT_ALL
REGEXP_EXTRACT_ALL(value, regexp)
Description
Returns an array of all substrings of value
that match the
re2 regular expression, regexp
. Returns an empty array
if there is no match.
If the regular expression contains a capturing group ((...)
), and there is a
match for that capturing group, that match is added to the results.
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.
Returns an error if:
- The regular expression is invalid
- The regular expression has more than one capturing group
Return type
ARRAY<STRING>
or ARRAY<BYTES>
Examples
SELECT REGEXP_EXTRACT_ALL('Try `func(x)` or `func(y)`', '`(.+?)`') AS example
/*--------------------*
| example |
+--------------------+
| [func(x), func(y)] |
*--------------------*/
REGEXP_REPLACE
REGEXP_REPLACE(value, regexp, replacement)
Description
Returns a STRING
where all substrings of value
that
match regular expression regexp
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
regexp
pattern. Use \0 to refer to the entire matching text.
To add a backslash in your regular expression, you must first escape it. For
example, SELECT REGEXP_REPLACE('abc', 'b(.)', 'X\\1');
returns aXc
. You can
also use raw strings to remove one layer of
escaping, for example SELECT REGEXP_REPLACE('abc', 'b(.)', r'X\1');
.
The REGEXP_REPLACE
function only replaces non-overlapping matches. For
example, replacing ana
within banana
results in only one replacement, not
two.
If the regexp
argument is not a valid regular expression, this function
returns an error.
Return type
STRING
or BYTES
Examples
SELECT REGEXP_REPLACE('# Heading', r'^# ([a-zA-Z0-9\s]+$)', '<h1>\\1</h1>') AS html
/*--------------------------*
| html |
+--------------------------+
| <h1>Heading</h1> |
*--------------------------*/
REPEAT
REPEAT(original_value, repetitions)
Description
Returns a STRING
or BYTES
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 returns an error if the repetitions
value is negative.
Return type
STRING
or BYTES
Examples
SELECT REPEAT('abc', 3) AS results
/*-----------*
| results |
|-----------|
| abcabcabc |
*-----------*/
SELECT REPEAT('abc', NULL) AS results
/*---------*
| results |
|---------|
| NULL |
*---------*/
SELECT REPEAT(NULL, 3) AS results
/*---------*
| results |
|---------|
| NULL |
*---------*/
REPLACE
REPLACE(original_value, from_pattern, to_pattern)
Description
Replaces all occurrences of from_pattern
with to_pattern
in
original_value
. If from_pattern
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 |
*--------------------*/
REVERSE
REVERSE(value)
Description
Returns the reverse of the input STRING
or BYTES
.
Return type
STRING
or BYTES
Examples
SELECT REVERSE('abc') AS results
/*---------*
| results |
+---------+
| cba |
*---------*/
SELECT FORMAT('%T', REVERSE(b'1a3')) AS results
/*---------*
| results |
+---------+
| b"3a1" |
*---------*/
RPAD
RPAD(original_value, return_length[, pattern])
Description
Returns a STRING
or BYTES
value that consists of original_value
appended
with pattern
. The return_length
parameter 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 FORMAT('%T', RPAD('c', 5)) AS results
/*---------*
| results |
+---------+
| "c " |
*---------*/
SELECT RPAD('b', 5, 'a') AS results
/*---------*
| results |
+---------+
| baaaa |
*---------*/
SELECT RPAD('abc', 10, 'ghd') AS results
/*------------*
| results |
+------------+
| abcghdghdg |
*------------*/
SELECT RPAD('abc', 2, 'd') AS results
/*---------*
| results |
+---------+
| ab |
*---------*/
SELECT FORMAT('%T', RPAD(b'abc', 10, b'ghd')) AS results
/*---------------*
| results |
+---------------+
| b"abcghdghdg" |
*---------------*/
RTRIM
RTRIM(value1[, value2])
Description
Identical to TRIM, but only removes trailing characters.
Return type
STRING
or BYTES
Examples
SELECT RTRIM('***apple***', '*') AS example
/*-----------*
| example |
+-----------+
| ***apple |
*-----------*/
SELECT RTRIM('applexxz', 'xyz') AS example
/*---------*
| example |
+---------+
| apple |
*---------*/
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;
SOUNDEX
SOUNDEX(value)
Description
Returns a STRING
that represents the
Soundex code for value
.
SOUNDEX produces a phonetic representation of a string. It indexes words by sound, as pronounced in English. It is typically used to help determine whether two strings, such as the family names Levine and Lavine, or the words to and too, have similar English-language pronunciation.
The result of the SOUNDEX consists of a letter followed by 3 digits. Non-latin
characters are ignored. If the remaining string is empty after removing
non-Latin characters, an empty STRING
is returned.
Return type
STRING
Examples
SELECT 'Ashcraft' AS value, SOUNDEX('Ashcraft') AS soundex
/*----------------------+---------*
| value | soundex |
+----------------------+---------+
| Ashcraft | A261 |
*----------------------+---------*/
SPLIT
SPLIT(value[, delimiter])
Description
Splits a STRING
or BYTES
value, using a delimiter. The delimiter
argument
must be a literal character or sequence of characters. You can't split with a
regular expression.
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<STRING>
or ARRAY<BYTES>
Examples
WITH letters AS
(SELECT '' as letter_group
UNION ALL
SELECT 'a' as letter_group
UNION ALL
SELECT 'b c d' as letter_group)
SELECT SPLIT(letter_group, ' ') as example
FROM letters;
/*----------------------*
| example |
+----------------------+
| [] |
| [a] |
| [b, c, d] |
*----------------------*/
STARTS_WITH
STARTS_WITH(value, prefix)
Description
Takes two STRING
or BYTES
values. Returns TRUE
if prefix
is a
prefix of value
.
Return type
BOOL
Examples
SELECT STARTS_WITH('bar', 'b') AS example
/*---------*
| example |
+---------+
| True |
*---------*/
STRPOS
STRPOS(value, subvalue)
Description
Takes two STRING
or BYTES
values. Returns the 1-based position of the first
occurrence of subvalue
inside value
. Returns 0
if subvalue
is not found.
Return type
INT64
Examples
SELECT STRPOS('foo@example.com', '@') AS example
/*---------*
| example |
+---------+
| 4 |
*---------*/
SUBSTR
SUBSTR(value, position[, length])
Description
Gets a portion (substring) of the supplied STRING
or BYTES
value.
The position
argument is an integer specifying the starting position of the
substring.
- If
position
is1
, the substring starts from the first character or byte. - If
position
is0
or less than-LENGTH(value)
,position
is set to1
, and the substring starts from the first character or byte. - If
position
is greater than the length ofvalue
, the function produces an empty substring. - If
position
is negative, the function counts from the end ofvalue
, with-1
indicating the last character or byte.
The length
argument specifies the maximum number of characters or bytes to
return.
- If
length
is not specified, the function produces a substring that starts at the specified position and ends at the last character or byte ofvalue
. - If
length
is0
, the function produces an empty substring. - If
length
is negative, the function produces an error. - The returned substring may be shorter than
length
, for example, whenlength
exceeds the length ofvalue
, or when the starting position of the substring pluslength
is greater than the length ofvalue
.
Return type
STRING
or BYTES
Examples
SELECT SUBSTR('apple', 2) AS example
/*---------*
| example |
+---------+
| pple |
*---------*/
SELECT SUBSTR('apple', 2, 2) AS example
/*---------*
| example |
+---------+
| pp |
*---------*/
SELECT SUBSTR('apple', -2) AS example
/*---------*
| example |
+---------+
| le |
*---------*/
SELECT SUBSTR('apple', 1, 123) AS example
/*---------*
| example |
+---------+
| apple |
*---------*/
SELECT SUBSTR('apple', 123) AS example
/*---------*
| example |
+---------+
| |
*---------*/
SELECT SUBSTR('apple', 123, 5) AS example
/*---------*
| example |
+---------+
| |
*---------*/
TO_BASE32
TO_BASE32(bytes_expr)
Description
Converts a sequence of BYTES
into a base32-encoded STRING
. To convert a
base32-encoded STRING
into BYTES
, use FROM_BASE32.
Return type
STRING
Example
SELECT TO_BASE32(b'abcde\xFF') AS base32_string;
/*------------------*
| base32_string |
+------------------+
| MFRGGZDF74====== |
*------------------*/
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.
There are several base64 encodings in common use that vary in exactly which
alphabet of 65 ASCII characters are used to encode the 64 digits and padding.
See RFC 4648 for details. This
function adds padding and uses the alphabet [A-Za-z0-9+/=]
.
Return type
STRING
Example
SELECT TO_BASE64(b'\377\340') AS base64_string;
/*---------------*
| base64_string |
+---------------+
| /+A= |
*---------------*/
To work with an encoding using a different base64 alphabet, you might need to
compose TO_BASE64
with the REPLACE
function. For instance, the
base64url
url-safe and filename-safe encoding commonly used in web programming
uses -_=
as the last characters rather than +/=
. To encode a
base64url
-encoded string, replace +
and /
with -
and _
respectively.
SELECT REPLACE(REPLACE(TO_BASE64(b'\377\340'), '+', '-'), '/', '_') as websafe_base64;
/*----------------*
| websafe_base64 |
+----------------+
| _-A= |
*----------------*/
TO_CODE_POINTS
TO_CODE_POINTS(value)
Description
Takes a STRING
or BYTES
value and returns an array of INT64
values that
represent code points or extended ASCII character values.
- If
value
is aSTRING
, 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
isBYTES
, 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<INT64>
Examples
The following examples get the code points for each element in an array of words.
SELECT
'foo' AS word,
TO_CODE_POINTS('foo') AS code_points
/*---------+------------------------------------*
| word | code_points |
+---------+------------------------------------+
| foo | [102, 111, 111] |
*---------+------------------------------------*/
SELECT
'bar' AS word,
TO_CODE_POINTS('bar') AS code_points
/*---------+------------------------------------*
| word | code_points |
+---------+------------------------------------+
| bar | [98, 97, 114] |
*---------+------------------------------------*/
SELECT
'baz' AS word,
TO_CODE_POINTS('baz') AS code_points
/*---------+------------------------------------*
| word | code_points |
+---------+------------------------------------+
| baz | [98, 97, 122] |
*---------+------------------------------------*/
SELECT
'giraffe' AS word,
TO_CODE_POINTS('giraffe') AS code_points
/*---------+------------------------------------*
| word | code_points |
+---------+------------------------------------+
| giraffe | [103, 105, 114, 97, 102, 102, 101] |
*---------+------------------------------------*/
SELECT
'llama' AS word,
TO_CODE_POINTS('llama') AS code_points
/*---------+------------------------------------*
| word | code_points |
+---------+------------------------------------+
| llama | [108, 108, 97, 109, 97] |
*---------+------------------------------------*/
The following examples convert integer representations of BYTES
to their
corresponding ASCII character values.
SELECT
b'\x66\x6f\x6f' AS bytes_value,
TO_CODE_POINTS(b'\x66\x6f\x6f') AS bytes_value_as_integer
/*------------------+------------------------*
| bytes_value | bytes_value_as_integer |
+------------------+------------------------+
| foo | [102, 111, 111] |
*------------------+------------------------*/
SELECT
b'\x00\x01\x10\xff' AS bytes_value,
TO_CODE_POINTS(b'\x00\x01\x10\xff') AS bytes_value_as_integer
/*------------------+------------------------*
| bytes_value | bytes_value_as_integer |
+------------------+------------------------+
| \x00\x01\x10\xff | [0, 1, 16, 255] |
*------------------+------------------------*/
The following example demonstrates the difference between a BYTES
result and a
STRING
result. 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.
SELECT TO_CODE_POINTS(b'Ā') AS b_result, TO_CODE_POINTS('Ā') AS s_result;
/*------------+----------*
| b_result | s_result |
+------------+----------+
| [196, 128] | [256] |
*------------+----------*/
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
SELECT
b'\x00\x01\x02\x03\xAA\xEE\xEF\xFF' AS byte_string,
TO_HEX(b'\x00\x01\x02\x03\xAA\xEE\xEF\xFF') AS hex_string
/*----------------------------------+------------------*
| byte_string | hex_string |
+----------------------------------+------------------+
| \x00\x01\x02\x03\xaa\xee\xef\xff | 00010203aaeeefff |
*----------------------------------+------------------*/
TRIM
TRIM(value_to_trim[, set_of_characters_to_remove])
Description
Takes a STRING
or BYTES
value to trim.
If the value to trim is a STRING
, removes from this value all leading and
trailing Unicode code points in set_of_characters_to_remove
.
The set of code points is optional. If it is not specified, all
whitespace characters are removed from the beginning and end of the
value to trim.
If the value to trim is BYTES
, removes from this value all leading and
trailing bytes in set_of_characters_to_remove
. The set of bytes is required.
Return type
STRING
ifvalue_to_trim
is aSTRING
value.BYTES
ifvalue_to_trim
is aBYTES
value.
Examples
In the following example, all leading and trailing whitespace characters are
removed from item
because set_of_characters_to_remove
is not specified.
SELECT CONCAT('#', TRIM( ' apple '), '#') AS example
/*----------*
| example |
+----------+
| #apple# |
*----------*/
In the following example, all leading and trailing *
characters are removed
from 'apple'.
SELECT TRIM('***apple***', '*') AS example
/*---------*
| example |
+---------+
| apple |
*---------*/
In the following example, all leading and trailing x
, y
, and z
characters
are removed from 'xzxapplexxy'.
SELECT TRIM('xzxapplexxy', 'xyz') as example
/*---------*
| example |
+---------+
| apple |
*---------*/
In the following example, examine how TRIM
interprets characters as
Unicode code-points. If your trailing character set contains a combining
diacritic mark over a particular letter, TRIM
might strip the
same diacritic mark from a different letter.
SELECT
TRIM('abaW̊', 'Y̊') AS a,
TRIM('W̊aba', 'Y̊') AS b,
TRIM('abaŪ̊', 'Y̊') AS c,
TRIM('Ū̊aba', 'Y̊') AS d
/*------+------+------+------*
| a | b | c | d |
+------+------+------+------+
| abaW | W̊aba | abaŪ | Ūaba |
*------+------+------+------*/
In the following example, all leading and trailing b'n'
, b'a'
, b'\xab'
bytes are removed from item
.
SELECT b'apple', TRIM(b'apple', b'na\xab') AS example
-- Note that the result of TRIM is of type BYTES, displayed as a base64-encoded string.
/*----------------------+------------------*
| item | example |
+----------------------+------------------+
| YXBwbGU= | cHBsZQ== |
*----------------------+------------------*/
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
SELECT UPPER('foo') AS example
/*---------*
| example |
+---------+
| FOO |
*---------*/
Timestamp functions in GoogleSQL
GoogleSQL for Spanner supports the following timestamp functions.
IMPORTANT: Before working with these functions, you need to understand the difference between the formats in which timestamps are stored and displayed, and how time zones are used for the conversion between these formats. To learn more, see How time zones work with timestamp functions.
NOTE: These functions return a runtime error if overflow occurs; result
values are bounded by the defined DATE
range
and TIMESTAMP
range.
Function list
Name | Summary |
---|---|
CURRENT_TIMESTAMP
|
Returns the current date and time as a TIMESTAMP object.
|
EXTRACT
|
Extracts part of a TIMESTAMP value.
|
FORMAT_TIMESTAMP
|
Formats a TIMESTAMP value according to the specified
format string.
|
PARSE_TIMESTAMP
|
Converts a STRING value to a TIMESTAMP value.
|
PENDING_COMMIT_TIMESTAMP
|
Write a pending commit timestamp. |
STRING (Timestamp)
|
Converts a TIMESTAMP value to a STRING value.
|
TIMESTAMP
|
Constructs a TIMESTAMP value.
|
TIMESTAMP_ADD
|
Adds a specified time interval to a TIMESTAMP value.
|
TIMESTAMP_DIFF
|
Gets the number of unit boundaries between two TIMESTAMP values
at a particular time granularity.
|
TIMESTAMP_MICROS
|
Converts the number of microseconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
|
TIMESTAMP_MILLIS
|
Converts the number of milliseconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
|
TIMESTAMP_SECONDS
|
Converts the number of seconds since
1970-01-01 00:00:00 UTC to a TIMESTAMP .
|
TIMESTAMP_SUB
|
Subtracts a specified time interval from a TIMESTAMP value.
|
TIMESTAMP_TRUNC
|
Truncates a TIMESTAMP value at a particular granularity.
|
UNIX_MICROS
|
Converts a TIMESTAMP value to the number of microseconds since
1970-01-01 00:00:00 UTC.
|
UNIX_MILLIS
|
Converts a TIMESTAMP value to the number of milliseconds
since 1970-01-01 00:00:00 UTC.
|
UNIX_SECONDS
|
Converts a TIMESTAMP value to the number of seconds since
1970-01-01 00:00:00 UTC.
|
CURRENT_TIMESTAMP
CURRENT_TIMESTAMP()
CURRENT_TIMESTAMP
Description
Returns the current date and time as a timestamp object. The timestamp is continuous, non-ambiguous, has exactly 60 seconds per minute and does not repeat values over the leap second. Parentheses are optional.
This function handles leap seconds by smearing them across a window of 20 hours around the inserted leap second.
The current date and time is recorded at the start of the query statement which contains this function, not when this specific function is evaluated.
Supported Input Types
Not applicable
Result Data Type
TIMESTAMP
Examples
SELECT CURRENT_TIMESTAMP() AS now;
/*--------------------------------*
| now |
+--------------------------------+
| 2020-06-02T23:58:40.347847393Z |
*--------------------------------*/
EXTRACT
EXTRACT(part FROM timestamp_expression [AT TIME ZONE time_zone])
Description
Returns a value that corresponds to the specified part
from
a supplied timestamp_expression
. This function supports an optional
time_zone
parameter. See
Time zone definitions for information
on how to specify a time zone.
Allowed part
values are:
NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
DAYOFWEEK
: Returns values in the range [1,7] with Sunday as the first day of 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 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.
Return Data Type
INT64
, except in the following cases:
- If
part
isDATE
, the function returns aDATE
object.
Examples
In the following example, EXTRACT
returns a value corresponding to the DAY
time part.
SELECT
EXTRACT(
DAY
FROM TIMESTAMP('2008-12-25 05:30:00+00') AT TIME ZONE 'UTC')
AS the_day_utc,
EXTRACT(
DAY
FROM TIMESTAMP('2008-12-25 05:30:00+00') AT TIME ZONE 'America/Los_Angeles')
AS the_day_california
/*-------------+--------------------*
| the_day_utc | the_day_california |
+-------------+--------------------+
| 25 | 24 |
*-------------+--------------------*/
In the following examples, EXTRACT
returns values corresponding to different
time parts from a column of type TIMESTAMP
.
SELECT
EXTRACT(ISOYEAR FROM TIMESTAMP("2005-01-03 12:34:56+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2005-01-03 12:34:56+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2005-01-03 12:34:56+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2005-01-03 12:34:56+00")) AS week
-- Display of results may differ, depending upon the environment and
-- time zone where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2005 | 1 | 2005 | 1 |
*---------+---------+------+------*/
SELECT
TIMESTAMP("2007-12-31 12:00:00+00") AS timestamp_value,
EXTRACT(ISOYEAR FROM TIMESTAMP("2007-12-31 12:00:00+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2007-12-31 12:00:00+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2007-12-31 12:00:00+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2007-12-31 12:00:00+00")) AS week
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2008 | 1 | 2007 | 52 |
*---------+---------+------+------*/
SELECT
TIMESTAMP("2009-01-01 12:00:00+00") AS timestamp_value,
EXTRACT(ISOYEAR FROM TIMESTAMP("2009-01-01 12:00:00+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2009-01-01 12:00:00+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2009-01-01 12:00:00+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2009-01-01 12:00:00+00")) AS week
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2009 | 1 | 2009 | 0 |
*---------+---------+------+------*/
SELECT
TIMESTAMP("2009-12-31 12:00:00+00") AS timestamp_value,
EXTRACT(ISOYEAR FROM TIMESTAMP("2009-12-31 12:00:00+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2009-12-31 12:00:00+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2009-12-31 12:00:00+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2009-12-31 12:00:00+00")) AS week
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2009 | 53 | 2009 | 52 |
*---------+---------+------+------*/
SELECT
TIMESTAMP("2017-01-02 12:00:00+00") AS timestamp_value,
EXTRACT(ISOYEAR FROM TIMESTAMP("2017-01-02 12:00:00+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2017-01-02 12:00:00+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2017-01-02 12:00:00+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2017-01-02 12:00:00+00")) AS week
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2017 | 1 | 2017 | 1 |
*---------+---------+------+------*/
SELECT
TIMESTAMP("2017-05-26 12:00:00+00") AS timestamp_value,
EXTRACT(ISOYEAR FROM TIMESTAMP("2017-05-26 12:00:00+00")) AS isoyear,
EXTRACT(ISOWEEK FROM TIMESTAMP("2017-05-26 12:00:00+00")) AS isoweek,
EXTRACT(YEAR FROM TIMESTAMP("2017-05-26 12:00:00+00")) AS year,
EXTRACT(WEEK FROM TIMESTAMP("2017-05-26 12:00:00+00")) AS week
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*---------+---------+------+------*
| isoyear | isoweek | year | week |
+---------+---------+------+------+
| 2017 | 21 | 2017 | 21 |
*---------+---------+------+------*/
FORMAT_TIMESTAMP
FORMAT_TIMESTAMP(format_string, timestamp_expr[, time_zone])
Description
Formats a TIMESTAMP
value according to the specified format string.
Definitions
format_string
: ASTRING
value that contains the format elements to use withtimestamp_expr
.timestamp_expr
: ATIMESTAMP
value that represents the timestamp to format.time_zone
: ASTRING
value that represents a time zone. For more information about how to use a time zone with a timestamp, see Time zone definitions.
Return Data Type
STRING
Examples
SELECT FORMAT_TIMESTAMP("%c", TIMESTAMP "2050-12-25 15:30:55+00", "UTC")
AS formatted;
/*--------------------------*
| formatted |
+--------------------------+
| Sun Dec 25 15:30:55 2050 |
*--------------------------*/
SELECT FORMAT_TIMESTAMP("%b-%d-%Y", TIMESTAMP "2050-12-25 15:30:55+00")
AS formatted;
/*-------------*
| formatted |
+-------------+
| Dec-25-2050 |
*-------------*/
SELECT FORMAT_TIMESTAMP("%b %Y", TIMESTAMP "2050-12-25 15:30:55+00")
AS formatted;
/*-------------*
| formatted |
+-------------+
| Dec 2050 |
*-------------*/
SELECT FORMAT_TIMESTAMP("%Y-%m-%dT%H:%M:%SZ", TIMESTAMP "2050-12-25 15:30:55", "UTC")
AS formatted;
/*+---------------------*
| formatted |
+----------------------+
| 2050-12-25T15:30:55Z |
*----------------------*/
PARSE_TIMESTAMP
PARSE_TIMESTAMP(format_string, timestamp_string[, time_zone])
Description
Converts a STRING
value to a TIMESTAMP
value.
Definitions
format_string
: ASTRING
value that contains the format elements to use withtimestamp_string
.timestamp_string
: ASTRING
value that represents the timestamp to parse.time_zone
: ASTRING
value that represents a time zone. For more information about how to use a time zone with a timestamp, see Time zone definitions.
Details
Each element in timestamp_string
must have a corresponding element in
format_string
. The location of each element in format_string
must match the
location of each element in timestamp_string
.
-- This works because elements on both sides match.
SELECT PARSE_TIMESTAMP("%a %b %e %I:%M:%S %Y", "Thu Dec 25 07:30:00 2008");
-- This produces an error because the year element is in different locations.
SELECT PARSE_TIMESTAMP("%a %b %e %Y %I:%M:%S", "Thu Dec 25 07:30:00 2008");
-- This produces an error because one of the year elements is missing.
SELECT PARSE_TIMESTAMP("%a %b %e %I:%M:%S", "Thu Dec 25 07:30:00 2008");
-- This works because %c can find all matching elements in timestamp_string.
SELECT PARSE_TIMESTAMP("%c", "Thu Dec 25 07:30:00 2008");
The format string fully supports most format elements, except for
%g
, %G
, %j
, %P
,
%u
, %U
, %V
, %w
, and %W
.
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 insensitivity. 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
). - Format divergence.
%p
can be used witham
,AM
,pm
, andPM
.
Return Data Type
TIMESTAMP
Example
SELECT PARSE_TIMESTAMP("%c", "Thu Dec 25 07:30:00 2008") AS parsed;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------*
| parsed |
+------------------------+
| 2008-12-25T15:30:00Z |
*------------------------*/
PENDING_COMMIT_TIMESTAMP
PENDING_COMMIT_TIMESTAMP()
Description
Use the PENDING_COMMIT_TIMESTAMP()
function in a DML INSERT
or UPDATE
statement to write the pending commit timestamp, that is, the commit timestamp
of the write when it commits, into a column of type TIMESTAMP
.
Spanner selects the commit timestamp when the transaction commits. The
PENDING_COMMIT_TIMESTAMP
function may only be used as a value for INSERT or
UPDATE of an appropriately typed column. It cannot be used in SELECT, or as the
input to any other scalar expression.
Return Data Type
TIMESTAMP
Example
The following DML statement updates the LastUpdated
column in the Singers
table with the commit timestamp.
UPDATE Performances SET LastUpdated = PENDING_COMMIT_TIMESTAMP()
WHERE SingerId=1 AND VenueId=2 AND EventDate="2015-10-21"
STRING
STRING(timestamp_expression[, time_zone])
Description
Converts a timestamp to a string. Supports an optional parameter to specify a time zone. See Time zone definitions for information on how to specify a time zone.
Return Data Type
STRING
Example
SELECT STRING(TIMESTAMP "2008-12-25 15:30:00+00", "UTC") AS string;
/*-------------------------------*
| string |
+-------------------------------+
| 2008-12-25 15:30:00+00 |
*-------------------------------*/
TIMESTAMP
TIMESTAMP(string_expression[, time_zone])
TIMESTAMP(date_expression[, time_zone])
Description
string_expression[, time_zone]
: Converts a string to a timestamp.string_expression
must include a timestamp literal. Ifstring_expression
includes a time zone in the timestamp literal, do not include an explicittime_zone
argument.date_expression[, time_zone]
: Converts a date to a timestamp. The value returned is the earliest timestamp that falls within the given date.
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
SELECT TIMESTAMP("2008-12-25 15:30:00+00") AS timestamp_str;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*----------------------*
| timestamp_str |
+----------------------+
| 2008-12-25T15:30:00Z |
*----------------------*/
SELECT TIMESTAMP("2008-12-25 15:30:00", "America/Los_Angeles") AS timestamp_str;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*----------------------*
| timestamp_str |
+----------------------+
| 2008-12-25T23:30:00Z |
*----------------------*/
SELECT TIMESTAMP("2008-12-25 15:30:00 UTC") AS timestamp_str;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*----------------------*
| timestamp_str |
+----------------------+
| 2008-12-25T15:30:00Z |
*----------------------*/
SELECT TIMESTAMP(DATE "2008-12-25") AS timestamp_date;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*----------------------*
| timestamp_date |
+----------------------+
| 2008-12-25T08:00:00Z |
*----------------------*/
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
parts.DAY
. Equivalent to 24HOUR
parts.
Return Data Types
TIMESTAMP
Example
SELECT
TIMESTAMP("2008-12-25 15:30:00+00") AS original,
TIMESTAMP_ADD(TIMESTAMP "2008-12-25 15:30:00+00", INTERVAL 10 MINUTE) AS later;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------+------------------------*
| original | later |
+------------------------+------------------------+
| 2008-12-25T15:30:00Z | 2008-12-25T15:40:00Z |
*------------------------+------------------------*/
TIMESTAMP_DIFF
TIMESTAMP_DIFF(end_timestamp, start_timestamp, granularity)
Description
Gets the number of unit boundaries between two TIMESTAMP
values
(end_timestamp
- start_timestamp
) at a particular time granularity.
Definitions
start_timestamp
: The startingTIMESTAMP
value.end_timestamp
: The endingTIMESTAMP
value.granularity
: The timestamp part that represents the granularity. This can be:NANOSECOND
MICROSECOND
MILLISECOND
SECOND
MINUTE
HOUR
. Equivalent to 60MINUTE
s.DAY
. Equivalent to 24HOUR
s.
Details
If end_timestamp
is earlier than start_timestamp
, the output is negative.
Produces an error if the computation overflows, such as if the difference
in nanoseconds
between the two TIMESTAMP
values overflows.
Return Data Type
INT64
Example
SELECT
TIMESTAMP("2010-07-07 10:20:00+00") AS later_timestamp,
TIMESTAMP("2008-12-25 15:30:00+00") AS earlier_timestamp,
TIMESTAMP_DIFF(TIMESTAMP "2010-07-07 10:20:00+00", TIMESTAMP "2008-12-25 15:30:00+00", HOUR) AS hours;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------+------------------------+-------*
| later_timestamp | earlier_timestamp | hours |
+------------------------+------------------------+-------+
| 2010-07-07T10:20:00Z | 2008-12-25T15:30:00Z | 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) AS negative_diff;
/*---------------*
| negative_diff |
+---------------+
| -61 |
*---------------*/
In this example, the result is 0 because only the number of whole specified
HOUR
intervals are included.
SELECT TIMESTAMP_DIFF("2001-02-01 01:00:00", "2001-02-01 00:00:01", HOUR) AS diff;
/*---------------*
| diff |
+---------------+
| 0 |
*---------------*/
TIMESTAMP_MICROS
TIMESTAMP_MICROS(int64_expression)
Description
Interprets int64_expression
as the number of microseconds since 1970-01-01
00:00:00 UTC and returns a timestamp.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_MICROS(1230219000000000) AS timestamp_value;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------*
| timestamp_value |
+------------------------+
| 2008-12-25T15:30:00Z |
*------------------------*/
TIMESTAMP_MILLIS
TIMESTAMP_MILLIS(int64_expression)
Description
Interprets int64_expression
as the number of milliseconds since 1970-01-01
00:00:00 UTC and returns a timestamp.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_MILLIS(1230219000000) AS timestamp_value;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------*
| timestamp_value |
+------------------------+
| 2008-12-25T15:30:00Z |
*------------------------*/
TIMESTAMP_SECONDS
TIMESTAMP_SECONDS(int64_expression)
Description
Interprets int64_expression
as the number of seconds since 1970-01-01 00:00:00
UTC and returns a timestamp.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_SECONDS(1230219000) AS timestamp_value;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------*
| timestamp_value |
+------------------------+
| 2008-12-25T15:30:00Z |
*------------------------*/
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
parts.DAY
. Equivalent to 24HOUR
parts.
Return Data Type
TIMESTAMP
Example
SELECT
TIMESTAMP("2008-12-25 15:30:00+00") AS original,
TIMESTAMP_SUB(TIMESTAMP "2008-12-25 15:30:00+00", INTERVAL 10 MINUTE) AS earlier;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------+------------------------*
| original | earlier |
+------------------------+------------------------+
| 2008-12-25T15:30:00Z | 2008-12-25T15:20:00Z |
*------------------------+------------------------*/
TIMESTAMP_TRUNC
TIMESTAMP_TRUNC(timestamp_value, timestamp_granularity[, time_zone])
Description
Truncates a TIMESTAMP
value at a particular granularity.
Definitions
timestamp_value
: ATIMESTAMP
value to truncate.timestamp_granularity
: The truncation granularity for aTIMESTAMP
value. Date granularities and time granularities can be used.time_zone
: A time zone to use with theTIMESTAMP
value. Time zone parts can be used. Use this argument if you want to use a time zone other than the default time zone, America/Los_Angeles, as part of the truncate operation.
Date granularity definitions
DAY
: The day in the Gregorian calendar year that contains the value to truncate.WEEK
: The first day in the week that contains the value to truncate. Weeks begin on Sundays.WEEK
is equivalent toWEEK(SUNDAY)
.ISOWEEK
: The first day in the ISO 8601 week that contains the value to truncate. The ISO week begins on Monday. The first ISO week of each ISO year contains the first Thursday of the corresponding Gregorian calendar year.MONTH
: The first day in the month that contains the value to truncate.QUARTER
: The first day in the quarter that contains the value to truncate.YEAR
: The first day in the year that contains the value to truncate.ISOYEAR
: The first day in the ISO 8601 week-numbering year that contains the value to truncate. The ISO year is the Monday of the first week where Thursday belongs to the corresponding Gregorian calendar year.
Time granularity definitions
NANOSECOND
: If used, nothing is truncated from the value.MICROSECOND
: The nearest lesser than or equal microsecond.MILLISECOND
: The nearest lesser than or equal millisecond.SECOND
: The nearest lesser than or equal second.MINUTE
: The nearest lesser than or equal minute.HOUR
: The nearest lesser than or equal hour.
Time zone part definitions
MINUTE
HOUR
DAY
WEEK
ISOWEEK
MONTH
QUARTER
YEAR
ISOYEAR
Details
The resulting value is always rounded to the beginning of granularity
.
Return Data Type
TIMESTAMP
Examples
SELECT
TIMESTAMP_TRUNC(TIMESTAMP "2008-12-25 15:30:00+00", DAY, "UTC") AS utc,
TIMESTAMP_TRUNC(TIMESTAMP "2008-12-25 15:30:00+00", DAY, "America/Los_Angeles") AS la;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------+------------------------*
| utc | la |
+------------------------+------------------------+
| 2008-12-25T00:00:00Z | 2008-12-25T08:00:00Z |
*------------------------+------------------------*/
In the following example, the original timestamp_expression
is in the
Gregorian calendar year 2015. However, TIMESTAMP_TRUNC
with the ISOYEAR
date
part truncates the timestamp_expression
to the beginning of the ISO year, not
the Gregorian calendar year. The first Thursday of the 2015 calendar year was
2015-01-01, so the ISO year 2015 begins on the preceding Monday, 2014-12-29.
Therefore the ISO year boundary preceding the timestamp_expression
2015-06-15 00:00:00+00 is 2014-12-29.
SELECT
TIMESTAMP_TRUNC("2015-06-15 00:00:00+00", ISOYEAR) AS isoyear_boundary,
EXTRACT(ISOYEAR FROM TIMESTAMP "2015-06-15 00:00:00+00") AS isoyear_number;
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*------------------------+----------------*
| parsed | isoyear_number |
+------------------------+----------------+
| 2014-12-29T08:00:00Z | 2015 |
*------------------------+----------------*/
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 by
rounding down to the beginning of the microsecond.
Return Data Type
INT64
Examples
SELECT UNIX_MICROS(TIMESTAMP "2008-12-25 15:30:00+00") AS micros;
/*------------------*
| micros |
+------------------+
| 1230219000000000 |
*------------------*/
SELECT UNIX_MICROS(TIMESTAMP "1970-01-01 00:00:00.0000018+00") AS micros;
/*------------------*
| micros |
+------------------+
| 1 |
*------------------*/
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 by rounding down to the beginning of the millisecond.
Return Data Type
INT64
Examples
SELECT UNIX_MILLIS(TIMESTAMP "2008-12-25 15:30:00+00") AS millis;
/*---------------*
| millis |
+---------------+
| 1230219000000 |
*---------------*/
SELECT UNIX_MILLIS(TIMESTAMP "1970-01-01 00:00:00.0018+00") AS millis;
/*---------------*
| millis |
+---------------+
| 1 |
*---------------*/
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 by rounding down to the beginning of the second.
Return Data Type
INT64
Examples
SELECT UNIX_SECONDS(TIMESTAMP "2008-12-25 15:30:00+00") AS seconds;
/*------------*
| seconds |
+------------+
| 1230219000 |
*------------*/
SELECT UNIX_SECONDS(TIMESTAMP "1970-01-01 00:00:01.8+00") AS seconds;
/*------------*
| seconds |
+------------+
| 1 |
*------------*/
Supplemental materials
How time zones work with timestamp functions
A timestamp represents an absolute point in time, independent of any time
zone. However, when a timestamp value is displayed, it is usually converted to
a human-readable format consisting of a civil date and time
(YYYY-MM-DD HH:MM:SS)
and a time zone. This is not the internal representation of the
TIMESTAMP
; it is only a human-understandable way to describe the point in time
that the timestamp represents.
Some timestamp functions have a time zone argument. A time zone is needed to
convert between civil time (YYYY-MM-DD HH:MM:SS) and the absolute time
represented by a timestamp.
A function like PARSE_TIMESTAMP
takes an input string that represents a
civil time and returns a timestamp that represents an absolute time. A
time zone is needed for this conversion. A function like EXTRACT
takes an
input timestamp (absolute time) and converts it to civil time in order to
extract a part of that civil time. This conversion requires a time zone.
If no time zone is specified, the default time zone, America/Los_Angeles,
is used.
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).
To learn more about how time zones work with the TIMESTAMP
type, see
Time zones.
Utility functions in GoogleSQL
GoogleSQL for Spanner supports the following utility functions.
Function list
Name | Summary |
---|---|
GENERATE_UUID
|
Produces a random universally unique identifier (UUID) as a
STRING value.
|
GENERATE_UUID
GENERATE_UUID()
Description
Returns a random universally unique identifier (UUID) as a STRING
.
The returned STRING
consists of 32 hexadecimal
digits in five groups separated by hyphens in the form 8-4-4-4-12. The
hexadecimal digits represent 122 random bits and 6 fixed bits, in compliance
with RFC 4122 section 4.4.
The returned STRING
is lowercase.
Return Data Type
STRING
Example
The following query generates a random UUID.
SELECT GENERATE_UUID() AS uuid;
/*--------------------------------------*
| uuid |
+--------------------------------------+
| 4192bff0-e1e0-43ce-a4db-912808c32493 |
*--------------------------------------*/