Commit e676d80f authored by Alice Salsé's avatar Alice Salsé
Browse files

🔨 improve insert & update functions

parent 87d2c64b
......@@ -7,30 +7,13 @@ CREATE OR REPLACE FUNCTION fnc_insert_from_jsonb(
)
RETURNS integer AS $BODY$
DECLARE
_json_keys text;
_json_values text;
_json_match record;
_upd_json jsonb;
BEGIN
i_json := jsonb_strip_nulls(i_json);
_json_match := utils.fnc_json_match_table(i_regclass, i_json);
with matching as (
SELECT key,
case
when udt_name = 'geometry' then ST_SetSRID(St_GeomFromGeoJSON(value), 2154)::text
when data_type = 'ARRAY' then replace(replace(value,'[','{'),']','}')::text
else value
end::text valuee
from jsonb_each_text(i_json)
inner join information_schema.columns
on table_schema=(parse_ident(i_regclass::text))[1]
and table_name=(parse_ident(i_regclass::text))[2]
and column_name=key
)
select string_agg(key::text,','), string_agg(quote_nullable(valuee::text),',')
INTO _json_keys, _json_values
FROM matching;
EXECUTE 'INSERT INTO '|| i_regclass ||' ('|| _json_keys ||')
VALUES ('|| _json_values ||')
EXECUTE 'INSERT INTO '|| i_regclass ||' ('|| _json_match.o_json_keys ||')
VALUES ('|| _json_match.o_json_values ||')
returning id;'
into o_id;
......
\encoding UTF8
set search_path to utils, public;
CREATE OR REPLACE FUNCTION fnc_json_match_table(
IN i_regclass regclass,
IN i_new_json jsonb,
IN i_old_json jsonb DEFAULT jsonb_build_object('emptyjson', Null),
OUT o_json_keys text,
OUT o_json_values text,
OUT o_upd_json jsonb
)
RETURNS record AS $BODY$
with upd_keys as (
select n.key, n.value
from jsonb_each_text(i_new_json) n
left outer join (select * from jsonb_each_text(i_old_json)) o on o.key=n.key
where n.key='id' or n.value IS DISTINCT FROM o.value
)
, matching as (
SELECT key,
case
when udt_name = 'geometry' then ST_SetSRID(St_GeomFromGeoJSON(value), 2154)::text
when data_type = 'ARRAY' then replace(replace(value,'[','{'),']','}')::text
else value
end::text valuee
from upd_keys
inner join information_schema.columns
on table_schema=(parse_ident(i_regclass::text))[1]
and table_name=(parse_ident(i_regclass::text))[2]
and column_name=key
)
select string_agg(key::text,',') o_json_keys
, string_agg(quote_nullable(valuee::text),',') o_json_values
, jsonb_object_agg(key,valuee) o_upd_json
FROM matching;
$BODY$
LANGUAGE sql IMMUTABLE SECURITY DEFINER
COST 100;
......@@ -3,44 +3,23 @@ set search_path to utils, public;
CREATE OR REPLACE FUNCTION fnc_update_from_jsonb(
IN i_regclass regclass,
IN i_new_json jsonb,
IN i_old_json jsonb
IN i_old_json jsonb DEFAULT jsonb_build_object('emptyjson', Null)
)
RETURNS void AS $BODY$
DECLARE
_json_keys text;
_json_values text;
_json_match record;
_upd_json jsonb;
_query text;
BEGIN
select json_object_agg(n.key,n.value) INTO i_new_json
from jsonb_each(i_new_json) n
left outer join (select * from jsonb_each(i_old_json)) o on o.key=n.key
where n.key='id' or n.value!=o.value or o.key is null;
_json_match := utils.fnc_json_match_table(i_regclass, i_new_json - 'id', i_old_json);
with matching as (
SELECT key,
case
when udt_name = 'geometry' then ST_SetSRID(St_GeomFromGeoJSON(value), 2154)::text
when data_type = 'ARRAY' then replace(replace(value,'[','{'),']','}')::text
else value
end::text valuee
from jsonb_each_text(i_new_json)
inner join information_schema.columns
on table_schema=(parse_ident(i_regclass::text))[1]
and table_name=(parse_ident(i_regclass::text))[2]
and column_name=key
where key!='id'
)
select string_agg(key::text,','), string_agg(quote_nullable(valuee::text),',')
INTO _json_keys, _json_values
FROM matching;
if _json_keys like '%,%' then
if _json_match.o_json_keys like '%,%' then
_query := 'UPDATE '|| i_regclass ||'
SET ('|| _json_keys ||') = ('|| _json_values ||')
SET ('|| _json_match.o_json_keys ||') = ('|| _json_match.o_json_values ||')
WHERE id = '|| (i_new_json->>'id') ||';';
else
_query := 'UPDATE '|| i_regclass ||'
SET '|| _json_keys ||' = '|| _json_values ||'
SET '|| _json_match.o_json_keys ||' = '|| _json_match.o_json_values ||'
WHERE id = '|| (i_new_json->>'id') ||';';
end if;
......
......@@ -57,7 +57,7 @@ begin
ELSE
-- Update geom attributes
_new := _new - 'geom' || jsonb_build_object('id', _geom_id);
PERFORM utils.fnc_update_from_jsonb(TG_TABLE_SCHEMA||'.'||_nw_table, _new, jsonb_build_object('emptyjson', 'None'));
PERFORM utils.fnc_update_from_jsonb(TG_TABLE_SCHEMA||'.'||_nw_table, _new);
END IF;
-- >>> Control if object exist <<<
EXECUTE FORMAT (
......
Supports Markdown
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment