diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 8819b60685f..e52e2d953b6 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -16287,7 +16287,7 @@ table2-mapping
jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)
- [{"f1":null,"f2":null},2,null,3]
+ [{"f1": null, "f2": null}, 2, null, 3]jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')
@@ -16526,7 +16526,7 @@ table2-mapping
comparisons.
- jsonb_path_exists_tz('["2015-08-01 12:00:00 -05"]', '$[*] ? (@.datetime() < "2015-08-02".datetime())')
+ jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() < "2015-08-02".datetime())')t
@@ -17564,1870 +17564,556 @@ $.* ? (@ like_regex "^\\d+$")
-
+
SQL/JSON Functions and Expressions
- SQL/JSON
- functions and expressions
+ SQL/JSON
+ functions and expressions
-
- To provide native support for JSON data types within the SQL environment,
- PostgreSQL implements the
- SQL/JSON data model.
- This model comprises sequences of items. Each item can hold SQL scalar
- values, with an additional SQL/JSON null value, and composite data structures
- that use JSON arrays and objects. The model is a formalization of the implied
- data model in the JSON specification
- RFC 7159.
-
+
+ To provide native support for JSON data types within the SQL environment,
+ PostgreSQL implements the
+ SQL/JSON data model.
+ This model comprises sequences of items. Each item can hold SQL scalar
+ values, with an additional SQL/JSON null value, and composite data structures
+ that use JSON arrays and objects. The model is a formalization of the implied
+ data model in the JSON specification
+ RFC 7159.
+
-
- SQL/JSON allows you to handle JSON data alongside regular SQL data,
- with transaction support, including:
-
+
+ SQL/JSON allows you to handle JSON data alongside regular SQL data,
+ with transaction support, including:
+
-
-
+
+
- Uploading JSON data into the database and storing it in
- regular SQL columns as character or binary strings.
+ Uploading JSON data into the database and storing it in
+ regular SQL columns as character or binary strings.
-
-
+
+
- Generating JSON objects and arrays from relational data.
+ Generating JSON objects and arrays from relational data.
-
-
+
+
Querying JSON data using SQL/JSON query functions and
SQL/JSON path language expressions.
-
-
+
+
-
- All SQL/JSON functions fall into one of two groups.
+
+ There are two groups of SQL/JSON functions.
Constructor functions
generate JSON data from values of SQL types.
Query functions
evaluate SQL/JSON path language expressions against JSON values
and produce values of SQL/JSON types, which are converted to SQL types.
-
-
-
- Producing JSON Content
+
- PostgreSQL provides several functions
- that generate JSON data. Taking values of SQL types as input, these
- functions construct JSON objects, JSON arrays or JSON scalars represented
- as the json or jsonb types, or as
- SQL character or binary strings.
+ Many SQL/JSON functions have an optional FORMAT
+ clause. This is provided to conform with the SQL standard, but has no
+ effect except where noted otherwise.
-
-
-
- JSON
-
-
-
-
- JSON_SCALAR
-
-
-
-
- JSON_OBJECT
-
-
-
-
- JSON_OBJECTAGG
-
-
-
-
- JSON_ARRAY
-
-
-
-
- JSON_ARRAYAGG
-
-
-
-
-
- JSON
- json
-
-JSON (
- expression FORMAT JSON ENCODING UTF8
- { WITH | WITHOUT } UNIQUE KEYS
- RETURNING json_data_type
-)
-
-
-
- Description
-
-
- The JSON function generates JSON
- from text data.
-
-
-
-
- Parameters
-
-
-
- expression FORMAT JSON ENCODING UTF8
-
-
-
- The string expression provides the
- JSON text data.
- It can be any character string (text,
- char, etc.) or binary string (bytea)
- in UTF8 encoding.
- If the expression is NULL an
- SQL null value is returned.
-
-
- The optional FORMAT clause is provided to conform
- to the SQL/JSON standard.
-
-
-
-
-
- { WITH | WITHOUT } UNIQUE KEYS
-
-
-
- Defines whether duplicate keys are allowed:
-
-
-
- WITHOUT
-
-
- Default. The constructed
- JSON object can contain duplicate keys.
-
-
-
-
- WITH
-
-
- Duplicate keys are not allowed.
- If the input data contains duplicate keys, an error is returned.
-
-
-
-
-
- Optionally, you can add the KEYS keyword for
- semantic clarity.
-
-
-
-
-
- RETURNING json_data_type
-
-
-
- The output clause that specifies the type (json or
- jsonb) of the generated JSON.
- The default is json.
-
-
-
-
-
-
-
- Notes
-
- Alternatively, you can construct JSON values simply
- using PostgreSQL-specific casts to
- json and jsonb types.
-
-
-
- Examples
-
- Construct JSON using the provided strings:
-
-
-SELECT JSON('{ "a" : 123, "b": [ true, "foo" ], "a" : "bar" }');
- json
---------------------------------------------------
- { "a" : 123, "b": [ true, "foo" ], "a" : "bar" }
-(1 row)
-
-
-SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' RETURNING jsonb);
- json
-----------------------------------
- {"a": "bar", "b": [true, "foo"]}
-(1 row)
-
-SELECT JSON('{"a": 123, "b": [true, "foo"], "a": "bar"}' WITH UNIQUE KEYS);
-ERROR: duplicate JSON object key value
-
-
-
-
-
- JSON_SCALAR
- json_scalar
-
-
-JSON_SCALAR (
- expression
- RETURNING json_data_type
-)
-
-
-
- Description
-
-
- The JSON_SCALAR function generates a
- JSON scalar value from SQL data.
-
-
-
-
- Parameters
-
-
-
- expression
-
-
-
- The expression provides the data for constructing a
- JSON value.
- For null input, SQL null
- (not a JSON null) value is returned.
- For any scalar other than a number or a Boolean, the text
- representation will be used, with escaping as necessary to make
- it a valid JSON string value.
- For details, see
- to_json()/to_jsonb()
- in .
-
-
-
-
-
- RETURNING json_data_type
-
-
-
- The output clause that specifies the type (json or
- jsonb) of the generated JSON scalar.
- The default is json.
-
-
-
-
-
-
-
- Notes
-
- Alternatively, you can construct JSON objects by
- using the PostgreSQL-specific
- to_json()/to_jsonb() functions.
- See for details.
-
-
-
- Examples
-
- Construct JSON scalars from the provided values of various types:
-
-
-SELECT JSON_SCALAR(123.45);
- json_scalar
--------------
- 123.45
-(1 row)
-
-SELECT JSON_SCALAR('123');
- json_scalar
--------------
- "123"
-(1 row)
-
-SELECT JSON_SCALAR(true);
- json_scalar
--------------
- true
-(1 row)
-
-
-
-
-
- JSON_OBJECT
- json_object
-
-
-JSON_OBJECT (
- { key_expression { VALUE | ':' }
- value_expression FORMAT JSON ENCODING UTF8 }, ...
- { NULL | ABSENT } ON NULL
- { WITH | WITHOUT } UNIQUE KEYS
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-
-
- Description
-
-
- The JSON_OBJECT function generates a
- JSON object from SQL or
- JSON data.
-
-
-
-
- Parameters
-
-
-
-
-
- key_expression { VALUE | ':' }
- value_expression FORMAT JSON ENCODING UTF8
-
-
-
-
- The input clause that provides the data for constructing a JSON object:
-
-
-
-
- key_expression is a scalar expression
- defining the JSON key, which is implicitly
- converted to the text type.
- The provided expression cannot be NULL or
- belong to a type that has a cast to json.
-
-
-
-
- value_expression is an expression
- that provides the input for the JSON value.
-
-
-
-
- The optional FORMAT clause is provided to
- conform to the SQL/JSON standard.
-
-
-
-
- You must use a colon or the VALUE keyword as a
- separator between the key and the value. Multiple key/value pairs are
- separated by commas.
-
-
-
-
-
-
- { NULL | ABSENT } ON NULL
-
-
-
- Defines whether NULL values are allowed in the constructed
- JSON object:
-
-
-
- NULL
-
-
- Default. NULL values are allowed.
-
-
-
-
- ABSENT
-
-
- If the value is NULL,
- the corresponding key/value pair is omitted from the generated
- JSON object.
-
-
-
-
-
-
-
-
-
- { WITH | WITHOUT } UNIQUE KEYS
-
-
- Defines whether duplicate keys are allowed:
-
-
-
- WITHOUT
-
-
- Default. The constructed
- JSON object can contain duplicate keys.
-
-
-
-
- WITH
-
-
- Duplicate keys are not allowed.
- If the input data contains duplicate keys, an error is returned.
- This check is performed before removing JSON items with NULL values.
-
-
-
-
-
- Optionally, you can add the KEYS keyword for semantic clarity.
-
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the type of the generated JSON object.
- For details, see .
-
-
-
-
-
-
-
-
- Notes
- Alternatively, you can construct JSON objects by using the
- PostgreSQL-specific json_build_object()/
- jsonb_build_object() functions.
- See for details.
-
-
-
-
- Examples
-
- Construct a JSON object from the provided key/value pairs of various types:
-
-
-SELECT JSON_OBJECT(
--- scalar JSON types
- 'key1': 'string',
- 'key2': '[1, 2]',
- 'key3' VALUE 123, -- alternative syntax for key-value delimiter
- 'key4': NULL,
--- other types
- 'key5': ARRAY[1, 2, 3], -- postgres array
- 'key6': jsonb '{"a": ["b", 1]}', -- composite json/jsonb
- 'key7': date '2017-09-30', -- datetime type
- 'key8': row(1, 'a'), -- row type
- 'key9': '[1, 2]' FORMAT JSON, -- same value as for key2, but with FORMAT
--- key can be an expression
- 'key' || 'last' : TRUE
-ABSENT ON NULL) AS json;
- json
-----------------------------------------------------
-{"key1" : "string", "key2" : "[1, 2]", "key3" : 123,
- "key5" : [1,2,3], "key6" : {"a": ["b", 1]},
- "key7" : "2017-09-30", "key8" : {"f1":1,"f2":"a"},
- "key9" : [1, 2], "keylast" : true}
-(1 row)
-
-
- From the films table, select some data
- about the films distributed by Paramount Pictures
- (did = 103) and return JSON objects:
+ lists the SQL/JSON
+ Constructor functions. Each function has a RETURNING
+ clause specifying the data type returned. For the json and
+ json_scalar functions, this needs to be either json or
+ jsonb. For the other constructor functions it must be one of json,
+ jsonb, bytea, a character string type (text, char,
+ varchar, or nchar), or a type for which there is a cast
+ from json to that type.
+ By default, the json type is returned.
-
-SELECT
-JSON_OBJECT(
- 'code' VALUE f.code,
- 'title' VALUE f.title,
- 'did' VALUE f.did
-) AS paramount
-FROM films AS f
-WHERE f.did = 103;
- paramount
-----------------------------------------------------
-{"code" : "P_301", "title" : "Vertigo", "did" : 103}
-{"code" : "P_302", "title" : "Becket", "did" : 103}
-{"code" : "P_303", "title" : "48 Hrs", "did" : 103}
-(3 rows)
-
-
-
-
-
- JSON_OBJECTAGG
- json_objectagg
-
-
-JSON_OBJECTAGG (
- { key_expression { VALUE | ':' } value_expression }
- { NULL | ABSENT } ON NULL
- { WITH | WITHOUT } UNIQUE KEYS
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-
-
-
- Description
-
-
- The JSON_OBJECTAGG function aggregates the provided data
- into a JSON object. You can use this function to combine values
- stored in different table columns into pairs.
-
-
-
-
- Parameters
-
-
-
-
- key_expression { VALUE | ':' } value_expression
-
-
-
-
- The input clause that provides the data to be aggregated as a JSON object:
-
-
-
-
- key_expression is a scalar expression
- defining the JSON key, which is implicitly
- converted to the text type.
- The provided expression cannot be NULL or
- belong to a type that has a cast to json.
-
-
-
-
- value_expression is an expression that
- provides the input for the JSON value preceded
- by its type.
- For JSON scalar types, you can omit the type.
-
-
-
- The input value of the bytea type must be stored in UTF8
- and contain a valid UTF8 string. Otherwise, an error occurs.
- PostgreSQL currently supports only UTF8.
-
-
-
-
-
- You must use a colon or the VALUE keyword as a separator between
- keys and values. Multiple key/value pairs are separated by commas.
-
-
-
-
-
-
- { NULL | ABSENT } ON NULL
-
-
-
- Defines whether NULL values are allowed in the constructed
- JSON object:
-
-
-
- NULL
-
-
- Default. NULL values are allowed.
-
-
-
-
- ABSENT
-
-
- If the value is NULL,
- the corresponding key/value pair is omitted from the generated
- JSON object.
-
-
-
-
-
-
-
-
-
- { WITH | WITHOUT } UNIQUE KEYS
-
-
- Defines whether duplicate keys are allowed:
-
-
-
- WITHOUT
-
-
- Default. The constructed
- JSON object can contain duplicate keys.
-
-
-
-
- WITH
-
-
- Duplicate keys are not allowed.
- If the input data contains duplicate keys, an error is returned.
- This check is performed before removing JSON items with NULL values.
-
-
-
-
-
- Optionally, you can add the KEYS keyword for semantic clarity.
-
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the type of the generated JSON object.
- For details, see .
-
-
-
-
-
-
-
-
- Notes
- Alternatively, you can create JSON objects by using
- PostgreSQL-specific json_object_agg()/
- jsonb_object_agg() aggregate functions.
- See for details.
-
-
-
-
- Examples
-
-
- For films with did = 103, aggregate key/value pairs
- of film genre (f.kind) and title (f.title)
- into a single object:
-
-
-SELECT
-JSON_OBJECTAGG(
- f.kind VALUE f.title)
- AS films_list
-FROM films AS f
-where f.did = 103;
- films_list
-----------------------------------------------------
-{ "Action" : "Vertigo", "Drama" : "Becket", "Action" : "48 Hrs" }
-
-
-
- Return the same object as jsonb. Note that only a single film of
- the action genre is included as the jsonb type does not allow duplicate keys.
-
-
-SELECT
-JSON_OBJECTAGG(
- f.kind VALUE f.title
- RETURNING jsonb)
-AS films_list
-FROM films AS f
-where f.did = 103;
- films_list
-----------------------------------------------------
-{"Drama": "Becket", "Action": "48 Hrs"}
-
-
-
- Return objects of film titles and length, grouped by the film genre:
-
-
-SELECT
- f.kind,
- JSON_OBJECTAGG(
- f.title VALUE f.len
-) AS films_list
-FROM films AS f
-GROUP BY f.kind;
-
- kind | films_list
--------------+----------------------------------
-Musical | { "West Side Story" : "02:32:00", "The King and I" : "02:13:00", "Bed Knobs and Broomsticks" : "01:57:00" }
-Romantic | { "The African Queen" : "01:43:00", "Une Femme est une Femme" : "01:25:00", "Storia di una donna" : "01:30:00" }
-Comedy | { "Bananas" : "01:22:00", "There's a Girl in my Soup" : "01:36:00" }
-Drama | { "The Third Man" : "01:44:00", "Becket" : "02:28:00", "War and Peace" : "05:57:00", "Yojimbo" : "01:50:00", "Das Boot" : "02:29:00" }
-Action | { "Vertigo" : "02:08:00", "48 Hrs" : "01:37:00", "Taxi Driver" : "01:54:00", "Absence of Malice" : "01:55:00" }
-(5 rows)
-
-
-
-
-
- JSON_ARRAY
- json_array
-
-
-JSON_ARRAY (
- { value_expression FORMAT JSON } , ...
- { NULL | ABSENT } ON NULL
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-JSON_ARRAY (
- query_expression
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-
-
- Description
-
-
- The JSON_ARRAY function constructs a JSON array from
- the provided SQL or JSON data.
-
-
-
-
- Parameters
-
-
-
-
- value_expression
-
-
-
-
- The input clause that provides the data for constructing a JSON array.
- The value_expression is an expression
- that provides the input for the JSON value preceded by its type.
- For JSON scalar types, you can omit the type.
-
-
-
- The input value of the bytea type must be stored in UTF8
- and contain a valid UTF8 string. Otherwise, an error occurs.
- PostgreSQL currently supports only UTF8.
-
-
-
-
-
-
-
-
- query_expression
-
-
-
- An SQL query that provides the data for constructing a JSON array.
- The query must return a single column that holds the values to be
- used in the array.
-
-
-
-
-
-
- { NULL | ABSENT } ON NULL
-
-
-
- Defines whether NULL values are allowed in the generated JSON array:
-
-
-
- NULL
-
-
- NULL values are allowed.
-
-
-
-
- ABSENT
-
-
- Default. If the value is NULL,
- the corresponding key/value pair is omitted from the generated
- JSON object.
-
-
-
-
-
- This clause is only supported for arrays built from an explicit list of values.
- If you are using an SQL query to generate an array, NULL values are always
- omitted.
-
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the return type of the constructed JSON array.
- For details, see .
-
-
-
-
-
-
-
-
- Notes
- Alternatively, you can create JSON arrays by using
- PostgreSQL-specific json_build_array()/
- jsonb_build_array() functions.
- See for details.
-
-
-
-
- Examples
-
- From the films table, select some data
- about the films distributed by Paramount Pictures
- (did = 103) and return JSON arrays:
-
-
-SELECT
-JSON_ARRAY(
- f.code,
- f.title,
- f.did
-) AS films
-FROM films AS f
-WHERE f.did = 103;
- films
-----------------------------------------------------
-["P_301", "Vertigo", 103]
-["P_302", "Becket", 103]
-["P_303", "48 Hrs", 103]
-(3 rows)
-
-
- Construct a JSON array from the list of film titles returned from the
- films table by a subquery:
-
-
-SELECT
-JSON_ARRAY(
- SELECT
- f.title
-FROM films AS f
-where f.did = 103)
-AS film_titles;
- film_titles
-----------------------------------------------------
-["Vertigo", "Becket", "48 Hrs"]
-(1 row)
-
-
-
-
-
- JSON_ARRAYAGG
- json_arrayagg
-
-
-JSON_ARRAYAGG (
- value_expression
- ORDER BY sort_expression
- { NULL | ABSENT } ON NULL
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-
-
-
- Description
-
-
- The JSON_ARRAYAGG function aggregates the provided SQL
- or JSON data into a JSON array.
-
-
-
-
- Parameters
-
-
-
-
- value_expression
-
-
-
-
- The input clause that provides the input data to be aggregated as
- a JSON array.
- The value_expression can be a value or a query
- returning the values to be used as input in array construction.
- You can provide multiple input values separated by commas.
-
-
-
-
-
-
- ORDER BY
-
-
-
- Sorts the input data to be aggregated as a JSON array.
- For details on the exact syntax of the ORDER BY clause, see .
-
-
-
-
-
-
- { NULL | ABSENT } ON NULL
-
-
-
- Defines whether NULL values are allowed in the constructed array:
-
-
-
- NULL — NULL values are allowed.
-
-
-
-
- ABSENT (default) — NULL
- values are omitted from the generated array.
-
-
-
-
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the return type of the constructed JSON array.
- For details, see .
-
-
-
-
-
-
-
-
- Notes
- Alternatively, you can create JSON arrays by using
- PostgreSQL-specific json_agg()/
- jsonb_agg() functions.
- See for details.
-
-
-
-
- Examples
-
- Construct an array of film titles sorted in alphabetical order:
-
-
-SELECT
-JSON_ARRAYAGG(
- f.title
-ORDER BY f.title ASC) AS film_titles
-FROM films AS f;
- film_titles
-----------------------------------------------------
-["48 Hrs", "Absence of Malice", "Bananas", "Becket", "Bed Knobs and Broomsticks", "Das Boot", "Storia di una donna", "Taxi Driver", "The African Queen", "The King and I", "There's a Girl in my Soup", "The Third Man", "Une Femme est une Femme", "Vertigo", "War and Peace", "West Side Story", "Yojimbo"]
-(1 row)
-
-
-
-
-
-
- Querying JSON
+
- SQL/JSON query functions evaluate SQL/JSON path language expressions
- against JSON values, producing values of SQL/JSON types, which are
- converted to SQL types. All SQL/JSON query functions accept several
- common clauses described in .
- For details on the SQL/JSON path language,
- see .
+ Many of the results that can be obtained from the SQL/JSON Constructor
+ functions can also be obtained by calling
+ PostgreSQL-specific functions detailed in
+ and
+ .
+
-
-
-
- IS JSON
-
-
-
-
- JSON_EXISTS
-
-
-
-
- JSON_VALUE
-
-
-
-
- JSON_QUERY
-
-
-
-
- JSON_TABLE
-
-
-
+
+ SQL/JSON Constructor Functions
+
+
+
+
+ Function signature
+
+
+ Description
+
+
+ Example(s)
+
+
+
+
+
+
+ json constructor
+ json (
+ expression
+ FORMAT JSONENCODING UTF8
+ { WITH | WITHOUT } UNIQUEKEYS
+ RETURNINGjson_data_type)
+
+
+ The expression can be any text type or a
+ bytea in UTF8 encoding. If the
+ expression is NULL, an
+ SQL null value is returned.
+ If WITH UNIQUE is specified, the
+ expression must not contain any duplicate
+ object keys.
+
+
+ json('{"a":123, "b":[true,"foo"], "a":"bar"}')
+ {"a":123, "b":[true,"foo"], "a":"bar"}
+
+
+ json('{"a":123,"b":[true,"foo"],"a":"bar"}' returning jsonb)
+ {"a": "bar", "b": [true, "foo"]}
+
+
+
+
+ json_scalar
+ json_scalar (expression
+ RETURNINGjson_data_type)
+
+
+ Returns a JSON scalar value representing
+ expression.
+ If the input is NULL, an SQL NULL is returned. If the input is a number
+ or a boolean value, a corresponding JSON number or boolean value is
+ returned. For any other value a JSON string is returned.
+
+
+ json_scalar(123.45)
+ 123.45
+
+
+ json_scalar(CURRENT_TIMESTAMP)
+ "2022-05-10T10:51:04.62128-04:00"
+
+
+
+
+ json_object
+ json_object (
+ { key_expression { VALUE | ':' }
+ value_expressionFORMAT JSONENCODING UTF8 }, ...
+ { NULL | ABSENT } ON NULL
+ { WITH | WITHOUT } UNIQUEKEYS
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ Constructs a JSON object of all the key value pairs given,
+ or an empty object if none are given.
+ key_expression is a scalar expression
+ defining the JSON key, which is
+ converted to the text type.
+ It cannot be NULL nor can it
+ belong to a type that has a cast to the json.
+ If WITH UNIQUE is specified, there must not
+ be any duplicate key_expression.
+ If ABSENT ON NULL is specified, the entire
+ pair is omitted if the value_expression
+ is NULL.
+
+
+ json_object('code' VALUE 'P123', 'title': 'Jaws')
+ {"code" : "P123", "title" : "Jaws"}
+
+
+
+
+ json_objectagg
+ json_objectagg (
+ { key_expression { VALUE | ':' } value_expression }
+ { NULL | ABSENT } ON NULL
+ { WITH | WITHOUT } UNIQUEKEYS
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ Behaves like json_object above, but as an
+ aggregate function, so it only takes one
+ key_expression and one
+ value_expression parameter.
+
+
+ SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)
+ { "a" : "2022-05-10", "b" : "2022-05-11" }
+
+
+
+
+ json_array
+ json_array (
+ { value_expressionFORMAT JSON } , ...
+ { NULL | ABSENT } ON NULL
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ json_array (
+ query_expression
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ Constructs a JSON array from either a series of
+ value_expression parameters or from the results
+ of query_expression,
+ which must be a SELECT query returning a single column. If
+ ABSENT ON NULL is specified, NULL values are ignored.
+ This is always the case if a
+ query_expression is used.
+
+
+ json_array(1,true,json '{"a":null}')
+ [1, true, {"a":null}]
+
+
+ json_array(SELECT * FROM (VALUES(1),(2)) t)
+ [1, 2]
+
+
+
+
+ json_arrayagg
+ json_arrayagg (
+ value_expression
+ ORDER BYsort_expression
+ { NULL | ABSENT } ON NULL
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ Behaves in the same way as json_array
+ but as an aggregate function so it only takes one
+ value_expression parameter.
+ If ABSENT ON NULL is specified, any NULL
+ values are omitted.
+ If ORDER BY is specified, the elements will
+ appear in the array in that order rather than in the input order.
+
+
+ SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)
+ [2, 1]
+
+
+
+
+
- In some usage examples for these functions,
- the following small table storing some JSON data will be used:
-
-CREATE TABLE my_films (
- js text );
-
-INSERT INTO my_films VALUES (
-'{ "favorites" : [
- { "kind" : "comedy", "films" : [
- { "title" : "Bananas",
- "director" : "Woody Allen"},
- { "title" : "The Dinner Game",
- "director" : "Francis Veber" } ] },
- { "kind" : "horror", "films" : [
- { "title" : "Psycho",
- "director" : "Alfred Hitchcock" } ] },
- { "kind" : "thriller", "films" : [
- { "title" : "Vertigo",
- "director" : "Alfred Hitchcock" } ] },
- { "kind" : "drama", "films" : [
- { "title" : "Yojimbo",
- "director" : "Akira Kurosawa" } ] }
- ] }');
-
-
-
-
- JSON_EXISTS
- json_exists
-
-
-JSON_EXISTS (
- context_item, path_expression PASSING { value AS varname } , ...
- RETURNING data_type
- { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR
-)
-
-
-
- Description
-
-
- The JSON_EXISTS function checks whether the provided
- JSON path expression can return any SQL/JSON items.
-
-
-
-
- Parameters
-
-
-
- context_item, path_expression PASSING { value AS varname } , ...
-
-
-
-
- The input data to query, the JSON path expression defining the query, and an optional PASSING clause.
- See for details.
-
-
-
-
-
-
- RETURNING data_type
-
-
-
- The output clause that specifies the data type of the returned value.
- The specified data type should have a cast from a boolean
- type, which is returned by default.
-
-
-
-
-
-
- { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR
-
-
-
- Defines the return value if an error occurs. The default value is FALSE.
-
-
-
-
-
-
-
-
- Examples
-
-
- Check whether the provided jsonb data contains a
- key/value pair with the key1 key, and its value
- contains an array with one or more elements bigger than 2:
+ details SQL/JSON
+ facilities for testing and serializing JSON.
+
+
+ SQL/JSON Testing and Serializing Functions
+
+
+
+
+ Function signature
+
+
+ Description
+
+
+ Example(s)
+
+
+
+
+
+
+ IS JSON
+ expressionISNOTJSON
+ { VALUE | SCALAR | ARRAY | OBJECT }
+ { WITH | WITHOUT } UNIQUEKEYS
+
+
+ This predicate tests whether expression can be
+ parsed as JSON, possibly of a specified type.
+ If SCALAR or ARRAY or
+ OBJECT is specified, the
+ test is whether or not the JSON is of that particular type. If
+ WITH UNIQUE is specified, then an any object in the
+ expression is also tested to see if it
+ has duplicate keys.
+
+
-SELECT JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)');
- json_exists
--------------
- t
-(1 row)
-
-
-
- Note the difference between strict and lax modes
- if the required item does not exist:
-
-
--- Strict mode with ERROR on ERROR clause
-SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR);
-ERROR: Invalid SQL/JSON subscript
-(1 row)
-
-
-
--- Lax mode
-SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR);
- json_exists
--------------
- f
-(1 row)
-
-
-
--- Strict mode using the default value for the ON ERROR clause
-SELECT JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]');
- json_exists
--------------
- f
-(1 row)
-
-
-
-
-
-
- JSON_VALUE
- json_value
-
-
-JSON_VALUE (
- context_item, path_expression PASSING { value AS varname } , ...
- RETURNING data_type
- { ERROR | NULL | DEFAULT expression } ON EMPTY
- { ERROR | NULL | DEFAULT expression } ON ERROR
-)
-
-
-
- Description
-
-
- The JSON_VALUE function extracts a value from the provided
- JSON data and converts it to an SQL scalar.
- If the specified JSON path expression returns more than one
- SQL/JSON item, an error occurs. To extract
- an SQL/JSON array or object, use .
-
-
-
-
- Parameters
-
-
-
-
-
- context_item, path_expression PASSING { value AS varname } , ...
-
-
-
-
- The input data to query, the JSON path expression defining the query, and an optional PASSING clause.
- For details, see .
-
-
-
-
-
-
- RETURNING data_type
-
-
-
- The output clause that specifies the data type of the returned value.
- Out of the box, PostgreSQL
- supports the following types: json, jsonb,
- bytea, and character string types (text, char,
- varchar, and nchar).
- The extracted value must be a single SQL/JSON scalar item
- and have a cast to the specified type. Otherwise, an error occurs.
- By default, JSON_VALUE returns a string
- of the text type.
-
-
-
-
-
-
- { ERROR | NULL | DEFAULT expression } ON EMPTY
-
-
-
- Defines the return value if no JSON value is found. The default is
- NULL. If you use
- DEFAULT expression,
- the provided expression is
- evaluated and cast to the type specified in the RETURNING clause.
-
-
-
-
-
-
- { ERROR | NULL | DEFAULT expression } ON ERROR
-
-
-
- Defines the return value if an unhandled error occurs. The default is
- NULL. If you use
- DEFAULT expression,
- the provided expression is
- evaluated and cast to the type specified in the RETURNING clause.
-
-
-
-
-
-
-
-
- Examples
-
-
- Extract an SQL/JSON value and return it as an SQL
- scalar of the specified type. Note that
- JSON_VALUE can only return a
- single scalar, and the returned value must have a
- cast to the specified return type:
-
-
-
-SELECT JSON_VALUE('"123.45"', '$' RETURNING float);
- json_value
-------------
- 123.45
-(1 row)
-
-SELECT JSON_VALUE('123.45', '$' RETURNING int ERROR ON ERROR);
- json_value
-------------
- 123
-(1 row)
-
-SELECT JSON_VALUE('"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date);
- json_value
-------------
- 2015-02-01
-(1 row)
-
-SELECT JSON_VALUE('"123.45"', '$' RETURNING int ERROR ON ERROR);
-ERROR: invalid input syntax for integer: "123.45"
-
-SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
-
-SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
-ERROR: more than one SQL/JSON item
-
-
-
- If the path expression returns an array, an object, or
- multiple SQL/JSON items, an error is returned, as specified
- in the ON ERROR clause:
-
-
-SELECT JSON_VALUE(jsonb '[1]', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
-
-SELECT JSON_VALUE(jsonb '{"a": 1}', 'strict $' ERROR ON ERROR);
-ERROR: SQL/JSON scalar required
-
-SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' ERROR ON ERROR);
-ERROR: more than one SQL/JSON item
-
-SELECT JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 1 ON ERROR);
-1
-
-
-
-
-
-
- JSON_QUERY
- json_query
-
-
-JSON_QUERY (
- context_item, path_expression PASSING { value AS varname } , ...
- RETURNING data_type FORMAT JSON ENCODING UTF8
- { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAY WRAPPER
- { KEEP | OMIT } QUOTES ON SCALAR STRING
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON EMPTY
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON ERROR
-)
-
-
-
- Description
-
-
- The JSON_QUERY function extracts an SQL/JSON
- array or object from JSON data. This function must return
- a JSON string, so if the path expression returns a scalar or multiple SQL/JSON
- items, you must wrap the result using the WITH WRAPPER clause.
- To extract a single SQL/JSON value, you can use .
-
-
-
-
- Parameters
-
-
-
-
-
- context_item, path_expression PASSING { value AS varname } , ...
-
-
-
-
- The input data to query, the JSON path expression defining the query, and an optional PASSING clause.
- For details, see .
-
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the data type of the returned value.
- For details, see .
-
-
-
-
-
-
- { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAY WRAPPER
-
-
-
- Defines whether to wrap a returned sequence of SQL/JSON
- items into an SQL/JSON array.
-
-
-
- WITHOUT WRAPPER
-
-
- Do not wrap the result.
- This is the default behavior if the WRAPPER
- clause is omitted.
-
-
-
-
- WITH UNCONDITIONAL WRAPPER
-
-
- Always wrap the result.
-
-
-
-
- WITH CONDITIONAL WRAPPER
-
-
- Wrap the result if the path
- expression returns anything other than a single
- SQL/JSON array or object.
-
-
-
-
-
- Optionally, you can add the ARRAY keyword for semantic clarity.
-
-
- You cannot use this clause together with the ON EMPTY clause.
-
-
-
-
-
-
-
- { KEEP | OMIT } QUOTES ON SCALAR STRING
-
-
-
- Defines whether to keep or omit quotes if a scalar string is returned.
- By default, scalar strings are returned with quotes. Using this
- clause together with the WITH WRAPPER clause is not allowed.
-
-
- Optionally, you can add the ON SCALAR STRING keywords for semantic clarity.
-
-
-
-
-
-
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON EMPTY
-
-
-
- Defines the return value if no JSON value is found. The default is NULL.
- If you use EMPTY ARRAY or EMPTY OBJECT,
- an empty JSON array [] or object {} is returned, respectively.
- If you use DEFAULT expression,
- the provided expression is evaluated and cast
- to the type specified in the RETURNING clause.
-
-
- You cannot use this clause together with the WRAPPER clause.
-
-
-
-
-
-
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON ERROR
-
-
-
- Defines the return value if an unhandled error occurs. The default is NULL.
- If you use EMPTY ARRAY or EMPTY OBJECT,
- an empty JSON array [] or object {} are returned, respectively.
- If you use DEFAULT expression,
- the provided expression is evaluated and cast
- to the type specified in the RETURNING clause.
-
-
-
-
-
-
-
-
- Examples
-
-
- Extract all film genres listed in the my_films table:
-
-
-SELECT
- JSON_QUERY(js, '$.favorites[*].kind' WITH WRAPPER ERROR ON ERROR)
-FROM my_films;
- json_query
-------------
- ["comedy", "horror", "thriller", "drama"]
-(1 row)
-
-
-
- Note that the same query will result in an error if you omit the
- WITH WRAPPER clause, as it returns multiple SQL/JSON items:
-
-
-SELECT
- JSON_QUERY(js, '$.favorites[*].kind' ERROR ON ERROR)
-FROM my_films;
-ERROR: more than one SQL/JSON item
-
-
-
- Compare the effect of different WRAPPER clauses:
-
-
-SELECT
- js,
- JSON_QUERY(js, 'lax $[*]') AS "without",
- JSON_QUERY(js, 'lax $[*]' WITH WRAPPER) AS "with uncond",
- JSON_QUERY(js, 'lax $[*]' WITH CONDITIONAL WRAPPER) AS "with cond"
+SELECT js,
+ js IS JSON "json?",
+ js IS JSON SCALAR "scalar?",
+ js IS JSON OBJECT "object?",
+ js IS JSON ARRAY "array?"
FROM
- (VALUES (jsonb '[]'), ('[1]'), ('[[1,2,3]]'), ('[{"a": 1}]'), ('[1, null, "2"]')) foo(js);
- js | without | with uncond | with cond
-----------------+-----------+----------------+----------------
- [] | (null) | (null) | (null)
- [1] | 1 | [1] | [1]
- [[1, 2, 3]] | [1, 2, 3] | [[1, 2, 3]] | [1, 2, 3]
- [{"a": 1}] | {"a": 1} | [{"a": 1}] | {"a": 1}
- [1, null, "2"] | (null) | [1, null, "2"] | [1, null, "2"]
-(5 rows)
+(VALUES ('123'), ('"abc"'), ('{"a": "b"}'),
+('[1,2]'),('abc')) foo(js);
+ js | json? | scalar? | object? | array?
+------------+-------+---------+---------+--------
+ 123 | t | t | f | f
+ "abc" | t | t | f | f
+ {"a": "b"} | t | f | t | f
+ [1,2] | t | f | f | t
+ abc | f | f | f | f
-
-Compare quote handling for scalar types with and without the OMIT QUOTES clause:
-
-
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text);
- json_query
-------------
- "aaa"
-(1 row)
-
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING text OMIT QUOTES);
- json_query
-------------
- aaa
-(1 row)
-
-
-
-
-
- IS JSON
- is_json
-
-
-expression
- IS NOT JSON
- { VALUE | SCALAR | ARRAY | OBJECT }
- { WITH | WITHOUT } UNIQUE KEYS
-
-
-
- Description
+
+
+
+
+ json_serialize (
+ expressionFORMAT JSONENCODING UTF8
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8)
+
+
+ Transforms an SQL/JSON value into a character or binary string. The
+ expression can be of any JSON type, any
+ character string type, or bytea in UTF8 encoding.
+ The returned type can be any character string type or
+ bytea. The default is text.
+
+
+ json_serialize('{ "a" : 1 } ' RETURNING bytea)
+ \x7b20226122203a2031207d20
+
+
+
+
+
- The IS JSON predicate tests whether the provided value is valid
- JSON data. If you provide a specific JSON data type as a parameter,
- you can check whether the value belongs to this type.
- You can also use this predicate in the IS NOT JSON form.
- The return values are:
-
-
-
- t if the value satisfies the specified condition.
-
-
-
-
- f if the value does not satisfy the specified condition.
-
-
-
+ details the SQL/JSON
+ functions that can be used to query JSON data, except
+ for json_table.
-
-
- Parameters
+
+
+ SQL/JSON paths can only be applied to the jsonb type, so it
+ might be necessary to cast the context_item
+ argument of these functions to jsonb.
+
+
-
-
-
-
- expression
-
-
-
-
- The input clause defining the value to test. You can provide the values
- of json, jsonb,
- bytea, or character string types.
-
-
-
-
-
-
- VALUE | SCALAR | ARRAY | OBJECT
-
-
-
-
- Specifies the JSON data type to test for:
-
-
-
- VALUE (default) — any JSON type.
-
-
-
-
- SCALAR — JSON number, string, or boolean.
-
-
-
-
- ARRAY — JSON array.
-
-
-
-
- OBJECT — JSON object.
-
-
-
-
-
-
-
-
-
- { WITH | WITHOUT } UNIQUE KEYS
-
-
- Defines whether duplicate keys are allowed:
-
-
-
- WITHOUT (default) — the
- JSON object can contain duplicate keys.
-
-
-
-
- WITH — duplicate keys are not allowed.
- If the input data contains duplicate keys, it is considered to be invalid JSON.
-
-
-
- Optionally, you can add the KEYS keyword for semantic clarity.
+
+ SQL/JSON Query Functions
+
+
+
+
+ Function signature
+
+
+ Description
+
+
+ Example(s)
+
+
+
+
+
+
+ json_exists
+ json_exists (
+ context_item, path_expressionPASSING { valueASvarname } , ...
+ RETURNINGdata_type
+ { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR)
+
+
+ Returns true if the SQL/JSON path_expression
+ applied to the context_item using the
+ values yields any items.
+ The ON ERROR clause specifies what is returned if
+ an error occurs. Note that if the path_expression
+ is strict, an error is generated if it yields no items.
+ The default value is UNKNOWN which causes a NULL
+ result.
+
+
+ json_exists(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)')
+ t
+
+
+ json_exists(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR)
+ f
+
+
+ json_exists(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR)
+ ERROR: jsonpath array subscript is out of bounds
+
+
+
+
+ json_value
+ json_value (
+ context_item, path_expression
+ PASSING { valueASvarname } , ...
+ RETURNINGdata_type
+ { ERROR | NULL | DEFAULTexpression } ON EMPTY
+ { ERROR | NULL | DEFAULTexpression } ON ERROR)
+
+
+ Returns the result of applying the
+ path_expression to the
+ context_item using the
+ values. The extracted value must be
+ a single SQL/JSON scalar item. For results that
+ are objects or arrays, use the json_query
+ instead.
+ The returned data_type has the same semantics
+ as for constructor functions like json_objectagg.
+ The default returned type is text.
+ The ON EMPTY clause specifies the behavior if the
+ path_expression yields no value at all.
+ The ON ERROR clause specifies the behavior if an
+ error occurs, as a result of either the evaluation or the application
+ of the ON EMPTY clause.
+
+
+ json_value(jsonb '"123.45"', '$' RETURNING float)
+ 123.45
+
+
+ json_value(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date)
+ 2015-02-01
+
+
+ json_value(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR)
+ 9
+
+
+
+
+ json_query
+ json_query (
+ context_item, path_expressionPASSING { valueASvarname } , ...
+ RETURNINGdata_typeFORMAT JSONENCODING UTF8
+ { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAYWRAPPER
+ { KEEP | OMIT } QUOTESON SCALAR STRING
+ { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULTexpression } ON EMPTY
+ { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULTexpression } ON ERROR)
-
-
-
+
+ Returns the result of applying the
+ path_expression to the
+ context_item using the
+ values.
+ This function must return a JSON string, so if the path expression
+ returns multiple SQL/JSON items, you must wrap the result using the
+ WITH WRAPPER clause. If the wrapper is
+ UNCONDITIONAL, an array wrapper will always
+ be applied, even if the returned value is already a single JSON object
+ or array, but if it is CONDITIONAL it will not be
+ applied to a single array or object. UNCONDITIONAL
+ is the default.
+ If the result is a a scalar string, by default the value returned will have
+ surrounding quotes making it a valid JSON value. However, this behavior
+ is reversed if OMIT QUOTES is specified.
+ The ON ERROR and ON EMPTY
+ clauses have similar semantics to those clauses for
+ json_value.
+ The returned data_type has the same semantics
+ as for constructor functions like json_objectagg.
+ The default returned type is text.
+
+
+ json_query(jsonb '[1,[2,3],null]', 'lax $[*][1]' WITH CONDITIONAL WRAPPER)
+ [3]
+
+
+
+
+
-
+
-
- Examples
+
+ JSON_TABLE
+
+ json_table
+
-
- Compare the result returned by the IS JSON
- predicate for different data types:
-
-
-SELECT
- js,
- js IS JSON "is json",
- js IS NOT JSON "is not json",
- js IS JSON SCALAR "is scalar",
- js IS JSON OBJECT "is object",
- js IS JSON ARRAY "is array"
-FROM
- (VALUES ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'), ('abc')) foo(js);
+
+ json_table is an SQL/JSON function which
+ queries JSON data
+ and presents the results as a relational view, which can be accessed as a
+ regular SQL table. You can only use json_table inside the
+ FROM clause of a SELECT statement.
+
- js | is json | is not json | is scalar | is object | is array
-------------+---------+-------------+-----------+-----------|-------------
- 123 | t | f | t | f | f
- "abc" | t | f | t | f | f
- {"a": "b"} | t | f | f | t | f
- [1,2] | t | f | f | f | t
- abc | f | t | f | f | f
-(5 rows)
-
-
-
+
+ Taking JSON data as input, json_table uses
+ a path expression to extract a part of the provided data that
+ will be used as a row pattern for the
+ constructed view. Each SQL/JSON item at the top level of the row pattern serves
+ as the source for a separate row in the constructed relational view.
+
-
- JSON_TABLE
- json_table
+
+ To split the row pattern into columns, json_table
+ provides the COLUMNS clause that defines the
+ schema of the created view. For each column to be constructed,
+ this clause provides a separate path expression that evaluates
+ the row pattern, extracts a JSON item, and returns it as a
+ separate SQL value for the specified column. If the required value
+ is stored in a nested level of the row pattern, it can be extracted
+ using the NESTED PATH subclause. Joining the
+ columns returned by NESTED PATH can add multiple
+ new rows to the constructed view. Such rows are called
+ child rows, as opposed to the parent row
+ that generates them.
+
-
-JSON_TABLE (
- context_item, path_expression AS json_path_name PASSING { value AS varname } , ...
- COLUMNS ( json_table_column, ... )
-
- PLAN ( json_table_plan ) |
- PLAN DEFAULT ( { INNER | OUTER } , { CROSS | UNION }
- | { CROSS | UNION } , { INNER | OUTER } )
-
-)
-
-where json_table_column is:
-
- nametype PATH json_path_specification
- { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAY WRAPPER
- { KEEP | OMIT } QUOTES ON SCALAR STRING
- { ERROR | NULL | DEFAULT expression } ON EMPTY
- { ERROR | NULL | DEFAULT expression } ON ERROR
- | nametype FORMAT json_representation
- PATH json_path_specification
- { WITHOUT | WITH { CONDITIONAL | UNCONDITIONAL } } ARRAY WRAPPER
- { KEEP | OMIT } QUOTES ON SCALAR STRING
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON EMPTY
- { ERROR | NULL | EMPTY { ARRAY | OBJECT } | DEFAULT expression } ON ERROR
- | nametype EXISTS PATH json_path_specification
- { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR
- | NESTED PATH json_path_specification AS path_name
- COLUMNS ( json_table_column, ... )
- | name FOR ORDINALITY
-
-json_table_plan is:
-
- json_path_name { OUTER | INNER } json_table_plan_primary
- | json_table_plan_primary { UNION json_table_plan_primary } ...
- | json_table_plan_primary { CROSS json_table_plan_primary } ...
-
-json_table_plan_primary is:
-
- json_path_name | ( json_table_plan )
+
+ The rows produced by JSON_TABLE are laterally
+ joined to the row that generated them, so you do not have to explicitly join
+ the constructed view with the original table holding JSON
+ data. Optionally, you can specify how to join the columns returned
+ by NESTED PATH using the PLAN clause.
+
-
-
-
- Description
-
-
- The JSON_TABLE function queries JSON data
- and presents the results as a relational view, which can be accessed as a
- regular SQL table. You can only use JSON_TABLE inside the
- FROM clause of the SELECT statement
- for an SQL table.
-
-
-
- Taking JSON data as input, JSON_TABLE uses
- a path expression to extract a part of the provided data that
- will be used as a row pattern for the
- constructed view. Each SQL/JSON item at the top level of the row pattern serves
- as the source for a separate row in the constructed relational view.
-
-
-
- To split the row pattern into columns, JSON_TABLE
- provides the COLUMNS clause that defines the
- schema of the created view. For each column to be constructed,
- this clause provides a separate path expression that evaluates
- the row pattern, extracts a JSON item, and returns it as a
- separate SQL value for the specified column. If the required value
- is stored in a nested level of the row pattern, it can be extracted
- using the NESTED PATH subclause. Joining the
- columns returned by NESTED PATH can add multiple
- new rows to the constructed view. Such rows are called
- child rows, as opposed to the parent row
- that generates them.
-
-
-
- The rows produced by JSON_TABLE are laterally
- joined to the row that generated them, so you do not have to explicitly join
- the constructed view with the original table holding JSON
- data. Optionally, you can specify how to join the columns returned
- by NESTED PATH using the PLAN clause.
-
-
-
- Each NESTED PATH clause can generate one or more
- columns, which are considered to be siblings
- to each other. In relation to the columns returned directly from the row
- expression or by the NESTED PATH clause of a
- higher level, these columns are child columns.
- Sibling columns are always joined first. Once they are processed,
- the resulting rows are joined to the parent row.
-
-
-
-
- Parameters
+
+ Each NESTED PATH clause can generate one or more
+ columns. Columns produced by NESTED PATHs at the
+ same level are considered to be siblings,
+ while a column produced by a NESTED PATH is
+ considered to be a child of the column produced by and
+ NESTED PATH or row expression at a higher level.
+ Sibling columns are always joined first. Once they are processed,
+ the resulting rows are joined to the parent row.
+
- context_item, path_expression AS json_path_name PASSING { value AS varname } , ...
+ context_item, path_expressionASjson_path_namePASSING { valueASvarname } , ...
-
The input data to query, the JSON path expression defining the query,
- and an optional PASSING clause, as described in
- . The result of the input data
+ and an optional PASSING clause, which can provide data
+ values to the path_expression.
+ The result of the input data
evaluation is called the row pattern. The row
pattern is used as the source for row values in the constructed view.
@@ -19436,7 +18122,7 @@ where json_table_column is:
- COLUMNS( json_table_column, ... )
+ COLUMNS( json_table_column, ... )
@@ -19444,15 +18130,15 @@ where json_table_column is:
The COLUMNS clause defining the schema of the
constructed view. In this clause, you must specify all the columns
to be filled with SQL/JSON items.
- The json_table_column
+ The json_table_column
expression has the following syntax variants:
- nametype
- PATH json_path_specification
+ nametype
+ PATHjson_path_specification
@@ -19462,7 +18148,7 @@ where json_table_column is:
The provided PATH expression parses the
- row pattern defined by json_api_common_syntax
+ row pattern defined by json_api_common_syntax
and fills the column with produced SQL/JSON items, one for each row.
If the PATH expression is omitted,
JSON_TABLE uses the
@@ -19471,30 +18157,22 @@ where json_table_column is:
In this case, the column name must correspond to one of the
keys within the SQL/JSON item produced by the row pattern.
-
- Internally, and
- are used to produce resulting values.
- is used for JSON, array, and
- composite column types, is used for
- other types.
-
Optionally, you can add ON EMPTY and
ON ERROR clauses to define how to handle missing values
or structural errors.
WRAPPER and QUOTES clauses can only
be used with JSON, array, and composite types.
- These clauses have the same syntax and semantics as in
- and
- .
+ These clauses have the same syntax and semantics as for
+ json_value and json_query.
- nametype FORMAT json_representation
- PATH json_path_specification
+ nametypeFORMATjson_representation
+ PATHjson_path_specification
@@ -19504,35 +18182,29 @@ where json_table_column is:
The provided PATH expression parses the
- row pattern defined by json_api_common_syntax
+ row pattern defined by json_api_common_syntax
and fills the column with produced SQL/JSON items, one for each row.
If the PATH expression is omitted,
JSON_TABLE uses the
- $.name path expression,
- where name is the provided column name.
+ $.name path expression,
+ where name is the provided column name.
In this case, the column name must correspond to one of the
keys within the SQL/JSON item produced by the row pattern.
-
- Internally, is used to produce
- resulting values.
-
Optionally, you can add WRAPPER, QUOTES,
ON EMPTY and ON ERROR clauses
to define additional settings for the returned SQL/JSON items.
These clauses have the same syntax and semantics as
- in .
+ for json_query.
-
- nametype
- EXISTS PATH json_path_specification
-
+ nametype
+ EXISTSPATHjson_path_specification
@@ -19541,10 +18213,10 @@ where json_table_column is:
The provided PATH expression parses the
- row pattern defined by json_api_common_syntax,
+ row pattern defined by json_api_common_syntax,
checks whether any SQL/JSON items were returned, and fills the column with
resulting boolean value, one for each row.
- The specified type should have cast from
+ The specified type should have cast from
boolean.
If the PATH expression is omitted,
JSON_TABLE uses the
@@ -19553,16 +18225,16 @@ where json_table_column is:
Optionally, you can add ON ERROR clause to define
- error behavior. This clause have the same syntax and semantics as in
- .
+ error behavior. This clause has the same syntax and semantics as
+ for json_exists.
- NESTED PATH json_path_specification AS json_path_name
- COLUMNS ( json_table_column, ... )
+ NESTED PATHjson_path_specificationASjson_path_name
+ COLUMNS ( json_table_column, ... )
@@ -19570,7 +18242,7 @@ where json_table_column is:
Extracts SQL/JSON items from nested levels of the row pattern,
generates one or more columns as defined by the COLUMNS
subclause, and inserts the extracted SQL/JSON items into each row of these columns.
- The json_table_column expression in the
+ The json_table_column expression in the
COLUMNS subclause uses the same syntax as in the
parent COLUMNS clause.
@@ -19586,14 +18258,14 @@ where json_table_column is:
You can use the PLAN clause to define how
- to join the columns returned by NESTED PATH clauses.
+ to join the columns returned by NESTED PATH clauses.
- name FOR ORDINALITY
+ nameFOR ORDINALITY
@@ -19612,13 +18284,13 @@ where json_table_column is:
- AS json_path_name
+ ASjson_path_name
- The optional json_path_name serves as an
- identifier of the provided json_path_specification.
+ The optional json_path_name serves as an
+ identifier of the provided json_path_specification.
The path name must be unique and distinct from the column names.
When using the PLAN clause, you must specify the names
for all the paths, including the row pattern. Each path name can appear in
@@ -19629,12 +18301,12 @@ where json_table_column is:
- PLAN ( json_table_plan )
+ PLAN ( json_table_plan )
- Defines how to join the data returned by NESTED PATH
+ Defines how to join the data returned by NESTED PATH
clauses to the constructed view.
@@ -19687,9 +18359,8 @@ where json_table_column is:
- Use FULL OUTER JOIN ON FALSE, so that both parent and child
- rows are included into the output, with NULL values inserted
- into both child and parent columns for all missing values.
+ Generate one row for each value produced by each of the sibling
+ columns. The columns from the other siblings are set to null.
This is the default option for joining sibling columns.
@@ -19704,9 +18375,7 @@ where json_table_column is:
- Use CROSS JOIN, so that the output includes
- a row for every possible combination of rows from the left-hand
- and the right-hand columns.
+ Generate one row for each combination of values from the sibling columns.
@@ -19718,26 +18387,55 @@ where json_table_column is:
- PLAN DEFAULT ( option, ... )
+ PLAN DEFAULT ( OUTER | INNER, UNION | CROSS )
- Overrides the default joining plans. The INNER and
- OUTER options define the joining plan for parent/child
- columns, while UNION and CROSS
- affect the sibling columns. You can override the default plans for all columns at once.
- Even though the path names are not included into the PLAN DEFAULT
- clause, they must be provided for all the paths to conform to
- the SQL/JSON standard.
+ The terms can also be specified in reverse order. The
+ INNER or OUTER option defines the
+ joining plan for parent/child columns, while UNION or
+ CROSS affects joins of sibling columns. This form
+ of PLAN overrides the default plan for
+ all columns at once. Even though the path names are not included in the
+ PLAN DEFAULT form, to conform to the SQL/JSON standard
+ they must be provided for all the paths if the PLAN
+ clause is used.
+
+
+ PLAN DEFAULT is simpler than specifying a complete
+ PLAN, and is often all that is required to get the desired
+ output.
-
-
- Examples
+ Examples
+
+ In these examples the following small table storing some JSON data will be used:
+
+CREATE TABLE my_films ( js jsonb );
+
+INSERT INTO my_films VALUES (
+'{ "favorites" : [
+ { "kind" : "comedy", "films" : [
+ { "title" : "Bananas",
+ "director" : "Woody Allen"},
+ { "title" : "The Dinner Game",
+ "director" : "Francis Veber" } ] },
+ { "kind" : "horror", "films" : [
+ { "title" : "Psycho",
+ "director" : "Alfred Hitchcock" } ] },
+ { "kind" : "thriller", "films" : [
+ { "title" : "Vertigo",
+ "director" : "Alfred Hitchcock" } ] },
+ { "kind" : "drama", "films" : [
+ { "title" : "Yojimbo",
+ "director" : "Akira Kurosawa" } ] }
+ ] }');
+
+
Query the my_films table holding
some JSON data about the films and create a view that
@@ -19757,7 +18455,7 @@ SELECT jt.* FROM
1 | comedy | Bananas | Woody Allen
1 | comedy | The Dinner Game | Francis Veber
2 | horror | Psycho | Alfred Hitchcock
- 3 | thriller | Vertigo | Hitchcock
+ 3 | thriller | Vertigo | Alfred Hitchcock
4 | drama | Yojimbo | Akira Kurosawa
(5 rows)
@@ -19788,194 +18486,14 @@ FROM
PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
) AS jt
WHERE kind1 > kind2 AND director1 = director2;
-
-
-
-
-
-
- Serializing JSON data
-
-
-
- JSON_SERIALIZE
-
-
-
-
-
- JSON_SERIALAIZE
- json_serialize
-
-
-JSON_SERIALIZE (
- expression FORMAT JSON ENCODING UTF8
- RETURNING data_type FORMAT JSON ENCODING UTF8
-)
-
-
-
- Description
-
-
- The JSON_SERIALIZE function transforms an SQL/JSON value
- into a character or binary string.
-
-
-
-
- Parameters
-
-
-
- expression FORMAT JSON ENCODING UTF8
-
-
-
- JSON typed expression that provides a data for
- serialization. Accepted JSON types (json and
- jsonb), any character string types (text,
- char, etc.), binary strings (bytea) in
- UTF8 encoding.
- For null input, null value is returned.
-
-
- The optional FORMAT clause is provided to conform
- to the SQL/JSON standard.
-
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the target character or binary string
- type (text, char, bytea, etc.).
-
-
-
-
-
-
-
- Notes
-
- Alternatively, you can construct JSON values simply
- using PostgreSQL-specific casts to
- json and jsonb types.
-
-
-
- Examples
-
- Construct serialized JSON using the provided strings:
-
-
-SELECT JSON_SERIALIZE(JSON_SCALAR('foo'));
- json_serialize
-----------------
- "foo"
-(1 row)
-
-SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2]}' RETURNING bytea);
- json_serialize
---------------------------------------------------------------
- \x7b22666f6f223a2022626172222c202262617a223a205b312c20325d7d
+ director | title1 | kind1 | title2 | kind2
+------------------+---------+----------+--------+--------
+ Alfred Hitchcock | Vertigo | thriller | Psycho | horror
(1 row)
-
-
-
-
-
-
- SQL/JSON Common Clauses
-
-
- SQL/JSON Input Clause
-
-
-
-
- context_item, path_expression
- PASSING { value AS varname } , ...
-
-
-
- The input clause specifies the JSON data to query and
- the exact query path to be passed to SQL/JSON query functions:
-
-
-
- The context_item is the JSON data to query.
-
-
-
- Currently for functions JSON_VALUE,
- JSON_EXISTS, and JSON_QUERY
- this must be a value of type jsonb.
-
-
-
-
-
- The path_expression is an SQL/JSON path
- expression that specifies the items to be retrieved from the JSON
- data. For details on path expression syntax, see
- .
-
-
-
-
- The optional PASSING clause provides the values for
- the named variables used in the SQL/JSON path expression.
-
-
-
-
- The input clause is common for all SQL/JSON query functions.
-
-
-
-
-
-
-
-
- SQL/JSON Output Clause
-
-
-
-
- RETURNING data_type FORMAT JSON ENCODING UTF8
-
-
-
- The output clause that specifies the return type of the generated
- JSON object. Out of the box, PostgreSQL
- supports the following types: json, jsonb,
- bytea, and character string types (text, char,
- varchar, and nchar).
- To use another type, you must create a cast from json to that type.
- By default, the json type is returned.
-
-
- The optional FORMAT clause is provided to conform to the SQL/JSON standard.
-
-
- The output clause is common for both constructor and query SQL/JSON functions.
-
-
-
-
-
-
-
-
+
@@ -22684,8 +21202,8 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
- In addition to the JSON aggregates shown here, see the JSON_OBJECTAGG
- and JSON_ARRAYAGG constructors in .
+ In addition to the JSON aggregates shown here, see the json_objectagg
+ and json_arrayagg constructors in .