From f96a5402108d1c617886d039bd7a9b636712abd5 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Thu, 20 Sep 2018 20:16:32 -0400 Subject: [PATCH 1/2] some cleanup and modify gl columns --- db_deploy.sql | 11 +++++++++-- schema/tables/fspr.sql | 5 ++--- schema/tables/gl.sql | 2 +- 3 files changed, 12 insertions(+), 6 deletions(-) diff --git a/db_deploy.sql b/db_deploy.sql index 18de438..5e3da01 100644 --- a/db_deploy.sql +++ b/db_deploy.sql @@ -31,21 +31,25 @@ COMMENT ON COLUMN evt.acct.prop IS 'properties'; ------------------------fiscal periods------------------------ CREATE TABLE evt.fspr ( - id ltree + id ltree PRIMARY KEY ,dur tstzrange ); COMMENT ON COLUMN evt.fspr.id IS 'fiscal period'; COMMENT ON COLUMN evt.fspr.dur IS 'duration of period as timestamp range'; - CREATE INDEX id_gist ON evt.fspr USING GIST (id); + --------------------------relational ledger------------------------------------------ CREATE TABLE evt.gl ( id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY ,bprid INT REFERENCES evt.bpr (id) ,acct text REFERENCES evt.acct (acct) + ,pstmp timestamptz DEFAULT CURRENT_TIMESTAMP + --populates by trigger join to evt.fspr + ,tstmp timestamptz + ,fspr ltree REFERENCES evt.fspr (id) ,amount numeric (12,2) ,glline INT ,bprkeys JSONB @@ -53,6 +57,9 @@ CREATE TABLE evt.gl ( COMMENT ON COLUMN evt.gl.id IS 'gl id'; COMMENT ON COLUMN evt.gl.bprid IS 'id of initial basic pecuniary record'; COMMENT ON COLUMN evt.gl.acct IS 'account code'; +COMMENT ON COLUMN evt.gl.pstmp IS 'post time stamp'; +COMMENT ON COLUMN evt.gl.tstmp IS 'transaction time stamp'; +COMMENT ON COLUMN evt.gl.fspr IS 'fiscal period'; COMMENT ON COLUMN evt.gl.amount IS 'amount'; COMMENT ON COLUMN evt.gl.glline IS 'gl line number'; COMMENT ON COLUMN evt.gl.bprkeys IS 'extract from initial basic pecuniary record'; diff --git a/schema/tables/fspr.sql b/schema/tables/fspr.sql index 25238fe..1fa789e 100644 --- a/schema/tables/fspr.sql +++ b/schema/tables/fspr.sql @@ -1,10 +1,9 @@ ------------------------fiscal periods------------------------ CREATE TABLE evt.fspr ( - id ltree + id ltree PRIMARY KEY ,dur tstzrange -) +); COMMENT ON COLUMN evt.fspr.id IS 'fiscal period'; COMMENT ON COLUMN evt.fspr.dur IS 'duration of period as timestamp range'; - CREATE INDEX id_gist ON evt.fspr USING GIST (id); diff --git a/schema/tables/gl.sql b/schema/tables/gl.sql index 2a055aa..da422f1 100644 --- a/schema/tables/gl.sql +++ b/schema/tables/gl.sql @@ -7,7 +7,7 @@ CREATE TABLE evt.gl ( ,pstmp timestamptz DEFAULT CURRENT_TIMESTAMP --populates by trigger join to evt.fspr ,tstmp timestamptz - ,fspr ltree REFERENCES evt.fspr (id); + ,fspr ltree REFERENCES evt.fspr (id) ,amount numeric (12,2) ,glline INT ,bprkeys JSONB From 9f1d191b9e5f29dd6e199bd5066d94ed44b86cc6 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Thu, 20 Sep 2018 22:13:06 -0400 Subject: [PATCH 2/2] update for new columns --- db_deploy.sql | 15 +++++++++------ schema/triggers/log_insert.sql | 25 +++++++++++++++---------- test | 3 ++- 3 files changed, 26 insertions(+), 17 deletions(-) diff --git a/db_deploy.sql b/db_deploy.sql index 5e3da01..9c63406 100644 --- a/db_deploy.sql +++ b/db_deploy.sql @@ -81,7 +81,7 @@ COMMENT ON COLUMN evt.bal.debits IS 'total debits'; COMMENT ON COLUMN evt.bal.credits IS 'total credits'; COMMENT ON COLUMN evt.bal.cbal IS 'closing balance'; ------------------------------------------process bpr insert trigger ----------------------------------- +---------------------------handle new logged event---------------------------------------- CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger LANGUAGE plpgsql @@ -89,7 +89,7 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger $func$ BEGIN WITH - ------------------------------------full extraction------------------------------------------- + --full extraction full_ex AS ( SELECT ins.id @@ -113,7 +113,7 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr#>ARRAY['gl','jpath',(a.rn - 1)::text]) WITH ORDINALITY p(i, rn) ON TRUE ) --select * from full_ex - --------------------------------re-ggregate extraction to gl line level---------------------- + --re-ggregate extraction to gl line level ,ex_gl_line AS ( SELECT id @@ -142,15 +142,19 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger RETURNING * ) INSERT INTO - evt.gl (bprid,acct, amount,glline, bprkeys) + evt.gl (bprid,acct, amount,tstmp , fspr, glline, bprkeys) SELECT id ,account ,amount + ,(bprkeys->>'date')::timestamptz + ,p.fspr ,gl_rownum ,bprkeys FROM - ex_gl_line; + ex_gl_line + LEFT OUTER JOIN evt.fspr p ON + p.dur @> (bprkeys->>'date')::timestamptz; RETURN NULL; END; $func$; @@ -162,5 +166,4 @@ CREATE TRIGGER log_insert FOR EACH STATEMENT EXECUTE PROCEDURE evt.log_insert(); - COMMIT; diff --git a/schema/triggers/log_insert.sql b/schema/triggers/log_insert.sql index 6e2ae61..69c19c2 100644 --- a/schema/triggers/log_insert.sql +++ b/schema/triggers/log_insert.sql @@ -1,3 +1,4 @@ +---------------------------handle new logged event---------------------------------------- CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger LANGUAGE plpgsql @@ -5,7 +6,7 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger $func$ BEGIN WITH - ------------------------------------full extraction------------------------------------------- + --full extraction full_ex AS ( SELECT ins.id @@ -29,7 +30,7 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr#>ARRAY['gl','jpath',(a.rn - 1)::text]) WITH ORDINALITY p(i, rn) ON TRUE ) --select * from full_ex - --------------------------------re-ggregate extraction to gl line level---------------------- + --re-ggregate extraction to gl line level ,ex_gl_line AS ( SELECT id @@ -58,18 +59,22 @@ CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger RETURNING * ) INSERT INTO - evt.gl (bprid,acct, amount,glline, bprkeys) + evt.gl (bprid,acct, amount,tstmp , fspr, glline, bprkeys) SELECT - id - ,account - ,amount - ,gl_rownum - ,bprkeys + e.id + ,e.account + ,e.amount + ,(e.bprkeys->>'date')::timestamptz + ,p.id + ,e.gl_rownum + ,e.bprkeys FROM - ex_gl_line; + ex_gl_line e + LEFT OUTER JOIN evt.fspr p ON + p.dur @> (bprkeys->>'date')::timestamptz; RETURN NULL; END; - $func$ + $func$; CREATE TRIGGER log_insert diff --git a/test b/test index a1d47ef..3fdc258 100644 --- a/test +++ b/test @@ -35,6 +35,7 @@ $${ "entity": "home", "module": "MHI", "offset": "h.dcard", - "transaction": "purchase" + "transaction": "purchase", + "date": "2018-08-01" } }$$::jsonb bpr \ No newline at end of file