develop map values set

This commit is contained in:
Paul Trowbridge 2018-05-25 10:09:12 -04:00
parent 64d3a1f310
commit cdba942e9e
3 changed files with 269 additions and 106 deletions

View File

@ -154,6 +154,7 @@ ALTER TABLE ONLY tps.trans
-------------create functions------------------------------------------------------------------------------------------------------------------------ -------------create functions------------------------------------------------------------------------------------------------------------------------
-----set source -----set source
DROP FUNCTION IF EXISTS tps.srce_set(jsonb);
CREATE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb CREATE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb
AS AS
$f$ $f$
@ -222,6 +223,7 @@ $f$
LANGUAGE plpgsql; LANGUAGE plpgsql;
-----generate sql to create select based on schema -----generate sql to create select based on schema
DROP FUNCTION IF EXISTS tps.build_srce_view_sql(text, text);
CREATE FUNCTION tps.build_srce_view_sql(_srce text, _schema text) RETURNS TEXT CREATE FUNCTION tps.build_srce_view_sql(_srce text, _schema text) RETURNS TEXT
AS AS
$f$ $f$
@ -353,7 +355,7 @@ CREATE AGGREGATE tps.jsonb_concat_obj(jsonb) (
); );
DROP FUNCTION IF EXISTS tps.report_unmapped; DROP FUNCTION IF EXISTS tps.report_unmapped(text);
CREATE FUNCTION tps.report_unmapped(_srce text) RETURNS TABLE CREATE FUNCTION tps.report_unmapped(_srce text) RETURNS TABLE
( (
source text, source text,
@ -1055,7 +1057,7 @@ EXCEPTION WHEN OTHERS THEN
return _message; return _message;
END; END;
$f$ $f$
LANGUAGE plpgsql LANGUAGE plpgsql;
---------------overwrite maps-------------------------------------------------------------------------------------------------------------- ---------------overwrite maps--------------------------------------------------------------------------------------------------------------
@ -1315,3 +1317,71 @@ EXCEPTION WHEN OTHERS THEN
END; END;
$f$ $f$
language plpgsql; language plpgsql;
---------------------set map values from json array of json objects-----------------------------------------------------
DROP FUNCTION IF EXISTS tps.map_rv_set;
CREATE OR REPLACE FUNCTION tps.map_rv_set(_defn jsonb) RETURNS jsonb
AS
$f$
DECLARE
_message jsonb;
_MESSAGE_TEXT text;
_PG_EXCEPTION_DETAIL text;
_PG_EXCEPTION_HINT text;
BEGIN
INSERT INTO
tps.map_rv (srce, target, retval, map, hist)
SELECT
r.source
,r.map
,r.ret_val
,r.mapped
,jsonb_build_object(
'hist_defn',mapped
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
) || '[]'::jsonb
FROM
JSONB_ARRAY_ELEMENTS(_defn) WITH ORDINALITY ae(r,s)
JOIN LATERAL jsonb_to_record(ae.r) r(source TEXT,map TEXT, ret_val jsonb, mapped jsonb) ON TRUE
ON CONFLICT ON CONSTRAINT map_rv_pk DO UPDATE
SET
map = excluded.map
,hist =
--the new definition going to position -0-
jsonb_build_object(
'hist_defn',excluded.map
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
)
--the previous definition, set upper bound of effective range which was previously null
|| jsonb_set(
map_rv.hist
,'{0,effective,1}'::text[]
,to_jsonb(CURRENT_TIMESTAMP)
);
-------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$
LANGUAGE plpgsql;

View File

@ -1,31 +1,64 @@
INSERT INTO DROP FUNCTION IF EXISTS tps.map_rv_set;
tps.map_rv (srce, target, retval, map, hist) CREATE OR REPLACE FUNCTION tps.map_rv_set(_defn jsonb) RETURNS jsonb
SELECT AS
r.source $f$
,r.map DECLARE
,r.ret_val _message jsonb;
,r.mapped _MESSAGE_TEXT text;
,jsonb_build_object( _PG_EXCEPTION_DETAIL text;
'hist_defn',mapped _PG_EXCEPTION_HINT text;
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz) BEGIN
) || '[]'::jsonb INSERT INTO
FROM tps.map_rv (srce, target, retval, map, hist)
JSONB_ARRAY_ELEMENTS( SELECT
$$[{"source":"DCARD","map":"First 20","ret_val":{"f20":"DISCOUNT DRUG MART 3"},"mapped":{"party":"Discount Drug Mart","reason":"groceries"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"TARGET STOW OH"},"mapped":{"party":"Target","reason":"groceries"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"WALMART GROCERY 800-"},"mapped":{"party":"Walmart","reason":"groceries"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"CIRCLE K 05416 STOW "},"mapped":{"party":"Circle K","reason":"gasoline"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"TARGET.COM * 800-591"},"mapped":{"party":"Target","reason":"home supplies"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"ACME NO. 17 STOW OH"},"mapped":{"party":"Acme","reason":"groceries"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"AT&T *PAYMENT 800-28"},"mapped":{"party":"AT&T","reason":"internet"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"AUTOZONE #0722 STOW "},"mapped":{"party":"Autozone","reason":"auto maint"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"BESTBUYCOM8055267948"},"mapped":{"party":"BestBuy","reason":"home supplies"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"BUFFALO WILD WINGS K"},"mapped":{"party":"Buffalo Wild Wings","reason":"restaurante"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"CASHBACK BONUS REDEM"},"mapped":{"party":"Discover Card","reason":"financing"}},{"source":"DCARD","map":"First 20","ret_val":{"f20":"CLE CLINIC PT PMTS 2"},"mapped":{"party":"Cleveland Clinic","reason":"medical"}}]$$::JSONB r.source
) WITH ORDINALITY ae(r,s) ,r.map
JOIN LATERAL jsonb_to_record(ae.r) r(source TEXT,map TEXT, ret_val jsonb, mapped jsonb) ON TRUE ,r.ret_val
ON CONFLICT ON CONSTRAINT map_rv_pk DO UPDATE ,r.mapped
SET ,jsonb_build_object(
map = excluded.map 'hist_defn',mapped
,hist =
--the new definition going to position -0-
jsonb_build_object(
'hist_defn',excluded.map
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz) ,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
) ) || '[]'::jsonb
--the previous definition, set upper bound of effective range which was previously null FROM
|| jsonb_set( JSONB_ARRAY_ELEMENTS(_defn) WITH ORDINALITY ae(r,s)
map_rv.hist JOIN LATERAL jsonb_to_record(ae.r) r(source TEXT,map TEXT, ret_val jsonb, mapped jsonb) ON TRUE
,'{0,effective,1}'::text[] ON CONFLICT ON CONSTRAINT map_rv_pk DO UPDATE
,to_jsonb(CURRENT_TIMESTAMP) SET
); map = excluded.map
,hist =
--the new definition going to position -0-
jsonb_build_object(
'hist_defn',excluded.map
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
)
--the previous definition, set upper bound of effective range which was previously null
|| jsonb_set(
map_rv.hist
,'{0,effective,1}'::text[]
,to_jsonb(CURRENT_TIMESTAMP)
);
-------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$
LANGUAGE plpgsql;

View File

@ -1,74 +1,134 @@
[ [
{ {
"source": "DCARD", "source": "dcard",
"map": "First 20", "map": "First 20",
"ret_val": { "f20": "DISCOUNT DRUG MART 3" }, "ret_val": {
"mapped": { "party": "Discount Drug Mart", "reason": "groceries" } "f20": "DISCOUNT DRUG MART 3"
}, },
{ "mapped": {
"source": "DCARD", "party": "Discount Drug Mart",
"map": "First 20", "reason": "groceries"
"ret_val": { "f20": "TARGET STOW OH" }, }
"mapped": { "party": "Target", "reason": "groceries" } },
}, {
{ "source": "dcard",
"source": "DCARD", "map": "First 20",
"map": "First 20", "ret_val": {
"ret_val": { "f20": "WALMART GROCERY 800-" }, "f20": "TARGET STOW OH"
"mapped": { "party": "Walmart", "reason": "groceries" } },
}, "mapped": {
{ "party": "Target",
"source": "DCARD", "reason": "groceries"
"map": "First 20", }
"ret_val": { "f20": "CIRCLE K 05416 STOW " }, },
"mapped": { "party": "Circle K", "reason": "gasoline" } {
}, "source": "dcard",
{ "map": "First 20",
"source": "DCARD", "ret_val": {
"map": "First 20", "f20": "WALMART GROCERY 800-"
"ret_val": { "f20": "TARGET.COM * 800-591" }, },
"mapped": { "party": "Target", "reason": "home supplies" } "mapped": {
}, "party": "Walmart",
{ "reason": "groceries"
"source": "DCARD", }
"map": "First 20", },
"ret_val": { "f20": "ACME NO. 17 STOW OH" }, {
"mapped": { "party": "Acme", "reason": "groceries" } "source": "dcard",
}, "map": "First 20",
{ "ret_val": {
"source": "DCARD", "f20": "CIRCLE K 05416 STOW "
"map": "First 20", },
"ret_val": { "f20": "AT&T *PAYMENT 800-28" }, "mapped": {
"mapped": { "party": "AT&T", "reason": "internet" } "party": "Circle K",
}, "reason": "gasoline"
{ }
"source": "DCARD", },
"map": "First 20", {
"ret_val": { "f20": "AUTOZONE #0722 STOW " }, "source": "dcard",
"mapped": { "party": "Autozone", "reason": "auto maint" } "map": "First 20",
}, "ret_val": {
{ "f20": "TARGET.COM * 800-591"
"source": "DCARD", },
"map": "First 20", "mapped": {
"ret_val": { "f20": "BESTBUYCOM8055267948" }, "party": "Target",
"mapped": { "party": "BestBuy", "reason": "home supplies" } "reason": "home supplies"
}, }
{ },
"source": "DCARD", {
"map": "First 20", "source": "dcard",
"ret_val": { "f20": "BUFFALO WILD WINGS K" }, "map": "First 20",
"mapped": { "party": "Buffalo Wild Wings", "reason": "restaurante" } "ret_val": {
}, "f20": "ACME NO. 17 STOW OH"
{ },
"source": "DCARD", "mapped": {
"map": "First 20", "party": "Acme",
"ret_val": { "f20": "CASHBACK BONUS REDEM" }, "reason": "groceries"
"mapped": { "party": "Discover Card", "reason": "financing" } }
}, },
{ {
"source": "DCARD", "source": "dcard",
"map": "First 20", "map": "First 20",
"ret_val": { "f20": "CLE CLINIC PT PMTS 2" }, "ret_val": {
"mapped": { "party": "Cleveland Clinic", "reason": "medical" } "f20": "AT&T *PAYMENT 800-28"
} },
"mapped": {
"party": "AT&T",
"reason": "internet"
}
},
{
"source": "dcard",
"map": "First 20",
"ret_val": {
"f20": "AUTOZONE #0722 STOW "
},
"mapped": {
"party": "Autozone",
"reason": "auto maint"
}
},
{
"source": "dcard",
"map": "First 20",
"ret_val": {
"f20": "BESTBUYCOM8055267948"
},
"mapped": {
"party": "BestBuy",
"reason": "home supplies"
}
},
{
"source": "dcard",
"map": "First 20",
"ret_val": {
"f20": "BUFFALO WILD WINGS K"
},
"mapped": {
"party": "Buffalo Wild Wings",
"reason": "restaurante"
}
},
{
"source": "dcard",
"map": "First 20",
"ret_val": {
"f20": "CASHBACK BONUS REDEM"
},
"mapped": {
"party": "Discover Card",
"reason": "financing"
}
},
{
"source": "dcard",
"map": "First 20",
"ret_val": {
"f20": "CLE CLINIC PT PMTS 2"
},
"mapped": {
"party": "Cleveland Clinic",
"reason": "medical"
}
}
] ]