finish initial gl_insert function

This commit is contained in:
Paul Trowbridge 2018-09-21 00:01:11 -04:00
parent e3c0530787
commit 87d9bf537c
2 changed files with 80 additions and 27 deletions

View File

@ -167,3 +167,48 @@ CREATE TRIGGER log_insert
REFERENCING NEW TABLE AS ins REFERENCING NEW TABLE AS ins
FOR EACH STATEMENT FOR EACH STATEMENT
EXECUTE PROCEDURE evt.log_insert(); 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();

View File

@ -4,15 +4,14 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
LANGUAGE plpgsql LANGUAGE plpgsql
AS AS
$func$ $func$
--upsert gl balance BEGIN
--if a new period is created roll any gaps
WITH WITH
agg AS ( agg AS (
SELECT SELECT
acct acct
,fspr ,fspr
,sum(amount) FILTER (WHERE amount > 0) debits ,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits
,sum(amount) FILTER (WHERE amount < 0) credits ,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits
FROM FROM
ins ins
GROUP BY GROUP BY
@ -24,13 +23,22 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
SELECT SELECT
acct acct
,fspr ,fspr
,0 ,0 obal
,debits ,debits
,credits ,credits
,debits + credits ,debits + credits
FROM FROM
agg agg
ON CONFLICT ON CONSTRAINT PRIMARY KEY DO UPDATE SET ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
debits = debits + EXCLUDED.debits debits = evt.bal.debits + EXCLUDED.debits
,credits = credits + EXCLUDED.credits ,credits = evt.bal.credits + EXCLUDED.credits
,cbal = cbal + debits + 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();