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-19 23:57:03 -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,
jsonb_build_object(
e.v->>'field',
CASE WHEN array_upper(mt.mt,1)=1
THEN to_json(mt.mt[1])
ELSE array_to_json(mt.mt)
END
) retval,
2017-10-19 18:02:52 -04:00
m.seq,
e.v->>'retain' retain
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
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 regexp_matches(t.rec #>> ((e.v ->> 'key')::text[]), e.v ->> 'regex'::text) WITH ORDINALITY mt(mt, rn) ON true
WHERE
2017-10-20 01:04:56 -04:00
t.map IS NULL
AND t.srce = 'DCARD'
2017-10-19 17:39:52 -04:00
ORDER BY
m.srce,
m.seq,
m.target,
t.id,
2017-10-19 23:57:03 -04:00
t.rec,
2017-10-19 17:39:52 -04:00
e.rn
),
----------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-19 23:57:03 -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-19 18:02:52 -04:00
tps.jsonb_concat_obj(CASE rx.retain WHEN 'y' THEN rx.retval ELSE '{}'::jsonb END) 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-19 23:57:03 -04:00
rx.rec,
2017-10-19 17:39:52 -04:00
rx.seq
)
-------------aggregate all targets back to row level (id)------------------------------------------------------------------------------------------------
2017-10-19 23:57:03 -04:00
,agg_orig AS (
2017-10-19 17:39:52 -04:00
SELECT
u.srce,
u.id,
2017-10-19 23:57:03 -04:00
u.rec,
2017-10-19 17:39:52 -04:00
string_agg(u.target,',') target,
2017-10-19 23:57:03 -04:00
tps.jsonb_concat_obj(coalesce(v.map,'{}'::jsonb) ORDER BY seq ) map,
2017-10-20 01:04:56 -04:00
--tps.jsonb_concat_obj(u.retval||coalesce(v.map,'{}'::jsonb) ORDER BY seq) comb,
2017-10-19 23:57:03 -04:00
tps.jsonb_concat_obj(u.retain||coalesce(v.map,'{}'::jsonb) ORDER BY seq) retain
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-20 01:04:56 -04:00
INNER 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-19 23:57:03 -04:00
u.id,
u.rec
)
2017-10-20 01:04:56 -04:00
--SELECT * FROM agg_orig
--UPDATE tps.trans t SET (map) = (SELECT retain FROM agg_orig WHERE t.id = agg_orig.id);
UPDATE
tps.trans t
SET
map = o.retain
FROM
agg_orig o
WHERE
o.id = t.id
/*
2017-10-19 23:57:03 -04:00
SELECT
retain->>'f20',
rec->>'Description',
COUNT(*)
FROM
agg_orig
GROUP BY
retain->>'f20',
rec->>'Description'
ORDER BY
retain->>'f20',
rec->>'Description'
2017-10-20 01:04:56 -04:00
*/