From a83586b5543b948f9e621462537a7303b113c482 Mon Sep 17 00:00:00 2001 From: Andrew Dunstan Date: Fri, 17 Jan 2020 11:41:35 +1030 Subject: [PATCH] Add a non-strict version of jsonb_set jsonb_set_lax() is the same as jsonb_set, except that it takes and extra argument that specifies what to do if the value argument is NULL. The default is 'use_json_null'. Other possibilities are 'raise_exception', 'return_target' and 'delete_key', all these behaviours having been suggested as reasonable by various users. Discussion: https://postgr.es/m/375873e2-c957-3a8d-64f9-26c43c2b16e7@2ndQuadrant.com Reviewed by: Pavel Stehule --- doc/src/sgml/func.sgml | 23 ++++++++++ src/backend/catalog/system_views.sql | 9 ++++ src/backend/utils/adt/jsonfuncs.c | 64 ++++++++++++++++++++++++++++ src/include/catalog/pg_proc.dat | 3 ++ src/test/regress/expected/jsonb.out | 57 +++++++++++++++++++++++++ src/test/regress/sql/jsonb.sql | 20 +++++++++ 6 files changed, 176 insertions(+) diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 4b42f12862..72072e7545 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -12231,6 +12231,9 @@ table2-mapping jsonb_set + + jsonb_set_lax + jsonb_insert @@ -12545,6 +12548,26 @@ table2-mapping [{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2] + + jsonb_set_lax(target jsonb, path text[], new_value jsonb , create_missing boolean , null_value_treatment text) + + jsonb + + If new_value is not null, + behaves identically to jsonb_set. Otherwise behaves + according to the value of null_value_treatment + which must be one of 'raise_exception', + 'use_json_null', 'delete_key', or + 'return_target'. The default is + 'use_json_null'. + + jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}',null) + jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}',null, true, 'return_target') + + [{"f1":null,"f2":null},2,null,3] + [{"f1": 99, "f2": null}, 2] + + diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql index b3e82de71e..c9e75f4370 100644 --- a/src/backend/catalog/system_views.sql +++ b/src/backend/catalog/system_views.sql @@ -1264,6 +1264,15 @@ LANGUAGE INTERNAL STRICT IMMUTABLE PARALLEL SAFE AS 'jsonb_set'; +CREATE OR REPLACE FUNCTION + jsonb_set_lax(jsonb_in jsonb, path text[] , replacement jsonb, + create_if_missing boolean DEFAULT true, + null_value_treatment text DEFAULT 'use_json_null') +RETURNS jsonb +LANGUAGE INTERNAL +CALLED ON NULL INPUT IMMUTABLE PARALLEL SAFE +AS 'jsonb_set_lax'; + CREATE OR REPLACE FUNCTION parse_ident(str text, strict boolean DEFAULT true) RETURNS text[] diff --git a/src/backend/utils/adt/jsonfuncs.c b/src/backend/utils/adt/jsonfuncs.c index ab5a24a858..4b5a0214dc 100644 --- a/src/backend/utils/adt/jsonfuncs.c +++ b/src/backend/utils/adt/jsonfuncs.c @@ -4395,6 +4395,70 @@ jsonb_set(PG_FUNCTION_ARGS) } +/* + * SQL function jsonb_set_lax(jsonb, text[], jsonb, boolean, text) + */ +Datum +jsonb_set_lax(PG_FUNCTION_ARGS) +{ + /* Jsonb *in = PG_GETARG_JSONB_P(0); */ + /* ArrayType *path = PG_GETARG_ARRAYTYPE_P(1); */ + /* Jsonb *newval = PG_GETARG_JSONB_P(2); */ + /* bool create = PG_GETARG_BOOL(3); */ + text *handle_null; + char *handle_val; + + if (PG_ARGISNULL(0) || PG_ARGISNULL(1) || PG_ARGISNULL(3)) + PG_RETURN_NULL(); + + /* could happen if they pass in an explicit NULL */ + if (PG_ARGISNULL(4)) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("need delete_key, return_target, use_json_null, or raise_exception"))); + + /* if the new value isn't an SQL NULL just call jsonb_set */ + if (! PG_ARGISNULL(2)) + return jsonb_set(fcinfo); + + handle_null = PG_GETARG_TEXT_P(4); + handle_val = text_to_cstring(handle_null); + + if (strcmp(handle_val,"raise_exception") == 0) + { + ereport(ERROR, + (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), + errmsg("NULL is not allowed"), + errdetail("exception raised due to \"null_value_treatment => 'raise_exception'\""), + errhint("to avoid, either change the null_value_treatment argument or ensure that an SQL NULL is not used"))); + } + else if (strcmp(handle_val, "use_json_null") == 0) + { + Datum newval; + + newval = DirectFunctionCall1(jsonb_in, CStringGetDatum("null")); + + fcinfo->args[2].value = newval; + fcinfo->args[2].isnull = false; + return jsonb_set(fcinfo); + } + else if (strcmp(handle_val, "delete_key") == 0) + { + return jsonb_delete_path(fcinfo); + } + else if (strcmp(handle_val, "return_target") == 0) + { + Jsonb *in = PG_GETARG_JSONB_P(0); + PG_RETURN_JSONB_P(in); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("need delete_key, return_target, use_json_null, or raise_exception"))); + } +} + /* * SQL function jsonb_delete_path(jsonb, text[]) */ diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index 427faa3c3b..fcf2a1214c 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -9305,6 +9305,9 @@ { oid => '3304', proname => 'jsonb_delete_path', prorettype => 'jsonb', proargtypes => 'jsonb _text', prosrc => 'jsonb_delete_path' }, +{ oid => '8945', descr => 'Set part of a jsonb, handle NULL value', + proname => 'jsonb_set_lax', prorettype => 'jsonb', proisstrict => 'f', + proargtypes => 'jsonb _text jsonb bool text', prosrc => 'jsonb_set_lax' }, { oid => '3305', descr => 'Set part of a jsonb', proname => 'jsonb_set', prorettype => 'jsonb', proargtypes => 'jsonb _text jsonb bool', prosrc => 'jsonb_set' }, diff --git a/src/test/regress/expected/jsonb.out b/src/test/regress/expected/jsonb.out index a2a19f8104..b92f8e8dbc 100644 --- a/src/test/regress/expected/jsonb.out +++ b/src/test/regress/expected/jsonb.out @@ -4511,6 +4511,63 @@ select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"' ERROR: path element at position 3 is not an integer: "non_integer" select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"'); ERROR: path element at position 3 is null +-- jsonb_set_lax +\pset null NULL +-- pass though non nulls to jsonb_set +select jsonb_set_lax('{"a":1,"b":2}','{b}','5') ; + jsonb_set_lax +------------------ + {"a": 1, "b": 5} +(1 row) + +select jsonb_set_lax('{"a":1,"b":2}','{d}','6', true) ; + jsonb_set_lax +-------------------------- + {"a": 1, "b": 2, "d": 6} +(1 row) + +-- using the default treatment +select jsonb_set_lax('{"a":1,"b":2}','{b}',null); + jsonb_set_lax +--------------------- + {"a": 1, "b": null} +(1 row) + +select jsonb_set_lax('{"a":1,"b":2}','{d}',null,true); + jsonb_set_lax +----------------------------- + {"a": 1, "b": 2, "d": null} +(1 row) + +-- errors +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, null); +ERROR: need delete_key, return_target, use_json_null, or raise_exception +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, 'no_such_treatment'); +ERROR: need delete_key, return_target, use_json_null, or raise_exception +-- explicit treatments +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'raise_exception') as raise_exception; +ERROR: NULL is not allowed +DETAIL: exception raised due to "null_value_treatment => 'raise_exception'" +HINT: to avoid, either change the null_value_treatment argument or ensure that an SQL NULL is not used +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'return_target') as return_target; + return_target +------------------ + {"a": 1, "b": 2} +(1 row) + +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'delete_key') as delete_key; + delete_key +------------ + {"a": 1} +(1 row) + +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'use_json_null') as use_json_null; + use_json_null +--------------------- + {"a": 1, "b": null} +(1 row) + +\pset null -- jsonb_insert select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"'); jsonb_insert diff --git a/src/test/regress/sql/jsonb.sql b/src/test/regress/sql/jsonb.sql index efd4c45185..3e2b8f66df 100644 --- a/src/test/regress/sql/jsonb.sql +++ b/src/test/regress/sql/jsonb.sql @@ -1153,6 +1153,26 @@ select jsonb_set('{"a": [1, 2, 3]}', '{a, non_integer}', '"new_value"'); select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, non_integer}', '"new_value"'); select jsonb_set('{"a": {"b": [1, 2, 3]}}', '{a, b, NULL}', '"new_value"'); +-- jsonb_set_lax + +\pset null NULL + +-- pass though non nulls to jsonb_set +select jsonb_set_lax('{"a":1,"b":2}','{b}','5') ; +select jsonb_set_lax('{"a":1,"b":2}','{d}','6', true) ; +-- using the default treatment +select jsonb_set_lax('{"a":1,"b":2}','{b}',null); +select jsonb_set_lax('{"a":1,"b":2}','{d}',null,true); +-- errors +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, null); +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, true, 'no_such_treatment'); +-- explicit treatments +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'raise_exception') as raise_exception; +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'return_target') as return_target; +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'delete_key') as delete_key; +select jsonb_set_lax('{"a":1,"b":2}', '{b}', null, null_value_treatment => 'use_json_null') as use_json_null; + +\pset null -- jsonb_insert select jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"');