work on initial bal insert problems

This commit is contained in:
Paul Trowbridge 2018-09-25 00:33:42 -04:00
parent 7f59452298
commit b6378f02fe
2 changed files with 140 additions and 125 deletions

View File

@ -1,6 +1,35 @@
CREATE FUNCTION evt.balrf(_mind tstzrange, _maxd tstzrange) RETURNS void AS CREATE FUNCTION evt.balrf(_mind tstzrange, _maxd tstzrange) RETURNS void AS
$func$ $func$
DECLARE
_lastdur tstzrange;
_newdur tstzrange;
BEGIN BEGIN
--get last global rollforward
SELECT
dur
INTO
_lastdur
FROM
evt.fspr
WHERE
prop @> '{"rf":"global"}'::jsonb
WITH;
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;
WITH WITH
--list each period in min and max --list each period in min and max
prng AS ( prng AS (

View File

@ -1,85 +1,55 @@
---------------------------handle new gl lines---------------------------------------- ---------------------------handle new gl lines----------------------------------------
CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
LANGUAGE plpgsql LANGUAGE plpgsql
AS AS
$func$ $func$
DECLARE DECLARE
_lastdur tstzrange; _mind timestamptz;
_newdur tstzrange; _maxd timestamptz;
BEGIN BEGIN
--get last global rollforward
SELECT SELECT
dur (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)
)
)
INTO INTO
_lastdur _mind
FROM ,_maxd;
evt.fspr
WHERE
prop @> '{"rf":"global"}'::jsonb
WITH;
WITH 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;
agg AS ( agg AS (
SELECT SELECT
acct acct
,fspr ,fspr
,dur
,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits ,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits
,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits ,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits
FROM FROM
ins ins
INNER JOIN evt.fspr f ON
f.id = ins.fspr
GROUP BY GROUP BY
acct acct
,fspr ,fspr
,dur
) )
,list AS ( --get every account involved in target range
SELECT ,arng AS (
b.acct SELECT DISTINCT
,least(min(lower(f.dur)),min(lower(g.dur))) minp acct
,greatest(max(lower(f.dur)),max(lower(g.dur))) maxp
FROM FROM
agg b agg b
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
GROUP BY
b.acct
) )
,seq AS ( ,seq AS (
WITH RECURSIVE rf (acct, minp, maxp, id, dur, obal, debits, credits, cbal) AS WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS
( (
SELECT SELECT
list.acct arng.acct
,list.minp
,list.maxp
,f.id ,f.id
,f.dur ,f.dur
,COALESCE(b.obal::numeric(12,2),0) ,COALESCE(b.obal::numeric(12,2),0)
@ -87,22 +57,20 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
,COALESCE(b.credits::numeric(12,2),0) + COALESCE(agg.credits,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) ,COALESCE(b.cbal::numeric(12,2),0) + COALESCE(agg.debits,0) + COALESCE(agg.credits,0)
FROM FROM
list arng
INNER JOIN evt.fspr f ON INNER JOIN evt.fspr f ON
upper(f.dur) = list.minp upper(f.dur) = _mind
LEFT OUTER JOIN evt.bal b ON LEFT OUTER JOIN evt.bal b ON
b.acct = list.acct b.acct = arng.acct
AND b.fspr = f.id AND b.fspr = f.id
LEFT OUTER JOIN agg ON LEFT OUTER JOIN agg ON
agg.acct = list.acct agg.acct = arng.acct
AND agg.fspr = f.id AND agg.fspr = f.id
UNION ALL UNION ALL
SELECT SELECT
rf.acct rf.acct
,rf.minp
,rf.maxp
,f.id ,f.id
,f.dur ,f.dur
,COALESCE(rf.cbal,0)::numeric(12,2) ,COALESCE(rf.cbal,0)::numeric(12,2)
@ -120,10 +88,11 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
agg.acct = rf.acct agg.acct = rf.acct
AND agg.fspr = f.id AND agg.fspr = f.id
WHERE WHERE
lower(f.dur) <= rf.maxp lower(f.dur) <= _maxd
) )
SELECT * FROM rf WHERE lower(dur) >= minp SELECT * FROM rf WHERE lower(dur) >= _mind
) )
,bali AS (
INSERT INTO INSERT INTO
evt.bal (acct, fspr, obal, debits, credits, cbal) evt.bal (acct, fspr, obal, debits, credits, cbal)
SELECT SELECT
@ -139,10 +108,27 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
obal = EXCLUDED.obal obal = EXCLUDED.obal
,debits = EXCLUDED.debits ,debits = EXCLUDED.debits
,credits = EXCLUDED.credits ,credits = EXCLUDED.credits
,cbal = EXCLUDED.cbal; ,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;
RETURN NULL; RETURN NULL;
END; END;
$func$; $func$;
CREATE TRIGGER gl_insert CREATE TRIGGER gl_insert
AFTER INSERT ON evt.gl AFTER INSERT ON evt.gl