From a31c910bb7c2052c2703509d8b5c03555cb5759f Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sat, 22 Sep 2018 00:21:02 -0400 Subject: [PATCH] do recursive balance cascade --- schema/triggers/bal_insert.sql | 122 ++++++++++++++++++++++++++------- 1 file changed, 99 insertions(+), 23 deletions(-) diff --git a/schema/triggers/bal_insert.sql b/schema/triggers/bal_insert.sql index ec0b204..b13dea3 100644 --- a/schema/triggers/bal_insert.sql +++ b/schema/triggers/bal_insert.sql @@ -6,30 +6,106 @@ CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger $func$ BEGIN WITH - --incoming new accounts and any other periods used for the same accounts - rng AS ( - --for each item determine if a gap exists between new an previous period (if any) - SELECT - ins.acct - ,ins.fspr - ,lower(f.dur) dur - ,max(lower(bp.dur)) maxp - ,min(lower(bp.dur)) minp - FROM - evt.bal ins - INNER JOIN evt.fspr f ON - f.id = ins.fspr - LEFT OUTER JOIN evt.bal b ON - b.acct = ins.acct - LEFT OUTER JOIN evt.fspr bp ON - bp.id = b.fspr - WHERE ins.fspr = '2018.11' - GROUP BY - ins.acct - ,ins.fspr - ,f.dur + seq AS ( + WITH RECURSIVE rf (acct, fspr, minrange, maxrange, dur, id, obal, debits, credits, cbal) AS + ( + SELECT + rng.acct + ,rng.fspr + ,rng.minrange + ,rng.maxrange + ,f.dur + ,f.id + ,b.obal::numeric(12,2) + ,b.debits::numeric(12,2) + ,b.credits::numeric(12,2) + ,b.cbal::numeric(12,2) + FROM + ( + --for each item determine if a gap exists between new an previous period (if any) + SELECT + ins.acct + ,ins.fspr + ,lower(f.dur) dur + ,CASE WHEN lower(f.dur) > max(lower(bp.dur)) THEN max(lower(bp.dur)) ELSE lower(f.dur) END minrange + ,CASE WHEN lower(f.dur) < max(lower(bp.dur)) THEN max(lower(bp.dur)) ELSE lower(f.dur) END maxrange + FROM + ( + SELECT + * + FROM + evt.bal + WHERE + fspr = '2018.11' + ) ins + INNER JOIN evt.fspr f ON + f.id = ins.fspr + LEFT OUTER JOIN evt.bal b ON + b.acct = ins.acct + LEFT OUTER JOIN evt.fspr bp ON + bp.id = b.fspr + WHERE + b.fspr <> '2018.11' + GROUP BY + ins.acct + ,ins.fspr + ,f.dur + ) rng + INNER JOIN evt.fspr f ON + lower(f.dur) = minrange + INNER JOIN evt.bal b ON + b.acct = rng.acct + AND b.fspr = f.id + + UNION ALL + + SELECT + rf.acct + ,rf.fspr + ,rf.minrange + ,rf.maxrange + ,f.dur + ,f.id + ,COALESCE(rf.cbal,0)::numeric(12,2) + ,COALESCE(b.debits,0)::numeric(12,2) + ,COALESCE(b.credits,0)::numeric(12,2) + ,(COALESCE(rf.cbal,0) + 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 + lower(f.dur) <= rf.maxrange + ) + SELECT * FROM rf ) - select + select * from seq + ,xseq AS ( + SELECT + rng.* + ,fspr.id + ,row_number() OVER (partition by rng.acct, rng.fspr ORDER BY lower(fspr.dur) ASC) rn + ,coalesce(b.obal,0) obal + ,coalesce(b.debits,0) debits + ,coalesce(b.credits,0) credits + ,coalesce(b.cbal,0) cbal + FROM + rng + INNER JOIN evt.fspr ON + lower(fspr.dur) >= minrange + AND lower(fspr.dur) <= maxrange + LEFT OUTER JOIN evt.bal b ON + b.acct = rng.acct + AND b.fspr = fspr.id + ORDER BY + rng.acct + ,rng.fspr + ,rn + ) + select * from seq RETURN NULL; END; $func$;