try adding balance cascade to gl insert
This commit is contained in:
parent
87528788f2
commit
70f0cd363b
@ -193,40 +193,25 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
|
|||||||
acct
|
acct
|
||||||
,fspr
|
,fspr
|
||||||
)
|
)
|
||||||
INSERT INTO
|
,ins AS (
|
||||||
evt.bal
|
INSERT INTO
|
||||||
SELECT
|
evt.bal
|
||||||
acct
|
SELECT
|
||||||
,fspr
|
acct
|
||||||
,0 obal
|
,fspr
|
||||||
,debits
|
,0 obal
|
||||||
,credits
|
,debits
|
||||||
,debits + credits
|
,credits
|
||||||
FROM
|
,debits + credits
|
||||||
agg
|
FROM
|
||||||
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
|
agg
|
||||||
debits = evt.bal.debits + EXCLUDED.debits
|
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
|
||||||
,credits = evt.bal.credits + EXCLUDED.credits
|
debits = evt.bal.debits + EXCLUDED.debits
|
||||||
,cbal = evt.bal.cbal + EXCLUDED.debits + EXCLUDED.credits;
|
,credits = evt.bal.credits + EXCLUDED.credits
|
||||||
RETURN NULL;
|
,cbal = evt.bal.cbal + EXCLUDED.debits + EXCLUDED.credits
|
||||||
END;
|
RETURNING *
|
||||||
$func$;
|
)
|
||||||
|
,seq AS (
|
||||||
CREATE TRIGGER gl_insert
|
|
||||||
AFTER INSERT ON evt.gl
|
|
||||||
REFERENCING NEW TABLE AS ins
|
|
||||||
FOR EACH STATEMENT
|
|
||||||
EXECUTE PROCEDURE evt.gl_insert();
|
|
||||||
|
|
||||||
---------------------------handle balance updates----------------------------------------
|
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS
|
|
||||||
$func$
|
|
||||||
BEGIN
|
|
||||||
WITH
|
|
||||||
seq AS (
|
|
||||||
WITH RECURSIVE rf (acct, fspr, minrange, maxrange, dur, id, obal, debits, credits, cbal) AS
|
WITH RECURSIVE rf (acct, fspr, minrange, maxrange, dur, id, obal, debits, credits, cbal) AS
|
||||||
(
|
(
|
||||||
SELECT
|
SELECT
|
||||||
@ -313,8 +298,10 @@ CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger
|
|||||||
END;
|
END;
|
||||||
$func$;
|
$func$;
|
||||||
|
|
||||||
CREATE TRIGGER bal_insert
|
CREATE TRIGGER gl_insert
|
||||||
AFTER INSERT ON evt.bal
|
AFTER INSERT ON evt.gl
|
||||||
REFERENCING NEW TABLE AS ins
|
REFERENCING NEW TABLE AS ins
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
EXECUTE PROCEDURE evt.bal_insert();
|
EXECUTE PROCEDURE evt.gl_insert();
|
||||||
|
|
||||||
|
COMMIT;
|
@ -18,21 +18,106 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
|
|||||||
acct
|
acct
|
||||||
,fspr
|
,fspr
|
||||||
)
|
)
|
||||||
|
,ins AS (
|
||||||
|
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;
|
||||||
|
)
|
||||||
|
,seq AS (
|
||||||
|
WITH RECURSIVE rf (acct, fspr, minrange, maxrange, dur, id, obal, debits, credits, cbal) AS
|
||||||
|
(
|
||||||
|
SELECT
|
||||||
|
rng.acct
|
||||||
|
,rng.fspr
|
||||||
|
,rng.minrange
|
||||||
|
,rng.maxrange
|
||||||
|
,f.dur
|
||||||
|
,f.id
|
||||||
|
,b.obal::numeric(12,2)
|
||||||
|
,b.debits::numeric(12,2)
|
||||||
|
,b.credits::numeric(12,2)
|
||||||
|
,b.cbal::numeric(12,2)
|
||||||
|
FROM
|
||||||
|
(
|
||||||
|
--for each item determine if a gap exists between new an previous period (if any)
|
||||||
|
SELECT
|
||||||
|
ins.acct
|
||||||
|
,ins.fspr
|
||||||
|
,lower(f.dur) dur
|
||||||
|
,CASE WHEN lower(f.dur) > max(lower(bp.dur)) THEN max(lower(bp.dur)) ELSE lower(f.dur) END minrange
|
||||||
|
,CASE WHEN lower(f.dur) < max(lower(bp.dur)) THEN max(lower(bp.dur)) ELSE lower(f.dur) END maxrange
|
||||||
|
FROM
|
||||||
|
ins
|
||||||
|
INNER JOIN evt.fspr f ON
|
||||||
|
f.id = ins.fspr
|
||||||
|
LEFT OUTER JOIN evt.bal b ON
|
||||||
|
b.acct = ins.acct
|
||||||
|
LEFT OUTER JOIN evt.fspr bp ON
|
||||||
|
bp.id = b.fspr
|
||||||
|
GROUP BY
|
||||||
|
ins.acct
|
||||||
|
,ins.fspr
|
||||||
|
,f.dur
|
||||||
|
) rng
|
||||||
|
INNER JOIN evt.fspr f ON
|
||||||
|
lower(f.dur) = minrange
|
||||||
|
INNER JOIN evt.bal b ON
|
||||||
|
b.acct = rng.acct
|
||||||
|
AND b.fspr = f.id
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
rf.acct
|
||||||
|
,rf.fspr
|
||||||
|
,rf.minrange
|
||||||
|
,rf.maxrange
|
||||||
|
,f.dur
|
||||||
|
,f.id
|
||||||
|
,COALESCE(rf.cbal,0)::numeric(12,2)
|
||||||
|
,COALESCE(b.debits,0)::numeric(12,2)
|
||||||
|
,COALESCE(b.credits,0)::numeric(12,2)
|
||||||
|
,(COALESCE(rf.cbal,0) + COALESCE(b.debits,0) + COALESCE(b.credits,0))::numeric(12,2)
|
||||||
|
FROM
|
||||||
|
rf
|
||||||
|
INNER JOIN evt.fspr f ON
|
||||||
|
lower(f.dur) = upper(rf.dur)
|
||||||
|
LEFT OUTER JOIN evt.bal b ON
|
||||||
|
b.acct = rf.acct
|
||||||
|
AND b.fspr = f.id
|
||||||
|
WHERE
|
||||||
|
lower(f.dur) <= rf.maxrange
|
||||||
|
)
|
||||||
|
SELECT * FROM rf
|
||||||
|
)
|
||||||
INSERT INTO
|
INSERT INTO
|
||||||
evt.bal
|
evt.bal (acct, fspr, obal, debits, credits, cbal)
|
||||||
SELECT
|
SELECT
|
||||||
acct
|
acct
|
||||||
,fspr
|
,id
|
||||||
,0 obal
|
,obal
|
||||||
,debits
|
,debits
|
||||||
,credits
|
,credits
|
||||||
,debits + credits
|
,cbal
|
||||||
FROM
|
FROM
|
||||||
agg
|
seq
|
||||||
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
|
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
|
||||||
debits = evt.bal.debits + EXCLUDED.debits
|
obal = EXCLUDED.obal
|
||||||
,credits = evt.bal.credits + EXCLUDED.credits
|
,debits = EXCLUDED.debits
|
||||||
,cbal = evt.bal.cbal + EXCLUDED.debits + EXCLUDED.credits;
|
,credits = EXCLUDED.credits
|
||||||
|
,cbal = EXCLUDED.cbal;
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END;
|
END;
|
||||||
$func$;
|
$func$;
|
||||||
|
Loading…
Reference in New Issue
Block a user