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,101 +23,95 @@ 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,
e.v->>'map' map_intention, e.v->>'map' map_intention,
e.v->>'retain' retain_result, e.v->>'retain' retain_result,
e.v->>'regex' regex_expression, e.v->>'regex' regex_expression,
e.rn target_item_number, e.rn target_item_number,
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, CASE e.v->>'map'
--------------------------json value resulting from regular expression----------------------------------------------------------------- WHEN 'y' THEN
CASE e.v->>'map' CASE regex->'regex'->>'function'
WHEN 'y' THEN WHEN 'extract' THEN
CASE regex->>'function' CASE WHEN array_upper(mt.mt,1)=1
WHEN 'extract' THEN THEN to_json(mt.mt[1])
CASE WHEN array_upper(mt.mt,1)=1 ELSE array_to_json(mt.mt)
THEN to_json(mt.mt[1]) END::jsonb
ELSE array_to_json(mt.mt) WHEN 'replace' THEN
END::jsonb to_jsonb(rp.rp)
WHEN 'replace' THEN ELSE
to_jsonb(rp.rp) '{}'::jsonb
ELSE END
'{}'::jsonb ELSE
END NULL
ELSE END map_val,
NULL CASE e.v->>'retain'
END map_val, WHEN 'y' THEN
--------------------------flag for if retruned regex result is stored as a new part of the final json output--------------------------- e.v->>'field'
CASE e.v->>'retain' ELSE
WHEN 'y' THEN NULL
e.v->>'field' END retain_key,
ELSE CASE e.v->>'retain'
NULL WHEN 'y' THEN
END retain_key, CASE regex->'regex'->>'function'
--------------------------push regex result into json object--------------------------------------------------------------------------- WHEN 'extract' THEN
CASE e.v->>'retain' CASE WHEN array_upper(mt.mt,1)=1
WHEN 'y' THEN THEN to_json(trim(mt.mt[1]))
CASE regex->>'function' ELSE array_to_json(mt.mt)
WHEN 'extract' THEN END::jsonb
CASE WHEN array_upper(mt.mt,1)=1 WHEN 'replace' THEN
THEN to_json(trim(mt.mt[1])) to_jsonb(rtrim(rp.rp))
ELSE array_to_json(mt.mt) ELSE
END::jsonb '{}'::jsonb
WHEN 'replace' THEN END
to_jsonb(rtrim(rp.rp)) ELSE
ELSE NULL
'{}'::jsonb END retain_val
END FROM
ELSE --------------------------start with all regex maps------------------------------------------------------------------------------------
NULL tps.map_rm m
END retain_val --------------------------isolate matching basis to limit map to only look at certain json---------------------------------------------
FROM LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE
--------------------------start with all regex maps------------------------------------------------------------------------------------ --------------------------join to main transaction table but only certain key/values are included--------------------------------------
tps.map_rm m INNER JOIN tps.trans t ON
--------------------------isolate matching basis to limit map to only look at certain json--------------------------------------------- t.srce = m.srce AND
JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE t.rec @> w.v
--------------------------break out array of regluar expressions in the map------------------------------------------------------------ --------------------------break out array of regluar expressions in the map------------------------------------------------------------
JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true 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-------------------------------------- --------------------------each regex references a path to the target value, extract the target from the reference and do regex---------
INNER JOIN tps.trans t 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
t.srce = m.srce AND m.regex->'regex'->>'function' = 'extract'
t.rec @> w.v --------------------------same as above but for a replacement type function------------------------------------------------------------
--------------------------each regex references a path to the target value, extract the target from the reference and do regex--------- 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_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' = 'replace'
m.regex->>'function' = 'extract' WHERE
--------------------------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
m.regex->>'function' = 'replace'
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,101 +24,95 @@ 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,
e.v->>'map' map_intention, e.v->>'map' map_intention,
e.v->>'retain' retain_result, e.v->>'retain' retain_result,
e.v->>'regex' regex_expression, e.v->>'regex' regex_expression,
e.rn target_item_number, e.rn target_item_number,
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
null
END map_key,
--------------------------json value resulting from regular expression-----------------------------------------------------------------
CASE e.v->>'map'
WHEN 'y' THEN
CASE regex->>'function'
WHEN 'extract' THEN
CASE WHEN array_upper(mt.mt,1)=1
THEN to_json(mt.mt[1])
ELSE array_to_json(mt.mt)
END::jsonb
WHEN 'replace' THEN
to_jsonb(rp.rp)
ELSE ELSE
'{}'::jsonb null
END END map_key,
ELSE CASE e.v->>'map'
NULL WHEN 'y' THEN
END map_val, CASE regex->'regex'->>'function'
--------------------------flag for if retruned regex result is stored as a new part of the final json output--------------------------- WHEN 'extract' THEN
CASE e.v->>'retain' CASE WHEN array_upper(mt.mt,1)=1
WHEN 'y' THEN THEN to_json(mt.mt[1])
e.v->>'field' ELSE array_to_json(mt.mt)
ELSE END::jsonb
NULL WHEN 'replace' THEN
END retain_key, to_jsonb(rp.rp)
--------------------------push regex result into json object--------------------------------------------------------------------------- ELSE
CASE e.v->>'retain' '{}'::jsonb
WHEN 'y' THEN END
CASE regex->>'function'
WHEN 'extract' THEN
CASE WHEN array_upper(mt.mt,1)=1
THEN to_json(trim(mt.mt[1]))
ELSE array_to_json(mt.mt)
END::jsonb
WHEN 'replace' THEN
to_jsonb(rtrim(rp.rp))
ELSE ELSE
'{}'::jsonb NULL
END END map_val,
ELSE CASE e.v->>'retain'
NULL WHEN 'y' THEN
END retain_val e.v->>'field'
FROM ELSE
--------------------------start with all regex maps------------------------------------------------------------------------------------ NULL
tps.map_rm m END retain_key,
--------------------------isolate matching basis to limit map to only look at certain json--------------------------------------------- CASE e.v->>'retain'
JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE WHEN 'y' THEN
--------------------------break out array of regluar expressions in the map------------------------------------------------------------ CASE regex->'regex'->>'function'
JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true WHEN 'extract' THEN
--------------------------join to main transaction table but only certain key/values are included-------------------------------------- CASE WHEN array_upper(mt.mt,1)=1
INNER JOIN tps.trans t ON THEN to_json(trim(mt.mt[1]))
t.srce = m.srce AND ELSE array_to_json(mt.mt)
t.rec @> w.v END::jsonb
--------------------------each regex references a path to the target value, extract the target from the reference and do regex--------- WHEN 'replace' THEN
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 to_jsonb(rtrim(rp.rp))
m.regex->>'function' = 'extract' ELSE
--------------------------same as above but for a replacement type function------------------------------------------------------------ '{}'::jsonb
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 END
m.regex->>'function' = 'replace' ELSE
WHERE NULL
--t.allj IS NULL END retain_val
t.srce = _srce AND FROM
e.v @> '{"map":"y"}'::jsonb --------------------------start with all regex maps------------------------------------------------------------------------------------
--rec @> '{"Transaction":"ACH Credits","Transaction":"ACH Debits"}' tps.map_rm m
--rec @> '{"Description":"CHECK 93013270 086129935"}'::jsonb --------------------------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
ORDER BY --------------------------join to main transaction table but only certain key/values are included--------------------------------------
t.id DESC, INNER JOIN tps.trans t ON
m.target, t.srce = m.srce AND
e.rn, t.rec @> w.v
COALESCE(mt.rn,rp.rn,1) --------------------------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---------
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'
--------------------------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
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
t.id DESC,
m.target,
e.rn,
COALESCE(mt.rn,rp.rn,1)
) )
--SELECT * FROM rx LIMIT 100 --SELECT * FROM rx LIMIT 100