include mods to mapping function in initial deploy sql

This commit is contained in:
Paul Trowbridge 2018-06-12 22:07:31 -04:00
parent 13929a6e32
commit 8c2936ee54
2 changed files with 88 additions and 80 deletions

View File

@ -17,7 +17,7 @@
"where": [ "where": [
{} {}
], ],
"function": "replace", "function": "extract",
"description": "pull first 20 characters from description for mapping" "description": "pull first 20 characters from description for mapping"
}, },
"sequence": 1 "sequence": 1

View File

@ -697,90 +697,97 @@ $f$;
-------------------create trigger to map imported items------------------------------------------------------------------------------------------------------ -------------------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 BEGIN
IF (TG_OP = 'INSERT') THEN IF (TG_OP = 'INSERT') THEN
WITH 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,
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' 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])
ELSE array_to_json(mt.mt) ELSE array_to_json(mt.mt)
END::jsonb END::jsonb
WHEN 'replace' THEN WHEN 'replace' THEN
to_jsonb(rp.rp) to_jsonb(rp.rp)
ELSE ELSE
'{}'::jsonb '{}'::jsonb
END END
ELSE ELSE
NULL NULL
END map_val, END map_val,
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,
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]))
ELSE array_to_json(mt.mt) ELSE array_to_json(mt.mt)
END::jsonb END::jsonb
WHEN 'replace' THEN WHEN 'replace' THEN
to_jsonb(rtrim(rp.rp)) to_jsonb(rtrim(rp.rp))
ELSE ELSE
'{}'::jsonb '{}'::jsonb
END END
ELSE ELSE
NULL NULL
END retain_val END retain_val
FROM FROM
tps.map_rm m 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 new_table t ON INNER JOIN new_table t ON
t.srce = m.srce AND t.srce = m.srce AND
t.rec @> w.v 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 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 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'
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 count(*) FROM rx LIMIT 100 --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 --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) --create a complete list of all new inserts assuming some do not have maps (left join)
,join_all AS ( ,join_all AS (
SELECT SELECT
@ -930,6 +937,7 @@ CREATE OR REPLACE FUNCTION tps.trans_insert_map() RETURNS TRIGGER AS $f$
join_all a join_all a
WHERE WHERE
t.id = a.id; t.id = a.id;
END IF; END IF;
RETURN NULL; RETURN NULL;