JSON Type
The JSON data type provides the capability to store native JSON in a single column and apply JSON-specific functions to it.
Create Table
|
|
|
|
Insert Data
|
|
|
|
|
|
Retrieve Data
To render a JSON value as a single-line string value:
|
|
|
|
|
|
JSON array and JSON map output:
+-------------------------------+
| j |
+-------------------------------+
| [1,2,"C"] |
| {"A":"B","C":{"D":5,"F":7}} |
+-------------------------------+
To render a JSON value as a formatted structure:
|
|
|
|
|
|
JSON array and JSON map output:
+---------------------+
| j |
+---------------------+
| [
1,
2,
"C"
] |
| {
"A": "B",
"C": {
"D": 5,
"F": 7
}
} |
+---------------------+
JSON Operators
JSON operators can be used to determine whether a given value meets (or does NOT meet) the criteria for being of a certain JSON type category.
Note that the following syntax differs between SQL and the native APIs (like Python) and that the category is specified differently between the two.
|
|
|
|
The given category code (APIs) or category name (SQL) will check the given value against the following JSON types:
Category Code | Category Name | JSON Types |
---|---|---|
0 | N/A | JSON array or object (API default) |
1 | VALUE | Any JSON type (SQL default) |
2 | ARRAY | JSON array |
3 | OBJECT | JSON object (map) |
4 | SCALAR |
|
Example
To pretty-print only JSON objects (maps) in a given JSON column:
|
|
|
|
JSON Functions
Scalar Functions
These functions can be applied to individual json column values, as well as array & string columns. However, for some functions to work as expected, the array or string value may need to be cast to JSON first.
Function | Description | ||||||||||||||||||||||||||||||
---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|
JSON(expr) | Casts the given expr to JSON data type Examples:
| ||||||||||||||||||||||||||||||
JSON_ARRAY (value[,...] <null_hand>) | Creates a JSON array out of the given list of values. An optional <null_hand> parameter can be added to the end of the list to specify handling of null values, though, at present, this only exists for compatibility with other databases' syntax--the option will be ignored and all null values will be added to the array as null. Accepted null handling options:
Note This function is only available in SQL or in the native API via /execute/sql. Examples:
| ||||||||||||||||||||||||||||||
JSON_ARRAY_APPEND(arr, value) | Appends the given value to the given array arr of type string, array, or JSON Examples:
| ||||||||||||||||||||||||||||||
JSON_ARRAY_CONTAINS (json, path, val) | Returns whether the given JSON json contains the primitive value val at the JSON query path, path Examples:
| ||||||||||||||||||||||||||||||
JSON_CARDINALITY(json) | Alias for JSON_LENGTH | ||||||||||||||||||||||||||||||
JSON_EXISTS(json, path) | Returns whether the given JSON json contains the JSON query path, path Examples:
| ||||||||||||||||||||||||||||||
JSON_KEYS(json, path) | Returns the set of keys of the JSON object at the given path in json; null, if the path doesn't exist or contains a non-object (non-map) value Examples:
| ||||||||||||||||||||||||||||||
JSON_LENGTH(json[, path]) | Returns the number of items in the top-level object of the given json, or at the level of the optional JSON path Examples:
| ||||||||||||||||||||||||||||||
JSON_MAKE_ARRAY(value) | Creates a JSON array out of the given value Examples:
| ||||||||||||||||||||||||||||||
JSON_OBJECT (value[,...] <null_hand>) | Creates a JSON map out of the given value set An optional <null_hand> parameter can be added to the end of the list to specify handling of null values, though, at present, this only exists for compatibility with other databases' syntax--the option will be ignored and all null values will be added to the array as null. Accepted null handling options:
Note This function is only available in SQL or in the native API via /execute/sql. Examples:
| ||||||||||||||||||||||||||||||
JSON_PRETTY(json) | Returns a formatted version of the given json object Examples:
| ||||||||||||||||||||||||||||||
JSON_QUERY (json, path [<return>]) | Returns the JSON object at the given path in json; null, if the path doesn't exist or contains a primitive (non-object) value An optional return clause can be added to the end of the path to specify the return type of the object found, as well as the error handling for the object lookup. The format of the clause is: [<wrapper> WRAPPER] [<empty_hand> ON EMPTY] [<error hand> ON ERROR] Note Return clause is only available in SQL or in the native API via /execute/sql.
Examples:
| ||||||||||||||||||||||||||||||
JSON_REPLACE(json, path, repl) | Returns the given json with the value at the JSON path path replaced with the replacement value repl Examples:
| ||||||||||||||||||||||||||||||
JSON_TYPE(expr) | Returns the JSON type of the given expr
| ||||||||||||||||||||||||||||||
JSON_VALUE (json, path [return]) | Returns the JSON value at the given path in json; null, if the path doesn't exist or contains an object (non-primitive) value An optional return clause can be added to the end of the path to specify the return type of the value found, as well as the error handling for the value lookup. The format of the clause is: [RETURNING <type>] [<empty_hand> ON EMPTY] [<error hand> ON ERROR] Note Return clause is only available in SQL or in the native API via /execute/sql.
Examples:
|
Aggregation Functions
These functions can be used across multiple primitive column values within grouping queries.
Note
These functions are only available in SQL or in the native API via /execute/sql.
Function | Description |
---|---|
JSON_ARRAYAGG(expr) | Combines column values within a group into a single JSON array of those values See examples. |
JSON_ARRAYAGG_DISTINCT(expr) | Combines column values within a group into a single JSON array of those values, removing any duplicates See examples. |
Examples
JSON_ARRAYAGG
+------+---------+---------------------------------+
| id | name | j |
+------+---------+---------------------------------+
| 1 | Joe | {} |
| 2 | Jane | {"A":"B"} |
| 3 | Jeff | [1,2,3] |
| 4 | Joyce | {"A":2,"C":{"D":5,"F":[7,8]}} |
+------+---------+---------------------------------+
|
|
+-------------+---------------------------------+--------------------------------------------------------+
| id_list | name_list | json_list |
+-------------+---------------------------------+--------------------------------------------------------+
| [1,2,3,4] | ["Joe","Jane","Jeff","Joyce"] | [{},{"A":"B"},[1,2,3],{"A":2,"C":{"D":5,"F":[7,8]}}] |
+-------------+---------------------------------+--------------------------------------------------------+
JSON_ARRAYAGG_DISTINCT
+------+---------+---------------------------------+
| id | name | j |
+------+---------+---------------------------------+
| 1 | Joe | {} |
| 1 | Joyce | [1,2,3] |
| 2 | Jane | {"A":"B"} |
| 2 | Jeff | {"A":2,"C":{"D":5,"F":[7,8]}} |
| 3 | Jane | {} |
| 3 | Jeff | [1,2,3] |
| 4 | Joe | {"A":"B"} |
| 4 | Joyce | {"A":2,"C":{"D":5,"F":[7,8]}} |
+------+---------+---------------------------------+
|
|
+-------------+---------------------------------+--------------------------------------------------------+
| id_list | name_list | json_list |
+-------------+---------------------------------+--------------------------------------------------------+
| [1,2,3,4] | ["Jane","Jeff","Joe","Joyce"] | [[1,2,3],{},{"A":"B"},{"A":2,"C":{"D":5,"F":[7,8]}}] |
+-------------+---------------------------------+--------------------------------------------------------+
UNNEST_JSON_ARRAY
The UNNEST_JSON_ARRAY function transposes array values into columnar data.
The two forms of the UNNEST_JSON_ARRAY function follow, one for cases where only one column needs to be unnested and one for cases where more than one column needs to be unnested. See examples.
|
|
Parameters | Description |
---|---|
<column alias> | Column alias to use for the resulting unnested data column; if no alias specified, use * to select the column |
<table name> | Name of the table containing the JSON array column |
<column name> | Name of the JSON array column to unnest |
WITH ORDINALITY | Also return the 0-based index in the source JSON arrays for each transposed array value; the index value will be returned as the column alias ordinality |
|
|
Parameters | Description |
---|---|
<column alias list> | Column aliases given to the resulting unnested data columns, specified in <table/columns aliases> |
<ordinality alias> | Column alias given to the resulting ordinality column in <table/columns aliases>, if WITH ORDINALITY is specified |
<table name> | Name of the table containing the JSON array column(s) |
<table alias> | Alias to use for the table containing the JSON array column(s) |
<column list> | Comma-separated list of JSON array columns to unnest |
<table/columns aliases> | Alias to use for the virtual table and columns being used to return the unnested data (including any ordinality alias, if specified), using the form: <table alias>(<column alias list> [,<ordinality alias>]) For example, to return two columns of unnested JSON array data as uai & uav, respectively, and the corresponding ordinality index as index, all within the virtual table unn use: unn(uai, uav, index) |
WITH ORDINALITY | Also return the 0-based index in the source JSON arrays for each transposed array value; the index value will be returned in an alias specified in <table/columns aliases> |
Examples
The following examples use this data set as a baseline:
+-----------+-----------------+
| ai | av |
+-----------+-----------------+
| [1,2,3] | ["A","B","C"] |
| [4,5,6] | ["D","E","F"] |
| [7,8,9] | ["D","E","F"] |
| [1,2,3] | ["G","H","I"] |
+-----------+-----------------+
To turn the string arrays in the av JSON column in the example.js_unn_arr table into a column of values aliased as uav:
|
|
+-------+
| uav |
+-------+
| A |
| B |
| C |
| D |
| D |
| E |
| E |
| F |
| F |
| G |
| H |
| I |
+-------+
To turn the integer arrays in the ai JSON column in the example.js_unn_arr table into a column of values aliased as uai and the corresponding index in the original json for each as a column of indices named ordinality:
|
|
+-------+--------------+
| uai | ordinality |
+-------+--------------+
| 1 | 0 |
| 1 | 0 |
| 2 | 1 |
| 2 | 1 |
| 3 | 2 |
| 3 | 2 |
| 4 | 0 |
| 5 | 1 |
| 6 | 2 |
| 7 | 0 |
| 8 | 1 |
| 9 | 2 |
+-------+--------------+
To turn the integer & string arrays in the ai & av JSON columns in the example.js_unn_arr table into two columns of values aliased as uai & uav in a virtual table with alias t, respectively:
|
|
+-------+-------+
| uai | uav |
+-------+-------+
| 1 | A |
| 1 | G |
| 2 | B |
| 2 | H |
| 3 | C |
| 3 | I |
| 4 | D |
| 5 | E |
| 6 | F |
| 7 | D |
| 8 | E |
| 9 | F |
+-------+-------+
To turn the integer & string arrays in the ai & av JSON columns in the example.js_unn_arr table into two columns of values aliased as uai & uav in a virtual table with alias t, respectively, and adding the corresponding index in the original array for each as a column of indices aliased as index:
|
|
+-------+-------+---------+
| uai | uav | index |
+-------+-------+---------+
| 1 | A | 0 |
| 1 | G | 0 |
| 2 | B | 1 |
| 2 | H | 1 |
| 3 | C | 2 |
| 3 | I | 2 |
| 4 | D | 0 |
| 5 | E | 1 |
| 6 | F | 2 |
| 7 | D | 0 |
| 8 | E | 1 |
| 9 | F | 2 |
+-------+-------+---------+
To turn the integer arrays in the ai JSON column in the example.js_unn_arr table into a column of values aliased as uai, removing any duplicates across all arrays:
|
|
+-------+
| uai |
+-------+
| 1 |
| 2 |
| 3 |
| 4 |
| 5 |
| 6 |
| 7 |
| 8 |
| 9 |
+-------+
UNNEST_JSON_OBJECT
The UNNEST_JSON_OBJECT function transposes JSON objects (maps) into columnar data. Each source object is split out into two columns: a string column containing the top-level object keys, and a JSON column containing the value objects for those keys.
The two forms of the UNNEST_JSON_OBJECT function follow, one for cases where only one column needs to be unnested and one for cases where more than one column needs to be unnested. See examples.
|
|
Parameters | Description |
---|---|
<column alias list> | Column aliases given to the resulting unnested key & value data columns specified in <table/columns aliases>; if no aliases are specified, use * to select the columns |
<table name> | Name of the table containing the JSON object (map) column |
<column name> | Name of the JSON object (map) column to unnest |
<table/columns aliases> | Alias to use for the virtual table and key/value columns being used to return the unnested data (including any ordinality alias, if specified), using the form: <table alias>(<key alias>, <value alias> [,<ordinality alias>]) For example, to return a column as unnested JSON map data, referenced as the key/value pairs j_k & j_v, respectively, with the corresponding ordinality index as index, all within the virtual table unn, use: unn(j_k, j_v, index) If no aliases are given, the two key/value columns will be returned as KEY_0 & VALUE_0, respectively. |
WITH ORDINALITY | Also return the 0-based index in the source maps for each transposed map value; the index value will be returned as the column alias ordinality unless overridden in <table/columns aliases> |
|
|
Parameters | Description |
---|---|
<column alias list> | Column aliases given to the resulting unnested key & value data columns specified in <table/columns aliases> |
<ordinality alias> | Column alias given to the resulting ordinality column in <table/columns aliases>, if WITH ORDINALITY is specified |
<table name> | Name of the table containing the JSON object (map) column(s) |
<table alias> | Alias to use for the table containing the JSON object (map) column(s) |
<column list> | Comma-separated list of JSON object (map) columns to unnest |
<table/columns aliases> | Alias to use for the virtual table and columns being used to return the unnested data (including any ordinality alias, if specified), using the form: <table alias>(<key alias>, <value alias>[,...] [,<ordinality alias>]) For example, to return two JSON map data columns as unnested, referenced as the key/value pairs j1_k & j1_v and j2_k & j2_v, respectively, with the corresponding ordinality index as index, all within the virtual table unn, use: unn(j1_k, j1_v, j2_k, j2_v, index) |
WITH ORDINALITY | Also return the 0-based index in the source maps for each transposed map value; the index value will be returned in an alias specified in <table/columns aliases> |
Examples
The following examples use this data set as a baseline:
+-----------------------------+------------------------------------------+
| j1 | j2 |
+-----------------------------+------------------------------------------+
| {"A":"B","C":4,"E":5} | {"A":{"B":"C"},"D":5,"F":[7,8,9]} |
| {"A":2,"C":"D","E":"F"} | {"A":[2,3],"D":"E","F":{"G":"H"}} |
| {"G":"H","I":10,"K":"12"} | {"I":{"J":"K"},"L":[13,14,15],"P":"Q"} |
| {"A":"B","C":4,"E":5} | {"A":{"B":"C"},"D":5,"F":[7,8,9]} |
+-----------------------------+------------------------------------------+
To turn the JSON maps in the j1 JSON column in the example.js_unn_obj table into key/value pair columns of values aliased as j1_k & j1_v, respectively:
|
|
+--------+--------+
| j1_k | j1_v |
+--------+--------+
| A | "B" |
| A | "B" |
| A | 2 |
| C | "D" |
| C | 4 |
| C | 4 |
| E | "F" |
| E | 5 |
| E | 5 |
| G | "H" |
| I | 10 |
| K | "12" |
+--------+--------+
To turn the JSON maps in the j2 JSON column in the example.js_unn_obj table into key/value pair columns of values aliased as j2_k & j2_v, and the corresponding index in the original map for each as a column of indices aliased as index:
|
|
+--------+--------------+---------+
| j2_k | j2_v | index |
+--------+--------------+---------+
| A | [2,3] | 0 |
| A | {"B":"C"} | 0 |
| A | {"B":"C"} | 0 |
| D | "E" | 1 |
| D | 5 | 1 |
| D | 5 | 1 |
| F | [7,8,9] | 2 |
| F | [7,8,9] | 2 |
| F | {"G":"H"} | 2 |
| I | {"J":"K"} | 0 |
| L | [13,14,15] | 1 |
| P | "Q" | 2 |
+--------+--------------+---------+
To turn the JSON maps in the j1 & j2 JSON columns in the example.js_unn_obj table into two sets of key/value pair columns of values aliased as j1_k & j1_v and j2_k & j2_v, respectively, in a virtual table with alias t:
|
|
+--------+--------+--------+--------------+
| j1_k | j1_v | j2_k | j2_v |
+--------+--------+--------+--------------+
| A | "B" | A | {"B":"C"} |
| A | "B" | A | {"B":"C"} |
| A | 2 | A | [2,3] |
| C | "D" | D | "E" |
| C | 4 | D | 5 |
| C | 4 | D | 5 |
| E | "F" | F | {"G":"H"} |
| E | 5 | F | [7,8,9] |
| E | 5 | F | [7,8,9] |
| G | "H" | I | {"J":"K"} |
| I | 10 | L | [13,14,15] |
| K | "12" | P | "Q" |
+--------+--------+--------+--------------+
To turn the JSON maps in the j1 & j2 JSON columns in the example.js_unn_obj table into two sets of key/value pair columns of values aliased as j1_k & j1_v and j2_k & j2_v, respectively, in a virtual table with alias t, and adding the corresponding index in the original map for each as a column of indices aliased as index:
|
|
+--------+--------+--------+--------------+---------+
| j1_k | j1_v | j2_k | j2_v | index |
+--------+--------+--------+--------------+---------+
| A | "B" | A | {"B":"C"} | 0 |
| A | "B" | A | {"B":"C"} | 0 |
| A | 2 | A | [2,3] | 0 |
| C | "D" | D | "E" | 1 |
| C | 4 | D | 5 | 1 |
| C | 4 | D | 5 | 1 |
| E | "F" | F | {"G":"H"} | 2 |
| E | 5 | F | [7,8,9] | 2 |
| E | 5 | F | [7,8,9] | 2 |
| G | "H" | I | {"J":"K"} | 0 |
| I | 10 | L | [13,14,15] | 1 |
| K | "12" | P | "Q" | 2 |
+--------+--------+--------+--------------+---------+