diff --git a/.gitignore b/.gitignore index afe4bb3..c6114bc 100644 --- a/.gitignore +++ b/.gitignore @@ -1 +1,4 @@ .vscode/database.json +.dbeaver-data-sources.xml +.project +Scripts/ diff --git a/deploy/ubm_schema.sql b/deploy/ubm_schema.sql index 2f12333..7a51994 100644 --- a/deploy/ubm_schema.sql +++ b/deploy/ubm_schema.sql @@ -30,6 +30,19 @@ COMMENT ON SCHEMA tps IS 'third party source'; SET search_path = tps, pg_catalog; +-- +-- Name: DCARD; Type: TYPE; Schema: tps; Owner: - +-- + +CREATE TYPE "DCARD" AS ( + "Trans. Date" date, + "Post Date" date, + "Description" text, + "Amount" numeric, + "Category" text +); + + -- -- Name: dcard; Type: TYPE; Schema: tps; Owner: - -- @@ -350,6 +363,62 @@ END $_$; +-- +-- Name: srce_map_def_set(text, text, jsonb, integer); Type: FUNCTION; Schema: tps; Owner: - +-- + +CREATE FUNCTION srce_map_def_set(_srce text, _map text, _defn jsonb, _seq integer) RETURNS jsonb + LANGUAGE plpgsql + AS $_$ + +DECLARE + _message jsonb; + _MESSAGE_TEXT text; + _PG_EXCEPTION_DETAIL text; + _PG_EXCEPTION_HINT text; + +BEGIN + + BEGIN + + INSERT INTO + tps.map_rm + SELECT + _srce + ,_map + ,_defn + ,_seq + ON CONFLICT ON CONSTRAINT map_rm_pk DO UPDATE SET + srce = _srce + ,target = _map + ,regex = _defn + ,seq = _seq; + + 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; + + _message:= jsonb_build_object('status','complete','message','definition has been set'); + return _message; + +END; +$_$; + + -- -- Name: srce_set(text, jsonb); Type: FUNCTION; Schema: tps; Owner: - -- @@ -362,6 +431,7 @@ DECLARE _cnt int; _conflict BOOLEAN; _message jsonb; +_sql text; BEGIN @@ -395,10 +465,11 @@ BEGIN return _message; END IF; - /*-----------------schema validation--------------------- - yeah dont feel like it right now + /*------------------------------------------------------- + schema validation ---------------------------------------------------------*/ + -------------------insert definition---------------------------------------- INSERT INTO tps.srce SELECT @@ -407,6 +478,31 @@ BEGIN SET defn = _defn; + ------------------drop existing type----------------------------------------- + + EXECUTE format('DROP TYPE IF EXISTS tps.%I',_name); + + ------------------create new type-------------------------------------------- + + SELECT + string_agg(quote_ident(prs.key)||' '||prs.type,',') + INTO + _sql + FROM + tps.srce + --unwrap the schema definition array + LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE + WHERE + srce = _name + GROUP BY + srce; + + RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_name,_sql; + + EXECUTE format('CREATE TYPE tps.%I AS (%s)',_name,_sql); + + ----------------set message----------------------------------------------------- + _message = $$ { diff --git a/functions/manual_do_map_g_option.pgsql b/functions/manual_do_map_g_option.sql similarity index 100% rename from functions/manual_do_map_g_option.pgsql rename to functions/manual_do_map_g_option.sql diff --git a/functions/manual_srce.pgsql b/functions/manual_srce.sql similarity index 100% rename from functions/manual_srce.pgsql rename to functions/manual_srce.sql diff --git a/functions/srce_edit.pgsql b/functions/srce_edit.sql similarity index 58% rename from functions/srce_edit.pgsql rename to functions/srce_edit.sql index cbfae26..e2eef8c 100644 --- a/functions/srce_edit.pgsql +++ b/functions/srce_edit.sql @@ -6,6 +6,7 @@ DECLARE _cnt int; _conflict BOOLEAN; _message jsonb; +_sql text; BEGIN @@ -39,10 +40,11 @@ BEGIN return _message; END IF; - /*-----------------schema validation--------------------- - yeah dont feel like it right now + /*------------------------------------------------------- + schema validation ---------------------------------------------------------*/ + -------------------insert definition---------------------------------------- INSERT INTO tps.srce SELECT @@ -51,6 +53,31 @@ BEGIN SET defn = _defn; + ------------------drop existing type----------------------------------------- + + EXECUTE format('DROP TYPE IF EXISTS tps.%I',_name); + + ------------------create new type-------------------------------------------- + + SELECT + string_agg(quote_ident(prs.key)||' '||prs.type,',') + INTO + _sql + FROM + tps.srce + --unwrap the schema definition array + LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE + WHERE + srce = _name + GROUP BY + srce; + + RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_name,_sql; + + EXECUTE format('CREATE TYPE tps.%I AS (%s)',_name,_sql); + + ----------------set message----------------------------------------------------- + _message = $$ { diff --git a/functions/srce_import.pgsql b/functions/srce_import.sql similarity index 100% rename from functions/srce_import.pgsql rename to functions/srce_import.sql diff --git a/functions/srce_map_set.sql b/functions/srce_map_set.sql new file mode 100644 index 0000000..6ef417c --- /dev/null +++ b/functions/srce_map_set.sql @@ -0,0 +1,51 @@ +CREATE OR REPLACE FUNCTION tps.srce_map_def_set(_srce text, _map text, _defn jsonb, _seq int) RETURNS jsonb +AS +$f$ + +DECLARE + _message jsonb; + _MESSAGE_TEXT text; + _PG_EXCEPTION_DETAIL text; + _PG_EXCEPTION_HINT text; + +BEGIN + + BEGIN + + INSERT INTO + tps.map_rm + SELECT + _srce + ,_map + ,_defn + ,_seq + ON CONFLICT ON CONSTRAINT map_rm_pk DO UPDATE SET + srce = _srce + ,target = _map + ,regex = _defn + ,seq = _seq; + + 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; + + _message:= jsonb_build_object('status','complete','message','definition has been set'); + return _message; + +END; +$f$ +language plpgsql \ No newline at end of file diff --git a/reports/all_map_return_values.sql b/reports/all_map_return_values.sql new file mode 100644 index 0000000..1f802b3 --- /dev/null +++ b/reports/all_map_return_values.sql @@ -0,0 +1,245 @@ +/* +first get distinct target json values +then apply regex +*/ + + +WITH + +--------------------apply regex operations to transactions--------------------------------------------------------------------------------- + +rx AS ( +SELECT + t.srce, + t.id, + t.rec, + m.target, + m.seq, + regex->>'function' regex_function, + e.v ->> 'field' result_key_name, + e.v ->> 'key' target_json_path, + e.v ->> 'flag' regex_options_flag, + e.v->>'map' map_intention, + 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, + --------------------------json key name assigned to return value----------------------------------------------------------------------- + CASE e.v->>'map' + WHEN 'y' THEN + e.v->>'field' + ELSE + null + END map_key, + --------------------------json value resulting from regular expression----------------------------------------------------------------- + CASE e.v->>'map' + WHEN 'y' 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, + --------------------------flag for if retruned regex result is stored as a new part of the final json output--------------------------- + CASE e.v->>'retain' + WHEN 'y' THEN + e.v->>'field' + ELSE + NULL + END retain_key, + --------------------------push regex result into json object--------------------------------------------------------------------------- + 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 + --------------------------start with all regex maps------------------------------------------------------------------------------------ + tps.map_rm m + --------------------------isolate matching basis to limit map to only look at certain json--------------------------------------------- + JOIN LATERAL jsonb_array_elements(m.regex->'where') w(v) ON TRUE + --------------------------break out array of regluar expressions in the map------------------------------------------------------------ + JOIN LATERAL jsonb_array_elements(m.regex->'defn') WITH ORDINALITY e(v, rn) ON true + --------------------------join to main transaction table but only certain key/values are included-------------------------------------- + INNER JOIN tps.trans t ON + t.srce = m.srce AND + t.rec @> w.v + --------------------------each regex references a path to the target value, extract the target from the reference and do regex--------- + 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' + --------------------------same as above but for a replacement type function------------------------------------------------------------ + 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.allj IS NULL + --t.srce = 'PNCC' AND + e.v @> '{"map":"y"}'::jsonb + --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 LIMIT 100 + + +, agg_to_target_items AS ( +SELECT + srce + ,id + ,target + ,seq + ,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 + ,seq + ,map_intention + ,regex_function + ,target_item_number + ,result_key_name + ,target_json_path + ,map_key + ,retain_key +) + +--SELECT * FROM agg_to_target_items LIMIT 100 + + +, agg_to_target AS ( +SELECT + srce + ,id + ,target + ,seq + ,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 + ,seq + ,map_intention +) + + +, agg_to_ret AS ( +SELECT + srce + ,target + ,seq + ,map_intention + ,map_val + ,retain_val + ,count(*) "count" +FROM + agg_to_target +GROUP BY + srce + ,target + ,seq + ,map_intention + ,map_val + ,retain_val +) + +, link_map AS ( +SELECT + a.srce + ,a.target + ,a.seq + ,a.map_intention + ,a.map_val + ,a."count" + ,a.retain_val + ,v.map mapped_val +FROM + agg_to_ret 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 + l.srce + ,l.target + ,l.seq + ,l.map_intention + ,l.map_val + ,l."count" + ,l.retain_val + ,l.mapped_val +FROM + link_map l +ORDER BY + l.srce + ,l.target + ,l.seq + ,l."count" + ,l.map_val + ,l.mapped_val \ No newline at end of file diff --git a/sample_discovercard/mapping.md b/sample_discovercard/mapping.md index 8f92787..5fe8f94 100644 --- a/sample_discovercard/mapping.md +++ b/sample_discovercard/mapping.md @@ -79,11 +79,12 @@ map definition SQL --------------------------------------------- -INSERT INTO - tps.map_rm -SELECT - 'DCARD', - 'First 20', +select + x.x +from + TPS.srce_map_def_set( + 'DCARD'::text, + 'First 20'::text, $$ { "defn": [ { @@ -103,7 +104,8 @@ SELECT "function": "extract", "description": "pull first 20 characters from description for mapping" } $$::jsonb, - 1 + 1::int + ) x(x) assign new key/values to the results of the regular expression, and then back to the underlying row it came from