diff --git a/deploy/ubm_schema.sql b/deploy/ubm_schema.sql index 4561a33..b7c63d0 100644 --- a/deploy/ubm_schema.sql +++ b/deploy/ubm_schema.sql @@ -1000,6 +1000,71 @@ END $_$; +-- +-- Name: srce_map_val_set_multi(jsonb); Type: FUNCTION; Schema: tps; Owner: - +-- + +CREATE FUNCTION tps.srce_map_val_set_multi(_maps jsonb) RETURNS jsonb + LANGUAGE plpgsql + AS $_$ + +DECLARE + _message jsonb; + _MESSAGE_TEXT text; + _PG_EXCEPTION_DETAIL text; + _PG_EXCEPTION_HINT text; + +BEGIN + + + WITH + -----------expand the json into a table------------------------------------------------------------------------------ + t AS ( + SELECT + jtr.* + FROM + jsonb_array_elements(_maps) ae(v) + JOIN LATERAL jsonb_to_record(ae.v) AS jtr(source text, map text, ret_val jsonb, mapped jsonb) ON TRUE + ) + -----------do merge--------------------------------------------------------------------------------------------------- + INSERT INTO + tps.map_rv + SELECT + t."source" + ,t."map" + ,t.ret_val + ,t.mapped + FROM + t + ON CONFLICT ON CONSTRAINT map_rv_pk DO UPDATE SET + map = excluded.map; + + -------return message-------------------------------------------------------------------------------------------------- + _message:= jsonb_build_object('status','complete'); + RETURN _message; + +EXCEPTION WHEN OTHERS THEN + + GET STACKED DIAGNOSTICS + _MESSAGE_TEXT = MESSAGE_TEXT, + _PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL, + _PG_EXCEPTION_HINT = PG_EXCEPTION_HINT; + _message:= + ($$ + { + "status":"fail", + "message":"error setting map value" + } + $$::jsonb) + ||jsonb_build_object('message_text',_MESSAGE_TEXT) + ||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL); + + RETURN _message; + +END; +$_$; + + -- -- Name: srce_set(text, jsonb); Type: FUNCTION; Schema: tps; Owner: - -- diff --git a/functions/srce_map_val_set_multi.sql b/functions/srce_map_val_set_multi.sql new file mode 100644 index 0000000..edaba13 --- /dev/null +++ b/functions/srce_map_val_set_multi.sql @@ -0,0 +1,60 @@ +DROP FUNCTION tps.srce_map_val_set_multi; +CREATE OR REPLACE FUNCTION tps.srce_map_val_set_multi(_maps jsonb) RETURNS JSONB +LANGUAGE plpgsql +AS $f$ + +DECLARE + _message jsonb; + _MESSAGE_TEXT text; + _PG_EXCEPTION_DETAIL text; + _PG_EXCEPTION_HINT text; + +BEGIN + + + WITH + -----------expand the json into a table------------------------------------------------------------------------------ + t AS ( + SELECT + jtr.* + FROM + jsonb_array_elements(_maps) ae(v) + JOIN LATERAL jsonb_to_record(ae.v) AS jtr(source text, map text, ret_val jsonb, mapped jsonb) ON TRUE + ) + -----------do merge--------------------------------------------------------------------------------------------------- + INSERT INTO + tps.map_rv + SELECT + t."source" + ,t."map" + ,t.ret_val + ,t.mapped + FROM + t + ON CONFLICT ON CONSTRAINT map_rv_pk DO UPDATE SET + map = excluded.map; + + -------return message-------------------------------------------------------------------------------------------------- + _message:= jsonb_build_object('status','complete'); + RETURN _message; + +EXCEPTION WHEN OTHERS THEN + + GET STACKED DIAGNOSTICS + _MESSAGE_TEXT = MESSAGE_TEXT, + _PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL, + _PG_EXCEPTION_HINT = PG_EXCEPTION_HINT; + _message:= + ($$ + { + "status":"fail", + "message":"error setting map value" + } + $$::jsonb) + ||jsonb_build_object('message_text',_MESSAGE_TEXT) + ||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL); + + RETURN _message; + +END; +$f$ \ No newline at end of file diff --git a/sample_discovercard/build_maps.xlsm b/sample_discovercard/build_maps.xlsm new file mode 100644 index 0000000..2b52228 Binary files /dev/null and b/sample_discovercard/build_maps.xlsm differ