mirror of
https://github.com/postgres/postgres.git
synced 2025-07-09 22:41:56 +03:00
SQL/JSON: support the IS JSON predicate
This patch introduces the SQL standard IS JSON predicate. It operates on text and bytea values representing JSON, as well as on the json and jsonb types. Each test has IS and IS NOT variants and supports a WITH UNIQUE KEYS flag. The tests are: IS JSON [VALUE] IS JSON ARRAY IS JSON OBJECT IS JSON SCALAR These should be self-explanatory. The WITH UNIQUE KEYS flag makes these return false when duplicate keys exist in any object within the value, not necessarily directly contained in the outermost object. Author: Nikita Glukhov <n.gluhov@postgrespro.ru> Author: Teodor Sigaev <teodor@sigaev.ru> Author: Oleg Bartunov <obartunov@gmail.com> Author: Alexander Korotkov <aekorotkov@gmail.com> Author: Amit Langote <amitlangote09@gmail.com> Author: Andrew Dunstan <andrew@dunslane.net> Reviewers have included (in no particular order) Andres Freund, Alexander Korotkov, Pavel Stehule, Andrew Alsup, Erik Rijkers, Zihong Yu, Himanshu Upadhyaya, Daniel Gustafsson, Justin Pryzby. Discussion: https://postgr.es/m/CAF4Au4w2x-5LTnN_bxky-mq4=WOqsGsxSpENCzHRAzSnEd8+WQ@mail.gmail.com Discussion: https://postgr.es/m/cd0bb935-0158-78a7-08b5-904886deac4b@postgrespro.ru Discussion: https://postgr.es/m/20220616233130.rparivafipt6doj3@alap3.anarazel.de Discussion: https://postgr.es/m/abd9b83b-aa66-f230-3d6d-734817f0995d%40postgresql.org
This commit is contained in:
@ -282,3 +282,99 @@ SELECT JSON_ARRAY(SELECT i FROM (VALUES (1), (2), (NULL), (4)) foo(i) RETURNING
|
||||
\sv json_array_subquery_view
|
||||
|
||||
DROP VIEW json_array_subquery_view;
|
||||
|
||||
-- IS JSON predicate
|
||||
SELECT NULL IS JSON;
|
||||
SELECT NULL IS NOT JSON;
|
||||
SELECT NULL::json IS JSON;
|
||||
SELECT NULL::jsonb IS JSON;
|
||||
SELECT NULL::text IS JSON;
|
||||
SELECT NULL::bytea IS JSON;
|
||||
SELECT NULL::int IS JSON;
|
||||
|
||||
SELECT '' IS JSON;
|
||||
|
||||
SELECT bytea '\x00' IS JSON;
|
||||
|
||||
CREATE TABLE test_is_json (js text);
|
||||
|
||||
INSERT INTO test_is_json VALUES
|
||||
(NULL),
|
||||
(''),
|
||||
('123'),
|
||||
('"aaa "'),
|
||||
('true'),
|
||||
('null'),
|
||||
('[]'),
|
||||
('[1, "2", {}]'),
|
||||
('{}'),
|
||||
('{ "a": 1, "b": null }'),
|
||||
('{ "a": 1, "a": null }'),
|
||||
('{ "a": 1, "b": [{ "a": 1 }, { "a": 2 }] }'),
|
||||
('{ "a": 1, "b": [{ "a": 1, "b": 0, "a": 2 }] }'),
|
||||
('aaa'),
|
||||
('{a:1}'),
|
||||
('["a",]');
|
||||
|
||||
SELECT
|
||||
js,
|
||||
js IS JSON "IS JSON",
|
||||
js IS NOT JSON "IS NOT JSON",
|
||||
js IS JSON VALUE "IS VALUE",
|
||||
js IS JSON OBJECT "IS OBJECT",
|
||||
js IS JSON ARRAY "IS ARRAY",
|
||||
js IS JSON SCALAR "IS SCALAR",
|
||||
js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
|
||||
js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
|
||||
FROM
|
||||
test_is_json;
|
||||
|
||||
SELECT
|
||||
js,
|
||||
js IS JSON "IS JSON",
|
||||
js IS NOT JSON "IS NOT JSON",
|
||||
js IS JSON VALUE "IS VALUE",
|
||||
js IS JSON OBJECT "IS OBJECT",
|
||||
js IS JSON ARRAY "IS ARRAY",
|
||||
js IS JSON SCALAR "IS SCALAR",
|
||||
js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
|
||||
js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
|
||||
FROM
|
||||
(SELECT js::json FROM test_is_json WHERE js IS JSON) foo(js);
|
||||
|
||||
SELECT
|
||||
js0,
|
||||
js IS JSON "IS JSON",
|
||||
js IS NOT JSON "IS NOT JSON",
|
||||
js IS JSON VALUE "IS VALUE",
|
||||
js IS JSON OBJECT "IS OBJECT",
|
||||
js IS JSON ARRAY "IS ARRAY",
|
||||
js IS JSON SCALAR "IS SCALAR",
|
||||
js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
|
||||
js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
|
||||
FROM
|
||||
(SELECT js, js::bytea FROM test_is_json WHERE js IS JSON) foo(js0, js);
|
||||
|
||||
SELECT
|
||||
js,
|
||||
js IS JSON "IS JSON",
|
||||
js IS NOT JSON "IS NOT JSON",
|
||||
js IS JSON VALUE "IS VALUE",
|
||||
js IS JSON OBJECT "IS OBJECT",
|
||||
js IS JSON ARRAY "IS ARRAY",
|
||||
js IS JSON SCALAR "IS SCALAR",
|
||||
js IS JSON WITHOUT UNIQUE KEYS "WITHOUT UNIQUE",
|
||||
js IS JSON WITH UNIQUE KEYS "WITH UNIQUE"
|
||||
FROM
|
||||
(SELECT js::jsonb FROM test_is_json WHERE js IS JSON) foo(js);
|
||||
|
||||
-- Test IS JSON deparsing
|
||||
EXPLAIN (VERBOSE, COSTS OFF)
|
||||
SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
|
||||
|
||||
CREATE VIEW is_json_view AS
|
||||
SELECT '1' IS JSON AS "any", ('1' || i) IS JSON SCALAR AS "scalar", '[]' IS NOT JSON ARRAY AS "array", '{}' IS JSON OBJECT WITH UNIQUE AS "object" FROM generate_series(1, 3) i;
|
||||
|
||||
\sv is_json_view
|
||||
|
||||
DROP VIEW is_json_view;
|
||||
|
Reference in New Issue
Block a user