jl/schema/triggers/gl_insert.sql

151 lines
4.5 KiB
MySQL
Raw Normal View History

2018-09-20 23:38:26 -04:00
---------------------------handle new gl lines----------------------------------------
CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
LANGUAGE plpgsql
AS
$func$
DECLARE
_lastdur tstzrange;
_newdur tstzrange;
2018-09-21 00:01:11 -04:00
BEGIN
--get last global rollforward
SELECT
dur
INTO
_lastdur
FROM
evt.fspr
WHERE
prop @> '{"rf":"global"}'::jsonb
WITH;
2018-09-21 00:01:11 -04:00
WITH
d AS (
SELECT DISTINCT fspr FROM ins
)
SELECT
max(f.dur)
INTO
_newdur
FROM
d
INNER JOIN evt.fspr f ON
f.id = d.id;
IF _newdur > _lastdur THEN
SELECT balrf(_lastdur, _newdur);
UPDATE
tps.fspr
SET
prop = jsonb_set(prop,'{rf}','max')
WHERE
END IF;
2018-09-21 00:01:11 -04:00
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
)
2018-09-24 00:02:41 -04:00
,list AS (
SELECT
b.acct
,least(min(lower(f.dur)),min(lower(g.dur))) minp
,greatest(max(lower(f.dur)),max(lower(g.dur))) maxp
2018-09-24 00:02:41 -04:00
FROM
2018-09-24 15:50:25 -04:00
agg b
2018-09-24 00:02:41 -04:00
INNER JOIN evt.fspr f ON
f.id = b.fspr
LEFT OUTER JOIN evt.bal e ON
e.acct = b.acct
LEFT OUTER JOIN evt.fspr g ON
e.fspr = g.id
2018-09-24 00:02:41 -04:00
GROUP BY
b.acct
)
,seq AS (
2018-09-24 00:02:41 -04:00
WITH RECURSIVE rf (acct, minp, maxp, id, dur, obal, debits, credits, cbal) AS
(
SELECT
2018-09-24 00:02:41 -04:00
list.acct
,list.minp
,list.maxp
,f.id
2018-09-24 00:02:41 -04:00
,f.dur
,COALESCE(b.obal::numeric(12,2),0)
2018-09-24 15:50:25 -04:00
,COALESCE(b.debits::numeric(12,2),0) + COALESCE(agg.debits,0)
,COALESCE(b.credits::numeric(12,2),0) + COALESCE(agg.credits,0)
,COALESCE(b.cbal::numeric(12,2),0) + COALESCE(agg.debits,0) + COALESCE(agg.credits,0)
FROM
2018-09-24 00:02:41 -04:00
list
INNER JOIN evt.fspr f ON
2018-09-24 00:02:41 -04:00
upper(f.dur) = list.minp
LEFT OUTER JOIN evt.bal b ON
b.acct = list.acct
AND b.fspr = f.id
2018-09-24 15:50:25 -04:00
LEFT OUTER JOIN agg ON
agg.acct = list.acct
AND agg.fspr = f.id
UNION ALL
SELECT
rf.acct
2018-09-24 00:02:41 -04:00
,rf.minp
,rf.maxp
,f.id
2018-09-24 00:02:41 -04:00
,f.dur
,COALESCE(rf.cbal,0)::numeric(12,2)
2018-09-24 15:50:25 -04:00
,COALESCE(b.debits,0)::numeric(12,2) + COALESCE(agg.debits,0)
,COALESCE(b.credits,0)::numeric(12,2) + COALESCe(agg.credits,0)
,(COALESCE(rf.cbal,0) + COALESCE(b.debits,0) + COALESCE(b.credits,0))::numeric(12,2) + COALESCE(agg.debits,0) + COALESCE(agg.credits,0)
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
2018-09-24 15:50:25 -04:00
LEFT OUTER JOIN agg ON
agg.acct = rf.acct
AND agg.fspr = f.id
WHERE
2018-09-24 00:02:41 -04:00
lower(f.dur) <= rf.maxp
)
2018-09-24 00:02:41 -04:00
SELECT * FROM rf WHERE lower(dur) >= minp
)
2018-09-21 00:01:11 -04:00
INSERT INTO
evt.bal (acct, fspr, obal, debits, credits, cbal)
2018-09-20 23:38:26 -04:00
SELECT
acct
,id
,obal
2018-09-21 00:01:11 -04:00
,debits
,credits
,cbal
2018-09-20 23:38:26 -04:00
FROM
seq
2018-09-21 00:01:11 -04:00
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
obal = EXCLUDED.obal
,debits = EXCLUDED.debits
,credits = EXCLUDED.credits
,cbal = EXCLUDED.cbal;
2018-09-21 00:01:11 -04:00
RETURN NULL;
END;
$func$;
CREATE TRIGGER gl_insert
AFTER INSERT ON evt.gl
2018-09-24 15:50:25 -04:00
REFERENCING NEW TABLE AS ins
2018-09-21 00:01:11 -04:00
FOR EACH STATEMENT
EXECUTE PROCEDURE evt.gl_insert();