From 18a7bacb7304bbdb03f106b11be1bf208a920386 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Tue, 22 May 2018 17:38:35 -0400 Subject: [PATCH] build out sql to deploy dev schemas --- deploy/setup_dev.sql | 122 ++++++++++++++++++++++++++++++++++++++++++- 1 file changed, 120 insertions(+), 2 deletions(-) diff --git a/deploy/setup_dev.sql b/deploy/setup_dev.sql index b92dad4..ba15d2f 100644 --- a/deploy/setup_dev.sql +++ b/deploy/setup_dev.sql @@ -1,8 +1,13 @@ ------create dev schema and api user----------------------------------------------------------------------------------------------------------------- -DROP SCHEMA IF EXISTS tps_dev; +DROP SCHEMA IF EXISTS tps_dev CASCADE; +DROP SCHEMA IF EXISTS tpsv_dev CASCADE; CREATE SCHEMA tps_dev; +COMMENT ON SCHEMA tps_dev IS 'third party source data'; + +CREATE SCHEMA tpsv_dev; +COMMENT ON SCHEMA tps_dev IS 'third party source views'; DROP USER IF EXISTS api_dev; @@ -14,15 +19,128 @@ CREATE USER api_dev WITH INHERIT NOREPLICATION CONNECTION LIMIT -1 - PASSWORD 'api_dev'; + ENCRYPTED PASSWORD 'md5787fffd13a11cfe69a5ad6e0876d4cfb'; -----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_dev TO api_dev; +GRANT SELECT, UPDATE, INSERT, DELETE ON ALL TABLES IN SCHEMA tpsv_dev TO api_dev; +--grant current sequence privledges GRANT USAGE ON ALL SEQUENCES IN SCHEMA tps_dev TO api_dev; +GRANT USAGE ON ALL SEQUENCES IN SCHEMA tpsv_dev TO api_dev; +--grant future table privledges ALTER DEFAULT PRIVILEGES IN SCHEMA tps_dev GRANT SELECT, UPDATE, INSERT, DELETE ON TABLES TO api_dev; +ALTER DEFAULT PRIVILEGES IN SCHEMA tpsv_dev GRANT SELECT, UPDATE, INSERT, DELETE ON TABLES TO api_dev; +--grant future sequence privledges ALTER DEFAULT PRIVILEGES IN SCHEMA tps_dev GRANT USAGE ON SEQUENCES TO api_dev; +ALTER DEFAULT PRIVILEGES IN SCHEMA tpsv_dev GRANT USAGE ON SEQUENCES TO api_dev; + +-----create tables----------------------------------------------------------------------------------------------------------------------------------- + +-----regex map instructions table + +CREATE TABLE tps_dev.map_rm ( + srce text NOT NULL, + target text NOT NULL, + regex jsonb, + seq integer NOT NULL +); +COMMENT ON TABLE tps_dev.map_rm IS 'regex map instructions'; + +-----return value table + +CREATE TABLE tps_dev.map_rv ( + srce text NOT NULL, + target text NOT NULL, + retval jsonb NOT NULL, + map jsonb +); +COMMENT ON TABLE tps_dev.map_rv IS 'return value lookup table'; + +-----source definition table + +CREATE TABLE tps_dev.srce ( + srce text NOT NULL, + defn jsonb +); +COMMENT ON TABLE tps_dev.srce IS 'source master listing and definition'; + +-----source data table + +CREATE TABLE tps_dev.trans ( + id integer NOT NULL, + srce text, + rec jsonb, + parse jsonb, + map jsonb, + allj jsonb, + ic jsonb +); +COMMENT ON TABLE tps_dev.trans IS 'source records'; +COMMENT ON COLUMN tps_dev.trans.ic IS 'input constraint value'; +ALTER TABLE tps_dev.trans ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY ( + SEQUENCE NAME tps_dev.trans_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1 +); + +-----import log table + +CREATE TABLE tps_dev.trans_log ( + id integer NOT NULL, + info jsonb +); +COMMENT ON TABLE tps_dev.trans_log IS 'import event information'; +ALTER TABLE tps_dev.trans_log ALTER COLUMN id ADD GENERATED BY DEFAULT AS IDENTITY ( + SEQUENCE NAME tps_dev.trans_log_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1 +); + + +-------------primary keys---------------------------------------------------------------------------------------------------------------------------- + +ALTER TABLE ONLY tps_dev.map_rm + ADD CONSTRAINT map_rm_pk PRIMARY KEY (srce, target); + +ALTER TABLE ONLY tps_dev.map_rv + ADD CONSTRAINT map_rv_pk PRIMARY KEY (srce, target, retval); + +ALTER TABLE ONLY tps_dev.srce + ADD CONSTRAINT srce_pkey PRIMARY KEY (srce); + +ALTER TABLE ONLY tps_dev.trans_log + ADD CONSTRAINT trans_log_pkey PRIMARY KEY (id); + +ALTER TABLE ONLY tps_dev.trans + ADD CONSTRAINT trans_pkey PRIMARY KEY (id); + +-------------indexes--------------------------------------------------------------------------------------------------------------------------------- + +CREATE INDEX trans_allj ON tps_dev.trans USING gin (allj); + +CREATE INDEX trans_rec ON tps_dev.trans USING gin (rec); + +CREATE INDEX trans_srce ON tps_dev.trans USING btree (srce); + +-------------foreign keys---------------------------------------------------------------------------------------------------------------------------- + +ALTER TABLE ONLY tps_dev.map_rm + ADD CONSTRAINT map_rm_fk_srce FOREIGN KEY (srce) REFERENCES tps_dev.srce(srce); + +ALTER TABLE ONLY tps_dev.map_rv + ADD CONSTRAINT map_rv_fk_rm FOREIGN KEY (srce, target) REFERENCES tps_dev.map_rm(srce, target); + +ALTER TABLE ONLY tps_dev.trans + ADD CONSTRAINT trans_srce_fkey FOREIGN KEY (srce) REFERENCES tps_dev.srce(srce); \ No newline at end of file