From 87d9bf537c3cc1316ef95d73932773117ea0ff97 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Fri, 21 Sep 2018 00:01:11 -0400 Subject: [PATCH] finish initial gl_insert function --- db_deploy.sql | 47 ++++++++++++++++++++++++++- schema/triggers/gl_insert.sql | 60 ++++++++++++++++++++--------------- 2 files changed, 80 insertions(+), 27 deletions(-) diff --git a/db_deploy.sql b/db_deploy.sql index 37cb718..a6a4b72 100644 --- a/db_deploy.sql +++ b/db_deploy.sql @@ -166,4 +166,49 @@ CREATE TRIGGER log_insert AFTER INSERT ON evt.bpr REFERENCING NEW TABLE AS ins FOR EACH STATEMENT - EXECUTE PROCEDURE evt.log_insert(); \ No newline at end of file + EXECUTE PROCEDURE evt.log_insert(); + +---------------------------handle new gl lines---------------------------------------- + +CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger + LANGUAGE plpgsql + AS + $func$ + BEGIN + WITH + agg AS ( + SELECT + acct + ,fspr + ,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits + ,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits + FROM + ins + GROUP BY + acct + ,fspr + ) + INSERT INTO + evt.bal + SELECT + acct + ,fspr + ,0 obal + ,debits + ,credits + ,debits + credits + FROM + agg + ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET + debits = evt.bal.debits + EXCLUDED.debits + ,credits = evt.bal.credits + EXCLUDED.credits + ,cbal = evt.bal.cbal + EXCLUDED.debits + EXCLUDED.credits; + RETURN NULL; + END; + $func$; + +CREATE TRIGGER gl_insert + AFTER INSERT ON evt.gl + REFERENCING NEW TABLE AS ins + FOR EACH STATEMENT + EXECUTE PROCEDURE evt.gl_insert(); \ No newline at end of file diff --git a/schema/triggers/gl_insert.sql b/schema/triggers/gl_insert.sql index de35a7f..293049e 100644 --- a/schema/triggers/gl_insert.sql +++ b/schema/triggers/gl_insert.sql @@ -4,33 +4,41 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger LANGUAGE plpgsql AS $func$ - --upsert gl balance - --if a new period is created roll any gaps - WITH - agg AS ( + BEGIN + WITH + agg AS ( + SELECT + acct + ,fspr + ,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits + ,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits + FROM + ins + GROUP BY + acct + ,fspr + ) + INSERT INTO + evt.bal SELECT acct ,fspr - ,sum(amount) FILTER (WHERE amount > 0) debits - ,sum(amount) FILTER (WHERE amount < 0) credits + ,0 obal + ,debits + ,credits + ,debits + credits FROM - ins - GROUP BY - acct - ,fspr - ) - INSERT INTO - evt.bal - SELECT - acct - ,fspr - ,0 - ,debits - ,credits - ,debits + credits - FROM - agg - ON CONFLICT ON CONSTRAINT PRIMARY KEY DO UPDATE SET - debits = debits + EXCLUDED.debits - ,credits = credits + EXCLUDED.credits - ,cbal = cbal + debits + credits \ No newline at end of file + agg + ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET + debits = evt.bal.debits + EXCLUDED.debits + ,credits = evt.bal.credits + EXCLUDED.credits + ,cbal = evt.bal.cbal + EXCLUDED.debits + EXCLUDED.credits; + RETURN NULL; + END; + $func$; + +CREATE TRIGGER gl_insert + AFTER INSERT ON evt.gl + REFERENCING NEW TABLE AS ins + FOR EACH STATEMENT + EXECUTE PROCEDURE evt.gl_insert(); \ No newline at end of file