2017-10-19 17:39:52 -04:00
WITH
--------------------apply regex operations to transactions-----------------------------------------------------------------------------------
rx AS (
SELECT
m.srce,
m.target,
t.id,
2017-10-20 10:09:55 -04:00
t.rec,
2017-10-19 17:39:52 -04:00
jsonb_build_object(
e.v ->> 'key',
(t.rec #> ((e.v ->> 'key')::text[]))
) AS rkey,
2017-10-25 16:28:42 -04:00
CASE regex->>'map'
WHEN 'yes' THEN
jsonb_build_object(
e.v->>'field',
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
'{}'::jsonb
END retval,
CASE e.v->>'retain'
WHEN 'y' THEN
jsonb_build_object(
e.v->>'field',
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
'{}'::jsonb
END retain,
m.seq
2017-10-19 17:39:52 -04:00
FROM
tps.map_rm m
LEFT JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE
2017-10-25 16:28:42 -04:00
INNER JOIN tps.trans t ON
2017-10-19 17:39:52 -04:00
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
2017-10-25 16:28:42 -04:00
LEFT JOIN LATERAL regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text) 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'::text) WITH ORDINALITY rp(rp, rn) ON
m.regex->>'function' = 'replace'
2017-10-19 17:39:52 -04:00
WHERE
2017-10-20 10:09:55 -04:00
t.map IS NULL
2017-10-19 17:39:52 -04:00
ORDER BY
2017-10-25 16:28:42 -04:00
t.id DESC
2017-10-19 17:39:52 -04:00
),
----------aggregate regex back to the target level (may be several targets per row)---------------------------------------------------------------
agg_rx AS (
SELECT
rx.srce,
rx.target,
rx.id,
2017-10-20 10:09:55 -04:00
rx.rec,
2017-10-19 17:39:52 -04:00
tps.jsonb_concat_obj(rx.rkey) rkey,
tps.jsonb_concat_obj(rx.retval) AS retval,
2017-10-25 16:28:42 -04:00
tps.jsonb_concat_obj(rx.retain) AS retain,
rx.seq
2017-10-19 17:39:52 -04:00
FROM
--unwrap json instruction and apply regex using a count per original line for re-aggregation
--need to look at integrating regex option like 'g' that would then need aggegated back as an array, or adding the ordinality number to the title
rx
GROUP BY
rx.srce,
rx.target,
rx.id,
2017-10-20 10:09:55 -04:00
rx.rec,
2017-10-19 17:39:52 -04:00
rx.seq
)
-------------aggregate all targets back to row level (id)------------------------------------------------------------------------------------------------
2017-10-20 10:09:55 -04:00
,agg_orig AS (
2017-10-19 17:39:52 -04:00
SELECT
u.srce,
u.id,
2017-10-20 10:09:55 -04:00
u.rec,
2017-10-19 17:39:52 -04:00
string_agg(u.target,',') target,
2017-10-25 16:28:42 -04:00
tps.jsonb_concat_obj(u.retval) retval,
tps.jsonb_concat_obj(u.retain) retain,
tps.jsonb_concat_obj(coalesce(v.map,'{}'::jsonb) ORDER BY seq ) map
2017-10-19 17:39:52 -04:00
FROM
--re-aggregate return values and explude any records where one or more regex failed with a null result
agg_rx u
2017-10-25 16:28:42 -04:00
LEFT OUTER JOIN tps.map_rv v ON
2017-10-19 17:39:52 -04:00
v.target = u.target AND
v.srce = u.srce AND
v.retval <@ u.retval
GROUP BY
u.srce,
2017-10-20 10:09:55 -04:00
u.id,
u.rec
)
UPDATE
tps.trans t
SET
2017-10-25 16:28:42 -04:00
map = o.map,
parse = o.retain
2017-10-20 10:09:55 -04:00
FROM
agg_orig o
WHERE
2017-10-25 16:28:42 -04:00
o.id = t.id