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
GoogleSQL for Bigtable 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.
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 |
Field access operator | Binary |
Array subscript operator | ARRAY |
Array position. Must be used with OFFSET or ORDINAL —see
Array Functions
. |
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, DATE with
INT64
|
Addition | Binary |
- |
All numeric types, DATE with
INT64
|
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. |
Arithmetic operators | Performs arithmetic operations. |
Date arithmetics operators | Performs arithmetic operations on dates. |
Bitwise operators | Performs bit manipulation. |
Logical operators |
Tests for the truth of some condition and produces TRUE ,
FALSE , or NULL .
|
Comparison operators |
Compares operands and produces the results of the comparison as a
BOOL value.
|
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. |
Concatenation operator | Combines multiple values into one. |
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
Return type
- For
STRUCT
: SQL data type offieldname
. If a field is not found in the struct, an error is thrown.
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:
{ index | 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)
. This position keyword produces the same result asindex
by itself.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.
index
: An integer that represents a specific position in the array. If used by itself without a position keyword, the index starts at zero and produces an error if the index is out of range. To produceNULL
instead of an error, use theSAFE_OFFSET(index)
orSAFE_ORDINAL(index)
position keyword.
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"][0] AS item_index,
["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_index | item_offset | item_ordinal | item_safe_offset |
+---------------------+------------+-------------+--------------+------------------+
| [coffee, tea, milk] | coffee | 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"][6] AS item_offset
-- Error. Array index 6 is out of bounds.
SELECT ["coffee", "tea", "milk"][OFFSET(6)] AS item_offset
The following queries contain an array subscript operator that is applied
to a column family called cell_plan
in a table called
test_table
:
SELECT MAP_KEYS(cell_plan)[0] AS results FROM test_table LIMIT 1
/*----------------*
| results |
+----------------+
| data_plan_01gb |
*----------------*/
SELECT MAP_KEYS(cell_plan)[1] AS results FROM test_table LIMIT 1
/*----------------*
| results |
+----------------+
| data_plan_05gb |
*----------------*/
SELECT MAP_KEYS(cell_plan)[OFFSET(1)] AS results FROM test_table LIMIT 1
/*----------------*
| results |
+----------------+
| data_plan_05gb |
*----------------*/
SELECT MAP_KEYS(cell_plan)[ORDINAL(0)] AS results FROM test_table LIMIT 1
/*----------------*
| results |
+----------------+
| data_plan_01gb |
*----------------*/
SELECT MAP_KEYS(cell_plan)[SAFE_OFFSET(5)] AS results FROM test_table LIMIT 1
/*----------------*
| results |
+----------------+
| NULL |
*----------------*/
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | INT64 | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Division:
INPUT | INT64 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
Result types for Unary Plus:
INPUT | INT64 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | INT64 | FLOAT32 | FLOAT64 |
Result types for Unary Minus:
INPUT | INT64 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | INT64 | FLOAT32 | FLOAT64 |
Date arithmetics operators
Operators '+' and '-' can be used for arithmetic operations on dates.
date_expression + int64_expression
int64_expression + date_expression
date_expression - int64_expression
Description
Adds or subtracts int64_expression
days to or from date_expression
. This is
equivalent to DATE_ADD
or DATE_SUB
functions, when interval is expressed in
days.
Return Data Type
DATE
Example
SELECT DATE "2020-09-22" + 1 AS day_later, DATE "2020-09-22" - 7 AS week_ago
/*------------+------------*
| day_later | week_ago |
+------------+------------+
| 2020-09-23 | 2020-09-15 |
*------------+------------*/
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 |
*-------*/
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 .
This operator supports specifying collation.
|
Less Than or Equal To | X <= Y |
Returns TRUE if X is less than or equal to
Y .
This operator supports specifying collation.
|
Greater Than | X > Y |
Returns TRUE if X is greater than
Y .
This operator supports specifying collation.
|
Greater Than or Equal To | X >= Y |
Returns TRUE if X is greater than or equal to
Y .
This operator supports specifying collation.
|
Equal | X = Y |
Returns TRUE if X is equal to Y .
This operator supports specifying collation.
|
Not Equal | X != Y X <> Y |
Returns TRUE if X is not equal to
Y .
This operator supports specifying collation.
|
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.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-
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'\%'
.
This operator supports collation, but caveats apply:
- Each
%
character inexpression_2
represents an arbitrary string specifier. An arbitrary string specifier can represent any sequence of0
or more characters. A character in the expression represents itself and is considered a single character specifier unless:
The character is a percent sign (
%
).The character is an underscore (
_
) and the collator is notund:ci
.
These additional rules apply to the underscore (
_
) character:If the collator is not
und:ci
, an error is produced when an underscore is not escaped inexpression_2
.If the collator is not
und:ci
, the underscore is not allowed when the operands have collation specified.Some compatibility composites, such as the fi-ligature (
fi
) and the telephone sign (℡
), will produce a match if they are compared to an underscore.A single underscore matches the idea of what a character is, based on an approximation known as a grapheme cluster.
For a contiguous sequence of single character specifiers, equality depends on the collator and its language tags and tailoring.
By default, the
und:ci
collator does not fully normalize a string. Some canonically equivalent strings are considered unequal for both the=
andLIKE
operators.The
LIKE
operator with collation has the same behavior as the=
operator when there are no wildcards in the strings.Character sequences with secondary or higher-weighted differences are considered unequal. This includes accent differences and some special cases.
For example there are three ways to produce German sharp
ß
:\u1E9E
\U00DF
ss
\u1E9E
and\U00DF
are considered equal but differ in tertiary. They are considered equal withund:ci
collation but different fromss
, which has secondary differences.Character sequences with tertiary or lower-weighted differences are considered equal. This includes case differences and kana subtype differences, which are considered equal.
There are ignorable characters defined in Unicode. Ignorable characters are ignored in the pattern matching.
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:
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> |
Conditional expressions
GoogleSQL for Bigtable 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 .
|
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.
This expression supports specifying collation.
Return Data Type
Supertype of result
[, ...] and else_result
.
Example
SELECT
CASE MAP_KEYS(cell_plan)[0]
WHEN b'data_plan_01gb' THEN 'Small data plan'
WHEN b'data_plan_05gb' THEN 'Large data plan'
ELSE 'Unknown data plan
END
AS result
FROM test_table LIMIT 2
/*-----------------*
| result |
+-----------------+
| Small data plan |
| Large data plan |
*-----------------*/
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.
This expression supports specifying collation.
Return Data Type
Supertype of result
[, ...] and else_result
.
Example
SELECT
CASE
WHEN MAP_KEYS(cell_plan)[0] != b'data_plan_01gb' THEN 'Small data plan'
WHEN MAP_KEYS(cell_plan)[0] != b'data_plan_05gb' THEN 'Large data plan'
ELSE 'Unknown data plan'
END
AS result
FROM test_table LIMIT 2
/*-----------------*
| result |
+-----------------+
| Large data plan |
| Small data plan |
*-----------------*/
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.
This expression supports specifying collation.
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
Array functions
GoogleSQL for Bigtable supports the following array functions.
Function list
Name | Summary |
---|---|
ARRAY_CONCAT
|
Concatenates one or more arrays with the same element type into a single array. |
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_LAST_N
|
Gets the suffix of an array, consisting of the last n
elements.
|
ARRAY_LENGTH
|
Gets the number of elements in an array. |
ARRAY_OFFSET
|
Searches an array from the beginning or ending and produces the zero-based offset for the first matching element. |
ARRAY_OFFSETS
|
Searches an array and gets the zero-based offsets for matching elements. |
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. |
GENERATE_TIMESTAMP_ARRAY
|
Generates an array of timestamps in a range. |
JSON_QUERY_ARRAY
|
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
value.
For more information, see JSON functions. |
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
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 |
*-------+------*/
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_LAST_N
ARRAY_LAST_N(input_array, n)
Description
Returns a suffix of input_array
consisting of the last n
elements.
Caveats:
- If
input_array
isNULL
, returnsNULL
. - If
n
isNULL
, returnsNULL
. - If
n
is0
, returns an empty array. - If
n
is longer thaninput_array
, returnsinput_array
. - If
n
is negative, produces an error.
Return type
ARRAY
Example
SELECT
ARRAY_LAST_N([1, 2, 3, 4, 5], 0) AS a,
ARRAY_LAST_N([1, 2, 3, 4, 5], 3) AS b,
ARRAY_LAST_N([1, 2, 3, 4, 5], 7) AS c
/*----------------------------------*
| a | b | c |
+----------------------------------+
| [] | [3, 4, 5] | [1, 2, 3, 4, 5] |
*----------------------------------*/
-- Error: out of bounds
SELECT ARRAY_LAST_N([1, 2, 3, 4, 5], -1)
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_OFFSET
ARRAY_OFFSET(input_array, element_to_find[, first_or_last])
element_to_find:
{ element_expression | element_lambda_expression }
lambda_expression:
element_alias -> boolean_expression
Description
Searches an array from the beginning or ending and gets the zero-based offset
for the first matching element. If no element is found, returns NULL
.
Arguments:
input_array
: The array to search.element_expression
: The element to find in the array. Must be a comparable data type.element_lambda_expression
: Each element ininput_array
is evaluated against the lambda expression. If the expression evaluates toTRUE
, the element is included in the search results.element_alias
: An alias that represents the element to find.boolean_expression
: The predicate used to filter the array elements.first_or_last
: Search from the beginning (FIRST
) or ending (LAST
) of the array. By default the function searches from the beginning.
Return type
INT64
Examples
The following queries get the offset for the first 4
in an array.
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], 4) AS result
/*--------*
| result |
+--------+
| 1 |
*--------*/
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], 4, 'FIRST') AS result
/*--------*
| result |
+--------+
| 1 |
*--------*/
The following queries get the offset for the last 4
in an array.
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], 4, 'LAST') AS result
/*--------*
| result |
+--------+
| 3 |
*--------*/
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], e -> e = 4, 'LAST') AS result
/*--------*
| result |
+--------+
| 3 |
*--------*/
The following query gets the offset for the last element in an array that is
greater than 2
and less than 5
.
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], e -> e > 2 AND e < 5, 'LAST') AS result
/*--------*
| result |
+--------+
| 3 |
*--------*/
The following query produces NULL
because 5
is not in the array.
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], 5) AS result
/*--------*
| result |
+--------+
| NULL |
*--------*/
The following query produces NULL
because there are no elements greater
than 7
in the array.
SELECT ARRAY_OFFSET([1, 4, 4, 4, 6], e -> e > 7) AS result
/*--------*
| result |
+--------+
| NULL |
*--------*/
ARRAY_OFFSETS
ARRAY_OFFSETS(input_array, element_to_find)
element_to_find:
{ element_expression | element_lambda_expression }
lambda_expression:
element_alias -> boolean_expression
Description
Searches an array and gets the zero-based offsets for matching elements. If no matching element is found, returns an empty array.
Arguments:
input_array
: The array to search.element_expression
: The element to find in the array. Must be a comparable data type.element_lambda_expression
: Each element ininput_array
is evaluated against the lambda expression. If the expression evaluates toTRUE
, the element is included in the search results.element_alias
: An alias that represents the element to find.boolean_expression
: The predicate used to filter the array elements.
Return type
ARRAY<INT64>
Examples
The following query gets all offsets for 4
in an array.
SELECT ARRAY_OFFSETS([1, 4, 4, 4, 6, 4], 4) AS result
/*--------------+
| result |
+--------------+
| [1, 2, 3, 5] |
+--------------*/
The following query gets the offsets for elements in an array that are
greater than 2
and less than 5
.
SELECT ARRAY_OFFSETS([1, 4, 7, 3, 6, 4], e -> e > 2 AND e < 5) AS result
/*-----------+
| result |
+-----------+
| [1, 3, 5] |
+-----------*/
The following query produces an empty array because 5
is not in the array.
SELECT ARRAY_OFFSETS([1, 4, 4, 4, 6], 5) AS result
/*--------*
| result |
+--------+
| [] |
*--------*/
The following query produces an empty array because there are no elements
greater than 7
in the array.
SELECT ARRAY_OFFSETS([1, 4, 4, 4, 6], e -> e > 7) AS result
/*--------*
| result |
+--------+
| [] |
*--------*/
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
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] |
*--------------------------------------------------------------*/
GENERATE_TIMESTAMP_ARRAY
GENERATE_TIMESTAMP_ARRAY(start_timestamp, end_timestamp,
INTERVAL step_expression date_part)
Description
Returns an ARRAY
of TIMESTAMPS
separated by a given interval. The
start_timestamp
and end_timestamp
parameters determine the inclusive
lower and upper bounds of the ARRAY
.
The GENERATE_TIMESTAMP_ARRAY
function accepts the following data types as
inputs:
start_timestamp
:TIMESTAMP
end_timestamp
:TIMESTAMP
step_expression
:INT64
- Allowed
date_part
values are:MICROSECOND
,MILLISECOND
,SECOND
,MINUTE
,HOUR
, orDAY
.
The step_expression
parameter determines the increment used to generate
timestamps.
Return Data Type
An ARRAY
containing 0 or more TIMESTAMP
values.
Examples
The following example returns an ARRAY
of TIMESTAMP
s at intervals of 1 day.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-05 00:00:00', '2016-10-07 00:00:00',
INTERVAL 1 DAY) AS timestamp_array;
/*--------------------------------------------------------------------------*
| timestamp_array |
+--------------------------------------------------------------------------+
| [2016-10-05 00:00:00+00, 2016-10-06 00:00:00+00, 2016-10-07 00:00:00+00] |
*--------------------------------------------------------------------------*/
The following example returns an ARRAY
of TIMESTAMP
s at intervals of 1
second.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-05 00:00:00', '2016-10-05 00:00:02',
INTERVAL 1 SECOND) AS timestamp_array;
/*--------------------------------------------------------------------------*
| timestamp_array |
+--------------------------------------------------------------------------+
| [2016-10-05 00:00:00+00, 2016-10-05 00:00:01+00, 2016-10-05 00:00:02+00] |
*--------------------------------------------------------------------------*/
The following example returns an ARRAY
of TIMESTAMPS
with a negative
interval.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-06 00:00:00', '2016-10-01 00:00:00',
INTERVAL -2 DAY) AS timestamp_array;
/*--------------------------------------------------------------------------*
| timestamp_array |
+--------------------------------------------------------------------------+
| [2016-10-06 00:00:00+00, 2016-10-04 00:00:00+00, 2016-10-02 00:00:00+00] |
*--------------------------------------------------------------------------*/
The following example returns an ARRAY
with a single element, because
start_timestamp
and end_timestamp
have the same value.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-05 00:00:00', '2016-10-05 00:00:00',
INTERVAL 1 HOUR) AS timestamp_array;
/*--------------------------*
| timestamp_array |
+--------------------------+
| [2016-10-05 00:00:00+00] |
*--------------------------*/
The following example returns an empty ARRAY
, because start_timestamp
is
later than end_timestamp
.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-06 00:00:00', '2016-10-05 00:00:00',
INTERVAL 1 HOUR) AS timestamp_array;
/*-----------------*
| timestamp_array |
+-----------------+
| [] |
*-----------------*/
The following example returns a null ARRAY
, because one of the inputs is
NULL
.
SELECT GENERATE_TIMESTAMP_ARRAY('2016-10-05 00:00:00', NULL, INTERVAL 1 HOUR)
AS timestamp_array;
/*-----------------*
| timestamp_array |
+-----------------+
| NULL |
*-----------------*/
Supplemental materials
OFFSET and ORDINAL
For information about using OFFSET
and ORDINAL
with arrays, see
Array subscript operator and Accessing array
elements.
Conversion functions
GoogleSQL for Bigtable 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. |
BIT_CAST_TO_INT64
|
Cast bits to an INT64 value.
For more information, see Bit functions. |
CAST
|
Convert the results of an expression to the given type. |
CHR
|
Converts a Unicode code point to a character.
For more information, see String functions. |
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. |
PARSE_DATE
|
Converts a STRING value to a DATE value.
For more information, see Date 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 (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_INT64
|
Converts the big-endian bytes of a 64-bit signed integer into an
INT64 value.
For more information, see String functions. |
TO_JSON_STRING
|
Converts a SQL value to a JSON-formatted STRING value.
For more information, see JSON functions. |
TO_VECTOR32
|
Converts the big-endian bytes of one or more 32-bit IEEE 754 floating
point numbers into an
ARRAY<FLOAT32> value.
For more information, see String functions. |
TO_VECTOR64
|
Converts the big-endian bytes of one or more 64-bit IEEE 754 floating
point numbers into an
ARRAY<FLOAT64> value.
For more information, see String 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
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
STRING |
BYTES |
Strings are cast to bytes using UTF-8 encoding. For example, the string "©", when cast to bytes, would become a 2-byte sequence with the hex values C2 and A9. |
CAST AS DATE
CAST(expression AS DATE)
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 FLOAT64
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
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
INT64 | FLOAT64 | Returns a close but potentially not exact floating point value. |
STRING |
FLOAT64 |
Returns x as a floating point value, interpreting it as
having the same form as a valid floating point literal.
Also supports casts from "[+,-]inf" to
[,-]Infinity ,
"[+,-]infinity" to [,-]Infinity , and
"[+,-]nan" to NaN .
Conversions are case-insensitive.
|
CAST AS INT64
CAST(expression AS INT64)
Description
GoogleSQL supports casting to integer types.
The expression
parameter can represent an expression for these data types:
INT64
FLOAT32
FLOAT64
ENUM
BOOL
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
FLOAT64 | INT64 |
Returns the closest integer value. Halfway cases such as 1.5 or -0.5 round away from zero. |
BOOL |
INT64 |
Returns 1 if x is TRUE ,
0 otherwise.
|
STRING |
INT64 |
A hex string can be cast to an integer. For example,
0x123 to 291 or -0x123 to
-291 .
|
Examples
If you are working with hex strings (0x123
), you can cast those strings as
integers:
SELECT '0x123' as hex_value, CAST('0x123' as INT64) as hex_to_int;
/*-----------+------------*
| hex_value | hex_to_int |
+-----------+------------+
| 0x123 | 291 |
*-----------+------------*/
SELECT '-0x123' as hex_value, CAST('-0x123' as INT64) as hex_to_int;
/*-----------+------------*
| hex_value | hex_to_int |
+-----------+------------+
| -0x123 | -291 |
*-----------+------------*/
CAST AS 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
ENUM
BOOL
BYTES
DATE
TIMESTAMP
STRING
Conversion rules
From | To | Rule(s) when casting x |
---|---|---|
FLOAT64 | STRING |
Returns an approximate string representation. A returned
NaN or 0 will not be signed. |
BOOL |
STRING |
Returns "true" if x is TRUE ,
"false" otherwise. |
BYTES |
STRING |
Returns x interpreted as a UTF-8 string.For example, the bytes literal b'\xc2\xa9' , when cast to a string,
is interpreted as UTF-8 and becomes the unicode character "©".An error occurs if x is not valid UTF-8. |
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. |
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, UTC. The number of subsecond digits produced depends on the number of trailing zeroes in the subsecond part: the CAST function will truncate zero, three, or six digits. |
Examples
SELECT CAST(CURRENT_DATE() AS STRING) AS current_date
/*---------------*
| current_date |
+---------------+
| 2021-03-09 |
*---------------*/
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,
UTC, is used. If the string has fewer than six digits,
then it is implicitly widened.
An error is produced if the string_expression is invalid,
has more than six subsecond digits (i.e., precision greater than
microseconds), or represents a time outside of the supported timestamp
range.
|
DATE |
TIMESTAMP |
Casting from a date to a timestamp interprets date_expression
as of midnight (start of the day) in the default time zone,
UTC.
|
Examples
The following example casts a string-formatted timestamp as a timestamp:
SELECT CAST("2020-06-02 17:00:53.110+00:00" AS TIMESTAMP) AS as_timestamp
-- Results depend upon where this query was executed.
/*-----------------------------*
| as_timestamp |
+-----------------------------+
| 2020-06-03 00:00:53.110 UTC |
*-----------------------------*/
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
GoogleSQL for Bigtable 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 , DATETIME , or
TIMESTAMP 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. |
LAST_DAY
|
Gets the last day in a specified time period that contains a
DATE value.
|
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, UTC, 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, UTC, 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.WEEK(<WEEKDAY>)
: This date part begins onWEEKDAY
. Valid values forWEEKDAY
areSUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, andSATURDAY
.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 WEEK(MONDAY)
returns 1. DATE_DIFF
with the date part ISOWEEK
also 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', WEEK(MONDAY)) AS week_weekday_diff,
DATE_DIFF('2017-12-18', '2017-12-17', ISOWEEK) AS isoweek_diff;
/*-----------+-------------------+--------------*
| week_diff | week_weekday_diff | isoweek_diff |
+-----------+-------------------+--------------+
| 0 | 1 | 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)
DATE_TRUNC(datetime_value, datetime_granularity)
DATE_TRUNC(timestamp_value, timestamp_granularity[, time_zone])
Description
Truncates a DATE
, DATETIME
, or TIMESTAMP
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.datetime_value
: ADATETIME
value to truncate.datetime_granularity
: The truncation granularity for aDATETIME
value. Date granularities and time granularities can be used.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, UTC, 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)
.WEEK(WEEKDAY)
: The first day in the week that contains the value to truncate. Weeks begin onWEEKDAY
.WEEKDAY
must be one of the following:SUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, orSATURDAY
.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
MICROSECOND
: If used, nothing is truncated from the value.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
WEEK(<WEEKDAY>)
ISOWEEK
MONTH
QUARTER
YEAR
ISOYEAR
Details
The resulting value is always rounded to the beginning of granularity
.
Return Data Type
The same data type as the first argument passed into this function.
Examples
SELECT DATE_TRUNC(DATE '2008-12-25', MONTH) AS month;
/*------------*
| month |
+------------+
| 2008-12-01 |
*------------*/
In the following example, the original date falls on a Sunday. Because
the date_part
is WEEK(MONDAY)
, DATE_TRUNC
returns the DATE
for the
preceding Monday.
SELECT date AS original, DATE_TRUNC(date, WEEK(MONDAY)) AS truncated
FROM (SELECT DATE('2017-11-05') AS date);
/*------------+------------*
| original | truncated |
+------------+------------+
| 2017-11-05 | 2017-10-30 |
*------------+------------*/
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.WEEK(<WEEKDAY>)
: Returns the week number of the date in the range [0, 53]. Weeks begin onWEEKDAY
. Dates prior to the firstWEEKDAY
of the year are in week 0. Valid values forWEEKDAY
areSUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, andSATURDAY
.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 |
*------------+---------+---------+------+------*/
In the following example, date_expression
falls on a Sunday. EXTRACT
calculates the first column using weeks that begin on Sunday, and it calculates
the second column using weeks that begin on Monday.
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 |
*-------------*/
LAST_DAY
LAST_DAY(date_expression[, date_part])
Description
Returns the last day from a date expression. This is commonly used to return the last day of the month.
You can optionally specify the date part for which the last day is returned.
If this parameter is not used, the default value is MONTH
.
LAST_DAY
supports the following values for date_part
:
YEAR
QUARTER
MONTH
WEEK
. Equivalent to 7DAY
s.WEEK(<WEEKDAY>)
.<WEEKDAY>
represents the starting day of the week. Valid values areSUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, andSATURDAY
.ISOWEEK
. Uses ISO 8601 week boundaries. ISO weeks begin on Monday.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.
Return Data Type
DATE
Example
These both return the last day of the month:
SELECT LAST_DAY(DATE '2008-11-25', MONTH) AS last_day
/*------------*
| last_day |
+------------+
| 2008-11-30 |
*------------*/
SELECT LAST_DAY(DATE '2008-11-25') AS last_day
/*------------*
| last_day |
+------------+
| 2008-11-30 |
*------------*/
This returns the last day of the year:
SELECT LAST_DAY(DATE '2008-11-25', YEAR) AS last_day
/*------------*
| last_day |
+------------+
| 2008-12-31 |
*------------*/
This returns the last day of the week for a week that starts on a Sunday:
SELECT LAST_DAY(DATE '2008-11-10', WEEK(SUNDAY)) AS last_day
/*------------*
| last_day |
+------------+
| 2008-11-15 |
*------------*/
This returns the last day of the week for a week that starts on a Monday:
SELECT LAST_DAY(DATE '2008-11-10', WEEK(MONDAY)) AS last_day
/*------------*
| last_day |
+------------+
| 2008-11-16 |
*------------*/
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');
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 |
*-----------------*/
JSON functions
GoogleSQL for Bigtable 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 |
Standard extractors |
JSON_QUERY JSON_VALUE JSON_QUERY_ARRAY |
Functions that extract JSON data. |
Legacy extractors |
JSON_EXTRACT JSON_EXTRACT_SCALAR |
Functions that extract JSON data. While these functions are supported by GoogleSQL, we recommend using the standard extractor functions. |
Other converters |
TO_JSON_STRING |
Other conversion functions from or to JSON. |
Function list
Name | Summary |
---|---|
JSON_EXTRACT
|
(Deprecated)
Extracts a JSON value and converts it to a SQL
JSON-formatted STRING
value.
|
JSON_EXTRACT_SCALAR
|
(Deprecated)
Extracts a JSON scalar value and converts it to a SQL
STRING value.
|
JSON_QUERY
|
Extracts a JSON value and converts it to a SQL
JSON-formatted STRING
value.
|
JSON_QUERY_ARRAY
|
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
value.
|
JSON_VALUE
|
Extracts a JSON scalar value and converts it to a SQL
STRING value.
|
TO_JSON_STRING
|
Converts a SQL value to a JSON-formatted STRING value.
|
JSON_EXTRACT
JSON_EXTRACT(json_string_expr, json_path)
Description
Extracts a JSON value and converts it to a
SQL JSON-formatted STRING
value.
This function uses single quotes and brackets 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_EXTRACT("null", "$") -- Returns a SQL NULL
json_path
: The JSONPath. This identifies the data that you want to obtain from the input.
Return type
A JSON-formatted STRING
Examples
In the following examples, JSON data is extracted and returned as JSON-formatted strings.
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "Jane"}]}}',
'$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[{"name":"Jane"}]}} |
*-----------------------------------------------------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": []}}',
'$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[]}} |
*-----------------------------------------------------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$') AS json_text_string;
/*-----------------------------------------------------------*
| json_text_string |
+-----------------------------------------------------------+
| {"class":{"students":[{"name":"John"},{"name":"Jamie"}]}} |
*-----------------------------------------------------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "Jane"}]}}',
'$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| {"name":"Jane"} |
*-----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": []}}',
'$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| NULL |
*-----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$.class.students[0]') AS first_student;
/*-----------------*
| first_student |
+-----------------+
| {"name":"John"} |
*-----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "Jane"}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": []}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "John"}, {"name": null}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| NULL |
*----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
'$.class.students[1].name') AS second_student;
/*----------------*
| second_student |
+----------------+
| "Jamie" |
*----------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "Jane"}]}}',
"$.class['students']") AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [{"name":"Jane"}] |
*------------------------------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": []}}',
"$.class['students']") AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [] |
*------------------------------------*/
SELECT JSON_EXTRACT(
'{"class": {"students": [{"name": "John"}, {"name": "Jamie"}]}}',
"$.class['students']") AS student_names;
/*------------------------------------*
| student_names |
+------------------------------------+
| [{"name":"John"},{"name":"Jamie"}] |
*------------------------------------*/
SELECT JSON_EXTRACT('{"a": null}', "$.a"); -- Returns a SQL NULL
SELECT JSON_EXTRACT('{"a": null}', "$.b"); -- Returns a SQL NULL
JSON_EXTRACT_SCALAR
JSON_EXTRACT_SCALAR(json_string_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 return values.
- Returns a SQL
NULL
if a non-scalar value is selected. - Uses single quotes and brackets to escape invalid JSONPath
characters in JSON keys. For example:
['a.b']
.
Arguments:
json_string_expr
: A JSON-formatted string. For example:'{"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.
Return type
STRING
Examples
The following example compares how results are returned for the JSON_EXTRACT
and JSON_EXTRACT_SCALAR
functions.
SELECT JSON_EXTRACT('{"name": "Jakob", "age": "6" }', '$.name') AS json_name,
JSON_EXTRACT_SCALAR('{"name": "Jakob", "age": "6" }', '$.name') AS scalar_name,
JSON_EXTRACT('{"name": "Jakob", "age": "6" }', '$.age') AS json_age,
JSON_EXTRACT_SCALAR('{"name": "Jakob", "age": "6" }', '$.age') AS scalar_age;
/*-----------+-------------+----------+------------*
| json_name | scalar_name | json_age | scalar_age |
+-----------+-------------+----------+------------+
| "Jakob" | Jakob | "6" | 6 |
*-----------+-------------+----------+------------*/
SELECT JSON_EXTRACT('{"fruits": ["apple", "banana"]}', '$.fruits') AS json_extract,
JSON_EXTRACT_SCALAR('{"fruits": ["apple", "banana"]}', '$.fruits') AS json_extract_scalar;
/*--------------------+---------------------*
| json_extract | json_extract_scalar |
+--------------------+---------------------+
| ["apple","banana"] | NULL |
*--------------------+---------------------*/
In cases where a JSON key uses invalid JSONPath characters, you can escape those
characters using single quotes and brackets, [' ']
. For example:
SELECT JSON_EXTRACT_SCALAR('{"a.b": {"c": "world"}}', "$['a.b'].c") AS hello;
/*-------*
| hello |
+-------+
| world |
*-------*/
JSON_QUERY
JSON_QUERY(json_string_expr, json_path)
Description
Extracts a JSON value and converts it to a SQL
JSON-formatted STRING
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_path
: The JSONPath. This identifies the data that you want to obtain from the input.
Return type
A JSON-formatted STRING
Examples
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
JSON_QUERY_ARRAY
JSON_QUERY_ARRAY(json_string_expr[, json_path])
Description
Extracts a JSON array and converts it to
a SQL ARRAY<JSON-formatted STRING>
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_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.
Return type
ARRAY<JSON-formatted STRING>
Examples
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 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"] |
*---------------------------------*/
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_VALUE
JSON_VALUE(json_string_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_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.
Return type
STRING
Examples
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 |
*-------*/
TO_JSON_STRING
TO_JSON_STRING(value[, pretty_print])
Description
Converts a SQL value to a JSON-formatted STRING
value.
Arguments:
value
: A SQL value. You can review the GoogleSQL data types that this function supports and their JSON encodings here.pretty_print
: Optional boolean parameter. Ifpretty_print
istrue
, the `returned value is formatted for easy readability.
Return type
A JSON-formatted STRING
Examples
The following query converts a STRUCT
value to a JSON-formatted string:
SELECT TO_JSON_STRING(STRUCT(1 AS id, [10,20] AS coordinates)) AS json_data
/*--------------------------------*
| json_data |
+--------------------------------+
| {"id":1,"coordinates":[10,20]} |
*--------------------------------*/
The following query converts a STRUCT
value to a JSON-formatted string that is
easy to read:
SELECT TO_JSON_STRING(STRUCT(1 AS id, [10,20] AS coordinates), true) AS json_data
/*--------------------*
| json_data |
+--------------------+
| { |
| "id": 1, |
| "coordinates": [ |
| 10, |
| 20 |
| ] |
| } |
*--------------------*/
Supplemental materials
JSON encodings
You can encode a SQL value as a JSON value with the following functions:
TO_JSON_STRING
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 Encoded as a number when the value is in the range of [-253, 253], which is the range of integers that can be represented losslessly as IEEE 754 double-precision floating point numbers. A value outside of this range is encoded as a string. |
SQL input: 9007199254740992 JSON output: 9007199254740992 SQL input: 9007199254740993 JSON output: "9007199254740993" |
FLOAT32 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" |
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} |
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: |
[][] [][][]...
|
Child subscript operator. If the object is a JSON array within an array, you can use as many additional brackets as you need to specify the child array index. |
JSON-formatted string:
JSON path:
JSON result: |
Map functions
GoogleSQL for Bigtable supports the following map functions.
Function list
Name | Summary |
---|---|
MAP_CONTAINS_KEY
|
Checks if a key is in a map. |
MAP_EMPTY
|
Checks if a map is empty. |
MAP_KEYS
|
Gets an array of lexicographically sorted keys from a map. |
MAP_VALUES
|
Gets an array of lexicographically key-sorted values from a map. |
MAP_CONTAINS_KEY
MAP_CONTAINS_KEY(input_map, key_to_find)
Description
Checks if a key is in a map. Returns TRUE
if the key is found. Otherwise,
returns FALSE
.
Definitions
input_map
: AMAP<K,V>
value that represents the map to search. If this value isNULL
, the function returnsNULL
.key_to_find
: The key to find in the map.
Return type
BOOL
Examples
The following query checks if a column called cell_plan
in a
table called test_table
has a key called
data_plan_05gb
:
SELECT MAP_CONTAINS_KEY(cell_plan, b'data_plan_05gb') AS results
FROM test_table
/*---------*
| results |
+---------+
| TRUE |
| TRUE |
| FALSE |
| FALSE |
| FALSE |
*---------*/
MAP_EMPTY
MAP_EMPTY(input_map)
Description
Checks if a map is empty. Returns TRUE
if the map is empty, otherwise FALSE
.
Definitions
input_map
: AMAP<K,V>
value that represents the map to search. If this value isNULL
, the function returnsNULL
.
Return type
BOOL
Example
The following query checks if a column called cell_plan
in a table called
test_table
is empty:
SELECT MAP_EMPTY(cell_plan) AS results
FROM test_table
/*----------*
| results |
+----------+
| FALSE |
| FALSE |
| TRUE |
| TRUE |
| FALSE |
| FALSE |
*----------*/
MAP_KEYS
MAP_KEYS(input_map)
Description
Gets an array of lexicographically sorted keys from a map.
Definitions
input_map
: AMAP<K,V>
value that represents the map to query. If this value isNULL
, the function returnsNULL
.
Return type
ARRAY<K>
Examples
The following query gets an lexicographically sorted list of keys from a table
called test_table
:
SELECT MAP_KEYS(cell_plan) AS results
FROM test_table
/*----------------------------------------*
| results |
+----------------------------------------+
| [ "data_plan_01gb", "data_plan_05gb" ] |
| [ "data_plan_05gb" ] |
| [] |
| [ "data_plan_10gb" ] |
| [ "data_plan_10gb" ] |
*----------------------------------------*/
MAP_VALUES
MAP_VALUES(input_map)
Description
Gets an array of lexicographically key-sorted values from a map.
Definitions
input_map
: AMAP<K,V>
value that represents the map to query. If this value isNULL
, the function returnsNULL
.
Return type
ARRAY<V>
Examples
The following query gets the key-sorted values from a table called
test_table
:
SELECT MAP_VALUES(cell_plan) AS results
FROM test_table
/*---------------------*
| results |
+---------------------+
| [ "true", "false" ] |
| [ "false" ] |
| [] |
| [ "false" ] |
| [ "false" ] |
*---------------------*/
Mathematical functions
GoogleSQL for Bigtable 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
COT
COTH
CSC
CSCH
SEC
SECH
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 |
COSINE_DISTANCE
EUCLIDEAN_DISTANCE
|
Comparison |
GREATEST
LEAST
|
Random number generator |
RAND
|
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 .
|
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. |
AVG (Differential Privacy)
|
DIFFERENTIAL_PRIVACY -supported AVG .Gets the differentially-private average of non- NULL ,
non-NaN values in a query with a
DIFFERENTIAL_PRIVACY clause.
For more information, see Differential privacy 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. |
COT
|
Computes the cotangent of X .
|
COTH
|
Computes the hyperbolic cotangent of X .
|
CSC
|
Computes the cosecant of X .
|
CSCH
|
Computes the hyperbolic cosecant of X .
|
DIV
|
Divides integer X by integer Y .
|
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.
|
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 .
|
RAND
|
Generates a pseudo-random value of type
FLOAT64 in the range of
[0, 1) .
|
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.
|
SEC
|
Computes the secant of X .
|
SECH
|
Computes the hyperbolic secant of X .
|
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. |
SUM (Differential Privacy)
|
DIFFERENTIAL_PRIVACY -supported SUM .Gets the differentially-private sum of non- NULL ,
non-NaN values in a query with a
DIFFERENTIAL_PRIVACY clause.
For more information, see Differential privacy 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | INT64 | 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].
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.
X | ACOSH(X) |
---|---|
+inf |
+inf |
-inf |
NaN |
NaN |
NaN |
X < 1 | Error |
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].
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.
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.
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 [-π,π].
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).
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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.
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 or a sparse vector that is represented by anARRAY<STRUCT<dimension,magnitude>>
value.vector2
: A vector that is represented by anARRAY<T>
value or a sparse vector that is represented by anARRAY<STRUCT<dimension,magnitude>>
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]
ARRAY<STRUCT<dimension,magnitude>>
can be used to represent a sparse vector. With a sparse vector, you only need to include dimension-magnitude pairs for non-zero magnitudes. If a magnitude isn't present in the sparse vector, the magnitude is implicitly understood to be zero.For example, if you have a vector with 10,000 dimensions, but only 10 dimensions have non-zero magnitudes, then the vector is a sparse vector. As a result, it's more efficient to describe a sparse vector by only mentioning its non-zero magnitudes.
In
ARRAY<STRUCT<dimension,magnitude>>
,STRUCT<dimension,magnitude>
represents a dimension-magnitude pair for each non-zero magnitude in a sparse vector. These parts need to be included for each dimension-magnitude pair:dimension
: ASTRING
orINT64
value that represents a dimension in a vector.magnitude
: AFLOAT64
value that represents a non-zero magnitude for a specific dimension in a vector.
You don't need to include empty dimension-magnitude pairs in a sparse vector. For example, the following sparse vector and non-sparse vector are equivalent:
-- sparse vector ARRAY<STRUCT<INT64, FLOAT64>> [(1, 10.0), (2: 30.0), (5, 40.0)]
-- vector ARRAY<FLOAT64> [0.0, 10.0, 30.0, 0.0, 0.0, 40.0]
In a sparse vector, dimension-magnitude pairs don't need to be in any particular order. The following sparse vectors are equivalent:
[('a', 10.0), ('b': 30.0), ('d': 40.0)]
[('d': 40.0), ('a', 10.0), ('b': 30.0)]
Both non-sparse 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, non-sparsevectors are used to compute the cosine distance:
SELECT COSINE_DISTANCE([1.0, 2.0], [3.0, 4.0]) AS results;
/*----------*
| results |
+----------+
| 0.016130 |
*----------*/
In the following example, sparse vectors are used to compute the cosine distance:
SELECT COSINE_DISTANCE(
[(1, 1.0), (2, 2.0)],
[(2, 4.0), (1, 3.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;
SELECT COSINE_DISTANCE([(1, 1.0), (2, 2.0)], [(1, 3.0), (2, 4.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;
-- ERROR
SELECT COSINE_DISTANCE([(1, 0.0), (2, 0.0)], [(1, 3.0), (2, 4.0)]) AS results;
Both non-sparse 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;
If you use sparse vectors and you repeat a dimension, an error is produced:
-- ERROR
SELECT COSINE_DISTANCE(
[(1, 9.0), (2, 7.0), (2, 8.0)], [(1, 8.0), (2, 4.0), (3, 5.0)]) AS results;
COT
COT(X)
Description
Computes the cotangent for the angle of X
, where X
is specified in radians.
X
can be any data type
that coerces to FLOAT64
.
Supports the SAFE.
prefix.
X | COT(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
0 |
Error |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT COT(1) AS a, SAFE.COT(0) AS b;
/*---------------------+------*
| a | b |
+---------------------+------+
| 0.64209261593433065 | NULL |
*---------------------+------*/
COTH
COTH(X)
Description
Computes the hyperbolic cotangent for the angle of X
, where X
is specified
in radians. X
can be any data type
that coerces to FLOAT64
.
Supports the SAFE.
prefix.
X | COTH(X) |
---|---|
+inf |
1 |
-inf |
-1 |
NaN |
NaN |
0 |
Error |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT COTH(1) AS a, SAFE.COTH(0) AS b;
/*----------------+------*
| a | b |
+----------------+------+
| 1.313035285499 | NULL |
*----------------+------*/
CSC
CSC(X)
Description
Computes the cosecant of the input angle, which is in radians.
X
can be any data type
that coerces to FLOAT64
.
Supports the SAFE.
prefix.
X | CSC(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
0 |
Error |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT CSC(100) AS a, CSC(-1) AS b, SAFE.CSC(0) AS c;
/*----------------+-----------------+------*
| a | b | c |
+----------------+-----------------+------+
| -1.97485753142 | -1.188395105778 | NULL |
*----------------+-----------------+------*/
CSCH
CSCH(X)
Description
Computes the hyperbolic cosecant of the input angle, which is in radians.
X
can be any data type
that coerces to FLOAT64
.
Supports the SAFE.
prefix.
X | CSCH(X) |
---|---|
+inf |
0 |
-inf |
0 |
NaN |
NaN |
0 |
Error |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT CSCH(0.5) AS a, CSCH(-2) AS b, SAFE.CSCH(0) AS c;
/*----------------+----------------+------*
| a | b | c |
+----------------+----------------+------+
| 1.919034751334 | -0.27572056477 | NULL |
*----------------+----------------+------*/
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.
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 |
---|---|
INT64 | INT64 |
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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 or a sparse vector that is represented by anARRAY<STRUCT<dimension,magnitude>>
value.vector2
: A vector that is represented by anARRAY<T>
value or a sparse vector that is represented by anARRAY<STRUCT<dimension,magnitude>>
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]
ARRAY<STRUCT<dimension,magnitude>>
can be used to represent a sparse vector. With a sparse vector, you only need to include dimension-magnitude pairs for non-zero magnitudes. If a magnitude isn't present in the sparse vector, the magnitude is implicitly understood to be zero.For example, if you have a vector with 10,000 dimensions, but only 10 dimensions have non-zero magnitudes, then the vector is a sparse vector. As a result, it's more efficient to describe a sparse vector by only mentioning its non-zero magnitudes.
In
ARRAY<STRUCT<dimension,magnitude>>
,STRUCT<dimension,magnitude>
represents a dimension-magnitude pair for each non-zero magnitude in a sparse vector. These parts need to be included for each dimension-magnitude pair:dimension
: ASTRING
orINT64
value that represents a dimension in a vector.magnitude
: AFLOAT64
value that represents a non-zero magnitude for a specific dimension in a vector.
You don't need to include empty dimension-magnitude pairs in a sparse vector. For example, the following sparse vector and non-sparse vector are equivalent:
-- sparse vector ARRAY<STRUCT<INT64, FLOAT64>> [(1, 10.0), (2: 30.0), (5, 40.0)]
-- vector ARRAY<FLOAT64> [0.0, 10.0, 30.0, 0.0, 0.0, 40.0]
In a sparse vector, dimension-magnitude pairs don't need to be in any particular order. The following sparse vectors are equivalent:
[('a', 10.0), ('b': 30.0), ('d': 40.0)]
[('d': 40.0), ('a', 10.0), ('b': 30.0)]
Both non-sparse 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, non-sparse vectors are used to compute the Euclidean distance:
SELECT EUCLIDEAN_DISTANCE([1.0, 2.0], [3.0, 4.0]) AS results;
/*----------*
| results |
+----------+
| 2.828 |
*----------*/
In the following example, sparse vectors are used to compute the Euclidean distance:
SELECT EUCLIDEAN_DISTANCE(
[(1, 1.0), (2, 2.0)],
[(2, 4.0), (1, 3.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]);
SELECT EUCLIDEAN_DISTANCE([(1, 1.0), (2, 2.0)], [(1, 3.0), (2, 4.0)]) AS results;
/*----------*
| results |
+----------+
| 2.828 |
*----------*/
Both non-sparse 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;
If you use sparse vectors and you repeat a dimension, an error is produced:
-- ERROR
SELECT EUCLIDEAN_DISTANCE(
[(1, 9.0), (2, 7.0), (2, 8.0)], [(1, 8.0), (2, 4.0), (3, 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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 |
This function supports specifying collation.
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.
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.
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 |
This function supports specifying collation.
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT32 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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 |
---|---|
INT64 | INT64 |
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
POWER
POWER(X, Y)
Description
Synonym of POW(X, Y)
.
RAND
RAND()
Description
Generates a pseudo-random value of type FLOAT64
in
the range of [0, 1), inclusive of 0 and exclusive of 1.
ROUND
ROUND(X [, N [, rounding_mode]])
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.
If X is a NUMERIC
or BIGNUMERIC
type, then you can
explicitly set rounding_mode
to one of the following:
"ROUND_HALF_AWAY_FROM_ZERO"
: (Default) Rounds halfway cases away from zero."ROUND_HALF_EVEN"
: Rounds halfway cases towards the nearest even digit.
If you set the rounding_mode
and X is not a NUMERIC
or BIGNUMERIC
type,
then the function generates an error.
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 |
ROUND(NUMERIC "2.25", 1, "ROUND_HALF_EVEN") |
2.2 |
ROUND(NUMERIC "2.35", 1, "ROUND_HALF_EVEN") |
2.4 |
ROUND(NUMERIC "2.251", 1, "ROUND_HALF_EVEN") |
2.3 |
ROUND(NUMERIC "-2.5", 0, "ROUND_HALF_EVEN") |
-2 |
ROUND(NUMERIC "2.5", 0, "ROUND_HALF_AWAY_FROM_ZERO") |
3 |
ROUND(NUMERIC "-2.5", 0, "ROUND_HALF_AWAY_FROM_ZERO") |
-3 |
Return Data Type
INPUT | INT64 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | INT64 | FLOAT64 | FLOAT64 |
FLOAT32 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT32 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | INT64 | FLOAT64 | FLOAT64 |
FLOAT32 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | INT64 | 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 | FLOAT32 | FLOAT64 |
---|---|---|---|
INT64 | INT64 | FLOAT64 | FLOAT64 |
FLOAT32 | FLOAT64 | FLOAT64 | FLOAT64 |
FLOAT64 | FLOAT64 | FLOAT64 | FLOAT64 |
SEC
SEC(X)
Description
Computes the secant for the angle of X
, where X
is specified in radians.
X
can be any data type
that coerces to FLOAT64
.
X | SEC(X) |
---|---|
+inf |
NaN |
-inf |
NaN |
NaN |
NaN |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT SEC(100) AS a, SEC(-1) AS b;
/*----------------+---------------*
| a | b |
+----------------+---------------+
| 1.159663822905 | 1.85081571768 |
*----------------+---------------*/
SECH
SECH(X)
Description
Computes the hyperbolic secant for the angle of X
, where X
is specified
in radians. X
can be any data type
that coerces to FLOAT64
.
Never produces an error.
X | SECH(X) |
---|---|
+inf |
0 |
-inf |
0 |
NaN |
NaN |
NULL |
NULL |
Return Data Type
FLOAT64
Example
SELECT SECH(0.5) AS a, SECH(-2) AS b, SECH(100) AS c;
/*----------------+----------------+---------------------*
| a | b | c |
+----------------+----------------+---------------------+
| 0.88681888397 | 0.265802228834 | 7.4401519520417E-44 |
*----------------+----------------+---------------------*/
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | INT64 | 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.
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | 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.
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 | FLOAT32 | FLOAT64 |
---|---|---|---|
OUTPUT | FLOAT64 | FLOAT64 | FLOAT64 |
String functions
GoogleSQL for Bigtable 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. |
ASCII
|
Gets the ASCII code for the first character or byte in a STRING
or BYTES value.
|
BYTE_LENGTH
|
Gets the number of BYTES in a STRING or
BYTES value.
|
CHAR_LENGTH
|
Gets the number of characters in a STRING value.
|
CHR
|
Converts a Unicode code point to a character. |
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.
|
INITCAP
|
Formats a STRING as proper case, which means that the first
character in each word is uppercase and all other characters are lowercase.
|
INSTR
|
Finds the position of a subvalue inside another value, optionally starting the search at a given offset or occurrence. |
LEFT
|
Gets the specified leftmost portion from a STRING or
BYTES value.
|
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.
|
OCTET_LENGTH
|
Alias for BYTE_LENGTH .
|
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_INSTR
|
Finds the position of a regular expression match in a value, optionally starting the search at a given offset or occurrence. |
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.
|
RIGHT
|
Gets the specified rightmost portion from 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 (Timestamp)
|
Converts a TIMESTAMP value to a STRING value.
For more information, see Timestamp 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.
|
SUBSTRING
|
Alias for SUBSTR |
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.
|
TO_INT64
|
Converts the big-endian bytes of a 64-bit signed integer into an
INT64 value.
|
TO_VECTOR32
|
Converts the big-endian bytes of one or more 32-bit IEEE 754 floating
point numbers into an
ARRAY<FLOAT32> value.
|
TO_VECTOR64
|
Converts the big-endian bytes of one or more 64-bit IEEE 754 floating
point numbers into an
ARRAY<FLOAT64> value.
|
TRANSLATE
|
Within a value, replaces each source character with the corresponding target character. |
TRIM
|
Removes the specified leading and trailing Unicode code points or bytes
from a STRING or BYTES value.
|
UNICODE
|
Gets the Unicode code point for the first character in a value. |
UPPER
|
Formats alphabetic characters in a STRING value as
uppercase.
Formats ASCII characters in a BYTES value as
uppercase.
|
ASCII
ASCII(value)
Description
Returns the ASCII code for the first character or byte in value
. Returns
0
if value
is empty or the ASCII code is 0
for the first character
or byte.
Return type
INT64
Examples
SELECT ASCII('abcd') as A, ASCII('a') as B, ASCII('') as C, ASCII(NULL) as D;
/*-------+-------+-------+-------*
| A | B | C | D |
+-------+-------+-------+-------+
| 97 | 97 | 0 | NULL |
*-------+-------+-------+-------*/
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 |
*------------ */
CHR
CHR(value)
Description
Takes a Unicode code point and returns
the character that matches the code point. Each valid code point should fall
within the range of [0, 0xD7FF] and [0xE000, 0x10FFFF]. Returns an empty string
if the code point is 0
. If an invalid Unicode code point is specified, an
error is returned.
To work with an array of Unicode code points, see
CODE_POINTS_TO_STRING
Return type
STRING
Examples
SELECT CHR(65) AS A, CHR(255) AS B, CHR(513) AS C, CHR(1024) AS D;
/*-------+-------+-------+-------*
| A | B | C | D |
+-------+-------+-------+-------+
| A | ÿ | ȁ | Ѐ |
*-------+-------+-------+-------*/
SELECT CHR(97) AS A, CHR(0xF9B5) AS B, CHR(0) AS C, CHR(NULL) AS D;
/*-------+-------+-------+-------*
| A | B | C | D |
+-------+-------+-------+-------+
| a | 例 | | NULL |
*-------+-------+-------+-------*/
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.
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.
CONCAT
CONCAT(value1[, ...])
Description
Concatenates one or more values into a single result. All values must be
BYTES
or data types that can be cast to STRING
.
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 |
*---------------------*/
SELECT CONCAT('Summer', ' ', 1923) as release_date;
/*---------------------*
| release_date |
+---------------------+
| Summer 1923 |
*---------------------*/
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
.
This function supports specifying collation.
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
- %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 |
FLOAT32 FLOAT64 |
F |
Decimal notation, in [-](integer part).(fractional part) for finite values, and in uppercase for non-finite values | 392.650000 INF NAN |
FLOAT32 FLOAT64 |
e |
Scientific notation (mantissa/exponent), lowercase | 3.926500e+02 inf nan |
FLOAT32 FLOAT64 |
E |
Scientific notation (mantissa/exponent), uppercase | 3.926500E+02 INF NAN |
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 |
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 |
FLOAT32 FLOAT64 |
s |
String of characters | sample |
STRING |
t |
Returns a printable string representing the value. Often looks
similar to casting the argument to STRING .
See %t 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.
%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 |
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" |
ARRAY | [value, value, ...] where values are formatted with %t |
[value, value, ...] where values are formatted with %T |
STRUCT | (value, value, ...) where fields are formatted with %t |
(value, value, ...) where fields are formatted with %T Special cases: Zero fields: STRUCT() One field: STRUCT(value) |
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
INITCAP
INITCAP(value[, delimiters])
Description
Takes a STRING
and returns it with the first character in each word in
uppercase and all other characters in lowercase. Non-alphabetic characters
remain the same.
delimiters
is an optional string argument that is used to override the default
set of characters used to separate words. If delimiters
is not specified, it
defaults to the following characters:
<whitespace> [ ] ( ) { } / | \ < > ! ? @ " ^ # $ & ~ _ , . : ; * % + -
If value
or delimiters
is NULL
, the function returns NULL
.
Return type
STRING
Examples
SELECT
'Hello World-everyone!' AS value,
INITCAP('Hello World-everyone!') AS initcap_value
/*-------------------------------+-------------------------------*
| value | initcap_value |
+-------------------------------+-------------------------------+
| Hello World-everyone! | Hello World-Everyone! |
*-------------------------------+-------------------------------*/
SELECT
'Apples1oranges2pears' as value,
'12' AS delimiters,
INITCAP('Apples1oranges2pears' , '12') AS initcap_value
/*----------------------+------------+----------------------*
| value | delimiters | initcap_value |
+----------------------+------------+----------------------+
| Apples1oranges2pears | 12 | Apples1Oranges2Pears |
*----------------------+------------+----------------------*/
INSTR
INSTR(value, subvalue[, position[, occurrence]])
Description
Returns the lowest 1-based position of subvalue
in value
.
value
and subvalue
must be the same type, either
STRING
or BYTES
.
If position
is specified, the search starts at this position in
value
, otherwise it starts at 1
, which is the beginning of
value
. If position
is negative, the function searches backwards
from the end of value
, with -1
indicating the last character.
position
is of type INT64
and cannot be 0
.
If occurrence
is specified, the search returns the position of a specific
instance of subvalue
in value
. If not specified, occurrence
defaults to 1
and returns the position of the first occurrence.
For occurrence
> 1
, the function includes overlapping occurrences.
occurrence
is of type INT64
and must be positive.
This function supports specifying collation.
Returns 0
if:
- No match is found.
- If
occurrence
is greater than the number of matches found. - If
position
is greater than the length ofvalue
.
Returns NULL
if:
- Any input argument is
NULL
.
Returns an error if:
position
is0
.occurrence
is0
or negative.
Return type
INT64
Examples
SELECT
'banana' AS value, 'an' AS subvalue, 1 AS position, 1 AS occurrence,
INSTR('banana', 'an', 1, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | 1 | 1 | 2 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'an' AS subvalue, 1 AS position, 2 AS occurrence,
INSTR('banana', 'an', 1, 2) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | 1 | 2 | 4 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'an' AS subvalue, 1 AS position, 3 AS occurrence,
INSTR('banana', 'an', 1, 3) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | 1 | 3 | 0 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'an' AS subvalue, 3 AS position, 1 AS occurrence,
INSTR('banana', 'an', 3, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | 3 | 1 | 4 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'an' AS subvalue, -1 AS position, 1 AS occurrence,
INSTR('banana', 'an', -1, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | -1 | 1 | 4 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'an' AS subvalue, -3 AS position, 1 AS occurrence,
INSTR('banana', 'an', -3, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | an | -3 | 1 | 4 |
*--------------+--------------+----------+------------+-------*/
SELECT
'banana' AS value, 'ann' AS subvalue, 1 AS position, 1 AS occurrence,
INSTR('banana', 'ann', 1, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| banana | ann | 1 | 1 | 0 |
*--------------+--------------+----------+------------+-------*/
SELECT
'helloooo' AS value, 'oo' AS subvalue, 1 AS position, 1 AS occurrence,
INSTR('helloooo', 'oo', 1, 1) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| helloooo | oo | 1 | 1 | 5 |
*--------------+--------------+----------+------------+-------*/
SELECT
'helloooo' AS value, 'oo' AS subvalue, 1 AS position, 2 AS occurrence,
INSTR('helloooo', 'oo', 1, 2) AS instr;
/*--------------+--------------+----------+------------+-------*
| value | subvalue | position | occurrence | instr |
+--------------+--------------+----------+------------+-------+
| helloooo | oo | 1 | 2 | 6 |
*--------------+--------------+----------+------------+-------*/
LEFT
LEFT(value, length)
Description
Returns a STRING
or BYTES
value that consists of the specified
number of leftmost characters or bytes from value
. The length
is an
INT64
that specifies the length of the returned
value. If value
is of type BYTES
, length
is the number of leftmost bytes
to return. If value
is STRING
, length
is the number of leftmost characters
to return.
If length
is 0, an empty STRING
or BYTES
value will be
returned. If length
is negative, an error will be returned. If length
exceeds the number of characters or bytes from value
, the original value
will be returned.
Return type
STRING
or BYTES
Examples
SELECT LEFT('banana', 3) AS results
/*---------*
| results |
+--------+
| ban |
*---------*/
SELECT LEFT(b'\xab\xcd\xef\xaa\xbb', 3) AS results
-- Note that the result of LEFT is of type BYTES, displayed as a base64-encoded string.
/*---------*
| results |
+---------+
| q83v |
*---------*/
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 |
*---+----+-------+-------+------+------*/
OCTET_LENGTH
OCTET_LENGTH(value)
Alias for BYTE_LENGTH
.
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_INSTR
REGEXP_INSTR(source_value, regexp [, position[, occurrence, [occurrence_position]]])
Description
Returns the lowest 1-based position of a regular expression, regexp
, in
source_value
. source_value
and regexp
must be the same type, either
STRING
or BYTES
.
If position
is specified, the search starts at this position in
source_value
, otherwise it starts at 1
, which is the beginning of
source_value
. position
is of type INT64
and must be positive.
If occurrence
is specified, the search returns the position of a specific
instance of regexp
in source_value
. If not specified, occurrence
defaults
to 1
and returns the position of the first occurrence. For occurrence
> 1,
the function searches for the next, non-overlapping occurrence.
occurrence
is of type INT64
and must be positive.
You can optionally use occurrence_position
to specify where a position
in relation to an occurrence
starts. Your choices are:
0
: Returns the start position ofoccurrence
.1
: Returns the end position ofoccurrence
+1
. If the end of the occurrence is at the end ofsource_value
,LENGTH(source_value) + 1
is returned.
Returns 0
if:
- No match is found.
- If
occurrence
is greater than the number of matches found. - If
position
is greater than the length ofsource_value
. - The regular expression is empty.
Returns NULL
if:
position
isNULL
.occurrence
isNULL
.
Returns an error if:
position
is0
or negative.occurrence
is0
or negative.occurrence_position
is neither0
nor1
.- The regular expression is invalid.
- The regular expression has more than one capturing group.
Return type
INT64
Examples
SELECT
REGEXP_INSTR('ab@cd-ef', '@[^-]*') AS instr_a,
REGEXP_INSTR('ab@d-ef', '@[^-]*') AS instr_b,
REGEXP_INSTR('abc@cd-ef', '@[^-]*') AS instr_c,
REGEXP_INSTR('abc-ef', '@[^-]*') AS instr_d,
/*---------------------------------------*
| instr_a | instr_b | instr_c | instr_d |
+---------------------------------------+
| 3 | 3 | 4 | 0 |
*---------------------------------------*/
SELECT
REGEXP_INSTR('a@cd-ef b@cd-ef', '@[^-]*', 1) AS instr_a,
REGEXP_INSTR('a@cd-ef b@cd-ef', '@[^-]*', 2) AS instr_b,
REGEXP_INSTR('a@cd-ef b@cd-ef', '@[^-]*', 3) AS instr_c,
REGEXP_INSTR('a@cd-ef b@cd-ef', '@[^-]*', 4) AS instr_d,
/*---------------------------------------*
| instr_a | instr_b | instr_c | instr_d |
+---------------------------------------+
| 2 | 2 | 10 | 10 |
*---------------------------------------*/
SELECT
REGEXP_INSTR('a@cd-ef b@cd-ef c@cd-ef', '@[^-]*', 1, 1) AS instr_a,
REGEXP_INSTR('a@cd-ef b@cd-ef c@cd-ef', '@[^-]*', 1, 2) AS instr_b,
REGEXP_INSTR('a@cd-ef b@cd-ef c@cd-ef', '@[^-]*', 1, 3) AS instr_c
/*-----------------------------*
| instr_a | instr_b | instr_c |
+-----------------------------+
| 2 | 10 | 18 |
*-----------------------------*/
SELECT
REGEXP_INSTR('a@cd-ef', '@[^-]*', 1, 1, 0) AS instr_a,
REGEXP_INSTR('a@cd-ef', '@[^-]*', 1, 1, 1) AS instr_b
/*-------------------*
| instr_a | instr_b |
+-------------------+
| 2 | 5 |
*-------------------*/
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.
This function supports specifying collation.
Return type
STRING
or BYTES
Examples
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" |
*---------*/
RIGHT
RIGHT(value, length)
Description
Returns a STRING
or BYTES
value that consists of the specified
number of rightmost characters or bytes from value
. The length
is an
INT64
that specifies the length of the returned
value. If value
is BYTES
, length
is the number of rightmost bytes to
return. If value
is STRING
, length
is the number of rightmost characters
to return.
If length
is 0, an empty STRING
or BYTES
value will be
returned. If length
is negative, an error will be returned. If length
exceeds the number of characters or bytes from value
, the original value
will be returned.
Return type
STRING
or BYTES
Examples
SELECT 'apple' AS example, RIGHT('apple', 3) AS right_example
/*---------+---------------*
| example | right_example |
+---------+---------------+
| apple | ple |
*---------+---------------*/
SELECT b'apple' AS example, RIGHT(b'apple', 3) AS right_example
-- Note that the result of RIGHT is of type BYTES, displayed as a base64-encoded string.
/*----------+---------------*
| example | right_example |
+----------+---------------+
| YXBwbGU= | cGxl |
*----------+---------------*/
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
.
This function supports specifying collation.
Return type
ARRAY<STRING>
or ARRAY<BYTES>
Examples
STARTS_WITH
STARTS_WITH(value, prefix)
Description
Takes two STRING
or BYTES
values. Returns TRUE
if prefix
is a
prefix of value
.
This function supports specifying collation.
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.
This function supports specifying collation.
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 |
+---------+
| |
*---------*/
SUBSTRING
SUBSTRING(value, position[, length])
Alias for SUBSTR
.
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 |
*----------------------------------+------------------*/
TO_INT64
TO_INT64(bytes_value)
Description
Converts the big-endian bytes of a 64-bit signed integer into an INT64
value.
Definitions
bytes_value
: The big-endian bytes to convert. The length ofbytes_value
must be 8. IfNULL
, the function returnsNULL
.
Return Data Type
INT64
Example
SELECT TO_INT64(b'\x00\x00\x00\x00\x00\x00\x00d') AS integer_value
/*---------------------*
| integer_value |
+---------------------+
| 100 |
*---------------------*/
TO_VECTOR32
TO_VECTOR32(bytes_value)
Description
Converts the big-endian bytes of one or more 32-bit IEEE 754 floating point
numbers into an ARRAY
value.
Definitions
bytes_value
: The bytes to convert, which must be the concatenation of the big-endian bytes of 32-bit IEEE 754 floating point numbers. The length ofbytes_value
must be a multiple of 8. IfNULL
, the function returnsNULL
.
Return Data Type
ARRAY<FLOAT32>
Example
SELECT TO_VECTOR32(b'\x3f\xc0\x00\x00\x42\xc8\x00\x00') AS array_val
/*---------------------*
| array_val |
+---------------------+
| [ 1.5, 100.0 ] |
*---------------------*/
TO_VECTOR64
TO_VECTOR64(bytes_value)
Description
Converts the big-endian bytes of one or more 64-bit IEEE 754 floating point
numbers into an ARRAY
value.
Definitions
bytes_value
: The bytes to convert, which must be the concatenation of the big-endian bytes of 64-bit IEEE 754 floating point numbers. The length ofbytes_value
must be a multiple of 8. IfNULL
, the function returnsNULL
.
Return Data Type
ARRAY<FLOAT64>
Example
SELECT TO_VECTOR64(b'\x40\x5e\xdc\xcc\xcc\xcc\xcc\xcd\x40\x4c\x63\xd7\x0a\x3d\x70\xa4') AS array_val
/*---------------------*
| array_val |
+---------------------+
| [ 123.45, 56.78 ] |
*---------------------*/
TRANSLATE
TRANSLATE(expression, source_characters, target_characters)
Description
In expression
, replaces each character in source_characters
with the
corresponding character in target_characters
. All inputs must be the same
type, either STRING
or BYTES
.
- Each character in
expression
is translated at most once. - A character in
expression
that is not present insource_characters
is left unchanged inexpression
. - A character in
source_characters
without a corresponding character intarget_characters
is omitted from the result. - A duplicate character in
source_characters
results in an error.
Return type
STRING
or BYTES
Examples
SELECT TRANSLATE('This is a cookie', 'sco', 'zku') AS translate
/*------------------*
| translate |
+------------------+
| Thiz iz a kuukie |
*------------------*/
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== |
*----------------------+------------------*/
UNICODE
UNICODE(value)
Description
Returns the Unicode code point for the first character in
value
. Returns 0
if value
is empty, or if the resulting Unicode code
point is 0
.
Return type
INT64
Examples
SELECT UNICODE('âbcd') as A, UNICODE('â') as B, UNICODE('') as C, UNICODE(NULL) as D;
/*-------+-------+-------+-------*
| A | B | C | D |
+-------+-------+-------+-------+
| 226 | 226 | 0 | NULL |
*-------+-------+-------+-------*/
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
GoogleSQL for Bigtable 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.
|
GENERATE_TIMESTAMP_ARRAY
|
Generates an array of timestamps in a range.
For more information, see Array functions. |
PARSE_TIMESTAMP
|
Converts a STRING value to a TIMESTAMP value.
|
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_FROM_UNIX_MICROS
|
Similar to TIMESTAMP_MICROS , except that additionally, a
TIMESTAMP value can be passed in.
|
TIMESTAMP_FROM_UNIX_MILLIS
|
Similar to TIMESTAMP_MILLIS , except that additionally, a
TIMESTAMP value can be passed in.
|
TIMESTAMP_FROM_UNIX_SECONDS
|
Similar to TIMESTAMP_SECONDS , except that additionally, a
TIMESTAMP value can be passed in.
|
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 or
DATETIME 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-02 23:57:12.120174 UTC |
*--------------------------------*/
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:
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.WEEK(<WEEKDAY>)
: Returns the week number oftimestamp_expression
in the range [0, 53]. Weeks begin onWEEKDAY
.datetime
s prior to the firstWEEKDAY
of the year are in week 0. Valid values forWEEKDAY
areSUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, andSATURDAY
.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 |
*---------+---------+------+------*/
In the following example, timestamp_expression
falls on a Monday. EXTRACT
calculates the first column using weeks that begin on Sunday, and it calculates
the second column using weeks that begin on Monday.
SELECT
EXTRACT(WEEK(SUNDAY) FROM TIMESTAMP("2017-11-06 00:00:00+00")) AS week_sunday,
EXTRACT(WEEK(MONDAY) FROM TIMESTAMP("2017-11-06 00:00:00+00")) AS week_monday
-- Display of results may differ, depending upon the environment and time zone
-- where this query was executed.
/*-------------+---------------*
| week_sunday | week_monday |
+-------------+---------------+
| 45 | 44 |
*-------------+---------------*/
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
%P
.
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, UTC. 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-25 07:30:00 UTC |
*-------------------------*/
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, UTC, 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-25 15:30:00 UTC |
*-------------------------*/
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-25 23:30:00 UTC |
*-------------------------*/
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-25 15:30:00 UTC |
*-------------------------*/
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-25 00:00:00 UTC |
*-------------------------*/
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
:
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-25 15:30:00 UTC | 2008-12-25 15:40:00 UTC |
*-------------------------+-------------------------*/
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: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 microseconds
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-07 10:20:00 UTC | 2008-12-25 15:30:00 UTC | 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_FROM_UNIX_MICROS
TIMESTAMP_FROM_UNIX_MICROS(int64_expression)
TIMESTAMP_FROM_UNIX_MICROS(timestamp_expression)
Description
Interprets int64_expression
as the number of microseconds since
1970-01-01 00:00:00 UTC and returns a timestamp. If a timestamp is passed in,
the same timestamp is returned.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_FROM_UNIX_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-25 15:30:00 UTC |
*-------------------------*/
TIMESTAMP_FROM_UNIX_MILLIS
TIMESTAMP_FROM_UNIX_MILLIS(int64_expression)
TIMESTAMP_FROM_UNIX_MILLIS(timestamp_expression)
Description
Interprets int64_expression
as the number of milliseconds since
1970-01-01 00:00:00 UTC and returns a timestamp. If a timestamp is passed in,
the same timestamp is returned.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_FROM_UNIX_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-25 15:30:00 UTC |
*-------------------------*/
TIMESTAMP_FROM_UNIX_SECONDS
TIMESTAMP_FROM_UNIX_SECONDS(int64_expression)
TIMESTAMP_FROM_UNIX_SECONDS(timestamp_expression)
Description
Interprets int64_expression
as the number of seconds since
1970-01-01 00:00:00 UTC and returns a timestamp. If a timestamp is passed in,
the same timestamp is returned.
Return Data Type
TIMESTAMP
Example
SELECT TIMESTAMP_FROM_UNIX_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-25 15:30:00 UTC |
*-------------------------*/
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-25 15:30:00 UTC |
*-------------------------*/
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-25 15:30:00 UTC |
*-------------------------*/
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-25 15:30:00 UTC |
*-------------------------*/
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
:
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-25 15:30:00 UTC | 2008-12-25 15:20:00 UTC |
*-------------------------+-------------------------*/
TIMESTAMP_TRUNC
TIMESTAMP_TRUNC(timestamp_value, timestamp_granularity[, time_zone])
TIMESTAMP_TRUNC(datetime_value, datetime_granularity)
Description
Truncates a TIMESTAMP
or DATETIME
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, UTC, as part of the truncate operation.datetime_value
: ADATETIME
value to truncate.datetime_granularity
: The truncation granularity for aDATETIME
value. Date granularities and time 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)
.WEEK(WEEKDAY)
: The first day in the week that contains the value to truncate. Weeks begin onWEEKDAY
.WEEKDAY
must be one of the following:SUNDAY
,MONDAY
,TUESDAY
,WEDNESDAY
,THURSDAY
,FRIDAY
, orSATURDAY
.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
MICROSECOND
: If used, nothing is truncated from the value.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
WEEK(<WEEKDAY>)
ISOWEEK
MONTH
QUARTER
YEAR
ISOYEAR
Details
The resulting value is always rounded to the beginning of granularity
.
Return Data Type
The same data type as the first argument passed into this function.
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-25 00:00:00 UTC | 2008-12-25 08:00:00 UTC |
*-------------------------+-------------------------*/
In the following example, timestamp_expression
has a time zone offset of +12.
The first column shows the timestamp_expression
in UTC time. The second
column shows the output of TIMESTAMP_TRUNC
using weeks that start on Monday.
Because the timestamp_expression
falls on a Sunday in UTC, TIMESTAMP_TRUNC
truncates it to the preceding Monday. The third column shows the same function
with the optional Time zone definition
argument 'Pacific/Auckland'. Here, the function truncates the
timestamp_expression
using New Zealand Daylight Time, where it falls on a
Monday.
SELECT
timestamp_value AS timestamp_value,
TIMESTAMP_TRUNC(timestamp_value, WEEK(MONDAY), "UTC") AS utc_truncated,
TIMESTAMP_TRUNC(timestamp_value, WEEK(MONDAY), "Pacific/Auckland") AS nzdt_truncated
FROM (SELECT TIMESTAMP("2017-11-06 00:00:00+12") AS timestamp_value);
-- Display of results may differ, depending upon the environment and time zone where this query was executed.
/*-------------------------+-------------------------+-------------------------*
| timestamp_value | utc_truncated | nzdt_truncated |
+-------------------------+-------------------------+-------------------------+
| 2017-11-05 12:00:00 UTC | 2017-10-30 00:00:00 UTC | 2017-11-05 11:00:00 UTC |
*-------------------------+-------------------------+-------------------------*/
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.
/*-------------------------+----------------*
| isoyear_boundary | isoyear_number |
+-------------------------+----------------+
| 2014-12-29 00:00:00 UTC | 2015 |
*-------------------------+----------------*/
UNIX_MICROS
UNIX_MICROS(timestamp_expression)
Description
Returns the number of microseconds since 1970-01-01 00:00:00 UTC
.
Return Data Type
INT64
Examples
SELECT UNIX_MICROS(TIMESTAMP "2008-12-25 15:30:00+00") AS micros;
/*------------------*
| micros |
+------------------+
| 1230219000000000 |
*------------------*/
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, UTC,
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.