create aggregate function that unwraps 2 arrays and returns one with distinct values from both provided
This commit is contained in:
parent
4d10455cf1
commit
0e6e7e45f4
27
postgres/concat_distinct_array_values.sql
Normal file
27
postgres/concat_distinct_array_values.sql
Normal file
@ -0,0 +1,27 @@
|
||||
DO $$
|
||||
DECLARE
|
||||
|
||||
_a1 jsonb;
|
||||
_a2 jsonb;
|
||||
_a3 jsonb;
|
||||
|
||||
BEGIN
|
||||
|
||||
_a1 := (select '["A","B","A"]'::jsonb);
|
||||
_a2 := (select '["A","B","A"]'::jsonb);
|
||||
SELECT
|
||||
jsonb_agg(DISTINCT x.ae)
|
||||
INTO
|
||||
_a3
|
||||
FROM
|
||||
(
|
||||
SELECT jsonb_array_elements(_a1) ae
|
||||
UNION ALL
|
||||
SELECT jsonb_array_elements(_a2) ae
|
||||
) x;
|
||||
|
||||
raise notice '%', _a3;
|
||||
|
||||
END;
|
||||
$$
|
||||
language plpgsql
|
27
postgres/jsonb_arr_aggcd.sql
Normal file
27
postgres/jsonb_arr_aggcd.sql
Normal file
@ -0,0 +1,27 @@
|
||||
CREATE OR REPLACE FUNCTION public.jsonb_concat_distinct_arr(
|
||||
state jsonb,
|
||||
concat jsonb)
|
||||
RETURNS jsonb AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
--RAISE notice 'state is %', state;
|
||||
--RAISE notice 'concat is %', concat;
|
||||
RETURN
|
||||
jsonb_agg(DISTINCT ae)
|
||||
FROM
|
||||
(
|
||||
SELECT jsonb_array_elements(state) ae
|
||||
UNION ALL
|
||||
SELECT jsonb_array_elements(concat) ae
|
||||
) x;
|
||||
END;
|
||||
$BODY$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
DROP AGGREGATE IF EXISTS public.jsonb_arr_aggcd(jsonb);
|
||||
CREATE AGGREGATE public.jsonb_arr_aggcd(jsonb) (
|
||||
SFUNC=public.jsonb_concat_distinct_arr,
|
||||
STYPE=jsonb,
|
||||
INITCOND='[]'
|
||||
);
|
||||
|
Loading…
Reference in New Issue
Block a user