jl/schema/triggers/bal_insert.sql

90 lines
2.7 KiB
MySQL
Raw Normal View History

2018-09-22 00:30:11 -04:00
---------------------------handle balance updates----------------------------------------
CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger
LANGUAGE plpgsql
AS
$func$
BEGIN
WITH
2018-09-24 00:02:59 -04:00
list AS (
SELECT
acct
,min(lower(dur)) minp
,max(lower(dur)) maxp
FROM
ins b
INNER JOIN evt.fspr f ON
f.id = b.fspr
GROUP BY
acct
)
,seq AS (
WITH RECURSIVE rf (acct, minp, maxp, id, dur, obal, debits, credits, cbal) AS
2018-09-22 00:21:02 -04:00
(
SELECT
2018-09-24 00:02:59 -04:00
list.acct
,list.minp
,list.maxp
2018-09-22 00:21:02 -04:00
,f.id
2018-09-24 00:02:59 -04:00
,f.dur
2018-09-22 00:21:02 -04:00
,b.obal::numeric(12,2)
,b.debits::numeric(12,2)
,b.credits::numeric(12,2)
,b.cbal::numeric(12,2)
FROM
2018-09-24 00:02:59 -04:00
list
2018-09-22 00:21:02 -04:00
INNER JOIN evt.fspr f ON
2018-09-24 00:02:59 -04:00
lower(f.dur) = list.minp
LEFT OUTER JOIN evt.bal b ON
b.acct = list.acct
2018-09-22 00:21:02 -04:00
AND b.fspr = f.id
UNION ALL
SELECT
rf.acct
2018-09-24 00:02:59 -04:00
,rf.minp
,rf.maxp
2018-09-22 00:21:02 -04:00
,f.id
2018-09-24 00:02:59 -04:00
,f.dur
2018-09-22 00:21:02 -04:00
,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
2018-09-24 00:02:59 -04:00
lower(f.dur) <= rf.maxp
2018-09-22 00:21:02 -04:00
)
2018-09-24 00:02:59 -04:00
select * from rf
2018-09-22 00:21:02 -04:00
)
2018-09-22 00:30:11 -04:00
INSERT INTO
2018-09-22 01:01:44 -04:00
evt.bal (acct, fspr, obal, debits, credits, cbal)
2018-09-22 00:21:02 -04:00
SELECT
2018-09-22 00:30:11 -04:00
acct
2018-09-22 01:01:44 -04:00
,id
2018-09-22 00:30:11 -04:00
,obal
,debits
,credits
,cbal
2018-09-22 00:21:02 -04:00
FROM
2018-09-22 00:30:11 -04:00
seq
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
obal = EXCLUDED.obal
,debits = EXCLUDED.debits
,credits = EXCLUDED.credits
,cbal = EXCLUDED.cbal;
RETURN NULL;
END;
$func$;
CREATE TRIGGER bal_insert
AFTER INSERT ON evt.bal
REFERENCING NEW TABLE AS ins
FOR EACH STATEMENT
EXECUTE PROCEDURE evt.bal_insert();