jl/schema/triggers/gl_insert.sql

146 lines
4.3 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
2018-09-25 00:33:42 -04:00
LANGUAGE plpgsql
AS
$func$
DECLARE
_mind timestamptz;
_maxd timestamptz;
BEGIN
2018-09-27 14:52:36 -04:00
--find min and max applicable periods to roll
--min: earliest period involved in current gl posting
--max: latest period involved in any posting, or if none, the current posting
2018-09-25 00:33:42 -04:00
SELECT
(SELECT min(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr)
,GREATEST(
(SELECT max(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr),
COALESCE(
(SELECT max(lower(dur)) FROM evt.fspr WHERE prop @> '{"gltouch":"yes"}'),
(SELECT max(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr)
)
)
2018-09-25 00:33:42 -04:00
INTO
_mind
,_maxd;
WITH
agg AS (
SELECT
2018-09-25 00:33:42 -04:00
acct
,fspr
,dur
2018-09-27 14:56:12 -04:00
put a negative in front to negate the initial debit/credit assignment
,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits
,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits
FROM
2018-09-25 00:33:42 -04:00
ins
INNER JOIN evt.fspr f ON
2018-09-25 00:33:42 -04:00
f.id = ins.fspr
GROUP BY
acct
,fspr
,dur
)
--get every account involved in target range
,arng AS (
SELECT DISTINCT
acct
FROM
agg b
)
,seq AS (
WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS
(
2018-09-21 00:01:11 -04:00
SELECT
2018-09-25 00:33:42 -04:00
arng.acct
,f.id
,f.dur
,COALESCE(b.obal::numeric(12,2),0)
,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)
2018-09-24 00:02:41 -04:00
FROM
2018-09-25 00:33:42 -04:00
arng
2018-09-24 00:02:41 -04:00
INNER JOIN evt.fspr f ON
2018-09-25 00:33:42 -04:00
upper(f.dur) = _mind
LEFT OUTER JOIN evt.bal b ON
b.acct = arng.acct
AND b.fspr = f.id
LEFT OUTER JOIN agg ON
agg.acct = arng.acct
AND agg.fspr = f.id
UNION ALL
2018-09-25 00:33:42 -04:00
SELECT
rf.acct
,f.id
,f.dur
,COALESCE(rf.cbal,0)::numeric(12,2)
,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
LEFT OUTER JOIN agg ON
agg.acct = rf.acct
AND agg.fspr = f.id
WHERE
lower(f.dur) <= _maxd
)
2018-09-25 00:33:42 -04:00
SELECT * FROM rf WHERE lower(dur) >= _mind
)
,bali AS (
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
2018-09-25 00:33:42 -04:00
,cbal = EXCLUDED.cbal
,prop = evt.bal.prop || EXCLUDED.prop
RETURNING *
)
,n as (
SELECT DISTINCT
fspr
FROM
bali
)
UPDATE
evt.fspr f
SET
prop = COALESCE(f.prop,'{}'::JSONB) || '{"gltouch":"yes"}'::jsonb
FROM
n
WHERE
f.id = n.fspr;
2018-09-25 14:10:15 -04:00
PERFORM evt.balrf();
2018-09-25 00:33:42 -04:00
RETURN NULL;
END;
$func$;
2018-09-21 00:01:11 -04:00
2018-09-27 12:49:12 -04:00
COMMENT ON FUNCTION evt.gl_insert IS 'update evt.bal with new ledger rows';
2018-09-21 00:01:11 -04:00
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();