merge wk
This commit is contained in:
commit
11aa70684d
22
col_balance.pgsql
Normal file
22
col_balance.pgsql
Normal file
@ -0,0 +1,22 @@
|
|||||||
|
|
||||||
|
SELECT
|
||||||
|
id
|
||||||
|
,rec->>'id'
|
||||||
|
,r.*
|
||||||
|
,CASE "Schedule#"
|
||||||
|
WHEN '02IN Raw Material' THEN 13097563.42
|
||||||
|
WHEN '03IN Finished Goods' THEN 35790696.52
|
||||||
|
ELSE 0
|
||||||
|
END + SUM("Sales"+"Credits & Adjustments"-"Gross Collections") OVER (PARTITION BY "Schedule#" ORDER BY "Schedule#" ASC, "PostDate" ASC, rec->>'id' ASC) running_bal
|
||||||
|
,(LEAST("CollateralBalance" - "Ineligible Amount","MaxEligible")*("AdvanceRate"/100))::NUMERIC(20,2) qualified_collateral
|
||||||
|
,(("CollateralBalance" - "Ineligible Amount")*("AdvanceRate"/100))::NUMERIC(20,2) qualified_collateral_nl
|
||||||
|
FROM
|
||||||
|
tps.trans
|
||||||
|
LEFT JOIN LATERAL jsonb_populate_record(null::tps.pncl, rec) r ON TRUE
|
||||||
|
WHERE
|
||||||
|
srce = 'PNCL'
|
||||||
|
--AND rec @> '{"Schedule#":"03IN Finished Goods"}'
|
||||||
|
ORDER BY
|
||||||
|
"Schedule#" asc
|
||||||
|
,r."PostDate" asc
|
||||||
|
,rec->>'id' asc
|
85
do_map.pgsql
85
do_map.pgsql
@ -13,23 +13,56 @@ SELECT
|
|||||||
e.v ->> 'key',
|
e.v ->> 'key',
|
||||||
(t.rec #> ((e.v ->> 'key')::text[]))
|
(t.rec #> ((e.v ->> 'key')::text[]))
|
||||||
) AS rkey,
|
) AS rkey,
|
||||||
jsonb_build_object(
|
CASE regex->>'map'
|
||||||
e.v->>'field',
|
WHEN 'yes' THEN
|
||||||
CASE WHEN array_upper(mt.mt,1)=1
|
jsonb_build_object(
|
||||||
THEN to_json(mt.mt[1])
|
e.v->>'field',
|
||||||
ELSE array_to_json(mt.mt)
|
CASE regex->>'function'
|
||||||
END
|
WHEN 'extract' THEN
|
||||||
) retval,
|
CASE WHEN array_upper(mt.mt,1)=1
|
||||||
m.seq,
|
THEN to_json(mt.mt[1])
|
||||||
e.v->>'retain' retain
|
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
|
||||||
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->'where') w(v) ON TRUE
|
||||||
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->'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
|
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'
|
||||||
WHERE
|
WHERE
|
||||||
t.map IS NULL
|
t.map IS NULL
|
||||||
AND t.srce = 'DCARD'
|
AND t.srce = 'DCARD'
|
||||||
@ -53,8 +86,8 @@ agg_rx AS (
|
|||||||
rx.rec,
|
rx.rec,
|
||||||
tps.jsonb_concat_obj(rx.rkey) rkey,
|
tps.jsonb_concat_obj(rx.rkey) rkey,
|
||||||
tps.jsonb_concat_obj(rx.retval) AS retval,
|
tps.jsonb_concat_obj(rx.retval) AS retval,
|
||||||
tps.jsonb_concat_obj(CASE rx.retain WHEN 'y' THEN rx.retval ELSE '{}'::jsonb END) retain,
|
tps.jsonb_concat_obj(rx.retain) AS retain,
|
||||||
rx.seq
|
rx.seq
|
||||||
FROM
|
FROM
|
||||||
--unwrap json instruction and apply regex using a count per original line for re-aggregation
|
--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
|
--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
|
||||||
@ -76,9 +109,9 @@ agg_rx AS (
|
|||||||
u.id,
|
u.id,
|
||||||
u.rec,
|
u.rec,
|
||||||
string_agg(u.target,',') target,
|
string_agg(u.target,',') target,
|
||||||
tps.jsonb_concat_obj(coalesce(v.map,'{}'::jsonb) ORDER BY seq ) map,
|
tps.jsonb_concat_obj(u.retval) retval,
|
||||||
--tps.jsonb_concat_obj(u.retval||coalesce(v.map,'{}'::jsonb) ORDER BY seq) comb,
|
tps.jsonb_concat_obj(u.retain) retain,
|
||||||
tps.jsonb_concat_obj(u.retain||coalesce(v.map,'{}'::jsonb) ORDER BY seq) retain
|
tps.jsonb_concat_obj(coalesce(v.map,'{}'::jsonb) ORDER BY seq ) map
|
||||||
FROM
|
FROM
|
||||||
--re-aggregate return values and explude any records where one or more regex failed with a null result
|
--re-aggregate return values and explude any records where one or more regex failed with a null result
|
||||||
agg_rx u
|
agg_rx u
|
||||||
@ -93,28 +126,12 @@ agg_rx AS (
|
|||||||
)
|
)
|
||||||
|
|
||||||
|
|
||||||
--SELECT * FROM agg_orig
|
|
||||||
--UPDATE tps.trans t SET (map) = (SELECT retain FROM agg_orig WHERE t.id = agg_orig.id);
|
|
||||||
UPDATE
|
UPDATE
|
||||||
tps.trans t
|
tps.trans t
|
||||||
SET
|
SET
|
||||||
map = o.retain
|
map = o.map,
|
||||||
|
parse = o.retain
|
||||||
FROM
|
FROM
|
||||||
agg_orig o
|
agg_orig o
|
||||||
WHERE
|
WHERE
|
||||||
o.id = t.id
|
o.id = t.id
|
||||||
|
|
||||||
/*
|
|
||||||
SELECT
|
|
||||||
retain->>'f20',
|
|
||||||
rec->>'Description',
|
|
||||||
COUNT(*)
|
|
||||||
FROM
|
|
||||||
agg_orig
|
|
||||||
GROUP BY
|
|
||||||
retain->>'f20',
|
|
||||||
rec->>'Description'
|
|
||||||
ORDER BY
|
|
||||||
retain->>'f20',
|
|
||||||
rec->>'Description'
|
|
||||||
*/
|
|
214
do_map_g_option.pgsql
Normal file
214
do_map_g_option.pgsql
Normal file
@ -0,0 +1,214 @@
|
|||||||
|
\timing
|
||||||
|
WITH
|
||||||
|
|
||||||
|
--------------------apply regex operations to transactions-----------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
rx AS (
|
||||||
|
SELECT
|
||||||
|
t.srce,
|
||||||
|
t.id,
|
||||||
|
t.rec,
|
||||||
|
m.target,
|
||||||
|
regex->>'map' map_intention,
|
||||||
|
regex->>'function' regex_function,
|
||||||
|
e.v ->> 'field' result_key_name,
|
||||||
|
e.v ->> 'key' target_json_path,
|
||||||
|
e.v ->> 'flag' regex_options_flag,
|
||||||
|
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 regex->>'map'
|
||||||
|
WHEN 'yes' THEN
|
||||||
|
e.v->>'field'
|
||||||
|
ELSE
|
||||||
|
null
|
||||||
|
END map_key,
|
||||||
|
CASE regex->>'map'
|
||||||
|
WHEN 'yes' 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 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,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'
|
||||||
|
WHERE
|
||||||
|
--t.srce = 'PNCC'
|
||||||
|
rec @> '{"Transaction":"ACH Credits","Transaction":"ACH Debits"}'
|
||||||
|
--rec @> '{"Description":"CHECK 93013270 086129935"}'::jsonb
|
||||||
|
ORDER BY
|
||||||
|
t.id DESC,
|
||||||
|
m.target,
|
||||||
|
e.rn,
|
||||||
|
COALESCE(mt.rn,rp.rn,1)
|
||||||
|
)
|
||||||
|
|
||||||
|
--SELECT * FROM rx
|
||||||
|
|
||||||
|
, agg_to_target_items AS (
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
,target
|
||||||
|
,map_intention
|
||||||
|
,regex_function
|
||||||
|
,target_item_number
|
||||||
|
,result_key_name
|
||||||
|
,target_json_path
|
||||||
|
,CASE WHEN map_key IS NULL
|
||||||
|
THEN
|
||||||
|
NULL
|
||||||
|
ELSE
|
||||||
|
jsonb_build_object(
|
||||||
|
map_key,
|
||||||
|
CASE WHEN max(result_number) = 1
|
||||||
|
THEN
|
||||||
|
jsonb_agg(map_val ORDER BY result_number) -> 0
|
||||||
|
ELSE
|
||||||
|
jsonb_agg(map_val ORDER BY result_number)
|
||||||
|
END
|
||||||
|
)
|
||||||
|
END map_val
|
||||||
|
,CASE WHEN retain_key IS NULL
|
||||||
|
THEN
|
||||||
|
NULL
|
||||||
|
ELSE
|
||||||
|
jsonb_build_object(
|
||||||
|
retain_key,
|
||||||
|
CASE WHEN max(result_number) = 1
|
||||||
|
THEN
|
||||||
|
jsonb_agg(retain_val ORDER BY result_number) -> 0
|
||||||
|
ELSE
|
||||||
|
jsonb_agg(retain_val ORDER BY result_number)
|
||||||
|
END
|
||||||
|
)
|
||||||
|
END retain_val
|
||||||
|
FROM
|
||||||
|
rx
|
||||||
|
GROUP BY
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
,target
|
||||||
|
,map_intention
|
||||||
|
,regex_function
|
||||||
|
,target_item_number
|
||||||
|
,result_key_name
|
||||||
|
,target_json_path
|
||||||
|
,map_key
|
||||||
|
,retain_key
|
||||||
|
)
|
||||||
|
|
||||||
|
--SELECT * FROM agg_to_target_items
|
||||||
|
|
||||||
|
, agg_to_target AS (
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
,target
|
||||||
|
,map_intention
|
||||||
|
,tps.jsonb_concat_obj(COALESCE(map_val,'{}'::JSONB)) map_val
|
||||||
|
,jsonb_strip_nulls(tps.jsonb_concat_obj(COALESCE(retain_val,'{}'::JSONB))) retain_val
|
||||||
|
FROM
|
||||||
|
agg_to_target_items
|
||||||
|
GROUP BY
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
,target
|
||||||
|
,map_intention
|
||||||
|
ORDER BY
|
||||||
|
id
|
||||||
|
)
|
||||||
|
|
||||||
|
|
||||||
|
--SELECT * FROM agg_to_target
|
||||||
|
|
||||||
|
|
||||||
|
, link_map AS (
|
||||||
|
SELECT
|
||||||
|
a.srce
|
||||||
|
,a.id
|
||||||
|
,a.target
|
||||||
|
,a.map_intention
|
||||||
|
,a.map_val
|
||||||
|
,a.retain_val retain_value
|
||||||
|
,v.map
|
||||||
|
FROM
|
||||||
|
agg_to_target a
|
||||||
|
LEFT OUTER JOIN tps.map_rv v ON
|
||||||
|
v.srce = a.srce AND
|
||||||
|
v.target = a.target AND
|
||||||
|
v.retval = a.map_val
|
||||||
|
)
|
||||||
|
|
||||||
|
--SELECT * FROM link_map
|
||||||
|
|
||||||
|
, agg_to_id AS (
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
,tps.jsonb_concat_obj(COALESCE(retain_value,'{}'::jsonb)) retain_val
|
||||||
|
,tps.jsonb_concat_obj(COALESCE(map,'{}'::jsonb)) map
|
||||||
|
FROM
|
||||||
|
link_map
|
||||||
|
GROUP BY
|
||||||
|
srce
|
||||||
|
,id
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT srce, id, jsonb_pretty(retain_val), jsonb_pretty(map) FROM agg_to_id
|
||||||
|
|
||||||
|
/*
|
||||||
|
UPDATE
|
||||||
|
tps.trans t
|
||||||
|
SET
|
||||||
|
map = o.map,
|
||||||
|
parse = o.retain_val,
|
||||||
|
allj = t.rec||o.map||o.retain_val
|
||||||
|
FROM
|
||||||
|
agg_to_id o
|
||||||
|
WHERE
|
||||||
|
o.id = t.id;
|
||||||
|
*/
|
14
loan_bal.pgsql
Normal file
14
loan_bal.pgsql
Normal file
@ -0,0 +1,14 @@
|
|||||||
|
\timing
|
||||||
|
SELECT
|
||||||
|
r.*,
|
||||||
|
SUM(r."Advances"+r."Adjustments"-r."Payments") OVER (PARTITION BY "Loan#" ORDER BY r."Post Date" asc ,rec->>'id' asc, r."Reference #" asc)
|
||||||
|
FROM
|
||||||
|
tps.trans
|
||||||
|
LEFT JOIN LATERAL jsonb_populate_record(null::tps.pnco, rec) r ON TRUE
|
||||||
|
WHERE
|
||||||
|
rec @> '{"Loan#":"606780191"}'
|
||||||
|
ORDER BY
|
||||||
|
r."Loan#"
|
||||||
|
,r."Post Date" asc
|
||||||
|
,rec->>'id' asc
|
||||||
|
,r."Reference #" asc
|
251
map_rm_template.pgsql
Normal file
251
map_rm_template.pgsql
Normal file
@ -0,0 +1,251 @@
|
|||||||
|
/*
|
||||||
|
DELETE FROM tps.map_rm where target = 'Strip Amount Commas';
|
||||||
|
INSERT INTO
|
||||||
|
tps.map_rm
|
||||||
|
SELECT *
|
||||||
|
FROM
|
||||||
|
(VALUES
|
||||||
|
('PNCC', 'Strip Amount Commas',
|
||||||
|
$j$
|
||||||
|
{
|
||||||
|
"name":"Strip Amount Commas",
|
||||||
|
"description":"the Amount field come from PNC with commas embeded so it cannot be cast to numeric",
|
||||||
|
"defn": [
|
||||||
|
{
|
||||||
|
"key": "{Amount}",
|
||||||
|
"field": "amount",
|
||||||
|
"regex": ",",
|
||||||
|
"replace":"",
|
||||||
|
"flag":"g",
|
||||||
|
"retain":"y"
|
||||||
|
}
|
||||||
|
],
|
||||||
|
"function":"replace",
|
||||||
|
"map":"no",
|
||||||
|
"where": [
|
||||||
|
{
|
||||||
|
}
|
||||||
|
]
|
||||||
|
}
|
||||||
|
$j$::jsonb
|
||||||
|
, 1)
|
||||||
|
) x;
|
||||||
|
|
||||||
|
DELETE FROM tps.map_rm where target = 'Parse Descr';
|
||||||
|
INSERT INTO
|
||||||
|
tps.map_rm
|
||||||
|
SELECT *
|
||||||
|
FROM
|
||||||
|
(VALUES
|
||||||
|
('PNCC', 'Parse Descr',
|
||||||
|
$j$
|
||||||
|
{
|
||||||
|
"name":"Parse Descr",
|
||||||
|
"description":"parse the description based on at least three capital letters followed by a comma until another set of at lesat 3 capital letters and a comma is encountered",
|
||||||
|
"defn": [
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field": "dparse",
|
||||||
|
"regex": "([A-Z]{3,}?:)(.*)(?=[A-Z]{3,}?:|$)",
|
||||||
|
"flag":"g",
|
||||||
|
"retain":"y"
|
||||||
|
}
|
||||||
|
],
|
||||||
|
"function":"extract",
|
||||||
|
"map":"no",
|
||||||
|
"where": [
|
||||||
|
{
|
||||||
|
}
|
||||||
|
]
|
||||||
|
}
|
||||||
|
$j$::jsonb
|
||||||
|
, 2)
|
||||||
|
) x;
|
||||||
|
|
||||||
|
|
||||||
|
DELETE FROM tps.map_rm where target = 'Extract OBI';
|
||||||
|
INSERT INTO
|
||||||
|
tps.map_rm
|
||||||
|
SELECT *
|
||||||
|
FROM
|
||||||
|
(VALUES
|
||||||
|
('PNCC', 'Extract OBI',
|
||||||
|
$j$
|
||||||
|
{
|
||||||
|
"name":"Extract OBI",
|
||||||
|
"description":"pull out whatever follows OBI in the description until atleast 3 capital letters followed by a colon are encountered",
|
||||||
|
"defn": [
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field": "obi",
|
||||||
|
"regex": "OBI:(.*?)(?=[A-Z]{3,}?:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
}
|
||||||
|
],
|
||||||
|
"function":"extract",
|
||||||
|
"map":"no",
|
||||||
|
"where": [
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer DB - Wire"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer CR-Other"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Intl Money Transfer Debits"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer DB - Other"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer CR-Wire"
|
||||||
|
}
|
||||||
|
]
|
||||||
|
}
|
||||||
|
$j$::jsonb
|
||||||
|
, 2)
|
||||||
|
) x;
|
||||||
|
|
||||||
|
DELETE FROM tps.map_rm where target = 'Extract RFB';
|
||||||
|
INSERT INTO
|
||||||
|
tps.map_rm
|
||||||
|
SELECT *
|
||||||
|
FROM
|
||||||
|
(VALUES
|
||||||
|
('PNCC', 'Extract RFB',
|
||||||
|
$j$
|
||||||
|
{
|
||||||
|
"name":"Extract RFB",
|
||||||
|
"description":"pull out whatever follows RFB in the description until atleast 3 capital letters followed by a colon are encountered",
|
||||||
|
"defn": [
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field": "rfb",
|
||||||
|
"regex": "RFB:(.*?)(?=[A-Z]{3,}?:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
}
|
||||||
|
],
|
||||||
|
"function":"extract",
|
||||||
|
"map":"no",
|
||||||
|
"where": [
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer DB - Wire"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer CR-Other"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Intl Money Transfer Debits"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer DB - Other"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"Money Transfer CR-Wire"
|
||||||
|
}
|
||||||
|
]
|
||||||
|
}
|
||||||
|
$j$::jsonb
|
||||||
|
, 2)
|
||||||
|
) x;
|
||||||
|
*/
|
||||||
|
DELETE FROM tps.map_rm where target = 'Parse ACH';
|
||||||
|
|
||||||
|
INSERT INTO
|
||||||
|
tps.map_rm
|
||||||
|
SELECT *
|
||||||
|
FROM
|
||||||
|
(VALUES
|
||||||
|
('PNCC', 'Parse ACH',
|
||||||
|
$j$
|
||||||
|
{
|
||||||
|
"name":"Parse ACH",
|
||||||
|
"description":"parse select components of the description for ACH Credits Receieved",
|
||||||
|
"defn": [
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Comp Name",
|
||||||
|
"regex": "Comp Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Cust ID",
|
||||||
|
"regex": "Cust ID:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Desc",
|
||||||
|
"regex": "Desc:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Cust Name",
|
||||||
|
"regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Batch Discr",
|
||||||
|
"regex": "Batch Discr:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Comp ID",
|
||||||
|
"regex": "Comp ID:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Addenda",
|
||||||
|
"regex": "Addenda:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"SETT",
|
||||||
|
"regex": "SETT:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Date",
|
||||||
|
"regex": "Date:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"key": "{Description}",
|
||||||
|
"field":"Time",
|
||||||
|
"regex": "Time:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
|
||||||
|
"flag":"",
|
||||||
|
"retain":"y"
|
||||||
|
}
|
||||||
|
],
|
||||||
|
"function":"extract",
|
||||||
|
"map":"no",
|
||||||
|
"where": [
|
||||||
|
{
|
||||||
|
"Transaction":"ACH Credits"
|
||||||
|
},
|
||||||
|
{
|
||||||
|
"Transaction":"ACH Debits"
|
||||||
|
}
|
||||||
|
]
|
||||||
|
}
|
||||||
|
$j$::jsonb
|
||||||
|
, 2)
|
||||||
|
) x;
|
@ -4,6 +4,8 @@ Concepts
|
|||||||
pull various static files into postgres and do basic transformation without losing the original document
|
pull various static files into postgres and do basic transformation without losing the original document
|
||||||
or getting into custom code for each scenario
|
or getting into custom code for each scenario
|
||||||
|
|
||||||
|
the is an in-between for an foreign data wrapper & custom programming
|
||||||
|
|
||||||
## Storage
|
## Storage
|
||||||
all records are jsonb
|
all records are jsonb
|
||||||
applied mappings are in associated jsonb documents
|
applied mappings are in associated jsonb documents
|
||||||
@ -15,6 +17,9 @@ applied mappings are in associated jsonb documents
|
|||||||
1. regular expressions are used to extract pieces of the json objects
|
1. regular expressions are used to extract pieces of the json objects
|
||||||
2. the results of the regular expressions are bumped up against a list of basic mappings and written to an associated jsonb document
|
2. the results of the regular expressions are bumped up against a list of basic mappings and written to an associated jsonb document
|
||||||
|
|
||||||
|
a target represents a whole scenario that needs matched. it can contain several regex expressions. if one fails, then no match is attempted because it coudl result in a false positive based on the @> oeprator used at join time
|
||||||
|
`this probably isn't correctly implemented`
|
||||||
|
|
||||||
## Transformation tools
|
## Transformation tools
|
||||||
* `COPY`
|
* `COPY`
|
||||||
* `regexp_matches()`
|
* `regexp_matches()`
|
||||||
|
26
srce.pgsql
26
srce.pgsql
@ -16,11 +16,21 @@ DECLARE _t text;
|
|||||||
DECLARE _c text;
|
DECLARE _c text;
|
||||||
DECLARE _path text;
|
DECLARE _path text;
|
||||||
DECLARE _srce text;
|
DECLARE _srce text;
|
||||||
|
<<<<<<< HEAD
|
||||||
|
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
_path := 'C:\users\fleet\downloads\d1026.csv';
|
_path := 'C:\users\fleet\downloads\d1026.csv';
|
||||||
_srce := 'DCARD';
|
_srce := 'DCARD';
|
||||||
|
=======
|
||||||
|
DECLARE _log_info text;
|
||||||
|
DECLARE _log_id text;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
_path := 'C:\users\ptrowbridge\downloads\llcol.csv';
|
||||||
|
_srce := 'PNCL';
|
||||||
|
>>>>>>> wk
|
||||||
|
|
||||||
----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
|
----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
|
||||||
|
|
||||||
@ -152,6 +162,7 @@ BEGIN
|
|||||||
|
|
||||||
--------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------
|
--------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
, logged AS (
|
||||||
INSERT INTO
|
INSERT INTO
|
||||||
tps.trans_log (info)
|
tps.trans_log (info)
|
||||||
SELECT
|
SELECT
|
||||||
@ -173,7 +184,20 @@ BEGIN
|
|||||||
FROM
|
FROM
|
||||||
unmatched_keys
|
unmatched_keys
|
||||||
)
|
)
|
||||||
);
|
)
|
||||||
|
RETURNING *
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
id
|
||||||
|
,info
|
||||||
|
INTO
|
||||||
|
_log_id
|
||||||
|
,_log_info
|
||||||
|
FROM
|
||||||
|
logged;
|
||||||
|
|
||||||
|
RAISE NOTICE 'import logged under id# %, info: %', _log_id, _log_info;
|
||||||
|
|
||||||
END
|
END
|
||||||
$$;
|
$$;
|
||||||
|
24
srce_defn.pgsql
Normal file
24
srce_defn.pgsql
Normal file
@ -0,0 +1,24 @@
|
|||||||
|
\timing
|
||||||
|
/*
|
||||||
|
WITH
|
||||||
|
ext AS (
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,defn->'unique_constraint'->>'fields'
|
||||||
|
,ARRAY(SELECT ae.e::text[] FROM jsonb_array_elements_text(defn->'unique_constraint'->'fields') ae(e)) text_array
|
||||||
|
FROM
|
||||||
|
tps.srce
|
||||||
|
--add where clause for targeted source
|
||||||
|
)
|
||||||
|
*/
|
||||||
|
|
||||||
|
SELECT COUNT(*) FROM
|
||||||
|
(
|
||||||
|
SELECT DISTINCT
|
||||||
|
t.srce
|
||||||
|
,(SELECT JSONB_OBJECT_agg(ae.e,rec #> ae.e::text[]) FROM jsonb_array_elements_text(defn->'unique_constraint'->'fields') ae(e)) ja
|
||||||
|
FROM
|
||||||
|
tps.trans t
|
||||||
|
INNER JOIN tps.srce s ON
|
||||||
|
s.srce = t.srce
|
||||||
|
) X
|
16
ubm_data.sql
16
ubm_data.sql
@ -40,6 +40,16 @@ INSERT INTO srce (srce, defn) VALUES ('CAMZ', '{"name": "CAMZ", "type": "csv", "
|
|||||||
|
|
||||||
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('DCARD', 'First 20', '{"defn": [{"key": "{Description}", "field": "f20", "regex": ".{1,20}", "retain": "y"}], "where": [{}]}', 2);
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('DCARD', 'First 20', '{"defn": [{"key": "{Description}", "field": "f20", "regex": ".{1,20}", "retain": "y"}], "where": [{}]}', 2);
|
||||||
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('HUNT', 'First 20', '{"defn": [{"key": "{Description}", "field": "f20", "regex": ".{1,20}", "retain": "y"}], "where": [{}]}', 1);
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('HUNT', 'First 20', '{"defn": [{"key": "{Description}", "field": "f20", "regex": ".{1,20}", "retain": "y"}], "where": [{}]}', 1);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'ACH Debits', '{"map": "yes", "defn": [{"key": "{Description}", "field": "ini", "regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)", "retain": "y"}, {"key": "{Description}", "field": "compn", "regex": "Comp Name:(.+?)(?=$| Comp|\\w+?:)", "retain": "y"}, {"key": "{Description}", "field": "adp_comp", "regex": "Cust ID:.*?(B3X|UDV|U7E|U7C|U7H|U7J).*?(?=$|\\w+?:)", "retain": "y"}, {"key": "{Description}", "field": "desc", "regex": "Desc:(.+?) Comp", "retain": "y"}, {"key": "{Description}", "field": "discr", "regex": "Discr:(.+?)(?=$| SEC:|\\w+?:)", "retain": "y"}], "where": [{"Transaction": "ACH Debits"}], "function": "extract"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Trans Type', '{"map": "yes", "defn": [{"key": "{AccountName}", "field": "acctn", "regex": "(.*)", "retain": "n"}, {"key": "{Transaction}", "field": "trans", "regex": "(.*)", "retain": "n"}, {"key": "{Description}", "field": "ini", "regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)", "retain": "y"}], "where": [{}], "function": "extract"}', 1);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Wires Out', '{"map": "yes", "defn": [{"key": "{Description}", "field": "ini", "regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)", "retain": "y"}, {"key": "{Description}", "field": "bene", "regex": "BENEFICIARY:(.+?) AC/", "retain": "y"}, {"key": "{Description}", "field": "accts", "regex": "AC/(\\w*) .*AC/(\\w*) ", "retain": "y"}], "where": [{"Transaction": "Intl Money Transfer Debits"}, {"Transaction": "Money Transfer DB - Wire"}], "function": "extract"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Currency', '{"map": "yes", "defn": [{"key": "{Description}", "field": "ini", "regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)", "retain": "y"}, {"key": "{Description}", "field": "curr1", "regex": ".*(DEBIT|CREDIT).*(USD|CAD).*(?=DEBIT|CREDIT).*(?=USD|CAD).*", "retain": "y"}, {"key": "{Description}", "field": "curr2", "regex": ".*(?=DEBIT|CREDIT).*(?=USD|CAD).*(DEBIT|CREDIT).*(USD|CAD).*", "retain": "y"}], "where": [{"Transaction": "Miscellaneous Credits"}, {"Transaction": "Miscellaneous Debits"}], "function": "extract"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Check Number', '{"map": "yes", "defn": [{"key": "{Description}", "field": "checkn", "regex": "[^0-9]*([0-9]*)\\s|$", "retain": "y"}], "where": [{"Transaction": "Checks Paid"}], "function": "extract"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Strip Amount Commas', '{"map": "no", "defn": [{"key": "{Amount}", "flag": "g", "field": "amount", "regex": ",", "retain": "y", "replace": ""}], "name": "Strip Amount Commas", "where": [{}], "function": "replace", "description": "the Amount field come from PNC with commas embeded so it cannot be cast to numeric"}', 1);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Parse Descr', '{"map": "no", "defn": [{"key": "{Description}", "flag": "g", "field": "dparse", "regex": "([A-Z]{3,}?:)(.*)(?=[A-Z]{3,}?:|$)", "retain": "y"}], "name": "Parse Descr", "where": [{}], "function": "extract", "description": "parse the description based on at least three capital letters followed by a comma until another set of at lesat 3 capital letters and a comma is encountered"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Extract OBI', '{"map": "no", "defn": [{"key": "{Description}", "flag": "", "field": "obi", "regex": "OBI:(.*?)(?=[A-Z]{3,}?:|$)", "retain": "y"}], "name": "Extract OBI", "where": [{"Transaction": "Money Transfer DB - Wire"}, {"Transaction": "Money Transfer CR-Other"}, {"Transaction": "Intl Money Transfer Debits"}, {"Transaction": "Money Transfer DB - Other"}, {"Transaction": "Money Transfer CR-Wire"}], "function": "extract", "description": "pull out whatever follows OBI in the description until atleast 3 capital letters followed by a colon are encountered"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Extract RFB', '{"map": "no", "defn": [{"key": "{Description}", "flag": "", "field": "rfb", "regex": "RFB:(.*?)(?=[A-Z]{3,}?:|$)", "retain": "y"}], "name": "Extract RFB", "where": [{"Transaction": "Money Transfer DB - Wire"}, {"Transaction": "Money Transfer CR-Other"}, {"Transaction": "Intl Money Transfer Debits"}, {"Transaction": "Money Transfer DB - Other"}, {"Transaction": "Money Transfer CR-Wire"}], "function": "extract", "description": "pull out whatever follows RFB in the description until atleast 3 capital letters followed by a colon are encountered"}', 2);
|
||||||
|
INSERT INTO map_rm (srce, target, regex, seq) VALUES ('PNCC', 'Parse ACH', '{"map": "no", "defn": [{"key": "{Description}", "flag": "", "field": "Comp Name", "regex": "Comp Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Cust ID", "regex": "Cust ID:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Desc", "regex": "Desc:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Cust Name", "regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Batch Discr", "regex": "Batch Discr:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Comp ID", "regex": "Comp ID:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Addenda", "regex": "Addenda:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "SETT", "regex": "SETT:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Date", "regex": "Date:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}, {"key": "{Description}", "flag": "", "field": "Time", "regex": "Time:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)", "retain": "y"}], "name": "Parse ACH", "where": [{"Transaction": "ACH Credits"}, {"Transaction": "ACH Debits"}], "function": "extract", "description": "parse select components of the description for ACH Credits Receieved"}', 2);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -105,7 +115,7 @@ INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f
|
|||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD 330-6733"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD 330-6733"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD 33067333"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD 33067333"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD KENT OH"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "BV HEGDE,MD KENT OH"}', '{"party": "Bv Hegde, MD", "reason": "Medical"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CAFE O PLAY CUYAHOGA"}', '{"party": "Café O Play", "reason": "Recreation"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CAFE O PLAY CUYAHOGA"}', '{"party": "Caf<EFBFBD> O Play", "reason": "Recreation"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CAJUN GRILL CLEVELAN"}', '{"party": "Cajun Grill", "reason": "Restaurante"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CAJUN GRILL CLEVELAN"}', '{"party": "Cajun Grill", "reason": "Restaurante"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CARTER''S #907 STOW O"}', '{"party": "Carters", "reason": "Clothes"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CARTER''S #907 STOW O"}', '{"party": "Carters", "reason": "Clothes"}');
|
||||||
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CASHBACK BONUS REDEM"}', '{"party": "Discover Card Rewards", "reason": "Financing"}');
|
INSERT INTO map_rv (srce, target, retval, map) VALUES ('DCARD', 'First 20', '{"f20": "CASHBACK BONUS REDEM"}', '{"party": "Discover Card Rewards", "reason": "Financing"}');
|
||||||
@ -847,8 +857,8 @@ INSERT INTO trans (id, srce, rec, map) VALUES (170, 'DCARD', '{"Amount": "3.49",
|
|||||||
INSERT INTO trans (id, srce, rec, map) VALUES (171, 'DCARD', '{"Amount": "57.68", "Category": "Restaurants", "Post Date": "2017-03-25", "Description": "HARTVILLE KITCHEN - ED HARTVILLE OH", "Trans. Date": "2017-03-25"}', '{"f20": "HARTVILLE KITCHEN - ", "party": "Hartville Kitchen", "reason": "Restaurante"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (171, 'DCARD', '{"Amount": "57.68", "Category": "Restaurants", "Post Date": "2017-03-25", "Description": "HARTVILLE KITCHEN - ED HARTVILLE OH", "Trans. Date": "2017-03-25"}', '{"f20": "HARTVILLE KITCHEN - ", "party": "Hartville Kitchen", "reason": "Restaurante"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (172, 'DCARD', '{"Amount": "32.59", "Category": "Gasoline", "Post Date": "2017-03-25", "Description": "BP#954635936241 7-ELEVEN STOW OH", "Trans. Date": "2017-03-25"}', '{"f20": "BP#954635936241 7-EL", "party": "BP", "reason": "Gas"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (172, 'DCARD', '{"Amount": "32.59", "Category": "Gasoline", "Post Date": "2017-03-25", "Description": "BP#954635936241 7-ELEVEN STOW OH", "Trans. Date": "2017-03-25"}', '{"f20": "BP#954635936241 7-EL", "party": "BP", "reason": "Gas"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (173, 'DCARD', '{"Amount": "7.47", "Category": "Gasoline", "Post Date": "2017-03-25", "Description": "7-ELEVEN 36241 STOW OH", "Trans. Date": "2017-03-25"}', '{"f20": "7-ELEVEN 36241 STOW ", "city": "Stow", "party": "7-Eleven", "reason": "Gasoline", "province": "Ohio"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (173, 'DCARD', '{"Amount": "7.47", "Category": "Gasoline", "Post Date": "2017-03-25", "Description": "7-ELEVEN 36241 STOW OH", "Trans. Date": "2017-03-25"}', '{"f20": "7-ELEVEN 36241 STOW ", "city": "Stow", "party": "7-Eleven", "reason": "Gasoline", "province": "Ohio"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (174, 'DCARD', '{"Amount": "39.50", "Category": "Travel/ Entertainment", "Post Date": "2017-03-20", "Description": "CAFE O PLAY CUYAHOGA FALLOH", "Trans. Date": "2017-03-20"}', '{"f20": "CAFE O PLAY CUYAHOGA", "party": "Café O Play", "reason": "Recreation"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (174, 'DCARD', '{"Amount": "39.50", "Category": "Travel/ Entertainment", "Post Date": "2017-03-20", "Description": "CAFE O PLAY CUYAHOGA FALLOH", "Trans. Date": "2017-03-20"}', '{"f20": "CAFE O PLAY CUYAHOGA", "party": "Caf<EFBFBD> O Play", "reason": "Recreation"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (175, 'DCARD', '{"Amount": "4.89", "Category": "Travel/ Entertainment", "Post Date": "2017-03-20", "Description": "CAFE O PLAY CUYAHOGA FALLOH", "Trans. Date": "2017-03-20"}', '{"f20": "CAFE O PLAY CUYAHOGA", "party": "Café O Play", "reason": "Recreation"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (175, 'DCARD', '{"Amount": "4.89", "Category": "Travel/ Entertainment", "Post Date": "2017-03-20", "Description": "CAFE O PLAY CUYAHOGA FALLOH", "Trans. Date": "2017-03-20"}', '{"f20": "CAFE O PLAY CUYAHOGA", "party": "Caf<EFBFBD> O Play", "reason": "Recreation"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (176, 'DCARD', '{"Amount": "323.24", "Category": "Merchandise", "Post Date": "2017-03-18", "Description": "WAL-MART SC - #2323 STOW OH", "Trans. Date": "2017-03-18"}', '{"f20": "WAL-MART SC - #2323 ", "party": "Wal-Mart", "reason": "Home Supplies"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (176, 'DCARD', '{"Amount": "323.24", "Category": "Merchandise", "Post Date": "2017-03-18", "Description": "WAL-MART SC - #2323 STOW OH", "Trans. Date": "2017-03-18"}', '{"f20": "WAL-MART SC - #2323 ", "party": "Wal-Mart", "reason": "Home Supplies"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (177, 'DCARD', '{"Amount": "-8.27", "Category": "Payments and Credits", "Post Date": "2017-03-16", "Description": "REPUBLIC WIRELESS 800-808-5150 NCP-10204888", "Trans. Date": "2017-03-15"}', '{"f20": "REPUBLIC WIRELESS 80", "party": "Republic Wireless", "reason": "Phones"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (177, 'DCARD', '{"Amount": "-8.27", "Category": "Payments and Credits", "Post Date": "2017-03-16", "Description": "REPUBLIC WIRELESS 800-808-5150 NCP-10204888", "Trans. Date": "2017-03-15"}', '{"f20": "REPUBLIC WIRELESS 80", "party": "Republic Wireless", "reason": "Phones"}');
|
||||||
INSERT INTO trans (id, srce, rec, map) VALUES (178, 'DCARD', '{"Amount": "45.38", "Category": "Gasoline", "Post Date": "2017-03-14", "Description": "MARATHON PETRO TWINSBURG OH", "Trans. Date": "2017-03-14"}', '{"f20": "MARATHON PETRO TWINS", "party": "Marathon", "reason": "Gas"}');
|
INSERT INTO trans (id, srce, rec, map) VALUES (178, 'DCARD', '{"Amount": "45.38", "Category": "Gasoline", "Post Date": "2017-03-14", "Description": "MARATHON PETRO TWINSBURG OH", "Trans. Date": "2017-03-14"}', '{"f20": "MARATHON PETRO TWINS", "party": "Marathon", "reason": "Gas"}');
|
||||||
|
@ -14,6 +14,13 @@ SET check_function_bodies = false;
|
|||||||
SET client_min_messages = warning;
|
SET client_min_messages = warning;
|
||||||
SET row_security = off;
|
SET row_security = off;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: bank; Type: SCHEMA; Schema: -; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE SCHEMA bank;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: evt; Type: SCHEMA; Schema: -; Owner: -
|
-- Name: evt; Type: SCHEMA; Schema: -; Owner: -
|
||||||
--
|
--
|
||||||
@ -56,6 +63,41 @@ CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
|
|||||||
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
|
COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: plprofiler; Type: EXTENSION; Schema: -; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE EXTENSION IF NOT EXISTS plprofiler WITH SCHEMA public;
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: EXTENSION plprofiler; Type: COMMENT; Schema: -; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
COMMENT ON EXTENSION plprofiler IS 'server-side support for profiling PL/pgSQL functions';
|
||||||
|
|
||||||
|
|
||||||
|
SET search_path = bank, pg_catalog;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: pncc; Type: TYPE; Schema: bank; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE TYPE pncc AS (
|
||||||
|
"AsOfDate" date,
|
||||||
|
"BankId" text,
|
||||||
|
"AccountNumber" text,
|
||||||
|
"AccountName" text,
|
||||||
|
"BaiControl" text,
|
||||||
|
"Currency" text,
|
||||||
|
"Transaction" text,
|
||||||
|
"Reference" text,
|
||||||
|
"Amount" numeric,
|
||||||
|
"Description" text,
|
||||||
|
"AdditionalRemittance" text
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
SET search_path = tps, pg_catalog;
|
SET search_path = tps, pg_catalog;
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -105,12 +147,14 @@ CREATE FUNCTION jsonb_extract(rec jsonb, key_list text[]) RETURNS jsonb
|
|||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS $$
|
AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
t text;
|
t text[];
|
||||||
j jsonb := '{}'::jsonb;
|
j jsonb := '{}'::jsonb;
|
||||||
|
|
||||||
BEGIN
|
BEGIN
|
||||||
FOREACH t IN ARRAY key_list LOOP
|
FOREACH t SLICE 1 IN ARRAY key_list LOOP
|
||||||
j := j || jsonb_build_object(t,rec->t);
|
--RAISE NOTICE '%', t;
|
||||||
|
--RAISE NOTICE '%', t[1];
|
||||||
|
j := j || jsonb_build_object(t[1],rec#>t);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
RETURN j;
|
RETURN j;
|
||||||
END;
|
END;
|
||||||
@ -219,7 +263,9 @@ CREATE TABLE trans (
|
|||||||
id integer NOT NULL,
|
id integer NOT NULL,
|
||||||
srce text,
|
srce text,
|
||||||
rec jsonb,
|
rec jsonb,
|
||||||
map jsonb
|
parse jsonb,
|
||||||
|
map jsonb,
|
||||||
|
allj jsonb
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
@ -313,6 +359,13 @@ ALTER TABLE ONLY trans
|
|||||||
ADD CONSTRAINT trans_pkey PRIMARY KEY (id);
|
ADD CONSTRAINT trans_pkey PRIMARY KEY (id);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: trans_allj; Type: INDEX; Schema: tps; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX trans_allj ON trans USING gin (allj);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: trans_rec; Type: INDEX; Schema: tps; Owner: -
|
-- Name: trans_rec; Type: INDEX; Schema: tps; Owner: -
|
||||||
--
|
--
|
||||||
|
Loading…
Reference in New Issue
Block a user