SQL/JSON: Correctly enforce the default ON EMPTY behavior
Currently, when the ON EMPTY clause is not present, the ON ERROR
clause (implicit or explicit) dictates the behavior when jsonpath
evaluation in ExecEvalJsonExprPath() results in an empty sequence.
That is an oversight in the commit 6185c9737c
.
This commit fixes things so that a NULL is returned instead in that
case which is the default behavior when the ON EMPTY clause is not
present.
Reported-by: Markus Winand
Discussion: https://postgr.es/m/F7DD1442-265C-4220-A603-CB0DEB77E91D%40winand.at
This commit is contained in:
parent
0f271e8e8d
commit
03ec203164
5 changed files with 64 additions and 40 deletions
|
@ -4418,11 +4418,11 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
|
|||
|
||||
coerceJsonExprOutput(pstate, jsexpr);
|
||||
|
||||
if (func->on_empty)
|
||||
jsexpr->on_empty = transformJsonBehavior(pstate,
|
||||
func->on_empty,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
|
||||
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
/* Assume NULL ON ERROR when ON ERROR is not specified. */
|
||||
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
|
@ -4448,11 +4448,11 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
|
|||
|
||||
coerceJsonExprOutput(pstate, jsexpr);
|
||||
|
||||
if (func->on_empty)
|
||||
jsexpr->on_empty = transformJsonBehavior(pstate,
|
||||
func->on_empty,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
|
||||
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
/* Assume NULL ON ERROR when ON ERROR is not specified. */
|
||||
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
|
||||
JSON_BEHAVIOR_NULL,
|
||||
jsexpr->returning);
|
||||
|
@ -4464,6 +4464,13 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
|
|||
jsexpr->returning->typid = exprType(jsexpr->formatted_expr);
|
||||
jsexpr->returning->typmod = -1;
|
||||
}
|
||||
|
||||
/*
|
||||
* Assume EMPTY ON ERROR when ON ERROR is not specified.
|
||||
*
|
||||
* ON EMPTY cannot be specified at the top level but it can be for
|
||||
* the individual columns.
|
||||
*/
|
||||
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
|
||||
JSON_BEHAVIOR_EMPTY,
|
||||
jsexpr->returning);
|
||||
|
|
|
@ -219,17 +219,17 @@ FROM json_table_test vals
|
|||
|
||||
-- Test using casts in DEFAULT .. ON ERROR expression
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT '"foo1"'::jsonb::text ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT '"foo1"'::jsonb::text ON EMPTY));
|
||||
js1
|
||||
--------
|
||||
"foo1"
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo'::jsonb_test_domain ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo'::jsonb_test_domain ON EMPTY));
|
||||
ERROR: value for domain jsonb_test_domain violates check constraint "jsonb_test_domain_check"
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo1'::jsonb_test_domain ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo1'::jsonb_test_domain ON EMPTY));
|
||||
js1
|
||||
------
|
||||
foo1
|
||||
|
@ -243,7 +243,7 @@ SELECT * FROM JSON_TABLE(jsonb '{"d1": "foo"}', '$'
|
|||
(1 row)
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "foo"}', '$'
|
||||
COLUMNS (js1 oid[] PATH '$.d2' DEFAULT '{1}'::int[]::oid[] ON ERROR));
|
||||
COLUMNS (js1 oid[] PATH '$.d2' DEFAULT '{1}'::int[]::oid[] ON EMPTY));
|
||||
js1
|
||||
-----
|
||||
{1}
|
||||
|
@ -885,7 +885,16 @@ SELECT sub.* FROM s,
|
|||
xx int path '$.c',
|
||||
NESTED PATH '$.a.za[1]' columns (NESTED PATH '$.z21[*]' COLUMNS (z21 int path '$?(@ >= $"x")' ERROR ON ERROR))
|
||||
)) sub;
|
||||
ERROR: no SQL/JSON item found for specified path of column "z21"
|
||||
xx | z21
|
||||
----+------
|
||||
3 |
|
||||
3 | 234
|
||||
3 | 2345
|
||||
10 | 32
|
||||
10 | 134
|
||||
10 | 1345
|
||||
(6 rows)
|
||||
|
||||
-- Parent columns xx1, xx appear before NESTED ones
|
||||
SELECT sub.* FROM s,
|
||||
(VALUES (23)) x(x), generate_series(13, 13) y,
|
||||
|
|
|
@ -362,11 +362,15 @@ SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
|
|||
error
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
|
||||
ERROR: no SQL/JSON item found for specified path
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR); -- NULL ON EMPTY
|
||||
json_value
|
||||
------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
|
||||
ERROR: no SQL/JSON item found for specified path
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.*' DEFAULT 2 ON ERROR);
|
||||
json_value
|
||||
------------
|
||||
2
|
||||
|
@ -375,10 +379,10 @@ SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
|
|||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
|
||||
json_value
|
||||
------------
|
||||
2
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY);
|
||||
json_value
|
||||
------------
|
||||
2
|
||||
|
@ -773,8 +777,12 @@ SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
|
|||
ERROR: no SQL/JSON item found for specified path
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
|
||||
ERROR: no SQL/JSON item found for specified path
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
|
||||
ERROR: no SQL/JSON item found for specified path
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR); -- NULL ON EMPTY
|
||||
json_query
|
||||
------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
|
||||
ERROR: JSON path expression in JSON_QUERY should return single item without wrapper
|
||||
HINT: Use WITH WRAPPER clause to wrap SQL/JSON items into array.
|
||||
|
@ -1032,7 +1040,7 @@ SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
|
|||
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON EMPTY ERROR ON ERROR);
|
||||
ERROR: no SQL/JSON item found for specified path
|
||||
-- Test timestamptz passing and output
|
||||
SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
|
||||
|
@ -1223,21 +1231,21 @@ LINE 1: SELECT JSON_QUERY(js, '$' RETURNING int DEFAULT (SELECT 1) ...
|
|||
DROP TABLE test_jsonb_mutability;
|
||||
DROP FUNCTION ret_setint;
|
||||
CREATE DOMAIN queryfuncs_test_domain AS text CHECK (value <> 'foo');
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo'::queryfuncs_test_domain ON EMPTY);
|
||||
ERROR: value for domain queryfuncs_test_domain violates check constraint "queryfuncs_test_domain_check"
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON EMPTY);
|
||||
json_value
|
||||
------------
|
||||
foo1
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT '"foo1"'::jsonb::text ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT '"foo1"'::jsonb::text ON EMPTY);
|
||||
json_value
|
||||
------------
|
||||
"foo1"
|
||||
(1 row)
|
||||
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "foo"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "foo"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON EMPTY);
|
||||
json_value
|
||||
------------
|
||||
foo1
|
||||
|
|
|
@ -118,19 +118,19 @@ FROM json_table_test vals
|
|||
|
||||
-- Test using casts in DEFAULT .. ON ERROR expression
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT '"foo1"'::jsonb::text ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT '"foo1"'::jsonb::text ON EMPTY));
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo'::jsonb_test_domain ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo'::jsonb_test_domain ON EMPTY));
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo1'::jsonb_test_domain ON ERROR));
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.a2' DEFAULT 'foo1'::jsonb_test_domain ON EMPTY));
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "foo"}', '$'
|
||||
COLUMNS (js1 jsonb_test_domain PATH '$.d1' DEFAULT 'foo2'::jsonb_test_domain ON ERROR));
|
||||
|
||||
SELECT * FROM JSON_TABLE(jsonb '{"d1": "foo"}', '$'
|
||||
COLUMNS (js1 oid[] PATH '$.d2' DEFAULT '{1}'::int[]::oid[] ON ERROR));
|
||||
COLUMNS (js1 oid[] PATH '$.d2' DEFAULT '{1}'::int[]::oid[] ON EMPTY));
|
||||
|
||||
-- JSON_TABLE: Test backward parsing
|
||||
|
||||
|
|
|
@ -87,11 +87,11 @@ SELECT JSON_VALUE(jsonb '{}', '$' ERROR ON ERROR);
|
|||
SELECT JSON_VALUE(jsonb '1', '$.a');
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.a' ERROR ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 'error' ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON ERROR); -- NULL ON EMPTY
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY ERROR ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.a' DEFAULT 2 ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'strict $.*' DEFAULT 2 ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT 2 ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' NULL ON EMPTY DEFAULT '2' ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' DEFAULT '2' ON EMPTY DEFAULT '3' ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '1', 'lax $.a' ERROR ON EMPTY DEFAULT '3' ON ERROR);
|
||||
|
@ -224,7 +224,7 @@ SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY NULL ON ERROR);
|
|||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY ARRAY ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY EMPTY OBJECT ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON EMPTY ERROR ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '[]', '$[*]' ERROR ON ERROR); -- NULL ON EMPTY
|
||||
|
||||
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' ERROR ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' DEFAULT '"empty"' ON ERROR);
|
||||
|
@ -304,7 +304,7 @@ SELECT * FROM unnest(JSON_QUERY(jsonb '[{"a": 1, "t": ["foo", []]}, {"a": 2, "jb
|
|||
-- Extension: domain types returning
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON ERROR);
|
||||
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null ERROR ON EMPTY ERROR ON ERROR);
|
||||
|
||||
-- Test timestamptz passing and output
|
||||
SELECT JSON_QUERY(jsonb 'null', '$ts' PASSING timestamptz '2018-02-21 12:34:56 +10' AS ts);
|
||||
|
@ -412,10 +412,10 @@ DROP TABLE test_jsonb_mutability;
|
|||
DROP FUNCTION ret_setint;
|
||||
|
||||
CREATE DOMAIN queryfuncs_test_domain AS text CHECK (value <> 'foo');
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT '"foo1"'::jsonb::text ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "foo"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON ERROR);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo'::queryfuncs_test_domain ON EMPTY);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON EMPTY);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "H"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT '"foo1"'::jsonb::text ON EMPTY);
|
||||
SELECT JSON_VALUE(jsonb '{"d1": "foo"}', '$.a2' RETURNING queryfuncs_test_domain DEFAULT 'foo1'::queryfuncs_test_domain ON EMPTY);
|
||||
|
||||
-- Check the cases where a coercion-related expression is masking an
|
||||
-- unsupported expressions
|
||||
|
|
Loading…
Reference in a new issue