update unampped listign to reflect change in json schema

This commit is contained in:
Paul Trowbridge 2018-06-16 01:15:24 -04:00
parent 3caa2b3887
commit bcdb728c3d
2 changed files with 171 additions and 204 deletions

View File

@ -1,24 +1,3 @@
CREATE OR REPLACE FUNCTION tps.jsonb_concat(
state jsonb,
concat jsonb)
RETURNS jsonb AS
$BODY$
BEGIN
--RAISE notice 'state is %', state;
--RAISE notice 'concat is %', concat;
RETURN state || concat;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
DROP AGGREGATE IF EXISTS tps.jsonb_concat_obj(jsonb);
CREATE AGGREGATE tps.jsonb_concat_obj(jsonb) (
SFUNC=tps.jsonb_concat,
STYPE=jsonb,
INITCOND='{}'
);
DROP FUNCTION IF EXISTS tps.report_unmapped; 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
@ -44,13 +23,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,
@ -61,17 +40,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])
@ -85,17 +62,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]))
@ -109,36 +84,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

View File

@ -24,13 +24,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,
@ -41,17 +41,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])
@ -65,17 +63,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]))
@ -89,36 +85,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