diff --git a/deploy/reload/hunt/map.json b/deploy/reload/hunt/map.json index aa796be..a595267 100644 --- a/deploy/reload/hunt/map.json +++ b/deploy/reload/hunt/map.json @@ -17,7 +17,7 @@ "where": [ {} ], - "function": "replace", + "function": "extract", "description": "pull first 20 characters from description for mapping" }, "sequence": 1 diff --git a/deploy/setup.sql b/deploy/setup.sql index e8cd9d7..2cb3f5e 100644 --- a/deploy/setup.sql +++ b/deploy/setup.sql @@ -697,90 +697,97 @@ $f$; -------------------create trigger to map imported items------------------------------------------------------------------------------------------------------ -CREATE OR REPLACE FUNCTION tps.trans_insert_map() RETURNS TRIGGER AS $f$ +CREATE OR REPLACE FUNCTION tps.trans_insert_map() RETURNS TRIGGER +AS +$f$ + DECLARE + _cnt INTEGER; + BEGIN IF (TG_OP = 'INSERT') THEN + + WITH --------------------apply regex operations to transactions----------------------------------------------------------------------------------- rx AS ( - SELECT - t.srce, - t.id, - t.rec, - m.target, - m.seq, - regex->>'function' regex_function, - e.v ->> 'field' result_key_name, - e.v ->> 'key' target_json_path, - e.v ->> 'flag' regex_options_flag, - e.v->>'map' map_intention, - e.v->>'retain' retain_result, - e.v->>'regex' regex_expression, - e.rn target_item_number, - COALESCE(mt.rn,rp.rn,1) result_number, - mt.mt rx_match, - rp.rp rx_replace, - CASE e.v->>'map' - WHEN 'y' THEN - e.v->>'field' - ELSE - null - END map_key, - 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 - '{}'::jsonb - END - ELSE - NULL - END map_val, - CASE e.v->>'retain' - WHEN 'y' THEN - e.v->>'field' - ELSE - NULL - END retain_key, - CASE e.v->>'retain' - WHEN 'y' THEN - 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 - '{}'::jsonb - END - ELSE - NULL - END retain_val - FROM - tps.map_rm m - LEFT JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE - INNER JOIN new_table t ON - t.srce = m.srce AND - t.rec @> w.v - LEFT JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true - 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' - 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' - ORDER BY - t.id DESC, - m.target, - e.rn, - COALESCE(mt.rn,rp.rn,1) + SELECT + t.srce, + t.id, + t.rec, + m.target, + m.seq, + regex->'regex'->>'function' regex_function, + e.v ->> 'field' result_key_name, + e.v ->> 'key' target_json_path, + e.v ->> 'flag' regex_options_flag, + e.v->>'map' map_intention, + e.v->>'retain' retain_result, + e.v->>'regex' regex_expression, + e.rn target_item_number, + COALESCE(mt.rn,rp.rn,1) result_number, + mt.mt rx_match, + rp.rp rx_replace, + CASE e.v->>'map' + WHEN 'y' THEN + e.v->>'field' + ELSE + null + END map_key, + CASE e.v->>'map' + WHEN 'y' THEN + CASE regex->'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 + '{}'::jsonb + END + ELSE + NULL + END map_val, + CASE e.v->>'retain' + WHEN 'y' THEN + e.v->>'field' + ELSE + NULL + END retain_key, + CASE e.v->>'retain' + WHEN 'y' THEN + CASE regex->'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 + '{}'::jsonb + END + ELSE + NULL + END retain_val + FROM + tps.map_rm m + LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE + INNER JOIN new_table t ON + t.srce = m.srce AND + t.rec @> w.v + LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'defn') WITH ORDINALITY e(v, rn) ON true + 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' + 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' + ORDER BY + t.id DESC, + m.target, + e.rn, + COALESCE(mt.rn,rp.rn,1) ) --SELECT count(*) FROM rx LIMIT 100 @@ -903,7 +910,7 @@ CREATE OR REPLACE FUNCTION tps.trans_insert_map() RETURNS TRIGGER AS $f$ ) --SELECT agg_to_id.srce, agg_to_id.id, jsonb_pretty(agg_to_id.retain_val) , jsonb_pretty(agg_to_id.map) FROM agg_to_id ORDER BY id desc LIMIT 100 - + --create a complete list of all new inserts assuming some do not have maps (left join) ,join_all AS ( SELECT @@ -930,6 +937,7 @@ CREATE OR REPLACE FUNCTION tps.trans_insert_map() RETURNS TRIGGER AS $f$ join_all a WHERE t.id = a.id; + END IF; RETURN NULL; diff --git a/interface/import/map_trigger.sql b/interface/import/map_trigger.sql index 86f8304..6002dc1 100644 --- a/interface/import/map_trigger.sql +++ b/interface/import/map_trigger.sql @@ -12,83 +12,83 @@ $f$ --------------------apply regex operations to transactions----------------------------------------------------------------------------------- rx AS ( - SELECT - t.srce, - t.id, - t.rec, - m.target, - m.seq, - regex->>'function' regex_function, - e.v ->> 'field' result_key_name, - e.v ->> 'key' target_json_path, - e.v ->> 'flag' regex_options_flag, - e.v->>'map' map_intention, - e.v->>'retain' retain_result, - e.v->>'regex' regex_expression, - e.rn target_item_number, - COALESCE(mt.rn,rp.rn,1) result_number, - mt.mt rx_match, - rp.rp rx_replace, - CASE e.v->>'map' - WHEN 'y' THEN - e.v->>'field' - ELSE - null - END map_key, - 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 - '{}'::jsonb - END - ELSE - NULL - END map_val, - CASE e.v->>'retain' - WHEN 'y' THEN - e.v->>'field' - ELSE - NULL - END retain_key, - CASE e.v->>'retain' - WHEN 'y' THEN - 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 - '{}'::jsonb - END - ELSE - NULL - END retain_val - FROM - tps.map_rm m - LEFT JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE - INNER JOIN new_table t ON - t.srce = m.srce AND - t.rec @> w.v - LEFT JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true - 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' - 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' - ORDER BY - t.id DESC, - m.target, - e.rn, - COALESCE(mt.rn,rp.rn,1) + SELECT + t.srce, + t.id, + t.rec, + m.target, + m.seq, + regex->'regex'->>'function' regex_function, + e.v ->> 'field' result_key_name, + e.v ->> 'key' target_json_path, + e.v ->> 'flag' regex_options_flag, + e.v->>'map' map_intention, + e.v->>'retain' retain_result, + e.v->>'regex' regex_expression, + e.rn target_item_number, + COALESCE(mt.rn,rp.rn,1) result_number, + mt.mt rx_match, + rp.rp rx_replace, + CASE e.v->>'map' + WHEN 'y' THEN + e.v->>'field' + ELSE + null + END map_key, + CASE e.v->>'map' + WHEN 'y' THEN + CASE regex->'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 + '{}'::jsonb + END + ELSE + NULL + END map_val, + CASE e.v->>'retain' + WHEN 'y' THEN + e.v->>'field' + ELSE + NULL + END retain_key, + CASE e.v->>'retain' + WHEN 'y' THEN + CASE regex->'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 + '{}'::jsonb + END + ELSE + NULL + END retain_val + FROM + tps.map_rm m + LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'where') w(v) ON TRUE + INNER JOIN new_table t ON + t.srce = m.srce AND + t.rec @> w.v + LEFT JOIN LATERAL jsonb_array_elements(m.regex->'regex'->'defn') WITH ORDINALITY e(v, rn) ON true + 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' + 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' + ORDER BY + t.id DESC, + m.target, + e.rn, + COALESCE(mt.rn,rp.rn,1) ) --SELECT count(*) FROM rx LIMIT 100 diff --git a/interface/map_def/srce_map_def_set.sql b/interface/map_def/srce_map_def_set.sql index a752dac..62a7288 100644 --- a/interface/map_def/srce_map_def_set.sql +++ b/interface/map_def/srce_map_def_set.sql @@ -10,26 +10,43 @@ DECLARE BEGIN - BEGIN - - INSERT INTO - tps.map_rm (srce, target, regex, seq, hist) + WITH + ------------------------------------------stage rows to insert----------------------------------------------------- + stg AS ( SELECT --data source - ae.r->>'srce' + ae.r->>'srce' srce --map name - ,ae.r->>'name' + ,ae.r->>'name' target --map definition - ,ae.r + ,ae.r regex --map aggregation sequence - ,(ae.r->>'sequence')::INTEGER + ,(ae.r->>'sequence')::INTEGER seq --history definition ,jsonb_build_object( 'hist_defn',ae.r ,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz) - ) || '[]'::jsonb + ) || '[]'::jsonb hist + --determine if the rows are new or match + ,(m.regex->>'regex' = ae.r->>'regex')::BOOLEAN rebuild FROM jsonb_array_elements(_defn) ae(r) + LEFT OUTER JOIN tps.map_rm m ON + m.srce = ae.r->>'srce' + AND m.target = ae.t->>'name' + ) + ---------------------------------------do the upsert------------------------------------------------------------------- + ,ins AS ( + INSERT INTO + tps.map_rm (srce, target, regex, seq, hist) + SELECT + srce + ,target + ,regex + ,seq + ,hist + FROM + stg ON CONFLICT ON CONSTRAINT map_rm_pk DO UPDATE SET srce = excluded.srce ,target = excluded.target @@ -46,29 +63,48 @@ BEGIN 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; + ) + ) + ---------------------------get list of sources that had maps change-------------------------------------------------------- + , to_update AS ( + SELECT DISTINCT + srce + FROM + ins + WHERE + rebuild = TRUE + ) + --------------------------call the map overwrite for each source and return all the messages into message---------------- + /*the whole source must be overwritten because if an element is no longer returned it shoudl be wiped from the data*/ + SELECT + jsonb_agg(x.message) + INTO + _message + FROM + to_update + JOIN LATERAL tps.srce_map_overwrite(to_update.srce) AS x(message) ON TRUE; _message:= jsonb_build_object('status','complete','message','definition has been set'); return _message; + + 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; $f$ language plpgsql \ No newline at end of file diff --git a/interface/map_def/srce_map_def_set_single.sql b/interface/map_def/srce_map_def_set_single.sql new file mode 100644 index 0000000..c22c488 --- /dev/null +++ b/interface/map_def/srce_map_def_set_single.sql @@ -0,0 +1,98 @@ +CREATE OR REPLACE FUNCTION tps.srce_map_def_set_single(_defn jsonb, _rebuild BOOLEAN) RETURNS jsonb +AS +$f$ + +DECLARE + _message jsonb; + _MESSAGE_TEXT text; + _PG_EXCEPTION_DETAIL text; + _PG_EXCEPTION_HINT text; + +BEGIN + + ---------test if anythign is changing-------------------------------------------------------------------------------------------- + + IF _defn->'regex' = (SELECT regex->'regex' FROM tps.map_rm WHERE srce = _defn->>'srce' and target = _defn->>'name') THEN + _message:= + ( + $$ + { + "status":"complete", + "message":"map was not different no action taken" + } + $$::jsonb + ); + RETURN _message; + END IF; + + ---------do the rebuild----------------------------------------------------------------------------------------------------------- + + 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 = excluded.srce + ,target = excluded.target + ,regex = excluded.regex + ,seq = excluded.seq + ,hist = + --the new definition going to position -0- + jsonb_build_object( + 'hist_defn',excluded.regex + ,'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) + ); + + --------------if rebuild was flag call the rebuild-------------------------------------------------------------------------------- + + IF _rebuild THEN + SELECT + x.message||'{"step":"overwrite maps in tps.trans"}'::jsonb + INTO + _message + FROM + tps.srce_map_overwrite(_defn->>'srce') as X(message); + END IF; + + 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 definition" + } + $$::jsonb) + ||jsonb_build_object('message_text',_MESSAGE_TEXT) + ||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL); + return _message; + + + +END; +$f$ +language plpgsql \ No newline at end of file diff --git a/interface/map_values/srce_map_overwrite.sql b/interface/map_values/srce_map_overwrite.sql index f11841f..408f8a9 100644 --- a/interface/map_values/srce_map_overwrite.sql +++ b/interface/map_values/srce_map_overwrite.sql @@ -18,7 +18,7 @@ BEGIN t.rec, m.target, m.seq, - regex->>'function' regex_function, + regex->'regex'->>'function' regex_function, e.v ->> 'field' result_key_name, e.v ->> 'key' target_json_path, e.v ->> 'flag' regex_options_flag, @@ -37,7 +37,7 @@ BEGIN END map_key, CASE e.v->>'map' WHEN 'y' THEN - CASE regex->>'function' + CASE regex->'regex'->>'function' WHEN 'extract' THEN CASE WHEN array_upper(mt.mt,1)=1 THEN to_json(mt.mt[1]) @@ -59,7 +59,7 @@ BEGIN END retain_key, CASE e.v->>'retain' WHEN 'y' THEN - CASE regex->>'function' + CASE regex->'regex'->>'function' WHEN 'extract' THEN CASE WHEN array_upper(mt.mt,1)=1 THEN to_json(trim(mt.mt[1])) @@ -75,15 +75,15 @@ BEGIN END retain_val FROM tps.map_rm m - LEFT 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 INNER JOIN tps.trans t ON t.srce = m.srce AND t.rec @> w.v - LEFT 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 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' 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 --t.allj IS NULL t.srce = _srce