setup new files

This commit is contained in:
Paul Trowbridge 2018-05-23 00:31:45 -04:00
parent 18a7bacb73
commit b6c1126ecb
6 changed files with 721 additions and 3 deletions

146
deploy/setup.sql Normal file
View File

@ -0,0 +1,146 @@
------create dev schema and api user-----------------------------------------------------------------------------------------------------------------
DROP SCHEMA IF EXISTS tps CASCADE;
DROP SCHEMA IF EXISTS tpsv CASCADE;
CREATE SCHEMA tps;
COMMENT ON SCHEMA tps IS 'third party source data';
CREATE SCHEMA tpsv;
COMMENT ON SCHEMA tps IS 'third party source views';
DROP USER IF EXISTS api;
CREATE USER api WITH
LOGIN
NOSUPERUSER
NOCREATEDB
NOCREATEROLE
INHERIT
NOREPLICATION
CONNECTION LIMIT -1
ENCRYPTED PASSWORD 'md56da13b696f737097e0146e47cc0d0985';
-----need to setup all database objects and then grant priveledges to api----------------------------------------------------------------------------
--grant current table privledges
GRANT SELECT, UPDATE, INSERT, DELETE ON ALL TABLES IN SCHEMA tps TO api;
GRANT SELECT, UPDATE, INSERT, DELETE ON ALL TABLES IN SCHEMA tpsv TO api;
--grant current sequence privledges
GRANT USAGE ON ALL SEQUENCES IN SCHEMA tps TO api;
GRANT USAGE ON ALL SEQUENCES IN SCHEMA tpsv TO api;
--grant future table privledges
ALTER DEFAULT PRIVILEGES IN SCHEMA tps GRANT SELECT, UPDATE, INSERT, DELETE ON TABLES TO api;
ALTER DEFAULT PRIVILEGES IN SCHEMA tpsv GRANT SELECT, UPDATE, INSERT, DELETE ON TABLES TO api;
--grant future sequence privledges
ALTER DEFAULT PRIVILEGES IN SCHEMA tps GRANT USAGE ON SEQUENCES TO api;
ALTER DEFAULT PRIVILEGES IN SCHEMA tpsv GRANT USAGE ON SEQUENCES TO api;
-----create tables-----------------------------------------------------------------------------------------------------------------------------------
-----regex map instructions table
CREATE TABLE tps.map_rm (
srce text NOT NULL,
target text NOT NULL,
regex jsonb,
seq integer NOT NULL
);
COMMENT ON TABLE tps.map_rm IS 'regex map instructions';
-----return value table
CREATE TABLE tps.map_rv (
srce text NOT NULL,
target text NOT NULL,
retval jsonb NOT NULL,
map jsonb
);
COMMENT ON TABLE tps.map_rv IS 'return value lookup table';
-----source definition table
CREATE TABLE tps.srce (
srce text NOT NULL,
defn jsonb
);
COMMENT ON TABLE tps.srce IS 'source master listing and definition';
-----source data table
CREATE TABLE tps.trans (
id integer NOT NULL,
srce text,
rec jsonb,
parse jsonb,
map jsonb,
allj jsonb,
ic jsonb
);
COMMENT ON TABLE tps.trans IS 'source records';
COMMENT ON COLUMN tps.trans.ic IS 'input constraint value';
ALTER TABLE tps.trans ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
SEQUENCE NAME tps.trans_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1
);
-----import log table
CREATE TABLE tps.trans_log (
id integer NOT NULL,
info jsonb
);
COMMENT ON TABLE tps.trans_log IS 'import event information';
ALTER TABLE tps.trans_log ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY (
SEQUENCE NAME tps.trans_log_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1
);
-------------primary keys----------------------------------------------------------------------------------------------------------------------------
ALTER TABLE ONLY tps.map_rm
ADD CONSTRAINT map_rm_pk PRIMARY KEY (srce, target);
ALTER TABLE ONLY tps.map_rv
ADD CONSTRAINT map_rv_pk PRIMARY KEY (srce, target, retval);
ALTER TABLE ONLY tps.srce
ADD CONSTRAINT srce_pkey PRIMARY KEY (srce);
ALTER TABLE ONLY tps.trans_log
ADD CONSTRAINT trans_log_pkey PRIMARY KEY (id);
ALTER TABLE ONLY tps.trans
ADD CONSTRAINT trans_pkey PRIMARY KEY (id);
-------------indexes---------------------------------------------------------------------------------------------------------------------------------
CREATE INDEX trans_allj ON tps.trans USING gin (allj);
CREATE INDEX trans_rec ON tps.trans USING gin (rec);
CREATE INDEX trans_srce ON tps.trans USING btree (srce);
-------------foreign keys----------------------------------------------------------------------------------------------------------------------------
ALTER TABLE ONLY tps.map_rm
ADD CONSTRAINT map_rm_fk_srce FOREIGN KEY (srce) REFERENCES tps.srce(srce);
ALTER TABLE ONLY tps.map_rv
ADD CONSTRAINT map_rv_fk_rm FOREIGN KEY (srce, target) REFERENCES tps.map_rm(srce, target);
ALTER TABLE ONLY tps.trans
ADD CONSTRAINT trans_srce_fkey FOREIGN KEY (srce) REFERENCES tps.srce(srce);

View File

@ -0,0 +1,107 @@
CREATE OR REPLACE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb
AS $f$
DECLARE
_cnt int;
_conflict BOOLEAN;
_message jsonb;
_sql text;
_cur_sch jsonb;
BEGIN
/*
1. determine if insert or update
2. if update, determine if conflicts exists
3. do merge
*/
-------extract current source schema for compare--------------------------
SELECT
defn->'schema'
INTO
_cur_sch
FROM
tps.srce
WHERE
srce = _defn->>'name';
-------check for transctions already existing under this source-----------
SELECT
COUNT(*)
INTO
_cnt
FROM
tps.trans
WHERE
srce = _defn->>'name';
--if there are transaction already and the schema is different stop--------
IF _cnt > 0 THEN
IF _cur_sch <> _defn->'schema' THEN
_conflict = TRUE;
--get out of the function somehow
_message =
$$
{
"message":"transactions already exist under source profile and there is a pending schema change"
,"status":"error"
}
$$::jsonb;
return _message;
END IF;
END IF;
/*-------------------------------------------------------
do schema validation fo _defn object?
---------------------------------------------------------*/
-------------------insert definition----------------------------------------
INSERT INTO
tps.srce
SELECT
_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',_defn->>'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 = _defn->>'name'
GROUP BY
srce;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_defn->>'name',_sql;
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_defn->>'name',_sql);
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_defn->>'name',(_defn->>'description'));
----------------set message-----------------------------------------------------
_message =
$$
{
"message":"definition set"
,"status":"success"
}
$$::jsonb;
return _message;
END;
$f$
LANGUAGE plpgsql

View File

@ -0,0 +1,150 @@
DO $f$
DECLARE
_defn jsonb;
_cnt int;
_conflict BOOLEAN;
_message jsonb;
_sql text;
_cur_sch jsonb;
BEGIN
SELECT
$$
{
"name":"dcard",
"source":"client_file",
"loading_function":"csv",
"constraint":[
"{Trans. Date}",
"{Post Date}"
],
"schemas":{
"default":[
{
"path":"{Trans. Date}",
"type":"date",
"column_name":"Trans. Date"
},
{
"path":"{Post Date}",
"type":"date",
"column_name":"Post Date"
},
{
"path":"{Description}",
"type":"text",
"column_name":"Description"
},
{
"path":"{Amount}",
"type":"numeric",
"column_name":"Amount"
},
{
"path":"{Category}",
"type":"text",
"column_name":"Category"
}
],
"version2":[]
}
}
$$
INTO
_defn;
/*
1. determine if insert or update
2. if update, determine if conflicts exists
3. do merge
*/
-------extract current source schema for compare--------------------------
SELECT
defn#>'{schemas,default}'
INTO
_cur_sch
FROM
tps.srce
WHERE
srce = _defn->>'name';
-------check for transctions already existing under this source-----------
SELECT
COUNT(*)
INTO
_cnt
FROM
tps.trans
WHERE
srce = _defn->>'name';
--if there are transaction already and the schema is different stop--------
IF _cnt > 0 THEN
IF _cur_sch <> _defn->'schema' THEN
_conflict = TRUE;
--get out of the function somehow
_message =
$$
{
"message": "transactions already exist under source profile and there is a pending schema change",
"status": "error"
}
$$: :jsonb;
return _message;
END IF;
END IF;
/*-------------------------------------------------------
do schema validation fo _defn object?
---------------------------------------------------------*/
-------------------insert definition----------------------------------------
INSERT INTO
tps.srce
SELECT
_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',_defn->>'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 = _defn->>'name'
GROUP BY
srce;
RAISE NOTICE 'CREATE TYPE tps.% AS (%)',_defn->>'name',_sql;
EXECUTE format('CREATE TYPE tps.%I AS (%s)',_defn->>'name',_sql);
EXECUTE format('COMMENT ON TYPE tps.%I IS %L',_defn->>'name',(_defn->>'description'));
----------------set message-----------------------------------------------------
_message =
$$
{
"message": "definition set",
"status": "success"
}
$$: :jsonb;
return _message;
END;
$f$
LANGUAGE plpgsql

View File

@ -87,13 +87,14 @@ source definition
```
{
"name":"sample_name",
"name":"dcard",
"source":"client_file",
"loading_function":"csv"
"constraint":[
"{doc}"
"{Trans. Date}",
"{Post Date}"
],
"table_views":{
"schemas":{
"default":[
{
"path":"{doc,origin_addresses,0}",

View File

@ -0,0 +1,275 @@
[
{
"Trans. Date": "1/2/2018",
"Post Date": "1/2/2018",
"Description": "GOOGLE *YOUTUBE VIDEOS G.CO/HELPPAY#CAP0H07TXV",
"Amount": 4.26,
"Category": "Services"
},
{
"Trans. Date": "1/2/2018",
"Post Date": "1/2/2018",
"Description": "MICROSOFT *ONEDRIVE 800-642-7676 WA",
"Amount": 4.26,
"Category": "Services"
},
{
"Trans. Date": "1/3/2018",
"Post Date": "1/3/2018",
"Description": "CLE CLINIC PT PMTS 216-445-6249 OHAK2C57F2F0B3",
"Amount": 200,
"Category": "Medical Services"
},
{
"Trans. Date": "1/4/2018",
"Post Date": "1/4/2018",
"Description": "AT&T *PAYMENT 800-288-2020 TX",
"Amount": 57.14,
"Category": "Services"
},
{
"Trans. Date": "1/4/2018",
"Post Date": "1/7/2018",
"Description": "WWW.KOHLS.COM #0873 MIDDLETOWN OH",
"Amount": -7.9,
"Category": "Payments and Credits"
},
{
"Trans. Date": "1/5/2018",
"Post Date": "1/7/2018",
"Description": "PIZZA HUT 007946 STOW OH",
"Amount": 9.24,
"Category": "Restaurants"
},
{
"Trans. Date": "1/5/2018",
"Post Date": "1/7/2018",
"Description": "SUBWAY 00044289255 STOW OH",
"Amount": 10.25,
"Category": "Restaurants"
},
{
"Trans. Date": "1/6/2018",
"Post Date": "1/7/2018",
"Description": "ACME NO. 17 STOW OH",
"Amount": 103.98,
"Category": "Supermarkets"
},
{
"Trans. Date": "1/6/2018",
"Post Date": "1/7/2018",
"Description": "DISCOUNT DRUG MART 32 STOW OH",
"Amount": 1.69,
"Category": "Merchandise"
},
{
"Trans. Date": "1/6/2018",
"Post Date": "1/7/2018",
"Description": "DISCOUNT DRUG MART 32 STOW OH",
"Amount": 2.19,
"Category": "Merchandise"
},
{
"Trans. Date": "1/9/2018",
"Post Date": "1/9/2018",
"Description": "CIRCLE K 05416 STOW OH00947R",
"Amount": 3.94,
"Category": "Gasoline"
},
{
"Trans. Date": "1/9/2018",
"Post Date": "1/9/2018",
"Description": "CIRCLE K 05416 STOW OH00915R",
"Amount": 52.99,
"Category": "Gasoline"
},
{
"Trans. Date": "1/13/2018",
"Post Date": "1/13/2018",
"Description": "AUTOZONE #0722 STOW OH",
"Amount": 85.36,
"Category": "Automotive"
},
{
"Trans. Date": "1/13/2018",
"Post Date": "1/13/2018",
"Description": "DISCOUNT DRUG MART 32 STOW OH",
"Amount": 26.68,
"Category": "Merchandise"
},
{
"Trans. Date": "1/13/2018",
"Post Date": "1/13/2018",
"Description": "EL CAMPESINO STOW OH",
"Amount": 6.5,
"Category": "Restaurants"
},
{
"Trans. Date": "1/13/2018",
"Post Date": "1/13/2018",
"Description": "TARGET STOW OH",
"Amount": 197.9,
"Category": "Merchandise"
},
{
"Trans. Date": "1/14/2018",
"Post Date": "1/14/2018",
"Description": "DISCOUNT DRUG MART 32 STOW OH",
"Amount": 13.48,
"Category": "Merchandise"
},
{
"Trans. Date": "1/15/2018",
"Post Date": "1/15/2018",
"Description": "TARGET.COM * 800-591-3869 MN",
"Amount": 22.41,
"Category": "Merchandise"
},
{
"Trans. Date": "1/16/2018",
"Post Date": "1/16/2018",
"Description": "BUFFALO WILD WINGS KENT KENT OH",
"Amount": 63.22,
"Category": "Restaurants"
},
{
"Trans. Date": "1/16/2018",
"Post Date": "1/16/2018",
"Description": "PARTA - KCG KENT OH",
"Amount": 4,
"Category": "Government Services"
},
{
"Trans. Date": "1/16/2018",
"Post Date": "1/16/2018",
"Description": "REMEMBERNHU 402-935-7733 IA",
"Amount": 60,
"Category": "Services"
},
{
"Trans. Date": "1/16/2018",
"Post Date": "1/16/2018",
"Description": "TARGET.COM * 800-591-3869 MN",
"Amount": 44.81,
"Category": "Merchandise"
},
{
"Trans. Date": "1/16/2018",
"Post Date": "1/16/2018",
"Description": "TREE CITY COFFEE & PASTR KENT OH",
"Amount": 17.75,
"Category": "Restaurants"
},
{
"Trans. Date": "1/17/2018",
"Post Date": "1/17/2018",
"Description": "BESTBUYCOM805526794885 888-BESTBUY MN",
"Amount": 343.72,
"Category": "Merchandise"
},
{
"Trans. Date": "1/19/2018",
"Post Date": "1/19/2018",
"Description": "DISCOUNT DRUG MART 32 STOW OH",
"Amount": 5.98,
"Category": "Merchandise"
},
{
"Trans. Date": "1/19/2018",
"Post Date": "1/19/2018",
"Description": "U-HAUL OF KENT-STOW KENT OH",
"Amount": 15.88,
"Category": "Travel/ Entertainment"
},
{
"Trans. Date": "1/19/2018",
"Post Date": "1/19/2018",
"Description": "WALMART GROCERY 800-966-6546 AR",
"Amount": 5.99,
"Category": "Supermarkets"
},
{
"Trans. Date": "1/19/2018",
"Post Date": "1/19/2018",
"Description": "WALMART GROCERY 800-966-6546 AR",
"Amount": 17.16,
"Category": "Supermarkets"
},
{
"Trans. Date": "1/19/2018",
"Post Date": "1/19/2018",
"Description": "WALMART GROCERY 800-966-6546 AR",
"Amount": 500.97,
"Category": "Supermarkets"
},
{
"Trans. Date": "1/20/2018",
"Post Date": "1/20/2018",
"Description": "GOOGLE *GOOGLE PLAY G.CO/HELPPAY#CAP0HFFS7W",
"Amount": 2.12,
"Category": "Services"
},
{
"Trans. Date": "1/20/2018",
"Post Date": "1/20/2018",
"Description": "LOWE'S OF STOW, OH. STOW OH",
"Amount": 256.48,
"Category": "Home Improvement"
},
{
"Trans. Date": "1/23/2018",
"Post Date": "1/23/2018",
"Description": "CASHBACK BONUS REDEMPTION PYMT/STMT CRDT",
"Amount": -32.2,
"Category": "Awards and Rebate Credits"
},
{
"Trans. Date": "1/23/2018",
"Post Date": "1/23/2018",
"Description": "INTERNET PAYMENT - THANK YOU",
"Amount": -2394.51,
"Category": "Payments and Credits"
},
{
"Trans. Date": "1/27/2018",
"Post Date": "1/27/2018",
"Description": "GIANT-EAGLE #4096 STOW OH",
"Amount": 67.81,
"Category": "Supermarkets"
},
{
"Trans. Date": "1/27/2018",
"Post Date": "1/27/2018",
"Description": "OFFICEMAX/OFFICE DEPOT63 STOW OH",
"Amount": 21.06,
"Category": "Merchandise"
},
{
"Trans. Date": "1/27/2018",
"Post Date": "1/27/2018",
"Description": "TARGET STOW OH",
"Amount": 71,
"Category": "Merchandise"
},
{
"Trans. Date": "1/29/2018",
"Post Date": "1/29/2018",
"Description": "NETFLIX.COM NETFLIX.COM CA19899514437",
"Amount": 14.93,
"Category": "Services"
},
{
"Trans. Date": "1/30/2018",
"Post Date": "1/30/2018",
"Description": "SQ *TWISTED MELTZ KENT OH0002305843011416898511",
"Amount": 16.87,
"Category": "Restaurants"
},
{
"Trans. Date": "1/30/2018",
"Post Date": "1/30/2018",
"Description": "TARGET STOW OH",
"Amount": 49.37,
"Category": "Merchandise"
}
]

View File

@ -0,0 +1,39 @@
{
"name":"dcard",
"source":"client_file",
"loading_function":"csv",
"constraint":[
"{Trans. Date}",
"{Post Date}"
],
"schemas":{
"default":[
{
"path":"{Trans. Date}",
"type":"date",
"column_name":"Trans. Date"
},
{
"path":"{Post Date}",
"type":"date",
"column_name":"Post Date"
},
{
"path":"{Description}",
"type":"text",
"column_name":"Description"
},
{
"path":"{Amount}",
"type":"numeric",
"column_name":"Amount"
},
{
"path":"{Category}",
"type":"text",
"column_name":"Category"
}
],
"version2":[]
}
}