Data types

This page provides an overview of all GoogleSQL for BigQuery data types, including information about their value domains. For information on data type literals and constructors, see Lexical Structure and Syntax.

Data type properties

When storing and querying data, it is helpful to keep the following data type properties in mind:

Nullable data types

For nullable data types, NULL is a valid value. Currently, all existing data types are nullable. Conditions apply for arrays.

Orderable data types

Expressions of orderable data types can be used in an ORDER BY clause. Applies to all data types except for:

  • ARRAY
  • STRUCT
  • GEOGRAPHY
  • JSON

Ordering NULLs

In the context of the ORDER BY clause, NULLs are the minimum possible value; that is, NULLs appear first in ASC sorts and last in DESC sorts.

NULL values can be specified as the first or last values for a column irrespective of ASC or DESC by using the NULLS FIRST or NULLS LAST modifiers respectively.

To learn more about using ASC, DESC, NULLS FIRST and NULLS LAST, see the ORDER BY clause.

Ordering floating points

Floating point values are sorted in this order, from least to greatest:

  1. NULL
  2. NaN — All NaN values are considered equal when sorting.
  3. -inf
  4. Negative numbers
  5. 0 or -0 — All zero values are considered equal when sorting.
  6. Positive numbers
  7. +inf

Groupable data types

Groupable data types can generally appear in an expression following GROUP BY, DISTINCT, and PARTITION BY. All data types are supported except for:

  • GEOGRAPHY
  • JSON
  • ARRAY
  • STRUCT

Grouping with floating point types

Groupable floating point types can appear in an expression following GROUP BY and DISTINCT. PARTITION BY expressions cannot include floating point types.

Special floating point values are grouped in the following way, including both grouping done by a GROUP BY clause and grouping done by the DISTINCT keyword:

  • NULL
  • NaN — All NaN values are considered equal when grouping.
  • -inf
  • 0 or -0 — All zero values are considered equal when grouping.
  • +inf

Comparable data types

Values of the same comparable data type can be compared to each other. All data types are supported except for:

  • GEOGRAPHY
  • JSON

Notes:

  • Equality comparisons for structs are supported field by field, in field order. Field names are ignored. Less than and greater than comparisons are not supported.
  • To compare geography values, use ST_Equals.
  • When comparing ranges, the lower bounds are compared. If the lower bounds are equal, the upper bounds are compared, instead.
  • When comparing ranges, NULL values are handled as follows:
    • NULL lower bounds are sorted before non-NULL lower bounds.
    • NULL upper bounds are sorted after non-NULL upper bounds.
    • If two bounds that are being compared are NULL, the comparison is TRUE.
    • An UNBOUNDED bound is treated as a NULL bound.
  • All types that support comparisons can be used in a JOIN condition. See JOIN Types for an explanation of join conditions.

Collatable data types

Collatable data types support collation, which determines how to sort and compare strings. These data types support collation:

  • String
  • String fields in a struct
  • String elements in an array

The maximum size of a column value is 10MiB, which applies to scalar and array types.

Data type sizes

Use the following table to see the size in logical bytes for each supported data type.

Data type Size
ARRAY The sum of the size of its elements. For example, an array defined as (ARRAY<INT64>) that contains 4 entries is calculated as 32 logical bytes (4 entries x 8 logical bytes).
BIGNUMERIC 32 logical bytes
BOOL 1 logical byte
BYTES 2 logical bytes + the number of logical bytes in the value
DATE 8 logical bytes
DATETIME 8 logical bytes
FLOAT64 8 logical bytes
GEOGRAPHY 16 logical bytes + 24 logical bytes * the number of vertices in the geography type. To verify the number of vertices, use the ST_NumPoints function.
INT64 8 logical bytes
INTERVAL 16 logical bytes
JSON The number of logical bytes in UTF-8 encoding of the JSON-formatted string equivalent after canonicalization.
NUMERIC 16 logical bytes
RANGE 16 logical bytes
STRING 2 logical bytes + the UTF-8 encoded string size
STRUCT 0 logical bytes + the size of the contained fields
TIME 8 logical bytes
TIMESTAMP 8 logical bytes

A NULL value for any data type is calculated as 0 logical bytes.

A repeated column is stored as an array, and the size is calculated based on the column data type and the number of values. For example, an integer column (INT64) that is repeated (ARRAY<INT64>) and contains 4 entries is calculated as 32 logical bytes (4 entries x 8 logical bytes). The total size of all values in a table row can't exceed the maximum row size.

Parameterized data types

Syntax:

DATA_TYPE(param[, ...])

You can use parameters to specify constraints for the following data types:

  • STRING
  • BYTES
  • NUMERIC
  • BIGNUMERIC

A data type that is declared with parameters is called a parameterized data type. You can only use parameterized data types with columns and script variables. A column with a parameterized data type is a parameterized column and a script variable with a parameterized data type is a parameterized script variable. Parameterized type constraints are enforced when writing a value to a parameterized column or when assigning a value to a parameterized script variable.

A data type's parameters are not propagated in an expression, only the data type is.

Examples

-- Declare a variable with type parameters.
DECLARE x STRING(10);

-- This is a valid assignment to x.
SET x = "hello";

-- This assignment to x violates the type parameter constraint and results in an OUT_OF_RANGE error.
SET x = "this string is too long"
-- Declare variables with type parameters.
DECLARE x NUMERIC(10) DEFAULT 12345;
DECLARE y NUMERIC(5, 2) DEFAULT 123.45;

-- The variable x is treated as a NUMERIC value when read, so the result of this query
-- is a NUMERIC without type parameters.
SELECT x;

-- Type parameters are not propagated within expressions, so variables x and y are treated
-- as NUMERIC values when read and the result of this query is a NUMERIC without type parameters.
SELECT x + y;

Array type

Name Description
ARRAY Ordered list of zero or more elements of any non-array type.

An array is an ordered list of zero or more elements of non-array values. Elements in an array must share the same type.

Arrays of arrays are not allowed. Queries that would produce an array of arrays will return an error. Instead, a struct must be inserted between the arrays using the SELECT AS STRUCT construct.

To learn more about the literal representation of an array type, see Array literals.

To learn more about using arrays in GoogleSQL, see Work with arrays.

NULLs and the array type

Currently, GoogleSQL for BigQuery has the following rules with respect to NULLs and arrays:

  • An array can be NULL.

    For example:

    SELECT CAST(NULL AS ARRAY<INT64>) IS NULL AS array_is_null;
    
    /*---------------*
     | array_is_null |
     +---------------+
     | TRUE          |
     *---------------*/
    
  • GoogleSQL for BigQuery translates a NULL array into an empty array in the query result, although inside the query, NULL and empty arrays are two distinct values.

    For example:

    WITH Items AS (
      SELECT [] AS numbers, "Empty array in query" AS description UNION ALL
      SELECT CAST(NULL AS ARRAY<INT64>), "NULL array in query")
    SELECT numbers, description, numbers IS NULL AS numbers_null
    FROM Items;
    
    /*---------+----------------------+--------------*
     | numbers | description          | numbers_null |
     +---------+----------------------+--------------+
     | []      | Empty array in query | false        |
     | []      | NULL array in query  | true         |
     *---------+----------------------+--------------*/
    

    When you write a NULL array to a table, it is converted to an empty array. If you write Items to a table from the previous query, then each array is written as an empty array:

    SELECT numbers, description, numbers IS NULL AS numbers_null
    FROM Items;
    
    /*---------+----------------------+--------------*
     | numbers | description          | numbers_null |
     +---------+----------------------+--------------+
     | []      | Empty array in query | false        |
     | []      | NULL array in query  | false        |
     *---------+----------------------+--------------*/
    
  • GoogleSQL for BigQuery raises an error if the query result has an array which contains NULL elements, although such an array can be used inside the query.

    For example, this works:

    SELECT FORMAT("%T", [1, NULL, 3]) as numbers;
    
    /*--------------*
     | numbers      |
     +--------------+
     | [1, NULL, 3] |
     *--------------*/
    

    But this raises an error:

    -- error
    SELECT [1, NULL, 3] as numbers;
    

Declaring an array type

ARRAY<T>

Array types are declared using the angle brackets (< and >). The type of the elements of an array can be arbitrarily complex with the exception that an array cannot directly contain another array.

Examples

Type Declaration Meaning
ARRAY<INT64> Simple array of 64-bit integers.
ARRAY<BYTES(5)> Simple array of parameterized bytes.
ARRAY<STRUCT<INT64, INT64>> An array of structs, each of which contains two 64-bit integers.
ARRAY<ARRAY<INT64>>
(not supported)
This is an invalid type declaration which is included here just in case you came looking for how to create a multi-level array. Arrays cannot contain arrays directly. Instead see the next example.
ARRAY<STRUCT<ARRAY<INT64>>> An array of arrays of 64-bit integers. Notice that there is a struct between the two arrays because arrays cannot hold other arrays directly.

Constructing an array

You can construct an array using array literals or array functions.

Using array literals

You can build an array literal in GoogleSQL using brackets ([ and ]). Each element in an array is separated by a comma.

SELECT [1, 2, 3] AS numbers;

SELECT ["apple", "pear", "orange"] AS fruit;

SELECT [true, false, true] AS booleans;

You can also create arrays from any expressions that have compatible types. For example:

SELECT [a, b, c]
FROM
  (SELECT 5 AS a,
          37 AS b,
          406 AS c);

SELECT [a, b, c]
FROM
  (SELECT CAST(5 AS INT64) AS a,
          CAST(37 AS FLOAT64) AS b,
          406 AS c);

Notice that the second example contains three expressions: one that returns an INT64, one that returns a FLOAT64, and one that declares a literal. This expression works because all three expressions share FLOAT64 as a supertype.

To declare a specific data type for an array, use angle brackets (< and >). For example:

SELECT ARRAY<FLOAT64>[1, 2, 3] AS floats;

Arrays of most data types, such as INT64 or STRING, don't require that you declare them first.

SELECT [1, 2, 3] AS numbers;

You can write an empty array of a specific type using ARRAY<type>[]. You can also write an untyped empty array using [], in which case GoogleSQL attempts to infer the array type from the surrounding context. If GoogleSQL cannot infer a type, the default type ARRAY<INT64> is used.

Using generated values

You can also construct an ARRAY with generated values.

Generating arrays of integers

GENERATE_ARRAY generates an array of values from a starting and ending value and a step value. For example, the following query generates an array that contains all of the odd integers from 11 to 33, inclusive:

SELECT GENERATE_ARRAY(11, 33, 2) AS odds;

/*--------------------------------------------------*
 | odds                                             |
 +--------------------------------------------------+
 | [11, 13, 15, 17, 19, 21, 23, 25, 27, 29, 31, 33] |
 *--------------------------------------------------*/

You can also generate an array of values in descending order by giving a negative step value:

SELECT GENERATE_ARRAY(21, 14, -1) AS countdown;

/*----------------------------------*
 | countdown                        |
 +----------------------------------+
 | [21, 20, 19, 18, 17, 16, 15, 14] |
 *----------------------------------*/
Generating arrays of dates

GENERATE_DATE_ARRAY generates an array of DATEs from a starting and ending DATE and a step INTERVAL.

You can generate a set of DATE values using GENERATE_DATE_ARRAY. For example, this query returns the current DATE and the following DATEs at 1 WEEK intervals up to and including a later DATE:

SELECT
  GENERATE_DATE_ARRAY('2017-11-21', '2017-12-31', INTERVAL 1 WEEK)
    AS date_array;

/*--------------------------------------------------------------------------*
 | date_array                                                               |
 +--------------------------------------------------------------------------+
 | [2017-11-21, 2017-11-28, 2017-12-05, 2017-12-12, 2017-12-19, 2017-12-26] |
 *--------------------------------------------------------------------------*/

Boolean type

Name Description
BOOL Boolean values are represented by the keywords TRUE and FALSE (case-insensitive).

Boolean values are sorted in this order, from least to greatest:

  1. NULL
  2. FALSE
  3. TRUE

Bytes type

Name Description
BYTES Variable-length binary data.

String and bytes are separate types that cannot be used interchangeably. Most functions on strings are also defined on bytes. The bytes version operates on raw bytes rather than Unicode characters. Casts between string and bytes enforce that the bytes are encoded using UTF-8.

To learn more about the literal representation of a bytes type, see Bytes literals.

Parameterized bytes type

Parameterized Type Description
BYTES(L) Sequence of bytes with a maximum of L bytes allowed in the binary string, where L is a positive INT64 value. If a sequence of bytes has more than L bytes, throws an OUT_OF_RANGE error.

See Parameterized Data Types for more information on parameterized types and where they can be used.

Date type

Name Range
DATE 0001-01-01 to 9999-12-31.

The date type represents a Gregorian calendar date, independent of time zone. A date value does not represent a specific 24-hour time period. Rather, a given date value represents a different 24-hour period when interpreted in different time zones, and may represent a shorter or longer day during daylight saving time (DST) transitions. To represent an absolute point in time, use a timestamp.

Canonical format
YYYY-[M]M-[D]D
  • YYYY: Four-digit year.
  • [M]M: One or two digit month.
  • [D]D: One or two digit day.

To learn more about the literal representation of a date type, see Date literals.

Datetime type

Name Range
DATETIME 0001-01-01 00:00:00 to 9999-12-31 23:59:59.999999

A datetime value represents a Gregorian date and a time, as they might be displayed on a watch, independent of time zone. It includes the year, month, day, hour, minute, second, and subsecond. To represent an absolute point in time, use a timestamp.

Canonical format
civil_date_part[time_part]

civil_date_part:
    YYYY-[M]M-[D]D

time_part:
    { |T|t}[H]H:[M]M:[S]S[.F]
  • YYYY: Four-digit year.
  • [M]M: One or two digit month.
  • [D]D: One or two digit day.
  • { |T|t}: A space or a T or t separator. The T and t separators are flags for time.
  • [H]H: One or two digit hour (valid values from 00 to 23).
  • [M]M: One or two digit minutes (valid values from 00 to 59).
  • [S]S: One or two digit seconds (valid values from 00 to 60).
  • [.F]: Up to six fractional digits (microsecond precision).

To learn more about the literal representation of a datetime type, see Datetime literals.

Geography type

Name Description
GEOGRAPHY A collection of points, linestrings, and polygons, which is represented as a point set, or a subset of the surface of the Earth.

The geography type is based on the OGC Simple Features specification (SFS), and can contain the following objects:

Geography object Description
Point

A single location in coordinate space known as a point. A point has an x-coordinate value and a y-coordinate value, where the x-coordinate is longitude and the y-coordinate is latitude of the point on the WGS84 reference ellipsoid.

Syntax:

POINT(x_coordinate y_coordinate)
Examples:
POINT(32 210)
POINT EMPTY

LineString

Represents a linestring, which is a one-dimensional geometric object, with a sequence of points and geodesic edges between them.

Syntax:

LINESTRING(point[, ...])
Examples:
LINESTRING(1 1, 2 1, 3.1 2.88, 3 -3)
LINESTRING EMPTY

Polygon

A polygon, which is represented as a planar surface defined by 1 exterior boundary and 0 or more interior boundaries. Each interior boundary defines a hole in the polygon. The boundary loops of polygons are oriented so that if you traverse the boundary vertices in order, the interior of the polygon is on the left.

Syntax:

POLYGON(interior_ring[, ...])

interior_ring:
  (point[, ...])
Examples:
POLYGON((0 0, 2 2, 2 0, 0 0), (2 2, 3 4, 2 4, 2 2))
POLYGON EMPTY

MultiPoint

A collection of points.

Syntax:

MULTIPOINT(point[, ...])
Examples:
MULTIPOINT(0 32, 123 9, 48 67)
MULTIPOINT EMPTY

MultiLineString

Represents a multilinestring, which is a collection of linestrings.

Syntax:

MULTILINESTRING((linestring)[, ...])
Examples:
MULTILINESTRING((2 2, 3 4), (5 6, 7 7))
MULTILINESTRING EMPTY

MultiPolygon

Represents a multipolygon, which is a collection of polygons.

Syntax:

MULTIPOLYGON((polygon)[, ...])
Examples:
MULTIPOLYGON(((0 -1, 1 0, 1 1, 0 -1)), ((0 0, 2 2, 3 0, 0 0), (2 2, 3 4, 2 4, 1 9)))
MULTIPOLYGON EMPTY

GeometryCollection

Represents a geometry collection with elements of different dimensions or an empty geography.

Syntax:

GEOMETRYCOLLECTION(geography_object[, ...])
Examples:
GEOMETRYCOLLECTION(MULTIPOINT(-1 2, 0 12), LINESTRING(-2 4, 0 6))
GEOMETRYCOLLECTION EMPTY

The points, linestrings and polygons of a geography value form a simple arrangement on the WGS84 reference ellipsoid. A simple arrangement is one where no point on the WGS84 surface is contained by multiple elements of the collection. If self intersections exist, they are automatically removed.

The geography that contains no points, linestrings or polygons is called an empty geography. An empty geography is not associated with a particular geometry shape. For example, the following query produces the same results:

SELECT
  ST_GEOGFROMTEXT('POINT EMPTY') AS a,
  ST_GEOGFROMTEXT('GEOMETRYCOLLECTION EMPTY') AS b

/*--------------------------+--------------------------*
 | a                        | b                        |
 +--------------------------+--------------------------+
 | GEOMETRYCOLLECTION EMPTY | GEOMETRYCOLLECTION EMPTY |
 *--------------------------+--------------------------*/

The structure of compound geometry objects is not preserved if a simpler type can be produced. For example, in column b, GEOMETRYCOLLECTION with (POINT(1 1) and POINT(2 2) is converted into the simplest possible geometry, MULTIPOINT(1 1, 2 2).

SELECT
  ST_GEOGFROMTEXT('MULTIPOINT(1 1, 2 2)') AS a,
  ST_GEOGFROMTEXT('GEOMETRYCOLLECTION(POINT(1 1), POINT(2 2))') AS b

/*----------------------+----------------------*
 | a                    | b                    |
 +----------------------+----------------------+
 | MULTIPOINT(1 1, 2 2) | MULTIPOINT(1 1, 2 2) |
 *----------------------+----------------------*/

A geography is the result of, or an argument to, a Geography Function.

Interval type

Name Range
INTERVAL -10000-0 -3660000 -87840000:0:0 to 10000-0 3660000 87840000:0:0

An INTERVAL object represents duration or amount of time, without referring to any specific point in time.

Canonical format
[sign]Y-M [sign]D [sign]H:M:S[.F]
  • sign: + or -
  • Y: Year
  • M: Month
  • D: Day
  • H: Hour
  • M: Minute
  • S: Second
  • [.F]: Up to six fractional digits (microsecond precision)

To learn more about the literal representation of an interval type, see Interval literals.

Constructing an interval

You can construct an interval with an interval literal that supports a single datetime part or a datetime part range.

Construct an interval with a single datetime part

INTERVAL int64_expression datetime_part

You can construct an INTERVAL object with an INT64 expression and one interval-supported datetime part. For example:

-- 1 year, 0 months, 0 days, 0 hours, 0 minutes, and 0 seconds (1-0 0 0:0:0)
INTERVAL 1 YEAR
INTERVAL 4 QUARTER
INTERVAL 12 MONTH

-- 0 years, 3 months, 0 days, 0 hours, 0 minutes, and 0 seconds (0-3 0 0:0:0)
INTERVAL 1 QUARTER
INTERVAL 3 MONTH

-- 0 years, 0 months, 42 days, 0 hours, 0 minutes, and 0 seconds (0-0 42 0:0:0)
INTERVAL 6 WEEK
INTERVAL 42 DAY

-- 0 years, 0 months, 0 days, 25 hours, 0 minutes, and 0 seconds (0-0 0 25:0:0)
INTERVAL 25 HOUR
INTERVAL 1500 MINUTE
INTERVAL 90000 SECOND

-- 0 years, 0 months, 0 days, 1 hours, 30 minutes, and 0 seconds (0-0 0 1:30:0)
INTERVAL 90 MINUTE

-- 0 years, 0 months, 0 days, 0 hours, 1 minutes, and 30 seconds (0-0 0 0:1:30)
INTERVAL 90 SECOND

-- 0 years, 0 months, -5 days, 0 hours, 0 minutes, and 0 seconds (0-0 -5 0:0:0)
INTERVAL -5 DAY

For additional examples, see Interval literals.

Construct an interval with a datetime part range

INTERVAL datetime_parts_string starting_datetime_part TO ending_datetime_part

You can construct an INTERVAL object with a STRING that contains the datetime parts that you want to include, a starting datetime part, and an ending datetime part. The resulting INTERVAL object only includes datetime parts in the specified range.

You can use one of the following formats with the interval-supported datetime parts:

Datetime part string Datetime parts Example
Y-M YEAR TO MONTH INTERVAL '2-11' YEAR TO MONTH
Y-M D YEAR TO DAY INTERVAL '2-11 28' YEAR TO DAY
Y-M D H YEAR TO HOUR INTERVAL '2-11 28 16' YEAR TO HOUR
Y-M D H:M YEAR TO MINUTE INTERVAL '2-11 28 16:15' YEAR TO MINUTE
Y-M D H:M:S YEAR TO SECOND INTERVAL '2-11 28 16:15:14' YEAR TO SECOND
M D MONTH TO DAY INTERVAL '11 28' MONTH TO DAY
M D H MONTH TO HOUR INTERVAL '11 28 16' MONTH TO HOUR
M D H:M MONTH TO MINUTE INTERVAL '11 28 16:15' MONTH TO MINUTE
M D H:M:S MONTH TO SECOND INTERVAL '11 28 16:15:14' MONTH TO SECOND
D H DAY TO HOUR INTERVAL '28 16' DAY TO HOUR
D H:M DAY TO MINUTE INTERVAL '28 16:15' DAY TO MINUTE
D H:M:S DAY TO SECOND INTERVAL '28 16:15:14' DAY TO SECOND
H:M HOUR TO MINUTE INTERVAL '16:15' HOUR TO MINUTE
H:M:S HOUR TO SECOND INTERVAL '16:15:14' HOUR TO SECOND
M:S MINUTE TO SECOND INTERVAL '15:14' MINUTE TO SECOND

For example:

-- 0 years, 8 months, 20 days, 17 hours, 0 minutes, and 0 seconds (0-8 20 17:0:0)
INTERVAL '8 20 17' MONTH TO HOUR

-- 0 years, 8 months, -20 days, 17 hours, 0 minutes, and 0 seconds (0-8 -20 17:0:0)
INTERVAL '8 -20 17' MONTH TO HOUR

For additional examples, see Interval literals.

Interval-supported date and time parts

You can use the following date parts to construct an interval:

  • YEAR: Number of years, Y.
  • QUARTER: Number of quarters; each quarter is converted to 3 months, M.
  • MONTH: Number of months, M. Each 12 months is converted to 1 year.
  • WEEK: Number of weeks; Each week is converted to 7 days, D.
  • DAY: Number of days, D.

You can use the following time parts to construct an interval:

  • HOUR: Number of hours, H.
  • MINUTE: Number of minutes, M. Each 60 minutes is converted to 1 hour.
  • SECOND: Number of seconds, S. Each 60 seconds is converted to 1 minute. Can include up to six fractional digits (microsecond precision).
  • MILLISECOND: Number of milliseconds.
  • MICROSECOND: Number of microseconds.

JSON type

Name Description
JSON Represents JSON, a lightweight data-interchange format.

Expect these canonicalization behaviors when creating a value of JSON type:

  • Booleans, strings, and nulls are preserved exactly.
  • Whitespace characters are not preserved.
  • A JSON value can store integers in the range of -9,223,372,036,854,775,808 (minimal signed 64-bit integer) to 18,446,744,073,709,551,615 (maximal unsigned 64-bit integer) and floating point numbers within a domain of FLOAT64.
  • The order of elements in an array is preserved exactly.
  • The order of the members of an object is not guaranteed or preserved.
  • If an object has duplicate keys, the first key that is found is preserved.
  • Up to 500 levels can be nested.
  • The format of the original string representation of a JSON number may not be preserved.

To learn more about the literal representation of a JSON type, see JSON literals.

Numeric types

Numeric types include the following types:

  • INT64 with alias INT, SMALLINT, INTEGER, BIGINT, TINYINT, BYTEINT

  • NUMERIC with alias DECIMAL

  • BIGNUMERIC with alias BIGDECIMAL

  • FLOAT64

Integer type

Integers are numeric values that do not have fractional components.

Name Range
INT64
INT
SMALLINT
INTEGER
BIGINT
TINYINT
BYTEINT
-9,223,372,036,854,775,808 to 9,223,372,036,854,775,807

INT, SMALLINT, INTEGER, BIGINT, TINYINT, and BYTEINT are aliases for INT64.

To learn more about the literal representation of an integer type, see Integer literals.

Decimal types

Decimal type values are numeric values with fixed decimal precision and scale. Precision is the number of digits that the number contains. Scale is how many of these digits appear after the decimal point.

This type can represent decimal fractions exactly, and is suitable for financial calculations.

Name Precision, Scale, and Range
NUMERIC
DECIMAL
Precision: 38
Scale: 9
Minimum value greater than 0 that can be handled: 1e-9
Min: -9.9999999999999999999999999999999999999E+28
Max: 9.9999999999999999999999999999999999999E+28
BIGNUMERIC
BIGDECIMAL
Precision: 76.76 (the 77th digit is partial)
Scale: 38
Minimum value greater than 0 that can be handled: 1e-38
Min: -5.7896044618658097711785492504343953926634992332820282019728792003956564819968E+38
Max: 5.7896044618658097711785492504343953926634992332820282019728792003956564819967E+38

DECIMAL is an alias for NUMERIC.

BIGDECIMAL is an alias for BIGNUMERIC.

To learn more about the literal representation of a NUMERIC type, see NUMERIC literals.

To learn more about the literal representation of a BIGNUMERIC type, see BIGNUMERIC literals.

To learn more about how BigQuery rounds values stored as a DECIMAL type, see rounding mode.

Parameterized decimal type

Parameterized Type Description
NUMERIC(P[,S])
DECIMAL(P[,S])
A NUMERIC or DECIMAL type with a maximum precision of P and maximum scale of S, where P and S are INT64 types. S is interpreted to be 0 if unspecified.

Maximum scale range: 0 ≤ S ≤ 9
Maximum precision range: max(1, S) ≤ PS + 29
BIGNUMERIC(P[, S])
BIGDECIMAL(P[, S])
A BIGNUMERIC or BIGDECIMAL type with a maximum precision of P and maximum scale of S, where P and S are INT64 types. S is interpreted to be 0 if unspecified.

Maximum scale range: 0 ≤ S ≤ 38
Maximum precision range: max(1, S) ≤ PS + 38

If a value has more than S decimal digits, the value is rounded to S decimal digits. For example, inserting the value 1.125 into a NUMERIC(5, 2) column rounds 1.125 half-up to 1.13.

If a value has more than P digits, throws an OUT_OF_RANGE error. For example, inserting 1111 into a NUMERIC(5, 2) column returns an OUT_OF_RANGE error since 1111 is larger than 999.99, the maximum allowed value in a NUMERIC(5, 2) column.

See Parameterized Data Types for more information on parameterized types and where they can be used.

Floating point type

Floating point values are approximate numeric values with fractional components.

Name Description
FLOAT64 Double precision (approximate) numeric values.

To learn more about the literal representation of a floating point type, see Floating point literals.

Floating point semantics

When working with floating point numbers, there are special non-numeric values that need to be considered: NaN and +/-inf

Arithmetic operators provide standard IEEE-754 behavior for all finite input values that produce finite output and for all operations for which at least one input is non-finite.

Function calls and operators return an overflow error if the input is finite but the output would be non-finite. If the input contains non-finite values, the output can be non-finite. In general functions do not introduce NaNs or +/-inf. However, specific functions like IEEE_DIVIDE can return non-finite values on finite input. All such cases are noted explicitly in Mathematical functions.

Floating point values are approximations.

  • The binary format used to represent floating point values can only represent a subset of the numbers between the most positive number and most negative number in the value range. This enables efficient handling of a much larger range than would be possible otherwise. Numbers that are not exactly representable are approximated by utilizing a close value instead. For example, 0.1 cannot be represented as an integer scaled by a power of 2. When this value is displayed as a string, it is rounded to a limited number of digits, and the value approximating 0.1 might appear as "0.1", hiding the fact that the value is not precise. In other situations, the approximation can be visible.
  • Summation of floating point values might produce surprising results because of limited precision. For example, (1e30 + 1) - 1e30 = 0, while (1e30 - 1e30) + 1 = 1.0. This is because the floating point value does not have enough precision to represent (1e30 + 1), and the result is rounded to 1e30. This example also shows that the result of the SUM aggregate function of floating points values depends on the order in which the values are accumulated. In general, this order is not deterministic and therefore the result is not deterministic. Thus, the resulting SUM of floating point values might not be deterministic and two executions of the same query on the same tables might produce different results.
  • If the above points are concerning, use a decimal type instead.
Mathematical function examples
Left Term Operator Right Term Returns
Any value + NaN NaN
1.0 + +inf +inf
1.0 + -inf -inf
-inf + +inf NaN
Maximum FLOAT64 value + Maximum FLOAT64 value Overflow error
Minimum FLOAT64 value / 2.0 0.0
1.0 / 0.0 "Divide by zero" error

Comparison operators provide standard IEEE-754 behavior for floating point input.

Comparison operator examples
Left Term Operator Right Term Returns
NaN = Any value FALSE
NaN < Any value FALSE
Any value < NaN FALSE
-0.0 = 0.0 TRUE
-0.0 < 0.0 FALSE

For more information on how these values are ordered and grouped so they can be compared, see Ordering floating point values.

Range type

Name Range
RANGE Contiguous range between two dates, datetimes, or timestamps. The lower and upper bound for the range are optional. The lower bound is inclusive and the upper bound is exclusive.

Declare a range type

A range type can be declared as follows:

Type Declaration Meaning
RANGE<DATE> Contiguous range between two dates.
RANGE<DATETIME> Contiguous range between two datetimes.
RANGE<TIMESTAMP> Contiguous range between two timestamps.

Construct a range

You can construct a range with the RANGE constructor or a range literal.

Construct a range with a constructor

You can construct a range with the RANGE constructor. To learn more, see RANGE.

Construct a range with a literal

You can construct a range with a range literal. The canonical format for a range literal has the following parts:

RANGE<T> '[lower_bound, upper_bound)'
  • T: The type of range. This can be DATE, DATETIME, or TIMESTAMP.
  • lower_bound: The range starts from this value. This can be a date, datetime, or timestamp literal. If this value is UNBOUNDED or NULL, the range does not include a lower bound.
  • upper_bound: The range ends before this value. This can be a date, datetime, or timestamp literal. If this value is UNBOUNDED or NULL, the range does not include an upper bound.

T, lower_bound, and upper_bound must be of the same data type.

To learn more about the literal representation of a range type, see Range literals.

Additional details

The range type does not support arithmetic operators.

String type

Name Description
STRING Variable-length character (Unicode) data.

Input string values must be UTF-8 encoded and output string values will be UTF-8 encoded. Alternate encodings like CESU-8 and Modified UTF-8 are not treated as valid UTF-8.

All functions and operators that act on string values operate on Unicode characters rather than bytes. For example, functions like SUBSTR and LENGTH applied to string input count the number of characters, not bytes.

Each Unicode character has a numeric value called a code point assigned to it. Lower code points are assigned to lower characters. When characters are compared, the code points determine which characters are less than or greater than other characters.

Most functions on strings are also defined on bytes. The bytes version operates on raw bytes rather than Unicode characters. Strings and bytes are separate types that cannot be used interchangeably. There is no implicit casting in either direction. Explicit casting between string and bytes does UTF-8 encoding and decoding. Casting bytes to string returns an error if the bytes are not valid UTF-8.

To learn more about the literal representation of a string type, see String literals.

Parameterized string type

Parameterized Type Description
STRING(L) String with a maximum of L Unicode characters allowed in the string, where L is a positive INT64 value. If a string with more than L Unicode characters is assigned, throws an OUT_OF_RANGE error.

See Parameterized Data Types for more information on parameterized types and where they can be used.

Struct type

Name Description
STRUCT Container of ordered fields each with a type (required) and field name (optional).

To learn more about the literal representation of a struct type, see Struct literals.

Declaring a struct type

STRUCT<T>

Struct types are declared using the angle brackets (< and >). The type of the elements of a struct can be arbitrarily complex.

Examples

Type Declaration Meaning
STRUCT<INT64> Simple struct with a single unnamed 64-bit integer field.
STRUCT<x STRING(10)> Simple struct with a single parameterized string field named x.
STRUCT<x STRUCT<y INT64, z INT64>> A struct with a nested struct named x inside it. The struct x has two fields, y and z, both of which are 64-bit integers.
STRUCT<inner_array ARRAY<INT64>> A struct containing an array named inner_array that holds 64-bit integer elements.

Constructing a struct

Tuple syntax

(expr1, expr2 [, ... ])

The output type is an anonymous struct type with anonymous fields with types matching the types of the input expressions. There must be at least two expressions specified. Otherwise this syntax is indistinguishable from an expression wrapped with parentheses.

Examples

Syntax Output Type Notes
(x, x+y) STRUCT<?,?> If column names are used (unquoted strings), the struct field data type is derived from the column data type. x and y are columns, so the data types of the struct fields are derived from the column types and the output type of the addition operator.

This syntax can also be used with struct comparison for comparison expressions using multi-part keys, e.g., in a WHERE clause:

WHERE (Key1,Key2) IN ( (12,34), (56,78) )

Typeless struct syntax

STRUCT( expr1 [AS field_name] [, ... ])

Duplicate field names are allowed. Fields without names are considered anonymous fields and cannot be referenced by name. struct values can be NULL, or can have NULL field values.

Examples

Syntax Output Type
STRUCT(1,2,3) STRUCT<int64,int64,int64>
STRUCT() STRUCT<>
STRUCT('abc') STRUCT<string>
STRUCT(1, t.str_col) STRUCT<int64, str_col string>
STRUCT(1 AS a, 'abc' AS b) STRUCT<a int64, b string>
STRUCT(str_col AS abc) STRUCT<abc string>

Typed struct syntax

STRUCT<[field_name] field_type, ...>( expr1 [, ... ])

Typed syntax allows constructing structs with an explicit struct data type. The output type is exactly the field_type provided. The input expression is coerced to field_type if the two types are not the same, and an error is produced if the types are not compatible. AS alias is not allowed on the input expressions. The number of expressions must match the number of fields in the type, and the expression types must be coercible or literal-coercible to the field types.

Examples

Syntax Output Type
STRUCT<int64>(5) STRUCT<int64>
STRUCT<date>("2011-05-05") STRUCT<date>
STRUCT<x int64, y string>(1, t.str_col) STRUCT<x int64, y string>
STRUCT<int64>(int_col) STRUCT<int64>
STRUCT<x int64>(5 AS x) Error - Typed syntax does not allow AS

Limited comparisons for structs

Structs can be directly compared using equality operators:

  • Equal (=)
  • Not Equal (!= or <>)
  • [NOT] IN

Notice, though, that these direct equality comparisons compare the fields of the struct pairwise in ordinal order ignoring any field names. If instead you want to compare identically named fields of a struct, you can compare the individual fields directly.

Time type

Name Range
TIME 00:00:00 to 23:59:59.999999

A time value represents a time of day, as might be displayed on a clock, independent of a specific date and time zone. To represent an absolute point in time, use a timestamp.

Canonical format
[H]H:[M]M:[S]S[.F]
  • [H]H: One or two digit hour (valid values from 00 to 23).
  • [M]M: One or two digit minutes (valid values from 00 to 59).
  • [S]S: One or two digit seconds (valid values from 00 to 60).
  • [.F]: Up to six fractional digits (microsecond precision).

To learn more about the literal representation of a time type, see Time literals.

Timestamp type

Name Range
TIMESTAMP 0001-01-01 00:00:00 to 9999-12-31 23:59:59.999999 UTC

A timestamp value represents an absolute point in time, independent of any time zone or convention such as daylight saving time (DST), with microsecond precision.

A timestamp is typically represented internally as the number of elapsed microseconds since a fixed initial point in time.

Note that a timestamp itself does not have a time zone; it represents the same instant in time globally. However, the display of a timestamp for human readability usually includes a Gregorian date, a time, and a time zone, in an implementation-dependent format. For example, the displayed values "2020-01-01 00:00:00 UTC", "2019-12-31 19:00:00 America/New_York", and "2020-01-01 05:30:00 Asia/Kolkata" all represent the same instant in time and therefore represent the same timestamp value.

  • To represent a Gregorian date as it might appear on a calendar (a civil date), use a date value.
  • To represent a time as it might appear on a clock (a civil time), use a time value.
  • To represent a Gregorian date and time as they might appear on a watch, use a datetime value.
Canonical format

The canonical format for a timestamp literal has the following parts:

{
  civil_date_part[time_part [time_zone]] |
  civil_date_part[time_part[time_zone_offset]] |
  civil_date_part[time_part[utc_time_zone]]
}

civil_date_part:
    YYYY-[M]M-[D]D

time_part:
    { |T|t}[H]H:[M]M:[S]S[.F]
  • YYYY: Four-digit year.
  • [M]M: One or two digit month.
  • [D]D: One or two digit day.
  • { |T|t}: A space or a T or t separator. The T and t separators are flags for time.
  • [H]H: One or two digit hour (valid values from 00 to 23).
  • [M]M: One or two digit minutes (valid values from 00 to 59).
  • [S]S: One or two digit seconds (valid values from 00 to 60).
  • [.F]: Up to six fractional digits (microsecond precision).
  • [time_zone]: String representing the time zone. When a time zone is not explicitly specified, the default time zone, UTC, is used. For details, see time zones.
  • [time_zone_offset]: String representing the offset from the Coordinated Universal Time (UTC) time zone. For details, see time zones.
  • [utc_time_zone]: String representing the Coordinated Universal Time (UTC), usually the letter Z or z. For details, see time zones.

To learn more about the literal representation of a timestamp type, see Timestamp literals.

Time zones

A time zone is used when converting from a civil date or time (as might appear on a calendar or clock) to a timestamp (an absolute time), or vice versa. This includes the operation of parsing a string containing a civil date and time like "2020-01-01 00:00:00" and converting it to a timestamp. The resulting timestamp value itself does not store a specific time zone, because it represents one instant in time globally.

Time zones are represented by strings in one of these canonical formats:

  • Offset from Coordinated Universal Time (UTC), or the letter Z or z for UTC.
  • Time zone name from the tz database.

The following timestamps are identical because the time zone offset for America/Los_Angeles is -08 for the specified date and time.

SELECT UNIX_MILLIS(TIMESTAMP '2008-12-25 15:30:00 America/Los_Angeles') AS millis;
SELECT UNIX_MILLIS(TIMESTAMP '2008-12-25 15:30:00-08:00') AS millis;

Offset from Coordinated Universal Time (UTC)

Format:

{+|-}H[H][:M[M]]
{Z|z}

Examples:

-08:00
-8:15
+3:00
+07:30
-7
Z

When using this format, no space is allowed between the time zone and the rest of the timestamp.

2014-09-27 12:30:00.45-8:00
2014-09-27T12:30:00.45Z

Time zone name

Format:

tz_identifier

A time zone name is a tz identifier from the tz database. For a less comprehensive but simpler reference, see the List of tz database time zones on Wikipedia.

Examples:

America/Los_Angeles
America/Argentina/Buenos_Aires
Etc/UTC
Pacific/Auckland

When using a time zone name, a space is required between the name and the rest of the timestamp:

2014-09-27 12:30:00.45 America/Los_Angeles

Note that not all time zone names are interchangeable even if they do happen to report the same time during a given part of the year. For example, America/Los_Angeles reports the same time as UTC-7:00 during daylight saving time (DST), but reports the same time as UTC-8:00 outside of DST.

If a time zone is not specified, the default time zone value is used.

Leap seconds

A timestamp is simply an offset from 1970-01-01 00:00:00 UTC, assuming there are exactly 60 seconds per minute. Leap seconds are not represented as part of a stored timestamp.

If the input contains values that use ":60" in the seconds field to represent a leap second, that leap second is not preserved when converting to a timestamp value. Instead that value is interpreted as a timestamp with ":00" in the seconds field of the following minute.

Leap seconds do not affect timestamp computations. All timestamp computations are done using Unix-style timestamps, which do not reflect leap seconds. Leap seconds are only observable through functions that measure real-world time. In these functions, it is possible for a timestamp second to be skipped or repeated when there is a leap second.