Re: pgsql: Add more SQL/JSON constructor functions
On 2024-May-27, Alvaro Herrera wrote:
JSON_SERIALIZE()
I just noticed this behavior, which looks like a bug to me:
select json_serialize('{"a":1, "a":2}' returning varchar(5));
json_serialize
────────────────
{"a":
I think this function should throw an error if the destination type
doesn't have room for the output json. Otherwise, what good is the
serialization function?
--
Álvaro Herrera 48°01'N 7°57'E — https://www.EnterpriseDB.com/
Import Notes
Reply to msg id not found: 202405271313.qkl63gffldmx@alvherre.pgsql
On Monday, May 27, 2024, Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:
On 2024-May-27, Alvaro Herrera wrote:
JSON_SERIALIZE()
I just noticed this behavior, which looks like a bug to me:
select json_serialize('{"a":1, "a":2}' returning varchar(5));
json_serialize
────────────────
{"a":I think this function should throw an error if the destination type
doesn't have room for the output json. Otherwise, what good is the
serialization function?
It’s not a self-evident bug given that this is exactly how casting data to
varchar(n) behaves as directed by the SQL Standard.
I'd probably leave the internal consistency and take the opportunity to
educate the reader that text is the preferred type in PostgreSQL and,
especially here, there is little good reason to use anything else.
David J.
Hi Alvaro,
On Mon, May 27, 2024 at 7:10 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:
On 2024-May-27, Alvaro Herrera wrote:
JSON_SERIALIZE()
I just noticed this behavior, which looks like a bug to me:
select json_serialize('{"a":1, "a":2}' returning varchar(5));
json_serialize
────────────────
{"a":I think this function should throw an error if the destination type
doesn't have room for the output json. Otherwise, what good is the
serialization function?
I remember using the reasoning mentioned by David G when testing
json_query() et al with varchar(n), so you get:
select json_query('{"a":1, "a":2}', '$' returning varchar(5));
json_query
------------
{"a":
(1 row)
which is the same as:
select '{"a":1, "a":2}'::varchar(5);
varchar
---------
{"a":
(1 row)
Also,
select json_value('{"a":"abcdef"}', '$.a' returning varchar(5) error on error);
json_value
------------
abcde
(1 row)
This behavior comes from using COERCE_EXPLICIT_CAST when creating the
coercion expression to convert json_*() functions' argument to the
RETURNING type.
--
Thanks, Amit Langote
Amit Langote <amitlangote09@gmail.com> writes:
On Mon, May 27, 2024 at 7:10 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:
On 2024-May-27, Alvaro Herrera wrote:
I just noticed this behavior, which looks like a bug to me:select json_serialize('{"a":1, "a":2}' returning varchar(5));
json_serialize
────────────────
{"a":I think this function should throw an error if the destination type
doesn't have room for the output json. Otherwise, what good is the
serialization function?
This behavior comes from using COERCE_EXPLICIT_CAST when creating the
coercion expression to convert json_*() functions' argument to the
RETURNING type.
Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit. I see
little reason that this should work differently from
select json_serialize('{"a":1, "a":2}' returning text)::varchar(5);
json_serialize
----------------
{"a":
(1 row)
regards, tom lane
On 29.05.24 18:44, Tom Lane wrote:
Amit Langote <amitlangote09@gmail.com> writes:
On Mon, May 27, 2024 at 7:10 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:
On 2024-May-27, Alvaro Herrera wrote:
I just noticed this behavior, which looks like a bug to me:select json_serialize('{"a":1, "a":2}' returning varchar(5));
json_serialize
────────────────
{"a":I think this function should throw an error if the destination type
doesn't have room for the output json. Otherwise, what good is the
serialization function?This behavior comes from using COERCE_EXPLICIT_CAST when creating the
coercion expression to convert json_*() functions' argument to the
RETURNING type.Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit. I see
little reason that this should work differently fromselect json_serialize('{"a":1, "a":2}' returning text)::varchar(5);
json_serialize
----------------
{"a":
(1 row)
The SQL standard says essentially that the output of json_serialize() is
some string that when parsed back in gives you an equivalent JSON value
as the input. That doesn't seem compatible with truncating the output.
If you want output truncation, you can of course use an actual cast.
But it makes sense that the RETURNING clause is separate from that.
Peter Eisentraut <peter@eisentraut.org> writes:
On 29.05.24 18:44, Tom Lane wrote:
Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit.
The SQL standard says essentially that the output of json_serialize() is
some string that when parsed back in gives you an equivalent JSON value
as the input. That doesn't seem compatible with truncating the output.
Maybe you should take this up with the SQL committee? If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).
If you want output truncation, you can of course use an actual cast.
But it makes sense that the RETURNING clause is separate from that.
Are you trying to say that the RETURNING clause's specified type
isn't the actual output type? I can't buy that either.
Again, if you think our existing behavior isn't right, I think
it's a problem for the SQL committee not us.
regards, tom lane
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).
It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:
"""
ii) Let JV be an implementation-dependent (UV097) value of type TT and
encoding ENC such that these two conditions hold:
1) JV is a JSON text.
2) When the General Rules of Subclause 9.42, “Parsing JSON text”, are
applied with JV as JSON TEXT, FO as FORMAT OPTION, and WITHOUT UNIQUE
KEYS as UNIQUENESS CONSTRAINT; let CST be the STATUS and let CSJI be the
SQL/JSON ITEM returned from the application of those General Rules, CST
is successful completion (00000) and CSJI is an SQL/JSON item that is
equivalent to SJI.
If there is no such JV, then let ST be the exception condition: data
exception — invalid JSON text (22032).
iii) If JV is longer than the length or maximum length of TT, then an
exception condition is raised: data exception — string data, right
truncation (22001).
"""
Oracle also behaves accordingly:
SQL> select json_serialize('{"a":1, "a":2}' returning varchar2(20)) from
dual;
JSON_SERIALIZE('{"A"
--------------------
{"a":1,"a":2}
SQL> select json_serialize('{"a":1, "a":2}' returning varchar2(5)) from
dual;
select json_serialize('{"a":1, "a":2}' returning varchar2(5)) from dual
*
ERROR at line 1:
ORA-40478: output value too large (maximum: 5)
JZN-00018: Input to serializer is too large
Help: https://docs.oracle.com/error-help/db/ora-40478/
As opposed to:
SQL> select cast(json_serialize('{"a":1, "a":2}') as varchar2(5)) from dual;
CAST(
-----
{"a":
Peter Eisentraut <peter@eisentraut.org> writes:
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).
It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:
Meh. Who needs consistency? But I guess the answer is to do what was
suggested earlier and change the code to use COERCE_IMPLICIT_CAST.
regards, tom lane
On Tue, Jun 4, 2024 at 2:20 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Peter Eisentraut <peter@eisentraut.org> writes:
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:Meh. Who needs consistency? But I guess the answer is to do what was
suggested earlier and change the code to use COERCE_IMPLICIT_CAST.
OK, will post a patch to do so in a new thread on -hackers.
--
Thanks, Amit Langote
On Tue, Jun 4, 2024 at 7:03 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jun 4, 2024 at 2:20 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Peter Eisentraut <peter@eisentraut.org> writes:
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:Meh. Who needs consistency? But I guess the answer is to do what was
suggested earlier and change the code to use COERCE_IMPLICIT_CAST.OK, will post a patch to do so in a new thread on -hackers.
Oops, didn't realize that this is already on -hackers.
Attached is a patch to use COERCE_IMPLICIT_CAST when the RETURNING
type specifies a length limit.
Given that this also affects JSON_OBJECT() et al that got added in
v16, maybe back-patching is in order but I'd like to hear opinions on
that.
--
Thanks, Amit Langote
Attachments:
v1-0001-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchapplication/octet-stream; name=v1-0001-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchDownload
From 4bbd598aca05bbeb7dd9a4f9a8087a05533e439d Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Wed, 5 Jun 2024 09:13:15 +0900
Subject: [PATCH v1] SQL/JSON: Use implicit casts for RETURNING type with
typmod
This fixes things so that the various SQL/JSON functions that support
specifying the type of the returned value using the RETURNING clause
perform an implicit cast to the target type at least in the cases
where the target type also specifies a length limit. That is to
ensure that the output values that exceed the length produce an error
instead of being silently truncated to the specified length, a
behavior that agrees with what the standard says regarding this.
Reported-by: Alvaro Herrera
Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/parser/parse_expr.c | 29 +++++++++++++++++--
src/test/regress/expected/sqljson.out | 11 +++++++
.../regress/expected/sqljson_jsontable.out | 18 ++++++------
.../regress/expected/sqljson_queryfuncs.out | 26 ++++++++++-------
src/test/regress/sql/sqljson.sql | 7 +++++
src/test/regress/sql/sqljson_queryfuncs.sql | 8 +++--
6 files changed, 73 insertions(+), 26 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 4c95986c31..afeb8cb1d2 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3614,7 +3614,9 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
returning->typid, returning->typmod,
+ returning->typmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
+ returning->typmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
@@ -3677,6 +3679,14 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr() will
+ * create an implicit cast to the RETURNING types with typmod and there are
+ * no implicit casts from json(b) to such types.
+ */
+ if (returning->typmod > 0)
+ placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
+ "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
@@ -4526,10 +4536,9 @@ coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
if (jsexpr->op == JSON_VALUE_OP)
{
/*
- * Use cast expressions for types with typmod and domain types.
+ * Use cast expression for domain types; we need CoerceToDomain here.
*/
- if (returning->typmod == -1 &&
- get_typtype(returning->typid) != TYPTYPE_DOMAIN)
+ if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
@@ -4561,6 +4570,20 @@ coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
default:
break;
}
+
+ /*
+ * coerceJsonFuncExpr() creates implicit casts for types with typmod,
+ * which (if present) don't handle errors softly, so use runtime
+ * coercion.
+ */
+ if (returning->typmod > 0)
+ {
+ if (jsexpr->omit_quotes)
+ jsexpr->use_io_coercion = true;
+ else
+ jsexpr->use_json_coercion = true;
+ return;
+ }
}
/* Look up a cast expression. */
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
index cbf8542d8d..034c22cb44 100644
--- a/src/test/regress/expected/sqljson.out
+++ b/src/test/regress/expected/sqljson.out
@@ -1278,3 +1278,14 @@ CREATE OR REPLACE VIEW public.is_json_view AS
'{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
FROM generate_series(1, 3) i(i)
DROP VIEW is_json_view;
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+ERROR: value too long for type character varying(2)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 9f649483ce..2d74fba506 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -103,14 +103,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | | | | [1,2] | "[1,2]" | "[1,2]"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
@@ -137,14 +137,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | | | "aaaaaaa" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | | | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | | | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | | | {"aaa": 123} | {"aaa": 123}
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | | | "[1,2]" | [1, 2]
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | | | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 98117b346d..24672524ad 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -234,10 +234,18 @@ SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
aaa
(1 row)
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
+ERROR: value too long for type character(2)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
json_value
------------
- aa
+
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ json_value
+------------
+ aaa
(1 row)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
@@ -632,16 +640,18 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERR
(1 row)
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ERROR: value too long for type character(3)
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
json_query
------------
- "a
+
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
json_query
------------
- aa
+ aaa
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
@@ -820,12 +830,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
[1, 2]
(1 row)
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
- json_query
-------------
- [1,
-(1 row)
-
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
json_query
------------
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
index e6e20175b0..cbf2d6e396 100644
--- a/src/test/regress/sql/sqljson.sql
+++ b/src/test/regress/sql/sqljson.sql
@@ -463,3 +463,10 @@ SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT
\sv is_json_view
DROP VIEW is_json_view;
+
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index d9dbb1ceaa..7368cfcd92 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -53,7 +53,9 @@ SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$');
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
@@ -188,8 +190,9 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
@@ -235,7 +238,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
--
2.43.0
On Tue, Jun 18, 2024 at 5:02 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jun 4, 2024 at 7:03 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jun 4, 2024 at 2:20 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Peter Eisentraut <peter@eisentraut.org> writes:
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:Meh. Who needs consistency? But I guess the answer is to do what was
suggested earlier and change the code to use COERCE_IMPLICIT_CAST.OK, will post a patch to do so in a new thread on -hackers.
Oops, didn't realize that this is already on -hackers.
Attached is a patch to use COERCE_IMPLICIT_CAST when the RETURNING
type specifies a length limit.
hi.
i am a little confused.
here[1]/messages/by-id/3189.1717001075@sss.pgh.pa.us tom says:
Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit. I see
little reason that this should work differently fromselect json_serialize('{"a":1, "a":2}' returning text)::varchar(5);
json_serialize
----------------
{"a":
(1 row)
if i understand it correctly, and my english interpretation is fine.
i think tom means something like:
select json_serialize('{"a":1, "a":2}' returning text)::varchar(5) =
json_serialize('{"a":1, "a":2}' returning varchar(5));
should return true.
the master will return true, but apply your patch, the above query
will yield an error.
your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.
------------------------------------------
current in ExecInitJsonExpr we have
if (jsexpr->coercion_expr)
...
else if (jsexpr->use_json_coercion)
...
else if (jsexpr->use_io_coercion)
...
do you think it is necessary to add following asserts:
Assert (!(jsexpr->coercion_expr && jsexpr->use_json_coercion))
Assert (!(jsexpr->coercion_expr && jsexpr->use_io_coercion))
Hi,
Thanks for taking a look.
On Fri, Jun 21, 2024 at 4:05 PM jian he <jian.universality@gmail.com> wrote:
On Tue, Jun 18, 2024 at 5:02 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jun 4, 2024 at 7:03 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jun 4, 2024 at 2:20 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Peter Eisentraut <peter@eisentraut.org> writes:
On 02.06.24 21:46, Tom Lane wrote:
If you don't
like our current behavior, then either you have to say that RETURNING
with a length-limited target type is illegal (which is problematic
for the spec, since they have no such type) or that the cast behaves
like an implicit cast, with errors for overlength input (which I find
to be an unintuitive definition for a construct that names the target
type explicitly).It asks for the latter behavior, essentially (but it's not defined in
terms of casts). It says:Meh. Who needs consistency? But I guess the answer is to do what was
suggested earlier and change the code to use COERCE_IMPLICIT_CAST.OK, will post a patch to do so in a new thread on -hackers.
Oops, didn't realize that this is already on -hackers.
Attached is a patch to use COERCE_IMPLICIT_CAST when the RETURNING
type specifies a length limit.hi.
i am a little confused.here[1] tom says:
Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit. I see
little reason that this should work differently fromselect json_serialize('{"a":1, "a":2}' returning text)::varchar(5);
json_serialize
----------------
{"a":
(1 row)if i understand it correctly, and my english interpretation is fine.
i think tom means something like:select json_serialize('{"a":1, "a":2}' returning text)::varchar(5) =
json_serialize('{"a":1, "a":2}' returning varchar(5));should return true.
the master will return true, but apply your patch, the above query
will yield an error.
The RETURNING variant giving an error is what the standard asks us to
do apparently. I read Tom's last message on this thread as agreeing
to that, even though hesitantly. He can correct me if I got that
wrong.
your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.
Interesting examples, thanks for sharing.
Attached updated version should take into account that typmod may be
hiding under domains. Please test.
------------------------------------------
current in ExecInitJsonExpr we haveif (jsexpr->coercion_expr)
...
else if (jsexpr->use_json_coercion)
...
else if (jsexpr->use_io_coercion)
...do you think it is necessary to add following asserts:
Assert (!(jsexpr->coercion_expr && jsexpr->use_json_coercion))
Assert (!(jsexpr->coercion_expr && jsexpr->use_io_coercion))
Yeah, perhaps, but let's consider this independently please.
--
Thanks, Amit Langote
Attachments:
v2-0001-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchapplication/octet-stream; name=v2-0001-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchDownload
From 5845f2788bd9d395da7977ceb3dcc2ef4d37e91b Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Wed, 5 Jun 2024 09:13:15 +0900
Subject: [PATCH v2] SQL/JSON: Use implicit casts for RETURNING type with
typmod
This fixes things so that the various SQL/JSON functions that support
specifying the type of the returned value using the RETURNING clause
perform an implicit cast to the target type at least in the cases
where the target type also specifies a length limit. That is to
ensure that the output values (including those specified in the
DEFAULT .. ON ERROR) that exceed the length produce an error instead
of being silently truncated to the specified length, which is a
behavior that agrees with what the SQL standard.
Reported-by: Alvaro Herrera
Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/parser/parse_expr.c | 60 +++++++++++++++++--
src/test/regress/expected/sqljson.out | 17 ++++++
.../regress/expected/sqljson_jsontable.out | 26 ++++----
.../regress/expected/sqljson_queryfuncs.out | 44 ++++++++------
src/test/regress/sql/sqljson.sql | 12 ++++
src/test/regress/sql/sqljson_jsontable.sql | 2 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 18 ++++--
7 files changed, 136 insertions(+), 43 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 3d79d17125..18d0adb64d 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3583,6 +3583,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
+ int32 baseTypmod = returning->typmod;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3611,10 +3612,19 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}
+ /*
+ * For domains, consider the base type's typmod to decide whether to setup
+ * an implicit or explicit cast.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
- returning->typid, returning->typmod,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
@@ -3640,6 +3650,7 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
+ int32 baseTypmod = returning->typmod;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3677,6 +3688,17 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr() will
+ * create an implicit cast to the RETURNING types with typmod and there are
+ * no implicit casts from json(b) to such types. For domains, the base
+ * type's typmod will be considered, so do so here too.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ if (baseTypmod > 0)
+ placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
+ "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
@@ -4593,10 +4615,9 @@ coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
if (jsexpr->op == JSON_VALUE_OP)
{
/*
- * Use cast expressions for types with typmod and domain types.
+ * Use cast expression for domain types; we need CoerceToDomain here.
*/
- if (returning->typmod == -1 &&
- get_typtype(returning->typid) != TYPTYPE_DOMAIN)
+ if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
@@ -4628,6 +4649,20 @@ coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
default:
break;
}
+
+ /*
+ * coerceJsonFuncExpr() creates implicit casts for types with typmod,
+ * which (if present) don't handle errors softly, so use runtime
+ * coercion.
+ */
+ if (returning->typmod > 0)
+ {
+ if (jsexpr->omit_quotes)
+ jsexpr->use_io_coercion = true;
+ else
+ jsexpr->use_json_coercion = true;
+ return;
+ }
}
/* Look up a cast expression. */
@@ -4776,11 +4811,24 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
btype == default_behavior))
coerce_at_runtime = true;
else
+ {
+ int32 baseTypmod = returning->typmod;
+
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
+ if (baseTypmod > 0)
+ expr = coerce_to_specific_type(pstate, expr, TEXTOID,
+ "JSON_FUNCTION()");
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, returning->typmod,
- COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
+ COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
+ }
if (coerced_expr == NULL)
ereport(ERROR,
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
index cbf8542d8d..4f91e2117e 100644
--- a/src/test/regress/expected/sqljson.out
+++ b/src/test/regress/expected/sqljson.out
@@ -1278,3 +1278,20 @@ CREATE OR REPLACE VIEW public.is_json_view AS
'{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
FROM generate_series(1, 3) i(i)
DROP VIEW is_json_view;
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+ERROR: value too long for type character varying(2)
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+ERROR: value too long for type character(2)
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
+ERROR: value for domain sqljson_char2 violates check constraint "sqljson_char2_check"
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index eace29efbf..327eb10e02 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -103,14 +103,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | | | | [1,2] | "[1,2]" | "[1,2]"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
@@ -137,14 +137,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | | | "aaaaaaa" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | | | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | | | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | | | {"aaa": 123} | {"aaa": 123}
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | | | "[1,2]" | [1, 2]
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | | | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
@@ -566,10 +566,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
ERROR: cannot cast type boolean to real
LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
^
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
------
- fal
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+-------
+ false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 0c4b62b0bb..35ce994ef3 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -234,10 +234,18 @@ SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
aaa
(1 row)
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
+ERROR: value too long for type character(2)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
json_value
------------
- aa
+
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ json_value
+------------
+ aaa
(1 row)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
@@ -636,30 +644,28 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERR
(1 row)
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ERROR: value too long for type character(3)
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
json_query
------------
- "a
+
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
json_query
------------
- aa
+ aaa
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
json_query
------------
bb
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
- json_query
-------------
- "b
-(1 row)
-
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
+ERROR: value too long for type character(2)
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -828,12 +834,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
[1, 2]
(1 row)
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
- json_query
-------------
- [1,
-(1 row)
-
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
json_query
------------
@@ -1369,3 +1369,11 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY | OBJECT }, or DEFAULT <value> is allowed in ON ERROR for JSON_QUERY().
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '12', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value for domain queryfuncs_char2 violates check constraint "queryfuncs_char2_check"
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
index e6e20175b0..bb2487e864 100644
--- a/src/test/regress/sql/sqljson.sql
+++ b/src/test/regress/sql/sqljson.sql
@@ -463,3 +463,15 @@ SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT
\sv is_json_view
DROP VIEW is_json_view;
+
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 1f81464c5f..990e5bcac0 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,7 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index 4586fdb8a4..adb34bf85a 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -53,7 +53,9 @@ SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$');
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
@@ -188,10 +190,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
@@ -235,7 +238,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
@@ -464,3 +466,9 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
+
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '12', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
--
2.43.0
On Fri, Jun 21, 2024 at 10:48 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Fri, Jun 21, 2024 at 4:05 PM jian he <jian.universality@gmail.com> wrote:
hi.
i am a little confused.here[1] tom says:
Yeah, I too think this is a cast, and truncation is the spec-defined
behavior for casting to varchar with a specific length limit. I see
little reason that this should work differently fromselect json_serialize('{"a":1, "a":2}' returning text)::varchar(5);
json_serialize
----------------
{"a":
(1 row)if i understand it correctly, and my english interpretation is fine.
i think tom means something like:select json_serialize('{"a":1, "a":2}' returning text)::varchar(5) =
json_serialize('{"a":1, "a":2}' returning varchar(5));should return true.
the master will return true, but apply your patch, the above query
will yield an error.The RETURNING variant giving an error is what the standard asks us to
do apparently. I read Tom's last message on this thread as agreeing
to that, even though hesitantly. He can correct me if I got that
wrong.your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.Interesting examples, thanks for sharing.
Attached updated version should take into account that typmod may be
hiding under domains. Please test.
I'd like to push this one tomorrow, barring objections.
I could use some advice on backpatching. As I mentioned upthread,
this changes the behavior for JSON_OBJECT(), JSON_ARRAY(),
JSON_ARRAYAGG(), JSON_OBJECTAGG() too, which were added in v16.
Should this change be backpatched? In general, what's our stance on
changes that cater to improving standard compliance, but are not
necessarily bugs.
--
Thanks, Amit Langote
On Wed, Jun 26, 2024 at 8:39 PM Amit Langote <amitlangote09@gmail.com> wrote:
The RETURNING variant giving an error is what the standard asks us to
do apparently. I read Tom's last message on this thread as agreeing
to that, even though hesitantly. He can correct me if I got that
wrong.your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.Interesting examples, thanks for sharing.
Attached updated version should take into account that typmod may be
hiding under domains. Please test.
SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'13' on error);
return
ERROR: value too long for type character(2)
should return 13
I found out the source of the problem is in coerceJsonExprOutput
/*
* Use cast expression for domain types; we need CoerceToDomain here.
*/
if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
}
I'd like to push this one tomorrow, barring objections.
Currently the latest patch available cannot be `git apply` cleanly.
@@ -464,3 +466,9 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
+
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '12', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
cannot found `SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);` in
https://git.postgresql.org/cgit/postgresql.git/tree/src/test/regress/sql/sqljson_queryfuncs.sql
hi.
I have assembled a list of simple examples, some works (for comparison
sake), most not work
as intended.
CREATE DOMAIN queryfuncs_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
CREATE DOMAIN queryfuncs_d_interval AS interval(2) CHECK (VALUE is not null);
SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'12' on error);
SELECT JSON_VALUE(jsonb '12', '$' RETURNING queryfuncs_char2 default
'11' on error);
SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'13' on error);
SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING queryfuncs_char2
default '17' on error);
SELECT JSON_QUERY(jsonb '111', '$' RETURNING queryfuncs_char2 default
'14' on error);
SELECT JSON_QUERY(jsonb '111', '$' RETURNING queryfuncs_char2 omit
quotes default '15' on error);
SELECT JSON_QUERY(jsonb '111', '$' RETURNING queryfuncs_char2 keep
quotes default '16' on error);
SELECT JSON_VALUE(jsonb '"01:23:45.6789"', '$' RETURNING
queryfuncs_d_interval default '01:23:45.6789' on error);
SELECT JSON_VALUE(jsonb '"01:23:45.6789"', '$' RETURNING
queryfuncs_d_interval default '01:23:45.6789' on empty);
SELECT JSON_QUERY(jsonb '"01:23:45.6789"', '$' RETURNING
queryfuncs_d_interval default '01:23:45.6789' on error);
SELECT JSON_QUERY(jsonb '"01:23:45.6789"', '$' RETURNING
queryfuncs_d_interval default '01:23:45.6789' on empty);
above 4 queries fails, meaning the changes you propose within
transformJsonBehavior is wrong?
i think it's because the COERCION_IMPLICIT cast from text to domain
queryfuncs_d_interval is not doable.
json_table seems also have problem with "exists" cast to other type, example:
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(2) EXISTS
PATH '$.a' ));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a queryfuncs_char2
EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a queryfuncs_char2
EXISTS PATH '$.a' error on error));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a queryfuncs_char2
EXISTS PATH '$.a' error on empty));
----------------------------------------------------------------------------------------------------
SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'13' on error);
for the above example:
coerceJsonExprOutput, coerceJsonFuncExpr set the result datum coercion
node to RelabelType:
RelabelType is not error safe. so the above query will fail converting
text 111 to queryfuncs_char2
which is not what we want.
I think making coerceJsonExprOutput the following way can solve this problem.
your patch cannot apply cleanly, I just posted the actual code snippet
of coerceJsonExprOutput, not a diff file.
static void
coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
{
JsonReturning *returning = jsexpr->returning;
Node *context_item = jsexpr->formatted_expr;
int default_typmod;
Oid default_typid;
bool omit_quotes =
jsexpr->op == JSON_QUERY_OP && jsexpr->omit_quotes;
Node *coercion_expr = NULL;
int32 baseTypmod = returning->typmod;
Assert(returning);
/*
* Check for cases where the coercion should be handled at runtime, that
* is, without using a cast expression.
*/
if (jsexpr->op == JSON_VALUE_OP)
{
/*
* Use cast expression for domain types; we need CoerceToDomain here.
*/
if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
}
else
{
/* domain type, typmod > 0 can only use use_io_coercion */
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
if (baseTypmod > 0)
{
jsexpr->use_io_coercion = true;
return;
}
}
}
else if (jsexpr->op == JSON_QUERY_OP)
{
/*
* Cast functions from jsonb to the following types (jsonb_bool() et
* al) don't handle errors softly, so coerce either by calling
* json_populate_type() or the type's input function so that any
* errors are handled appropriately. The latter only if OMIT QUOTES is
* true.
*/
switch (returning->typid)
{
case BOOLOID:
case NUMERICOID:
case INT2OID:
case INT4OID:
case INT8OID:
case FLOAT4OID:
case FLOAT8OID:
if (jsexpr->omit_quotes)
jsexpr->use_io_coercion = true;
else
jsexpr->use_json_coercion = true;
return;
default:
break;
}
/*
* for returning domain type, we cannot use coercion expression.
* it may not be able to catch the error, for example RelabelType
* for we either use_io_coercion or use_json_coercion.
*/
if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
/*
* coerceJsonFuncExpr() creates implicit casts for types with typmod,
* which (if present) don't handle errors softly, so use runtime
* coercion.
*/
if (baseTypmod > 0)
{
if (jsexpr->omit_quotes)
jsexpr->use_io_coercion = true;
else
jsexpr->use_json_coercion = true;
return;
}
}
...
-------------------------------
Hi,
On Wed, Jun 26, 2024 at 11:46 PM jian he <jian.universality@gmail.com> wrote:
On Wed, Jun 26, 2024 at 8:39 PM Amit Langote <amitlangote09@gmail.com> wrote:
The RETURNING variant giving an error is what the standard asks us to
do apparently. I read Tom's last message on this thread as agreeing
to that, even though hesitantly. He can correct me if I got that
wrong.your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.Interesting examples, thanks for sharing.
Attached updated version should take into account that typmod may be
hiding under domains. Please test.SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'13' on error);
return
ERROR: value too long for type character(2)
should return 13I found out the source of the problem is in coerceJsonExprOutput
/*
* Use cast expression for domain types; we need CoerceToDomain here.
*/
if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
}
Thanks for this test case and the analysis. Yes, using a cast
expression for coercion to the RETURNING type generally seems to be a
source of many problems that could've been solved by fixing things so
that only use_io_coercion and use_json_coercion are enough to handle
all the cases.
I've attempted that in the attached 0001, which removes
JsonExpr.coercion_expr and a bunch of code around it.
0002 is now the original patch minus the changes to make
JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE() behave as we would like,
because the changes in 0001 covers them. The changes for JsonBehavior
expression coercion as they were in the last version of the patch are
still needed, but I decided to move those into 0001 so that the
changes for query functions are all in 0001 and those for constructors
in 0002. It would be nice to get rid of that coerce_to_target_type()
call to coerce the "behavior expression" to RETURNING type, but I'm
leaving that as a task for another day.
--
Thanks, Amit Langote
Attachments:
v3-0001-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchapplication/octet-stream; name=v3-0001-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchDownload
From 4660ecb1869884e7024b6fc0fbb10f5084f8bf3f Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 27 Jun 2024 16:07:39 +0900
Subject: [PATCH v3 1/2] SQL/JSON: Always coerce JsonExpr result at runtime
Instead of looking up casts at parse time for converting the result
of JsonPath* query functions to the specified or the default
RETURNING type, always perform the conversion at runtime using either
the target type's input function or the function
json_populate_type(). The main motivation for this change is to
avoid ending up in some cases with a cast expression that doesn't
support soft handling of errors.
JsonExpr.coercion_expr which would store the cast expression is no
longer necessary, so remove.
---
src/backend/executor/execExpr.c | 42 ++----
src/backend/executor/execExprInterp.c | 31 ++--
src/backend/nodes/nodeFuncs.c | 13 +-
src/backend/parser/parse_expr.c | 141 ++++--------------
src/backend/utils/adt/jsonfuncs.c | 22 ++-
src/include/executor/execExpr.h | 1 +
src/include/nodes/primnodes.h | 6 -
src/include/utils/jsonfuncs.h | 1 +
.../regress/expected/sqljson_jsontable.out | 52 +++----
.../regress/expected/sqljson_queryfuncs.out | 72 ++++++---
src/test/regress/sql/sqljson_jsontable.sql | 2 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 25 +++-
12 files changed, 170 insertions(+), 238 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 2bf86d06ef..a8be57d21b 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -92,7 +92,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
Datum *resv, bool *resnull,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull);
@@ -4318,7 +4318,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*/
- if (jsexpr->coercion_expr)
+ if (jsexpr->use_json_coercion)
{
scratch->opcode = EEOP_JUMP;
scratch->d.jump.jumpdone = state->steps_len + 1;
@@ -4337,33 +4337,12 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* NULL returned on NULL input as described above.
*/
jsestate->jump_eval_coercion = -1;
- if (jsexpr->coercion_expr)
- {
- Datum *save_innermost_caseval;
- bool *save_innermost_casenull;
- ErrorSaveContext *save_escontext;
-
- jsestate->jump_eval_coercion = state->steps_len;
-
- save_innermost_caseval = state->innermost_caseval;
- save_innermost_casenull = state->innermost_casenull;
- save_escontext = state->escontext;
-
- state->innermost_caseval = resv;
- state->innermost_casenull = resnull;
- state->escontext = escontext;
-
- ExecInitExprRec((Expr *) jsexpr->coercion_expr, state, resv, resnull);
-
- state->innermost_caseval = save_innermost_caseval;
- state->innermost_casenull = save_innermost_casenull;
- state->escontext = save_escontext;
- }
- else if (jsexpr->use_json_coercion)
+ if (jsexpr->use_json_coercion)
{
jsestate->jump_eval_coercion = state->steps_len;
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4435,8 +4414,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
@@ -4468,8 +4447,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
foreach(lc, jumps_to_end)
@@ -4488,7 +4467,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
*/
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4501,5 +4480,6 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
+ scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 852186312c..3a13f90d48 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4303,8 +4303,14 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
- *op->resvalue = BoolGetDatum(exists);
*op->resnull = false;
+ if (jsexpr->use_json_coercion)
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ BoolGetDatum(exists) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ else
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4317,21 +4323,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*op->resnull = (DatumGetPointer(*op->resvalue) == NULL);
- /* Handle OMIT QUOTES. */
- if (!*op->resnull && jsexpr->omit_quotes)
- {
+ if (!*op->resnull && jsexpr->use_io_coercion)
val_string = JsonbUnquote(DatumGetJsonbP(*op->resvalue));
- /*
- * Pass the string as a text value to the cast expression if
- * one present. If not, use the input function call below to
- * do the coercion.
- */
- if (jump_eval_coercion >= 0)
- *op->resvalue =
- DirectFunctionCall1(textin,
- PointerGetDatum(val_string));
- }
break;
case JSON_VALUE_OP:
@@ -4355,6 +4349,11 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
val_string = DatumGetCString(DirectFunctionCall1(jsonb_out,
JsonbPGetDatum(JsonbValueToJsonb(jbv))));
}
+ else if (jsexpr->use_json_coercion)
+ {
+ *op->resvalue = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+ *op->resnull = false;
+ }
else
{
val_string = ExecGetJsonValueItemString(jbv, op->resnull);
@@ -4545,7 +4544,9 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
op->d.jsonexpr_coercion.targettypmod,
&op->d.jsonexpr_coercion.json_populate_type_cache,
econtext->ecxt_per_query_memory,
- op->resnull, (Node *) escontext);
+ op->resnull,
+ op->d.jsonexpr_coercion.omit_quotes,
+ (Node *) escontext);
}
/*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 89ee4b61f2..d2e2af4f81 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1006,10 +1006,7 @@ exprCollation(const Node *expr)
{
const JsonExpr *jsexpr = (JsonExpr *) expr;
- if (jsexpr->coercion_expr)
- coll = exprCollation(jsexpr->coercion_expr);
- else
- coll = jsexpr->collation;
+ coll = jsexpr->collation;
}
break;
case T_JsonBehavior:
@@ -1265,10 +1262,7 @@ exprSetCollation(Node *expr, Oid collation)
{
JsonExpr *jexpr = (JsonExpr *) expr;
- if (jexpr->coercion_expr)
- exprSetCollation((Node *) jexpr->coercion_expr, collation);
- else
- jexpr->collation = collation;
+ jexpr->collation = collation;
}
break;
case T_JsonBehavior:
@@ -2368,8 +2362,6 @@ expression_tree_walker_impl(Node *node,
return true;
if (WALK(jexpr->path_spec))
return true;
- if (WALK(jexpr->coercion_expr))
- return true;
if (WALK(jexpr->passing_values))
return true;
/* we assume walker doesn't care about passing_names */
@@ -3411,7 +3403,6 @@ expression_tree_mutator_impl(Node *node,
FLATCOPY(newnode, jexpr, JsonExpr);
MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
- MUTATE(newnode->coercion_expr, jexpr->coercion_expr, Node *);
MUTATE(newnode->passing_values, jexpr->passing_values, List *);
/* assume mutator does not care about passing_names */
MUTATE(newnode->on_empty, jexpr->on_empty, JsonBehavior *);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 00cd7358eb..97a92f2b0d 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4360,39 +4360,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
- {
- Node *coercion_expr;
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
- int location = exprLocation((Node *) jsexpr);
-
- /*
- * We abuse CaseTestExpr here as placeholder to pass the
- * result of evaluating JSON_EXISTS to the coercion
- * expression.
- */
- placeholder->typeId = BOOLOID;
- placeholder->typeMod = -1;
- placeholder->collation = InvalidOid;
-
- coercion_expr =
- coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
- jsexpr->returning->typid,
- jsexpr->returning->typmod,
- COERCION_EXPLICIT,
- COERCE_IMPLICIT_CAST,
- location);
-
- if (coercion_expr == NULL)
- ereport(ERROR,
- (errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast type %s to %s",
- format_type_be(BOOLOID),
- format_type_be(jsexpr->returning->typid)),
- parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
-
- if (coercion_expr != (Node *) placeholder)
- jsexpr->coercion_expr = coercion_expr;
- }
+ jsexpr->use_json_coercion = true;
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
@@ -4517,12 +4485,8 @@ static void
coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
{
JsonReturning *returning = jsexpr->returning;
- Node *context_item = jsexpr->formatted_expr;
- int default_typmod;
- Oid default_typid;
bool omit_quotes =
jsexpr->op == JSON_QUERY_OP && jsexpr->omit_quotes;
- Node *coercion_expr = NULL;
Assert(returning);
@@ -4533,95 +4497,29 @@ coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
if (jsexpr->op == JSON_VALUE_OP)
{
/*
- * Use cast expressions for types with typmod and domain types.
+ * Use json_populate_type() when coercing to domain types with
+ * constraints, coercion using IO won't check them.
*/
- if (returning->typmod == -1 &&
- get_typtype(returning->typid) != TYPTYPE_DOMAIN)
+ if (get_typtype(returning->typid) != TYPTYPE_DOMAIN ||
+ !DomainHasConstraints(returning->typid))
{
jsexpr->use_io_coercion = true;
return;
}
- }
- else if (jsexpr->op == JSON_QUERY_OP)
- {
- /*
- * Cast functions from jsonb to the following types (jsonb_bool() et
- * al) don't handle errors softly, so coerce either by calling
- * json_populate_type() or the type's input function so that any
- * errors are handled appropriately. The latter only if OMIT QUOTES is
- * true.
- */
- switch (returning->typid)
+ else
{
- case BOOLOID:
- case NUMERICOID:
- case INT2OID:
- case INT4OID:
- case INT8OID:
- case FLOAT4OID:
- case FLOAT8OID:
- if (jsexpr->omit_quotes)
- jsexpr->use_io_coercion = true;
- else
- jsexpr->use_json_coercion = true;
- return;
- default:
- break;
+ jsexpr->use_json_coercion = true;
+ return;
}
}
-
- /* Look up a cast expression. */
-
- /*
- * For JSON_VALUE() and for JSON_QUERY() when OMIT QUOTES is true,
- * ExecEvalJsonExprPath() will convert a quote-stripped source value to
- * its text representation, so use TEXTOID as the source type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
- {
- default_typid = TEXTOID;
- default_typmod = -1;
- }
- else
- {
- default_typid = exprType(context_item);
- default_typmod = exprTypmod(context_item);
- }
-
- if (returning->typid != default_typid ||
- returning->typmod != default_typmod)
- {
- /*
- * We abuse CaseTestExpr here as placeholder to pass the result of
- * jsonpath evaluation as input to the coercion expression.
- */
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
-
- placeholder->typeId = default_typid;
- placeholder->typeMod = default_typmod;
-
- coercion_expr = coerceJsonFuncExpr(pstate, (Node *) placeholder,
- returning, false);
- if (coercion_expr == (Node *) placeholder)
- coercion_expr = NULL;
- }
-
- jsexpr->coercion_expr = coercion_expr;
-
- if (coercion_expr == NULL)
+ else if (jsexpr->op == JSON_QUERY_OP)
{
- /*
- * Either no cast was found or coercion is unnecessary but still must
- * convert the string value to the output type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
+ if (omit_quotes)
jsexpr->use_io_coercion = true;
else
jsexpr->use_json_coercion = true;
+ return;
}
-
- Assert(jsexpr->coercion_expr != NULL ||
- (jsexpr->use_io_coercion != jsexpr->use_json_coercion));
}
/*
@@ -4716,11 +4614,24 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
btype == default_behavior))
coerce_at_runtime = true;
else
+ {
+ int32 baseTypmod = returning->typmod;
+
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
+ if (baseTypmod > 0)
+ expr = coerce_to_specific_type(pstate, expr, TEXTOID,
+ "JSON_FUNCTION()");
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, returning->typmod,
- COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
+ COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
+ }
if (coerced_expr == NULL)
ereport(ERROR,
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index ab5aa0ccb8..b26a1cbfcb 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -3338,7 +3338,7 @@ Datum
json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
- bool *isnull,
+ bool *isnull, bool omit_quotes,
Node *escontext)
{
JsValue jsv = {0};
@@ -3368,10 +3368,22 @@ json_populate_type(Datum json_val, Oid json_type,
jsv.val.jsonb = &jbv;
- /* fill binary jsonb value pointing to jb */
- jbv.type = jbvBinary;
- jbv.val.binary.data = &jsonb->root;
- jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ if (omit_quotes)
+ {
+ char *str = JsonbUnquote(DatumGetJsonbP(json_val));
+
+ /* fill the quote-stripped string */
+ jbv.type = jbvString;
+ jbv.val.string.len = strlen(str);
+ jbv.val.string.val = str;
+ }
+ else
+ {
+ /* fill binary jsonb value pointing to jb */
+ jbv.type = jbvBinary;
+ jbv.val.binary.data = &jsonb->root;
+ jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ }
}
if (*cache == NULL)
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 64698202a5..55337d4916 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -707,6 +707,7 @@ typedef struct ExprEvalStep
{
Oid targettype;
int32 targettypmod;
+ bool omit_quotes;
void *json_populate_type_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4830efc573..dacc75f2af 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1838,13 +1838,7 @@ typedef struct JsonExpr
/*
* Information about converting the result of jsonpath functions
* JsonPathQuery() and JsonPathValue() to the RETURNING type.
- *
- * coercion_expr is a cast expression if the parser can find it for the
- * source and the target type. If not, either use_io_coercion or
- * use_json_coercion is set to determine the coercion method to use at
- * runtime; see coerceJsonExprOutput() and ExecInitJsonExpr().
*/
- Node *coercion_expr;
bool use_io_coercion;
bool use_json_coercion;
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 190e13284b..93384d900a 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -93,6 +93,7 @@ extern Datum json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
bool *isnull,
+ bool omit_quotes,
Node *escontext);
#endif
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index cee90cead1..cf43442891 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -103,14 +103,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | false | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | true | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | | | | [1,2] | "[1,2]" | "[1,2]"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
@@ -137,14 +137,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | | | "aaaaaaa" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | | | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | | | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | | | {"aaa": 123} | {"aaa": 123}
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | | | "[1,2]" | [1, 2]
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | | | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -555,31 +555,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to smallint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to smallint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to bigint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to bigint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to real
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
- ^
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
------
- fal
+ERROR: cannot cast behavior expression of type boolean to real
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+-------
+ false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to json
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to json
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to jsonb
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
- ^
+ERROR: cannot cast behavior expression of type boolean to jsonb
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 9cb250a27a..ea136eefa7 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -234,10 +234,18 @@ SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
aaa
(1 row)
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
+ERROR: value too long for type character(2)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
json_value
------------
- aa
+
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ json_value
+------------
+ aaa
(1 row)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
@@ -636,30 +644,28 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERR
(1 row)
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ERROR: value too long for type character(3)
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
json_query
------------
- "a
+
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
json_query
------------
- aa
+ aaa
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
json_query
------------
bb
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
- json_query
-------------
- "b
-(1 row)
-
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
+ERROR: value too long for type character(2)
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -828,12 +834,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
[1, 2]
(1 row)
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
- json_query
-------------
- [1,
-(1 row)
-
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
json_query
------------
@@ -1353,3 +1353,39 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
1
(1 row)
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index a1f924146e..70bff37a6d 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,7 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index dc6380141b..0d6482f384 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -53,7 +53,9 @@ SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$');
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
@@ -188,10 +190,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
@@ -235,7 +238,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
@@ -459,3 +461,16 @@ SELECT json_value('"aaa"', path RETURNING json) FROM jsonpaths;
SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xy);
SELECT JSON_QUERY(jsonb 'null', '$xy' PASSING 1 AS xyz);
SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
+
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
--
2.43.0
v3-0002-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchapplication/octet-stream; name=v3-0002-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchDownload
From 58746e21b076d8697fd1a2ce9b9056ce1f5a797b Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Wed, 5 Jun 2024 09:13:15 +0900
Subject: [PATCH v3 2/2] SQL/JSON: Use implicit casts for RETURNING type with
typmod
This fixes things so that the various SQL/JSON functions that support
specifying the type of the returned value using the RETURNING clause
perform an implicit cast to the target type at least in the cases
where the target type also specifies a length limit. That is to
ensure that the output values (including those specified in the
DEFAULT .. ON ERROR) that exceed the length produce an error instead
of being silently truncated to the specified length, which is a
behavior that agrees with what the SQL standard.
Reported-by: Alvaro Herrera
Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/parser/parse_expr.c | 24 +++++++++++++++++++++++-
src/test/regress/expected/sqljson.out | 17 +++++++++++++++++
src/test/regress/sql/sqljson.sql | 12 ++++++++++++
3 files changed, 52 insertions(+), 1 deletion(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 97a92f2b0d..f91eb5b658 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3583,6 +3583,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
+ int32 baseTypmod = returning->typmod;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3611,10 +3612,19 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}
+ /*
+ * For domains, consider the base type's typmod to decide whether to setup
+ * an implicit or explicit cast.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
- returning->typid, returning->typmod,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
@@ -3640,6 +3650,7 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
+ int32 baseTypmod = returning->typmod;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3677,6 +3688,17 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr() will
+ * create an implicit cast to the RETURNING types with typmod and there are
+ * no implicit casts from json(b) to such types. For domains, the base
+ * type's typmod will be considered, so do so here too.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ if (baseTypmod > 0)
+ placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
+ "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
index cbf8542d8d..4f91e2117e 100644
--- a/src/test/regress/expected/sqljson.out
+++ b/src/test/regress/expected/sqljson.out
@@ -1278,3 +1278,20 @@ CREATE OR REPLACE VIEW public.is_json_view AS
'{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
FROM generate_series(1, 3) i(i)
DROP VIEW is_json_view;
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+ERROR: value too long for type character varying(2)
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+ERROR: value too long for type character(2)
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
+ERROR: value for domain sqljson_char2 violates check constraint "sqljson_char2_check"
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
index e6e20175b0..bb2487e864 100644
--- a/src/test/regress/sql/sqljson.sql
+++ b/src/test/regress/sql/sqljson.sql
@@ -463,3 +463,15 @@ SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT
\sv is_json_view
DROP VIEW is_json_view;
+
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
--
2.43.0
On Thu, Jun 27, 2024 at 6:57 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Wed, Jun 26, 2024 at 11:46 PM jian he <jian.universality@gmail.com> wrote:
On Wed, Jun 26, 2024 at 8:39 PM Amit Langote <amitlangote09@gmail.com> wrote:
The RETURNING variant giving an error is what the standard asks us to
do apparently. I read Tom's last message on this thread as agreeing
to that, even though hesitantly. He can correct me if I got that
wrong.your patch will make domain and char(n) behavior inconsistent.
create domain char2 as char(2);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char2 ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);another example:
SELECT JSON_query(jsonb '"aaa"', '$' RETURNING char(2) keep quotes
default '"aaa"'::jsonb ON ERROR);
same value (jsonb "aaa") error on error will yield error,
but `default expression on error` can coerce the value to char(2),
which looks a little bit inconsistent, I think.Interesting examples, thanks for sharing.
Attached updated version should take into account that typmod may be
hiding under domains. Please test.SELECT JSON_VALUE(jsonb '111', '$' RETURNING queryfuncs_char2 default
'13' on error);
return
ERROR: value too long for type character(2)
should return 13I found out the source of the problem is in coerceJsonExprOutput
/*
* Use cast expression for domain types; we need CoerceToDomain here.
*/
if (get_typtype(returning->typid) != TYPTYPE_DOMAIN)
{
jsexpr->use_io_coercion = true;
return;
}Thanks for this test case and the analysis. Yes, using a cast
expression for coercion to the RETURNING type generally seems to be a
source of many problems that could've been solved by fixing things so
that only use_io_coercion and use_json_coercion are enough to handle
all the cases.I've attempted that in the attached 0001, which removes
JsonExpr.coercion_expr and a bunch of code around it.0002 is now the original patch minus the changes to make
JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE() behave as we would like,
because the changes in 0001 covers them. The changes for JsonBehavior
expression coercion as they were in the last version of the patch are
still needed, but I decided to move those into 0001 so that the
changes for query functions are all in 0001 and those for constructors
in 0002. It would be nice to get rid of that coerce_to_target_type()
call to coerce the "behavior expression" to RETURNING type, but I'm
leaving that as a task for another day.
Updated 0001 to remove outdated references, remove some more unnecessary code.
--
Thanks, Amit Langote
Attachments:
v4-0002-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchapplication/octet-stream; name=v4-0002-SQL-JSON-Use-implicit-casts-for-RETURNING-type-wi.patchDownload
From a197e450f5220369769be327a5ac40c52cfde8b9 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Wed, 5 Jun 2024 09:13:15 +0900
Subject: [PATCH v4 2/2] SQL/JSON: Use implicit casts for RETURNING type with
typmod
This fixes things so that the various SQL/JSON functions that support
specifying the type of the returned value using the RETURNING clause
perform an implicit cast to the target type at least in the cases
where the target type also specifies a length limit. That is to
ensure that the output values (including those specified in the
DEFAULT .. ON ERROR) that exceed the length produce an error instead
of being silently truncated to the specified length, which is a
behavior that agrees with what the SQL standard.
Reported-by: Alvaro Herrera
Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/parser/parse_expr.c | 24 +++++++++++++++++++++++-
src/test/regress/expected/sqljson.out | 17 +++++++++++++++++
src/test/regress/sql/sqljson.sql | 12 ++++++++++++
3 files changed, 52 insertions(+), 1 deletion(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 82e4b82755..699d0be751 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3582,6 +3582,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
+ int32 baseTypmod = returning->typmod;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3610,10 +3611,19 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}
+ /*
+ * For domains, consider the base type's typmod to decide whether to setup
+ * an implicit or explicit cast.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
- returning->typid, returning->typmod,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
@@ -3639,6 +3649,7 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
+ int32 baseTypmod = returning->typmod;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3676,6 +3687,17 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr() will
+ * create an implicit cast to the RETURNING types with typmod and there are
+ * no implicit casts from json(b) to such types. For domains, the base
+ * type's typmod will be considered, so do so here too.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ if (baseTypmod > 0)
+ placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
+ "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
index cbf8542d8d..4f91e2117e 100644
--- a/src/test/regress/expected/sqljson.out
+++ b/src/test/regress/expected/sqljson.out
@@ -1278,3 +1278,20 @@ CREATE OR REPLACE VIEW public.is_json_view AS
'{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
FROM generate_series(1, 3) i(i)
DROP VIEW is_json_view;
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+ERROR: value too long for type character varying(2)
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+ERROR: value too long for type character(2)
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
+ERROR: value for domain sqljson_char2 violates check constraint "sqljson_char2_check"
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
index e6e20175b0..bb2487e864 100644
--- a/src/test/regress/sql/sqljson.sql
+++ b/src/test/regress/sql/sqljson.sql
@@ -463,3 +463,15 @@ SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT
\sv is_json_view
DROP VIEW is_json_view;
+
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
--
2.43.0
v4-0001-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchapplication/octet-stream; name=v4-0001-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchDownload
From 405b8e7a1846fc22b7673fde10059b2fcbac9aef Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 27 Jun 2024 16:07:39 +0900
Subject: [PATCH v4 1/2] SQL/JSON: Always coerce JsonExpr result at runtime
Instead of looking up casts at parse time for converting the result
of JsonPath* query functions to the specified or the default
RETURNING type, always perform the conversion at runtime using either
the target type's input function or the function
json_populate_type(). The main motivation for this change is to
avoid ending up in some cases with a cast expression that doesn't
support soft handling of errors.
JsonExpr.coercion_expr which would store the cast expression is no
longer necessary, so remove.
---
src/backend/executor/execExpr.c | 42 +---
src/backend/executor/execExprInterp.c | 37 ++--
src/backend/nodes/nodeFuncs.c | 13 +-
src/backend/parser/parse_expr.c | 195 ++++--------------
src/backend/utils/adt/jsonfuncs.c | 22 +-
src/include/executor/execExpr.h | 1 +
src/include/nodes/primnodes.h | 6 -
src/include/utils/jsonfuncs.h | 1 +
.../regress/expected/sqljson_jsontable.out | 52 ++---
.../regress/expected/sqljson_queryfuncs.out | 72 +++++--
src/test/regress/sql/sqljson_jsontable.sql | 2 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 25 ++-
12 files changed, 189 insertions(+), 279 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 2bf86d06ef..a8be57d21b 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -92,7 +92,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
Datum *resv, bool *resnull,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull);
@@ -4318,7 +4318,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*/
- if (jsexpr->coercion_expr)
+ if (jsexpr->use_json_coercion)
{
scratch->opcode = EEOP_JUMP;
scratch->d.jump.jumpdone = state->steps_len + 1;
@@ -4337,33 +4337,12 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* NULL returned on NULL input as described above.
*/
jsestate->jump_eval_coercion = -1;
- if (jsexpr->coercion_expr)
- {
- Datum *save_innermost_caseval;
- bool *save_innermost_casenull;
- ErrorSaveContext *save_escontext;
-
- jsestate->jump_eval_coercion = state->steps_len;
-
- save_innermost_caseval = state->innermost_caseval;
- save_innermost_casenull = state->innermost_casenull;
- save_escontext = state->escontext;
-
- state->innermost_caseval = resv;
- state->innermost_casenull = resnull;
- state->escontext = escontext;
-
- ExecInitExprRec((Expr *) jsexpr->coercion_expr, state, resv, resnull);
-
- state->innermost_caseval = save_innermost_caseval;
- state->innermost_casenull = save_innermost_casenull;
- state->escontext = save_escontext;
- }
- else if (jsexpr->use_json_coercion)
+ if (jsexpr->use_json_coercion)
{
jsestate->jump_eval_coercion = state->steps_len;
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4435,8 +4414,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
@@ -4468,8 +4447,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
foreach(lc, jumps_to_end)
@@ -4488,7 +4467,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
*/
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4501,5 +4480,6 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
+ scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 852186312c..58b409cea4 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4303,8 +4303,14 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
- *op->resvalue = BoolGetDatum(exists);
*op->resnull = false;
+ if (jsexpr->use_json_coercion)
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ BoolGetDatum(exists) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ else
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4317,21 +4323,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*op->resnull = (DatumGetPointer(*op->resvalue) == NULL);
- /* Handle OMIT QUOTES. */
- if (!*op->resnull && jsexpr->omit_quotes)
- {
+ if (!*op->resnull && jsexpr->use_io_coercion)
val_string = JsonbUnquote(DatumGetJsonbP(*op->resvalue));
- /*
- * Pass the string as a text value to the cast expression if
- * one present. If not, use the input function call below to
- * do the coercion.
- */
- if (jump_eval_coercion >= 0)
- *op->resvalue =
- DirectFunctionCall1(textin,
- PointerGetDatum(val_string));
- }
break;
case JSON_VALUE_OP:
@@ -4355,6 +4349,11 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
val_string = DatumGetCString(DirectFunctionCall1(jsonb_out,
JsonbPGetDatum(JsonbValueToJsonb(jbv))));
}
+ else if (jsexpr->use_json_coercion)
+ {
+ *op->resvalue = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+ *op->resnull = false;
+ }
else
{
val_string = ExecGetJsonValueItemString(jbv, op->resnull);
@@ -4364,9 +4363,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
* expression if one present. If not, use the input
* function call below to do the coercion.
*/
- *op->resvalue = PointerGetDatum(val_string);
- if (jump_eval_coercion >= 0)
- *op->resvalue = DirectFunctionCall1(textin, *op->resvalue);
+ if (!jsexpr->use_io_coercion)
+ *op->resvalue = DirectFunctionCall1(textin,
+ CStringGetDatum(val_string));
}
}
break;
@@ -4545,7 +4544,9 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
op->d.jsonexpr_coercion.targettypmod,
&op->d.jsonexpr_coercion.json_populate_type_cache,
econtext->ecxt_per_query_memory,
- op->resnull, (Node *) escontext);
+ op->resnull,
+ op->d.jsonexpr_coercion.omit_quotes,
+ (Node *) escontext);
}
/*
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 89ee4b61f2..d2e2af4f81 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1006,10 +1006,7 @@ exprCollation(const Node *expr)
{
const JsonExpr *jsexpr = (JsonExpr *) expr;
- if (jsexpr->coercion_expr)
- coll = exprCollation(jsexpr->coercion_expr);
- else
- coll = jsexpr->collation;
+ coll = jsexpr->collation;
}
break;
case T_JsonBehavior:
@@ -1265,10 +1262,7 @@ exprSetCollation(Node *expr, Oid collation)
{
JsonExpr *jexpr = (JsonExpr *) expr;
- if (jexpr->coercion_expr)
- exprSetCollation((Node *) jexpr->coercion_expr, collation);
- else
- jexpr->collation = collation;
+ jexpr->collation = collation;
}
break;
case T_JsonBehavior:
@@ -2368,8 +2362,6 @@ expression_tree_walker_impl(Node *node,
return true;
if (WALK(jexpr->path_spec))
return true;
- if (WALK(jexpr->coercion_expr))
- return true;
if (WALK(jexpr->passing_values))
return true;
/* we assume walker doesn't care about passing_names */
@@ -3411,7 +3403,6 @@ expression_tree_mutator_impl(Node *node,
FLATCOPY(newnode, jexpr, JsonExpr);
MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
- MUTATE(newnode->coercion_expr, jexpr->coercion_expr, Node *);
MUTATE(newnode->passing_values, jexpr->passing_values, List *);
/* assume mutator does not care about passing_names */
MUTATE(newnode->on_empty, jexpr->on_empty, JsonBehavior *);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 00cd7358eb..82e4b82755 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -96,7 +96,6 @@ static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func);
static void transformJsonPassingArgs(ParseState *pstate, const char *constructName,
JsonFormatType format, List *args,
List **passing_values, List **passing_names);
-static void coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr);
static JsonBehavior *transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
JsonBehaviorType default_behavior,
JsonReturning *returning);
@@ -4360,39 +4359,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
- {
- Node *coercion_expr;
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
- int location = exprLocation((Node *) jsexpr);
-
- /*
- * We abuse CaseTestExpr here as placeholder to pass the
- * result of evaluating JSON_EXISTS to the coercion
- * expression.
- */
- placeholder->typeId = BOOLOID;
- placeholder->typeMod = -1;
- placeholder->collation = InvalidOid;
-
- coercion_expr =
- coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
- jsexpr->returning->typid,
- jsexpr->returning->typmod,
- COERCION_EXPLICIT,
- COERCE_IMPLICIT_CAST,
- location);
-
- if (coercion_expr == NULL)
- ereport(ERROR,
- (errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast type %s to %s",
- format_type_be(BOOLOID),
- format_type_be(jsexpr->returning->typid)),
- parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
-
- if (coercion_expr != (Node *) placeholder)
- jsexpr->coercion_expr = coercion_expr;
- }
+ jsexpr->use_json_coercion = true;
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
@@ -4416,7 +4383,20 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
jsexpr->omit_quotes = (func->quotes == JS_QUOTES_OMIT);
jsexpr->wrapper = func->wrapper;
- coerceJsonExprOutput(pstate, jsexpr);
+ /*
+ * Set up to coerce the result value of JsonPathValue() to the
+ * RETURNING type (default or user-specified), if needed. Also if
+ * OMIT QUOTES is true.
+ */
+ if (jsexpr->returning->typid != JSONBOID ||
+ jsexpr->omit_quotes)
+ {
+ /* Use IO coercion if OMIT QUOTES is true. */
+ if (jsexpr->omit_quotes)
+ jsexpr->use_io_coercion = true;
+ else
+ jsexpr->use_json_coercion = true;
+ }
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
@@ -4446,7 +4426,18 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* Always omit quotes from scalar strings. */
jsexpr->omit_quotes = true;
- coerceJsonExprOutput(pstate, jsexpr);
+ /*
+ * Set up to coerce the result value of JsonPathValue() to the
+ * RETURNING type (default or user-specified), if needed.
+ */
+ if (jsexpr->returning->typid != TEXTOID)
+ {
+ if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
+ DomainHasConstraints(jsexpr->returning->typid))
+ jsexpr->use_json_coercion = true;
+ else
+ jsexpr->use_io_coercion = true;
+ }
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
@@ -4509,121 +4500,6 @@ transformJsonPassingArgs(ParseState *pstate, const char *constructName,
}
}
-/*
- * Set up to coerce the result value of JSON_VALUE() / JSON_QUERY() to the
- * RETURNING type (default or user-specified), if needed.
- */
-static void
-coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
-{
- JsonReturning *returning = jsexpr->returning;
- Node *context_item = jsexpr->formatted_expr;
- int default_typmod;
- Oid default_typid;
- bool omit_quotes =
- jsexpr->op == JSON_QUERY_OP && jsexpr->omit_quotes;
- Node *coercion_expr = NULL;
-
- Assert(returning);
-
- /*
- * Check for cases where the coercion should be handled at runtime, that
- * is, without using a cast expression.
- */
- if (jsexpr->op == JSON_VALUE_OP)
- {
- /*
- * Use cast expressions for types with typmod and domain types.
- */
- if (returning->typmod == -1 &&
- get_typtype(returning->typid) != TYPTYPE_DOMAIN)
- {
- jsexpr->use_io_coercion = true;
- return;
- }
- }
- else if (jsexpr->op == JSON_QUERY_OP)
- {
- /*
- * Cast functions from jsonb to the following types (jsonb_bool() et
- * al) don't handle errors softly, so coerce either by calling
- * json_populate_type() or the type's input function so that any
- * errors are handled appropriately. The latter only if OMIT QUOTES is
- * true.
- */
- switch (returning->typid)
- {
- case BOOLOID:
- case NUMERICOID:
- case INT2OID:
- case INT4OID:
- case INT8OID:
- case FLOAT4OID:
- case FLOAT8OID:
- if (jsexpr->omit_quotes)
- jsexpr->use_io_coercion = true;
- else
- jsexpr->use_json_coercion = true;
- return;
- default:
- break;
- }
- }
-
- /* Look up a cast expression. */
-
- /*
- * For JSON_VALUE() and for JSON_QUERY() when OMIT QUOTES is true,
- * ExecEvalJsonExprPath() will convert a quote-stripped source value to
- * its text representation, so use TEXTOID as the source type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
- {
- default_typid = TEXTOID;
- default_typmod = -1;
- }
- else
- {
- default_typid = exprType(context_item);
- default_typmod = exprTypmod(context_item);
- }
-
- if (returning->typid != default_typid ||
- returning->typmod != default_typmod)
- {
- /*
- * We abuse CaseTestExpr here as placeholder to pass the result of
- * jsonpath evaluation as input to the coercion expression.
- */
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
-
- placeholder->typeId = default_typid;
- placeholder->typeMod = default_typmod;
-
- coercion_expr = coerceJsonFuncExpr(pstate, (Node *) placeholder,
- returning, false);
- if (coercion_expr == (Node *) placeholder)
- coercion_expr = NULL;
- }
-
- jsexpr->coercion_expr = coercion_expr;
-
- if (coercion_expr == NULL)
- {
- /*
- * Either no cast was found or coercion is unnecessary but still must
- * convert the string value to the output type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
- jsexpr->use_io_coercion = true;
- else
- jsexpr->use_json_coercion = true;
- }
-
- Assert(jsexpr->coercion_expr != NULL ||
- (jsexpr->use_io_coercion != jsexpr->use_json_coercion));
-}
-
/*
* Recursively checks if the given expression, or its sub-node in some cases,
* is valid for using as an ON ERROR / ON EMPTY DEFAULT expression.
@@ -4716,11 +4592,24 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
btype == default_behavior))
coerce_at_runtime = true;
else
+ {
+ int32 baseTypmod = returning->typmod;
+
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
+ if (baseTypmod > 0)
+ expr = coerce_to_specific_type(pstate, expr, TEXTOID,
+ "JSON_FUNCTION()");
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, returning->typmod,
- COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
+ COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
+ }
if (coerced_expr == NULL)
ereport(ERROR,
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index ab5aa0ccb8..b26a1cbfcb 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -3338,7 +3338,7 @@ Datum
json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
- bool *isnull,
+ bool *isnull, bool omit_quotes,
Node *escontext)
{
JsValue jsv = {0};
@@ -3368,10 +3368,22 @@ json_populate_type(Datum json_val, Oid json_type,
jsv.val.jsonb = &jbv;
- /* fill binary jsonb value pointing to jb */
- jbv.type = jbvBinary;
- jbv.val.binary.data = &jsonb->root;
- jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ if (omit_quotes)
+ {
+ char *str = JsonbUnquote(DatumGetJsonbP(json_val));
+
+ /* fill the quote-stripped string */
+ jbv.type = jbvString;
+ jbv.val.string.len = strlen(str);
+ jbv.val.string.val = str;
+ }
+ else
+ {
+ /* fill binary jsonb value pointing to jb */
+ jbv.type = jbvBinary;
+ jbv.val.binary.data = &jsonb->root;
+ jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ }
}
if (*cache == NULL)
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 64698202a5..55337d4916 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -707,6 +707,7 @@ typedef struct ExprEvalStep
{
Oid targettype;
int32 targettypmod;
+ bool omit_quotes;
void *json_populate_type_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4830efc573..dacc75f2af 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1838,13 +1838,7 @@ typedef struct JsonExpr
/*
* Information about converting the result of jsonpath functions
* JsonPathQuery() and JsonPathValue() to the RETURNING type.
- *
- * coercion_expr is a cast expression if the parser can find it for the
- * source and the target type. If not, either use_io_coercion or
- * use_json_coercion is set to determine the coercion method to use at
- * runtime; see coerceJsonExprOutput() and ExecInitJsonExpr().
*/
- Node *coercion_expr;
bool use_io_coercion;
bool use_json_coercion;
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 190e13284b..93384d900a 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -93,6 +93,7 @@ extern Datum json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
bool *isnull,
+ bool omit_quotes,
Node *escontext);
#endif
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index cee90cead1..cf43442891 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -103,14 +103,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | false | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | true | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | | | | [1,2] | "[1,2]" | "[1,2]"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
@@ -137,14 +137,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | | | "aaaaaaa" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | | | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | | | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | | | {"aaa": 123} | {"aaa": 123}
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | | | "[1,2]" | [1, 2]
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | | | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -555,31 +555,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to smallint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to smallint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to bigint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to bigint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to real
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
- ^
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
------
- fal
+ERROR: cannot cast behavior expression of type boolean to real
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+-------
+ false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to json
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to json
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to jsonb
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
- ^
+ERROR: cannot cast behavior expression of type boolean to jsonb
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 9cb250a27a..ea136eefa7 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -234,10 +234,18 @@ SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
aaa
(1 row)
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
+ERROR: value too long for type character(2)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
json_value
------------
- aa
+
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ json_value
+------------
+ aaa
(1 row)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
@@ -636,30 +644,28 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERR
(1 row)
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ERROR: value too long for type character(3)
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
json_query
------------
- "a
+
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
json_query
------------
- aa
+ aaa
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
json_query
------------
bb
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
- json_query
-------------
- "b
-(1 row)
-
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
+ERROR: value too long for type character(2)
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -828,12 +834,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
[1, 2]
(1 row)
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
- json_query
-------------
- [1,
-(1 row)
-
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
json_query
------------
@@ -1353,3 +1353,39 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
1
(1 row)
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index a1f924146e..70bff37a6d 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,7 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index dc6380141b..0d6482f384 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -53,7 +53,9 @@ SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$');
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
@@ -188,10 +190,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
@@ -235,7 +238,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
@@ -459,3 +461,16 @@ SELECT json_value('"aaa"', path RETURNING json) FROM jsonpaths;
SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xy);
SELECT JSON_QUERY(jsonb 'null', '$xy' PASSING 1 AS xyz);
SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
+
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
--
2.43.0
On Thu, Jun 27, 2024 at 7:48 PM Amit Langote <amitlangote09@gmail.com> wrote:
I've attempted that in the attached 0001, which removes
JsonExpr.coercion_expr and a bunch of code around it.0002 is now the original patch minus the changes to make
JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE() behave as we would like,
because the changes in 0001 covers them. The changes for JsonBehavior
expression coercion as they were in the last version of the patch are
still needed, but I decided to move those into 0001 so that the
changes for query functions are all in 0001 and those for constructors
in 0002. It would be nice to get rid of that coerce_to_target_type()
call to coerce the "behavior expression" to RETURNING type, but I'm
leaving that as a task for another day.Updated 0001 to remove outdated references, remove some more unnecessary code.
i found some remaining references of "coercion_expr" should be removed.
src/include/nodes/primnodes.h
/* JsonExpr's collation, if coercion_expr is NULL. */
src/include/nodes/execnodes.h
/*
* Address of the step to coerce the result value of jsonpath evaluation
* to the RETURNING type using JsonExpr.coercion_expr. -1 if no coercion
* is necessary or if either JsonExpr.use_io_coercion or
* JsonExpr.use_json_coercion is true.
*/
int jump_eval_coercion;
src/backend/jit/llvm/llvmjit_expr.c
/* coercion_expr code */
LLVMPositionBuilderAtEnd(b, b_coercion);
if (jsestate->jump_eval_coercion >= 0)
LLVMBuildBr(b, opblocks[jsestate->jump_eval_coercion]);
else
LLVMBuildUnreachable(b);
src/backend/executor/execExprInterp.c
/*
* Checks if an error occurred either when evaluating JsonExpr.coercion_expr or
* in ExecEvalJsonCoercion(). If so, this sets JsonExprState.error to trigger
* the ON ERROR handling steps.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
{
}
if (jbv == NULL)
{
/* Will be coerced with coercion_expr, if any. */
*op->resvalue = (Datum) 0;
*op->resnull = true;
}
src/backend/executor/execExpr.c
/*
* Jump to coerce the NULL using coercion_expr if present. Coercing NULL
* is only interesting when the RETURNING type is a domain whose
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*/
/*
* Jump to coerce the NULL using coercion_expr if present. Coercing NULL
* is only interesting when the RETURNING type is a domain whose
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*/
On Fri, Jun 28, 2024 at 3:14 PM jian he <jian.universality@gmail.com> wrote:
On Thu, Jun 27, 2024 at 7:48 PM Amit Langote <amitlangote09@gmail.com> wrote:
I've attempted that in the attached 0001, which removes
JsonExpr.coercion_expr and a bunch of code around it.0002 is now the original patch minus the changes to make
JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE() behave as we would like,
because the changes in 0001 covers them. The changes for JsonBehavior
expression coercion as they were in the last version of the patch are
still needed, but I decided to move those into 0001 so that the
changes for query functions are all in 0001 and those for constructors
in 0002. It would be nice to get rid of that coerce_to_target_type()
call to coerce the "behavior expression" to RETURNING type, but I'm
leaving that as a task for another day.Updated 0001 to remove outdated references, remove some more unnecessary code.
i found some remaining references of "coercion_expr" should be removed.
src/include/nodes/primnodes.h
/* JsonExpr's collation, if coercion_expr is NULL. */src/include/nodes/execnodes.h
/*
* Address of the step to coerce the result value of jsonpath evaluation
* to the RETURNING type using JsonExpr.coercion_expr. -1 if no coercion
* is necessary or if either JsonExpr.use_io_coercion or
* JsonExpr.use_json_coercion is true.
*/
int jump_eval_coercion;src/backend/jit/llvm/llvmjit_expr.c
/* coercion_expr code */
LLVMPositionBuilderAtEnd(b, b_coercion);
if (jsestate->jump_eval_coercion >= 0)
LLVMBuildBr(b, opblocks[jsestate->jump_eval_coercion]);
else
LLVMBuildUnreachable(b);src/backend/executor/execExprInterp.c
/*
* Checks if an error occurred either when evaluating JsonExpr.coercion_expr or
* in ExecEvalJsonCoercion(). If so, this sets JsonExprState.error to trigger
* the ON ERROR handling steps.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
{
}if (jbv == NULL)
{
/* Will be coerced with coercion_expr, if any. */
*op->resvalue = (Datum) 0;
*op->resnull = true;
}src/backend/executor/execExpr.c
/*
* Jump to coerce the NULL using coercion_expr if present. Coercing NULL
* is only interesting when the RETURNING type is a domain whose
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*//*
* Jump to coerce the NULL using coercion_expr if present. Coercing NULL
* is only interesting when the RETURNING type is a domain whose
* constraints must be checked. jsexpr->coercion_expr containing a
* CoerceToDomain node must have been set in that case.
*/
Thanks for checking.
Will push the attached 0001 and 0002 shortly.
--
Thanks, Amit Langote
Attachments:
v5-0001-SQL-JSON-Fix-coercion-of-constructor-outputs-to-t.patchapplication/octet-stream; name=v5-0001-SQL-JSON-Fix-coercion-of-constructor-outputs-to-t.patchDownload
From 6f820fbfb68a900e7f478bba89895324d9a64a48 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Wed, 5 Jun 2024 09:13:15 +0900
Subject: [PATCH v5 1/2] SQL/JSON: Fix coercion of constructor outputs to types
with typmod
Ensure SQL/JSON constructor functions that allow specifying the
target type using the RETURNING clause perform implicit cast to
that type. This ensures that output values that exceed the specified
length produce an error rather than being silently truncated. This
behavior conforms to the SQL standard.
Reported-by: Alvaro Herrera <alvherre@alvh.no-ip.org>
Reviewed-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/parser/parse_expr.c | 24 +++++++++++++++++++++++-
src/test/regress/expected/sqljson.out | 17 +++++++++++++++++
src/test/regress/sql/sqljson.sql | 12 ++++++++++++
3 files changed, 52 insertions(+), 1 deletion(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 233b7b1cc9..df766cdec1 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3583,6 +3583,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
+ int32 baseTypmod = returning->typmod;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3611,10 +3612,19 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}
+ /*
+ * For domains, consider the base type's typmod to decide whether to setup
+ * an implicit or explicit cast.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
- returning->typid, returning->typmod,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
@@ -3640,6 +3650,7 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
+ int32 baseTypmod = returning->typmod;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3677,6 +3688,17 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr()
+ * will create an implicit cast to the RETURNING types with typmod and
+ * there are no implicit casts from json(b) to such types. For domains,
+ * the base type's typmod will be considered, so do so here too.
+ */
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ if (baseTypmod > 0)
+ placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
+ "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
diff --git a/src/test/regress/expected/sqljson.out b/src/test/regress/expected/sqljson.out
index cbf8542d8d..4f91e2117e 100644
--- a/src/test/regress/expected/sqljson.out
+++ b/src/test/regress/expected/sqljson.out
@@ -1278,3 +1278,20 @@ CREATE OR REPLACE VIEW public.is_json_view AS
'{}'::text IS JSON OBJECT WITH UNIQUE KEYS AS object
FROM generate_series(1, 3) i(i)
DROP VIEW is_json_view;
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+ERROR: value too long for type character varying(2)
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+ERROR: value too long for type character varying(2)
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+ERROR: value too long for type character varying(2)
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+ERROR: value too long for type character(2)
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
+ERROR: value for domain sqljson_char2 violates check constraint "sqljson_char2_check"
diff --git a/src/test/regress/sql/sqljson.sql b/src/test/regress/sql/sqljson.sql
index e6e20175b0..bb2487e864 100644
--- a/src/test/regress/sql/sqljson.sql
+++ b/src/test/regress/sql/sqljson.sql
@@ -463,3 +463,15 @@ SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT
\sv is_json_view
DROP VIEW is_json_view;
+
+-- Test implicit coercion to a fixed-length type specified in RETURNING
+SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2));
+SELECT JSON_OBJECT('a': JSON_OBJECT('b': 1 RETURNING varchar(2)));
+SELECT JSON_ARRAY(JSON_ARRAY('{ "a" : 123 }' RETURNING varchar(2)));
+SELECT JSON_ARRAYAGG(('111' || i)::bytea FORMAT JSON NULL ON NULL RETURNING varchar(2)) FROM generate_series(1,1) i;
+SELECT JSON_OBJECTAGG(i: ('111' || i)::bytea FORMAT JSON WITH UNIQUE RETURNING varchar(2)) FROM generate_series(1, 1) i;
+
+-- Now try domain over fixed-length type
+CREATE DOMAIN sqljson_char2 AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_SERIALIZE('123' RETURNING sqljson_char2);
+SELECT JSON_SERIALIZE('12' RETURNING sqljson_char2);
--
2.43.0
v5-0002-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchapplication/octet-stream; name=v5-0002-SQL-JSON-Always-coerce-JsonExpr-result-at-runtime.patchDownload
From 091027bde219a1712b117dda9679aa2d6481b4ac Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 27 Jun 2024 16:07:39 +0900
Subject: [PATCH v5 2/2] SQL/JSON: Always coerce JsonExpr result at runtime
Instead of looking up casts at parse time for converting the result
of JsonPath* query functions to the specified or the default
RETURNING type, always perform the conversion at runtime using either
the target type's input function or the function
json_populate_type().
There are two motivations for this change:
1. json_populate_type() coerces to types with typmod such that any
string values that exceed length limit cause an error instead of
silent truncation, which is necessary to be standard-conforming
2. It was possible to end up with a cast expression that doesn't
support soft handling of errors causing bugs in handling the ON
ERROR clause
JsonExpr.coercion_expr which would store the cast expression is no
longer necessary, so remove.
Reviewed-by: Jian He <jian.universality@gmail.com>
Discussion: Discussion: https://postgr.es/m/202405271326.5a5rprki64aw%40alvherre.pgsql
---
src/backend/executor/execExpr.c | 52 ++---
src/backend/executor/execExprInterp.c | 46 ++---
src/backend/jit/llvm/llvmjit_expr.c | 2 +-
src/backend/nodes/nodeFuncs.c | 13 +-
src/backend/parser/parse_expr.c | 188 ++++--------------
src/backend/utils/adt/jsonfuncs.c | 48 +++--
src/include/executor/execExpr.h | 1 +
src/include/nodes/execnodes.h | 5 +-
src/include/nodes/primnodes.h | 8 +-
src/include/utils/jsonfuncs.h | 1 +
.../regress/expected/sqljson_jsontable.out | 52 ++---
.../regress/expected/sqljson_queryfuncs.out | 72 +++++--
src/test/regress/sql/sqljson_jsontable.sql | 2 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 25 ++-
14 files changed, 210 insertions(+), 305 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 2bf86d06ef..ccd4863778 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -92,7 +92,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
Datum *resv, bool *resnull,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull);
@@ -4313,13 +4313,15 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalPushStep(state, scratch);
/*
- * Jump to coerce the NULL using coercion_expr if present. Coercing NULL
- * is only interesting when the RETURNING type is a domain whose
- * constraints must be checked. jsexpr->coercion_expr containing a
- * CoerceToDomain node must have been set in that case.
+ * Jump to coerce the NULL using json_populate_type() if needed. Coercing
+ * NULL is only interesting when the RETURNING type is a domain whose
+ * constraints must be checked. jsexpr->use_json_coercion must have been
+ * set in that case.
*/
- if (jsexpr->coercion_expr)
+ if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
+ DomainHasConstraints(jsexpr->returning->typid))
{
+ Assert(jsexpr->use_json_coercion);
scratch->opcode = EEOP_JUMP;
scratch->d.jump.jumpdone = state->steps_len + 1;
ExprEvalPushStep(state, scratch);
@@ -4337,33 +4339,12 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* NULL returned on NULL input as described above.
*/
jsestate->jump_eval_coercion = -1;
- if (jsexpr->coercion_expr)
- {
- Datum *save_innermost_caseval;
- bool *save_innermost_casenull;
- ErrorSaveContext *save_escontext;
-
- jsestate->jump_eval_coercion = state->steps_len;
-
- save_innermost_caseval = state->innermost_caseval;
- save_innermost_casenull = state->innermost_casenull;
- save_escontext = state->escontext;
-
- state->innermost_caseval = resv;
- state->innermost_casenull = resnull;
- state->escontext = escontext;
-
- ExecInitExprRec((Expr *) jsexpr->coercion_expr, state, resv, resnull);
-
- state->innermost_caseval = save_innermost_caseval;
- state->innermost_casenull = save_innermost_casenull;
- state->escontext = save_escontext;
- }
- else if (jsexpr->use_json_coercion)
+ if (jsexpr->use_json_coercion)
{
jsestate->jump_eval_coercion = state->steps_len;
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv, resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4435,8 +4416,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
@@ -4468,8 +4449,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext, resv,
- resnull);
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, resv, resnull);
}
foreach(lc, jumps_to_end)
@@ -4488,7 +4469,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
*/
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
- ErrorSaveContext *escontext,
+ ErrorSaveContext *escontext, bool omit_quotes,
Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4501,5 +4482,6 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
+ scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 852186312c..918b63f30a 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4303,8 +4303,14 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
- *op->resvalue = BoolGetDatum(exists);
*op->resnull = false;
+ if (jsexpr->use_json_coercion)
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ BoolGetDatum(exists) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ else
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4316,22 +4322,6 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
jsexpr->column_name);
*op->resnull = (DatumGetPointer(*op->resvalue) == NULL);
-
- /* Handle OMIT QUOTES. */
- if (!*op->resnull && jsexpr->omit_quotes)
- {
- val_string = JsonbUnquote(DatumGetJsonbP(*op->resvalue));
-
- /*
- * Pass the string as a text value to the cast expression if
- * one present. If not, use the input function call below to
- * do the coercion.
- */
- if (jump_eval_coercion >= 0)
- *op->resvalue =
- DirectFunctionCall1(textin,
- PointerGetDatum(val_string));
- }
break;
case JSON_VALUE_OP:
@@ -4343,7 +4333,7 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (jbv == NULL)
{
- /* Will be coerced with coercion_expr, if any. */
+ /* Will be coerced with json_populate_type(), if needed. */
*op->resvalue = (Datum) 0;
*op->resnull = true;
}
@@ -4355,6 +4345,11 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
val_string = DatumGetCString(DirectFunctionCall1(jsonb_out,
JsonbPGetDatum(JsonbValueToJsonb(jbv))));
}
+ else if (jsexpr->use_json_coercion)
+ {
+ *op->resvalue = JsonbPGetDatum(JsonbValueToJsonb(jbv));
+ *op->resnull = false;
+ }
else
{
val_string = ExecGetJsonValueItemString(jbv, op->resnull);
@@ -4364,9 +4359,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
* expression if one present. If not, use the input
* function call below to do the coercion.
*/
- *op->resvalue = PointerGetDatum(val_string);
- if (jump_eval_coercion >= 0)
- *op->resvalue = DirectFunctionCall1(textin, *op->resvalue);
+ if (!jsexpr->use_io_coercion)
+ *op->resvalue = DirectFunctionCall1(textin,
+ CStringGetDatum(val_string));
}
}
break;
@@ -4545,13 +4540,14 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
op->d.jsonexpr_coercion.targettypmod,
&op->d.jsonexpr_coercion.json_populate_type_cache,
econtext->ecxt_per_query_memory,
- op->resnull, (Node *) escontext);
+ op->resnull,
+ op->d.jsonexpr_coercion.omit_quotes,
+ (Node *) escontext);
}
/*
- * Checks if an error occurred either when evaluating JsonExpr.coercion_expr or
- * in ExecEvalJsonCoercion(). If so, this sets JsonExprState.error to trigger
- * the ON ERROR handling steps.
+ * Checks if an error occurred in ExecEvalJsonCoercion(). If so, this sets
+ * JsonExprState.error to trigger the ON ERROR handling steps.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
diff --git a/src/backend/jit/llvm/llvmjit_expr.c b/src/backend/jit/llvm/llvmjit_expr.c
index 9e0efd2668..306aea82d3 100644
--- a/src/backend/jit/llvm/llvmjit_expr.c
+++ b/src/backend/jit/llvm/llvmjit_expr.c
@@ -2010,7 +2010,7 @@ llvm_compile_expr(ExprState *state)
v_jump_coercion = l_int32_const(lc, jsestate->jump_eval_coercion);
LLVMAddCase(v_switch, v_jump_coercion, b_coercion);
}
- /* coercion_expr code */
+ /* jump_eval_coercion code */
LLVMPositionBuilderAtEnd(b, b_coercion);
if (jsestate->jump_eval_coercion >= 0)
LLVMBuildBr(b, opblocks[jsestate->jump_eval_coercion]);
diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c
index 89ee4b61f2..d2e2af4f81 100644
--- a/src/backend/nodes/nodeFuncs.c
+++ b/src/backend/nodes/nodeFuncs.c
@@ -1006,10 +1006,7 @@ exprCollation(const Node *expr)
{
const JsonExpr *jsexpr = (JsonExpr *) expr;
- if (jsexpr->coercion_expr)
- coll = exprCollation(jsexpr->coercion_expr);
- else
- coll = jsexpr->collation;
+ coll = jsexpr->collation;
}
break;
case T_JsonBehavior:
@@ -1265,10 +1262,7 @@ exprSetCollation(Node *expr, Oid collation)
{
JsonExpr *jexpr = (JsonExpr *) expr;
- if (jexpr->coercion_expr)
- exprSetCollation((Node *) jexpr->coercion_expr, collation);
- else
- jexpr->collation = collation;
+ jexpr->collation = collation;
}
break;
case T_JsonBehavior:
@@ -2368,8 +2362,6 @@ expression_tree_walker_impl(Node *node,
return true;
if (WALK(jexpr->path_spec))
return true;
- if (WALK(jexpr->coercion_expr))
- return true;
if (WALK(jexpr->passing_values))
return true;
/* we assume walker doesn't care about passing_names */
@@ -3411,7 +3403,6 @@ expression_tree_mutator_impl(Node *node,
FLATCOPY(newnode, jexpr, JsonExpr);
MUTATE(newnode->formatted_expr, jexpr->formatted_expr, Node *);
MUTATE(newnode->path_spec, jexpr->path_spec, Node *);
- MUTATE(newnode->coercion_expr, jexpr->coercion_expr, Node *);
MUTATE(newnode->passing_values, jexpr->passing_values, List *);
/* assume mutator does not care about passing_names */
MUTATE(newnode->on_empty, jexpr->on_empty, JsonBehavior *);
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index df766cdec1..75987b2aa6 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -96,7 +96,6 @@ static Node *transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func);
static void transformJsonPassingArgs(ParseState *pstate, const char *constructName,
JsonFormatType format, List *args,
List **passing_values, List **passing_names);
-static void coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr);
static JsonBehavior *transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
JsonBehaviorType default_behavior,
JsonReturning *returning);
@@ -4492,39 +4491,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
- {
- Node *coercion_expr;
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
- int location = exprLocation((Node *) jsexpr);
-
- /*
- * We abuse CaseTestExpr here as placeholder to pass the
- * result of evaluating JSON_EXISTS to the coercion
- * expression.
- */
- placeholder->typeId = BOOLOID;
- placeholder->typeMod = -1;
- placeholder->collation = InvalidOid;
-
- coercion_expr =
- coerce_to_target_type(pstate, (Node *) placeholder, BOOLOID,
- jsexpr->returning->typid,
- jsexpr->returning->typmod,
- COERCION_EXPLICIT,
- COERCE_IMPLICIT_CAST,
- location);
-
- if (coercion_expr == NULL)
- ereport(ERROR,
- (errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast type %s to %s",
- format_type_be(BOOLOID),
- format_type_be(jsexpr->returning->typid)),
- parser_coercion_errposition(pstate, location, (Node *) jsexpr)));
-
- if (coercion_expr != (Node *) placeholder)
- jsexpr->coercion_expr = coercion_expr;
- }
+ jsexpr->use_json_coercion = true;
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
@@ -4548,7 +4515,13 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
jsexpr->omit_quotes = (func->quotes == JS_QUOTES_OMIT);
jsexpr->wrapper = func->wrapper;
- coerceJsonExprOutput(pstate, jsexpr);
+ /*
+ * Set up to coerce the result value of JsonPathValue() to the
+ * RETURNING type (default or user-specified), if needed. Also
+ * if OMIT QUOTES is specified.
+ */
+ if (jsexpr->returning->typid != JSONBOID || jsexpr->omit_quotes)
+ jsexpr->use_json_coercion = true;
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
@@ -4578,7 +4551,18 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* Always omit quotes from scalar strings. */
jsexpr->omit_quotes = true;
- coerceJsonExprOutput(pstate, jsexpr);
+ /*
+ * Set up to coerce the result value of JsonPathValue() to the
+ * RETURNING type (default or user-specified), if needed.
+ */
+ if (jsexpr->returning->typid != TEXTOID)
+ {
+ if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
+ DomainHasConstraints(jsexpr->returning->typid))
+ jsexpr->use_json_coercion = true;
+ else
+ jsexpr->use_io_coercion = true;
+ }
/* Assume NULL ON EMPTY when ON EMPTY is not specified. */
jsexpr->on_empty = transformJsonBehavior(pstate, func->on_empty,
@@ -4641,121 +4625,6 @@ transformJsonPassingArgs(ParseState *pstate, const char *constructName,
}
}
-/*
- * Set up to coerce the result value of JSON_VALUE() / JSON_QUERY() to the
- * RETURNING type (default or user-specified), if needed.
- */
-static void
-coerceJsonExprOutput(ParseState *pstate, JsonExpr *jsexpr)
-{
- JsonReturning *returning = jsexpr->returning;
- Node *context_item = jsexpr->formatted_expr;
- int default_typmod;
- Oid default_typid;
- bool omit_quotes =
- jsexpr->op == JSON_QUERY_OP && jsexpr->omit_quotes;
- Node *coercion_expr = NULL;
-
- Assert(returning);
-
- /*
- * Check for cases where the coercion should be handled at runtime, that
- * is, without using a cast expression.
- */
- if (jsexpr->op == JSON_VALUE_OP)
- {
- /*
- * Use cast expressions for types with typmod and domain types.
- */
- if (returning->typmod == -1 &&
- get_typtype(returning->typid) != TYPTYPE_DOMAIN)
- {
- jsexpr->use_io_coercion = true;
- return;
- }
- }
- else if (jsexpr->op == JSON_QUERY_OP)
- {
- /*
- * Cast functions from jsonb to the following types (jsonb_bool() et
- * al) don't handle errors softly, so coerce either by calling
- * json_populate_type() or the type's input function so that any
- * errors are handled appropriately. The latter only if OMIT QUOTES is
- * true.
- */
- switch (returning->typid)
- {
- case BOOLOID:
- case NUMERICOID:
- case INT2OID:
- case INT4OID:
- case INT8OID:
- case FLOAT4OID:
- case FLOAT8OID:
- if (jsexpr->omit_quotes)
- jsexpr->use_io_coercion = true;
- else
- jsexpr->use_json_coercion = true;
- return;
- default:
- break;
- }
- }
-
- /* Look up a cast expression. */
-
- /*
- * For JSON_VALUE() and for JSON_QUERY() when OMIT QUOTES is true,
- * ExecEvalJsonExprPath() will convert a quote-stripped source value to
- * its text representation, so use TEXTOID as the source type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
- {
- default_typid = TEXTOID;
- default_typmod = -1;
- }
- else
- {
- default_typid = exprType(context_item);
- default_typmod = exprTypmod(context_item);
- }
-
- if (returning->typid != default_typid ||
- returning->typmod != default_typmod)
- {
- /*
- * We abuse CaseTestExpr here as placeholder to pass the result of
- * jsonpath evaluation as input to the coercion expression.
- */
- CaseTestExpr *placeholder = makeNode(CaseTestExpr);
-
- placeholder->typeId = default_typid;
- placeholder->typeMod = default_typmod;
-
- coercion_expr = coerceJsonFuncExpr(pstate, (Node *) placeholder,
- returning, false);
- if (coercion_expr == (Node *) placeholder)
- coercion_expr = NULL;
- }
-
- jsexpr->coercion_expr = coercion_expr;
-
- if (coercion_expr == NULL)
- {
- /*
- * Either no cast was found or coercion is unnecessary but still must
- * convert the string value to the output type.
- */
- if (omit_quotes || jsexpr->op == JSON_VALUE_OP)
- jsexpr->use_io_coercion = true;
- else
- jsexpr->use_json_coercion = true;
- }
-
- Assert(jsexpr->coercion_expr != NULL ||
- (jsexpr->use_io_coercion != jsexpr->use_json_coercion));
-}
-
/*
* Recursively checks if the given expression, or its sub-node in some cases,
* is valid for using as an ON ERROR / ON EMPTY DEFAULT expression.
@@ -4848,11 +4717,24 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
btype == default_behavior))
coerce_at_runtime = true;
else
+ {
+ int32 baseTypmod = returning->typmod;
+
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
+ if (baseTypmod > 0)
+ expr = coerce_to_specific_type(pstate, expr, TEXTOID,
+ "JSON_FUNCTION()");
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, returning->typmod,
- COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
+ COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
+ }
if (coerced_expr == NULL)
ereport(ERROR,
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index ab5aa0ccb8..48c3f88140 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -447,12 +447,13 @@ static Datum populate_composite(CompositeIOData *io, Oid typid,
HeapTupleHeader defaultval, JsValue *jsv, bool *isnull,
Node *escontext);
static Datum populate_scalar(ScalarIOData *io, Oid typid, int32 typmod, JsValue *jsv,
- bool *isnull, Node *escontext);
+ bool *isnull, Node *escontext, bool omit_quotes);
static void prepare_column_cache(ColumnIOData *column, Oid typid, int32 typmod,
MemoryContext mcxt, bool need_scalar);
static Datum populate_record_field(ColumnIOData *col, Oid typid, int32 typmod,
const char *colname, MemoryContext mcxt, Datum defaultval,
- JsValue *jsv, bool *isnull, Node *escontext);
+ JsValue *jsv, bool *isnull, Node *escontext,
+ bool omit_quotes);
static RecordIOData *allocate_record_info(MemoryContext mcxt, int ncolumns);
static bool JsObjectGetField(JsObject *obj, char *field, JsValue *jsv);
static void populate_recordset_record(PopulateRecordsetState *state, JsObject *obj);
@@ -2622,7 +2623,8 @@ populate_array_element(PopulateArrayContext *ctx, int ndim, JsValue *jsv)
ctx->aio->element_type,
ctx->aio->element_typmod,
NULL, ctx->mcxt, PointerGetDatum(NULL),
- jsv, &element_isnull, ctx->escontext);
+ jsv, &element_isnull, ctx->escontext,
+ false);
/* Nothing to do on an error. */
if (SOFT_ERROR_OCCURRED(ctx->escontext))
return false;
@@ -3119,7 +3121,7 @@ populate_composite(CompositeIOData *io,
*/
static Datum
populate_scalar(ScalarIOData *io, Oid typid, int32 typmod, JsValue *jsv,
- bool *isnull, Node *escontext)
+ bool *isnull, Node *escontext, bool omit_quotes)
{
Datum res;
char *str = NULL;
@@ -3162,7 +3164,9 @@ populate_scalar(ScalarIOData *io, Oid typid, int32 typmod, JsValue *jsv,
{
JsonbValue *jbv = jsv->val.jsonb;
- if (typid == JSONBOID)
+ if (jbv->type == jbvString && omit_quotes)
+ str = pnstrdup(jbv->val.string.val, jbv->val.string.len);
+ else if (typid == JSONBOID)
{
Jsonb *jsonb = JsonbValueToJsonb(jbv); /* directly use jsonb */
@@ -3225,7 +3229,7 @@ populate_domain(DomainIOData *io,
res = populate_record_field(io->base_io,
io->base_typid, io->base_typmod,
colname, mcxt, PointerGetDatum(NULL),
- jsv, isnull, escontext);
+ jsv, isnull, escontext, false);
Assert(!*isnull || SOFT_ERROR_OCCURRED(escontext));
}
@@ -3338,7 +3342,7 @@ Datum
json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
- bool *isnull,
+ bool *isnull, bool omit_quotes,
Node *escontext)
{
JsValue jsv = {0};
@@ -3368,10 +3372,22 @@ json_populate_type(Datum json_val, Oid json_type,
jsv.val.jsonb = &jbv;
- /* fill binary jsonb value pointing to jb */
- jbv.type = jbvBinary;
- jbv.val.binary.data = &jsonb->root;
- jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ if (omit_quotes)
+ {
+ char *str = JsonbUnquote(DatumGetJsonbP(json_val));
+
+ /* fill the quote-stripped string */
+ jbv.type = jbvString;
+ jbv.val.string.len = strlen(str);
+ jbv.val.string.val = str;
+ }
+ else
+ {
+ /* fill binary jsonb value pointing to jb */
+ jbv.type = jbvBinary;
+ jbv.val.binary.data = &jsonb->root;
+ jbv.val.binary.len = VARSIZE(jsonb) - VARHDRSZ;
+ }
}
if (*cache == NULL)
@@ -3379,7 +3395,7 @@ json_populate_type(Datum json_val, Oid json_type,
return populate_record_field(*cache, typid, typmod, NULL, mcxt,
PointerGetDatum(NULL), &jsv, isnull,
- escontext);
+ escontext, omit_quotes);
}
/* recursively populate a record field or an array element from a json/jsonb value */
@@ -3392,7 +3408,8 @@ populate_record_field(ColumnIOData *col,
Datum defaultval,
JsValue *jsv,
bool *isnull,
- Node *escontext)
+ Node *escontext,
+ bool omit_scalar_quotes)
{
TypeCat typcat;
@@ -3426,7 +3443,7 @@ populate_record_field(ColumnIOData *col,
{
case TYPECAT_SCALAR:
return populate_scalar(&col->scalar_io, typid, typmod, jsv,
- isnull, escontext);
+ isnull, escontext, omit_scalar_quotes);
case TYPECAT_ARRAY:
return populate_array(&col->io.array, colname, mcxt, jsv,
@@ -3595,7 +3612,8 @@ populate_record(TupleDesc tupdesc,
nulls[i] ? (Datum) 0 : values[i],
&field,
&nulls[i],
- escontext);
+ escontext,
+ false);
}
res = heap_form_tuple(tupdesc, values, nulls);
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 64698202a5..55337d4916 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -707,6 +707,7 @@ typedef struct ExprEvalStep
{
Oid targettype;
int32 targettypmod;
+ bool omit_quotes;
void *json_populate_type_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h
index 8bc421e7c0..b62c96f206 100644
--- a/src/include/nodes/execnodes.h
+++ b/src/include/nodes/execnodes.h
@@ -1052,9 +1052,8 @@ typedef struct JsonExprState
/*
* Address of the step to coerce the result value of jsonpath evaluation
- * to the RETURNING type using JsonExpr.coercion_expr. -1 if no coercion
- * is necessary or if either JsonExpr.use_io_coercion or
- * JsonExpr.use_json_coercion is true.
+ * to the RETURNING type. -1 if no coercion if JsonExpr.use_io_coercion
+ * is true.
*/
int jump_eval_coercion;
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4830efc573..ea47652adb 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -1838,13 +1838,7 @@ typedef struct JsonExpr
/*
* Information about converting the result of jsonpath functions
* JsonPathQuery() and JsonPathValue() to the RETURNING type.
- *
- * coercion_expr is a cast expression if the parser can find it for the
- * source and the target type. If not, either use_io_coercion or
- * use_json_coercion is set to determine the coercion method to use at
- * runtime; see coerceJsonExprOutput() and ExecInitJsonExpr().
*/
- Node *coercion_expr;
bool use_io_coercion;
bool use_json_coercion;
@@ -1854,7 +1848,7 @@ typedef struct JsonExpr
/* KEEP or OMIT QUOTES for singleton scalars returned by JSON_QUERY() */
bool omit_quotes;
- /* JsonExpr's collation, if coercion_expr is NULL. */
+ /* JsonExpr's collation. */
Oid collation;
/* Original JsonFuncExpr's location */
diff --git a/src/include/utils/jsonfuncs.h b/src/include/utils/jsonfuncs.h
index 190e13284b..93384d900a 100644
--- a/src/include/utils/jsonfuncs.h
+++ b/src/include/utils/jsonfuncs.h
@@ -93,6 +93,7 @@ extern Datum json_populate_type(Datum json_val, Oid json_type,
Oid typid, int32 typmod,
void **cache, MemoryContext mcxt,
bool *isnull,
+ bool omit_quotes,
Node *escontext);
#endif
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index dfc7182ba9..5fd43be367 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -103,14 +103,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | t | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | | 1.23 | 1.23 | | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | 2 | 2 | 2 | | 2 | 2 | "2" | "2"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | aaaa | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | | aaaaaaa | | | | aaaaaaa | "aaaaaaa" | "aaaaaaa"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | | foo | foo | | | | "foo" | "foo"
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | | | | | | | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | f | false | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | t | true | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | | f | f | f | | false | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | | t | t | t | | true | true | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | | | | | | | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | [1,2 | | | [1,2] | "[1,2]" | "[1,2]"
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | "str | | | "str" | "\"str\"" | "\"str\""
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | | [1,2] | | | | [1,2] | "[1,2]" | "[1,2]"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | | "str" | | | | "str" | "\"str\"" | "\"str\""
(14 rows)
-- "formatted" columns
@@ -137,14 +137,14 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 1 | 1 | 1 | 1 | 1 | 1
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 2 | 1.23 | 1.23 | 1.23 | 1.23 | 1.23
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 3 | "2" | "2" | "2" | "2" | 2
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | "aaa | "aaa | "aaaaaaa" |
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | "foo | "foo | "foo" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 4 | "aaaaaaa" | | | "aaaaaaa" |
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 5 | "foo" | | | "foo" |
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | null | null | null | null | null
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | fals | fals | false | false
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | false | | | false | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | true | true | true | true | true
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | {"aa | {"aa | {"aaa": 123} | {"aaa": 123}
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | "[1, | "[1, | "[1,2]" | [1, 2]
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | "\"s | "\"s | "\"str\"" | "str"
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | {"aaa": 123} | | | {"aaa": 123} | {"aaa": 123}
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | "[1,2]" | | | "[1,2]" | [1, 2]
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | "\"str\"" | | | "\"str\"" | "str"
(14 rows)
-- EXISTS columns
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -555,31 +555,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to smallint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to smallint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to bigint
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to bigint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to real
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 E...
- ^
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
------
- fal
+ERROR: cannot cast behavior expression of type boolean to real
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+-------
+ false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to json
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXI...
- ^
+ERROR: cannot cast behavior expression of type boolean to json
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast type boolean to jsonb
-LINE 1: ...ELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EX...
- ^
+ERROR: cannot cast behavior expression of type boolean to jsonb
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 6ca17a3d42..074aedb2dd 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -234,10 +234,18 @@ SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
aaa
(1 row)
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
+ERROR: value too long for type character(2)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
json_value
------------
- aa
+
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ json_value
+------------
+ aaa
(1 row)
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
@@ -636,30 +644,28 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERR
(1 row)
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+ERROR: value too long for type character(3)
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
json_query
------------
- "a
+
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
json_query
------------
- aa
+ aaa
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
json_query
------------
bb
(1 row)
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
- json_query
-------------
- "b
-(1 row)
-
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
+ERROR: value too long for type character(2)
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -828,12 +834,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
[1, 2]
(1 row)
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
- json_query
-------------
- [1,
-(1 row)
-
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
json_query
------------
@@ -1369,3 +1369,39 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY ], EMPTY OBJECT, or DEFAULT expression is allowed in ON ERROR for JSON_QUERY().
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+ERROR: value too long for type character(2)
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+ json_value
+------------
+ 1
+(1 row)
+
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index f1d99a8a73..4594e5b013 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,7 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index 4586fdb8a4..be5593b332 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -53,7 +53,9 @@ SELECT JSON_VALUE(jsonb '"1.23"', '$' RETURNING int ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$');
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING text);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(5));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(2));
+SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING jsonb);
SELECT JSON_VALUE(jsonb '"aaa"', '$' RETURNING json ERROR ON ERROR);
@@ -188,10 +190,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING json OMIT QUOTES ERROR ON ERROR);
SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING bytea FORMAT JSON OMIT QUOTES ERROR ON ERROR);
-- Behavior when a RETURNING type has typmod != -1
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2));
-SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(2) OMIT QUOTES);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bbb' ON EMPTY);
-SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bbb"'::jsonb ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3));
+SELECT JSON_QUERY(jsonb '"aaa"', '$' RETURNING char(3) OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb' ON EMPTY);
+SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
@@ -235,7 +238,6 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING jsonb FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(10));
-SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING char(3));
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING text FORMAT JSON);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea);
SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
@@ -464,3 +466,16 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz);
SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
+
+-- Test implicit coercion domain over fixed-legth type specified in RETURNING
+CREATE DOMAIN queryfuncs_char2 AS char(2);
+CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT '1' ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT '1' ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
+DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
--
2.43.0
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index 233b7b1cc9..df766cdec1 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -3583,6 +3583,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr, Node *res; int location; Oid exprtype = exprType(expr); + int32 baseTypmod = returning->typmod;/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3611,10 +3612,19 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
I didn't review this patch in detail, but I just noticed this tiny bit
and wanted to say that I don't like this coding style where you
initialize a variable to a certain value, and much later you override it
with a completely different value. It seems much clearer to leave it
uninitialized at first, and have both places that determine the value
together,
if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
else
baseTypmod = returning->typmod;
Not only because in the domain case the initializer value is a downright
lie, but also because of considerations such as if you later add code
that uses the variable in between those two places, you'd be introducing
a bug in the domain case because it hasn't been set. With the coding I
propose, the compiler immediately tells you that the initialization is
missing.
TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?
--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
"Small aircraft do not crash frequently ... usually only once!"
(ponder, http://thedailywtf.com/)
Alvaro Herrera <alvherre@alvh.no-ip.org> writes:
+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?
Hmm ... there are a bunch of existing places that seem to have similar
logic, but they are all in new-ish SQL/JSON functionality, and I would
not be surprised if they are all wrong. parse_coerce.c is quite
opinionated about what a domain's typtypmod means (see comments in
coerce_type() for instance); see also the logic in coerce_to_domain:
* If the domain applies a typmod to its base type, build the appropriate
* coercion step. Mark it implicit for display purposes, because we don't
* want it shown separately by ruleutils.c; but the isExplicit flag passed
* to the conversion function depends on the manner in which the domain
* coercion is invoked, so that the semantics of implicit and explicit
* coercion differ. (Is that really the behavior we want?)
I don't think that this SQL/JSON behavior quite matches that.
While I'm bitching ... this coding style is bogus anyway:
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
because it results in two syscache lookups not one. You are supposed
to apply getBaseTypeAndTypmod unconditionally, as is done everywhere
except in the SQL/JSON logic. I am also wondering how it can possibly
be sensible to throw away the function result of getBaseTypeAndTypmod
in this context.
regards, tom lane
On Sun, Jun 30, 2024 at 2:24 AM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:
TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?
I am using an example to explain it.
SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
we cannot directly use implicit cast from json to text in
{coerceJsonFuncExpr, coerce_to_target_type}
because function calls:
coerceJsonFuncExpr->coerce_to_target_type->can_coerce_type
->find_coercion_pathway
will look up pg_cast entries.
but we don't have text & json implicit cast entries, we will fail at:
````
if (!res && report_error)
ereport(ERROR,
errcode(ERRCODE_CANNOT_COERCE),
errmsg("cannot cast type %s to %s",
format_type_be(exprtype),
format_type_be(returning->typid)),
parser_coercion_errposition(pstate, location, expr));
````
Most of the cast uses explicit cast, which is what we previously did,
then in this thread, we found out for the returning type typmod(
(varchar, or varchar's domain)
We need to first cast the expression to text then text to varchar via
implicit cast.
To trap the error:
for example: SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar(2);
also see the comment:
https://git.postgresql.org/cgit/postgresql.git/commit/?id=c2d93c3802b205d135d1ae1d7ac167d74e08a274
+ /*
+ * Convert the source expression to text, because coerceJsonFuncExpr()
+ * will create an implicit cast to the RETURNING types with typmod and
+ * there are no implicit casts from json(b) to such types. For domains,
+ * the base type's typmod will be considered, so do so here too.
+ */
In general, I think implicit cast here is an exception.
overall I come up with following logic:
-----------------
int32 baseTypmod = -1;
if (returning->typmod < 0)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
else
baseTypmod = returning->typmod;
res = coerce_to_target_type(pstate, expr, exprtype,
returning->typid, baseTypmod,
baseTypmod > 0 ? COERCION_IMPLICIT :
COERCION_EXPLICIT,
baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
location);
-----------------
By the same way we are dealing with varchar,
I came up with a verbose patch for transformJsonBehavior,
which can cope with all the corner cases of bit and varbit data type.
I also attached a test sql file (scratch169.sql) for it.
some examples:
--fail
SELECT JSON_VALUE(jsonb '"111a"', '$' RETURNING bit(3) default '1111'
on error);
--ok
SELECT JSON_VALUE(jsonb '"111a"', '$' RETURNING bit(3) default '111' on error);
--ok
SELECT JSON_VALUE(jsonb '"111a"', '$' RETURNING bit(3) default 32 on error);
makeJsonConstructorExpr we called (void)
getBaseTypeAndTypmod(returning->typid, &baseTypmod);
later in coerceJsonFuncExpr
we may also call (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
maybe we can do some refactoring.
Attachments:
v1-0001-hanlde-types-that-have-type-modifier-for-json-on-.patchapplication/x-patch; name=v1-0001-hanlde-types-that-have-type-modifier-for-json-on-.patchDownload
From 5f2d070d3cc47f7461d1474a5fe18e905243b31b Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Mon, 1 Jul 2024 14:26:09 +0800
Subject: [PATCH v1 1/1] hanlde types that have type modifier for json on
error, on empty
---
src/backend/parser/parse_expr.c | 83 ++++++++++++++++++++++++++-------
1 file changed, 65 insertions(+), 18 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 560b3606..15cdea1c 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3582,7 +3582,7 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
- int32 baseTypmod = returning->typmod;
+ int32 baseTypmod = -1;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3615,8 +3615,10 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
* For domains, consider the base type's typmod to decide whether to setup
* an implicit or explicit cast.
*/
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ if (returning->typmod < 0)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ else
+ baseTypmod = returning->typmod;
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
@@ -3649,7 +3651,7 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
- int32 baseTypmod = returning->typmod;
+ int32 baseTypmod = -1;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3693,8 +3695,10 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
* there are no implicit casts from json(b) to such types. For domains,
* the base type's typmod will be considered, so do so here too.
*/
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ if (returning->typmod < 0)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ else
+ baseTypmod = returning->typmod;
if (baseTypmod > 0)
placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
"JSON_CONSTRUCTOR()");
@@ -4718,22 +4722,65 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
coerce_at_runtime = true;
else
{
- int32 baseTypmod = returning->typmod;
-
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ int32 baseTypmod = -1;
+ char typcategory;
+ bool typispreferred;
+ get_type_category_preferred(returning->typid, &typcategory, &typispreferred);
+ if (returning->typmod < 0)
(void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ else
+ baseTypmod = returning->typmod;
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
- coerced_expr =
- coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
- COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
- COERCE_EXPLICIT_CAST,
- exprLocation((Node *) behavior));
+ if (typcategory == TYPCATEGORY_STRING)
+ {
+ if (baseTypmod > 0)
+ expr = coerce_to_specific_type(pstate, expr, TEXTOID,
+ "JSON_FUNCTION()");
+ coerced_expr =
+ coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, baseTypmod,
+ baseTypmod > 0 ? COERCION_IMPLICIT :
+ COERCION_EXPLICIT,
+ baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ COERCE_EXPLICIT_CAST,
+ exprLocation((Node *) behavior));
+ }
+ else if (typcategory == TYPCATEGORY_BITSTRING)
+ {
+ CoercionContext ccontext;
+ CoercionForm cformat;
+
+ /*
+ * pg_cast don't have bit & text entry, so in function can_coerce_type
+ * cannot implilcit cast to text then cast to varbit.
+ * but we can unknown cast to bit via implilcit cast.
+ * select '21'::text::bit(2); --fail
+ * select 21::int4::bit(2); --ok
+ * so DEFAULT 21 ON ERROR, DEFAULT 11 ON ERROR should be fine;
+ */
+ if(baseTypmod > 0 && ((exprType(expr) != INT4OID && exprType(expr) != INT8OID)))
+ {
+ ccontext = COERCION_IMPLICIT;
+ cformat = COERCE_IMPLICIT_CAST;
+ }
+ else
+ {
+ ccontext = COERCION_EXPLICIT;
+ cformat = COERCE_EXPLICIT_CAST;
+ }
+ coerced_expr =
+ coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, returning->typmod,
+ ccontext,
+ cformat,
+ exprLocation((Node *) behavior));
+ }
+ else
+ coerced_expr =
+ coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, returning->typmod,
+ COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ exprLocation((Node *) behavior));
}
if (coerced_expr == NULL)
--
2.34.1
On Sun, Jun 30, 2024 at 3:56 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Alvaro Herrera <alvherre@alvh.no-ip.org> writes:
+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?Hmm ... there are a bunch of existing places that seem to have similar
logic, but they are all in new-ish SQL/JSON functionality, and I would
not be surprised if they are all wrong. parse_coerce.c is quite
opinionated about what a domain's typtypmod means (see comments in
coerce_type() for instance); see also the logic in coerce_to_domain:* If the domain applies a typmod to its base type, build the appropriate
* coercion step. Mark it implicit for display purposes, because we don't
* want it shown separately by ruleutils.c; but the isExplicit flag passed
* to the conversion function depends on the manner in which the domain
* coercion is invoked, so that the semantics of implicit and explicit
* coercion differ. (Is that really the behavior we want?)I don't think that this SQL/JSON behavior quite matches that.
The reason I decided to go for the implicit cast only when there is a
typmod is that the behavior with COERCION_EXPLICIT is only problematic
when there's a typmod because of this code in
build_coercion_expression:
if (nargs == 3)
{
/* Pass it a boolean isExplicit parameter, too */
cons = makeConst(BOOLOID,
-1,
InvalidOid,
sizeof(bool),
BoolGetDatum(ccontext == COERCION_EXPLICIT),
false,
true);
args = lappend(args, cons);
}
Yeah, we could have fixed that by always using COERCION_IMPLICIT for
SQL/JSON but, as Jian said, we don't have a bunch of casts that these
SQL/JSON functions need, which is why I guess we ended up with
COERCION_EXPLICIT here in the first place.
One option I hadn't tried was using COERCION_ASSIGNMENT instead, which
seems to give coerceJsonFuncExpr() the casts it needs with the
behavior it wants, so how about applying the attached?
--
Thanks, Amit Langote
Attachments:
v6-0001-SQL-JSON-Rethink-c2d93c3802b.patchapplication/octet-stream; name=v6-0001-SQL-JSON-Rethink-c2d93c3802b.patchDownload
From b092df2d6f7b3ddba0f4fd4fedf2b6b172d7b7a7 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Mon, 1 Jul 2024 17:09:19 +0900
Subject: [PATCH v6] SQL/JSON: Rethink c2d93c3802b
This essentially reverts all of c2d93c3802b and teaches
coerceJsonFuncExpr() to use COERCION_ASSIGNMENT instead of
COERCION_EXPLICIT so that the casts to types with typmod
are considered as implicit casts.
Discussion: https://postgr.es/m/202406291824.reofujy7xdj3@alvherre.pgsql
---
src/backend/parser/parse_expr.c | 26 ++------------------------
1 file changed, 2 insertions(+), 24 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 45c019627c..0c96f9e8e4 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -3582,7 +3582,6 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
Node *res;
int location;
Oid exprtype = exprType(expr);
- int32 baseTypmod = returning->typmod;
/* if output type is not specified or equals to function type, return */
if (!OidIsValid(returning->typid) || returning->typid == exprtype)
@@ -3611,19 +3610,10 @@ coerceJsonFuncExpr(ParseState *pstate, Node *expr,
return (Node *) fexpr;
}
- /*
- * For domains, consider the base type's typmod to decide whether to setup
- * an implicit or explicit cast.
- */
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
/* try to coerce expression to the output type */
res = coerce_to_target_type(pstate, expr, exprtype,
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
- COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
+ returning->typid, returning->typmod,
+ COERCION_ASSIGNMENT,
COERCE_EXPLICIT_CAST,
location);
@@ -3649,7 +3639,6 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
JsonConstructorExpr *jsctor = makeNode(JsonConstructorExpr);
Node *placeholder;
Node *coercion;
- int32 baseTypmod = returning->typmod;
jsctor->args = args;
jsctor->func = fexpr;
@@ -3687,17 +3676,6 @@ makeJsonConstructorExpr(ParseState *pstate, JsonConstructorType type,
placeholder = (Node *) cte;
}
- /*
- * Convert the source expression to text, because coerceJsonFuncExpr()
- * will create an implicit cast to the RETURNING types with typmod and
- * there are no implicit casts from json(b) to such types. For domains,
- * the base type's typmod will be considered, so do so here too.
- */
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
- if (baseTypmod > 0)
- placeholder = coerce_to_specific_type(pstate, placeholder, TEXTOID,
- "JSON_CONSTRUCTOR()");
coercion = coerceJsonFuncExpr(pstate, placeholder, returning, true);
if (coercion != placeholder)
--
2.43.0
On Mon, Jul 1, 2024 at 6:45 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Sun, Jun 30, 2024 at 3:56 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Alvaro Herrera <alvherre@alvh.no-ip.org> writes:
+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?Hmm ... there are a bunch of existing places that seem to have similar
logic, but they are all in new-ish SQL/JSON functionality, and I would
not be surprised if they are all wrong. parse_coerce.c is quite
opinionated about what a domain's typtypmod means (see comments in
coerce_type() for instance); see also the logic in coerce_to_domain:* If the domain applies a typmod to its base type, build the appropriate
* coercion step. Mark it implicit for display purposes, because we don't
* want it shown separately by ruleutils.c; but the isExplicit flag passed
* to the conversion function depends on the manner in which the domain
* coercion is invoked, so that the semantics of implicit and explicit
* coercion differ. (Is that really the behavior we want?)I don't think that this SQL/JSON behavior quite matches that.
The reason I decided to go for the implicit cast only when there is a
typmod is that the behavior with COERCION_EXPLICIT is only problematic
when there's a typmod because of this code in
build_coercion_expression:if (nargs == 3)
{
/* Pass it a boolean isExplicit parameter, too */
cons = makeConst(BOOLOID,
-1,
InvalidOid,
sizeof(bool),
BoolGetDatum(ccontext == COERCION_EXPLICIT),
false,
true);args = lappend(args, cons);
}Yeah, we could have fixed that by always using COERCION_IMPLICIT for
SQL/JSON but, as Jian said, we don't have a bunch of casts that these
SQL/JSON functions need, which is why I guess we ended up with
COERCION_EXPLICIT here in the first place.One option I hadn't tried was using COERCION_ASSIGNMENT instead, which
seems to give coerceJsonFuncExpr() the casts it needs with the
behavior it wants, so how about applying the attached?
you patched works.
i think it's because of you mentioned build_coercion_expression ` if
(nargs == 3)` related code
and
find_coercion_pathway:
if (result == COERCION_PATH_NONE)
{
if (ccontext >= COERCION_ASSIGNMENT &&
TypeCategory(targetTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
else if (ccontext >= COERCION_EXPLICIT &&
TypeCategory(sourceTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
}
functions: JSON_OBJECT,JSON_ARRAY, JSON_ARRAYAGG,JSON_OBJECTAGG,
JSON_SERIALIZE
the returning type can only be string type or json. json type already
being handled in other code.
so the targetTypeId category will be only TYPCATEGORY_STRING.
On Tue, Jul 2, 2024 at 3:19 PM jian he <jian.universality@gmail.com> wrote:
On Mon, Jul 1, 2024 at 6:45 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Sun, Jun 30, 2024 at 3:56 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Alvaro Herrera <alvherre@alvh.no-ip.org> writes:
+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?Hmm ... there are a bunch of existing places that seem to have similar
logic, but they are all in new-ish SQL/JSON functionality, and I would
not be surprised if they are all wrong. parse_coerce.c is quite
opinionated about what a domain's typtypmod means (see comments in
coerce_type() for instance); see also the logic in coerce_to_domain:* If the domain applies a typmod to its base type, build the appropriate
* coercion step. Mark it implicit for display purposes, because we don't
* want it shown separately by ruleutils.c; but the isExplicit flag passed
* to the conversion function depends on the manner in which the domain
* coercion is invoked, so that the semantics of implicit and explicit
* coercion differ. (Is that really the behavior we want?)I don't think that this SQL/JSON behavior quite matches that.
The reason I decided to go for the implicit cast only when there is a
typmod is that the behavior with COERCION_EXPLICIT is only problematic
when there's a typmod because of this code in
build_coercion_expression:if (nargs == 3)
{
/* Pass it a boolean isExplicit parameter, too */
cons = makeConst(BOOLOID,
-1,
InvalidOid,
sizeof(bool),
BoolGetDatum(ccontext == COERCION_EXPLICIT),
false,
true);args = lappend(args, cons);
}Yeah, we could have fixed that by always using COERCION_IMPLICIT for
SQL/JSON but, as Jian said, we don't have a bunch of casts that these
SQL/JSON functions need, which is why I guess we ended up with
COERCION_EXPLICIT here in the first place.One option I hadn't tried was using COERCION_ASSIGNMENT instead, which
seems to give coerceJsonFuncExpr() the casts it needs with the
behavior it wants, so how about applying the attached?you patched works.
i think it's because of you mentioned build_coercion_expression ` if
(nargs == 3)` related code
andfind_coercion_pathway:
if (result == COERCION_PATH_NONE)
{
if (ccontext >= COERCION_ASSIGNMENT &&
TypeCategory(targetTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
else if (ccontext >= COERCION_EXPLICIT &&
TypeCategory(sourceTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
}functions: JSON_OBJECT,JSON_ARRAY, JSON_ARRAYAGG,JSON_OBJECTAGG,
JSON_SERIALIZE
the returning type can only be string type or json. json type already
being handled in other code.
so the targetTypeId category will be only TYPCATEGORY_STRING.
Yes, thanks for confirming that.
I checked other sites that use COERCION_ASSIGNMENT and I don't see a
reason why it can't be used in this context.
I'll push the patch tomorrow unless there are objections.
--
Thanks, Amit Langote
On Tue, Jul 2, 2024 at 5:03 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Jul 2, 2024 at 3:19 PM jian he <jian.universality@gmail.com> wrote:
On Mon, Jul 1, 2024 at 6:45 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Sun, Jun 30, 2024 at 3:56 AM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Alvaro Herrera <alvherre@alvh.no-ip.org> writes:
+ /* + * For domains, consider the base type's typmod to decide whether to setup + * an implicit or explicit cast. + */ + if (get_typtype(returning->typid) == TYPTYPE_DOMAIN) + (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);TBH I'm not super clear on why we decide on explicit or implicit cast
based on presence of a typmod. Why isn't it better to always use an
implicit one?Hmm ... there are a bunch of existing places that seem to have similar
logic, but they are all in new-ish SQL/JSON functionality, and I would
not be surprised if they are all wrong. parse_coerce.c is quite
opinionated about what a domain's typtypmod means (see comments in
coerce_type() for instance); see also the logic in coerce_to_domain:* If the domain applies a typmod to its base type, build the appropriate
* coercion step. Mark it implicit for display purposes, because we don't
* want it shown separately by ruleutils.c; but the isExplicit flag passed
* to the conversion function depends on the manner in which the domain
* coercion is invoked, so that the semantics of implicit and explicit
* coercion differ. (Is that really the behavior we want?)I don't think that this SQL/JSON behavior quite matches that.
The reason I decided to go for the implicit cast only when there is a
typmod is that the behavior with COERCION_EXPLICIT is only problematic
when there's a typmod because of this code in
build_coercion_expression:if (nargs == 3)
{
/* Pass it a boolean isExplicit parameter, too */
cons = makeConst(BOOLOID,
-1,
InvalidOid,
sizeof(bool),
BoolGetDatum(ccontext == COERCION_EXPLICIT),
false,
true);args = lappend(args, cons);
}Yeah, we could have fixed that by always using COERCION_IMPLICIT for
SQL/JSON but, as Jian said, we don't have a bunch of casts that these
SQL/JSON functions need, which is why I guess we ended up with
COERCION_EXPLICIT here in the first place.One option I hadn't tried was using COERCION_ASSIGNMENT instead, which
seems to give coerceJsonFuncExpr() the casts it needs with the
behavior it wants, so how about applying the attached?you patched works.
i think it's because of you mentioned build_coercion_expression ` if
(nargs == 3)` related code
andfind_coercion_pathway:
if (result == COERCION_PATH_NONE)
{
if (ccontext >= COERCION_ASSIGNMENT &&
TypeCategory(targetTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
else if (ccontext >= COERCION_EXPLICIT &&
TypeCategory(sourceTypeId) == TYPCATEGORY_STRING)
result = COERCION_PATH_COERCEVIAIO;
}functions: JSON_OBJECT,JSON_ARRAY, JSON_ARRAYAGG,JSON_OBJECTAGG,
JSON_SERIALIZE
the returning type can only be string type or json. json type already
being handled in other code.
so the targetTypeId category will be only TYPCATEGORY_STRING.Yes, thanks for confirming that.
I checked other sites that use COERCION_ASSIGNMENT and I don't see a
reason why it can't be used in this context.I'll push the patch tomorrow unless there are objections.
Sorry, I dropped the ball on this one.
I've pushed the patch now.
--
Thanks, Amit Langote
we still have problem in transformJsonBehavior
currently transformJsonBehavior:
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ERROR);
ERROR: cannot cast behavior expression of type text to bit
LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ...
here, 010111 will default to int4, so "cannot cast behavior expression
of type text to bit"
is wrong?
also int4/int8 can be explicitly cast to bit(3), in this case, it
should return 111.
Also, do we want to deal with bit data type's typmod like we did for
string type in transformJsonBehavior?
like:
SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(3) default '1111' on error);
should return error:
ERROR: bit string length 2 does not match type bit(3)
or success
The attached patch makes it return an error, similar to what we did
for the fixed length string type.
Attachments:
v1-0001-fix-transformJsonBehavior-coerce-to-different-typ.patchapplication/x-patch; name=v1-0001-fix-transformJsonBehavior-coerce-to-different-typ.patchDownload
From d457e3efebaaf1882693f7c9e2afd49520bce2a8 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Thu, 18 Jul 2024 13:38:19 +0800
Subject: [PATCH v1 1/1] fix transformJsonBehavior coerce to different types.
make transformJsonBehavior behave the same as for fix length string type
and fix length bit string type.
make transformJsonBehavior coerce to fix length string type aware the length.
---
src/backend/parser/parse_expr.c | 63 ++++++++++++++-----
.../regress/expected/sqljson_queryfuncs.out | 29 +++++++++
src/test/regress/sql/sqljson_queryfuncs.sql | 11 ++++
3 files changed, 89 insertions(+), 14 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f278..5aadff34 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4703,22 +4703,57 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
coerce_at_runtime = true;
else
{
- int32 baseTypmod = returning->typmod;
+ char typcategory;
+ bool typispreferred;
+ get_type_category_preferred(returning->typid, &typcategory, &typispreferred);
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+ if (typcategory == TYPCATEGORY_STRING)
+ coerced_expr = coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, returning->typmod,
+ COERCION_ASSIGNMENT,
+ COERCE_IMPLICIT_CAST,
+ location);
+ else if (typcategory == TYPCATEGORY_BITSTRING)
+ {
+ int32 baseTypmod = -1;
+ CoercionContext ccontext = COERCION_EXPLICIT;
+ CoercionForm cformat = COERCE_EXPLICIT_CAST;
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
- coerced_expr =
- coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
- COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
- COERCE_EXPLICIT_CAST,
- exprLocation((Node *) behavior));
+ if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
+ (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
+
+ /*
+ * '111'::bit(2); typmod aware should fail.
+ * '111'::bit(2); don't care typmod should ok.
+ * here typmod refers to domain's basetype typmod when type is domain.
+ * pg_cast only have explicit cast entry between bit and int4/int8,
+ * we need set it accordingly,
+ * so DEFAULT 21 ON ERROR, DEFAULT 11 ON ERROR should ok;
+ */
+ if(baseTypmod > 0 || returning->typmod > 0)
+ {
+ ccontext = COERCION_IMPLICIT;
+ cformat = COERCE_IMPLICIT_CAST;
+ }
+ if (exprType(expr) == INT4OID || exprType(expr) == INT8OID)
+ {
+ ccontext = COERCION_EXPLICIT;
+ cformat = COERCE_EXPLICIT_CAST;
+ }
+
+ coerced_expr =
+ coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, returning->typmod,
+ ccontext,
+ cformat,
+ exprLocation((Node *) behavior));
+ }
+ else
+ coerced_expr =
+ coerce_to_target_type(pstate, expr, exprType(expr),
+ returning->typid, returning->typmod,
+ COERCION_EXPLICIT, COERCE_EXPLICIT_CAST,
+ exprLocation((Node *) behavior));
}
if (coerced_expr == NULL)
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 074aedb2..62d8452d 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -1405,3 +1405,32 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test implicit coercion over fixed-legth type specified in ON ERROR, ON EMPTY.
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) error on error);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::int8 ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) default '1111' on empty);
+ERROR: bit string length 4 does not match type bit(3)
+SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING bit(3) DEFAULT 1::int4 ON EMPTY);
+ json_value
+------------
+ 001
+(1 row)
+
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index be5593b3..f1402704 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -479,3 +479,14 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test implicit coercion over fixed-legth type specified in ON ERROR, ON EMPTY.
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) error on error);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::int8 ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) default '1111' on empty);
+SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING bit(3) DEFAULT 1::int4 ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
\ No newline at end of file
--
2.34.1
On Thu, Jul 18, 2024 at 3:04 PM jian he <jian.universality@gmail.com> wrote:
we still have problem in transformJsonBehavior
currently transformJsonBehavior:
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ERROR);
ERROR: cannot cast behavior expression of type text to bit
LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ...here, 010111 will default to int4, so "cannot cast behavior expression
of type text to bit"
is wrong?
also int4/int8 can be explicitly cast to bit(3), in this case, it
should return 111.
I think we shouldn't try too hard in the code to "automatically" cast
the DEFAULT expression, especially if that means having to add special
case code for all sorts of source-target-type combinations.
I'm inclined to just give a HINT to the user to cast the DEFAULT
expression by hand, because they *can* do that with the syntax that
exists.
On the other hand, transformJsonBehavior() should handle other
"internal" expressions for which the cast cannot be specified by hand.
Also, do we want to deal with bit data type's typmod like we did for
string type in transformJsonBehavior?
like:
SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(3) default '1111' on error);
should return error:
ERROR: bit string length 2 does not match type bit(3)
or successThe attached patch makes it return an error, similar to what we did
for the fixed length string type.
Yeah, that makes sense.
I'm planning to push the attached 2 patches. 0001 is to fix
transformJsonBehavior() for these cases and 0002 to adjust the
behavior of casting the result of JSON_EXISTS() and EXISTS columns to
integer type. I've included the tests in your patch in 0001. I
noticed using cast expression to coerce the boolean constants to
fixed-length types would produce unexpected errors when the planner's
const-simplification calls the cast functions. So in 0001, I've made
that case also use runtime coercion using json_populate_type().
--
Thanks, Amit Langote
Attachments:
0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchapplication/octet-stream; name=0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchDownload
From 32c2510695d36a0363a51056f05787744fe89cd7 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Mon, 22 Jul 2024 17:13:58 +0900
Subject: [PATCH 2/2] SQL/JSON: Fix casting for integer EXISTS columns in
JSON_TABLE
The current method of coercing the boolean result value of
JsonPathExists() to the target type specified for an EXISTS column,
which is to call the type's input function via json_populate_type(),
leads to an error when the target type is integer, because the
integer input function doesn't recognize boolean literal values as
valid.
Instead use the boolean-to-integer cast function for coercion in that
case so that using integer as type for EXISTS columns works. Note
that coercion for ON ERROR values TRUE and FALSE already works like
that because the parser creates a cast expression including the cast
function, but the coercion of the actual result value is not handled
by the parser.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExprInterp.c | 19 +++++++++++++++++++
src/backend/parser/parse_expr.c | 2 +-
.../regress/expected/sqljson_jsontable.out | 10 ++++++++--
src/test/regress/sql/sqljson_jsontable.sql | 3 ++-
4 files changed, 30 insertions(+), 4 deletions(-)
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d8735286c4..271a4b8f15 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4304,11 +4304,30 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
*op->resnull = false;
+
+ /*
+ * Prepare to call json_populate_type() to coerce the
+ * boolean result to the target type. Parser must have set
+ * use_json_coercion to false if the target type is
+ * integer, because in that case we call the boolean-to-
+ * integer cast function instead as the integer's input
+ * function (which is what json_populate_type() for scalar
+ * target types) doesn't accept boolean literals as valid
+ * input. We only have a special case for integer as it
+ * seems common to use integer type for EXISTS columns in
+ * JSON_TABLE().
+ */
if (jsexpr->use_json_coercion)
+ {
+ Assert(jsexpr->returning->typid != INT4OID);
*op->resvalue = DirectFunctionCall1(jsonb_in,
BoolGetDatum(exists) ?
CStringGetDatum("true") :
CStringGetDatum("false"));
+ }
+ else if (jsexpr->returning->typid == INT4OID)
+ *op->resvalue = DirectFunctionCall1(bool_int4,
+ BoolGetDatum(exists));
else
*op->resvalue = BoolGetDatum(exists);
}
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index d31b4ffcec..61611b8a59 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4476,7 +4476,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
- jsexpr->use_json_coercion = true;
+ jsexpr->use_json_coercion = jsexpr->returning->typid != INT4OID;
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 939e1b2f87..9e93307f85 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -548,12 +548,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
(1 row)
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
a
---
0
(1 row)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+ a
+---
+ 1
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
ERROR: cannot cast behavior expression of type boolean to smallint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index dc509bed8a..f6fc09b7ad 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -262,7 +262,8 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAU
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
--
2.43.0
0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchapplication/octet-stream; name=0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchDownload
From 5933a949f71a212d49f7157360786d3ba6c4b280 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Mon, 22 Jul 2024 17:14:20 +0900
Subject: [PATCH 1/2] SQL/JSON: Some fixes to JsonBehavior expression casting
1. Remove the special case handling when casting the JsonBehavior
expressions to types with typmod, like 86d33987 did for the casting
of SQL/JSON constructor functions.
2. Fix casting for fixed-length character and bit string types by
using assignment-level casts. This is again similar to what
86d33987 did, but for ON ERROR / EMPTY expressions.
3. Use runtime coercion for the boolean ON ERROR constants so that
the coercion works correctly for EXISTS columns that use fixed-
length character string types. For example, so that the default
"false" doesn't emit an "value too long for type character(2)"
error even when no ON ERROR clause is specified.
4. Simplify the conditions of when to use runtime coercion vs
creating the cast expression in the parser itself. jsonb-valued
expressions are now always coerced at runtime and boolean
expressions too if the target type is a string type for the
reasons mentioned above.
5. Add a note to the document that an SQL NULL is returned if
JsonBehavior expression cannot be coerced to the target type
at runtime when either the ON ERROR or ON EMPTY behavior must
be invoked.
Tests related to casting to bit(N) are taken from Jian He's patch.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
doc/src/sgml/func.sgml | 7 ++
src/backend/parser/parse_expr.c | 100 ++++++++++++------
.../regress/expected/sqljson_jsontable.out | 11 +-
.../regress/expected/sqljson_queryfuncs.out | 68 +++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 13 +++
6 files changed, 158 insertions(+), 46 deletions(-)
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index fd5699f4d8..a9ff8619ce 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -18940,6 +18940,13 @@ DETAIL: Missing "]" after array dimensions.
the JSON <literal>null</literal> as is.
</para>
</note>
+ <note>
+ <para>
+ If an <literal>ON ERROR</literal> or <literal>ON EMPTY</literal>
+ expression can't be coerced to the <literal>RETURNING</literal> type
+ successfully, an SQL NULL value will be returned.
+ </para>
+ </note>
</sect2>
<sect2 id="functions-sqljson-table">
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f27806..d31b4ffcec 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4685,51 +4685,89 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
if (expr == NULL && btype != JSON_BEHAVIOR_ERROR)
expr = GetJsonBehaviorConst(btype, location);
- if (expr)
+ /*
+ * Try to coerce the expression if needed.
+ *
+ * Use runtime coercion using json_populate_type() if the expression is
+ * NULL, jsonb-valued, or boolean-valued. The last only if the target is
+ * a string type, because casting functions don't handle errors softly, so
+ * won't correctly handle the casting of the boolean literal values to
+ * fixed-length types correctly if they exceed the specified length.
+ *
+ * For other non-NULL expressions, try to find a cast and error out if
+ * one is not found.
+ */
+ if (expr && exprType(expr) != returning->typid)
{
- Node *coerced_expr = expr;
bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull);
-
- /*
- * Coerce NULLs and "internal" (that is, not specified by the user)
- * jsonb-valued expressions at runtime using json_populate_type().
- *
- * For other (user-specified) non-NULL values, try to find a cast and
- * error out if one is not found.
- */
+ char typcategory = TypeCategory(returning->typid);
if (isnull ||
- (exprType(expr) == JSONBOID &&
- btype == default_behavior))
+ exprType(expr) == JSONBOID ||
+ (exprType(expr) == BOOLOID && typcategory == TYPCATEGORY_STRING))
+ {
coerce_at_runtime = true;
+
+ /*
+ * json_populate_type() expects to be passed a jsonb value, so
+ * gin up a Const containing the appropriate boolean value
+ * represented as jsonb, discarding the original Const containing a
+ * plain boolean.
+ */
+ if (exprType(expr) == BOOLOID)
+ {
+ char *val = btype == JSON_BEHAVIOR_TRUE ? "true" : "false";
+
+ expr = (Node *) makeConst(JSONBOID, -1, InvalidOid, -1,
+ DirectFunctionCall1(jsonb_in,
+ CStringGetDatum(val)),
+ false,false);
+ }
+ }
else
{
- int32 baseTypmod = returning->typmod;
+ Node *coerced_expr;
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
+ /*
+ * Use an assignment cast if coercing to a string type so that
+ * build_coercion_expression() assumes implicit coercion when
+ * coercing the typmod, so that inputs exceeding length cause an
+ * error instead of silent truncation.
+ */
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
+ returning->typid, returning->typmod,
+ (typcategory == TYPCATEGORY_STRING ||
+ typcategory == TYPCATEGORY_BITSTRING) ?
+ COERCION_ASSIGNMENT :
COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
- }
- if (coerced_expr == NULL)
- ereport(ERROR,
- errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast behavior expression of type %s to %s",
- format_type_be(exprType(expr)),
- format_type_be(returning->typid)),
- parser_errposition(pstate, exprLocation(expr)));
- else
+ if (coerced_expr == NULL)
+ {
+ /*
+ * Provide a HINT if the expression comes from a DEFAULT
+ * clause.
+ */
+ if (btype == JSON_BEHAVIOR_DEFAULT)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ errhint("You will need to cast the expression."),
+ parser_errposition(pstate, exprLocation(expr)));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ }
+
expr = coerced_expr;
+ }
}
if (behavior)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 5fd43be367..939e1b2f87 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -560,7 +560,16 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
ERROR: cannot cast behavior expression of type boolean to bigint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
ERROR: cannot cast behavior expression of type boolean to real
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+ a
+---
+
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
a
-------
false
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 074aedb2dd..ef5dfb4157 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -665,7 +665,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-ERROR: value too long for type character(2)
+ json_query
+------------
+ bb
+(1 row)
+
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -853,13 +857,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
(1 row)
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
json_query
------------
@@ -873,13 +881,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1405,3 +1417,33 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test coercion to domain over another fixed-legth type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+ERROR: cannot cast behavior expression of type integer to bit
+LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR...
+ ^
+HINT: You will need to cast the expression.
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+ERROR: bit string length 4 does not match type bit(3)
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 4594e5b013..dc509bed8a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index be5593b332..6875891843 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -479,3 +479,16 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test coercion to domain over another fixed-legth type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
--
2.43.0
On Mon, Jul 22, 2024 at 4:46 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Jul 18, 2024 at 3:04 PM jian he <jian.universality@gmail.com> wrote:
we still have problem in transformJsonBehavior
currently transformJsonBehavior:
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ERROR);
ERROR: cannot cast behavior expression of type text to bit
LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ...here, 010111 will default to int4, so "cannot cast behavior expression
of type text to bit"
is wrong?
also int4/int8 can be explicitly cast to bit(3), in this case, it
should return 111.I think we shouldn't try too hard in the code to "automatically" cast
the DEFAULT expression, especially if that means having to add special
case code for all sorts of source-target-type combinations.I'm inclined to just give a HINT to the user to cast the DEFAULT
expression by hand, because they *can* do that with the syntax that
exists.
select typname, typinput, pg_get_function_identity_arguments(typinput)
from pg_type pt join pg_proc proc on proc.oid = pt.typinput
where typtype = 'b' and typarray <> 0 and proc.pronargs > 1;
As you can see from the query result, we only need to deal with bit
and character type
in this context.
SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING bit(3) DEFAULT 10111 ON empty);
SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING char(3) DEFAULT 10111
ON empty) ;
the single quote literal ', no explicit cast, resolve to text type.
no single quote like 11, no explicit cast, resolve to int type.
we actually can cast int to bit, also have pg_cast entry.
so the above these 2 examples should behave the same, given there is
no pg_cast entry for int to text.
select castsource::regtype ,casttarget::regtype ,castfunc,castcontext,
castmethod
from pg_cast where 'int'::regtype in (castsource::regtype ,casttarget::regtype);
but i won't insist on it, since bit/varbit don't use that much.
I'm planning to push the attached 2 patches. 0001 is to fix
transformJsonBehavior() for these cases and 0002 to adjust the
behavior of casting the result of JSON_EXISTS() and EXISTS columns to
integer type. I've included the tests in your patch in 0001. I
noticed using cast expression to coerce the boolean constants to
fixed-length types would produce unexpected errors when the planner's
const-simplification calls the cast functions. So in 0001, I've made
that case also use runtime coercion using json_populate_type().
+ <note>
+ <para>
+ If an <literal>ON ERROR</literal> or <literal>ON EMPTY</literal>
+ expression can't be coerced to the <literal>RETURNING</literal> type
+ successfully, an SQL NULL value will be returned.
+ </para>
+ </note>
I think this change will have some controversy.
the following are counterexamples
SELECT JSON_value(jsonb '"aaa"', '$.a' RETURNING bool DEFAULT
'"2022-01-01"' ON empty);
return error, based on your change, should return NULL?
SELECT JSON_QUERY(jsonb '"[3,4]"', '$.a' RETURNING bigint[] EMPTY
array ON empty);
SELECT JSON_QUERY(jsonb '"[3,4]"', '$.a' RETURNING bigint[] EMPTY
object ON empty);
Now things get more confusing. empty array, empty object refers to
jsonb '[]' and jsonb '{}',
both cannot explicitly be cast to bigint[],
so both should return NULL based on your new implementation?
omit/keep quotes applied when casting '"[1,2]"' to int4range.
SELECT JSON_query(jsonb '"aaa"', '$.a' RETURNING int4range omit quotes
DEFAULT '"[1,2]"'::jsonb ON empty);
SELECT JSON_query(jsonb '"aaa"', '$.a' RETURNING int4range keep quotes
DEFAULT '"[1,2]"'::jsonb ON empty);
SELECT JSON_value(jsonb '"aaa"', '$.a' RETURNING date DEFAULT
'"2022-01-01"'::jsonb ON empty);
but jsonb cannot coerce to date., the example "select
('"2022-01-01"'::jsonb)::date; " yields an error.
but why does this query still return a date?
While reviewing the patch, I found some inconsistency on json_table EXISTS.
--tested based on your patch and master.
src4=# SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb
EXISTS PATH '$'));
ERROR: cannot cast behavior expression of type boolean to jsonb
src4=# SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb
EXISTS PATH '$' error on error));
a
------
true
(1 row)
Why explicitly "error on error" not report error while not explicitly
mentioning it yields an error?
"(a jsonb EXISTS PATH '$' error on error)" returns jsonb 'true'
imply that no errors happened.
so "(a jsonb EXISTS PATH '$')" should not have any errors.
but boolean cannot cast to jsonb so for JSON_TABLE,
we should reject
COLUMNS (a jsonb EXISTS PATH '$' error on error ));
COLUMNS (a jsonb EXISTS PATH '$' unknown on error ));
at an earlier stage.
because json_populate_type will use literal 'true'/'false' cast to
jsonb, which will not fail.
but JsonPathExists returns are *not* quoted true/false.
so rejecting it earlier is better than handling it at ExecEvalJsonExprPath.
attached patch trying to solve the problem, changes applied based on
your 0001, 0002.
after apply attached patch:
create domain djsonb as jsonb check(value = 'true');
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS
PATH '$' error on error));
ERROR: cannot cast type boolean to djsonb
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS
PATH '$' unknown on error));
ERROR: cannot cast type boolean to djsonb
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$'));
ERROR: cannot cast type boolean to jsonb
i found out a typo in
src/test/regress/expected/sqljson_queryfuncs.out,
src/test/regress/sql/sqljson_queryfuncs.sql
"fixed-legth" should be "fixed-length"
Attachments:
v1-0001-better-handle-json_table-EXISTS-ERROR-UNKNOWN-ON-.patchapplication/x-patch; name=v1-0001-better-handle-json_table-EXISTS-ERROR-UNKNOWN-ON-.patchDownload
From bf05974a330a1df5877e77a0484922b4d17ccde9 Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Tue, 23 Jul 2024 19:57:26 +0800
Subject: [PATCH v1 1/1] better handle json_table EXISTS ERROR|UNKNOWN ON ERROR
cases
bool cannot cast to jsonb/json.
so the following two expression should fail.
(column_name jsonb EXISTS PATH path_expression error on error);
(column_name jsonb EXISTS PATH path_expression unknown on error);
make it fail at parsing stage.
---
src/backend/parser/parse_expr.c | 9 +++++++++
src/test/regress/expected/sqljson_jsontable.out | 15 +++++++++++++--
src/test/regress/sql/sqljson_jsontable.sql | 10 ++++++++++
3 files changed, 32 insertions(+), 2 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 61611b8a..92dbf854 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4262,6 +4262,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
Node *path_spec;
const char *func_name = NULL;
JsonFormatType default_format;
+ Oid returning_typid;
switch (func->op)
{
@@ -4478,6 +4479,14 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
if (jsexpr->returning->typid != BOOLOID)
jsexpr->use_json_coercion = jsexpr->returning->typid != INT4OID;
+ returning_typid = getBaseType(jsexpr->returning->typid);
+
+ if (returning_typid == JSONBOID || returning_typid == JSONOID)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast type boolean to %s",
+ format_type_be(jsexpr->returning->typid)));
+
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
jsexpr->returning);
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 9e93307f..b8779276 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -560,6 +560,17 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR
1
(1 row)
+--corner cases:
+--(column_name, jsonb EXISTS PATH '$' unknown on error)
+--(column_name, jsonb EXISTS PATH '$' error on error)
+create domain djsonb as jsonb check(value = 'true');
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS PATH '$' error on error));
+ERROR: cannot cast type boolean to djsonb
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS PATH '$' unknown on error));
+ERROR: cannot cast type boolean to djsonb
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$'));
+ERROR: cannot cast type boolean to jsonb
+drop domain djsonb;
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
ERROR: cannot cast behavior expression of type boolean to smallint
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
@@ -582,9 +593,9 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' E
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to json
+ERROR: cannot cast type boolean to json
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to jsonb
+ERROR: cannot cast type boolean to jsonb
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index f6fc09b7..09fd5c66 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -264,6 +264,16 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
-- JSON_TABLE: EXISTS PATH types
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+
+--corner cases:
+--(column_name, jsonb EXISTS PATH '$' unknown on error)
+--(column_name, jsonb EXISTS PATH '$' error on error)
+create domain djsonb as jsonb check(value = 'true');
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS PATH '$' error on error));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a djsonb EXISTS PATH '$' unknown on error));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$'));
+drop domain djsonb;
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
--
2.34.1
On Tue, Jul 23, 2024 at 11:45 AM jian he <jian.universality@gmail.com> wrote:
On Mon, Jul 22, 2024 at 4:46 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Jul 18, 2024 at 3:04 PM jian he <jian.universality@gmail.com> wrote:
we still have problem in transformJsonBehavior
currently transformJsonBehavior:
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ERROR);
ERROR: cannot cast behavior expression of type text to bit
LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 010111 ON ...here, 010111 will default to int4, so "cannot cast behavior expression
of type text to bit"
is wrong?
also int4/int8 can be explicitly cast to bit(3), in this case, it
should return 111.I think we shouldn't try too hard in the code to "automatically" cast
the DEFAULT expression, especially if that means having to add special
case code for all sorts of source-target-type combinations.I'm inclined to just give a HINT to the user to cast the DEFAULT
expression by hand, because they *can* do that with the syntax that
exists.select typname, typinput, pg_get_function_identity_arguments(typinput)
from pg_type pt join pg_proc proc on proc.oid = pt.typinput
where typtype = 'b' and typarray <> 0 and proc.pronargs > 1;As you can see from the query result, we only need to deal with bit
and character type
in this context.SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING bit(3) DEFAULT 10111 ON empty);
SELECT JSON_VALUE(jsonb '1234', '$.a' RETURNING char(3) DEFAULT 10111
ON empty) ;the single quote literal ', no explicit cast, resolve to text type.
no single quote like 11, no explicit cast, resolve to int type.
we actually can cast int to bit, also have pg_cast entry.
so the above these 2 examples should behave the same, given there is
no pg_cast entry for int to text.select castsource::regtype ,casttarget::regtype ,castfunc,castcontext,
castmethod
from pg_cast where 'int'::regtype in (castsource::regtype ,casttarget::regtype);but i won't insist on it, since bit/varbit don't use that much.
The cast from int to bit that exists in pg_cast is only good for
explicit casts, so would truncate user's value instead of flagging it
as invalid input, and this whole discussion is about not doing that.
With the DEFAULT expression specified or interpreted as a text string,
we don't have that problem because we can then use CoerceViaIO as an
assignment-level cast, whereby the invalid input *is* flagged as it
should, like this:
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT '11111' ON ERROR);
ERROR: bit string length 5 does not match type bit(3)
So it seems fair to me to flag it when the user specifies an integer
in DEFAULT we can't create a cast expression that does not truncate a
value to fit the RETURNING type.
I'm planning to push the attached 2 patches. 0001 is to fix
transformJsonBehavior() for these cases and 0002 to adjust the
behavior of casting the result of JSON_EXISTS() and EXISTS columns to
integer type. I've included the tests in your patch in 0001. I
noticed using cast expression to coerce the boolean constants to
fixed-length types would produce unexpected errors when the planner's
const-simplification calls the cast functions. So in 0001, I've made
that case also use runtime coercion using json_populate_type().+ <note> + <para> + If an <literal>ON ERROR</literal> or <literal>ON EMPTY</literal> + expression can't be coerced to the <literal>RETURNING</literal> type + successfully, an SQL NULL value will be returned. + </para> + </note>I think this change will have some controversy.
On second thought, I agree. I've made some changes to *throw* the
error when the JsonBehavior values fail being coerced to the RETURNING
type. Please check the attached.
In the attached patch, I've also taken care of the problem mentioned
in your latest email -- the solution I've chosen is not to produce the
error when ERROR ON ERROR is specified but to use runtime coercion
also for the jsonb type or any type that is not integer. Also fixed
the typos.
Thanks for your attention!
--
Thanks, Amit Langote
Attachments:
0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchapplication/octet-stream; name=0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchDownload
From 7e70e0643aebdb1b34788bb5cd8d2829bd0ff393 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Mon, 22 Jul 2024 17:13:58 +0900
Subject: [PATCH 2/2] SQL/JSON: Fix casting for integer EXISTS columns in
JSON_TABLE
The current method of coercing the boolean result value of
JsonPathExists() to the target type specified for an EXISTS column,
which is to call the type's input function via json_populate_type(),
leads to an error when the target type is integer, because the
integer input function doesn't recognize boolean literal values as
valid.
Instead use the boolean-to-integer cast function for coercion in that
case so that using integer as type for EXISTS columns works. Note
that coercion for ON ERROR values TRUE and FALSE already works like
that because the parser creates a cast expression including the cast
function, but the coercion of the actual result value is not handled
by the parser.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExprInterp.c | 19 +++++++++++++++++++
src/backend/parser/parse_expr.c | 2 +-
.../regress/expected/sqljson_jsontable.out | 10 ++++++++--
src/test/regress/sql/sqljson_jsontable.sql | 3 ++-
4 files changed, 30 insertions(+), 4 deletions(-)
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 9d4cca0db2..68a7201e35 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4303,11 +4303,30 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
*op->resnull = false;
+
+ /*
+ * Prepare to call json_populate_type() to coerce the
+ * boolean result to the target type. Parser must have
+ * set use_json_coercion to false if the target type is
+ * integer, because in that case we call the boolean-to-
+ * integer cast function instead as the integer's input
+ * function (which is what json_populate_type() for scalar
+ * target types) doesn't accept boolean literals as valid
+ * input. We only have a special case for integer as it
+ * seems common to use integer type for EXISTS columns in
+ * JSON_TABLE().
+ */
if (jsexpr->use_json_coercion)
+ {
+ Assert(jsexpr->returning->typid != INT4OID);
*op->resvalue = DirectFunctionCall1(jsonb_in,
BoolGetDatum(exists) ?
CStringGetDatum("true") :
CStringGetDatum("false"));
+ }
+ else if (jsexpr->returning->typid == INT4OID)
+ *op->resvalue = DirectFunctionCall1(bool_int4,
+ BoolGetDatum(exists));
else
*op->resvalue = BoolGetDatum(exists);
}
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 5485104b6b..a2566d9a20 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4476,7 +4476,7 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
/* JSON_TABLE() COLUMNS can specify a non-boolean type. */
if (jsexpr->returning->typid != BOOLOID)
- jsexpr->use_json_coercion = true;
+ jsexpr->use_json_coercion = jsexpr->returning->typid != INT4OID;
jsexpr->on_error = transformJsonBehavior(pstate, func->on_error,
JSON_BEHAVIOR_FALSE,
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index eeeb411e47..469ca542ad 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -548,12 +548,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
(1 row)
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
a
---
0
(1 row)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+ a
+---
+ 1
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
DETAIL: invalid input syntax for type smallint: "false"
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index dc509bed8a..f6fc09b7ad 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -262,7 +262,8 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAU
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
--
2.43.0
0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchapplication/octet-stream; name=0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchDownload
From 46630c58183571be9e0662aaa389ad84f6ddc17a Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Tue, 23 Jul 2024 21:05:55 +0900
Subject: [PATCH 1/2] SQL/JSON: Some fixes to JsonBehavior expression casting
1. Remove the special case handling when casting the JsonBehavior
expressions to types with typmod, like 86d33987 did for the casting
of SQL/JSON constructor functions.
2. Fix casting for fixed-length character and bit string types by
using assignment-level casts. This is again similar to what
86d33987 did, but for ON ERROR / EMPTY expressions.
3. Use runtime coercion for the boolean ON ERROR constants so that
the coercion works correctly for EXISTS columns that use fixed-
length character string types. For example, so that the default
"false" doesn't emit an "value too long for type character(2)"
error even when no ON ERROR clause is specified.
4. Simplify the conditions of when to use runtime coercion vs
creating the cast expression in the parser itself. jsonb-valued
expressions are now always coerced at runtime and boolean
expressions too if the target type is a string type for the
reasons mentioned above.
5. Instead of returning a NULL when the JsonBehavior value cannot be
coerced to the RETURNING type, throw the error message telling the
user to possibly reconsider the RETURNING type.
Tests related to casting to bit(N) are taken from Jian He's patch.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 12 +++
src/backend/executor/execExprInterp.c | 81 +++++++++++++--
src/backend/parser/parse_expr.c | 99 +++++++++++++------
.../regress/expected/sqljson_jsontable.out | 29 ++++--
.../regress/expected/sqljson_queryfuncs.out | 78 ++++++++++-----
src/test/regress/sql/sqljson_jsontable.sql | 5 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 15 ++-
7 files changed, 249 insertions(+), 70 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index ccd4863778..54cd9b1c42 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4416,9 +4416,15 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
+ {
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
jsexpr->omit_quotes, resv, resnull);
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
+
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP;
@@ -4449,8 +4455,14 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
+ {
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
jsexpr->omit_quotes, resv, resnull);
+
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
}
foreach(lc, jumps_to_end)
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d8735286c4..9d4cca0db2 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4284,13 +4284,12 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
memset(&jsestate->error, 0, sizeof(NullableDatum));
memset(&jsestate->empty, 0, sizeof(NullableDatum));
- /*
- * Also reset ErrorSaveContext contents for the next row. Since we don't
- * set details_wanted, we don't need to also reset error_data, which would
- * be NULL anyway.
- */
- Assert(!jsestate->escontext.details_wanted &&
- jsestate->escontext.error_data == NULL);
+ /* Also reset ErrorSaveContext contents for the next row. */
+ if (jsestate->escontext.details_wanted)
+ {
+ jsestate->escontext.error_data = NULL;
+ jsestate->escontext.details_wanted = false;
+ }
jsestate->escontext.error_occurred = false;
switch (jsexpr->op)
@@ -4400,6 +4399,15 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
error = true;
}
+ /*
+ * When setting up the ErrorSaveContext (if needed) for capturing the
+ * errors that occur when coercing the JsonBehavior expression, set
+ * details_wanted to be able to show the actual error message as the
+ * DETAIL of the error message that tells that it is the
+ * JsonBehavior expression that caused the error; see
+ * ExecEvalJsonCoercionFinish().
+ */
+
/* Handle ON EMPTY. */
if (empty)
{
@@ -4410,6 +4418,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->empty.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON EMPTY value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(jsestate->jump_empty >= 0);
return jsestate->jump_empty;
}
@@ -4417,6 +4428,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
else if (jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(!throw_error && jsestate->jump_error >= 0);
return jsestate->jump_error;
}
@@ -4442,6 +4456,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*op->resvalue = (Datum) 0;
*op->resnull = true;
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
return jsestate->jump_error;
}
@@ -4544,9 +4561,33 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
(Node *) escontext);
}
+static char *
+GetJsonBehaviorValueString(JsonBehavior *behavior)
+{
+ /*
+ * The order of array elements must correspond to the order of
+ * JsonBehaviorType members.
+ */
+ const char *behavior_names[] =
+ {
+ "NULL",
+ "ERROR",
+ "EMPTY",
+ "TRUE",
+ "FALSE",
+ "UNKNOWN",
+ "EMPTY ARRAY",
+ "EMPTY OBJECT",
+ "DEFAULT"
+ };
+
+ return pstrdup(behavior_names[behavior->btype]);
+}
+
/*
* Checks if an error occurred in ExecEvalJsonCoercion(). If so, this sets
- * JsonExprState.error to trigger the ON ERROR handling steps.
+ * JsonExprState.error to trigger the ON ERROR handling steps, unless the
+ * error is thrown when coercing a JsonBehavior value.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
@@ -4555,9 +4596,33 @@ ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
if (SOFT_ERROR_OCCURRED(&jsestate->escontext))
{
+ /*
+ * jsestate->error or jsetate->empty being set means that the error
+ * occurred when coercing the JsonBehavior value. Throw the error in
+ * that case with the actual coercion error message shown in the
+ * DETAIL part.
+ */
+ if (DatumGetBool(jsestate->error.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON ERROR expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_error)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+ else if (DatumGetBool(jsestate->empty.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON EMPTY expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_empty)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+
*op->resvalue = (Datum) 0;
*op->resnull = true;
+
jsestate->error.value = BoolGetDatum(true);
+
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
}
}
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f27806..5485104b6b 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4685,51 +4685,90 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
if (expr == NULL && btype != JSON_BEHAVIOR_ERROR)
expr = GetJsonBehaviorConst(btype, location);
- if (expr)
+ /*
+ * Try to coerce the expression if needed.
+ *
+ * Use runtime coercion using json_populate_type() if the expression is
+ * NULL, jsonb-valued, or boolean-valued (unless the target type is integer
+ * or domain over integer, in which case use the boolean-to-integer cast
+ * function).
+ *
+ * For other non-NULL expressions, try to find a cast and error out if one
+ * is not found.
+ */
+ if (expr && exprType(expr) != returning->typid)
{
- Node *coerced_expr = expr;
bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull);
+ char typcategory = TypeCategory(returning->typid);
- /*
- * Coerce NULLs and "internal" (that is, not specified by the user)
- * jsonb-valued expressions at runtime using json_populate_type().
- *
- * For other (user-specified) non-NULL values, try to find a cast and
- * error out if one is not found.
- */
if (isnull ||
- (exprType(expr) == JSONBOID &&
- btype == default_behavior))
+ exprType(expr) == JSONBOID ||
+ (exprType(expr) == BOOLOID &&
+ getBaseType(returning->typid) != INT4OID))
+ {
coerce_at_runtime = true;
+
+ /*
+ * json_populate_type() expects to be passed a jsonb value, so gin
+ * up a Const containing the appropriate boolean value represented
+ * as jsonb, discarding the original Const containing a plain
+ * boolean.
+ */
+ if (exprType(expr) == BOOLOID)
+ {
+ char *val = btype == JSON_BEHAVIOR_TRUE ? "true" : "false";
+
+ expr = (Node *) makeConst(JSONBOID, -1, InvalidOid, -1,
+ DirectFunctionCall1(jsonb_in,
+ CStringGetDatum(val)),
+ false, false);
+ }
+ }
else
{
- int32 baseTypmod = returning->typmod;
+ Node *coerced_expr;
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
+ /*
+ * Use an assignment cast if coercing to a string type so that
+ * build_coercion_expression() assumes implicit coercion when
+ * coercing the typmod, so that inputs exceeding length cause an
+ * error instead of silent truncation.
+ */
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
+ returning->typid, returning->typmod,
+ (typcategory == TYPCATEGORY_STRING ||
+ typcategory == TYPCATEGORY_BITSTRING) ?
+ COERCION_ASSIGNMENT :
COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
- }
- if (coerced_expr == NULL)
- ereport(ERROR,
- errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast behavior expression of type %s to %s",
- format_type_be(exprType(expr)),
- format_type_be(returning->typid)),
- parser_errposition(pstate, exprLocation(expr)));
- else
+ if (coerced_expr == NULL)
+ {
+ /*
+ * Provide a HINT if the expression comes from a DEFAULT
+ * clause.
+ */
+ if (btype == JSON_BEHAVIOR_DEFAULT)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ errhint("You will need to cast the expression."),
+ parser_errposition(pstate, exprLocation(expr)));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ }
+
expr = coerced_expr;
+ }
}
if (behavior)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 5fd43be367..eeeb411e47 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -555,21 +555,38 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to smallint
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type smallint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to bigint
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type bigint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to real
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type real: "false"
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
a
-------
false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to json
+ a
+-------
+ false
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to jsonb
+ a
+-------
+ false
+(1 row)
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 074aedb2dd..95bfe369f8 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -313,11 +313,8 @@ SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
-- Test NULL checks execution in domain types
CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null);
- json_value
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null ERROR ON ERROR);
ERROR: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR);
@@ -665,7 +662,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-ERROR: value too long for type character(2)
+ json_query
+------------
+ bb
+(1 row)
+
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -853,13 +854,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
(1 row)
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
json_query
------------
@@ -873,13 +878,11 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1035,11 +1038,8 @@ SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
(1 row)
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON EMPTY expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
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
@@ -1369,7 +1369,7 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY ], EMPTY OBJECT, or DEFAULT expression is allowed in ON ERROR for JSON_QUERY().
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -1405,3 +1405,33 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+ERROR: cannot cast behavior expression of type integer to bit
+LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR...
+ ^
+HINT: You will need to cast the expression.
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+ERROR: bit string length 4 does not match type bit(3)
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 4594e5b013..dc509bed8a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index be5593b332..0dd55f9453 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -467,7 +467,7 @@ SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -479,3 +479,16 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
--
2.43.0
On Tue, Jul 23, 2024 at 8:52 PM Amit Langote <amitlangote09@gmail.com> wrote:
In the attached patch, I've also taken care of the problem mentioned
in your latest email -- the solution I've chosen is not to produce the
error when ERROR ON ERROR is specified but to use runtime coercion
also for the jsonb type or any type that is not integer. Also fixed
the typos.Thanks for your attention!
COLUMNS (col_name jsonb EXISTS PATH 'pah_expression') inconsistency
seems resolved.
I also tested the domain over jsonb, it works.
transformJsonFuncExpr we have:
case JSON_QUERY_OP:
if (jsexpr->returning->typid != JSONBOID || jsexpr->omit_quotes)
jsexpr->use_json_coercion = true;
case JSON_VALUE_OP:
if (jsexpr->returning->typid != TEXTOID)
{
if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
DomainHasConstraints(jsexpr->returning->typid))
jsexpr->use_json_coercion = true;
else
jsexpr->use_io_coercion = true;
}
JSONBOID won't be a domain. for domain type, json_value, json_query
will use jsexpr->use_json_coercion.
jsexpr->use_json_coercion can handle whether the domain has constraints or not.
so i don't know the purpose of following code in ExecInitJsonExpr
if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
DomainHasConstraints(jsexpr->returning->typid))
{
Assert(jsexpr->use_json_coercion);
scratch->opcode = EEOP_JUMP;
scratch->d.jump.jumpdone = state->steps_len + 1;
ExprEvalPushStep(state, scratch);
}
json_table exits works fine with int4, not domain over int4. The
following are test suites.
drop domain if exists dint4, dint4_1,dint4_0;
create domain dint4 as int;
create domain dint4_1 as int check ( value <> 1 );
create domain dint4_0 as int check ( value <> 0 );
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' ));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' false ON ERROR));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' ERROR ON ERROR));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_0
EXISTS PATH '$.a'));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_0
EXISTS PATH '$'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$.a'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$.a' ERROR ON ERROR));
drop domain if exists djs;
create domain djs as jsonb check ( value <> '"11"' );
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING djs keep quotes
DEFAULT '"11"' ON empty);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING djs omit quotes
DEFAULT '"11"' ON empty);
SELECT JSON_QUERY(jsonb '"11"', '$' RETURNING djs omit quotes DEFAULT
'"11"' ON empty);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING jsonb keep quotes
DEFAULT '"11"' ON empty);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING jsonb omit quotes
DEFAULT '"11"' ON empty);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING int4range omit quotes
DEFAULT '"[1,2]"'::jsonb ON empty);
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING int4range keep quotes
DEFAULT '"[1,2]"'::jsonb ON empty);
SELECT JSON_value(jsonb '"aaa"', '$.a' RETURNING int4range DEFAULT
'"[1,2]"'::jsonb ON empty);
----------------------------
I found out 2 issues for the above tests.
1. RETURNING types is jsonb/domain over jsonb, default expression does
not respect omit/keep quotes,
but other RETURNING types do. Maybe this will be fine.
2. domain over jsonb should fail just like domain over other types?
RETURNING djs keep quotes DEFAULT '"11"' ON empty
should fail as
ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
DETAIL: value for domain djs violates check constraint "djs_check""
errcode(ERRCODE_CANNOT_COERCE),
errmsg("cannot cast behavior expression of
type %s to %s",
format_type_be(exprType(expr)),
format_type_be(returning->typid)),
errhint("You will need to cast the expression."),
parser_errposition(pstate, exprLocation(expr)));
maybe
errhint("You will need to explicitly cast the expression to type %s",
format_type_be(returning->typid))
On Wed, Jul 24, 2024 at 3:25 PM jian he <jian.universality@gmail.com> wrote:
transformJsonFuncExpr we have:
case JSON_QUERY_OP:
if (jsexpr->returning->typid != JSONBOID || jsexpr->omit_quotes)
jsexpr->use_json_coercion = true;case JSON_VALUE_OP:
if (jsexpr->returning->typid != TEXTOID)
{
if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
DomainHasConstraints(jsexpr->returning->typid))
jsexpr->use_json_coercion = true;
else
jsexpr->use_io_coercion = true;
}JSONBOID won't be a domain. for domain type, json_value, json_query
will use jsexpr->use_json_coercion.
jsexpr->use_json_coercion can handle whether the domain has constraints or not.so i don't know the purpose of following code in ExecInitJsonExpr
if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
DomainHasConstraints(jsexpr->returning->typid))
{
Assert(jsexpr->use_json_coercion);
scratch->opcode = EEOP_JUMP;
scratch->d.jump.jumpdone = state->steps_len + 1;
ExprEvalPushStep(state, scratch);
}
Yeah, it's a useless JUMP. I forget why it's there. I have attached
a patch (0005) to remove it.
json_table exits works fine with int4, not domain over int4. The
following are test suites.drop domain if exists dint4, dint4_1,dint4_0;
create domain dint4 as int;
create domain dint4_1 as int check ( value <> 1 );
create domain dint4_0 as int check ( value <> 0 );
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' ));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' false ON ERROR));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4
EXISTS PATH '$.a' ERROR ON ERROR));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_0
EXISTS PATH '$.a'));
SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_0
EXISTS PATH '$'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$.a'));
SELECT a,a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4_1
EXISTS PATH '$.a' ERROR ON ERROR));
Domain-over-integer case should be fixed with the attached updated 0002.
I found out 2 issues for the above tests.
1. RETURNING types is jsonb/domain over jsonb, default expression does
not respect omit/keep quotes,
but other RETURNING types do. Maybe this will be fine.
Yeah, I am not sure whether and how we could implement OMIT/KEEP
QUOTES for the DEFAULT expression. I might try later or simply
document that OMIT/KEEP QUOTE is only applied to the query result but
not the DEFAULT expression.
2. domain over jsonb should fail just like domain over other types?
RETURNING djs keep quotes DEFAULT '"11"' ON empty
should fail as
ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
DETAIL: value for domain djs violates check constraint "djs_check""
I think this should be fixed with the attached patch 0004.
errcode(ERRCODE_CANNOT_COERCE),
errmsg("cannot cast behavior expression of
type %s to %s",
format_type_be(exprType(expr)),
format_type_be(returning->typid)),
errhint("You will need to cast the expression."),
parser_errposition(pstate, exprLocation(expr)));maybe
errhint("You will need to explicitly cast the expression to type %s",
format_type_be(returning->typid))
OK, done.
Please check.
--
Thanks, Amit Langote
Attachments:
0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchapplication/octet-stream; name=0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchDownload
From dae8cf6c2abf7e120a72c711201950e62c324dbc Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 14:51:29 +0900
Subject: [PATCH 2/5] SQL/JSON: Fix casting for integer EXISTS columns in
JSON_TABLE
The current method of coercing the boolean result value of
JsonPathExists() to the target type specified for an EXISTS column,
which is to call the type's input function via json_populate_type(),
leads to an error when the target type is integer, because the
integer input function doesn't recognize boolean literal values as
valid.
Instead use the boolean-to-integer cast function for coercion in that
case so that using integer or domains thereof as type for EXISTS
columns works. Note that coercion for ON ERROR values TRUE and FALSE
already works like that because the parser creates a cast expression
including the cast function, but the coercion of the actual result
value is not handled by the parser.
Tests by Jian He.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 21 +++++---
src/backend/executor/execExprInterp.c | 46 ++++++++++++++---
src/include/executor/execExpr.h | 5 +-
.../regress/expected/sqljson_jsontable.out | 49 ++++++++++++++++++-
src/test/regress/sql/sqljson_jsontable.sql | 18 ++++++-
5 files changed, 121 insertions(+), 18 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index ccd4863778..db1ec11390 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -93,7 +93,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
- Datum *resv, bool *resnull);
+ bool exists_coerce, Datum *resv, bool *resnull);
/*
@@ -4344,7 +4344,9 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsestate->jump_eval_coercion = state->steps_len;
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes,
+ jsexpr->op == JSON_EXISTS_OP,
+ resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4417,7 +4419,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
@@ -4450,7 +4453,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
}
foreach(lc, jumps_to_end)
@@ -4470,7 +4474,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
- Datum *resv, bool *resnull)
+ bool exists_coerce, Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4480,8 +4484,13 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.resnull = resnull;
scratch.d.jsonexpr_coercion.targettype = returning->typid;
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
- scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
+ scratch.d.jsonexpr_coercion.json_coercion_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
+ scratch.d.jsonexpr_coercion.exists_coerce = exists_coerce;
+ scratch.d.jsonexpr_coercion.exists_cast_to_int = exists_coerce &&
+ getBaseType(returning->typid) == INT4OID;
+ scratch.d.jsonexpr_coercion.check_domain = exists_coerce &&
+ DomainHasConstraints(returning->typid);
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d8735286c4..d463e831ed 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4304,13 +4304,7 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
*op->resnull = false;
- if (jsexpr->use_json_coercion)
- *op->resvalue = DirectFunctionCall1(jsonb_in,
- BoolGetDatum(exists) ?
- CStringGetDatum("true") :
- CStringGetDatum("false"));
- else
- *op->resvalue = BoolGetDatum(exists);
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4534,10 +4528,46 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
{
ErrorSaveContext *escontext = op->d.jsonexpr_coercion.escontext;
+ /*
+ * Prepare to call json_populate_type() to coerce the boolean result of
+ * JSON_EXISTS_OP to the target type. If the the target type is integer
+ * or a domain over integer, call the boolean-to-integer cast function
+ * instead, because the integer's input function (which is what
+ * json_populate_type() calls to coerce to scalar target types) doesn't
+ * accept boolean literals as valid input. We only have a special case
+ * for integer and domains thereof as it seems common to use those types
+ * for EXISTS columns in JSON_TABLE().
+ */
+ if (op->d.jsonexpr_coercion.exists_coerce)
+ {
+ if (op->d.jsonexpr_coercion.exists_cast_to_int)
+ {
+ /* Check domain constraints if any. */
+ if (op->d.jsonexpr_coercion.check_domain &&
+ !domain_check_safe(*op->resvalue, *op->resnull,
+ op->d.jsonexpr_coercion.targettype,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
+ econtext->ecxt_per_query_memory,
+ (Node *) escontext))
+ {
+ *op->resnull = true;
+ *op->resvalue = (Datum) 0;
+ }
+ else
+ *op->resvalue = DirectFunctionCall1(bool_int4, *op->resvalue);
+ return;
+ }
+
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ DatumGetBool(*op->resvalue) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ }
+
*op->resvalue = json_populate_type(*op->resvalue, JSONBOID,
op->d.jsonexpr_coercion.targettype,
op->d.jsonexpr_coercion.targettypmod,
- &op->d.jsonexpr_coercion.json_populate_type_cache,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
econtext->ecxt_per_query_memory,
op->resnull,
op->d.jsonexpr_coercion.omit_quotes,
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 55337d4916..b6e031f108 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -708,7 +708,10 @@ typedef struct ExprEvalStep
Oid targettype;
int32 targettypmod;
bool omit_quotes;
- void *json_populate_type_cache;
+ bool exists_coerce;
+ bool exists_cast_to_int;
+ bool check_domain;
+ void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
} d;
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 82aa6e9a3e..e634b1e3b5 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -548,12 +548,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
(1 row)
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
a
---
0
(1 row)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+ a
+---
+ 1
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
a
---
@@ -599,6 +605,45 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
false
(1 row)
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+ a | a
+---+---
+ 1 | t
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+DROP DOMAIN dint4, dint4_0, dint4_1;
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index dc509bed8a..d7cfe3d39a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -262,7 +262,8 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAU
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
@@ -273,6 +274,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' E
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+DROP DOMAIN dint4, dint4_0, dint4_1;
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' OMIT QUOTES ON SCALAR STRING));
--
2.43.0
0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchapplication/octet-stream; name=0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchDownload
From 5a73a9bb1db237ea8146e02d3e46bda83292b915 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 22:36:23 +0900
Subject: [PATCH 1/5] SQL/JSON: Some fixes to JsonBehavior expression casting
1. Remove the special case handling when casting the JsonBehavior
expressions to types with typmod, like 86d33987 did for the casting
of SQL/JSON constructor functions.
2. Fix casting for fixed-length character and bit string types by
using assignment-level casts. This is again similar to what
86d33987 did, but for ON ERROR / EMPTY expressions.
3. Use runtime coercion for the boolean ON ERROR constants so that
the coercion works correctly for EXISTS columns that use fixed-
length character string types. For example, so that the default
"false" doesn't emit an "value too long for type character(2)"
error even when no ON ERROR clause is specified.
4. Simplify the conditions of when to use runtime coercion vs
creating the cast expression in the parser itself. jsonb-valued
expressions are now always coerced at runtime and boolean
expressions too if the target type is a string type for the
reasons mentioned above.
Tests are from a patch that Jian He posted.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/parser/parse_expr.c | 100 ++++++++++++------
.../regress/expected/sqljson_jsontable.out | 41 +++++--
.../regress/expected/sqljson_queryfuncs.out | 70 +++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 15 ++-
5 files changed, 179 insertions(+), 52 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f27806..26737572c4 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4685,51 +4685,91 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
if (expr == NULL && btype != JSON_BEHAVIOR_ERROR)
expr = GetJsonBehaviorConst(btype, location);
- if (expr)
+ /*
+ * Try to coerce the expression if needed.
+ *
+ * Use runtime coercion using json_populate_type() if the expression is
+ * NULL, jsonb-valued, or boolean-valued (unless the target type is integer
+ * or domain over integer, in which case use the boolean-to-integer cast
+ * function).
+ *
+ * For other non-NULL expressions, try to find a cast and error out if one
+ * is not found.
+ */
+ if (expr && exprType(expr) != returning->typid)
{
- Node *coerced_expr = expr;
bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull);
- /*
- * Coerce NULLs and "internal" (that is, not specified by the user)
- * jsonb-valued expressions at runtime using json_populate_type().
- *
- * For other (user-specified) non-NULL values, try to find a cast and
- * error out if one is not found.
- */
if (isnull ||
- (exprType(expr) == JSONBOID &&
- btype == default_behavior))
+ exprType(expr) == JSONBOID ||
+ (exprType(expr) == BOOLOID &&
+ getBaseType(returning->typid) != INT4OID))
+ {
coerce_at_runtime = true;
+
+ /*
+ * json_populate_type() expects to be passed a jsonb value, so gin
+ * up a Const containing the appropriate boolean value represented
+ * as jsonb, discarding the original Const containing a plain
+ * boolean.
+ */
+ if (exprType(expr) == BOOLOID)
+ {
+ char *val = btype == JSON_BEHAVIOR_TRUE ? "true" : "false";
+
+ expr = (Node *) makeConst(JSONBOID, -1, InvalidOid, -1,
+ DirectFunctionCall1(jsonb_in,
+ CStringGetDatum(val)),
+ false, false);
+ }
+ }
else
{
- int32 baseTypmod = returning->typmod;
+ Node *coerced_expr;
+ char typcategory = TypeCategory(returning->typid);
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
+ /*
+ * Use an assignment cast if coercing to a string type so that
+ * build_coercion_expression() assumes implicit coercion when
+ * coercing the typmod, so that inputs exceeding length cause an
+ * error instead of silent truncation.
+ */
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
+ returning->typid, returning->typmod,
+ (typcategory == TYPCATEGORY_STRING ||
+ typcategory == TYPCATEGORY_BITSTRING) ?
+ COERCION_ASSIGNMENT :
COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
- }
- if (coerced_expr == NULL)
- ereport(ERROR,
- errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast behavior expression of type %s to %s",
- format_type_be(exprType(expr)),
- format_type_be(returning->typid)),
- parser_errposition(pstate, exprLocation(expr)));
- else
+ if (coerced_expr == NULL)
+ {
+ /*
+ * Provide a HINT if the expression comes from a DEFAULT
+ * clause.
+ */
+ if (btype == JSON_BEHAVIOR_DEFAULT)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ errhint("You will need to explicitly cast the expression to type %s.",
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ }
+
expr = coerced_expr;
+ }
}
if (behavior)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 5fd43be367..82aa6e9a3e 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -555,21 +555,50 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to smallint
+ a
+---
+
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to bigint
+ a
+---
+
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to real
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+---
+
+(1 row)
+
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+ a
+---
+
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
a
-------
false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to json
+ a
+-------
+ false
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to jsonb
+ a
+-------
+ false
+(1 row)
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 074aedb2dd..e7b64a9882 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -665,7 +665,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-ERROR: value too long for type character(2)
+ json_query
+------------
+ bb
+(1 row)
+
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -853,13 +857,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
(1 row)
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
json_query
------------
@@ -873,13 +881,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1369,7 +1381,7 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY ], EMPTY OBJECT, or DEFAULT expression is allowed in ON ERROR for JSON_QUERY().
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -1405,3 +1417,33 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+ERROR: cannot cast behavior expression of type integer to bit
+LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR...
+ ^
+HINT: You will need to explicitly cast the expression to type bit.
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+ERROR: bit string length 4 does not match type bit(3)
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 4594e5b013..dc509bed8a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index be5593b332..0dd55f9453 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -467,7 +467,7 @@ SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -479,3 +479,16 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
--
2.43.0
0005-SQL-JSON-Remove-useless-code-in-ExecInitJsonExpr.patchapplication/octet-stream; name=0005-SQL-JSON-Remove-useless-code-in-ExecInitJsonExpr.patchDownload
From c03d5cddf9f0a68ab88cdf8537e1e302ad9ab4c6 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 23:02:11 +0900
Subject: [PATCH 5/5] SQL/JSON: Remove useless code in ExecInitJsonExpr
The code was for adding an JUMP to the next step, which is
unnecessary.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 15 ---------------
1 file changed, 15 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 23d907451d..b614f7a4af 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4312,21 +4312,6 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.constval.isnull = true;
ExprEvalPushStep(state, scratch);
- /*
- * Jump to coerce the NULL using json_populate_type() if needed. Coercing
- * NULL is only interesting when the RETURNING type is a domain whose
- * constraints must be checked. jsexpr->use_json_coercion must have been
- * set in that case.
- */
- if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
- DomainHasConstraints(jsexpr->returning->typid))
- {
- Assert(jsexpr->use_json_coercion);
- scratch->opcode = EEOP_JUMP;
- scratch->d.jump.jumpdone = state->steps_len + 1;
- ExprEvalPushStep(state, scratch);
- }
-
/*
* To handle coercion errors softly, use the following ErrorSaveContext to
* pass to ExecInitExprRec() when initializing the coercion expressions
--
2.43.0
0004-SQL-JSON-Respect-OMIT-QUOTES-when-RETURNING-domain_t.patchapplication/octet-stream; name=0004-SQL-JSON-Respect-OMIT-QUOTES-when-RETURNING-domain_t.patchDownload
From bb14709b3fe73045916ebde27f031112b438ee6b Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 23:07:21 +0900
Subject: [PATCH 4/5] SQL/JSON: Respect OMIT QUOTES when RETURNING domain_type
populate_domain() didn't consider the omit_quotes flag passed down to
json_populate_type() by ExecEvalJsonCoercion(). Fix that.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/utils/adt/jsonfuncs.c | 11 ++++++-----
src/test/regress/expected/sqljson_queryfuncs.out | 8 ++++++++
src/test/regress/sql/sqljson_queryfuncs.sql | 3 +++
3 files changed, 17 insertions(+), 5 deletions(-)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 48c3f88140..1b681eff5f 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -453,7 +453,7 @@ static void prepare_column_cache(ColumnIOData *column, Oid typid, int32 typmod,
static Datum populate_record_field(ColumnIOData *col, Oid typid, int32 typmod,
const char *colname, MemoryContext mcxt, Datum defaultval,
JsValue *jsv, bool *isnull, Node *escontext,
- bool omit_quotes);
+ bool omit_scalar_quotes);
static RecordIOData *allocate_record_info(MemoryContext mcxt, int ncolumns);
static bool JsObjectGetField(JsObject *obj, char *field, JsValue *jsv);
static void populate_recordset_record(PopulateRecordsetState *state, JsObject *obj);
@@ -470,7 +470,7 @@ static Datum populate_array(ArrayIOData *aio, const char *colname,
Node *escontext);
static Datum populate_domain(DomainIOData *io, Oid typid, const char *colname,
MemoryContext mcxt, JsValue *jsv, bool *isnull,
- Node *escontext);
+ Node *escontext, bool omit_quotes);
/* functions supporting jsonb_delete, jsonb_set and jsonb_concat */
static JsonbValue *IteratorConcat(JsonbIterator **it1, JsonbIterator **it2,
@@ -3218,7 +3218,8 @@ populate_domain(DomainIOData *io,
MemoryContext mcxt,
JsValue *jsv,
bool *isnull,
- Node *escontext)
+ Node *escontext,
+ bool omit_quotes)
{
Datum res;
@@ -3229,7 +3230,7 @@ populate_domain(DomainIOData *io,
res = populate_record_field(io->base_io,
io->base_typid, io->base_typmod,
colname, mcxt, PointerGetDatum(NULL),
- jsv, isnull, escontext, false);
+ jsv, isnull, escontext, omit_quotes);
Assert(!*isnull || SOFT_ERROR_OCCURRED(escontext));
}
@@ -3461,7 +3462,7 @@ populate_record_field(ColumnIOData *col,
case TYPECAT_DOMAIN:
return populate_domain(&col->io.domain, typid, colname, mcxt,
- jsv, isnull, escontext);
+ jsv, isnull, escontext, omit_scalar_quotes);
default:
elog(ERROR, "unrecognized type category '%c'", typcat);
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 3080f5ed3e..2a56e247f8 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -738,6 +738,14 @@ SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quot
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error);
ERROR: malformed range literal: ""[1,2]""
DETAIL: Missing left parenthesis or bracket.
+CREATE DOMAIN char_domain_not_a AS char(1);
+SELECT JSON_QUERY(jsonb '"a"', '$' RETURNING char_domain_not_a OMIT QUOTES ERROR ON ERROR);
+ json_query
+------------
+ a
+(1 row)
+
+DROP DOMAIN char_domain_not_a;
SELECT JSON_QUERY(jsonb '[]', '$[*]');
json_query
------------
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index 0dd55f9453..6ae33418b2 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -214,6 +214,9 @@ SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range omit quotes);
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes);
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error);
+CREATE DOMAIN char_domain_not_a AS char(1);
+SELECT JSON_QUERY(jsonb '"a"', '$' RETURNING char_domain_not_a OMIT QUOTES ERROR ON ERROR);
+DROP DOMAIN char_domain_not_a;
SELECT JSON_QUERY(jsonb '[]', '$[*]');
SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
--
2.43.0
0003-SQL-JSON-Fix-handling-of-errors-coercing-JsonBehavio.patchapplication/octet-stream; name=0003-SQL-JSON-Fix-handling-of-errors-coercing-JsonBehavio.patchDownload
From 215360b921334c1810f35ad98a33eebadd874273 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 22:13:12 +0900
Subject: [PATCH 3/5] SQL/JSON: Fix handling of errors coercing JsonBehavior
expressions
Instead of returning a NULL when the JsonBehavior value cannot be
coerced to the RETURNING type, throw the error message informing the
user that it is the JsonBehavior expression that caused the error
with the actual error message show in the DETAIL.
To ensure that the errors of executing a JsonBehavior expression that
is coerced in the parser are caught instead of being thrown directly,
pass ErrorSaveContext to ExecInitExprRec() when initializing it.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 47 ++++++++++-
src/backend/executor/execExprInterp.c | 81 +++++++++++++++++--
.../regress/expected/sqljson_jsontable.out | 40 ++++-----
.../regress/expected/sqljson_queryfuncs.out | 34 +++-----
4 files changed, 146 insertions(+), 56 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index db1ec11390..23d907451d 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4402,6 +4402,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
+ ErrorSaveContext *saved_escontext;
+
jsestate->jump_error = state->steps_len;
/* JUMP to end if false, that is, skip the ON ERROR expression. */
@@ -4412,9 +4414,15 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.jump.jumpdone = -1; /* set below */
ExprEvalPushStep(state, scratch);
- /* Steps to evaluate the ON ERROR expression */
+ /*
+ * Steps to evaluate the ON ERROR expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
ExecInitExprRec((Expr *) jsexpr->on_error->expr,
state, resv, resnull);
+ state->escontext = saved_escontext;
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
@@ -4422,6 +4430,19 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsexpr->omit_quotes, false,
resv, resnull);
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur
+ * when coercing and rethrow them.
+ */
+ if (jsexpr->on_error->coerce ||
+ IsA(jsexpr->on_error->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_error->expr, CoerceToDomain))
+ {
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
+
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP;
@@ -4436,6 +4457,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_empty != NULL &&
jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
+ ErrorSaveContext *saved_escontext;
+
jsestate->jump_empty = state->steps_len;
/* JUMP to end if false, that is, skip the ON EMPTY expression. */
@@ -4446,15 +4469,35 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.jump.jumpdone = -1; /* set below */
ExprEvalPushStep(state, scratch);
- /* Steps to evaluate the ON EMPTY expression */
+ /*
+ * Steps to evaluate the ON EMPTY expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
ExecInitExprRec((Expr *) jsexpr->on_empty->expr,
state, resv, resnull);
+ state->escontext = saved_escontext;
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
jsexpr->omit_quotes, false,
resv, resnull);
+
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur
+ * when coercing and rethrow them.
+ */
+ if (jsexpr->on_empty->coerce ||
+ IsA(jsexpr->on_empty->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_empty->expr, CoerceToDomain))
+ {
+
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
}
foreach(lc, jumps_to_end)
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d463e831ed..ce102d7665 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4284,13 +4284,12 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
memset(&jsestate->error, 0, sizeof(NullableDatum));
memset(&jsestate->empty, 0, sizeof(NullableDatum));
- /*
- * Also reset ErrorSaveContext contents for the next row. Since we don't
- * set details_wanted, we don't need to also reset error_data, which would
- * be NULL anyway.
- */
- Assert(!jsestate->escontext.details_wanted &&
- jsestate->escontext.error_data == NULL);
+ /* Also reset ErrorSaveContext contents for the next row. */
+ if (jsestate->escontext.details_wanted)
+ {
+ jsestate->escontext.error_data = NULL;
+ jsestate->escontext.details_wanted = false;
+ }
jsestate->escontext.error_occurred = false;
switch (jsexpr->op)
@@ -4394,6 +4393,15 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
error = true;
}
+ /*
+ * When setting up the ErrorSaveContext (if needed) for capturing the
+ * errors that occur when coercing the JsonBehavior expression, set
+ * details_wanted to be able to show the actual error message as the
+ * DETAIL of the error message that tells that it is the
+ * JsonBehavior expression that caused the error; see
+ * ExecEvalJsonCoercionFinish().
+ */
+
/* Handle ON EMPTY. */
if (empty)
{
@@ -4404,6 +4412,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->empty.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON EMPTY value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(jsestate->jump_empty >= 0);
return jsestate->jump_empty;
}
@@ -4411,6 +4422,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
else if (jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(!throw_error && jsestate->jump_error >= 0);
return jsestate->jump_error;
}
@@ -4436,6 +4450,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*op->resvalue = (Datum) 0;
*op->resnull = true;
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
return jsestate->jump_error;
}
@@ -4574,9 +4591,33 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
(Node *) escontext);
}
+static char *
+GetJsonBehaviorValueString(JsonBehavior *behavior)
+{
+ /*
+ * The order of array elements must correspond to the order of
+ * JsonBehaviorType members.
+ */
+ const char *behavior_names[] =
+ {
+ "NULL",
+ "ERROR",
+ "EMPTY",
+ "TRUE",
+ "FALSE",
+ "UNKNOWN",
+ "EMPTY ARRAY",
+ "EMPTY OBJECT",
+ "DEFAULT"
+ };
+
+ return pstrdup(behavior_names[behavior->btype]);
+}
+
/*
* Checks if an error occurred in ExecEvalJsonCoercion(). If so, this sets
- * JsonExprState.error to trigger the ON ERROR handling steps.
+ * JsonExprState.error to trigger the ON ERROR handling steps, unless the
+ * error is thrown when coercing a JsonBehavior value.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
@@ -4585,9 +4626,33 @@ ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
if (SOFT_ERROR_OCCURRED(&jsestate->escontext))
{
+ /*
+ * jsestate->error or jsetate->empty being set means that the error
+ * occurred when coercing the JsonBehavior value. Throw the error in
+ * that case with the actual coercion error message shown in the
+ * DETAIL part.
+ */
+ if (DatumGetBool(jsestate->error.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON ERROR expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_error)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+ else if (DatumGetBool(jsestate->empty.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON EMPTY expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_empty)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+
*op->resvalue = (Datum) 0;
*op->resnull = true;
+
jsestate->error.value = BoolGetDatum(true);
+
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
}
}
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index e634b1e3b5..2b1c2d20ac 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -227,7 +227,8 @@ SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
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"
+ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
+DETAIL: 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 EMPTY));
js1
@@ -561,30 +562,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type smallint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type bigint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type real: "false"
-- Default FALSE (ON ERROR) doesn't fit char(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value too long for type character(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
ERROR: value too long for type character(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
@@ -616,11 +605,13 @@ SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH
(1 row)
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
-ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
-ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
a | a
---+---
@@ -636,7 +627,8 @@ SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
-ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+ERROR: could not coerce ON ERROR expression (TRUE) to the RETURNING type
+DETAIL: value for domain dint4_1 violates check constraint "dint4_1_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
a | a
---+---
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index e7b64a9882..3080f5ed3e 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -313,11 +313,8 @@ SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
-- Test NULL checks execution in domain types
CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null);
- json_value
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null ERROR ON ERROR);
ERROR: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR);
@@ -881,17 +878,11 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1047,11 +1038,8 @@ SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
(1 row)
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON EMPTY expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
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
@@ -1244,7 +1232,8 @@ 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 EMPTY);
-ERROR: value for domain queryfuncs_test_domain violates check constraint "queryfuncs_test_domain_check"
+ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
+DETAIL: 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 EMPTY);
json_value
------------
@@ -1430,7 +1419,8 @@ SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010
(1 row)
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
-ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+ERROR: could not coerce ON ERROR expression (DEFAULT) to the RETURNING type
+DETAIL: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
ERROR: bit string length 3 does not match type bit(2)
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
--
2.43.0
On Thu, Jul 25, 2024 at 11:16 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Wed, Jul 24, 2024 at 3:25 PM jian he <jian.universality@gmail.com> wrote:
2. domain over jsonb should fail just like domain over other types?
RETURNING djs keep quotes DEFAULT '"11"' ON empty
should fail as
ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
DETAIL: value for domain djs violates check constraint "djs_check""I think this should be fixed with the attached patch 0004.
It is fixed but with the patch 0003, not 0004.
Also, the test cases in 0004, which is a patch to fix a problem with
OMIT QUOTES being disregarded when RETURNING domain-over-jsonb, didn't
test that problem. So I have updated the test case to use a domain
over jsonb.
--
Thanks, Amit Langote
Attachments:
0004-SQL-JSON-Respect-OMIT-QUOTES-when-RETURNING-domains-.patchapplication/octet-stream; name=0004-SQL-JSON-Respect-OMIT-QUOTES-when-RETURNING-domains-.patchDownload
From 42f3337e3f27ca8e66367af01ad485584509a82b Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 26 Jul 2024 11:01:05 +0900
Subject: [PATCH 4/5] SQL/JSON: Respect OMIT QUOTES when RETURNING domains over
jsonb
populate_domain() didn't take into account the omit_quotes flag passed
down to json_populate_type() by ExecEvalJsonCoercion(). Fix that.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/utils/adt/jsonfuncs.c | 11 ++++++-----
src/test/regress/expected/sqljson_queryfuncs.out | 15 +++++++++++++++
src/test/regress/sql/sqljson_queryfuncs.sql | 5 +++++
3 files changed, 26 insertions(+), 5 deletions(-)
diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c
index 48c3f88140..1b681eff5f 100644
--- a/src/backend/utils/adt/jsonfuncs.c
+++ b/src/backend/utils/adt/jsonfuncs.c
@@ -453,7 +453,7 @@ static void prepare_column_cache(ColumnIOData *column, Oid typid, int32 typmod,
static Datum populate_record_field(ColumnIOData *col, Oid typid, int32 typmod,
const char *colname, MemoryContext mcxt, Datum defaultval,
JsValue *jsv, bool *isnull, Node *escontext,
- bool omit_quotes);
+ bool omit_scalar_quotes);
static RecordIOData *allocate_record_info(MemoryContext mcxt, int ncolumns);
static bool JsObjectGetField(JsObject *obj, char *field, JsValue *jsv);
static void populate_recordset_record(PopulateRecordsetState *state, JsObject *obj);
@@ -470,7 +470,7 @@ static Datum populate_array(ArrayIOData *aio, const char *colname,
Node *escontext);
static Datum populate_domain(DomainIOData *io, Oid typid, const char *colname,
MemoryContext mcxt, JsValue *jsv, bool *isnull,
- Node *escontext);
+ Node *escontext, bool omit_quotes);
/* functions supporting jsonb_delete, jsonb_set and jsonb_concat */
static JsonbValue *IteratorConcat(JsonbIterator **it1, JsonbIterator **it2,
@@ -3218,7 +3218,8 @@ populate_domain(DomainIOData *io,
MemoryContext mcxt,
JsValue *jsv,
bool *isnull,
- Node *escontext)
+ Node *escontext,
+ bool omit_quotes)
{
Datum res;
@@ -3229,7 +3230,7 @@ populate_domain(DomainIOData *io,
res = populate_record_field(io->base_io,
io->base_typid, io->base_typmod,
colname, mcxt, PointerGetDatum(NULL),
- jsv, isnull, escontext, false);
+ jsv, isnull, escontext, omit_quotes);
Assert(!*isnull || SOFT_ERROR_OCCURRED(escontext));
}
@@ -3461,7 +3462,7 @@ populate_record_field(ColumnIOData *col,
case TYPECAT_DOMAIN:
return populate_domain(&col->io.domain, typid, colname, mcxt,
- jsv, isnull, escontext);
+ jsv, isnull, escontext, omit_scalar_quotes);
default:
elog(ERROR, "unrecognized type category '%c'", typcat);
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 3080f5ed3e..848189ace2 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -738,6 +738,21 @@ SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quot
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error);
ERROR: malformed range literal: ""[1,2]""
DETAIL: Missing left parenthesis or bracket.
+CREATE DOMAIN qf_char_domain AS char(1);
+CREATE DOMAIN qf_jsonb_domain AS jsonb;
+SELECT JSON_QUERY(jsonb '"1"', '$' RETURNING qf_char_domain OMIT QUOTES ERROR ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+SELECT JSON_QUERY(jsonb '"1"', '$' RETURNING qf_jsonb_domain OMIT QUOTES ERROR ON ERROR);
+ json_query
+------------
+ 1
+(1 row)
+
+DROP DOMAIN qf_char_domain, qf_jsonb_domain;
SELECT JSON_QUERY(jsonb '[]', '$[*]');
json_query
------------
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index 0dd55f9453..3f5984808e 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -214,6 +214,11 @@ SELECT JSON_QUERY(jsonb'{"rec": "{1,2,3}"}', '$.rec' returning int[] keep quotes
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range omit quotes);
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes);
SELECT JSON_QUERY(jsonb'{"rec": "[1,2]"}', '$.rec' returning int4range keep quotes error on error);
+CREATE DOMAIN qf_char_domain AS char(1);
+CREATE DOMAIN qf_jsonb_domain AS jsonb;
+SELECT JSON_QUERY(jsonb '"1"', '$' RETURNING qf_char_domain OMIT QUOTES ERROR ON ERROR);
+SELECT JSON_QUERY(jsonb '"1"', '$' RETURNING qf_jsonb_domain OMIT QUOTES ERROR ON ERROR);
+DROP DOMAIN qf_char_domain, qf_jsonb_domain;
SELECT JSON_QUERY(jsonb '[]', '$[*]');
SELECT JSON_QUERY(jsonb '[]', '$[*]' NULL ON EMPTY);
--
2.43.0
0005-SQL-JSON-Remove-useless-code-in-ExecInitJsonExpr.patchapplication/octet-stream; name=0005-SQL-JSON-Remove-useless-code-in-ExecInitJsonExpr.patchDownload
From 399274f1186da19d84164f48971a0fb7da20ae12 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 23:02:11 +0900
Subject: [PATCH 5/5] SQL/JSON: Remove useless code in ExecInitJsonExpr
The code was for adding an JUMP to the next step, which is
unnecessary.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 15 ---------------
1 file changed, 15 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 23d907451d..b614f7a4af 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4312,21 +4312,6 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.constval.isnull = true;
ExprEvalPushStep(state, scratch);
- /*
- * Jump to coerce the NULL using json_populate_type() if needed. Coercing
- * NULL is only interesting when the RETURNING type is a domain whose
- * constraints must be checked. jsexpr->use_json_coercion must have been
- * set in that case.
- */
- if (get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN &&
- DomainHasConstraints(jsexpr->returning->typid))
- {
- Assert(jsexpr->use_json_coercion);
- scratch->opcode = EEOP_JUMP;
- scratch->d.jump.jumpdone = state->steps_len + 1;
- ExprEvalPushStep(state, scratch);
- }
-
/*
* To handle coercion errors softly, use the following ErrorSaveContext to
* pass to ExecInitExprRec() when initializing the coercion expressions
--
2.43.0
0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchapplication/octet-stream; name=0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchDownload
From 5a73a9bb1db237ea8146e02d3e46bda83292b915 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 22:36:23 +0900
Subject: [PATCH 1/5] SQL/JSON: Some fixes to JsonBehavior expression casting
1. Remove the special case handling when casting the JsonBehavior
expressions to types with typmod, like 86d33987 did for the casting
of SQL/JSON constructor functions.
2. Fix casting for fixed-length character and bit string types by
using assignment-level casts. This is again similar to what
86d33987 did, but for ON ERROR / EMPTY expressions.
3. Use runtime coercion for the boolean ON ERROR constants so that
the coercion works correctly for EXISTS columns that use fixed-
length character string types. For example, so that the default
"false" doesn't emit an "value too long for type character(2)"
error even when no ON ERROR clause is specified.
4. Simplify the conditions of when to use runtime coercion vs
creating the cast expression in the parser itself. jsonb-valued
expressions are now always coerced at runtime and boolean
expressions too if the target type is a string type for the
reasons mentioned above.
Tests are from a patch that Jian He posted.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/parser/parse_expr.c | 100 ++++++++++++------
.../regress/expected/sqljson_jsontable.out | 41 +++++--
.../regress/expected/sqljson_queryfuncs.out | 70 +++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 15 ++-
5 files changed, 179 insertions(+), 52 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f27806..26737572c4 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4685,51 +4685,91 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
if (expr == NULL && btype != JSON_BEHAVIOR_ERROR)
expr = GetJsonBehaviorConst(btype, location);
- if (expr)
+ /*
+ * Try to coerce the expression if needed.
+ *
+ * Use runtime coercion using json_populate_type() if the expression is
+ * NULL, jsonb-valued, or boolean-valued (unless the target type is integer
+ * or domain over integer, in which case use the boolean-to-integer cast
+ * function).
+ *
+ * For other non-NULL expressions, try to find a cast and error out if one
+ * is not found.
+ */
+ if (expr && exprType(expr) != returning->typid)
{
- Node *coerced_expr = expr;
bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull);
- /*
- * Coerce NULLs and "internal" (that is, not specified by the user)
- * jsonb-valued expressions at runtime using json_populate_type().
- *
- * For other (user-specified) non-NULL values, try to find a cast and
- * error out if one is not found.
- */
if (isnull ||
- (exprType(expr) == JSONBOID &&
- btype == default_behavior))
+ exprType(expr) == JSONBOID ||
+ (exprType(expr) == BOOLOID &&
+ getBaseType(returning->typid) != INT4OID))
+ {
coerce_at_runtime = true;
+
+ /*
+ * json_populate_type() expects to be passed a jsonb value, so gin
+ * up a Const containing the appropriate boolean value represented
+ * as jsonb, discarding the original Const containing a plain
+ * boolean.
+ */
+ if (exprType(expr) == BOOLOID)
+ {
+ char *val = btype == JSON_BEHAVIOR_TRUE ? "true" : "false";
+
+ expr = (Node *) makeConst(JSONBOID, -1, InvalidOid, -1,
+ DirectFunctionCall1(jsonb_in,
+ CStringGetDatum(val)),
+ false, false);
+ }
+ }
else
{
- int32 baseTypmod = returning->typmod;
+ Node *coerced_expr;
+ char typcategory = TypeCategory(returning->typid);
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
+ /*
+ * Use an assignment cast if coercing to a string type so that
+ * build_coercion_expression() assumes implicit coercion when
+ * coercing the typmod, so that inputs exceeding length cause an
+ * error instead of silent truncation.
+ */
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
+ returning->typid, returning->typmod,
+ (typcategory == TYPCATEGORY_STRING ||
+ typcategory == TYPCATEGORY_BITSTRING) ?
+ COERCION_ASSIGNMENT :
COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
- }
- if (coerced_expr == NULL)
- ereport(ERROR,
- errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast behavior expression of type %s to %s",
- format_type_be(exprType(expr)),
- format_type_be(returning->typid)),
- parser_errposition(pstate, exprLocation(expr)));
- else
+ if (coerced_expr == NULL)
+ {
+ /*
+ * Provide a HINT if the expression comes from a DEFAULT
+ * clause.
+ */
+ if (btype == JSON_BEHAVIOR_DEFAULT)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ errhint("You will need to explicitly cast the expression to type %s.",
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ }
+
expr = coerced_expr;
+ }
}
if (behavior)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 5fd43be367..82aa6e9a3e 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -555,21 +555,50 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to smallint
+ a
+---
+
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to bigint
+ a
+---
+
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to real
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ a
+---
+
+(1 row)
+
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+ a
+---
+
+(1 row)
+
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
a
-------
false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to json
+ a
+-------
+ false
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to jsonb
+ a
+-------
+ false
+(1 row)
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index 074aedb2dd..e7b64a9882 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -665,7 +665,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-ERROR: value too long for type character(2)
+ json_query
+------------
+ bb
+(1 row)
+
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -853,13 +857,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
(1 row)
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
json_query
------------
@@ -873,13 +881,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ json_query
+------------
+
+(1 row)
+
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1369,7 +1381,7 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY ], EMPTY OBJECT, or DEFAULT expression is allowed in ON ERROR for JSON_QUERY().
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -1405,3 +1417,33 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+ERROR: cannot cast behavior expression of type integer to bit
+LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR...
+ ^
+HINT: You will need to explicitly cast the expression to type bit.
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+ERROR: bit string length 4 does not match type bit(3)
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 4594e5b013..dc509bed8a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index be5593b332..0dd55f9453 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -467,7 +467,7 @@ SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -479,3 +479,16 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
--
2.43.0
0003-SQL-JSON-Fix-handling-of-errors-coercing-JsonBehavio.patchapplication/octet-stream; name=0003-SQL-JSON-Fix-handling-of-errors-coercing-JsonBehavio.patchDownload
From 215360b921334c1810f35ad98a33eebadd874273 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 22:13:12 +0900
Subject: [PATCH 3/5] SQL/JSON: Fix handling of errors coercing JsonBehavior
expressions
Instead of returning a NULL when the JsonBehavior value cannot be
coerced to the RETURNING type, throw the error message informing the
user that it is the JsonBehavior expression that caused the error
with the actual error message show in the DETAIL.
To ensure that the errors of executing a JsonBehavior expression that
is coerced in the parser are caught instead of being thrown directly,
pass ErrorSaveContext to ExecInitExprRec() when initializing it.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 47 ++++++++++-
src/backend/executor/execExprInterp.c | 81 +++++++++++++++++--
.../regress/expected/sqljson_jsontable.out | 40 ++++-----
.../regress/expected/sqljson_queryfuncs.out | 34 +++-----
4 files changed, 146 insertions(+), 56 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index db1ec11390..23d907451d 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4402,6 +4402,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
+ ErrorSaveContext *saved_escontext;
+
jsestate->jump_error = state->steps_len;
/* JUMP to end if false, that is, skip the ON ERROR expression. */
@@ -4412,9 +4414,15 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.jump.jumpdone = -1; /* set below */
ExprEvalPushStep(state, scratch);
- /* Steps to evaluate the ON ERROR expression */
+ /*
+ * Steps to evaluate the ON ERROR expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
ExecInitExprRec((Expr *) jsexpr->on_error->expr,
state, resv, resnull);
+ state->escontext = saved_escontext;
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
@@ -4422,6 +4430,19 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsexpr->omit_quotes, false,
resv, resnull);
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur
+ * when coercing and rethrow them.
+ */
+ if (jsexpr->on_error->coerce ||
+ IsA(jsexpr->on_error->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_error->expr, CoerceToDomain))
+ {
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
+
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP;
@@ -4436,6 +4457,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_empty != NULL &&
jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
+ ErrorSaveContext *saved_escontext;
+
jsestate->jump_empty = state->steps_len;
/* JUMP to end if false, that is, skip the ON EMPTY expression. */
@@ -4446,15 +4469,35 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.jump.jumpdone = -1; /* set below */
ExprEvalPushStep(state, scratch);
- /* Steps to evaluate the ON EMPTY expression */
+ /*
+ * Steps to evaluate the ON EMPTY expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
ExecInitExprRec((Expr *) jsexpr->on_empty->expr,
state, resv, resnull);
+ state->escontext = saved_escontext;
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
jsexpr->omit_quotes, false,
resv, resnull);
+
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur
+ * when coercing and rethrow them.
+ */
+ if (jsexpr->on_empty->coerce ||
+ IsA(jsexpr->on_empty->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_empty->expr, CoerceToDomain))
+ {
+
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
}
foreach(lc, jumps_to_end)
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d463e831ed..ce102d7665 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4284,13 +4284,12 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
memset(&jsestate->error, 0, sizeof(NullableDatum));
memset(&jsestate->empty, 0, sizeof(NullableDatum));
- /*
- * Also reset ErrorSaveContext contents for the next row. Since we don't
- * set details_wanted, we don't need to also reset error_data, which would
- * be NULL anyway.
- */
- Assert(!jsestate->escontext.details_wanted &&
- jsestate->escontext.error_data == NULL);
+ /* Also reset ErrorSaveContext contents for the next row. */
+ if (jsestate->escontext.details_wanted)
+ {
+ jsestate->escontext.error_data = NULL;
+ jsestate->escontext.details_wanted = false;
+ }
jsestate->escontext.error_occurred = false;
switch (jsexpr->op)
@@ -4394,6 +4393,15 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
error = true;
}
+ /*
+ * When setting up the ErrorSaveContext (if needed) for capturing the
+ * errors that occur when coercing the JsonBehavior expression, set
+ * details_wanted to be able to show the actual error message as the
+ * DETAIL of the error message that tells that it is the
+ * JsonBehavior expression that caused the error; see
+ * ExecEvalJsonCoercionFinish().
+ */
+
/* Handle ON EMPTY. */
if (empty)
{
@@ -4404,6 +4412,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->empty.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON EMPTY value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(jsestate->jump_empty >= 0);
return jsestate->jump_empty;
}
@@ -4411,6 +4422,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
else if (jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
Assert(!throw_error && jsestate->jump_error >= 0);
return jsestate->jump_error;
}
@@ -4436,6 +4450,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*op->resvalue = (Datum) 0;
*op->resnull = true;
jsestate->error.value = BoolGetDatum(true);
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
return jsestate->jump_error;
}
@@ -4574,9 +4591,33 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
(Node *) escontext);
}
+static char *
+GetJsonBehaviorValueString(JsonBehavior *behavior)
+{
+ /*
+ * The order of array elements must correspond to the order of
+ * JsonBehaviorType members.
+ */
+ const char *behavior_names[] =
+ {
+ "NULL",
+ "ERROR",
+ "EMPTY",
+ "TRUE",
+ "FALSE",
+ "UNKNOWN",
+ "EMPTY ARRAY",
+ "EMPTY OBJECT",
+ "DEFAULT"
+ };
+
+ return pstrdup(behavior_names[behavior->btype]);
+}
+
/*
* Checks if an error occurred in ExecEvalJsonCoercion(). If so, this sets
- * JsonExprState.error to trigger the ON ERROR handling steps.
+ * JsonExprState.error to trigger the ON ERROR handling steps, unless the
+ * error is thrown when coercing a JsonBehavior value.
*/
void
ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
@@ -4585,9 +4626,33 @@ ExecEvalJsonCoercionFinish(ExprState *state, ExprEvalStep *op)
if (SOFT_ERROR_OCCURRED(&jsestate->escontext))
{
+ /*
+ * jsestate->error or jsetate->empty being set means that the error
+ * occurred when coercing the JsonBehavior value. Throw the error in
+ * that case with the actual coercion error message shown in the
+ * DETAIL part.
+ */
+ if (DatumGetBool(jsestate->error.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON ERROR expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_error)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+ else if (DatumGetBool(jsestate->empty.value))
+ ereport(ERROR,
+ (errcode(ERRCODE_DATATYPE_MISMATCH),
+ errmsg("could not coerce ON EMPTY expression (%s) to the RETURNING type",
+ GetJsonBehaviorValueString(jsestate->jsexpr->on_empty)),
+ errdetail("%s", jsestate->escontext.error_data->message)));
+
*op->resvalue = (Datum) 0;
*op->resnull = true;
+
jsestate->error.value = BoolGetDatum(true);
+
+ /* Set up to catch coercion errors of the ON ERROR value. */
+ jsestate->escontext.error_occurred = false;
+ jsestate->escontext.details_wanted = true;
}
}
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index e634b1e3b5..2b1c2d20ac 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -227,7 +227,8 @@ SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
SELECT * FROM JSON_TABLE(jsonb '{"d1": "H"}', '$'
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"
+ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
+DETAIL: 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 EMPTY));
js1
@@ -561,30 +562,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type smallint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type bigint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type real: "false"
-- Default FALSE (ON ERROR) doesn't fit char(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
- a
----
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value too long for type character(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
ERROR: value too long for type character(3)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
@@ -616,11 +605,13 @@ SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH
(1 row)
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
-ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
-ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
a | a
---+---
@@ -636,7 +627,8 @@ SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
-ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+ERROR: could not coerce ON ERROR expression (TRUE) to the RETURNING type
+DETAIL: value for domain dint4_1 violates check constraint "dint4_1_check"
SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
a | a
---+---
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index e7b64a9882..3080f5ed3e 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -313,11 +313,8 @@ SELECT JSON_VALUE(jsonb '"2017-02-20"', '$' RETURNING date) + 9;
-- Test NULL checks execution in domain types
CREATE DOMAIN sqljsonb_int_not_null AS int NOT NULL;
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null);
- json_value
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null ERROR ON ERROR);
ERROR: domain sqljsonb_int_not_null does not allow null values
SELECT JSON_VALUE(jsonb 'null', '$' RETURNING sqljsonb_int_not_null DEFAULT 2 ON EMPTY ERROR ON ERROR);
@@ -881,17 +878,11 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1047,11 +1038,8 @@ SELECT JSON_QUERY(jsonb '{"a": 1}', '$.a' RETURNING sqljsonb_int_not_null);
(1 row)
SELECT JSON_QUERY(jsonb '{"a": 1}', '$.b' RETURNING sqljsonb_int_not_null);
- json_query
-------------
-
-(1 row)
-
+ERROR: could not coerce ON EMPTY expression (NULL) to the RETURNING type
+DETAIL: domain sqljsonb_int_not_null does not allow null values
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
@@ -1244,7 +1232,8 @@ 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 EMPTY);
-ERROR: value for domain queryfuncs_test_domain violates check constraint "queryfuncs_test_domain_check"
+ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
+DETAIL: 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 EMPTY);
json_value
------------
@@ -1430,7 +1419,8 @@ SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010
(1 row)
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
-ERROR: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+ERROR: could not coerce ON ERROR expression (DEFAULT) to the RETURNING type
+DETAIL: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
ERROR: bit string length 3 does not match type bit(2)
SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
--
2.43.0
0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchapplication/octet-stream; name=0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchDownload
From dae8cf6c2abf7e120a72c711201950e62c324dbc Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 25 Jul 2024 14:51:29 +0900
Subject: [PATCH 2/5] SQL/JSON: Fix casting for integer EXISTS columns in
JSON_TABLE
The current method of coercing the boolean result value of
JsonPathExists() to the target type specified for an EXISTS column,
which is to call the type's input function via json_populate_type(),
leads to an error when the target type is integer, because the
integer input function doesn't recognize boolean literal values as
valid.
Instead use the boolean-to-integer cast function for coercion in that
case so that using integer or domains thereof as type for EXISTS
columns works. Note that coercion for ON ERROR values TRUE and FALSE
already works like that because the parser creates a cast expression
including the cast function, but the coercion of the actual result
value is not handled by the parser.
Tests by Jian He.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 21 +++++---
src/backend/executor/execExprInterp.c | 46 ++++++++++++++---
src/include/executor/execExpr.h | 5 +-
.../regress/expected/sqljson_jsontable.out | 49 ++++++++++++++++++-
src/test/regress/sql/sqljson_jsontable.sql | 18 ++++++-
5 files changed, 121 insertions(+), 18 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index ccd4863778..db1ec11390 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -93,7 +93,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
- Datum *resv, bool *resnull);
+ bool exists_coerce, Datum *resv, bool *resnull);
/*
@@ -4344,7 +4344,9 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsestate->jump_eval_coercion = state->steps_len;
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes,
+ jsexpr->op == JSON_EXISTS_OP,
+ resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4417,7 +4419,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
/* JUMP to end to skip the ON EMPTY steps added below. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
@@ -4450,7 +4453,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
}
foreach(lc, jumps_to_end)
@@ -4470,7 +4474,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
- Datum *resv, bool *resnull)
+ bool exists_coerce, Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4480,8 +4484,13 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.resnull = resnull;
scratch.d.jsonexpr_coercion.targettype = returning->typid;
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
- scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
+ scratch.d.jsonexpr_coercion.json_coercion_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
+ scratch.d.jsonexpr_coercion.exists_coerce = exists_coerce;
+ scratch.d.jsonexpr_coercion.exists_cast_to_int = exists_coerce &&
+ getBaseType(returning->typid) == INT4OID;
+ scratch.d.jsonexpr_coercion.check_domain = exists_coerce &&
+ DomainHasConstraints(returning->typid);
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index d8735286c4..d463e831ed 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4304,13 +4304,7 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
*op->resnull = false;
- if (jsexpr->use_json_coercion)
- *op->resvalue = DirectFunctionCall1(jsonb_in,
- BoolGetDatum(exists) ?
- CStringGetDatum("true") :
- CStringGetDatum("false"));
- else
- *op->resvalue = BoolGetDatum(exists);
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4534,10 +4528,46 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
{
ErrorSaveContext *escontext = op->d.jsonexpr_coercion.escontext;
+ /*
+ * Prepare to call json_populate_type() to coerce the boolean result of
+ * JSON_EXISTS_OP to the target type. If the the target type is integer
+ * or a domain over integer, call the boolean-to-integer cast function
+ * instead, because the integer's input function (which is what
+ * json_populate_type() calls to coerce to scalar target types) doesn't
+ * accept boolean literals as valid input. We only have a special case
+ * for integer and domains thereof as it seems common to use those types
+ * for EXISTS columns in JSON_TABLE().
+ */
+ if (op->d.jsonexpr_coercion.exists_coerce)
+ {
+ if (op->d.jsonexpr_coercion.exists_cast_to_int)
+ {
+ /* Check domain constraints if any. */
+ if (op->d.jsonexpr_coercion.check_domain &&
+ !domain_check_safe(*op->resvalue, *op->resnull,
+ op->d.jsonexpr_coercion.targettype,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
+ econtext->ecxt_per_query_memory,
+ (Node *) escontext))
+ {
+ *op->resnull = true;
+ *op->resvalue = (Datum) 0;
+ }
+ else
+ *op->resvalue = DirectFunctionCall1(bool_int4, *op->resvalue);
+ return;
+ }
+
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ DatumGetBool(*op->resvalue) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ }
+
*op->resvalue = json_populate_type(*op->resvalue, JSONBOID,
op->d.jsonexpr_coercion.targettype,
op->d.jsonexpr_coercion.targettypmod,
- &op->d.jsonexpr_coercion.json_populate_type_cache,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
econtext->ecxt_per_query_memory,
op->resnull,
op->d.jsonexpr_coercion.omit_quotes,
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 55337d4916..b6e031f108 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -708,7 +708,10 @@ typedef struct ExprEvalStep
Oid targettype;
int32 targettypmod;
bool omit_quotes;
- void *json_populate_type_cache;
+ bool exists_coerce;
+ bool exists_cast_to_int;
+ bool check_domain;
+ void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
} d;
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 82aa6e9a3e..e634b1e3b5 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -548,12 +548,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
(1 row)
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
a
---
0
(1 row)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+ a
+---
+ 1
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
a
---
@@ -599,6 +605,45 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
false
(1 row)
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+ a | a
+---+---
+ 1 | t
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+DROP DOMAIN dint4, dint4_0, dint4_1;
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index dc509bed8a..d7cfe3d39a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -262,7 +262,8 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAU
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
@@ -273,6 +274,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' E
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+DROP DOMAIN dint4, dint4_0, dint4_1;
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' OMIT QUOTES ON SCALAR STRING));
--
2.43.0
On Fri, Jul 26, 2024 at 11:12 AM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Jul 25, 2024 at 11:16 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Wed, Jul 24, 2024 at 3:25 PM jian he <jian.universality@gmail.com> wrote:
2. domain over jsonb should fail just like domain over other types?
RETURNING djs keep quotes DEFAULT '"11"' ON empty
should fail as
ERROR: could not coerce ON EMPTY expression (DEFAULT) to the RETURNING type
DETAIL: value for domain djs violates check constraint "djs_check""I think this should be fixed with the attached patch 0004.
It is fixed but with the patch 0003, not 0004.
Also, the test cases in 0004, which is a patch to fix a problem with
OMIT QUOTES being disregarded when RETURNING domain-over-jsonb, didn't
test that problem. So I have updated the test case to use a domain
over jsonb.
Pushed 0003-0005 ahead of 0001-0002. Will try to push them over the
weekend. Rebased for now.
--
Thanks, Amit Langote
Attachments:
0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchapplication/octet-stream; name=0001-SQL-JSON-Some-fixes-to-JsonBehavior-expression-casti.patchDownload
From 82f80c5294c9f68fdab74a29334e308eddb25ea9 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 26 Jul 2024 16:56:41 +0900
Subject: [PATCH 1/2] SQL/JSON: Some fixes to JsonBehavior expression casting
1. Remove the special case handling when casting the JsonBehavior
expressions to types with typmod, like 86d33987 did for the casting
of SQL/JSON constructor functions.
2. Fix casting for fixed-length character and bit string types by
using assignment-level casts. This is again similar to what
86d33987 did, but for ON ERROR / EMPTY expressions.
3. Use runtime coercion for the boolean ON ERROR constants so that
using fixed-length character string types, for example, for an
EXISTS column doesn't cause a "value too long for type
character(n)" when the parser tries to coerce the default ON ERROR
value "false" to that type, that is, even when clause is not
specified.
4. Simplify the conditions of when to use runtime coercion vs
creating the cast expression in the parser itself. jsonb-valued
expressions are now always coerced at runtime and boolean
expressions too if the target type is a string type for the
reasons mentioned above.
Tests are from a patch that Jian He posted.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
Backpatch-through: 17
---
src/backend/parser/parse_expr.c | 100 ++++++++++++------
.../regress/expected/sqljson_jsontable.out | 29 +++--
.../regress/expected/sqljson_queryfuncs.out | 65 +++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 +-
src/test/regress/sql/sqljson_queryfuncs.sql | 15 ++-
5 files changed, 162 insertions(+), 52 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 8577f27806..26737572c4 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4685,51 +4685,91 @@ transformJsonBehavior(ParseState *pstate, JsonBehavior *behavior,
if (expr == NULL && btype != JSON_BEHAVIOR_ERROR)
expr = GetJsonBehaviorConst(btype, location);
- if (expr)
+ /*
+ * Try to coerce the expression if needed.
+ *
+ * Use runtime coercion using json_populate_type() if the expression is
+ * NULL, jsonb-valued, or boolean-valued (unless the target type is integer
+ * or domain over integer, in which case use the boolean-to-integer cast
+ * function).
+ *
+ * For other non-NULL expressions, try to find a cast and error out if one
+ * is not found.
+ */
+ if (expr && exprType(expr) != returning->typid)
{
- Node *coerced_expr = expr;
bool isnull = (IsA(expr, Const) && ((Const *) expr)->constisnull);
- /*
- * Coerce NULLs and "internal" (that is, not specified by the user)
- * jsonb-valued expressions at runtime using json_populate_type().
- *
- * For other (user-specified) non-NULL values, try to find a cast and
- * error out if one is not found.
- */
if (isnull ||
- (exprType(expr) == JSONBOID &&
- btype == default_behavior))
+ exprType(expr) == JSONBOID ||
+ (exprType(expr) == BOOLOID &&
+ getBaseType(returning->typid) != INT4OID))
+ {
coerce_at_runtime = true;
+
+ /*
+ * json_populate_type() expects to be passed a jsonb value, so gin
+ * up a Const containing the appropriate boolean value represented
+ * as jsonb, discarding the original Const containing a plain
+ * boolean.
+ */
+ if (exprType(expr) == BOOLOID)
+ {
+ char *val = btype == JSON_BEHAVIOR_TRUE ? "true" : "false";
+
+ expr = (Node *) makeConst(JSONBOID, -1, InvalidOid, -1,
+ DirectFunctionCall1(jsonb_in,
+ CStringGetDatum(val)),
+ false, false);
+ }
+ }
else
{
- int32 baseTypmod = returning->typmod;
+ Node *coerced_expr;
+ char typcategory = TypeCategory(returning->typid);
- if (get_typtype(returning->typid) == TYPTYPE_DOMAIN)
- (void) getBaseTypeAndTypmod(returning->typid, &baseTypmod);
-
- if (baseTypmod > 0)
- expr = coerce_to_specific_type(pstate, expr, TEXTOID,
- "JSON_FUNCTION()");
+ /*
+ * Use an assignment cast if coercing to a string type so that
+ * build_coercion_expression() assumes implicit coercion when
+ * coercing the typmod, so that inputs exceeding length cause an
+ * error instead of silent truncation.
+ */
coerced_expr =
coerce_to_target_type(pstate, expr, exprType(expr),
- returning->typid, baseTypmod,
- baseTypmod > 0 ? COERCION_IMPLICIT :
+ returning->typid, returning->typmod,
+ (typcategory == TYPCATEGORY_STRING ||
+ typcategory == TYPCATEGORY_BITSTRING) ?
+ COERCION_ASSIGNMENT :
COERCION_EXPLICIT,
- baseTypmod > 0 ? COERCE_IMPLICIT_CAST :
COERCE_EXPLICIT_CAST,
exprLocation((Node *) behavior));
- }
- if (coerced_expr == NULL)
- ereport(ERROR,
- errcode(ERRCODE_CANNOT_COERCE),
- errmsg("cannot cast behavior expression of type %s to %s",
- format_type_be(exprType(expr)),
- format_type_be(returning->typid)),
- parser_errposition(pstate, exprLocation(expr)));
- else
+ if (coerced_expr == NULL)
+ {
+ /*
+ * Provide a HINT if the expression comes from a DEFAULT
+ * clause.
+ */
+ if (btype == JSON_BEHAVIOR_DEFAULT)
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ errhint("You will need to explicitly cast the expression to type %s.",
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ else
+ ereport(ERROR,
+ errcode(ERRCODE_CANNOT_COERCE),
+ errmsg("cannot cast behavior expression of type %s to %s",
+ format_type_be(exprType(expr)),
+ format_type_be(returning->typid)),
+ parser_errposition(pstate, exprLocation(expr)));
+ }
+
expr = coerced_expr;
+ }
}
if (behavior)
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index fcad9cc028..24892d5e18 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -556,21 +556,38 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to smallint
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type smallint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to bigint
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type bigint: "false"
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to real
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: invalid input syntax for type real: "false"
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value too long for type character(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
a
-------
false
(1 row)
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to json
+ a
+-------
+ false
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
-ERROR: cannot cast behavior expression of type boolean to jsonb
+ a
+-------
+ false
+(1 row)
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out
index bdadf4b788..848189ace2 100644
--- a/src/test/regress/expected/sqljson_queryfuncs.out
+++ b/src/test/regress/expected/sqljson_queryfuncs.out
@@ -662,7 +662,11 @@ SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT 'bb
(1 row)
SELECT JSON_QUERY(jsonb '"aaa"', '$.a' RETURNING char(2) OMIT QUOTES DEFAULT '"bb"'::jsonb ON EMPTY);
-ERROR: value too long for type character(2)
+ json_query
+------------
+ bb
+(1 row)
+
-- OMIT QUOTES behavior should not be specified when WITH WRAPPER used:
-- Should fail
SELECT JSON_QUERY(jsonb '[1]', '$' WITH WRAPPER OMIT QUOTES);
@@ -865,13 +869,17 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$' RETURNING bytea FORMAT JSON);
(1 row)
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ... JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bytea
-LINE 1: ...jsonb '[1,2]', '$[*]' RETURNING bytea FORMAT JSON EMPTY OBJE...
- ^
+ json_query
+------------
+ \x7b7d
+(1 row)
+
SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING json EMPTY OBJECT ON ERROR);
json_query
------------
@@ -885,13 +893,11 @@ SELECT JSON_QUERY(jsonb '[1,2]', '$[*]' RETURNING jsonb EMPTY OBJECT ON ERROR);
(1 row)
SELECT JSON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ...ON_QUERY(jsonb '[3,4]', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
SELECT JSON_QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJECT ON ERROR);
-ERROR: cannot cast behavior expression of type jsonb to bigint[]
-LINE 1: ..._QUERY(jsonb '"[3,4]"', '$[*]' RETURNING bigint[] EMPTY OBJE...
- ^
+ERROR: could not coerce ON ERROR expression (EMPTY OBJECT) to the RETURNING type
+DETAIL: expected JSON array
-- Coercion fails with quotes on
SELECT JSON_QUERY(jsonb '"123.1"', '$' RETURNING int2 error on error);
ERROR: invalid input syntax for type smallint: ""123.1""
@@ -1379,7 +1385,7 @@ ERROR: invalid ON ERROR behavior
LINE 1: SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
^
DETAIL: Only ERROR, NULL, EMPTY [ ARRAY ], EMPTY OBJECT, or DEFAULT expression is allowed in ON ERROR for JSON_QUERY().
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -1415,3 +1421,34 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON E
(1 row)
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+ERROR: bit string too long for type bit varying(3)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+ json_value
+------------
+ 010
+(1 row)
+
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+ERROR: could not coerce ON ERROR expression (DEFAULT) to the RETURNING type
+DETAIL: value for domain queryfuncs_d_varbit3 violates check constraint "queryfuncs_d_varbit3_check"
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+ERROR: bit string length 3 does not match type bit(2)
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+ERROR: cannot cast behavior expression of type integer to bit
+LINE 1: ...VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR...
+ ^
+HINT: You will need to explicitly cast the expression to type bit.
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+ json_value
+------------
+ 001
+(1 row)
+
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+ERROR: bit string length 4 does not match type bit(3)
+DROP DOMAIN queryfuncs_d_varbit3;
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 4594e5b013..dc509bed8a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -266,7 +266,10 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a'));
+-- Default FALSE (ON ERROR) doesn't fit char(3)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(3) EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' ERROR ON ERROR));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql
index e9005d3d4e..3f5984808e 100644
--- a/src/test/regress/sql/sqljson_queryfuncs.sql
+++ b/src/test/regress/sql/sqljson_queryfuncs.sql
@@ -472,7 +472,7 @@ SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);
SELECT JSON_VALUE(jsonb '1', '$' EMPTY ON ERROR);
SELECT JSON_QUERY(jsonb '1', '$' TRUE ON ERROR);
--- Test implicit coercion domain over fixed-legth type specified in RETURNING
+-- Test implicit coercion domain over fixed-length type specified in RETURNING
CREATE DOMAIN queryfuncs_char2 AS char(2);
CREATE DOMAIN queryfuncs_char2_chk AS char(2) CHECK (VALUE NOT IN ('12'));
SELECT JSON_QUERY(jsonb '123', '$' RETURNING queryfuncs_char2 ERROR ON ERROR);
@@ -484,3 +484,16 @@ SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2 DEFAULT 1 ON ERROR
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk ERROR ON ERROR);
SELECT JSON_VALUE(jsonb '123', '$' RETURNING queryfuncs_char2_chk DEFAULT 1 ON ERROR);
DROP DOMAIN queryfuncs_char2, queryfuncs_char2_chk;
+
+-- Test coercion to domain over another fixed-length type of the ON ERROR /
+-- EMPTY expressions. Ask user to cast the DEFAULT expression explicitly if
+-- automatic casting cannot be done, for example, from int to bit(2).
+CREATE DOMAIN queryfuncs_d_varbit3 AS varbit(3) CHECK (VALUE <> '01');
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '111111' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '010' ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING queryfuncs_d_varbit3 DEFAULT '01' ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$' RETURNING bit(2) ERROR ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1 ON ERROR);
+SELECT JSON_VALUE(jsonb '1234', '$' RETURNING bit(3) DEFAULT 1::bit(3) ON ERROR);
+SELECT JSON_VALUE(jsonb '"111"', '$.a' RETURNING bit(3) DEFAULT '1111' ON EMPTY);
+DROP DOMAIN queryfuncs_d_varbit3;
--
2.43.0
0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchapplication/octet-stream; name=0002-SQL-JSON-Fix-casting-for-integer-EXISTS-columns-in-J.patchDownload
From 2fe1a76413af60b60e9506210eedfb59f9b55544 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 26 Jul 2024 16:56:21 +0900
Subject: [PATCH 2/2] SQL/JSON: Fix casting for integer EXISTS columns in
JSON_TABLE
The current method of coercing the boolean result value of
JsonPathExists() to the target type specified for an EXISTS column,
which is to call the type's input function via json_populate_type(),
leads to an error when the target type is integer, because the
integer input function doesn't recognize boolean literal values as
valid.
Instead use the boolean-to-integer cast function for coercion in that
case so that using integer or domains thereof as type for EXISTS
columns works. Note that coercion for ON ERROR values TRUE and FALSE
already works like that because the parser creates a cast expression
including the cast function, but the coercion of the actual result
value is not handled by the parser.
Tests by Jian He.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
Backpatch-through: 17
---
src/backend/executor/execExpr.c | 19 +++++--
src/backend/executor/execExprInterp.c | 46 +++++++++++++---
src/include/executor/execExpr.h | 5 +-
.../regress/expected/sqljson_jsontable.out | 52 ++++++++++++++++++-
src/test/regress/sql/sqljson_jsontable.sql | 18 ++++++-
5 files changed, 124 insertions(+), 16 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index f1caf48036..3c4e503b8c 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -93,6 +93,7 @@ static void ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalStep *scratch);
static void ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
+ bool exists_coerce,
Datum *resv, bool *resnull);
@@ -4329,7 +4330,9 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsestate->jump_eval_coercion = state->steps_len;
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes,
+ jsexpr->op == JSON_EXISTS_OP,
+ resv, resnull);
}
else if (jsexpr->use_io_coercion)
{
@@ -4410,7 +4413,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON ERROR expression if needed */
if (jsexpr->on_error->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
/*
* Add a COERCION_FINISH step to check for errors that may occur when
@@ -4466,7 +4470,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/* Step to coerce the ON EMPTY expression if needed */
if (jsexpr->on_empty->coerce)
ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, resv, resnull);
+ jsexpr->omit_quotes, false,
+ resv, resnull);
/*
* Add a COERCION_FINISH step to check for errors that may occur when
@@ -4502,6 +4507,7 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
static void
ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
ErrorSaveContext *escontext, bool omit_quotes,
+ bool exists_coerce,
Datum *resv, bool *resnull)
{
ExprEvalStep scratch = {0};
@@ -4512,8 +4518,13 @@ ExecInitJsonCoercion(ExprState *state, JsonReturning *returning,
scratch.resnull = resnull;
scratch.d.jsonexpr_coercion.targettype = returning->typid;
scratch.d.jsonexpr_coercion.targettypmod = returning->typmod;
- scratch.d.jsonexpr_coercion.json_populate_type_cache = NULL;
+ scratch.d.jsonexpr_coercion.json_coercion_cache = NULL;
scratch.d.jsonexpr_coercion.escontext = escontext;
scratch.d.jsonexpr_coercion.omit_quotes = omit_quotes;
+ scratch.d.jsonexpr_coercion.exists_coerce = exists_coerce;
+ scratch.d.jsonexpr_coercion.exists_cast_to_int = exists_coerce &&
+ getBaseType(returning->typid) == INT4OID;
+ scratch.d.jsonexpr_coercion.check_domain = exists_coerce &&
+ DomainHasConstraints(returning->typid);
ExprEvalPushStep(state, &scratch);
}
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index 430438f668..452215c0c3 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4303,13 +4303,7 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
if (!error)
{
*op->resnull = false;
- if (jsexpr->use_json_coercion)
- *op->resvalue = DirectFunctionCall1(jsonb_in,
- BoolGetDatum(exists) ?
- CStringGetDatum("true") :
- CStringGetDatum("false"));
- else
- *op->resvalue = BoolGetDatum(exists);
+ *op->resvalue = BoolGetDatum(exists);
}
}
break;
@@ -4550,10 +4544,46 @@ ExecEvalJsonCoercion(ExprState *state, ExprEvalStep *op,
{
ErrorSaveContext *escontext = op->d.jsonexpr_coercion.escontext;
+ /*
+ * Prepare to call json_populate_type() to coerce the boolean result of
+ * JSON_EXISTS_OP to the target type. If the the target type is integer
+ * or a domain over integer, call the boolean-to-integer cast function
+ * instead, because the integer's input function (which is what
+ * json_populate_type() calls to coerce to scalar target types) doesn't
+ * accept boolean literals as valid input. We only have a special case
+ * for integer and domains thereof as it seems common to use those types
+ * for EXISTS columns in JSON_TABLE().
+ */
+ if (op->d.jsonexpr_coercion.exists_coerce)
+ {
+ if (op->d.jsonexpr_coercion.exists_cast_to_int)
+ {
+ /* Check domain constraints if any. */
+ if (op->d.jsonexpr_coercion.check_domain &&
+ !domain_check_safe(*op->resvalue, *op->resnull,
+ op->d.jsonexpr_coercion.targettype,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
+ econtext->ecxt_per_query_memory,
+ (Node *) escontext))
+ {
+ *op->resnull = true;
+ *op->resvalue = (Datum) 0;
+ }
+ else
+ *op->resvalue = DirectFunctionCall1(bool_int4, *op->resvalue);
+ return;
+ }
+
+ *op->resvalue = DirectFunctionCall1(jsonb_in,
+ DatumGetBool(*op->resvalue) ?
+ CStringGetDatum("true") :
+ CStringGetDatum("false"));
+ }
+
*op->resvalue = json_populate_type(*op->resvalue, JSONBOID,
op->d.jsonexpr_coercion.targettype,
op->d.jsonexpr_coercion.targettypmod,
- &op->d.jsonexpr_coercion.json_populate_type_cache,
+ &op->d.jsonexpr_coercion.json_coercion_cache,
econtext->ecxt_per_query_memory,
op->resnull,
op->d.jsonexpr_coercion.omit_quotes,
diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h
index 55337d4916..b6e031f108 100644
--- a/src/include/executor/execExpr.h
+++ b/src/include/executor/execExpr.h
@@ -708,7 +708,10 @@ typedef struct ExprEvalStep
Oid targettype;
int32 targettypmod;
bool omit_quotes;
- void *json_populate_type_cache;
+ bool exists_coerce;
+ bool exists_cast_to_int;
+ bool check_domain;
+ void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
} d;
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 24892d5e18..2b1c2d20ac 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -175,7 +175,7 @@ FROM json_table_test vals
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 6 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 7 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 8 | f | 0 | | false
- [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 0 | | true
+ [1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 9 | t | 1 | 1 | true
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 10 | f | 0 | | false
[1, 1.23, "2", "aaaaaaa", "foo", null, false, true, {"aaa": 123}, "[1,2]", "\"str\""] | 11 | f | 0 | | false
(14 rows)
@@ -549,12 +549,18 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT
(1 row)
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
a
---
0
(1 row)
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
+ a
+---
+ 1
+(1 row)
+
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
DETAIL: invalid input syntax for type smallint: "false"
@@ -588,6 +594,48 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
false
(1 row)
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+ERROR: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+ERROR: could not coerce ON ERROR expression (FALSE) to the RETURNING type
+DETAIL: value for domain dint4_0 violates check constraint "dint4_0_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+ a | a
+---+---
+ 1 | t
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+ERROR: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+ERROR: could not coerce ON ERROR expression (TRUE) to the RETURNING type
+DETAIL: value for domain dint4_1 violates check constraint "dint4_1_check"
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+ a | a
+---+---
+ 0 | f
+(1 row)
+
+DROP DOMAIN dint4, dint4_0, dint4_1;
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
item
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index dc509bed8a..d7cfe3d39a 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -262,7 +262,8 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'strict $.a' DEFAU
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int PATH 'lax $.a' DEFAULT 1 ON EMPTY DEFAULT 2 ON ERROR)) jt;
-- JSON_TABLE: EXISTS PATH types
-SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a'));
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$.a' ERROR ON ERROR)); -- ok; can cast to int4
+SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int4 EXISTS PATH '$' ERROR ON ERROR)); -- ok; can cast to int4
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int2 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a int8 EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a float4 EXISTS PATH '$.a'));
@@ -273,6 +274,21 @@ SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a char(5) EXISTS PATH '$.a' E
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a json EXISTS PATH '$.a'));
SELECT * FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a jsonb EXISTS PATH '$.a'));
+-- EXISTS PATH domain over int
+CREATE DOMAIN dint4 AS int;
+CREATE DOMAIN dint4_0 AS int CHECK (VALUE <> 0 );
+CREATE DOMAIN dint4_1 AS int CHECK (VALUE <> 1 );
+SELECT a, a::bool FROM JSON_TABLE(jsonb '"a"', '$' COLUMNS (a dint4 EXISTS PATH '$.a' ));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' FALSE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_0 EXISTS PATH '$.b' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a'));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' ERROR ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' TRUE ON ERROR));
+SELECT a, a::bool FROM JSON_TABLE(jsonb '{"a":1}', '$' COLUMNS (a dint4_1 EXISTS PATH '$.a' FALSE ON ERROR));
+DROP DOMAIN dint4, dint4_0, dint4_1;
+
-- JSON_TABLE: WRAPPER/QUOTES clauses on scalar columns
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' KEEP QUOTES ON SCALAR STRING));
SELECT * FROM JSON_TABLE(jsonb '"world"', '$' COLUMNS (item text PATH '$' OMIT QUOTES ON SCALAR STRING));
--
2.43.0
On Fri, Jul 26, 2024 at 4:53 PM Amit Langote <amitlangote09@gmail.com> wrote:
Pushed 0003-0005 ahead of 0001-0002. Will try to push them over the
weekend. Rebased for now.
{
...
/*
* For expression nodes that support soft errors. Should be set to NULL
* before calling ExecInitExprRec() if the caller wants errors thrown.
*/
ErrorSaveContext *escontext;
} ExprState;
i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.
Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?
struct
{
Oid targettype;
int32 targettypmod;
bool omit_quotes;
bool exists_coerce;
bool exists_cast_to_int;
bool check_domain;
void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
do we need to comment that "check_domain" is only used for JSON_EXISTS_OP?
While reviewing it, I found another minor issue.
json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;
EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?
case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;
also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");
for json_value, json_query, i believe we can save some circles in
ExecInitJsonExpr
if you don't specify on error, on empty
can you please check the attached, based on your latest attachment.
Attachments:
v2-0001-save-some-circle-in-ExecInitJsonExpr.patchapplication/x-patch; name=v2-0001-save-some-circle-in-ExecInitJsonExpr.patchDownload
From 618b48991d5239eb924070b0357c5208a9d1ca5c Mon Sep 17 00:00:00 2001
From: jian he <jian.universality@gmail.com>
Date: Fri, 26 Jul 2024 21:15:41 +0800
Subject: [PATCH v2 1/1] save some circle in ExecInitJsonExpr
if returning type is not domain and on_error->btype is JSON_BEHAVIOR_NULL
or
if returning type is not domain and on_empty->btype is JSON_BEHAVIOR_NULL
---
src/backend/executor/execExpr.c | 139 +++++++++++++++++---------------
1 file changed, 75 insertions(+), 64 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 3c4e503b..48324e98 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4237,6 +4237,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ?
&jsestate->escontext : NULL;
+ bool returning_is_domain =
+ get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN;
jsestate->jsexpr = jsexpr;
/*
@@ -4388,8 +4390,6 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
{
- ErrorSaveContext *saved_escontext;
-
jsestate->jump_error = state->steps_len;
/* JUMP to end if false, that is, skip the ON ERROR expression. */
@@ -4400,42 +4400,46 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.jump.jumpdone = -1; /* set below */
ExprEvalPushStep(state, scratch);
- /*
- * Steps to evaluate the ON ERROR expression; handle errors softly to
- * rethrow them in COERCION_FINISH step that will be added later.
- */
- saved_escontext = state->escontext;
- state->escontext = escontext;
- ExecInitExprRec((Expr *) jsexpr->on_error->expr,
- state, resv, resnull);
- state->escontext = saved_escontext;
-
- /* Step to coerce the ON ERROR expression if needed */
- if (jsexpr->on_error->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, false,
- resv, resnull);
-
- /*
- * Add a COERCION_FINISH step to check for errors that may occur when
- * coercing and rethrow them.
- */
- if (jsexpr->on_error->coerce ||
- IsA(jsexpr->on_error->expr, CoerceViaIO) ||
- IsA(jsexpr->on_error->expr, CoerceToDomain))
+ if (returning_is_domain || jsexpr->on_error->btype != JSON_BEHAVIOR_NULL)
{
- scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
- scratch->resvalue = resv;
- scratch->resnull = resnull;
- scratch->d.jsonexpr.jsestate = jsestate;
+ ErrorSaveContext *saved_escontext;
+ /*
+ * Steps to evaluate the ON ERROR expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
+ ExecInitExprRec((Expr *) jsexpr->on_error->expr,
+ state, resv, resnull);
+ state->escontext = saved_escontext;
+
+ /* Step to coerce the ON ERROR expression if needed */
+ if (jsexpr->on_error->coerce)
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, false,
+ resv, resnull);
+
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur when
+ * coercing and rethrow them.
+ */
+ if (jsexpr->on_error->coerce ||
+ IsA(jsexpr->on_error->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_error->expr, CoerceToDomain))
+ {
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->resvalue = resv;
+ scratch->resnull = resnull;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
+
+ /* JUMP to end to skip the ON EMPTY steps added below. */
+ jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
+ scratch->opcode = EEOP_JUMP;
+ scratch->d.jump.jumpdone = -1;
ExprEvalPushStep(state, scratch);
}
-
- /* JUMP to end to skip the ON EMPTY steps added below. */
- jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
- scratch->opcode = EEOP_JUMP;
- scratch->d.jump.jumpdone = -1;
- ExprEvalPushStep(state, scratch);
}
/*
@@ -4445,8 +4449,6 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
if (jsexpr->on_empty != NULL &&
jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
{
- ErrorSaveContext *saved_escontext;
-
jsestate->jump_empty = state->steps_len;
/* JUMP to end if false, that is, skip the ON EMPTY expression. */
@@ -4458,35 +4460,44 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalPushStep(state, scratch);
/*
- * Steps to evaluate the ON EMPTY expression; handle errors softly to
- * rethrow them in COERCION_FINISH step that will be added later.
- */
- saved_escontext = state->escontext;
- state->escontext = escontext;
- ExecInitExprRec((Expr *) jsexpr->on_empty->expr,
- state, resv, resnull);
- state->escontext = saved_escontext;
-
- /* Step to coerce the ON EMPTY expression if needed */
- if (jsexpr->on_empty->coerce)
- ExecInitJsonCoercion(state, jsexpr->returning, escontext,
- jsexpr->omit_quotes, false,
- resv, resnull);
-
- /*
- * Add a COERCION_FINISH step to check for errors that may occur when
- * coercing and rethrow them.
- */
- if (jsexpr->on_empty->coerce ||
- IsA(jsexpr->on_empty->expr, CoerceViaIO) ||
- IsA(jsexpr->on_empty->expr, CoerceToDomain))
+ * only json_query, json_value can set on_empty if on_empty is default
+ * JSON_BEHAVIOR_NULL, the above EEOP_JUMP_IF_NOT_TRUE action is enough.
+ * but domain can have not null, so we still need coercion steps.
+ */
+ if (returning_is_domain || jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL)
{
+ ErrorSaveContext *saved_escontext;
+ /*
+ * Steps to evaluate the ON EMPTY expression; handle errors softly to
+ * rethrow them in COERCION_FINISH step that will be added later.
+ */
+ saved_escontext = state->escontext;
+ state->escontext = escontext;
+ ExecInitExprRec((Expr *) jsexpr->on_empty->expr,
+ state, resv, resnull);
+ state->escontext = saved_escontext;
- scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
- scratch->resvalue = resv;
- scratch->resnull = resnull;
- scratch->d.jsonexpr.jsestate = jsestate;
- ExprEvalPushStep(state, scratch);
+ /* Step to coerce the ON EMPTY expression if needed */
+ if (jsexpr->on_empty->coerce)
+ ExecInitJsonCoercion(state, jsexpr->returning, escontext,
+ jsexpr->omit_quotes, false,
+ resv, resnull);
+
+ /*
+ * Add a COERCION_FINISH step to check for errors that may occur when
+ * coercing and rethrow them.
+ */
+ if (jsexpr->on_empty->coerce ||
+ IsA(jsexpr->on_empty->expr, CoerceViaIO) ||
+ IsA(jsexpr->on_empty->expr, CoerceToDomain))
+ {
+
+ scratch->opcode = EEOP_JSONEXPR_COERCION_FINISH;
+ scratch->resvalue = resv;
+ scratch->resnull = resnull;
+ scratch->d.jsonexpr.jsestate = jsestate;
+ ExprEvalPushStep(state, scratch);
+ }
}
}
--
2.34.1
Hi,
On Fri, Jul 26, 2024 at 11:19 PM jian he <jian.universality@gmail.com> wrote:
On Fri, Jul 26, 2024 at 4:53 PM Amit Langote <amitlangote09@gmail.com> wrote:
Pushed 0003-0005 ahead of 0001-0002. Will try to push them over the
weekend. Rebased for now.
Pushed them now.
{
...
/*
* For expression nodes that support soft errors. Should be set to NULL
* before calling ExecInitExprRec() if the caller wants errors thrown.
*/
ErrorSaveContext *escontext;
} ExprState;i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?
OK, I'll look into updating this.
struct
{
Oid targettype;
int32 targettypmod;
bool omit_quotes;
bool exists_coerce;
bool exists_cast_to_int;
bool check_domain;
void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
do we need to comment that "check_domain" is only used for JSON_EXISTS_OP?
I've renamed it to exists_check_domain and added a comment that
exists_* fields are relevant only for JSON_EXISTS_OP.
json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");
Something like the attached makes sense? While this meaningfully
changes the deparsing output, there is no behavior change for
JsonTable top-level path execution. That's because the behavior when
there's an error in the execution of the top-level path is to throw it
or return an empty set, which is handled in jsonpath_exec.c, not
execExprInterp.c.
for json_value, json_query, i believe we can save some circles in
ExecInitJsonExpr
if you don't specify on error, on emptycan you please check the attached, based on your latest attachment.
Perhaps makes sense, though I haven't checked closely. I'll take a
look next week.
--
Thanks, Amit Langote
On Tue, Jul 30, 2024 at 12:59 PM Amit Langote <amitlangote09@gmail.com> wrote:
Hi,
On Fri, Jul 26, 2024 at 11:19 PM jian he <jian.universality@gmail.com> wrote:
On Fri, Jul 26, 2024 at 4:53 PM Amit Langote <amitlangote09@gmail.com> wrote:
Pushed 0003-0005 ahead of 0001-0002. Will try to push them over the
weekend. Rebased for now.Pushed them now.
{
...
/*
* For expression nodes that support soft errors. Should be set to NULL
* before calling ExecInitExprRec() if the caller wants errors thrown.
*/
ErrorSaveContext *escontext;
} ExprState;i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?OK, I'll look into updating this.
struct
{
Oid targettype;
int32 targettypmod;
bool omit_quotes;
bool exists_coerce;
bool exists_cast_to_int;
bool check_domain;
void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
do we need to comment that "check_domain" is only used for JSON_EXISTS_OP?I've renamed it to exists_check_domain and added a comment that
exists_* fields are relevant only for JSON_EXISTS_OP.json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");Something like the attached makes sense? While this meaningfully
changes the deparsing output, there is no behavior change for
JsonTable top-level path execution. That's because the behavior when
there's an error in the execution of the top-level path is to throw it
or return an empty set, which is handled in jsonpath_exec.c, not
execExprInterp.c.
hi amit.
seems you forgot to attach the patch?
On Thu, Aug 22, 2024 at 11:02 jian he <jian.universality@gmail.com> wrote:
On Tue, Jul 30, 2024 at 12:59 PM Amit Langote <amitlangote09@gmail.com>
wrote:Hi,
On Fri, Jul 26, 2024 at 11:19 PM jian he <jian.universality@gmail.com>
wrote:
On Fri, Jul 26, 2024 at 4:53 PM Amit Langote <amitlangote09@gmail.com>
wrote:
Pushed 0003-0005 ahead of 0001-0002. Will try to push them over the
weekend. Rebased for now.Pushed them now.
{
...
/*
* For expression nodes that support soft errors. Should be setto NULL
* before calling ExecInitExprRec() if the caller wants errors
thrown.
*/
ErrorSaveContext *escontext;
} ExprState;i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?OK, I'll look into updating this.
struct
{
Oid targettype;
int32 targettypmod;
bool omit_quotes;
bool exists_coerce;
bool exists_cast_to_int;
bool check_domain;
void *json_coercion_cache;
ErrorSaveContext *escontext;
} jsonexpr_coercion;
do we need to comment that "check_domain" is only used forJSON_EXISTS_OP?
I've renamed it to exists_check_domain and added a comment that
exists_* fields are relevant only for JSON_EXISTS_OP.json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");Something like the attached makes sense? While this meaningfully
changes the deparsing output, there is no behavior change for
JsonTable top-level path execution. That's because the behavior when
there's an error in the execution of the top-level path is to throw it
or return an empty set, which is handled in jsonpath_exec.c, not
execExprInterp.c.hi amit.
seems you forgot to attach the patch?
Yeah, I had planned to look at this after my vacation earlier this month,
but I context switched into working on another project and lost track of
this. I’ll make some time next week to fix whatever remains go be fixed
here. Thanks for the reminder.
Show quoted text
On Thu, Aug 22, 2024 at 12:44 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Aug 22, 2024 at 11:02 jian he <jian.universality@gmail.com> wrote:
On Tue, Jul 30, 2024 at 12:59 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Fri, Jul 26, 2024 at 11:19 PM jian he <jian.universality@gmail.com> wrote:
{
...
/*
* For expression nodes that support soft errors. Should be set to NULL
* before calling ExecInitExprRec() if the caller wants errors thrown.
*/
ErrorSaveContext *escontext;
} ExprState;i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?OK, I'll look into updating this.
See 0001.
json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");Something like the attached makes sense? While this meaningfully
changes the deparsing output, there is no behavior change for
JsonTable top-level path execution. That's because the behavior when
there's an error in the execution of the top-level path is to throw it
or return an empty set, which is handled in jsonpath_exec.c, not
execExprInterp.c.
See 0002.
I'm also attaching 0003 to fix a minor annoyance that JSON_TABLE()
columns' default ON ERROR, ON EMPTY behaviors are unnecessarily
emitted in the deparsed output when the top-level ON ERROR behavior is
ERROR.
Will push these on Monday.
I haven't had a chance to take a closer look at your patch to optimize
the code in ExecInitJsonExpr() yet.
--
Thanks, Amit Langote
Attachments:
v1-0002-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchapplication/octet-stream; name=v1-0002-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchDownload
From 5b891dac2b2781296ab9971a17f8ec0c586ebb1e Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:19:50 +0900
Subject: [PATCH v1 2/3] SQL/JSON: Fix default ON ERROR behavior for JSON_TABLE
Use EMPTY ARRAY instead of EMPTY.
This change does not affect the runtime behavior of JSON_TABLE(),
which continues to return an empty relation ON ERROR. It only alters
whether the default ON ERROR behavior is shown in the deparsed output.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/parser/parse_expr.c | 4 +--
src/backend/utils/adt/ruleutils.c | 2 +-
.../regress/expected/sqljson_jsontable.out | 33 +++++++++++++++++++
src/test/regress/sql/sqljson_jsontable.sql | 6 ++++
4 files changed, 42 insertions(+), 3 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 56e413da9f..36c1b7a88f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4603,13 +4603,13 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
}
/*
- * Assume EMPTY ON ERROR when ON ERROR is not specified.
+ * Assume EMPTY ARRAY 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,
+ JSON_BEHAVIOR_EMPTY_ARRAY,
jsexpr->returning);
break;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b31be31321..0aa090be20 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11875,7 +11875,7 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
get_json_table_columns(tf, castNode(JsonTablePathScan, tf->plan), context,
showimplicit);
- if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+ if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY_ARRAY)
get_json_behavior(jexpr->on_error, context, "ERROR");
if (PRETTY_INDENT(context))
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 721e01d6ad..f25d03bc77 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1132,3 +1132,36 @@ ERROR: invalid ON ERROR behavior for column "a"
LINE 1: ...M JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty obje...
^
DETAIL: Only ERROR, TRUE, FALSE, or UNKNOWN is allowed in ON ERROR for EXISTS columns.
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR)
+(3 rows)
+
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 38992316f5..932a3ecf59 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -542,3 +542,9 @@ SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int) NULL ON ERROR);
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int true on empty));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int omit quotes true on error));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty object on error));
+
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
--
2.43.0
v1-0001-Update-comment-about-ExprState.escontext.patchapplication/octet-stream; name=v1-0001-Update-comment-about-ExprState.escontext.patchDownload
From 6bf0d618fd2fb6e5d4f042bcf0aadc182f5c9485 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:10:09 +0900
Subject: [PATCH v1 1/3] Update comment about ExprState.escontext
The updated comment provides more helpful guidance by mentioning that
escontext should be set when soft error handling is needed.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/include/nodes/execnodes.h | 6 ++++--
1 file changed, 4 insertions(+), 2 deletions(-)
diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h
index af7d8fd1e7..e4a4dcb029 100644
--- a/src/include/nodes/execnodes.h
+++ b/src/include/nodes/execnodes.h
@@ -132,8 +132,10 @@ typedef struct ExprState
bool *innermost_domainnull;
/*
- * For expression nodes that support soft errors. Should be set to NULL
- * before calling ExecInitExprRec() if the caller wants errors thrown.
+ * For expression nodes that support soft errors. Should be set to NULL if
+ * the caller wants errors to be thrown. Callers that do not want errors
+ * thrown should set it to a valid ErrorSaveContext before calling
+ * ExecInitExprRec().
*/
ErrorSaveContext *escontext;
} ExprState;
--
2.43.0
v1-0003-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchapplication/octet-stream; name=v1-0003-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchDownload
From 26204e454877601a7fe4993dcc6e7790126ad7d2 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:55:04 +0900
Subject: [PATCH v1 3/3] SQL/JSON: Fix JSON_TABLE() column deparsing
The deparsing code in get_json_expr_options() unnecessarily emitted
the default column-specific ON ERROR / EMPTY behavior when the
top-level ON ERROR behavior in JSON_TABLE was set to ERROR. Fix that
by not overriding the column-specific default, determined based on
the column's JsonExprOp in get_json_table_columns(), with
JSON_BEHAVIOR_ERROR when that is the top-level ON ERROR behavior.
Note that this only removes redundancy; the current deparsing output
is not incorrect, just redundant.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/utils/adt/ruleutils.c | 8 +++----
.../regress/expected/sqljson_jsontable.out | 24 ++++++++++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 ++++
3 files changed, 30 insertions(+), 7 deletions(-)
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0aa090be20..cd9c3eddd1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11719,7 +11719,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
bool showimplicit)
{
StringInfo buf = context->buf;
- JsonExpr *jexpr = castNode(JsonExpr, tf->docexpr);
ListCell *lc_colname;
ListCell *lc_coltype;
ListCell *lc_coltypmod;
@@ -11772,6 +11771,10 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
if (ordinality)
continue;
+ /*
+ * Set default_behavior to guide get_json_expr_options() on whether to
+ * to emit the ON ERROR / EMPTY clauses.
+ */
if (colexpr->op == JSON_EXISTS_OP)
{
appendStringInfoString(buf, " EXISTS");
@@ -11795,9 +11798,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
default_behavior = JSON_BEHAVIOR_NULL;
}
- if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
- default_behavior = JSON_BEHAVIOR_ERROR;
-
appendStringInfoString(buf, " PATH ");
get_json_path_spec(colexpr->path_spec, context, showimplicit);
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index f25d03bc77..1a24e478eb 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1158,10 +1158,28 @@ EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EM
(3 rows)
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
- Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR)
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
+(3 rows)
+
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 932a3ecf59..6d2b5be027 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -548,3 +548,8 @@ EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
--
2.43.0
On Fri, Aug 30, 2024 at 4:32 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Aug 22, 2024 at 12:44 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Aug 22, 2024 at 11:02 jian he <jian.universality@gmail.com> wrote:
On Tue, Jul 30, 2024 at 12:59 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Fri, Jul 26, 2024 at 11:19 PM jian he <jian.universality@gmail.com> wrote:
{
...
/*
* For expression nodes that support soft errors. Should be set to NULL
* before calling ExecInitExprRec() if the caller wants errors thrown.
*/
ErrorSaveContext *escontext;
} ExprState;i believe by default makeNode will set escontext to NULL.
So the comment should be, if you want to catch the soft errors, make
sure the escontext pointing to an allocated ErrorSaveContext.
or maybe just say, default is NULL.Otherwise, the original comment's meaning feels like: we need to
explicitly set it to NULL
for certain operations, which I believe is false?OK, I'll look into updating this.
See 0001.
json_behavior_type:
ERROR_P { $$ = JSON_BEHAVIOR_ERROR; }
| NULL_P { $$ = JSON_BEHAVIOR_NULL; }
| TRUE_P { $$ = JSON_BEHAVIOR_TRUE; }
| FALSE_P { $$ = JSON_BEHAVIOR_FALSE; }
| UNKNOWN { $$ = JSON_BEHAVIOR_UNKNOWN; }
| EMPTY_P ARRAY { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
| EMPTY_P OBJECT_P { $$ = JSON_BEHAVIOR_EMPTY_OBJECT; }
/* non-standard, for Oracle compatibility only */
| EMPTY_P { $$ = JSON_BEHAVIOR_EMPTY_ARRAY; }
;EMPTY_P behaves the same as EMPTY_P ARRAY
so for function GetJsonBehaviorConst, the following "case
JSON_BEHAVIOR_EMPTY:" is wrong?case JSON_BEHAVIOR_NULL:
case JSON_BEHAVIOR_UNKNOWN:
case JSON_BEHAVIOR_EMPTY:
val = (Datum) 0;
isnull = true;
typid = INT4OID;
len = sizeof(int32);
isbyval = true;
break;also src/backend/utils/adt/ruleutils.c
if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
get_json_behavior(jexpr->on_error, context, "ERROR");Something like the attached makes sense? While this meaningfully
changes the deparsing output, there is no behavior change for
JsonTable top-level path execution. That's because the behavior when
there's an error in the execution of the top-level path is to throw it
or return an empty set, which is handled in jsonpath_exec.c, not
execExprInterp.c.See 0002.
I'm also attaching 0003 to fix a minor annoyance that JSON_TABLE()
columns' default ON ERROR, ON EMPTY behaviors are unnecessarily
emitted in the deparsed output when the top-level ON ERROR behavior is
ERROR.Will push these on Monday.
Didn't as there's a release freeze in effect for the v17 branch. Will
push to both master and v17 once the freeze is over.
I haven't had a chance to take a closer look at your patch to optimize
the code in ExecInitJsonExpr() yet.
I've simplified your patch a bit and attached it as 0004.
--
Thanks, Amit Langote
Attachments:
v2-0002-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchapplication/octet-stream; name=v2-0002-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchDownload
From 5b891dac2b2781296ab9971a17f8ec0c586ebb1e Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:19:50 +0900
Subject: [PATCH v2 2/4] SQL/JSON: Fix default ON ERROR behavior for JSON_TABLE
Use EMPTY ARRAY instead of EMPTY.
This change does not affect the runtime behavior of JSON_TABLE(),
which continues to return an empty relation ON ERROR. It only alters
whether the default ON ERROR behavior is shown in the deparsed output.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/parser/parse_expr.c | 4 +--
src/backend/utils/adt/ruleutils.c | 2 +-
.../regress/expected/sqljson_jsontable.out | 33 +++++++++++++++++++
src/test/regress/sql/sqljson_jsontable.sql | 6 ++++
4 files changed, 42 insertions(+), 3 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 56e413da9f..36c1b7a88f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4603,13 +4603,13 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
}
/*
- * Assume EMPTY ON ERROR when ON ERROR is not specified.
+ * Assume EMPTY ARRAY 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,
+ JSON_BEHAVIOR_EMPTY_ARRAY,
jsexpr->returning);
break;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b31be31321..0aa090be20 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11875,7 +11875,7 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
get_json_table_columns(tf, castNode(JsonTablePathScan, tf->plan), context,
showimplicit);
- if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+ if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY_ARRAY)
get_json_behavior(jexpr->on_error, context, "ERROR");
if (PRETTY_INDENT(context))
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 721e01d6ad..f25d03bc77 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1132,3 +1132,36 @@ ERROR: invalid ON ERROR behavior for column "a"
LINE 1: ...M JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty obje...
^
DETAIL: Only ERROR, TRUE, FALSE, or UNKNOWN is allowed in ON ERROR for EXISTS columns.
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR)
+(3 rows)
+
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 38992316f5..932a3ecf59 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -542,3 +542,9 @@ SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int) NULL ON ERROR);
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int true on empty));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int omit quotes true on error));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty object on error));
+
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
--
2.43.0
v2-0004-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchapplication/octet-stream; name=v2-0004-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchDownload
From bfded37e0439ab9397197c165b7bbf1618fe29dd Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Mon, 2 Sep 2024 16:48:58 +0900
Subject: [PATCH v2 4/4] SQL/JSON: Avoid initializing unnecessary ON ERROR / ON
EMPTY steps
When the ON ERROR / ON EMPTY behavior is to return NULL (the default
for JSON_VALUE() and JSON_QUERY()), returning NULL directly from
ExecEvalJsonExprPath() suffices. Therefore, there's no need to create
separate steps to check the error/empty flag or those to evaluate the
the constant NULL expression. However, these steps are necessary if
the RETURNING type is a domain, as constraints on the domain may need
to be checked.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 22 ++++++++++++++--------
1 file changed, 14 insertions(+), 8 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 63289ee35e..eb1621ae75 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4414,6 +4414,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ErrorSaveContext *escontext =
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ?
&jsestate->escontext : NULL;
+ bool returning_domain =
+ get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN;
jsestate->jsexpr = jsexpr;
@@ -4556,20 +4558,21 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalPushStep(state, scratch);
}
- jsestate->jump_empty = jsestate->jump_error = -1;
-
/*
* Step to check jsestate->error and return the ON ERROR expression if
* there is one. This handles both the errors that occur during jsonpath
* evaluation in EEOP_JSONEXPR_PATH and subsequent coercion evaluation.
+ *
+ * Only add the extra steps for a NULL-valued expression when RETURNING a
+ * domain type to check the constraints, if any.
*/
+ jsestate->jump_error = state->steps_len;
if (jsexpr->on_error &&
- jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
+ (jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))
{
ErrorSaveContext *saved_escontext;
- jsestate->jump_error = state->steps_len;
-
/* JUMP to end if false, that is, skip the ON ERROR expression. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP_IF_NOT_TRUE;
@@ -4619,14 +4622,17 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/*
* Step to check jsestate->empty and return the ON EMPTY expression if
* there is one.
+ *
+ * Only add the extra steps for a NULL-valued expression when RETURNING a
+ * domain type to check the constraints, if any.
*/
+ jsestate->jump_empty = state->steps_len;
if (jsexpr->on_empty != NULL &&
- jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR &&
+ (jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL || returning_domain))
{
ErrorSaveContext *saved_escontext;
- jsestate->jump_empty = state->steps_len;
-
/* JUMP to end if false, that is, skip the ON EMPTY expression. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP_IF_NOT_TRUE;
--
2.43.0
v2-0003-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchapplication/octet-stream; name=v2-0003-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchDownload
From 26204e454877601a7fe4993dcc6e7790126ad7d2 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:55:04 +0900
Subject: [PATCH v2 3/4] SQL/JSON: Fix JSON_TABLE() column deparsing
The deparsing code in get_json_expr_options() unnecessarily emitted
the default column-specific ON ERROR / EMPTY behavior when the
top-level ON ERROR behavior in JSON_TABLE was set to ERROR. Fix that
by not overriding the column-specific default, determined based on
the column's JsonExprOp in get_json_table_columns(), with
JSON_BEHAVIOR_ERROR when that is the top-level ON ERROR behavior.
Note that this only removes redundancy; the current deparsing output
is not incorrect, just redundant.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/utils/adt/ruleutils.c | 8 +++----
.../regress/expected/sqljson_jsontable.out | 24 ++++++++++++++++---
src/test/regress/sql/sqljson_jsontable.sql | 5 ++++
3 files changed, 30 insertions(+), 7 deletions(-)
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 0aa090be20..cd9c3eddd1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11719,7 +11719,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
bool showimplicit)
{
StringInfo buf = context->buf;
- JsonExpr *jexpr = castNode(JsonExpr, tf->docexpr);
ListCell *lc_colname;
ListCell *lc_coltype;
ListCell *lc_coltypmod;
@@ -11772,6 +11771,10 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
if (ordinality)
continue;
+ /*
+ * Set default_behavior to guide get_json_expr_options() on whether to
+ * to emit the ON ERROR / EMPTY clauses.
+ */
if (colexpr->op == JSON_EXISTS_OP)
{
appendStringInfoString(buf, " EXISTS");
@@ -11795,9 +11798,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
default_behavior = JSON_BEHAVIOR_NULL;
}
- if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
- default_behavior = JSON_BEHAVIOR_ERROR;
-
appendStringInfoString(buf, " PATH ");
get_json_path_spec(colexpr->path_spec, context, showimplicit);
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index f25d03bc77..1a24e478eb 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1158,10 +1158,28 @@ EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EM
(3 rows)
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
- QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------------------------------
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
- Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR)
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
+(3 rows)
+
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 932a3ecf59..6d2b5be027 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -548,3 +548,8 @@ EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
--
2.43.0
v2-0001-Update-comment-about-ExprState.escontext.patchapplication/octet-stream; name=v2-0001-Update-comment-about-ExprState.escontext.patchDownload
From 6bf0d618fd2fb6e5d4f042bcf0aadc182f5c9485 Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 30 Aug 2024 12:10:09 +0900
Subject: [PATCH v2 1/4] Update comment about ExprState.escontext
The updated comment provides more helpful guidance by mentioning that
escontext should be set when soft error handling is needed.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/include/nodes/execnodes.h | 6 ++++--
1 file changed, 4 insertions(+), 2 deletions(-)
diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h
index af7d8fd1e7..e4a4dcb029 100644
--- a/src/include/nodes/execnodes.h
+++ b/src/include/nodes/execnodes.h
@@ -132,8 +132,10 @@ typedef struct ExprState
bool *innermost_domainnull;
/*
- * For expression nodes that support soft errors. Should be set to NULL
- * before calling ExecInitExprRec() if the caller wants errors thrown.
+ * For expression nodes that support soft errors. Should be set to NULL if
+ * the caller wants errors to be thrown. Callers that do not want errors
+ * thrown should set it to a valid ErrorSaveContext before calling
+ * ExecInitExprRec().
*/
ErrorSaveContext *escontext;
} ExprState;
--
2.43.0
On Mon, Sep 2, 2024 at 4:18 PM Amit Langote <amitlangote09@gmail.com> wrote:
See 0001.
See 0002.
I'm also attaching 0003 to fix a minor annoyance that JSON_TABLE()
columns' default ON ERROR, ON EMPTY behaviors are unnecessarily
emitted in the deparsed output when the top-level ON ERROR behavior is
ERROR.Will push these on Monday.
v2-0001 looks good to me.
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
Are these tests duplicated? appears both in v2-0002 and v2-0003.
0002 output is:
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
+
QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS
json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON
ERROR) ERROR ON ERROR)
+(3 rows)
0003 output is:
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS
json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)
two patches with different output,
overall we should merge 0002 and 0003?
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))
we can be simplified as
if ( jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))
since if jsexpr->on_error is NULL, then segfault will appear at the beginning of
ExecInitJsonExpr
+ *
+ * Only add the extra steps for a NULL-valued expression when RETURNING a
+ * domain type to check the constraints, if any.
*/
+ jsestate->jump_error = state->steps_len;
if (jsexpr->on_error &&
- jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
+ (jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))
+ *
+ * Only add the extra steps for a NULL-valued expression when RETURNING a
+ * domain type to check the constraints, if any.
*/
+ jsestate->jump_empty = state->steps_len;
if (jsexpr->on_empty != NULL &&
- jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR &&
+ (jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL || returning_domain))
I am a little bit confused with the comments.
not sure the "NULL-valued expression" refers to.
i think it is:
implicitly default for ON EMPTY | ERROR clause is NULL (JSON_BEHAVIOR_NULL)
for that situation, we can skip the json coercion process,
but this only applies when the returning type of JsonExpr is not domain,
Hi,
On Tue, Sep 3, 2024 at 6:05 PM jian he <jian.universality@gmail.com> wrote:
On Mon, Sep 2, 2024 at 4:18 PM Amit Langote <amitlangote09@gmail.com> wrote: v2-0001 looks good to me. +-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY +-- behavior +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$')); +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);Are these tests duplicated? appears both in v2-0002 and v2-0003.
0002 output is: +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR); + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------ + Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32) + Output: a + Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR) +(3 rows)0003 output is:
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS
json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)two patches with different output,
overall we should merge 0002 and 0003?
Looks like I ordered the patches wrong. I'd like to commit the two separately.
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))we can be simplified as
if ( jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))since if jsexpr->on_error is NULL, then segfault will appear at the beginning of
ExecInitJsonExpr
Ok, done.
+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_error = state->steps_len; if (jsexpr->on_error && - jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_empty = state->steps_len; if (jsexpr->on_empty != NULL && - jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL || returning_domain))I am a little bit confused with the comments.
not sure the "NULL-valued expression" refers to.
It refers to on_error/on_empty->expr, which is a Const node encoding
the NULL (constisnull is true) for that behavior.
That's actually the case also for behaviors UNKNOWN and EMPTY, so the
condition should actually be checking whether the expr is a
NULL-valued expression.
I've updated the patch.
i think it is:
implicitly default for ON EMPTY | ERROR clause is NULL (JSON_BEHAVIOR_NULL)
for that situation, we can skip the json coercion process,
but this only applies when the returning type of JsonExpr is not domain,
I've reworded the comment to mention that this speeds up the default
ON ERROR / EMPTY handling for JSON_QUERY() and JSON_VALUE().
Plan to push these tomorrow.
--
Thanks, Amit Langote
Attachments:
v3-0002-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchapplication/octet-stream; name=v3-0002-SQL-JSON-Fix-JSON_TABLE-column-deparsing.patchDownload
From 4b9e1f758860ab0f85d2ebcc4dc4e35f466ae99f Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 5 Sep 2024 21:56:04 +0900
Subject: [PATCH v3 2/4] SQL/JSON: Fix JSON_TABLE() column deparsing
The deparsing code in get_json_expr_options() unnecessarily emitted
the default column-specific ON ERROR / EMPTY behavior when the
top-level ON ERROR behavior in JSON_TABLE was set to ERROR. Fix that
by not overriding the column-specific default, determined based on
the column's JsonExprOp in get_json_table_columns(), with
JSON_BEHAVIOR_ERROR when that is the top-level ON ERROR behavior.
Note that this only removes redundancy; the current deparsing output
is not incorrect, just redundant.
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/utils/adt/ruleutils.c | 8 ++++----
.../regress/expected/sqljson_jsontable.out | 18 ++++++++++++++++++
src/test/regress/sql/sqljson_jsontable.sql | 5 +++++
3 files changed, 27 insertions(+), 4 deletions(-)
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index b31be31321..371b46e7a2 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11719,7 +11719,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
bool showimplicit)
{
StringInfo buf = context->buf;
- JsonExpr *jexpr = castNode(JsonExpr, tf->docexpr);
ListCell *lc_colname;
ListCell *lc_coltype;
ListCell *lc_coltypmod;
@@ -11772,6 +11771,10 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
if (ordinality)
continue;
+ /*
+ * Set default_behavior to guide get_json_expr_options() on whether to
+ * to emit the ON ERROR / EMPTY clauses.
+ */
if (colexpr->op == JSON_EXISTS_OP)
{
appendStringInfoString(buf, " EXISTS");
@@ -11795,9 +11798,6 @@ get_json_table_columns(TableFunc *tf, JsonTablePathScan *scan,
default_behavior = JSON_BEHAVIOR_NULL;
}
- if (jexpr->on_error->btype == JSON_BEHAVIOR_ERROR)
- default_behavior = JSON_BEHAVIOR_ERROR;
-
appendStringInfoString(buf, " PATH ");
get_json_path_spec(colexpr->path_spec, context, showimplicit);
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index 721e01d6ad..ebfde38a05 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1132,3 +1132,21 @@ ERROR: invalid ON ERROR behavior for column "a"
LINE 1: ...M JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty obje...
^
DETAIL: Only ERROR, TRUE, FALSE, or UNKNOWN is allowed in ON ERROR for EXISTS columns.
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
+(3 rows)
+
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index 38992316f5..c940887892 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -542,3 +542,8 @@ SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int) NULL ON ERROR);
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int true on empty));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int omit quotes true on error));
SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty object on error));
+
+-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY
+-- behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
--
2.43.0
v3-0001-Update-comment-about-ExprState.escontext.patchapplication/octet-stream; name=v3-0001-Update-comment-about-ExprState.escontext.patchDownload
From 8c3fecf5feb694694c95311b92d42e271db1e40f Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 5 Sep 2024 21:55:46 +0900
Subject: [PATCH v3 1/4] Update comment about ExprState.escontext
The updated comment provides more helpful guidance by mentioning that
escontext should be set when soft error handling is needed.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/include/nodes/execnodes.h | 6 ++++--
1 file changed, 4 insertions(+), 2 deletions(-)
diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h
index 627f99c13d..516b948743 100644
--- a/src/include/nodes/execnodes.h
+++ b/src/include/nodes/execnodes.h
@@ -132,8 +132,10 @@ typedef struct ExprState
bool *innermost_domainnull;
/*
- * For expression nodes that support soft errors. Should be set to NULL
- * before calling ExecInitExprRec() if the caller wants errors thrown.
+ * For expression nodes that support soft errors. Should be set to NULL if
+ * the caller wants errors to be thrown. Callers that do not want errors
+ * thrown should set it to a valid ErrorSaveContext before calling
+ * ExecInitExprRec().
*/
ErrorSaveContext *escontext;
} ExprState;
--
2.43.0
v3-0004-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchapplication/octet-stream; name=v3-0004-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchDownload
From 8037429545f83d568772b16928f20e7c1044154f Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 5 Sep 2024 21:56:40 +0900
Subject: [PATCH v3 4/4] SQL/JSON: Avoid initializing unnecessary ON ERROR / ON
EMPTY steps
When the ON ERROR / ON EMPTY behavior is to return NULL (the default
for JSON_VALUE() and JSON_QUERY()), returning NULL directly from
ExecEvalJsonExprPath() suffices. Therefore, there's no need to create
separate steps to check the error/empty flag or those to evaluate the
the constant NULL expression. However, these steps are necessary if
the RETURNING type is a domain, as constraints on the domain may need
to be checked.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/executor/execExpr.c | 30 ++++++++++++++++++++++--------
1 file changed, 22 insertions(+), 8 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 63289ee35e..4d247538be 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4414,6 +4414,8 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ErrorSaveContext *escontext =
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ?
&jsestate->escontext : NULL;
+ bool returning_domain =
+ get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN;
jsestate->jsexpr = jsexpr;
@@ -4556,20 +4558,27 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
ExprEvalPushStep(state, scratch);
}
- jsestate->jump_empty = jsestate->jump_error = -1;
-
/*
* Step to check jsestate->error and return the ON ERROR expression if
* there is one. This handles both the errors that occur during jsonpath
* evaluation in EEOP_JSONEXPR_PATH and subsequent coercion evaluation.
+ *
+ * Speed up common cases by avoiding extra steps for a NULL-valued ON
+ * ERROR expression unless RETURNING a domain type, where constraints must
+ * be checked. ExecEvalJsonExprPath() already returns NULL on error,
+ * making additional steps unnecessary in typical scenarios. Note that the
+ * default ON ERROR behavior for JSON_VALUE() and JSON_QUERY() is to
+ * return NULL.
*/
+ jsestate->jump_error = state->steps_len;
if (jsexpr->on_error &&
- jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
+ (!(IsA(jsexpr->on_error->expr, Const) &&
+ ((Const *) jsexpr->on_error->expr)->constisnull) ||
+ returning_domain))
{
ErrorSaveContext *saved_escontext;
- jsestate->jump_error = state->steps_len;
-
/* JUMP to end if false, that is, skip the ON ERROR expression. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP_IF_NOT_TRUE;
@@ -4619,14 +4628,19 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/*
* Step to check jsestate->empty and return the ON EMPTY expression if
* there is one.
+ *
+ * See the comment above for details on the optimization for NULL-valued
+ * expressions.
*/
+ jsestate->jump_empty = state->steps_len;
if (jsexpr->on_empty != NULL &&
- jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR &&
+ (!(IsA(jsexpr->on_empty->expr, Const) &&
+ ((Const *) jsexpr->on_empty->expr)->constisnull) ||
+ returning_domain))
{
ErrorSaveContext *saved_escontext;
- jsestate->jump_empty = state->steps_len;
-
/* JUMP to end if false, that is, skip the ON EMPTY expression. */
jumps_to_end = lappend_int(jumps_to_end, state->steps_len);
scratch->opcode = EEOP_JUMP_IF_NOT_TRUE;
--
2.43.0
v3-0003-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchapplication/octet-stream; name=v3-0003-SQL-JSON-Fix-default-ON-ERROR-behavior-for-JSON_T.patchDownload
From 0aa916ea5af5d2fd2767a2cd13bebe1a60dc159a Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Thu, 5 Sep 2024 21:56:19 +0900
Subject: [PATCH v3 3/4] SQL/JSON: Fix default ON ERROR behavior for JSON_TABLE
Use EMPTY ARRAY instead of EMPTY.
This change does not affect the runtime behavior of JSON_TABLE(),
which continues to return an empty relation ON ERROR. It only alters
whether the default ON ERROR behavior is shown in the deparsed output.
Reported-by: Jian He <jian.universality@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
---
src/backend/parser/parse_expr.c | 4 +--
src/backend/utils/adt/ruleutils.c | 2 +-
.../regress/expected/sqljson_jsontable.out | 25 +++++++++++++++++++
src/test/regress/sql/sqljson_jsontable.sql | 5 ++++
4 files changed, 33 insertions(+), 3 deletions(-)
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 56e413da9f..36c1b7a88f 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -4603,13 +4603,13 @@ transformJsonFuncExpr(ParseState *pstate, JsonFuncExpr *func)
}
/*
- * Assume EMPTY ON ERROR when ON ERROR is not specified.
+ * Assume EMPTY ARRAY 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,
+ JSON_BEHAVIOR_EMPTY_ARRAY,
jsexpr->returning);
break;
diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c
index 371b46e7a2..cd9c3eddd1 100644
--- a/src/backend/utils/adt/ruleutils.c
+++ b/src/backend/utils/adt/ruleutils.c
@@ -11875,7 +11875,7 @@ get_json_table(TableFunc *tf, deparse_context *context, bool showimplicit)
get_json_table_columns(tf, castNode(JsonTablePathScan, tf->plan), context,
showimplicit);
- if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY)
+ if (jexpr->on_error->btype != JSON_BEHAVIOR_EMPTY_ARRAY)
get_json_behavior(jexpr->on_error, context, "ERROR");
if (PRETTY_INDENT(context))
diff --git a/src/test/regress/expected/sqljson_jsontable.out b/src/test/regress/expected/sqljson_jsontable.out
index ebfde38a05..5c7aaa6159 100644
--- a/src/test/regress/expected/sqljson_jsontable.out
+++ b/src/test/regress/expected/sqljson_jsontable.out
@@ -1150,3 +1150,28 @@ EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ER
Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
+ Output: a
+ Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$'))
+(3 rows)
+
diff --git a/src/test/regress/sql/sqljson_jsontable.sql b/src/test/regress/sql/sqljson_jsontable.sql
index c940887892..31bc9c9ea0 100644
--- a/src/test/regress/sql/sqljson_jsontable.sql
+++ b/src/test/regress/sql/sqljson_jsontable.sql
@@ -547,3 +547,8 @@ SELECT * FROM JSON_TABLE(jsonb '1', '$' COLUMNS (a int exists empty object on er
-- behavior
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);
+
+-- Test JSON_TABLE() deparsing -- don't emit default ON ERROR behavior
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$'));
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ON ERROR);
+EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') EMPTY ARRAY ON ERROR);
--
2.43.0
On Thu, Sep 5, 2024 at 9:58 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Sep 3, 2024 at 6:05 PM jian he <jian.universality@gmail.com> wrote:
On Mon, Sep 2, 2024 at 4:18 PM Amit Langote <amitlangote09@gmail.com> wrote: v2-0001 looks good to me. +-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY +-- behavior +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$')); +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);Are these tests duplicated? appears both in v2-0002 and v2-0003.
0002 output is: +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR); + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------ + Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32) + Output: a + Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR) +(3 rows)0003 output is:
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS
json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)two patches with different output,
overall we should merge 0002 and 0003?Looks like I ordered the patches wrong. I'd like to commit the two separately.
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))we can be simplified as
if ( jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))since if jsexpr->on_error is NULL, then segfault will appear at the beginning of
ExecInitJsonExprOk, done.
+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_error = state->steps_len; if (jsexpr->on_error && - jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_empty = state->steps_len; if (jsexpr->on_empty != NULL && - jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL || returning_domain))I am a little bit confused with the comments.
not sure the "NULL-valued expression" refers to.It refers to on_error/on_empty->expr, which is a Const node encoding
the NULL (constisnull is true) for that behavior.That's actually the case also for behaviors UNKNOWN and EMPTY, so the
condition should actually be checking whether the expr is a
NULL-valued expression.I've updated the patch.
i think it is:
implicitly default for ON EMPTY | ERROR clause is NULL (JSON_BEHAVIOR_NULL)
for that situation, we can skip the json coercion process,
but this only applies when the returning type of JsonExpr is not domain,I've reworded the comment to mention that this speeds up the default
ON ERROR / EMPTY handling for JSON_QUERY() and JSON_VALUE().Plan to push these tomorrow.
Pushed.
--
Thanks, Amit Langote
On Fri, Sep 6, 2024 at 12:07 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Sep 5, 2024 at 9:58 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Tue, Sep 3, 2024 at 6:05 PM jian he <jian.universality@gmail.com> wrote:
On Mon, Sep 2, 2024 at 4:18 PM Amit Langote <amitlangote09@gmail.com> wrote: v2-0001 looks good to me. +-- Test JSON_TABLE() column deparsing -- don't emit default ON ERROR / EMPTY +-- behavior +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$')); +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR);Are these tests duplicated? appears both in v2-0002 and v2-0003.
0002 output is: +EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text PATH '$') ERROR ON ERROR); + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------ + Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32) + Output: a + Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS json_table_path_0 COLUMNS (a text PATH '$' NULL ON EMPTY NULL ON ERROR) ERROR ON ERROR) +(3 rows)0003 output is:
EXPLAIN VERBOSE SELECT * from JSON_TABLE('"a"', '$' COLUMNS (a text
PATH '$') ERROR ON ERROR);
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------
Table Function Scan on "json_table" (cost=0.01..1.00 rows=100 width=32)
Output: a
Table Function Call: JSON_TABLE('"a"'::jsonb, '$' AS
json_table_path_0 COLUMNS (a text PATH '$') ERROR ON ERROR)
(3 rows)two patches with different output,
overall we should merge 0002 and 0003?Looks like I ordered the patches wrong. I'd like to commit the two separately.
if (jsexpr->on_error &&
jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))we can be simplified as
if ( jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
(jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))since if jsexpr->on_error is NULL, then segfault will appear at the beginning of
ExecInitJsonExprOk, done.
+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_error = state->steps_len; if (jsexpr->on_error && - jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_error->btype != JSON_BEHAVIOR_NULL || returning_domain))+ * + * Only add the extra steps for a NULL-valued expression when RETURNING a + * domain type to check the constraints, if any. */ + jsestate->jump_empty = state->steps_len; if (jsexpr->on_empty != NULL && - jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR) + jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR && + (jsexpr->on_empty->btype != JSON_BEHAVIOR_NULL || returning_domain))I am a little bit confused with the comments.
not sure the "NULL-valued expression" refers to.It refers to on_error/on_empty->expr, which is a Const node encoding
the NULL (constisnull is true) for that behavior.That's actually the case also for behaviors UNKNOWN and EMPTY, so the
condition should actually be checking whether the expr is a
NULL-valued expression.I've updated the patch.
i think it is:
implicitly default for ON EMPTY | ERROR clause is NULL (JSON_BEHAVIOR_NULL)
for that situation, we can skip the json coercion process,
but this only applies when the returning type of JsonExpr is not domain,I've reworded the comment to mention that this speeds up the default
ON ERROR / EMPTY handling for JSON_QUERY() and JSON_VALUE().Plan to push these tomorrow.
Pushed.
Reverted 0002-0004 from both master and REL_17_STABLE due to BF failures.
0002-0003 are easily fixed by changing the newly added tests to not
use EXPLAIN VERBOSE to test deparsing related changes, so will re-push
those shortly.
0004 perhaps doesn't play nicely with LLVM compilation but I don't yet
understand why.
--
Thanks, Amit Langote
On Fri, Sep 6, 2024 at 1:34 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Fri, Sep 6, 2024 at 12:07 PM Amit Langote <amitlangote09@gmail.com> wrote:
On Thu, Sep 5, 2024 at 9:58 PM Amit Langote <amitlangote09@gmail.com> wr
Pushed.Reverted 0002-0004 from both master and REL_17_STABLE due to BF failures.
0002-0003 are easily fixed by changing the newly added tests to not
use EXPLAIN VERBOSE to test deparsing related changes, so will re-push
those shortly.
Done.
0004 perhaps doesn't play nicely with LLVM compilation but I don't yet
understand why.
Attached is an updated patch that takes care of the issue. The bug
was that llvm_compile_expr() didn't like that jump_error, jump_empty,
and jump_end could all point to the same step. In the attached,
jump_empty / jump_error are left to be -1 if ON ERROR, ON EMPTY steps
are not added, instead of making them also point to the step address
that jump_end points to. ExecEvalJsonExprPath() are also updated to
check if jump_error or jump_empty is -1 and return jump_end if so.
--
Thanks, Amit Langote
Attachments:
v4-0001-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchapplication/octet-stream; name=v4-0001-SQL-JSON-Avoid-initializing-unnecessary-ON-ERROR-.patchDownload
From 95b412ef6cf6c7d35714e2dc1a1d234397bbf3aa Mon Sep 17 00:00:00 2001
From: Amit Langote <amitlan@postgresql.org>
Date: Fri, 6 Sep 2024 12:05:40 +0900
Subject: [PATCH v4] SQL/JSON: Avoid initializing unnecessary ON ERROR / ON
EMPTY steps
When the ON ERROR / ON EMPTY behavior is to return NULL, returning
NULL directly from ExecEvalJsonExprPath() suffices. Therefore, there's
no need to create separate steps to check the error/empty flag or
those to evaluate the the constant NULL expression. This speeds up
common cases because the default ON ERROR / ON EMPTY behavior for
JSON_QUERY() and JSON_VALUE() is to return NULL. However, these steps
are necessary if the RETURNING type is a domain, as constraints on the
domain may need to be checked.
Reported-by: Jian He <jian.universality@gmail.com>
Author: Jian He <jian.universality@gmail.com>
Author: Amit Langote <amitlangote09@gmail.com>
Discussion: https://postgr.es/m/CACJufxEo4sUjKCYtda0_qt9tazqqKPmF1cqhW9KBOUeJFqQd2g@mail.gmail.com
Backpatch-through: 17
---
src/backend/executor/execExpr.c | 32 ++++++++++++++++++++++-----
src/backend/executor/execExprInterp.c | 14 +++++++-----
2 files changed, 34 insertions(+), 12 deletions(-)
diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c
index 63289ee35e..c8077aa57b 100644
--- a/src/backend/executor/execExpr.c
+++ b/src/backend/executor/execExpr.c
@@ -4411,9 +4411,11 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
List *jumps_return_null = NIL;
List *jumps_to_end = NIL;
ListCell *lc;
- ErrorSaveContext *escontext =
- jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ?
- &jsestate->escontext : NULL;
+ ErrorSaveContext *escontext;
+ bool returning_domain =
+ get_typtype(jsexpr->returning->typid) == TYPTYPE_DOMAIN;
+
+ Assert(jsexpr->on_error != NULL);
jsestate->jsexpr = jsexpr;
@@ -4491,6 +4493,9 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
scratch->d.constval.isnull = true;
ExprEvalPushStep(state, scratch);
+ escontext = jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR ?
+ &jsestate->escontext : NULL;
+
/*
* To handle coercion errors softly, use the following ErrorSaveContext to
* pass to ExecInitExprRec() when initializing the coercion expressions
@@ -4562,9 +4567,18 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
* Step to check jsestate->error and return the ON ERROR expression if
* there is one. This handles both the errors that occur during jsonpath
* evaluation in EEOP_JSONEXPR_PATH and subsequent coercion evaluation.
+ *
+ * Speed up common cases by avoiding extra steps for a NULL-valued ON
+ * ERROR expression unless RETURNING a domain type, where constraints must
+ * be checked. ExecEvalJsonExprPath() already returns NULL on error,
+ * making additional steps unnecessary in typical scenarios. Note that the
+ * default ON ERROR behavior for JSON_VALUE() and JSON_QUERY() is to
+ * return NULL.
*/
- if (jsexpr->on_error &&
- jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
+ if (jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR &&
+ (!(IsA(jsexpr->on_error->expr, Const) &&
+ ((Const *) jsexpr->on_error->expr)->constisnull) ||
+ returning_domain))
{
ErrorSaveContext *saved_escontext;
@@ -4619,9 +4633,15 @@ ExecInitJsonExpr(JsonExpr *jsexpr, ExprState *state,
/*
* Step to check jsestate->empty and return the ON EMPTY expression if
* there is one.
+ *
+ * See the comment above for details on the optimization for NULL-valued
+ * expressions.
*/
if (jsexpr->on_empty != NULL &&
- jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR)
+ jsexpr->on_empty->btype != JSON_BEHAVIOR_ERROR &&
+ (!(IsA(jsexpr->on_empty->expr, Const) &&
+ ((Const *) jsexpr->on_empty->expr)->constisnull) ||
+ returning_domain))
{
ErrorSaveContext *saved_escontext;
diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c
index a6c47f61e0..9fd988cc99 100644
--- a/src/backend/executor/execExprInterp.c
+++ b/src/backend/executor/execExprInterp.c
@@ -4550,8 +4550,8 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
/* Set up to catch coercion errors of the ON EMPTY value. */
jsestate->escontext.error_occurred = false;
jsestate->escontext.details_wanted = true;
- Assert(jsestate->jump_empty >= 0);
- return jsestate->jump_empty;
+ /* Jump to end if the ON EMPTY behavior is to return NULL */
+ return jsestate->jump_empty >= 0 ? jsestate->jump_empty : jsestate->jump_end;
}
}
else if (jsexpr->on_error->btype != JSON_BEHAVIOR_ERROR)
@@ -4560,8 +4560,9 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
/* Set up to catch coercion errors of the ON ERROR value. */
jsestate->escontext.error_occurred = false;
jsestate->escontext.details_wanted = true;
- Assert(!throw_error && jsestate->jump_error >= 0);
- return jsestate->jump_error;
+ Assert(!throw_error);
+ /* Jump to end if the ON ERROR behavior is to return NULL */
+ return jsestate->jump_error >= 0 ? jsestate->jump_error : jsestate->jump_end;
}
if (jsexpr->column_name)
@@ -4581,14 +4582,15 @@ ExecEvalJsonExprPath(ExprState *state, ExprEvalStep *op,
*/
if (error)
{
- Assert(!throw_error && jsestate->jump_error >= 0);
+ Assert(!throw_error);
*op->resvalue = (Datum) 0;
*op->resnull = true;
jsestate->error.value = BoolGetDatum(true);
/* Set up to catch coercion errors of the ON ERROR value. */
jsestate->escontext.error_occurred = false;
jsestate->escontext.details_wanted = true;
- return jsestate->jump_error;
+ /* Jump to end if the ON ERROR behavior is to return NULL */
+ return jsestate->jump_error >= 0 ? jsestate->jump_error : jsestate->jump_end;
}
return jump_eval_coercion >= 0 ? jump_eval_coercion : jsestate->jump_end;
--
2.43.0