Add more SQL/JSON constructor functions

This Patch introduces three SQL standard JSON functions:

JSON()
JSON_SCALAR()
JSON_SERIALIZE()

JSON() produces json values from text, bytea, json or jsonb values,
and has facilitites for handling duplicate keys.

JSON_SCALAR() produces a json value from any scalar sql value,
including json and jsonb.

JSON_SERIALIZE() produces text or bytea from input which containis
or represents json or jsonb;

For the most part these functions don't add any significant new
capabilities, but they will be of use to users wanting standard
compliant JSON handling.

Catversion bumped as this changes ruleutils.c.

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: Andrew Dunstan <andrew@dunslane.net>
Author: Amit Langote <amitlangote09@gmail.com>

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, Álvaro Herrera,
Peter Eisentraut

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
Discussion: https://postgr.es/m/CA+HiwqE4XTdfb1nW=Ojoy_tQSRhYt-q_kb6i5d4xcKyrLC1Nbg@mail.gmail.com
This commit is contained in:
Amit Langote
2023-07-20 22:21:43 +09:00
parent 254ac5a7c3
commit 03734a7fed
22 changed files with 1397 additions and 42 deletions

View File

@ -1,3 +1,67 @@
-- JSON()
SELECT JSON();
SELECT JSON(NULL);
SELECT JSON('{ "a" : 1 } ');
SELECT JSON('{ "a" : 1 } ' FORMAT JSON);
SELECT JSON('{ "a" : 1 } ' FORMAT JSON ENCODING UTF8);
SELECT JSON('{ "a" : 1 } '::bytea FORMAT JSON ENCODING UTF8);
SELECT pg_typeof(JSON('{ "a" : 1 } '));
SELECT JSON(' 1 '::json);
SELECT JSON(' 1 '::jsonb);
SELECT JSON(' 1 '::json WITH UNIQUE KEYS);
SELECT JSON(123);
SELECT JSON('{"a": 1, "a": 2}');
SELECT JSON('{"a": 1, "a": 2}' WITH UNIQUE KEYS);
SELECT JSON('{"a": 1, "a": 2}' WITHOUT UNIQUE KEYS);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' FORMAT JSON);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123'::bytea FORMAT JSON ENCODING UTF8);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITH UNIQUE KEYS);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123' WITHOUT UNIQUE KEYS);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON('123');
SELECT pg_typeof(JSON('123'));
-- JSON_SCALAR()
SELECT JSON_SCALAR();
SELECT JSON_SCALAR(NULL);
SELECT JSON_SCALAR(NULL::int);
SELECT JSON_SCALAR(123);
SELECT JSON_SCALAR(123.45);
SELECT JSON_SCALAR(123.45::numeric);
SELECT JSON_SCALAR(true);
SELECT JSON_SCALAR(false);
SELECT JSON_SCALAR(' 123.45');
SELECT JSON_SCALAR('2020-06-07'::date);
SELECT JSON_SCALAR('2020-06-07 01:02:03'::timestamp);
SELECT JSON_SCALAR('{}'::json);
SELECT JSON_SCALAR('{}'::jsonb);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR(123);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SCALAR('123');
-- JSON_SERIALIZE()
SELECT JSON_SERIALIZE();
SELECT JSON_SERIALIZE(NULL);
SELECT JSON_SERIALIZE(JSON('{ "a" : 1 } '));
SELECT JSON_SERIALIZE('{ "a" : 1 } ');
SELECT JSON_SERIALIZE('1');
SELECT JSON_SERIALIZE('1' FORMAT JSON);
SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING bytea);
SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING varchar);
SELECT pg_typeof(JSON_SERIALIZE(NULL));
-- only string types or bytea allowed
SELECT JSON_SERIALIZE('{ "a" : 1 } ' RETURNING jsonb);
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}');
EXPLAIN (VERBOSE, COSTS OFF) SELECT JSON_SERIALIZE('{}' RETURNING bytea);
-- JSON_OBJECT()
SELECT JSON_OBJECT();
SELECT JSON_OBJECT(RETURNING json);
@ -216,6 +280,9 @@ FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
FROM (VALUES (1, 1), (1, NULL), (2, 2)) foo(k, v);
SELECT JSON_OBJECTAGG(k: v ABSENT ON NULL WITH UNIQUE KEYS RETURNING jsonb)
FROM (VALUES (1, 1), (0, NULL),(4, null), (5, null),(6, null),(2, 2)) foo(k, v);
-- Test JSON_OBJECT deparsing
EXPLAIN (VERBOSE, COSTS OFF)
SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
@ -227,6 +294,24 @@ SELECT JSON_OBJECT('foo' : '1' FORMAT JSON, 'bar' : 'baz' RETURNING json);
DROP VIEW json_object_view;
SELECT to_json(a) AS a, JSON_OBJECTAGG(k : v WITH UNIQUE KEYS) OVER (ORDER BY k)
FROM (VALUES (1,1), (2,2)) a(k,v);
SELECT to_json(a) AS a, JSON_OBJECTAGG(k : v WITH UNIQUE KEYS) OVER (ORDER BY k)
FROM (VALUES (1,1), (1,2), (2,2)) a(k,v);
SELECT to_json(a) AS a, JSON_OBJECTAGG(k : v ABSENT ON NULL WITH UNIQUE KEYS)
OVER (ORDER BY k)
FROM (VALUES (1,1), (1,null), (2,2)) a(k,v);
SELECT to_json(a) AS a, JSON_OBJECTAGG(k : v ABSENT ON NULL)
OVER (ORDER BY k)
FROM (VALUES (1,1), (1,null), (2,2)) a(k,v);
SELECT to_json(a) AS a, JSON_OBJECTAGG(k : v ABSENT ON NULL)
OVER (ORDER BY k RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
FROM (VALUES (1,1), (1,null), (2,2)) a(k,v);
-- Test JSON_ARRAY deparsing
EXPLAIN (VERBOSE, COSTS OFF)
SELECT JSON_ARRAY('1' FORMAT JSON, 2 RETURNING json);