253 lines
7.3 KiB
PL/PgSQL
253 lines
7.3 KiB
PL/PgSQL
------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 ROLE 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 schema USAGE
|
|
GRANT USAGE ON SCHEMA tps 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,
|
|
hist 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);
|
|
|
|
-------------create functions------------------------------------------------------------------------------------------------------------------------
|
|
|
|
-----set source
|
|
CREATE FUNCTION tps.srce_set(_defn jsonb) RETURNS jsonb
|
|
AS
|
|
$f$
|
|
DECLARE
|
|
_message jsonb;
|
|
_MESSAGE_TEXT text;
|
|
_PG_EXCEPTION_DETAIL text;
|
|
_PG_EXCEPTION_HINT text;
|
|
BEGIN
|
|
INSERT INTO
|
|
tps.srce (srce, defn, hist)
|
|
SELECT
|
|
--extract name from defintion
|
|
_defn->>'name'
|
|
--add current timestamp to defintions
|
|
,_defn
|
|
--add definition
|
|
,jsonb_build_object(
|
|
'hist_defn',_defn
|
|
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
|
|
) || '[]'::jsonb
|
|
ON CONFLICT ON CONSTRAINT srce_pkey DO UPDATE
|
|
SET
|
|
defn = _defn
|
|
,hist =
|
|
--the new definition going to position -0-
|
|
jsonb_build_object(
|
|
'hist_defn',_defn
|
|
,'effective',jsonb_build_array(CURRENT_TIMESTAMP,null::timestamptz)
|
|
)
|
|
--the previous definition, set upper bound of effective range which was previously null
|
|
|| jsonb_set(
|
|
srce.hist
|
|
,'{0,effective,1}'::text[]
|
|
,to_jsonb(CURRENT_TIMESTAMP)
|
|
);
|
|
|
|
_message:=
|
|
(
|
|
$$
|
|
{
|
|
"status":"complete",
|
|
"message":"source set"
|
|
}
|
|
$$::jsonb
|
|
);
|
|
RETURN _message;
|
|
|
|
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 importing data"
|
|
}
|
|
$$::jsonb)
|
|
||jsonb_build_object('message_text',_MESSAGE_TEXT)
|
|
||jsonb_build_object('pg_exception_detail',_PG_EXCEPTION_DETAIL);
|
|
RETURN _message;
|
|
END;
|
|
$f$
|
|
LANGUAGE plpgsql;
|
|
|
|
-----generate sql to create select based on schema
|
|
CREATE FUNCTION tps.build_srce_view_sql(_srce text, _schema text) RETURNS TEXT
|
|
AS
|
|
$f$
|
|
DECLARE
|
|
--_schema text;
|
|
_path text[];
|
|
--_srce text;
|
|
_sql text;
|
|
BEGIN
|
|
--_schema:= 'default';
|
|
_path:= ARRAY['schemas',_schema]::text[];
|
|
--_srce:= 'dcard';
|
|
SELECT
|
|
'CREATE VIEW tpsv.'||_srce||'_'||_path[2]||' AS SELECT '||string_agg('(rec#>>'''||r.PATH::text||''')::'||r.type||' AS "'||r.column_name||'"',', ')||' FROM tps.trans WHERE srce = '''||_srce||''''
|
|
INTO
|
|
_sql
|
|
FROM
|
|
tps.srce
|
|
JOIN LATERAL jsonb_array_elements(defn#>_path) ae(v) ON TRUE
|
|
JOIN LATERAL jsonb_to_record (ae.v) AS r(PATH text[], "type" text, column_name text) ON TRUE
|
|
WHERE
|
|
srce = _srce
|
|
GROUP BY
|
|
srce.srce;
|
|
|
|
RETURN _sql;
|
|
RAISE NOTICE '%',_sql;
|
|
|
|
END
|
|
$f$
|
|
LANGUAGE plpgsql; |