Merge branch 'master' into key_log

This commit is contained in:
Paul Trowbridge 2018-03-10 02:30:41 -05:00
commit 8e4ba4ef28
7 changed files with 483 additions and 600 deletions

View File

@ -49,26 +49,6 @@ CREATE TYPE tps."DCARD" AS (
COMMENT ON TYPE tps."DCARD" IS 'Discover Card';
--
-- Name: DCARD2; Type: TYPE; Schema: tps; Owner: -
--
CREATE TYPE tps."DCARD2" AS (
"Trans. Date" numeric,
"Post Date" numeric,
"Description" text,
"Amount" numeric,
"Category" text
);
--
-- Name: TYPE "DCARD2"; Type: COMMENT; Schema: tps; Owner: -
--
COMMENT ON TYPE tps."DCARD2" IS 'Discover Card';
--
-- Name: DMAPI; Type: TYPE; Schema: tps; Owner: -
--
@ -1085,10 +1065,10 @@ $_$;
--
-- Name: srce_set(text, jsonb); Type: FUNCTION; Schema: tps; Owner: -
-- Name: srce_set(jsonb); Type: FUNCTION; Schema: tps; Owner: -
--
CREATE FUNCTION tps.srce_set(_name text, _defn jsonb) RETURNS jsonb
CREATE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb
LANGUAGE plpgsql
AS $_$
@ -1115,7 +1095,7 @@ BEGIN
FROM
tps.srce
WHERE
srce = _name;
srce = _defn->>'name';
-------check for transctions already existing under this source-----------
SELECT
@ -1125,7 +1105,7 @@ BEGIN
FROM
tps.trans
WHERE
srce = _name;
srce = _defn->>'name';
--if there are transaction already and the schema is different stop--------
IF _cnt > 0 THEN
@ -1151,14 +1131,14 @@ BEGIN
INSERT INTO
tps.srce
SELECT
_name, _defn
_defn->>'name', _defn
ON CONFLICT ON CONSTRAINT srce_pkey DO UPDATE
SET
defn = _defn;
------------------drop existing type-----------------------------------------
EXECUTE format('DROP TYPE IF EXISTS tps.%I',_name);
EXECUTE format('DROP TYPE IF EXISTS tps.%I',_defn->>'name');
------------------create new type--------------------------------------------
@ -1171,15 +1151,15 @@ BEGIN
--unwrap the schema definition array
LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE
WHERE
srce = _name
srce = _defn->>'name'
GROUP BY
srce;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_name,_sql;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_defn->>'name',_sql;
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_name,_sql);
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_defn->>'name',_sql);
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_name,(_defn->>'description'));
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_defn->>'name',(_defn->>'description'));
----------------set message-----------------------------------------------------

View File

@ -1,5 +1,5 @@
CREATE OR REPLACE FUNCTION tps.srce_set(_name text, _defn jsonb) RETURNS jsonb
CREATE OR REPLACE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb
AS $f$
DECLARE
@ -25,7 +25,7 @@ BEGIN
FROM
tps.srce
WHERE
srce = _name;
srce = _defn->>'name';
-------check for transctions already existing under this source-----------
SELECT
@ -35,7 +35,7 @@ BEGIN
FROM
tps.trans
WHERE
srce = _name;
srce = _defn->>'name';
--if there are transaction already and the schema is different stop--------
IF _cnt > 0 THEN
@ -61,14 +61,14 @@ BEGIN
INSERT INTO
tps.srce
SELECT
_name, _defn
_defn->>'name', _defn
ON CONFLICT ON CONSTRAINT srce_pkey DO UPDATE
SET
defn = _defn;
------------------drop existing type-----------------------------------------
EXECUTE format('DROP TYPE IF EXISTS tps.%I',_name);
EXECUTE format('DROP TYPE IF EXISTS tps.%I',_defn->>'name');
------------------create new type--------------------------------------------
@ -81,15 +81,15 @@ BEGIN
--unwrap the schema definition array
LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE
WHERE
srce = _name
srce = _defn->>'name'
GROUP BY
srce;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_name,_sql;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_defn->>'name',_sql;
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_name,_sql);
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_defn->>'name',_sql);
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_name,(_defn->>'description'));
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_defn->>'name',(_defn->>'description'));
----------------set message-----------------------------------------------------

View File

@ -10,6 +10,7 @@ The goal is to:
It is well suited for data from outside systems that
* requires complex transformation (parsing and mapping)
* original data is retained for reference
* don't feel like writing a map-reduce
use cases:
* on-going bank feeds

View File

@ -1,43 +0,0 @@
DELETE FROM tps.map_rm;
INSERT INTO
tps.map_rm
SELECT *
FROM
(VALUES
('DCARD', 'First 20',
$j$
{
"defn": [
{
"key": "{Description}",
"field": "f20",
"regex": ".{1,20}"
,"retain":"y"
}
],
"where": [
{
}
]
}
$j$::jsonb
, 2)
,('HUNT', 'First 20',
$j$
{
"defn": [
{
"key": "{Description}",
"field": "f20",
"regex": ".{1,20}"
,"retain":"y"
}
],
"where": [
{
}
]
}
$j$::jsonb
, 1)
) x

View File

@ -0,0 +1,462 @@
{
"strip commas":
{
"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",
"map": "n"
}
],
"function": "replace",
"where": [
{}
]
},
"Parse ACH Credits":
{
"name": "Parse ACH Credits",
"description": "parse select components of the description for ACH Credits Receieved",
"defn": [
{
"key": "{Description}",
"field": "beneficiary",
"regex": "Comp Name:(.+?)(?=\\d{6} Com|SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"key": "{Description}",
"field": "originator",
"regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
}
],
"function": "extract",
"where": [
{
"Transaction": "ACH Credits"
}
]
},
"Parse ACH Debits":
{
"name": "Parse ACH Debits",
"description": "parse select components of the description for ACH Credits Receieved",
"defn": [
{
"key": "{Description}",
"field": "originator",
"regex": "Comp Name:(.+?)(?=\\d{6} Com|SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"key": "{Description}",
"field": "beneficiary",
"regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
},
{
"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",
"map": "n"
}
],
"function": "extract",
"where": [
{
"Transaction": "ACH Debits"
}
]
},
"Parse Wires":
{
"name": "Parse Wires",
"description": "pull out whatever follows OBI in the description until atleast 3 capital letters followed by a colon are encountered",
"defn": [
{
"key": "{Description}",
"field": "dparse",
"regex": "([A-Z]{3,}?:)(.*)(?=[A-Z]{3,}?:|$)",
"flag": "g",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "beneficiary_components",
"regex": "BENEFICIARY:(.*?)AC/(\\d*) (.*)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "originator_components",
"regex": "ORIGINATOR:(.*?)AC/(\\d*) (.*)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "beneficiary",
"regex": "BENEFICIARY:(.*?)AC/\\d* .*(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "originator",
"regex": "ORIGINATOR:(.*?)AC/\\d* .*(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "OBI",
"regex": "OBI:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "RFB",
"regex": "RFB:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "ABA",
"regex": "ABA:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "BBI",
"regex": "BBI:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "BENEBNK",
"regex": "BENEBNK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "IBK",
"regex": "IBK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "RATE",
"regex": "RATE:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
},
{
"key": "{Description}",
"field": "RECVBNK",
"regex": "RECVBNK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag": "",
"retain": "y",
"map": "n"
}
],
"function": "extract",
"where": [
{
"Transaction": "Money Transfer DB - Wire"
},
{
"Transaction": "Money Transfer DB - Other"
},
{
"Transaction": "Money Transfer CR-Wire"
},
{
"Transaction": "Money Transfer CR-Other"
},
{
"Transaction": "Intl Money Transfer Debits"
},
{
"Transaction": "Intl Money Transfer Credits"
}
]
},
"Trans Type":
{
"name": "Trans Type",
"description": "extract intial description in conjunction with account name and transaction type for mapping",
"defn": [
{
"key": "{AccountName}",
"field": "acctn",
"regex": "(.*)",
"retain": "n",
"map": "y"
},
{
"key": "{Transaction}",
"field": "trans",
"regex": "(.*)",
"retain": "n",
"map": "y"
},
{
"key": "{Description}",
"field": "ini",
"regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)",
"retain": "y",
"map": "y"
}
],
"where": [
{}
],
"function": "extract"
},
"Currency":
{
"name": "Currency",
"description": "pull out currency indicators from description of misc items and map",
"defn": [
{
"key": "{Description}",
"field": "ini",
"regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)",
"retain": "y",
"map": "y"
},
{
"key": "{Description}",
"field": "curr1",
"regex": ".*(DEBIT|CREDIT).*(USD|CAD).*(?=DEBIT|CREDIT).*(?=USD|CAD).*",
"retain": "y",
"map": "y"
},
{
"key": "{Description}",
"field": "curr2",
"regex": ".*(?=DEBIT|CREDIT).*(?=USD|CAD).*(DEBIT|CREDIT).*(USD|CAD).*",
"retain": "y",
"map": "y"
}
],
"where": [
{
"Transaction": "Miscellaneous Credits"
},
{
"Transaction": "Miscellaneous Debits"
}
],
"function": "extract"
},
"check number":
{
"defn": [
{
"key": "{Description}",
"field": "checkn",
"regex": "[^0-9]*([0-9]*)\\s|$",
"retain": "y",
"map": "n"
}
],
"where": [
{
"Transaction": "Checks Paid"
}
],
"function": "extract"
},
"ADP Codes":
{
"name": "ADP Codes",
"description": "link to adp code definitions",
"defn": [
{
"key": "{gl_descr}",
"field": "gl_descr",
"regex": ".*",
"flag": "",
"retain": "n",
"map": "y"
},
{
"key": "{prim_offset}",
"field": "prim_offset",
"regex": ".*",
"flag": "",
"retain": "n",
"map": "y"
},
{
"key": "{pay_date}",
"field": "pay_month",
"regex": ".{1,4}",
"flag": "",
"retain": "y",
"map": "n"
}
],
"function": "extract",
"where": [
{}
]
}
}

View File

@ -1,510 +0,0 @@
UPDATE tps.map_rm
SET regex =
$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",
"map":"n"
}
],
"function":"replace",
"where": [
{
}
]
}
$j$::jsonb
WHERE
target = 'Strip Amount Commas';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"Parse ACH Credits",
"description":"parse select components of the description for ACH Credits Receieved",
"defn": [
{
"key": "{Description}",
"field":"beneficiary",
"regex": "Comp Name:(.+?)(?=\\d{6} Com|SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"key": "{Description}",
"field":"originator",
"regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
}
],
"function":"extract",
"where": [
{
"Transaction":"ACH Credits"
}
]
}
$j$::jsonb
WHERE target = 'Parse ACH Credits';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"Parse ACH Debits",
"description":"parse select components of the description for ACH Credits Receieved",
"defn": [
{
"key": "{Description}",
"field":"originator",
"regex": "Comp Name:(.+?)(?=\\d{6} Com|SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"key": "{Description}",
"field":"beneficiary",
"regex": "Cust Name:(.+?)(?=SEC:|Cust ID:|Desc:|Comp Name:|Comp ID:|Batch Discr:|Cust Name:|Addenda:|SETT:|Date:|Time:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
},
{
"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",
"map":"n"
}
],
"function":"extract",
"where": [
{
"Transaction":"ACH Debits"
}
]
}
$j$::jsonb
WHERE target = 'Parse ACH Debits';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"Parse Wires",
"description":"pull out whatever follows OBI in the description until atleast 3 capital letters followed by a colon are encountered",
"defn": [
{
"key": "{Description}",
"field": "dparse",
"regex": "([A-Z]{3,}?:)(.*)(?=[A-Z]{3,}?:|$)",
"flag":"g",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "beneficiary_components",
"regex": "BENEFICIARY:(.*?)AC/(\\d*) (.*)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "originator_components",
"regex": "ORIGINATOR:(.*?)AC/(\\d*) (.*)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "beneficiary",
"regex": "BENEFICIARY:(.*?)AC/\\d* .*(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "originator",
"regex": "ORIGINATOR:(.*?)AC/\\d* .*(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "OBI",
"regex": "OBI:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "RFB",
"regex": "RFB:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "ABA",
"regex": "ABA:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "BBI",
"regex": "BBI:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "BENEBNK",
"regex": "BENEBNK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "IBK",
"regex": "IBK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "RATE",
"regex": "RATE:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
},
{
"key": "{Description}",
"field": "RECVBNK",
"regex": "RECVBNK:(.*?)(?=[A-Z]{3,}?:|$)",
"flag":"",
"retain":"y",
"map":"n"
}
],
"function":"extract",
"where": [
{
"Transaction":"Money Transfer DB - Wire"
},
{
"Transaction":"Money Transfer DB - Other"
},
{
"Transaction":"Money Transfer CR-Wire"
},
{
"Transaction":"Money Transfer CR-Other"
},
{
"Transaction":"Intl Money Transfer Debits"
},
{
"Transaction":"Intl Money Transfer Credits"
}
]
}
$j$::jsonb
WHERE target = 'Parse Wires';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"Trans Type",
"description":"extract intial description in conjunction with account name and transaction type for mapping",
"defn": [
{
"key": "{AccountName}",
"field": "acctn",
"regex": "(.*)",
"retain": "n",
"map":"y"
},
{
"key": "{Transaction}",
"field": "trans",
"regex": "(.*)",
"retain": "n",
"map":"y"
},
{
"key": "{Description}",
"field": "ini",
"regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)",
"retain": "y",
"map":"y"
}
],
"where": [
{
}
],
"function": "extract"
}
$j$::jsonb
WHERE target = 'Trans Type';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"Currency",
"description":"pull out currency indicators from description of misc items and map",
"defn": [
{
"key": "{Description}",
"field": "ini",
"regex": "([\\w].*?)(?=$| -|\\s[0-9].*?|\\s[\\w/]+?:)",
"retain": "y",
"map":"y"
},
{
"key": "{Description}",
"field": "curr1",
"regex": ".*(DEBIT|CREDIT).*(USD|CAD).*(?=DEBIT|CREDIT).*(?=USD|CAD).*",
"retain": "y",
"map":"y"
},
{
"key": "{Description}",
"field": "curr2",
"regex": ".*(?=DEBIT|CREDIT).*(?=USD|CAD).*(DEBIT|CREDIT).*(USD|CAD).*",
"retain": "y",
"map":"y"
}
],
"where": [
{
"Transaction": "Miscellaneous Credits"
},
{
"Transaction": "Miscellaneous Debits"
}
],
"function": "extract"
}
$j$::jsonb
WHERE target = 'Currency';
UPDATE tps.map_rm
SET regex =
$j$
{
"defn": [
{
"key": "{Description}",
"field": "checkn",
"regex": "[^0-9]*([0-9]*)\\s|$",
"retain": "y",
"map":"n"
}
],
"where": [
{
"Transaction": "Checks Paid"
}
],
"function": "extract"
}
$j$::jsonb
WHERE target = 'Check Number';
UPDATE tps.map_rm
SET regex =
$j$
{
"name":"ADP Codes",
"description":"link to adp code definitions",
"defn": [
{
"key": "{gl_descr}",
"field": "gl_descr",
"regex": ".*",
"flag":"",
"retain":"n",
"map":"y"
},
{
"key": "{prim_offset}",
"field": "prim_offset",
"regex": ".*",
"flag":"",
"retain":"n",
"map":"y"
},
{
"key": "{pay_date}",
"field": "pay_month",
"regex": ".{1,4}",
"flag":"",
"retain":"y",
"map":"n"
}
],
"function":"extract",
"where": [
{
}
]
}
$j$::jsonb
WHERE
target = 'ADP Codes';

View File

@ -1,7 +1,3 @@
UPDATE tps.SRCE
SET DEFN =
$$
{
"name": "WMPD",
"descr": "Williams Paid File",
@ -123,6 +119,3 @@ $$
]
}
}
$$::JSONB
WHERE
SRCE = 'WMPD'