jl/schema/functions/rollforward.sql

125 lines
3.1 KiB
MySQL
Raw Normal View History

2018-09-25 13:57:02 -04:00
CREATE FUNCTION evt.balrf() RETURNS void
LANGUAGE plpgsql AS
2018-09-24 16:47:38 -04:00
$func$
2018-09-25 00:33:42 -04:00
DECLARE
2018-09-25 12:58:29 -04:00
_mind timestamptz;
_maxd timestamptz;
2018-09-24 16:47:38 -04:00
BEGIN
2018-09-25 00:33:42 -04:00
2018-09-25 12:58:29 -04:00
--get last accounts touched and last rollforward if available
2018-09-25 00:33:42 -04:00
SELECT
2018-09-25 12:58:29 -04:00
--get last rollforward, if none, use earliest period touched
COALESCE(
MAX(lower(dur)) FILTER (WHERE prop @> '{"rf":"global"}'::jsonb)
,MIN(lower(dur)) FILTER (WHERE prop @> '{"gltouch":"yes"}'::jsonb)
2018-09-25 13:57:02 -04:00
) mind
2018-09-25 12:58:29 -04:00
--max period touched
,MAX(lower(dur)) FILTER (WHERE prop @> '{"gltouch":"yes"}'::jsonb) maxd
2018-09-25 00:33:42 -04:00
INTO
2018-09-25 12:58:29 -04:00
_mind
,_maxd
2018-09-25 00:33:42 -04:00
FROM
2018-09-25 12:58:29 -04:00
evt.fspr;
2018-09-25 13:57:02 -04:00
2018-09-25 13:59:09 -04:00
IF _maxd <= _mind THEN
2018-09-25 13:57:02 -04:00
RETURN;
2018-09-25 13:59:09 -04:00
END IF;
2018-09-25 00:33:42 -04:00
2018-09-24 16:47:38 -04:00
WITH
--list each period in min and max
prng AS (
SELECT
id
,dur
,prop
2018-09-24 14:04:31 -04:00
FROM
2018-09-24 16:47:38 -04:00
evt.fspr f
2018-09-24 14:04:31 -04:00
WHERE
2018-09-25 12:58:29 -04:00
lower(f.dur) >= _mind
AND lower(f.dur) <= _maxd
2018-09-24 16:47:38 -04:00
)
--get every account involved in target range
,arng AS (
SELECT DISTINCT
acct
FROM
evt.bal b
INNER JOIN prng ON
prng.id = b.fspr
)
,bld AS (
2018-09-25 12:58:29 -04:00
WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS
2018-09-24 16:47:38 -04:00
(
SELECT
a.acct
,f.id
,f.dur
,COALESCE(b.obal,0)::numeric(12,2)
,COALESCE(b.debits,0)::numeric(12,2)
,COALESCE(b.credits,0)::numeric(12,2)
,COALESCE(b.cbal,0)::numeric(12,2)
FROM
arng a
INNER JOIN evt.fspr f ON
2018-09-25 12:58:29 -04:00
lower(f.dur) = _mind
2018-09-24 16:47:38 -04:00
LEFT OUTER JOIN evt.bal b ON
b.acct = a.acct
AND b.fspr = f.id
UNION ALL
SELECT
rf.acct
,f.id
,f.dur
,rf.cbal
,COALESCE(b.debits,0)::numeric(12,2)
,COALESCE(b.credits,0)::numeric(12,2)
,(rf.cbal + 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-25 12:58:29 -04:00
lower(f.dur) <= _maxd
2018-09-24 16:47:38 -04:00
)
select * from rf
)
2018-09-25 13:47:37 -04:00
,ins AS (
INSERT INTO
evt.bal
SELECT
acct
,id
,obal
,debits
,credits
,cbal
FROM
bld
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
obal = EXCLUDED.obal
,debits = EXCLUDED.debits
,credits = EXCLUDED.credits
,cbal = EXCLUDED.cbal
RETURNING *
)
,touched AS (
SELECT DISTINCT
fspr
FROM
ins
)
UPDATE
evt.fspr f
SET
prop = f.prop || '{"rf":"global"}'::jsonb
FROM
touched t
WHERE
t.fspr = f.id;
2018-09-24 16:47:38 -04:00
END;
2018-09-25 12:58:29 -04:00
$func$;