diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 93ee3d4b60c..f9d7a8f9c35 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -18665,10 +18665,15 @@ $.* ? (@ like_regex "^\\d+$") JSON_QUERY(), and JSON_VALUE() described in can be used to query JSON documents. Each of these functions apply a - path_expression (the query) to a - context_item (the document); see + path_expression (an SQL/JSON path query) to a + context_item (the document). See for more details on what - path_expression can contain. + the path_expression can contain. The + path_expression can also reference variables, + whose values are specified with their respective names in the + PASSING clause that is supported by each function. + context_item can be a jsonb value + or a character string that can be successfully cast to jsonb. @@ -18691,37 +18696,48 @@ $.* ? (@ like_regex "^\\d+$") json_exists - json_exists ( - context_item, path_expression PASSING { value AS varname } , ... - { TRUE | FALSE | UNKNOWN | ERROR } ON ERROR ) + +JSON_EXISTS ( +context_item, path_expression + PASSING { value AS varname } , ... +{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR ) boolean + + + Returns true if the SQL/JSON path_expression - applied to the context_item using the - PASSING values yields any - items. + applied to the context_item yields any + items, false otherwise. + + The ON ERROR clause specifies the behavior if - an error occurs; the default is to return the boolean - FALSE value. Note that if the - path_expression is strict - and ON ERROR behavior is ERROR, - an error is generated if it yields no items. + an error occurs during path_expression + evaluation. Specifying ERROR will cause an error to + be thrown with the appropriate message. Other options include + returning boolean values FALSE or + TRUE or the value UNKNOWN which + is actually an SQL NULL. The default when no ON ERROR + clause is specified is to return the boolean value + FALSE. + + Examples: - select json_exists(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)') + JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > $x)' PASSING 2 AS x) t - select json_exists(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR) + JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR) f - select json_exists(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR) + JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR) ERROR: jsonpath array subscript is out of bounds @@ -18731,72 +18747,96 @@ ERROR: jsonpath array subscript is out of bounds 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 ) + +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 ) jsonb + + + Returns the result of applying the SQL/JSON path_expression to the - context_item using the - PASSING values. + context_item. + + - If the path expression returns multiple SQL/JSON items, it might be - necessary to wrap the result using the WITH WRAPPER - clause to make it a valid JSON string. If the wrapper is - UNCONDITIONAL, an array wrapper will always be - applied, even if the returned value is already a single JSON object - or an array. If it is CONDITIONAL, it will not be - applied to a single JSON object or an array. - UNCONDITIONAL is the default. + By default, the result is returned as a value of type jsonb, + though the RETURNING clause can be used to return + as some other type to which it can be successfully coerced. + + + + If the path expression may return multiple values, it might be necessary + to wrap those values using the WITH WRAPPER clause to + make it a valid JSON string, because the default behavior is to not wrap + them, as if WITHOUT WRAPPER were specified. The + WITH WRAPPER clause is by default taken to mean + WITH UNCONDITIONAL WRAPPER, which means that even a + single result value will be wrapped. To apply the wrapper only when + multiple values are present, specify WITH CONDITIONAL WRAPPER. + Getting multiple values in result will be treated as an error if + WITHOUT WRAPPER is specified. + + + If the result is a scalar string, by default, the returned value will be surrounded by quotes, making it a valid JSON value. It can be made explicit by specifying KEEP QUOTES. Conversely, quotes can be omitted by specifying OMIT QUOTES. - Note that OMIT QUOTES cannot be specified when - WITH WRAPPER is also specified. - - - The RETURNING clause can be used to specify the - data_type of the result value. By default, - the returned value will be of type jsonb. + To ensure that the result is a valid JSON value, OMIT QUOTES + cannot be specified when WITH WRAPPER is also + specified. + + The ON EMPTY clause specifies the behavior if - evaluating path_expression yields no value - at all. The default when ON EMPTY is not specified - is to return a null value. + evaluating path_expression yields an empty + set. The ON ERROR clause specifies the behavior + if an error occurs when evaluating path_expression, + when coercing the result value to the RETURNING type, + or when evaluating the ON EMPTY expression if the + path_expression evaluation returns an empty + set. + + - The ON ERROR clause specifies the - behavior if an error occurs when evaluating - path_expression, including the operation to - coerce the result value to the output type, or during the execution of - ON EMPTY behavior (that is caused by empty result - of path_expression evaluation). The default - when ON ERROR is not specified is to return a null - value. + For both ON EMPTY and ON ERROR, + specifying ERROR will cause an error to be thrown with + the appropriate message. Other options include returning an SQL NULL, an + empty array (EMPTY ARRAY), + an empty object (EMPTY OBJECT), or a user-specified + expression (DEFAULT expression) + that can be coerced to jsonb or the type specified in RETURNING. + The default when ON EMPTY or ON ERROR + is not specified is to return an SQL NULL value. + + Examples: - select json_query(jsonb '[1,[2,3],null]', 'lax $[*][1]' WITH CONDITIONAL WRAPPER) + JSON_QUERY(jsonb '[1,[2,3],null]', 'lax $[*][$off]' PASSING 1 AS off WITH CONDITIONAL WRAPPER) [3] - select json_query(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES); + JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES) [1, 2] - select json_query(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR); + JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR) ERROR: malformed array literal: "[1, 2]" @@ -18808,55 +18848,76 @@ DETAIL: Missing "]" after array dimensions. 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 ) + +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 ) text + + + Returns the result of applying the SQL/JSON path_expression to the - context_item using the - PASSING values. + context_item. + + - The extracted value must be a single SQL/JSON - scalar item; an error is thrown if that's not the case. If you expect - that extracted value might be an object or an array, use the - json_query function instead. + Only use JSON_VALUE() if the extracted value is + expected to be a single SQL/JSON scalar item; + getting multiple values will be treated as an error. If you expect that + extracted value might be an object or an array, use the + JSON_QUERY function instead. + + - The RETURNING clause can be used to specify the - data_type of the result value. By default, - the returned value will be of type text. + By default, the result, which must be a single scalar value, is + returned as a value of type text, though the + RETURNING clause can be used to return as some + other type to which it can be successfully coerced. + + The ON ERROR and ON EMPTY clauses have similar semantics as mentioned in the description of - json_query. + JSON_QUERY, except the set of values returned in + lieu of throwing an error is different. + + - Note that scalar strings returned by json_value + Note that scalar strings returned by JSON_VALUE always have their quotes removed, equivalent to specifying - OMIT QUOTES in json_query. + OMIT QUOTES in JSON_QUERY. + + Examples: - select json_value(jsonb '"123.45"', '$' RETURNING float) + JSON_VALUE(jsonb '"123.45"', '$' RETURNING float) 123.45 - select json_value(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date) + JSON_VALUE(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date) 2015-02-01 - select json_value(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR) + JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 as off) + 2 + + + JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR) 9 - + + @@ -18871,6 +18932,14 @@ DETAIL: Missing "]" after array dimensions. clause. + + + JSON_VALUE() returns an SQL NULL if + path_expression returns a JSON + null, whereas JSON_QUERY() returns + the JSON null as is. + +