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
][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> |