From a93e2a1e25a6d5410abb1446637c4d9a4f24e35d Mon Sep 17 00:00:00 2001 From: Dean Rasheed Date: Sun, 12 Jan 2025 13:35:12 +0000 Subject: [PATCH] Fix JsonExpr deparsing to quote variable names in the PASSING clause. When deparsing a JsonExpr, variable names in the PASSING clause were not quoted. However, since they are parsed as ColLabel tokens, some variable names require double quotes to ensure that they are properly interpreted. Fix by using quote_identifier() in the deparsing code. This oversight was limited to the SQL/JSON query functions JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE(). Back-patch to v17, where these functions were added. Dean Rasheed, reviewed by Tom Lane. Discussion: https://postgr.es/m/CAEZATCXTpAS%3DncfLNTZ7YS6O5puHeLg_SUYAit%2Bcs7wsrd9Msg%40mail.gmail.com --- src/backend/utils/adt/ruleutils.c | 2 +- .../regress/expected/sqljson_queryfuncs.out | 20 ++++++++++++++++--- src/test/regress/sql/sqljson_queryfuncs.sql | 5 ++++- 3 files changed, 22 insertions(+), 5 deletions(-) diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index b9358687164..2a77f715fba 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -10443,7 +10443,7 @@ get_rule_expr(Node *node, deparse_context *context, get_rule_expr((Node *) lfirst(lc2), context, showimplicit); appendStringInfo(buf, " AS %s", - ((String *) lfirst_node(String, lc1))->sval); + quote_identifier(lfirst_node(String, lc1)->sval)); } } diff --git a/src/test/regress/expected/sqljson_queryfuncs.out b/src/test/regress/expected/sqljson_queryfuncs.out index 175349f7dc1..329ef674961 100644 --- a/src/test/regress/expected/sqljson_queryfuncs.out +++ b/src/test/regress/expected/sqljson_queryfuncs.out @@ -1084,7 +1084,7 @@ CREATE TABLE test_jsonb_constraints ( CONSTRAINT test_jsonb_constraint1 CHECK (js IS JSON) CONSTRAINT test_jsonb_constraint2 - CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr)) + CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS "TXT", array[1,2,3] as arr)) CONSTRAINT test_jsonb_constraint3 CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT '12' ON EMPTY ERROR ON ERROR) > i) CONSTRAINT test_jsonb_constraint4 @@ -1101,7 +1101,7 @@ CREATE TABLE test_jsonb_constraints ( x | jsonb | | | JSON_QUERY('[1, 2]'::jsonb, '$[*]' RETURNING jsonb WITH UNCONDITIONAL WRAPPER KEEP QUOTES) Check constraints: "test_jsonb_constraint1" CHECK (js IS JSON) - "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS int, i::text AS txt, ARRAY[1, 2, 3] AS arr)) + "test_jsonb_constraint2" CHECK (JSON_EXISTS(js::jsonb, '$."a"' PASSING i + 5 AS "int", i::text AS "TXT", ARRAY[1, 2, 3] AS arr)) "test_jsonb_constraint3" CHECK (JSON_VALUE(js::jsonb, '$."a"' RETURNING integer DEFAULT 12 ON EMPTY ERROR ON ERROR) > i) "test_jsonb_constraint4" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER KEEP QUOTES EMPTY OBJECT ON ERROR) = '[10]'::jsonb) "test_jsonb_constraint5" CHECK (JSON_QUERY(js::jsonb, '$."a"' RETURNING character(5) WITHOUT WRAPPER OMIT QUOTES EMPTY ARRAY ON EMPTY) > ('a'::bpchar COLLATE "C")) @@ -1116,7 +1116,7 @@ ORDER BY 1; (JSON_QUERY((js)::jsonb, '$."a"' RETURNING jsonb WITH CONDITIONAL WRAPPER KEEP QUOTES EMPTY OBJECT ON ERROR) = '[10]'::jsonb) (JSON_VALUE((js)::jsonb, '$."a"' RETURNING integer DEFAULT 12 ON EMPTY ERROR ON ERROR) > i) (js IS JSON) - JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS int, (i)::text AS txt, ARRAY[1, 2, 3] AS arr) + JSON_EXISTS((js)::jsonb, '$."a"' PASSING (i + 5) AS "int", (i)::text AS "TXT", ARRAY[1, 2, 3] AS arr) (5 rows) SELECT pg_get_expr(adbin, adrelid) @@ -1366,6 +1366,20 @@ SELECT JSON_QUERY(jsonb 'null', '$xyz' PASSING 1 AS xyz); 1 (1 row) +SELECT JSON_QUERY(jsonb 'null', '$Xyz' PASSING 1 AS Xyz); +ERROR: could not find jsonpath variable "Xyz" +SELECT JSON_QUERY(jsonb 'null', '$Xyz' PASSING 1 AS "Xyz"); + json_query +------------ + 1 +(1 row) + +SELECT JSON_QUERY(jsonb 'null', '$"Xyz"' PASSING 1 AS "Xyz"); + json_query +------------ + 1 +(1 row) + -- Test ON ERROR / EMPTY value validity for the function; all fail. SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR); ERROR: invalid ON ERROR behavior diff --git a/src/test/regress/sql/sqljson_queryfuncs.sql b/src/test/regress/sql/sqljson_queryfuncs.sql index 21b5d49ecec..8d7b225b612 100644 --- a/src/test/regress/sql/sqljson_queryfuncs.sql +++ b/src/test/regress/sql/sqljson_queryfuncs.sql @@ -327,7 +327,7 @@ CREATE TABLE test_jsonb_constraints ( CONSTRAINT test_jsonb_constraint1 CHECK (js IS JSON) CONSTRAINT test_jsonb_constraint2 - CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS txt, array[1,2,3] as arr)) + CHECK (JSON_EXISTS(js::jsonb, '$.a' PASSING i + 5 AS int, i::text AS "TXT", array[1,2,3] as arr)) CONSTRAINT test_jsonb_constraint3 CHECK (JSON_VALUE(js::jsonb, '$.a' RETURNING int DEFAULT '12' ON EMPTY ERROR ON ERROR) > i) CONSTRAINT test_jsonb_constraint4 @@ -465,6 +465,9 @@ 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); +SELECT JSON_QUERY(jsonb 'null', '$Xyz' PASSING 1 AS Xyz); +SELECT JSON_QUERY(jsonb 'null', '$Xyz' PASSING 1 AS "Xyz"); +SELECT JSON_QUERY(jsonb 'null', '$"Xyz"' PASSING 1 AS "Xyz"); -- Test ON ERROR / EMPTY value validity for the function; all fail. SELECT JSON_EXISTS(jsonb '1', '$' DEFAULT 1 ON ERROR);