From a6baa4baddd5f111bc59d8f5ed5cadbb2d91e98d Mon Sep 17 00:00:00 2001 From: Andrew Dunstan Date: Thu, 7 Apr 2022 23:36:50 -0400 Subject: [PATCH] Documentation for SQL/JSON features This documents the features added in commits f79b803dcc, f4fb45d15c, 33a377608f, 1a36bc9dba, 606948b058, 49082c2cc3, 4e34747c88, and fadb48b00e. I have cleaned up the aggregate section of the submitted docs, but there is still a deal of copy editing required. However, I thought it best to have some documentation sooner rather than later so testers can have a better idea what they are playing with. Nikita Glukhov Reviewers have included (in no particular order) Andres Freund, Alexander Korotkov, Pavel Stehule, Andrew Alsup, Erik Rijkers, Zhihong Yu, Himanshu Upadhyaya, Daniel Gustafsson, Justin Pryzby. Discussion: https://postgr.es/m/cd0bb935-0158-78a7-08b5-904886deac4b@postgrespro.ru Discussion: https://postgr.es/m/7e2cb85d-24cf-4abb-30a5-1a33715959bd@postgrespro.ru --- doc/src/sgml/func.sgml | 2542 +++++++++++++++++++++++++++++++++++++++- 1 file changed, 2540 insertions(+), 2 deletions(-) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 2f7aff9f21..569c78e792 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -17564,6 +17564,2421 @@ $.* ? (@ like_regex "^\\d+$") + + + 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. + + + + 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. + + + + + 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. + 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. + + + + + + JSON + + + + + JSON_SCALAR + + + + + JSON_OBJECT + + + + + JSON_OBJECTAGG + + + + + JSON_ARRAY + + + + + JSON_ARRAYAGG + + + + + + <literal>JSON</literal> + 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 a JSON 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 + + + + + + <literal>JSON_SCALAR</literal> + 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 a JSON from the provided values 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) + + + + + + <literal>JSON_OBJECT</literal> + 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: + + +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) + + + + + + <literal>JSON_OBJECTAGG</literal> + 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. If you specify a GROUP BY + or an ORDER BY clause, this function returns a separate JSON object + for each table row. + + + + + 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) + + + + + + <literal>JSON_ARRAY</literal> + 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) + + + + + + <literal>JSON_ARRAYAGG</literal> + 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: + + + + NULLNULL 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 . + + + + + + IS JSON + + + + + JSON_EXISTS + + + + + JSON_VALUE + + + + + JSON_QUERY + + + + + JSON_TABLE + + + + + + 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" } ] } + ] }'); + + + + + <literal>JSON_EXISTS</literal> + json_exists + + +JSON_EXISTS ( + context_item, path_expression PASSING { value AS varname } , ... + RETURNING data_type + { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR +) + + + + Description + + + 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: + + +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) + + + + + + + <literal>JSON_VALUE</literal> + 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 + + + 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 + + + + + + + <literal>JSON_QUERY</literal> + 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 + + + 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 a 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" +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) + + +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) + + + + + + <literal>IS JSON</literal> + is_json + + +expression + IS NOT JSON + { VALUE | SCALAR | ARRAY | OBJECT } + { WITH | WITHOUT } UNIQUE KEYS + + + + Description + + + 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. + + + + + + + + Parameters + + + + + + 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. + + + + + SCALARJSON number, string, or boolean. + + + + + ARRAYJSON array. + + + + + OBJECTJSON 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. + + + + + + + + + Examples + + + 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); + + 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) + + + + + + <literal>JSON_TABLE</literal> + json_table + + +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: + + name type 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 + | name type 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 + | name type 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 ) + + + + + Description + + + 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 + + + + + context_item, path_expression AS json_path_name PASSING { value AS varname } , ... + + + + + 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 + evaluation is called the row pattern. The row + pattern is used as the source for row values in the constructed view. + + + + + + + COLUMNS( json_table_column , ... ) + + + + + 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 + expression has the following syntax variants: + + + + + + name type + PATH json_path_specification + + + + + Inserts a single SQL/JSON item into each row of + the specified column. + + + The provided PATH expression parses the + 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. + 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 + . + + + + + + + name type FORMAT json_representation + PATH json_path_specification + + + + + Generates a column and inserts a composite SQL/JSON + item into each row of this column. + + + The provided PATH expression parses the + 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. + 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 . + + + + + + + + name type + EXISTS PATH json_path_specification + + + + + + Generates a column and inserts a boolean item into each row of this column. + + + The provided PATH expression parses the + 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 + boolean. + If the PATH expression is omitted, + JSON_TABLE uses the + $.name path expression, + where name is the provided column name. + + + Optionally, you can add ON ERROR clause to define + error behavior. This clause have the same syntax and semantics as in + . + + + + + + + NESTED PATH json_path_specification AS json_path_name + COLUMNS ( json_table_column , ... ) + + + + + 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 + COLUMNS subclause uses the same syntax as in the + parent COLUMNS clause. + + + + The NESTED PATH syntax is recursive, + so you can go down multiple nested levels by specifying several + NESTED PATH subclauses within each other. + It allows to unnest the hierarchy of JSON objects and arrays + in a single function invocation rather than chaining several + JSON_TABLE expressions in an SQL statement. + + + + You can use the PLAN clause to define how + to join the columns returned by NESTED PATH clauses. + + + + + + + name FOR ORDINALITY + + + + + Adds an ordinality column that provides sequential row numbering. + You can have only one ordinality column per table. Row numbering + is 1-based. For child rows that result from the NESTED PATH + clauses, the parent row number is repeated. + + + + + + + + + + + AS json_path_name + + + + + The optional json_path_name serves as an + identifier of the provided json_path_specification. + The path name must be unique and cannot coincide with 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 + the PLAN clause only once. + + + + + + + PLAN ( json_table_plan ) + + + + + Defines how to join the data returned by NESTED PATH + clauses to the constructed view. + + + To join columns with parent/child relationship, you can use: + + + + + INNER + + + + + Use INNER JOIN, so that the parent row + is omitted from the output if it does not have any child rows + after joining the data returned by NESTED PATH. + + + + + + + OUTER + + + + + Use LEFT OUTER JOIN, so that the parent row + is always included into the output even if it does not have any child rows + after joining the data returned by NESTED PATH, with NULL values + inserted into the child columns if the corresponding + values are missing. + + + This is the default option for joining columns with parent/child relationship. + + + + + + + To join sibling columns, you can use: + + + + + + UNION + + + + + 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. + + + This is the default option for joining sibling columns. + + + + + + + CROSS + + + + + 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. + + + + + + + + + + + + PLAN DEFAULT ( option , ... ) + + + + 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. + + + + + + + + Examples + + + Query the my_films table holding + some JSON data about the films and create a view that + distributes the film genre, title, and director between separate columns: + +SELECT jt.* FROM + my_films, + JSON_TABLE ( js, '$.favorites[*]' COLUMNS ( + id FOR ORDINALITY, + kind text PATH '$.kind', + NESTED PATH '$.films[*]' COLUMNS ( + title text PATH '$.title', + director text PATH '$.director'))) AS jt; +----+----------+------------------+------------------- + id | kind | title | director +----+----------+------------------+------------------- + 1 | comedy | Bananas | Woody Allen + 1 | comedy | The Dinner Game | Francis Veber + 2 | horror | Psycho | Alfred Hitchcock + 3 | thriller | Vertigo | Hitchcock + 4 | drama | Yojimbo | Akira Kurosawa + (5 rows) + + + + + Find a director that has done films in two different genres: + +SELECT + director1 AS director, title1, kind1, title2, kind2 +FROM + my_films, + JSON_TABLE ( js, '$.favorites' AS favs COLUMNS ( + NESTED PATH '$[*]' AS films1 COLUMNS ( + kind1 text PATH '$.kind', + NESTED PATH '$.films[*]' AS film1 COLUMNS ( + title1 text PATH '$.title', + director1 text PATH '$.director') + ), + NESTED PATH '$[*]' AS films2 COLUMNS ( + kind2 text PATH '$.kind', + NESTED PATH '$.films[*]' AS film2 COLUMNS ( + title2 text PATH '$.title', + director2 text PATH '$.director' + ) + ) + ) + PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2))) + ) AS jt + WHERE kind1 > kind2 AND director1 = director2; + + + + + + + + Serializing JSON data + + + + JSON_SERIALIZE + + + + + + <literal>JSON_SERIALAIZE</literal> + json_serialize + + +JSON_SERIALIZE ( + expression FORMAT JSON ENCODING UTF8 + RETURNING data_type FORMAT JSON ENCODING UTF8 +) + + + + Description + + + JSON_SERIALIZE function transforms a 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 a JSON the provided strings: + + +SELECT JSON_SERIALIZE(JSON_SCALAR('foo')); + json_serialize +---------------- + "foo" +(1 row) + +SELECT JSON_SERIALIZE('{"foo": "bar", "baz": [1, 2, 3]}' RETURNING bytea); + json_serialize +-------------------------------------------------------------------- + \x7b22666f6f223a2022626172222c202262617a223a205b312c20322c20335d7d +(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 other types, you must create the CAST from json for this 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. + + + + + + + + + @@ -19932,6 +22347,29 @@ SELECT NULLIF(value, '(none)') ... No + + + + json_agg_strict + + json_agg_strict ( anyelement ) + json + + + + jsonb_agg_strict + + jsonb_agg_strict ( anyelement ) + jsonb + + + Collects all the input values, skipping nulls, into a JSON array. + Values are converted to JSON as per to_json + or to_jsonb. + + No + + @@ -19953,13 +22391,101 @@ SELECT NULLIF(value, '(none)') ... Collects all the key/value pairs into a JSON object. Key arguments - are coerced to text; value arguments are converted as - per to_json or to_jsonb. + are coerced to text; value arguments are converted as per + to_json or to_jsonb Values can be null, but not keys. No + + + + json_object_agg_strict + + json_object_agg_strict ( + key "any", + value "any" ) + json + + + + jsonb_object_agg_strict + + jsonb_object_agg_strict ( + key "any", + value "any" ) + jsonb + + + Collects all the key/value pairs into a JSON object. Key arguments + are coerced to text; value arguments are converted as per + to_json or to_jsonb. + The key can not be null. If the + value is null then the entry is skipped, + + No + + + + + + json_object_agg_unique + + json_object_agg_unique ( + key "any", + value "any" ) + json + + + + jsonb_object_agg_unique + + jsonb_object_agg_unique ( + key "any", + value "any" ) + jsonb + + + Collects all the key/value pairs into a JSON object. Key arguments + are coerced to text; value arguments are converted as per + to_json or to_jsonb. + Values can be null, but not keys. + If there is a duplicate key an error is thrown. + + No + + + + + + json_object_agg_unique_strict + + json_object_agg_unique_strict ( + key "any", + value "any" ) + json + + + + jsonb_object_agg_unique_strict + + jsonb_object_agg_unique_strict ( + key "any", + value "any" ) + jsonb + + + Collects all the key/value pairs into a JSON object. Key arguments + are coerced to text; value arguments are converted as per + to_json or to_jsonb. + The key can not be null. If the + value is null then the entry is skipped, + If there is a duplicate key an error is thrown. + + No + + @@ -20133,7 +22659,12 @@ SELECT NULLIF(value, '(none)') ... The aggregate functions array_agg, json_agg, jsonb_agg, + json_agg_strict, jsonb_agg_strict, json_object_agg, jsonb_object_agg, + json_object_agg_strict, jsonb_object_agg_strict, + json_object_agg_unique, jsonb_object_agg_unique, + json_object_agg_unique_strict, + jsonb_object_agg_unique_strict, string_agg, and xmlagg, as well as similar user-defined aggregate functions, produce meaningfully different result values @@ -20153,6 +22684,13 @@ SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab; subquery's output to be reordered before the aggregate is computed. + + + In addition to the JSON aggregates shown here, see the JSON_OBJECTAGG + and JSON_ARRAYAGG constructors in . + + + ANY