work on initial bal insert problems
This commit is contained in:
parent
7f59452298
commit
b6378f02fe
@ -1,6 +1,35 @@
|
||||
CREATE FUNCTION evt.balrf(_mind tstzrange, _maxd tstzrange) RETURNS void AS
|
||||
$func$
|
||||
DECLARE
|
||||
_lastdur tstzrange;
|
||||
_newdur tstzrange;
|
||||
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
|
||||
--list each period in min and max
|
||||
prng AS (
|
||||
|
@ -5,81 +5,51 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
|
||||
AS
|
||||
$func$
|
||||
DECLARE
|
||||
_lastdur tstzrange;
|
||||
_newdur tstzrange;
|
||||
_mind timestamptz;
|
||||
_maxd timestamptz;
|
||||
BEGIN
|
||||
|
||||
--get last global rollforward
|
||||
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
|
||||
_lastdur
|
||||
FROM
|
||||
evt.fspr
|
||||
WHERE
|
||||
prop @> '{"rf":"global"}'::jsonb
|
||||
WITH;
|
||||
|
||||
_mind
|
||||
,_maxd;
|
||||
|
||||
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 (
|
||||
SELECT
|
||||
acct
|
||||
,fspr
|
||||
,dur
|
||||
,coalesce(sum(amount) FILTER (WHERE amount > 0),0) debits
|
||||
,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits
|
||||
FROM
|
||||
ins
|
||||
INNER JOIN evt.fspr f ON
|
||||
f.id = ins.fspr
|
||||
GROUP BY
|
||||
acct
|
||||
,fspr
|
||||
,dur
|
||||
)
|
||||
,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
|
||||
--get every account involved in target range
|
||||
,arng AS (
|
||||
SELECT DISTINCT
|
||||
acct
|
||||
FROM
|
||||
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 (
|
||||
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
|
||||
list.acct
|
||||
,list.minp
|
||||
,list.maxp
|
||||
arng.acct
|
||||
,f.id
|
||||
,f.dur
|
||||
,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.cbal::numeric(12,2),0) + COALESCE(agg.debits,0) + COALESCE(agg.credits,0)
|
||||
FROM
|
||||
list
|
||||
arng
|
||||
INNER JOIN evt.fspr f ON
|
||||
upper(f.dur) = list.minp
|
||||
upper(f.dur) = _mind
|
||||
LEFT OUTER JOIN evt.bal b ON
|
||||
b.acct = list.acct
|
||||
b.acct = arng.acct
|
||||
AND b.fspr = f.id
|
||||
LEFT OUTER JOIN agg ON
|
||||
agg.acct = list.acct
|
||||
agg.acct = arng.acct
|
||||
AND agg.fspr = f.id
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
rf.acct
|
||||
,rf.minp
|
||||
,rf.maxp
|
||||
,f.id
|
||||
,f.dur
|
||||
,COALESCE(rf.cbal,0)::numeric(12,2)
|
||||
@ -120,10 +88,11 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
|
||||
agg.acct = rf.acct
|
||||
AND agg.fspr = f.id
|
||||
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
|
||||
evt.bal (acct, fspr, obal, debits, credits, cbal)
|
||||
SELECT
|
||||
@ -139,7 +108,24 @@ CREATE OR REPLACE FUNCTION evt.gl_insert() RETURNS trigger
|
||||
obal = EXCLUDED.obal
|
||||
,debits = EXCLUDED.debits
|
||||
,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;
|
||||
END;
|
||||
$func$;
|
||||
|
Loading…
Reference in New Issue
Block a user