cast items in and specify insert columns, create test script

This commit is contained in:
Paul Trowbridge 2018-05-24 17:11:26 -04:00
parent f23da6f5ec
commit 02555012f5
3 changed files with 105 additions and 4 deletions

View File

@ -251,4 +251,78 @@ RAISE NOTICE '%',_sql;
END END
$f$ $f$
LANGUAGE plpgsql; LANGUAGE plpgsql;
-----set map defintion from json argument
CREATE OR REPLACE FUNCTION tps.srce_map_def_set(_defn jsonb) RETURNS jsonb
AS
$f$
DECLARE
_message jsonb;
_MESSAGE_TEXT text;
_PG_EXCEPTION_DETAIL text;
_PG_EXCEPTION_HINT text;
BEGIN
BEGIN
INSERT INTO
tps.map_rm (srce, target, regex, seq, hist)
SELECT
--data source
_defn->>'srce'
--map name
,_defn->>'name'
--map definition
,_defn
--map aggregation sequence
,(_defn->>'sequence')::INTEGER
--history definition
,jsonb_build_object(
'hist_defn',_defn
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
) || '[]'::jsonb
ON CONFLICT ON CONSTRAINT map_rm_pk DO UPDATE SET
srce = _defn->>'srce'
,target = _defn->>'name'
,regex = _defn
,seq = (_defn->>'sequence')::INTEGER
,hist =
--the new definition going to position -0-
jsonb_build_object(
'hist_defn',_defn
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
)
--the previous definition, set upper bound of effective range which was previously null
|| jsonb_set(
map_rm.hist
,'{0,effective,1}'::text[]
,to_jsonb(CURRENT_TIMESTAMP)
);
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 definition"
}
$$::jsonb)
||jsonb_build_object('message_text',_MESSAGE_TEXT)
||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL);
return _message;
END;
_message:= jsonb_build_object('status','complete','message','definition has been set');
return _message;
END;
$f$
language plpgsql;

View File

@ -13,7 +13,7 @@ BEGIN
BEGIN BEGIN
INSERT INTO INSERT INTO
tps.map_rm tps.map_rm (srce, target, regex, seq, hist)
SELECT SELECT
--data source --data source
_defn->>'srce' _defn->>'srce'
@ -22,7 +22,7 @@ BEGIN
--map definition --map definition
,_defn ,_defn
--map aggregation sequence --map aggregation sequence
,_defn->>'sequence' ,(_defn->>'sequence')::INTEGER
--history definition --history definition
,jsonb_build_object( ,jsonb_build_object(
'hist_defn',_defn 'hist_defn',_defn
@ -32,7 +32,7 @@ BEGIN
srce = _defn->>'srce' srce = _defn->>'srce'
,target = _defn->>'name' ,target = _defn->>'name'
,regex = _defn ,regex = _defn
,seq = _defn->>'sequence' ,seq = (_defn->>'sequence')::INTEGER
,hist = ,hist =
--the new definition going to position -0- --the new definition going to position -0-
jsonb_build_object( jsonb_build_object(

View File

@ -0,0 +1,27 @@
SELECT
*
FROM
tps.srce_map_def_set(
$$
{
"srce":"dcard",
"sequence":1,
"defn": [
{
"key": "{Description}",
"map": "y",
"flag": "g",
"field": "f20",
"regex": ".{1,20}",
"retain": "y"
}
],
"name": "First 20",
"where": [
{}
],
"function": "extract",
"description": "pull first 20 characters from description for mapping"
}
$$
)