include changes to json schema in main sql function setup

This commit is contained in:
Paul Trowbridge 2018-06-16 08:30:33 -04:00
parent bcdb728c3d
commit 203fabb2c6

View File

@ -439,7 +439,7 @@ CREATE AGGREGATE tps.jsonb_concat_obj(jsonb) (
); );
DROP FUNCTION IF EXISTS tps.report_unmapped(text); DROP FUNCTION IF EXISTS tps.report_unmapped;
CREATE FUNCTION tps.report_unmapped(_srce text) RETURNS TABLE CREATE FUNCTION tps.report_unmapped(_srce text) RETURNS TABLE
( (
source text, source text,
@ -463,13 +463,13 @@ WITH
--------------------apply regex operations to transactions--------------------------------------------------------------------------------- --------------------apply regex operations to transactions---------------------------------------------------------------------------------
rx AS ( rx AS (
SELECT SELECT
t.srce, t.srce,
t.id, t.id,
t.rec, t.rec,
m.target, m.target,
m.seq, m.seq,
regex->>'function' regex_function, regex->'regex'->>'function' regex_function,
e.v ->> 'field' result_key_name, e.v ->> 'field' result_key_name,
e.v ->> 'key' target_json_path, e.v ->> 'key' target_json_path,
e.v ->> 'flag' regex_options_flag, e.v ->> 'flag' regex_options_flag,
@ -480,17 +480,15 @@ SELECT
COALESCE(mt.rn,rp.rn,1) result_number, COALESCE(mt.rn,rp.rn,1) result_number,
mt.mt rx_match, mt.mt rx_match,
rp.rp rx_replace, rp.rp rx_replace,
--------------------------json key name assigned to return value-----------------------------------------------------------------------
CASE e.v->>'map' CASE e.v->>'map'
WHEN 'y' THEN WHEN 'y' THEN
e.v->>'field' e.v->>'field'
ELSE ELSE
null null
END map_key, END map_key,
--------------------------json value resulting from regular expression-----------------------------------------------------------------
CASE e.v->>'map' CASE e.v->>'map'
WHEN 'y' THEN WHEN 'y' THEN
CASE regex->>'function' CASE regex->'regex'->>'function'
WHEN 'extract' THEN WHEN 'extract' THEN
CASE WHEN array_upper(mt.mt,1)=1 CASE WHEN array_upper(mt.mt,1)=1
THEN to_json(mt.mt[1]) THEN to_json(mt.mt[1])
@ -504,17 +502,15 @@ SELECT
ELSE ELSE
NULL NULL
END map_val, END map_val,
--------------------------flag for if retruned regex result is stored as a new part of the final json output---------------------------
CASE e.v->>'retain' CASE e.v->>'retain'
WHEN 'y' THEN WHEN 'y' THEN
e.v->>'field' e.v->>'field'
ELSE ELSE
NULL NULL
END retain_key, END retain_key,
--------------------------push regex result into json object---------------------------------------------------------------------------
CASE e.v->>'retain' CASE e.v->>'retain'
WHEN 'y' THEN WHEN 'y' THEN
CASE regex->>'function' CASE regex->'regex'->>'function'
WHEN 'extract' THEN WHEN 'extract' THEN
CASE WHEN array_upper(mt.mt,1)=1 CASE WHEN array_upper(mt.mt,1)=1
THEN to_json(trim(mt.mt[1])) THEN to_json(trim(mt.mt[1]))
@ -528,36 +524,34 @@ SELECT
ELSE ELSE
NULL NULL
END retain_val END retain_val
FROM FROM
--------------------------start with all regex maps------------------------------------------------------------------------------------ --------------------------start with all regex maps------------------------------------------------------------------------------------
tps.map_rm m tps.map_rm m
--------------------------isolate matching basis to limit map to only look at certain json--------------------------------------------- --------------------------isolate matching basis to limit map to only look at certain json---------------------------------------------
JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE
--------------------------break out array of regluar expressions in the map------------------------------------------------------------
JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true
--------------------------join to main transaction table but only certain key/values are included-------------------------------------- --------------------------join to main transaction table but only certain key/values are included--------------------------------------
INNER JOIN tps.trans t ON INNER JOIN tps.trans t ON
t.srce = m.srce AND t.srce = m.srce AND
t.rec @> w.v t.rec @> w.v
--------------------------break out array of regluar expressions in the map------------------------------------------------------------
LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'defn') WITH ORDINALITY e(v, rn) ON true
--------------------------each regex references a path to the target value, extract the target from the reference and do regex--------- --------------------------each regex references a path to the target value, extract the target from the reference and do regex---------
LEFT JOIN LATERAL regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text,COALESCE(e.v ->> 'flag','')) WITH ORDINALITY mt(mt, rn) ON LEFT JOIN LATERAL regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text,COALESCE(e.v ->> 'flag','')) WITH ORDINALITY mt(mt, rn) ON
m.regex->>'function' = 'extract' m.regex->'regex'->>'function' = 'extract'
--------------------------same as above but for a replacement type function------------------------------------------------------------ --------------------------same as above but for a replacement type function------------------------------------------------------------
LEFT JOIN LATERAL regexp_replace(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text, e.v ->> 'replace'::text,e.v ->> 'flag') WITH ORDINALITY rp(rp, rn) ON LEFT JOIN LATERAL regexp_replace(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text, e.v ->> 'replace'::text,e.v ->> 'flag') WITH ORDINALITY rp(rp, rn) ON
m.regex->>'function' = 'replace' m.regex->'regex'->>'function' = 'replace'
WHERE WHERE
--t.allj IS NULL --t.allj IS NULL
t.srce = _srce AND t.srce = _srce AND
e.v @> '{"map":"y"}'::jsonb e.v @> '{"map":"y"}'::jsonb
--rec @> '{"Transaction":"ACH Credits","Transaction":"ACH Debits"}' --rec @> '{"Transaction":"ACH Credits","Transaction":"ACH Debits"}'
--rec @> '{"Description":"CHECK 93013270 086129935"}'::jsonb --rec @> '{"Description":"CHECK 93013270 086129935"}'::jsonb
/* ORDER BY
ORDER BY
t.id DESC, t.id DESC,
m.target, m.target,
e.rn, e.rn,
COALESCE(mt.rn,rp.rn,1) COALESCE(mt.rn,rp.rn,1)
*/
) )
--SELECT * FROM rx LIMIT 100 --SELECT * FROM rx LIMIT 100
@ -1733,15 +1727,27 @@ $f$;
------------------------------test regex with all original records-------------------------------------------------------------- ------------------------------test regex with all original records--------------------------------------------------------------
DROP FUNCTION IF EXISTS tps.test_regex_rec(jsonb); DROP FUNCTION IF EXISTS tps.report_unmapped_recs;
CREATE FUNCTION tps.test_regex_recs(_defn jsonb) RETURNS jsonb CREATE FUNCTION tps.report_unmapped_recs(_srce text) RETURNS TABLE
(
source text,
map text,
ret_val jsonb,
"count" bigint,
recs jsonb
)
LANGUAGE plpgsql LANGUAGE plpgsql
AS AS
$f$ $f$
DECLARE
_rslt jsonb;
BEGIN BEGIN
/*
first get distinct target json values
then apply regex
*/
RETURN QUERY
WITH WITH
--------------------apply regex operations to transactions--------------------------------------------------------------------------------- --------------------apply regex operations to transactions---------------------------------------------------------------------------------
@ -1810,21 +1816,27 @@ rx AS (
END retain_val END retain_val
FROM FROM
--------------------------start with all regex maps------------------------------------------------------------------------------------ --------------------------start with all regex maps------------------------------------------------------------------------------------
(SELECT _defn->>'srce' srce, _defn->>'name' target, _defn regex, (_defn->>'sequence')::numeric seq) m tps.map_rm m
--------------------------isolate matching basis to limit map to only look at certain json--------------------------------------------- --------------------------isolate matching basis to limit map to only look at certain json---------------------------------------------
LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE
--------------------------break out array of regluar expressions in the map------------------------------------------------------------
LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'defn') WITH ORDINALITY e(v, rn) ON true
--------------------------join to main transaction table but only certain key/values are included-------------------------------------- --------------------------join to main transaction table but only certain key/values are included--------------------------------------
INNER JOIN tps.trans t ON INNER JOIN tps.trans t ON
t.srce = m.srce AND t.srce = m.srce AND
t.rec @> w.v t.rec @> w.v
--------------------------break out array of regluar expressions in the map------------------------------------------------------------
LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'defn') WITH ORDINALITY e(v, rn) ON true
--------------------------each regex references a path to the target value, extract the target from the reference and do regex--------- --------------------------each regex references a path to the target value, extract the target from the reference and do regex---------
LEFT JOIN LATERAL regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text,COALESCE(e.v ->> 'flag','')) WITH ORDINALITY mt(mt, rn) ON LEFT JOIN LATERAL regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text,COALESCE(e.v ->> 'flag','')) WITH ORDINALITY mt(mt, rn) ON
m.regex->'regex'->>'function' = 'extract' m.regex->'regex'->>'function' = 'extract'
--------------------------same as above but for a replacement type function------------------------------------------------------------ --------------------------same as above but for a replacement type function------------------------------------------------------------
LEFT JOIN LATERAL regexp_replace(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text, e.v ->> 'replace'::text,e.v ->> 'flag') WITH ORDINALITY rp(rp, rn) ON LEFT JOIN LATERAL regexp_replace(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text, e.v ->> 'replace'::text,e.v ->> 'flag') WITH ORDINALITY rp(rp, rn) ON
m.regex->'regex'->>'function' = 'replace' m.regex->'regex'->>'function' = 'replace'
WHERE
--t.allj IS NULL
t.srce = _srce AND
e.v @> '{"map":"y"}'::jsonb
--rec @> '{"Transaction":"ACH Credits","Transaction":"ACH Debits"}'
--rec @> '{"Description":"CHECK 93013270 086129935"}'::jsonb
ORDER BY ORDER BY
t.id DESC, t.id DESC,
m.target, m.target,
@ -1915,6 +1927,8 @@ GROUP BY
,seq ,seq
,map_intention ,map_intention
) )
, agg_to_ret AS ( , agg_to_ret AS (
SELECT SELECT
srce srce
@ -1935,12 +1949,38 @@ GROUP BY
,map_val ,map_val
,retain_val ,retain_val
) )
, link_map AS (
SELECT SELECT
jsonb_agg(row_to_json(agg_to_ret)::jsonb) a.srce
INTO ,a.target
_rslt ,a.seq
,a.map_intention
,a.map_val
,a."count"
,a.rec
,a.retain_val
,v.map mapped_val
FROM FROM
agg_to_ret; agg_to_ret a
RETURN _rslt; LEFT OUTER JOIN tps.map_rv v ON
v.srce = a.srce AND
v.target = a.target AND
v.retval = a.map_val
)
SELECT
l.srce
,l.target
,l.map_val
,l."count"
,l.rec
FROM
link_map l
WHERE
l.mapped_val IS NULL
ORDER BY
l.srce
,l.target
,l."count" desc;
END; END;
$f$; $f$