String functions in GoogleSQL

GoogleSQL for Spanner supports string functions. These string functions work on two different values: STRING and BYTES data types. STRING values must be well-formed UTF-8.

Functions that return position values, such as STRPOS, encode those positions as INT64. The value 1 refers to the first character (or byte), 2 refers to the second, and so on. The value 0 indicates an invalid position. When working on STRING types, the returned positions refer to character positions.

All string comparisons are done byte-by-byte, without regard to Unicode canonical equivalence.

Function list

Name Summary
BYTE_LENGTH Gets the number of BYTES in a STRING or BYTES value.
CHAR_LENGTH Gets the number of characters in a STRING value.
CHARACTER_LENGTH Synonym for CHAR_LENGTH.
CODE_POINTS_TO_BYTES Converts an array of extended ASCII code points to a BYTES value.
CODE_POINTS_TO_STRING Converts an array of extended ASCII code points to a STRING value.
CONCAT Concatenates one or more STRING or BYTES values into a single result.
ENDS_WITH Checks if a STRING or BYTES value is the suffix of another value.
FORMAT Formats data and produces the results as a STRING value.
FROM_BASE32 Converts a base32-encoded STRING value into a BYTES value.
FROM_BASE64 Converts a base64-encoded STRING value into a BYTES value.
FROM_HEX Converts a hexadecimal-encoded STRING value into a BYTES value.
LENGTH Gets the length of a STRING or BYTES value.
LOWER Formats alphabetic characters in a STRING value as lowercase.

Formats ASCII characters in a BYTES value as lowercase.
LPAD Prepends a STRING or BYTES value with a pattern.
LTRIM Identical to the TRIM function, but only removes leading characters.
NORMALIZE Case-sensitively normalizes the characters in a STRING value.
NORMALIZE_AND_CASEFOLD Case-insensitively normalizes the characters in a STRING value.
REGEXP_CONTAINS Checks if a value is a partial match for a regular expression.
REGEXP_EXTRACT Produces a substring that matches a regular expression.
REGEXP_EXTRACT_ALL Produces an array of all substrings that match a regular expression.
REGEXP_REPLACE Produces a STRING value where all substrings that match a regular expression are replaced with a specified value.
REPEAT Produces a STRING or BYTES value that consists of an original value, repeated.
REPLACE Replaces all occurrences of a pattern with another pattern in a STRING or BYTES value.
REVERSE Reverses a STRING or BYTES value.
RPAD Appends a STRING or BYTES value with a pattern.
RTRIM Identical to the TRIM function, but only removes trailing characters.
SAFE_CONVERT_BYTES_TO_STRING Converts a BYTES value to a STRING value and replace any invalid UTF-8 characters with the Unicode replacement character, U+FFFD.
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.
STRPOS Finds the position of the first occurrence of a subvalue inside another value.
SUBSTR Gets a portion of a STRING or BYTES value.
TO_BASE32 Converts a BYTES value to a base32-encoded STRING value.
TO_BASE64 Converts a BYTES value to a base64-encoded STRING value.
TO_CODE_POINTS Converts a STRING or BYTES value into an array of extended ASCII code points.
TO_HEX Converts a BYTES value to a hexadecimal STRING value.
TRIM Removes the specified leading and trailing Unicode code points or bytes from a STRING or BYTES value.
UPPER Formats alphabetic characters in a STRING value as uppercase.

Formats ASCII characters in a BYTES value as uppercase.

BYTE_LENGTH

BYTE_LENGTH(value)

Description

Gets the number of BYTES in a STRING or BYTES value, regardless of whether the value is a STRING or BYTES type.

Return type

INT64

Examples

WITH example AS
  (SELECT 'абвгд' AS characters, b'абвгд' AS bytes)

SELECT
  characters,
  BYTE_LENGTH(characters) AS string_example,
  bytes,
  BYTE_LENGTH(bytes) AS bytes_example
FROM example;

/*------------+----------------+-------+---------------*
 | characters | string_example | bytes | bytes_example |
 +------------+----------------+-------+---------------+
 | абвгд      | 10             | абвгд | 10            |
 *------------+----------------+-------+---------------*/

CHAR_LENGTH

CHAR_LENGTH(value)

Description

Gets the number of characters in a STRING value.

Return type

INT64

Examples

WITH example AS
  (SELECT 'абвгд' AS characters)

SELECT
  characters,
  CHAR_LENGTH(characters) AS char_length_example
FROM example;

/*------------+---------------------*
 | characters | char_length_example |
 +------------+---------------------+
 | абвгд      |                   5 |
 *------------+---------------------*/

CHARACTER_LENGTH

CHARACTER_LENGTH(value)

Description

Synonym for CHAR_LENGTH.

Return type

INT64

Examples

WITH example AS
  (SELECT 'абвгд' AS characters)

SELECT
  characters,
  CHARACTER_LENGTH(characters) AS char_length_example
FROM example;

/*------------+---------------------*
 | characters | char_length_example |
 +------------+---------------------+
 | абвгд      |                   5 |
 *------------+---------------------*/

CODE_POINTS_TO_BYTES

CODE_POINTS_TO_BYTES(ascii_code_points)

Description

Takes an array of extended ASCII code points as ARRAY<INT64> and returns BYTES.

To convert from BYTES to an array of code points, see TO_CODE_POINTS.

Return type

BYTES

Examples

The following is a basic example using CODE_POINTS_TO_BYTES.

SELECT CODE_POINTS_TO_BYTES([65, 98, 67, 100]) AS bytes;

-- Note that the result of CODE_POINTS_TO_BYTES is of type BYTES, displayed as a base64-encoded string.
-- In BYTES format, b'AbCd' is the result.
/*----------*
 | bytes    |
 +----------+
 | QWJDZA== |
 *----------*/

The following example uses a rotate-by-13 places (ROT13) algorithm to encode a string.

SELECT CODE_POINTS_TO_BYTES(ARRAY(
  (SELECT
      CASE
        WHEN chr BETWEEN b'a' AND b'z'
          THEN TO_CODE_POINTS(b'a')[offset(0)] +
            MOD(code + 13 - TO_CODE_POINTS(b'a')[offset(0)],26)
        WHEN chr BETWEEN b'A' AND b'Z'
          THEN TO_CODE_POINTS(b'A')[offset(0)] +
            MOD(code + 13 - TO_CODE_POINTS(b'A')[offset(0)],26)
        ELSE code
      END
   FROM
     (SELECT code, CODE_POINTS_TO_BYTES(ARRAY[code]) AS chr
      FROM UNNEST(TO_CODE_POINTS(input)) AS code WITH OFFSET
      ORDER BY OFFSET)
   ))) AS encoded_string
FROM UNNEST(ARRAY['Test String!']) AS input;

-- Note that the result of CODE_POINTS_TO_BYTES is of type BYTES, displayed as a base64-encoded string.
-- In BYTES format, b'Grfg Fgevat!' is the result.
/*------------------*
 | encoded_string   |
 +------------------+
 | R3JmZyBGZ2V2YXQh |
 *------------------*/

CODE_POINTS_TO_STRING

CODE_POINTS_TO_STRING(unicode_code_points)

Description

Takes an array of Unicode code points as ARRAY<INT64> and returns a STRING.

To convert from a string to an array of code points, see TO_CODE_POINTS.

Return type

STRING

Examples

The following are basic examples using CODE_POINTS_TO_STRING.

SELECT CODE_POINTS_TO_STRING([65, 255, 513, 1024]) AS string;

/*--------*
 | string |
 +--------+
 | AÿȁЀ   |
 *--------*/
SELECT CODE_POINTS_TO_STRING([97, 0, 0xF9B5]) AS string;

/*--------*
 | string |
 +--------+
 | a例    |
 *--------*/
SELECT CODE_POINTS_TO_STRING([65, 255, NULL, 1024]) AS string;

/*--------*
 | string |
 +--------+
 | NULL   |
 *--------*/

The following example computes the frequency of letters in a set of words.

WITH Words AS (
  SELECT word
  FROM UNNEST(['foo', 'bar', 'baz', 'giraffe', 'llama']) AS word
)
SELECT
  CODE_POINTS_TO_STRING([code_point]) AS letter,
  COUNT(*) AS letter_count
FROM Words,
  UNNEST(TO_CODE_POINTS(word)) AS code_point
GROUP BY 1
ORDER BY 2 DESC;

/*--------+--------------*
 | letter | letter_count |
 +--------+--------------+
 | a      | 5            |
 | f      | 3            |
 | r      | 2            |
 | b      | 2            |
 | l      | 2            |
 | o      | 2            |
 | g      | 1            |
 | z      | 1            |
 | e      | 1            |
 | m      | 1            |
 | i      | 1            |
 *--------+--------------*/

CONCAT

CONCAT(value1[, ...])

Description

Concatenates one or more STRING or BYTE values into a single result.

The function returns NULL if any input argument is NULL.

Return type

STRING or BYTES

Examples

SELECT CONCAT('T.P.', ' ', 'Bar') as author;

/*---------------------*
 | author              |
 +---------------------+
 | T.P. Bar            |
 *---------------------*/

With Employees AS
  (SELECT
    'John' AS first_name,
    'Doe' AS last_name
  UNION ALL
  SELECT
    'Jane' AS first_name,
    'Smith' AS last_name
  UNION ALL
  SELECT
    'Joe' AS first_name,
    'Jackson' AS last_name)

SELECT
  CONCAT(first_name, ' ', last_name)
  AS full_name
FROM Employees;

/*---------------------*
 | full_name           |
 +---------------------+
 | John Doe            |
 | Jane Smith          |
 | Joe Jackson         |
 *---------------------*/

ENDS_WITH

ENDS_WITH(value, suffix)

Description

Takes two STRING or BYTES values. Returns TRUE if suffix is a suffix of value.

Return type

BOOL

Examples

WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  ENDS_WITH(item, 'e') as example
FROM items;

/*---------*
 | example |
 +---------+
 |    True |
 |   False |
 |    True |
 *---------*/

FORMAT

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:

Format specifiers
Specifier Description Examples Types
d or i Decimal integer 392 INT64
o Octal

Note: If an INT64 value is negative, an error is produced.
610 INT64
x Hexadecimal integer

Note: If an INT64 value is negative, an error is produced.
7fa INT64
X Hexadecimal integer (uppercase)

Note: If an INT64 value is negative, an error is produced.
7FA INT64
f Decimal notation, in [-](integer part).(fractional part) for finite values, and in lowercase for non-finite values 392.650000
inf
nan
NUMERIC
FLOAT64
F Decimal notation, in [-](integer part).(fractional part) for finite values, and in uppercase for non-finite values 392.650000
INF
NAN
NUMERIC
FLOAT64
e Scientific notation (mantissa/exponent), lowercase 3.926500e+02
inf
nan
NUMERIC
FLOAT64
E Scientific notation (mantissa/exponent), uppercase 3.926500E+02
INF
NAN
NUMERIC
FLOAT64
g Either decimal notation or scientific notation, depending on the input value's exponent and the specified precision. Lowercase. See %g and %G behavior for details. 392.65
3.9265e+07
inf
nan
NUMERIC
FLOAT64
G Either decimal notation or scientific notation, depending on the input value's exponent and the specified precision. Uppercase. See %g and %G behavior for details. 392.65
3.9265E+07
INF
NAN
NUMERIC
FLOAT64
p Produces a one-line printable string representing JSON. See %p and %P behavior.
{"month":10,"year":2019}
JSON
P Produces a multi-line printable string representing JSON. See %p and %P behavior.
{
  "month": 10,
  "year": 2019
}
JSON
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
#
  • For `%o`, `%x`, and `%X`, this flag means to precede the value with 0, 0x or 0X respectively for values different than zero.
  • For `%f`, `%F`, `%e`, and `%E`, this flag means to add the decimal point even when there is no fractional part, unless the value is non-finite.
  • For `%g` and `%G`, this flag means to add the decimal point even when there is no fractional part unless the value is non-finite, and never remove the trailing zeros after the decimal point.
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:

  • FORMAT("%'d", 12345678) returns 12,345,678
  • FORMAT("%'x", 12345678) returns bc:614e
  • FORMAT("%'o", 55555) returns 15,4403
  • This flag is only relevant for decimal, hex, and octal values.

Flags may be specified in any order. Duplicate flags are not an error. When flags are not relevant for some element type, they are ignored.

Width
Width Description
<number> Minimum number of characters to be printed. If the value to be printed is shorter than this number, the result is padded with blank spaces. The value is not truncated even if the result is larger
* The width is not specified in the format string, but as an additional integer value argument preceding the argument that has to be formatted
Precision
Precision Description
.<number>
  • For integer specifiers `%d`, `%i`, `%o`, `%u`, `%x`, and `%X`: precision specifies the minimum number of digits to be written. If the value to be written is shorter than this number, the result is padded with trailing zeros. The value is not truncated even if the result is longer. A precision of 0 means that no character is written for the value 0.
  • For specifiers `%a`, `%A`, `%e`, `%E`, `%f`, and `%F`: this is the number of digits to be printed after the decimal point. The default value is 6.
  • For specifiers `%g` and `%G`: this is the number of significant digits to be printed, before the removal of the trailing zeros after the decimal point. The default value is 6.
.* The precision is not specified in the format string, but as an additional integer value argument preceding the argument that has to be formatted
%g and %G behavior

The %g and %G format specifiers choose either the decimal notation (like the %f and %F specifiers) or the scientific notation (like the %e and %E specifiers), depending on the input value's exponent and the specified precision.

Let p stand for the specified precision (defaults to 6; 1 if the specified precision is less than 1). The input value is first converted to scientific notation with precision = (p - 1). If the resulting exponent part x is less than -4 or no less than p, the scientific notation with precision = (p - 1) is used; otherwise the decimal notation with precision = (p - 1 - x) is used.

Unless # flag is present, the trailing zeros after the decimal point are removed, and the decimal point is also removed if there is no digit after it.

%p and %P behavior

The %p format specifier produces a one-line printable string. The %P format specifier produces a multi-line printable string. You can use these format specifiers with the following data types:

Type %p %P
JSON

JSON input:

JSON '
{
  "month": 10,
  "year": 2019
}
'

Produces a one-line printable string representing JSON:

{"month":10,"year":2019}

JSON input:

JSON '
{
  "month": 10,
  "year": 2019
}
'

Produces a multi-line printable string representing JSON:

{
  "month": 10,
  "year": 2019
}
%t and %T behavior

The %t and %T format specifiers are defined for all types. The width, precision, and flags act as they do for %s: the width is the minimum width and the STRING will be padded to that size, and precision is the maximum width of content to show and the STRING will be truncated to that size, prior to padding to width.

The %t specifier is always meant to be a readable form of the value.

The %T specifier is always a valid SQL literal of a similar type, such as a wider numeric type. The literal will not include casts or a type name, except for the special case of non-finite floating point values.

The STRING is formatted as follows:

Type %t %T
NULL of any type NULL NULL
INT64
123 123
NUMERIC 123.0 (always with .0) NUMERIC "123.0"
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
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
JSON one-line printable string representing JSON.
{"name":"apple","stock":3}
one-line printable string representing a JSON literal.
JSON '{"name":"apple","stock":3}'
Error conditions

If a format specifier is invalid, or is not compatible with the related argument type, or the wrong number or arguments are provided, then an error is produced. For example, the following <format_string> expressions are invalid:

FORMAT('%s', 1)
FORMAT('%')
NULL argument handling

A NULL format string results in a NULL output STRING. Any other arguments are ignored in this case.

The function generally produces a NULL value if a NULL argument is present. For example, FORMAT('%i', NULL_expression) produces a NULL STRING as output.

However, there are some exceptions: if the format specifier is %t or %T (both of which produce STRINGs that effectively match CAST and literal value semantics), a NULL value produces 'NULL' (without the quotes) in the result STRING. For example, the function:

FORMAT('00-%t-00', NULL_expression);

Returns

00-NULL-00
Additional semantic rules

FLOAT64 values can be +/-inf or NaN. When an argument has one of those values, the result of the format specifiers %f, %F, %e, %E, %g, %G, and %t are inf, -inf, or nan (or the same in uppercase) as appropriate. This is consistent with how GoogleSQL casts these values to STRING. For %T, GoogleSQL returns quoted strings for FLOAT64 values that don't have non-string literal representations.

FROM_BASE32

FROM_BASE32(string_expr)

Description

Converts the base32-encoded input string_expr into BYTES format. To convert BYTES to a base32-encoded STRING, use TO_BASE32.

Return type

BYTES

Example

SELECT FROM_BASE32('MFRGGZDF74======') AS byte_data;

-- Note that the result of FROM_BASE32 is of type BYTES, displayed as a base64-encoded string.
/*-----------*
 | byte_data |
 +-----------+
 | YWJjZGX/  |
 *-----------*/

FROM_BASE64

FROM_BASE64(string_expr)

Description

Converts the base64-encoded input string_expr into BYTES format. To convert BYTES to a base64-encoded STRING, use [TO_BASE64][string-link-to-base64].

There are several base64 encodings in common use that vary in exactly which alphabet of 65 ASCII characters are used to encode the 64 digits and padding. See RFC 4648 for details. This function expects the alphabet [A-Za-z0-9+/=].

Return type

BYTES

Example

SELECT FROM_BASE64('/+A=') AS byte_data;

-- Note that the result of FROM_BASE64 is of type BYTES, displayed as a base64-encoded string.
/*-----------*
 | byte_data |
 +-----------+
 | /+A=      |
 *-----------*/

To work with an encoding using a different base64 alphabet, you might need to compose FROM_BASE64 with the REPLACE function. For instance, the base64url url-safe and filename-safe encoding commonly used in web programming uses -_= as the last characters rather than +/=. To decode a base64url-encoded string, replace - and _ with + and / respectively.

SELECT FROM_BASE64(REPLACE(REPLACE('_-A=', '-', '+'), '_', '/')) AS binary;

-- Note that the result of FROM_BASE64 is of type BYTES, displayed as a base64-encoded string.
/*--------*
 | binary |
 +--------+
 | /+A=   |
 *--------*/

FROM_HEX

FROM_HEX(string)

Description

Converts a hexadecimal-encoded STRING into BYTES format. Returns an error if the input STRING contains characters outside the range (0..9, A..F, a..f). The lettercase of the characters does not matter. If the input STRING has an odd number of characters, the function acts as if the input has an additional leading 0. To convert BYTES to a hexadecimal-encoded STRING, use TO_HEX.

Return type

BYTES

Example

WITH Input AS (
  SELECT '00010203aaeeefff' AS hex_str UNION ALL
  SELECT '0AF' UNION ALL
  SELECT '666f6f626172'
)
SELECT hex_str, FROM_HEX(hex_str) AS bytes_str
FROM Input;

-- Note that the result of FROM_HEX is of type BYTES, displayed as a base64-encoded string.
/*------------------+--------------*
 | hex_str          | bytes_str    |
 +------------------+--------------+
 | 0AF              | AAECA6ru7/8= |
 | 00010203aaeeefff | AK8=         |
 | 666f6f626172     | Zm9vYmFy     |
 *------------------+--------------*/

LENGTH

LENGTH(value)

Description

Returns the length of the STRING or BYTES value. The returned value is in characters for STRING arguments and in bytes for the BYTES argument.

Return type

INT64

Examples


WITH example AS
  (SELECT 'абвгд' AS characters)

SELECT
  characters,
  LENGTH(characters) AS string_example,
  LENGTH(CAST(characters AS BYTES)) AS bytes_example
FROM example;

/*------------+----------------+---------------*
 | characters | string_example | bytes_example |
 +------------+----------------+---------------+
 | абвгд      |              5 |            10 |
 *------------+----------------+---------------*/

LOWER

LOWER(value)

Description

For STRING arguments, returns the original string with all alphabetic characters in lowercase. Mapping between lowercase and uppercase is done according to the Unicode Character Database without taking into account language-specific mappings.

For BYTES arguments, the argument is treated as ASCII text, with all bytes greater than 127 left intact.

Return type

STRING or BYTES

Examples


WITH items AS
  (SELECT
    'FOO' as item
  UNION ALL
  SELECT
    'BAR' as item
  UNION ALL
  SELECT
    'BAZ' as item)

SELECT
  LOWER(item) AS example
FROM items;

/*---------*
 | example |
 +---------+
 | foo     |
 | bar     |
 | baz     |
 *---------*/

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 negative
  • pattern is empty

Return type

STRING or BYTES

Examples

SELECT t, len, FORMAT('%T', LPAD(t, len)) AS LPAD FROM UNNEST([
  STRUCT('abc' AS t, 5 AS len),
  ('abc', 2),
  ('例子', 4)
]);

/*------+-----+----------*
 | t    | len | LPAD     |
 |------|-----|----------|
 | abc  | 5   | "  abc"  |
 | abc  | 2   | "ab"     |
 | 例子  | 4   | "  例子" |
 *------+-----+----------*/
SELECT t, len, pattern, FORMAT('%T', LPAD(t, len, pattern)) AS LPAD FROM UNNEST([
  STRUCT('abc' AS t, 8 AS len, 'def' AS pattern),
  ('abc', 5, '-'),
  ('例子', 5, '中文')
]);

/*------+-----+---------+--------------*
 | t    | len | pattern | LPAD         |
 |------|-----|---------|--------------|
 | abc  | 8   | def     | "defdeabc"   |
 | abc  | 5   | -       | "--abc"      |
 | 例子  | 5   | 中文    | "中文中例子"   |
 *------+-----+---------+--------------*/
SELECT FORMAT('%T', t) AS t, len, FORMAT('%T', LPAD(t, len)) AS LPAD FROM UNNEST([
  STRUCT(b'abc' AS t, 5 AS len),
  (b'abc', 2),
  (b'\xab\xcd\xef', 4)
]);

/*-----------------+-----+------------------*
 | t               | len | LPAD             |
 |-----------------|-----|------------------|
 | b"abc"          | 5   | b"  abc"         |
 | b"abc"          | 2   | b"ab"            |
 | b"\xab\xcd\xef" | 4   | b" \xab\xcd\xef" |
 *-----------------+-----+------------------*/
SELECT
  FORMAT('%T', t) AS t,
  len,
  FORMAT('%T', pattern) AS pattern,
  FORMAT('%T', LPAD(t, len, pattern)) AS LPAD
FROM UNNEST([
  STRUCT(b'abc' AS t, 8 AS len, b'def' AS pattern),
  (b'abc', 5, b'-'),
  (b'\xab\xcd\xef', 5, b'\x00')
]);

/*-----------------+-----+---------+-------------------------*
 | t               | len | pattern | LPAD                    |
 |-----------------|-----|---------|-------------------------|
 | b"abc"          | 8   | b"def"  | b"defdeabc"             |
 | b"abc"          | 5   | b"-"    | b"--abc"                |
 | b"\xab\xcd\xef" | 5   | b"\x00" | b"\x00\x00\xab\xcd\xef" |
 *-----------------+-----+---------+-------------------------*/

LTRIM

LTRIM(value1[, value2])

Description

Identical to TRIM, but only removes leading characters.

Return type

STRING or BYTES

Examples

WITH items AS
  (SELECT '   apple   ' as item
  UNION ALL
  SELECT '   banana   ' as item
  UNION ALL
  SELECT '   orange   ' as item)

SELECT
  CONCAT('#', LTRIM(item), '#') as example
FROM items;

/*-------------*
 | example     |
 +-------------+
 | #apple   #  |
 | #banana   # |
 | #orange   # |
 *-------------*/
WITH items AS
  (SELECT '***apple***' as item
  UNION ALL
  SELECT '***banana***' as item
  UNION ALL
  SELECT '***orange***' as item)

SELECT
  LTRIM(item, '*') as example
FROM items;

/*-----------*
 | example   |
 +-----------+
 | apple***  |
 | banana*** |
 | orange*** |
 *-----------*/
WITH items AS
  (SELECT 'xxxapplexxx' as item
  UNION ALL
  SELECT 'yyybananayyy' as item
  UNION ALL
  SELECT 'zzzorangezzz' as item
  UNION ALL
  SELECT 'xyzpearxyz' as item)

SELECT
  LTRIM(item, 'xyz') as example
FROM items;

/*-----------*
 | example   |
 +-----------+
 | applexxx  |
 | bananayyy |
 | orangezzz |
 | pearxyz   |
 *-----------*/

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

SELECT a, b, a = b as normalized
FROM (SELECT NORMALIZE('\u00ea') as a, NORMALIZE('\u0065\u0302') as b);

/*---+---+------------*
 | a | b | normalized |
 +---+---+------------+
 | ê | ê | true       |
 *---+---+------------*/

The following example normalizes different space characters.

WITH EquivalentNames AS (
  SELECT name
  FROM UNNEST([
      'Jane\u2004Doe',
      'John\u2004Smith',
      'Jane\u2005Doe',
      'Jane\u2006Doe',
      'John Smith']) AS name
)
SELECT
  NORMALIZE(name, NFKC) AS normalized_name,
  COUNT(*) AS name_count
FROM EquivalentNames
GROUP BY 1;

/*-----------------+------------*
 | normalized_name | name_count |
 +-----------------+------------+
 | John Smith      | 2          |
 | Jane Doe        | 3          |
 *-----------------+------------*/

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
  a, b,
  NORMALIZE(a) = NORMALIZE(b) as normalized,
  NORMALIZE_AND_CASEFOLD(a) = NORMALIZE_AND_CASEFOLD(b) as normalized_with_case_folding
FROM (SELECT 'The red barn' AS a, 'The Red Barn' AS b);

/*--------------+--------------+------------+------------------------------*
 | a            | b            | normalized | normalized_with_case_folding |
 +--------------+--------------+------------+------------------------------+
 | The red barn | The Red Barn | false      | true                         |
 *--------------+--------------+------------+------------------------------*/
WITH Strings AS (
  SELECT '\u2168' AS a, 'IX' AS b UNION ALL
  SELECT '\u0041\u030A', '\u00C5'
)
SELECT a, b,
  NORMALIZE_AND_CASEFOLD(a, NFD)=NORMALIZE_AND_CASEFOLD(b, NFD) AS nfd,
  NORMALIZE_AND_CASEFOLD(a, NFC)=NORMALIZE_AND_CASEFOLD(b, NFC) AS nfc,
  NORMALIZE_AND_CASEFOLD(a, NFKD)=NORMALIZE_AND_CASEFOLD(b, NFKD) AS nkfd,
  NORMALIZE_AND_CASEFOLD(a, NFKC)=NORMALIZE_AND_CASEFOLD(b, NFKC) AS nkfc
FROM Strings;

/*---+----+-------+-------+------+------*
 | a | b  | nfd   | nfc   | nkfd | nkfc |
 +---+----+-------+-------+------+------+
 | Ⅸ | IX | false | false | true | true |
 | Å | Å  | true  | true  | true | true |
 *---+----+-------+-------+------+------*/

REGEXP_CONTAINS

REGEXP_CONTAINS(value, regexp)

Description

Returns TRUE if value is a partial match for the regular expression, regexp.

If the regexp argument is invalid, the function returns an error.

You can search for a full match by using ^ (beginning of text) and $ (end of text). Due to regular expression operator precedence, it is good practice to use parentheses around everything between ^ and $.

Return type

BOOL

Examples

SELECT
  email,
  REGEXP_CONTAINS(email, r'@[a-zA-Z0-9-]+\.[a-zA-Z0-9-.]+') AS is_valid
FROM
  (SELECT
    ['foo@example.com', 'bar@example.org', 'www.example.net']
    AS addresses),
  UNNEST(addresses) AS email;

/*-----------------+----------*
 | email           | is_valid |
 +-----------------+----------+
 | foo@example.com | true     |
 | bar@example.org | true     |
 | www.example.net | false    |
 *-----------------+----------*/

-- Performs a full match, using ^ and $. Due to regular expression operator
-- precedence, it is good practice to use parentheses around everything between ^
-- and $.
SELECT
  email,
  REGEXP_CONTAINS(email, r'^([\w.+-]+@foo\.com|[\w.+-]+@bar\.org)$')
    AS valid_email_address,
  REGEXP_CONTAINS(email, r'^[\w.+-]+@foo\.com|[\w.+-]+@bar\.org$')
    AS without_parentheses
FROM
  (SELECT
    ['a@foo.com', 'a@foo.computer', 'b@bar.org', '!b@bar.org', 'c@buz.net']
    AS addresses),
  UNNEST(addresses) AS email;

/*----------------+---------------------+---------------------*
 | email          | valid_email_address | without_parentheses |
 +----------------+---------------------+---------------------+
 | a@foo.com      | true                | true                |
 | a@foo.computer | false               | true                |
 | b@bar.org      | true                | true                |
 | !b@bar.org     | false               | true                |
 | c@buz.net      | false               | false               |
 *----------------+---------------------+---------------------*/

REGEXP_EXTRACT

REGEXP_EXTRACT(value, 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

WITH email_addresses AS
  (SELECT 'foo@example.com' as email
  UNION ALL
  SELECT 'bar@example.org' as email
  UNION ALL
  SELECT 'baz@example.net' as email)

SELECT
  REGEXP_EXTRACT(email, r'^[a-zA-Z0-9_.+-]+')
  AS user_name
FROM email_addresses;

/*-----------*
 | user_name |
 +-----------+
 | foo       |
 | bar       |
 | baz       |
 *-----------*/
WITH email_addresses AS
  (SELECT 'foo@example.com' as email
  UNION ALL
  SELECT 'bar@example.org' as email
  UNION ALL
  SELECT 'baz@example.net' as email)

SELECT
  REGEXP_EXTRACT(email, r'^[a-zA-Z0-9_.+-]+@[a-zA-Z0-9-]+\.([a-zA-Z0-9-.]+$)')
  AS top_level_domain
FROM email_addresses;

/*------------------*
 | top_level_domain |
 +------------------+
 | com              |
 | org              |
 | net              |
 *------------------*/
WITH
  characters AS (
    SELECT 'ab' AS value, '.b' AS regex UNION ALL
    SELECT 'ab' AS value, '(.)b' AS regex UNION ALL
    SELECT 'xyztb' AS value, '(.)+b' AS regex UNION ALL
    SELECT 'ab' AS value, '(z)?b' AS regex
  )
SELECT value, regex, REGEXP_EXTRACT(value, regex) AS result FROM characters;

/*-------+---------+----------*
 | value | regex   | result   |
 +-------+---------+----------+
 | ab    | .b      | ab       |
 | ab    | (.)b    | a        |
 | xyztb | (.)+b   | t        |
 | ab    | (z)?b   | 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

WITH code_markdown AS
  (SELECT 'Try `function(x)` or `function(y)`' as code)

SELECT
  REGEXP_EXTRACT_ALL(code, '`(.+?)`') AS example
FROM code_markdown;

/*----------------------------*
 | example                    |
 +----------------------------+
 | [function(x), function(y)] |
 *----------------------------*/

REGEXP_REPLACE

REGEXP_REPLACE(value, 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

WITH markdown AS
  (SELECT '# Heading' as heading
  UNION ALL
  SELECT '# Another heading' as heading)

SELECT
  REGEXP_REPLACE(heading, r'^# ([a-zA-Z0-9\s]+$)', '<h1>\\1</h1>')
  AS html
FROM markdown;

/*--------------------------*
 | html                     |
 +--------------------------+
 | <h1>Heading</h1>         |
 | <h1>Another heading</h1> |
 *--------------------------*/

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 t, n, REPEAT(t, n) AS REPEAT FROM UNNEST([
  STRUCT('abc' AS t, 3 AS n),
  ('例子', 2),
  ('abc', null),
  (null, 3)
]);

/*------+------+-----------*
 | t    | n    | REPEAT    |
 |------|------|-----------|
 | abc  | 3    | abcabcabc |
 | 例子 | 2    | 例子例子  |
 | abc  | NULL | NULL      |
 | NULL | 3    | NULL      |
 *------+------+-----------*/

REPLACE

REPLACE(original_value, from_pattern, to_pattern)

Description

Replaces all occurrences of from_pattern with to_pattern in original_value. If from_pattern is empty, no replacement is made.

Return type

STRING or BYTES

Examples

WITH desserts AS
  (SELECT 'apple pie' as dessert
  UNION ALL
  SELECT 'blackberry pie' as dessert
  UNION ALL
  SELECT 'cherry pie' as dessert)

SELECT
  REPLACE (dessert, 'pie', 'cobbler') as example
FROM desserts;

/*--------------------*
 | example            |
 +--------------------+
 | apple cobbler      |
 | blackberry cobbler |
 | cherry cobbler     |
 *--------------------*/

REVERSE

REVERSE(value)

Description

Returns the reverse of the input STRING or BYTES.

Return type

STRING or BYTES

Examples

WITH example AS (
  SELECT 'foo' AS sample_string, b'bar' AS sample_bytes UNION ALL
  SELECT 'абвгд' AS sample_string, b'123' AS sample_bytes
)
SELECT
  sample_string,
  REVERSE(sample_string) AS reverse_string,
  sample_bytes,
  REVERSE(sample_bytes) AS reverse_bytes
FROM example;

/*---------------+----------------+--------------+---------------*
 | sample_string | reverse_string | sample_bytes | reverse_bytes |
 +---------------+----------------+--------------+---------------+
 | foo           | oof            | bar          | rab           |
 | абвгд         | дгвба          | 123          | 321           |
 *---------------+----------------+--------------+---------------*/

RPAD

RPAD(original_value, return_length[, pattern])

Description

Returns a 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 negative
  • pattern is empty

Return type

STRING or BYTES

Examples

SELECT t, len, FORMAT('%T', RPAD(t, len)) AS RPAD FROM UNNEST([
  STRUCT('abc' AS t, 5 AS len),
  ('abc', 2),
  ('例子', 4)
]);

/*------+-----+----------*
 | t    | len | RPAD     |
 +------+-----+----------+
 | abc  | 5   | "abc  "  |
 | abc  | 2   | "ab"     |
 | 例子  | 4   | "例子  " |
 *------+-----+----------*/
SELECT t, len, pattern, FORMAT('%T', RPAD(t, len, pattern)) AS RPAD FROM UNNEST([
  STRUCT('abc' AS t, 8 AS len, 'def' AS pattern),
  ('abc', 5, '-'),
  ('例子', 5, '中文')
]);

/*------+-----+---------+--------------*
 | t    | len | pattern | RPAD         |
 +------+-----+---------+--------------+
 | abc  | 8   | def     | "abcdefde"   |
 | abc  | 5   | -       | "abc--"      |
 | 例子  | 5   | 中文     | "例子中文中"  |
 *------+-----+---------+--------------*/
SELECT FORMAT('%T', t) AS t, len, FORMAT('%T', RPAD(t, len)) AS RPAD FROM UNNEST([
  STRUCT(b'abc' AS t, 5 AS len),
  (b'abc', 2),
  (b'\xab\xcd\xef', 4)
]);

/*-----------------+-----+------------------*
 | t               | len | RPAD             |
 +-----------------+-----+------------------+
 | b"abc"          | 5   | b"abc  "         |
 | b"abc"          | 2   | b"ab"            |
 | b"\xab\xcd\xef" | 4   | b"\xab\xcd\xef " |
 *-----------------+-----+------------------*/
SELECT
  FORMAT('%T', t) AS t,
  len,
  FORMAT('%T', pattern) AS pattern,
  FORMAT('%T', RPAD(t, len, pattern)) AS RPAD
FROM UNNEST([
  STRUCT(b'abc' AS t, 8 AS len, b'def' AS pattern),
  (b'abc', 5, b'-'),
  (b'\xab\xcd\xef', 5, b'\x00')
]);

/*-----------------+-----+---------+-------------------------*
 | t               | len | pattern | RPAD                    |
 +-----------------+-----+---------+-------------------------+
 | b"abc"          | 8   | b"def"  | b"abcdefde"             |
 | b"abc"          | 5   | b"-"    | b"abc--"                |
 | b"\xab\xcd\xef" | 5   | b"\x00" | b"\xab\xcd\xef\x00\x00" |
 *-----------------+-----+---------+-------------------------*/

RTRIM

RTRIM(value1[, value2])

Description

Identical to TRIM, but only removes trailing characters.

Return type

STRING or BYTES

Examples

WITH items AS
  (SELECT '***apple***' as item
  UNION ALL
  SELECT '***banana***' as item
  UNION ALL
  SELECT '***orange***' as item)

SELECT
  RTRIM(item, '*') as example
FROM items;

/*-----------*
 | example   |
 +-----------+
 | ***apple  |
 | ***banana |
 | ***orange |
 *-----------*/
WITH items AS
  (SELECT 'applexxx' as item
  UNION ALL
  SELECT 'bananayyy' as item
  UNION ALL
  SELECT 'orangezzz' as item
  UNION ALL
  SELECT 'pearxyz' as item)

SELECT
  RTRIM(item, 'xyz') as example
FROM items;

/*---------*
 | example |
 +---------+
 | apple   |
 | banana  |
 | orange  |
 | pear    |
 *---------*/

SAFE_CONVERT_BYTES_TO_STRING

SAFE_CONVERT_BYTES_TO_STRING(value)

Description

Converts a sequence of BYTES to a STRING. Any invalid UTF-8 characters are replaced with the Unicode replacement character, U+FFFD.

Return type

STRING

Examples

The following statement returns the Unicode replacement character, �.

SELECT SAFE_CONVERT_BYTES_TO_STRING(b'\xc2') as safe_convert;

SPLIT

SPLIT(value[, delimiter])

Description

Splits value using the delimiter argument.

For STRING, the default delimiter is the comma ,.

For BYTES, you must specify a delimiter.

Splitting on an empty delimiter produces an array of UTF-8 characters for STRING values, and an array of BYTES for BYTES values.

Splitting an empty STRING returns an ARRAY with a single empty STRING.

Return type

ARRAY<STRING> or ARRAY<BYTES>

Examples

WITH letters AS
  (SELECT '' as letter_group
  UNION ALL
  SELECT 'a' as letter_group
  UNION ALL
  SELECT 'b c d' as letter_group)

SELECT SPLIT(letter_group, ' ') as example
FROM letters;

/*----------------------*
 | example              |
 +----------------------+
 | []                   |
 | [a]                  |
 | [b, c, d]            |
 *----------------------*/

STARTS_WITH

STARTS_WITH(value, prefix)

Description

Takes two STRING or BYTES values. Returns TRUE if prefix is a prefix of value.

Return type

BOOL

Examples

WITH items AS
  (SELECT 'foo' as item
  UNION ALL
  SELECT 'bar' as item
  UNION ALL
  SELECT 'baz' as item)

SELECT
  STARTS_WITH(item, 'b') as example
FROM items;

/*---------*
 | example |
 +---------+
 |   False |
 |    True |
 |    True |
 *---------*/

STRPOS

STRPOS(value, subvalue)

Description

Takes two STRING or BYTES values. Returns the 1-based position of the first occurrence of subvalue inside value. Returns 0 if subvalue is not found.

Return type

INT64

Examples

WITH email_addresses AS
  (SELECT
    'foo@example.com' AS email_address
  UNION ALL
  SELECT
    'foobar@example.com' AS email_address
  UNION ALL
  SELECT
    'foobarbaz@example.com' AS email_address
  UNION ALL
  SELECT
    'quxexample.com' AS email_address)

SELECT
  STRPOS(email_address, '@') AS example
FROM email_addresses;

/*---------*
 | example |
 +---------+
 |       4 |
 |       7 |
 |      10 |
 |       0 |
 *---------*/

SUBSTR

SUBSTR(value, position[, length])

Description

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 is 1, the substring starts from the first character or byte.
  • If position is 0 or less than -LENGTH(value), position is set to 1, and the substring starts from the first character or byte.
  • If position is greater than the length of value, the function produces an empty substring.
  • If position is negative, the function counts from the end of value, 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 of value.
  • If length is 0, 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, when length exceeds the length of value, or when the starting position of the substring plus length is greater than the length of value.

Return type

STRING or BYTES

Examples

WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, 2) as example
FROM items;

/*---------*
 | example |
 +---------+
 | pple    |
 | anana   |
 | range   |
 *---------*/
WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, 2, 2) as example
FROM items;

/*---------*
 | example |
 +---------+
 | pp      |
 | an      |
 | ra      |
 *---------*/
WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, -2) as example
FROM items;

/*---------*
 | example |
 +---------+
 | le      |
 | na      |
 | ge      |
 *---------*/
WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, 1, 123) as example
FROM items;

/*---------*
 | example |
 +---------+
 | apple   |
 | banana  |
 | orange  |
 *---------*/
WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, 123) as example
FROM items;

/*---------*
 | example |
 +---------+
 |         |
 |         |
 |         |
 *---------*/
WITH items AS
  (SELECT 'apple' as item
  UNION ALL
  SELECT 'banana' as item
  UNION ALL
  SELECT 'orange' as item)

SELECT
  SUBSTR(item, 123, 5) as example
FROM items;

/*---------*
 | example |
 +---------+
 |         |
 |         |
 |         |
 *---------*/

TO_BASE32

TO_BASE32(bytes_expr)

Description

Converts a sequence of BYTES into a base32-encoded STRING. To convert a base32-encoded STRING into BYTES, use FROM_BASE32.

Return type

STRING

Example

SELECT TO_BASE32(b'abcde\xFF') AS base32_string;

/*------------------*
 | base32_string    |
 +------------------+
 | MFRGGZDF74====== |
 *------------------*/

TO_BASE64

TO_BASE64(bytes_expr)

Description

Converts a sequence of BYTES into a base64-encoded STRING. To convert a base64-encoded STRING into BYTES, use FROM_BASE64.

There are several base64 encodings in common use that vary in exactly which alphabet of 65 ASCII characters are used to encode the 64 digits and padding. See RFC 4648 for details. This function adds padding and uses the alphabet [A-Za-z0-9+/=].

Return type

STRING

Example

SELECT TO_BASE64(b'\377\340') AS base64_string;

/*---------------*
 | base64_string |
 +---------------+
 | /+A=          |
 *---------------*/

To work with an encoding using a different base64 alphabet, you might need to compose TO_BASE64 with the REPLACE function. For instance, the base64url url-safe and filename-safe encoding commonly used in web programming uses -_= as the last characters rather than +/=. To encode a base64url-encoded string, replace + and / with - and _ respectively.

SELECT REPLACE(REPLACE(TO_BASE64(b'\377\340'), '+', '-'), '/', '_') as websafe_base64;

/*----------------*
 | websafe_base64 |
 +----------------+
 | _-A=           |
 *----------------*/

TO_CODE_POINTS

TO_CODE_POINTS(value)

Description

Takes a STRING or BYTES value and returns an array of INT64 values that represent code points or extended ASCII character values.

  • If value is a STRING, each element in the returned array represents a code point. Each code point falls within the range of [0, 0xD7FF] and [0xE000, 0x10FFFF].
  • If value is BYTES, each element in the array is an extended ASCII character value in the range of [0, 255].

To convert from an array of code points to a STRING or BYTES, see CODE_POINTS_TO_STRING or CODE_POINTS_TO_BYTES.

Return type

ARRAY<INT64>

Examples

The following example gets the code points for each element in an array of words.

SELECT word, TO_CODE_POINTS(word) AS code_points
FROM UNNEST(['foo', 'bar', 'baz', 'giraffe', 'llama']) AS word;

/*---------+------------------------------------*
 | word    | code_points                        |
 +---------+------------------------------------+
 | foo     | [102, 111, 111]                    |
 | bar     | [98, 97, 114]                      |
 | baz     | [98, 97, 122]                      |
 | giraffe | [103, 105, 114, 97, 102, 102, 101] |
 | llama   | [108, 108, 97, 109, 97]            |
 *---------+------------------------------------*/

The following example converts integer representations of BYTES to their corresponding ASCII character values.

SELECT word, TO_CODE_POINTS(word) AS bytes_value_as_integer
FROM UNNEST([b'\x00\x01\x10\xff', b'\x66\x6f\x6f']) AS word;

/*------------------+------------------------*
 | word             | bytes_value_as_integer |
 +------------------+------------------------+
 | \x00\x01\x10\xff | [0, 1, 16, 255]        |
 | foo              | [102, 111, 111]        |
 *------------------+------------------------*/

The following example demonstrates the difference between a BYTES result and a STRING result.

SELECT TO_CODE_POINTS(b'Ā') AS b_result, TO_CODE_POINTS('Ā') AS s_result;

/*------------+----------*
 | b_result   | s_result |
 +------------+----------+
 | [196, 128] | [256]    |
 *------------+----------*/

Notice that the character, Ā, is represented as a two-byte Unicode sequence. As a result, the BYTES version of TO_CODE_POINTS returns an array with two elements, while the STRING version returns an array with a single element.

TO_HEX

TO_HEX(bytes)

Description

Converts a sequence of BYTES into a hexadecimal STRING. Converts each byte in the STRING as two hexadecimal characters in the range (0..9, a..f). To convert a hexadecimal-encoded STRING to BYTES, use FROM_HEX.

Return type

STRING

Example

WITH Input AS (
  SELECT b'\x00\x01\x02\x03\xAA\xEE\xEF\xFF' AS byte_str UNION ALL
  SELECT b'foobar'
)
SELECT byte_str, TO_HEX(byte_str) AS hex_str
FROM Input;

/*----------------------------------+------------------*
 | byte_string                      | hex_string       |
 +----------------------------------+------------------+
 | \x00\x01\x02\x03\xaa\xee\xef\xff | 00010203aaeeefff |
 | foobar                           | 666f6f626172     |
 *----------------------------------+------------------*/

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 if value_to_trim is a STRING value.
  • BYTES if value_to_trim is a BYTES 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.

WITH items AS
  (SELECT '   apple   ' as item
  UNION ALL
  SELECT '   banana   ' as item
  UNION ALL
  SELECT '   orange   ' as item)

SELECT
  CONCAT('#', TRIM(item), '#') as example
FROM items;

/*----------*
 | example  |
 +----------+
 | #apple#  |
 | #banana# |
 | #orange# |
 *----------*/

In the following example, all leading and trailing * characters are removed from item.

WITH items AS
  (SELECT '***apple***' as item
  UNION ALL
  SELECT '***banana***' as item
  UNION ALL
  SELECT '***orange***' as item)

SELECT
  TRIM(item, '*') as example
FROM items;

/*---------*
 | example |
 +---------+
 | apple   |
 | banana  |
 | orange  |
 *---------*/

In the following example, all leading and trailing x, y, and z characters are removed from item.

WITH items AS
  (SELECT 'xxxapplexxx' as item
  UNION ALL
  SELECT 'yyybananayyy' as item
  UNION ALL
  SELECT 'zzzorangezzz' as item
  UNION ALL
  SELECT 'xyzpearxyz' as item)

SELECT
  TRIM(item, 'xyz') as example
FROM items;

/*---------*
 | example |
 +---------+
 | apple   |
 | banana  |
 | orange  |
 | pear    |
 *---------*/

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.

WITH items AS
(
  SELECT b'apple' as item UNION ALL
  SELECT b'banana' as item UNION ALL
  SELECT b'\xab\xcd\xef\xaa\xbb' as item
)
SELECT item, TRIM(item, b'na\xab') AS examples
FROM items;

-- Note that the result of TRIM is of type BYTES, displayed as a base64-encoded string.
/*----------------------+------------------*
 | item                 | example          |
 +----------------------+------------------+
 | YXBwbGU=             | cHBsZQ==         |
 | YmFuYW5h             | Yg==             |
 | q83vqrs=             | ze+quw==         |
 *----------------------+------------------*/

UPPER

UPPER(value)

Description

For STRING arguments, returns the original string with all alphabetic characters in uppercase. Mapping between uppercase and lowercase is done according to the Unicode Character Database without taking into account language-specific mappings.

For BYTES arguments, the argument is treated as ASCII text, with all bytes greater than 127 left intact.

Return type

STRING or BYTES

Examples

WITH items AS
  (SELECT
    'foo' as item
  UNION ALL
  SELECT
    'bar' as item
  UNION ALL
  SELECT
    'baz' as item)

SELECT
  UPPER(item) AS example
FROM items;

/*---------*
 | example |
 +---------+
 | FOO     |
 | BAR     |
 | BAZ     |
 *---------*/