add function to setup, drop dev set, add test script

This commit is contained in:
Paul Trowbridge 2018-05-24 01:10:08 -04:00
parent a4f630ca54
commit cd311ee1ce
3 changed files with 109 additions and 72 deletions

View File

@ -148,3 +148,72 @@ ALTER TABLE ONLY tps.map_rv
ALTER TABLE ONLY tps.trans
ADD CONSTRAINT trans_srce_fkey FOREIGN KEY (srce) REFERENCES tps.srce(srce);
-------------create functions------------------------------------------------------------------------------------------------------------------------
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;

View File

@ -1,71 +0,0 @@
--need to build history (trigger)?
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;
-------------------insert definition----------------------------------------
INSERT INTO
tps.srce (srce, defn)
SELECT
_defn->>'name', _defn
ON CONFLICT ON CONSTRAINT srce_pkey DO UPDATE
SET
defn = _defn;
END;
$f$
LANGUAGE plpgsql

View File

@ -0,0 +1,39 @@
SELECT * FROM TPS.SRCE_SET($${
"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":[]
}
}$$::JSONB)