From aa2c36858c2132063bfe1691cee5e9303fc020e9 Mon Sep 17 00:00:00 2001 From: naisila Date: Wed, 6 Sep 2023 16:38:16 +0300 Subject: [PATCH] Add tests with JSON_ARRAYAGG and JSON_OBJECTAGG aggregates Relevant PG commit: https://github.com/postgres/postgres/commit/7081ac46ace8c459966174400b53418683c9fe5c 7081ac46ace8c459966174400b53418683c9fe5c --- src/test/regress/expected/pg16.out | 82 ++++++++++++++++++++++++++++++ src/test/regress/sql/pg16.sql | 51 +++++++++++++++++++ 2 files changed, 133 insertions(+) diff --git a/src/test/regress/expected/pg16.out b/src/test/regress/expected/pg16.out index a8ff5e47d26..be4afc98105 100644 --- a/src/test/regress/expected/pg16.out +++ b/src/test/regress/expected/pg16.out @@ -520,6 +520,88 @@ SET citus.shard_replication_factor TO 1; -- DEFAULT cannot be used in COPY TO COPY (select 1 as test) TO stdout WITH (default '\D'); ERROR: COPY DEFAULT only available using COPY FROM +-- Tests for SQL/JSON: JSON_ARRAYAGG and JSON_OBJECTAGG aggregates +-- Relevant PG commit: +-- https://github.com/postgres/postgres/commit/7081ac4 +SET citus.next_shard_id TO 952000; +CREATE TABLE agg_test(a int, b serial); +SELECT create_distributed_table('agg_test', 'a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO agg_test SELECT i FROM generate_series(1, 5) i; +-- JSON_ARRAYAGG with distribution key +SELECT JSON_ARRAYAGG(a ORDER BY a), +JSON_ARRAYAGG(a ORDER BY a RETURNING jsonb) +FROM agg_test; + json_arrayagg | json_arrayagg +--------------------------------------------------------------------- + [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5] +(1 row) + +-- JSON_ARRAYAGG with other column +SELECT JSON_ARRAYAGG(b ORDER BY b), +JSON_ARRAYAGG(b ORDER BY b RETURNING jsonb) +FROM agg_test; + json_arrayagg | json_arrayagg +--------------------------------------------------------------------- + [1, 2, 3, 4, 5] | [1, 2, 3, 4, 5] +(1 row) + +-- JSON_ARRAYAGG with router query +SET citus.log_remote_commands TO on; +SELECT JSON_ARRAYAGG(a ORDER BY a), +JSON_ARRAYAGG(a ORDER BY a RETURNING jsonb) +FROM agg_test WHERE a = 2; +NOTICE: issuing SELECT JSON_ARRAYAGG(a ORDER BY a RETURNING json) AS "json_arrayagg", JSON_ARRAYAGG(a ORDER BY a RETURNING jsonb) AS "json_arrayagg" FROM pg16.agg_test_952000 agg_test WHERE (a OPERATOR(pg_catalog.=) 2) +DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx + json_arrayagg | json_arrayagg +--------------------------------------------------------------------- + [2] | [2] +(1 row) + +RESET citus.log_remote_commands; +-- JSON_OBJECTAGG with distribution key +SELECT + JSON_OBJECTAGG(a: a), + JSON_ARRAYAGG(a ORDER BY a), -- for order + JSON_OBJECTAGG(a: a RETURNING jsonb) +FROM + agg_test; + json_objectagg | json_arrayagg | json_objectagg +--------------------------------------------------------------------- + { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | [1, 2, 3, 4, 5] | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5} +(1 row) + +-- JSON_OBJECTAGG with other column +SELECT + JSON_OBJECTAGG(b: b), + JSON_ARRAYAGG(b ORDER BY b), -- for order + JSON_OBJECTAGG(b: b RETURNING jsonb) +FROM + agg_test; + json_objectagg | json_arrayagg | json_objectagg +--------------------------------------------------------------------- + { "1" : 1, "2" : 2, "3" : 3, "4" : 4, "5" : 5 } | [1, 2, 3, 4, 5] | {"1": 1, "2": 2, "3": 3, "4": 4, "5": 5} +(1 row) + +-- JSON_OBJECTAGG with router query +SET citus.log_remote_commands TO on; +SELECT + JSON_OBJECTAGG(a: a), + JSON_OBJECTAGG(a: a RETURNING jsonb) +FROM + agg_test WHERE a = 3; +NOTICE: issuing SELECT JSON_OBJECTAGG(a : a RETURNING json) AS "json_objectagg", JSON_OBJECTAGG(a : a RETURNING jsonb) AS "json_objectagg" FROM pg16.agg_test_952000 agg_test WHERE (a OPERATOR(pg_catalog.=) 3) +DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx + json_objectagg | json_objectagg +--------------------------------------------------------------------- + { "3" : 3 } | {"3": 3} +(1 row) + +RESET citus.log_remote_commands; -- Tests for SQL/JSON: support the IS JSON predicate -- Relevant PG commit: -- https://github.com/postgres/postgres/commit/6ee30209 diff --git a/src/test/regress/sql/pg16.sql b/src/test/regress/sql/pg16.sql index 8cffb917ecc..47c17e72d65 100644 --- a/src/test/regress/sql/pg16.sql +++ b/src/test/regress/sql/pg16.sql @@ -319,6 +319,57 @@ SET citus.shard_replication_factor TO 1; -- DEFAULT cannot be used in COPY TO COPY (select 1 as test) TO stdout WITH (default '\D'); +-- Tests for SQL/JSON: JSON_ARRAYAGG and JSON_OBJECTAGG aggregates +-- Relevant PG commit: +-- https://github.com/postgres/postgres/commit/7081ac4 +SET citus.next_shard_id TO 952000; + +CREATE TABLE agg_test(a int, b serial); +SELECT create_distributed_table('agg_test', 'a'); +INSERT INTO agg_test SELECT i FROM generate_series(1, 5) i; + +-- JSON_ARRAYAGG with distribution key +SELECT JSON_ARRAYAGG(a ORDER BY a), +JSON_ARRAYAGG(a ORDER BY a RETURNING jsonb) +FROM agg_test; + +-- JSON_ARRAYAGG with other column +SELECT JSON_ARRAYAGG(b ORDER BY b), +JSON_ARRAYAGG(b ORDER BY b RETURNING jsonb) +FROM agg_test; + +-- JSON_ARRAYAGG with router query +SET citus.log_remote_commands TO on; +SELECT JSON_ARRAYAGG(a ORDER BY a), +JSON_ARRAYAGG(a ORDER BY a RETURNING jsonb) +FROM agg_test WHERE a = 2; +RESET citus.log_remote_commands; + +-- JSON_OBJECTAGG with distribution key +SELECT + JSON_OBJECTAGG(a: a), + JSON_ARRAYAGG(a ORDER BY a), -- for order + JSON_OBJECTAGG(a: a RETURNING jsonb) +FROM + agg_test; + +-- JSON_OBJECTAGG with other column +SELECT + JSON_OBJECTAGG(b: b), + JSON_ARRAYAGG(b ORDER BY b), -- for order + JSON_OBJECTAGG(b: b RETURNING jsonb) +FROM + agg_test; + +-- JSON_OBJECTAGG with router query +SET citus.log_remote_commands TO on; +SELECT + JSON_OBJECTAGG(a: a), + JSON_OBJECTAGG(a: a RETURNING jsonb) +FROM + agg_test WHERE a = 3; +RESET citus.log_remote_commands; + -- Tests for SQL/JSON: support the IS JSON predicate -- Relevant PG commit: -- https://github.com/postgres/postgres/commit/6ee30209