Merge pull request #34 from fleetside72/stop_dup

include map set checking and change json def for map def
This commit is contained in:
fleetside72 2018-06-12 22:23:14 -04:00 committed by GitHub
commit db5f3d6133
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 334 additions and 192 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;

View File

@ -12,83 +12,83 @@ $f$
--------------------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

View File

@ -10,26 +10,43 @@ DECLARE
BEGIN BEGIN
BEGIN WITH
------------------------------------------stage rows to insert-----------------------------------------------------
INSERT INTO stg AS (
tps.map_rm (srce, target, regex, seq, hist)
SELECT SELECT
--data source --data source
ae.r->>'srce' ae.r->>'srce' srce
--map name --map name
,ae.r->>'name' ,ae.r->>'name' target
--map definition --map definition
,ae.r ,ae.r regex
--map aggregation sequence --map aggregation sequence
,(ae.r->>'sequence')::INTEGER ,(ae.r->>'sequence')::INTEGER seq
--history definition --history definition
,jsonb_build_object( ,jsonb_build_object(
'hist_defn',ae.r 'hist_defn',ae.r
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz) ,'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 FROM
jsonb_array_elements(_defn) ae(r) 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 ON CONFLICT ON CONSTRAINT map_rm_pk DO UPDATE SET
srce = excluded.srce srce = excluded.srce
,target = excluded.target ,target = excluded.target
@ -46,29 +63,48 @@ BEGIN
map_rm.hist map_rm.hist
,'{0,effective,1}'::text[] ,'{0,effective,1}'::text[]
,to_jsonb(CURRENT_TIMESTAMP) ,to_jsonb(CURRENT_TIMESTAMP)
); )
)
EXCEPTION WHEN OTHERS THEN ---------------------------get list of sources that had maps change--------------------------------------------------------
, to_update AS (
GET STACKED DIAGNOSTICS SELECT DISTINCT
_MESSAGE_TEXT = MESSAGE_TEXT, srce
_PG_EXCEPTION_DETAIL = PG_EXCEPTION_DETAIL, FROM
_PG_EXCEPTION_HINT = PG_EXCEPTION_HINT; ins
_message:= WHERE
($$ rebuild = TRUE
{ )
"status":"fail", --------------------------call the map overwrite for each source and return all the messages into message----------------
"message":"error setting definition" /*the whole source must be overwritten because if an element is no longer returned it shoudl be wiped from the data*/
} SELECT
$$::jsonb) jsonb_agg(x.message)
||jsonb_build_object('message_text',_MESSAGE_TEXT) INTO
||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL); _message
return _message; FROM
END; 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'); _message:= jsonb_build_object('status','complete','message','definition has been set');
return _message; 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; END;
$f$ $f$
language plpgsql language plpgsql

View File

@ -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

View File

@ -18,7 +18,7 @@ BEGIN
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,
@ -37,7 +37,7 @@ BEGIN
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])
@ -59,7 +59,7 @@ BEGIN
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]))
@ -75,15 +75,15 @@ BEGIN
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 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
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'
WHERE WHERE
--t.allj IS NULL --t.allj IS NULL
t.srce = _srce t.srce = _srce