Skip to content

Instantly share code, notes, and snippets.

@rabidaudio
Last active April 19, 2020 04:57
Show Gist options
  • Save rabidaudio/d7667119af0b5d1572e2ec5ce6b9c6e9 to your computer and use it in GitHub Desktop.
Save rabidaudio/d7667119af0b5d1572e2ec5ce6b9c6e9 to your computer and use it in GitHub Desktop.
Deep jsonb_concat for Postgres
-- Postgres jsonb_concat() function only merges the top level keys, it does not merge nested objects.
-- This will merge all nested objects. Note that it doesn't recurse through arrays, nor does it append
-- arrays, it simply replaces them. It would be easy to adjust this if you need. Tested on 9.6.
-- NOTE: This was mostly an experiment and has not been thoroughly vetted for functionality or performance,
-- use at your own risk!
-- This work is in the Public Domain.
CREATE OR REPLACE FUNCTION _deep_jsonb_concat(a jsonb, b jsonb) RETURNS jsonb AS $$
DECLARE
key text;
merged jsonb;
BEGIN
if jsonb_typeof(a) <> 'object' THEN
return b;
end if;
if jsonb_typeof(b) <> 'object' THEN
return b;
end if;
merged := a;
FOR key in SELECT jsonb_object_keys(b) LOOP
merged := jsonb_set(merged, ARRAY[key], _deep_jsonb_concat(
jsonb_object_field(a, key),
jsonb_object_field(b, key)
));
END LOOP;
RETURN merged;
END;
$$ LANGUAGE plpgsql;
SELECT jsonb_concat('{"a":{"nested":1}}'::jsonb, '{"a":{"also nested":2}}'::jsonb); -- {"a": {"also nested": 2}}
SELECT _deep_jsonb_concat('{"a":{"nested":1}}'::jsonb, '{"a":{"also nested":2}}'::jsonb); -- {"a": {"nested": 1, "also nested": 2}}
@rabidaudio
Copy link
Author

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment