add comments

This commit is contained in:
Paul Trowbridge 2018-10-05 14:29:04 -04:00
parent 664b18cdce
commit 85922e0141
2 changed files with 62 additions and 14 deletions

View File

@ -188,6 +188,11 @@ DECLARE
_mind timestamptz; _mind timestamptz;
_maxd timestamptz; _maxd timestamptz;
BEGIN BEGIN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--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
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT SELECT
(SELECT min(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr) (SELECT min(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr)
,GREATEST( ,GREATEST(
@ -201,12 +206,16 @@ BEGIN
_mind _mind
,_maxd; ,_maxd;
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--aggregate all inserted gl transactions
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
WITH WITH
agg AS ( agg AS (
SELECT SELECT
acct acct
,fspr ,fspr
,dur ,dur
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) debits
,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits ,coalesce(sum(amount) FILTER (WHERE amount < 0),0) credits
FROM FROM
@ -218,14 +227,19 @@ BEGIN
,fspr ,fspr
,dur ,dur
) )
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--get every account involved in target range --get every account involved in target range
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,arng AS ( ,arng AS (
SELECT DISTINCT SELECT DISTINCT
acct acct
FROM FROM
agg b agg b
) )
,seq AS ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--roll the balances forward
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,bld AS (
WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS
( (
SELECT SELECT
@ -272,7 +286,10 @@ BEGIN
) )
SELECT * FROM rf WHERE lower(dur) >= _mind SELECT * FROM rf WHERE lower(dur) >= _mind
) )
,bali AS ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--insert the rolled balances
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,ins AS (
INSERT INTO INSERT INTO
evt.bal (acct, fspr, obal, debits, credits, cbal) evt.bal (acct, fspr, obal, debits, credits, cbal)
SELECT SELECT
@ -283,7 +300,7 @@ BEGIN
,credits ,credits
,cbal ,cbal
FROM FROM
seq bld
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
obal = EXCLUDED.obal obal = EXCLUDED.obal
,debits = EXCLUDED.debits ,debits = EXCLUDED.debits
@ -292,21 +309,30 @@ BEGIN
,prop = evt.bal.prop || EXCLUDED.prop ,prop = evt.bal.prop || EXCLUDED.prop
RETURNING * RETURNING *
) )
,n as ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--determine all fiscal periods invovled in the insert
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,touched as (
SELECT DISTINCT SELECT DISTINCT
fspr fspr
FROM FROM
bali ins
) )
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
--update evt.fspr to reflect touched by gl
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
UPDATE UPDATE
evt.fspr f evt.fspr f
SET SET
prop = COALESCE(f.prop,'{}'::JSONB) || '{"gltouch":"yes"}'::jsonb prop = COALESCE(f.prop,'{}'::JSONB) || '{"gltouch":"yes"}'::jsonb
FROM FROM
n touched t
WHERE WHERE
f.id = n.fspr; f.id = t.fspr;
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--this is to catch up all the other accounts if actually necessary
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
PERFORM evt.balrf(); PERFORM evt.balrf();
RETURN NULL; RETURN NULL;

View File

@ -8,9 +8,11 @@ DECLARE
_mind timestamptz; _mind timestamptz;
_maxd timestamptz; _maxd timestamptz;
BEGIN BEGIN
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--find min and max applicable periods to roll --find min and max applicable periods to roll
--min: earliest period involved in current gl posting --min: earliest period involved in current gl posting
--max: latest period involved in any posting, or if none, the current posting --max: latest period involved in any posting, or if none, the current posting
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT SELECT
(SELECT min(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr) (SELECT min(lower(f.dur)) FROM ins INNER JOIN evt.fspr f ON f.id = ins.fspr)
,GREATEST( ,GREATEST(
@ -24,6 +26,9 @@ BEGIN
_mind _mind
,_maxd; ,_maxd;
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--aggregate all inserted gl transactions
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
WITH WITH
agg AS ( agg AS (
SELECT SELECT
@ -42,14 +47,19 @@ BEGIN
,fspr ,fspr
,dur ,dur
) )
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--get every account involved in target range --get every account involved in target range
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,arng AS ( ,arng AS (
SELECT DISTINCT SELECT DISTINCT
acct acct
FROM FROM
agg b agg b
) )
,seq AS ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--roll the balances forward
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,bld AS (
WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS WITH RECURSIVE rf (acct, id, dur, obal, debits, credits, cbal) AS
( (
SELECT SELECT
@ -96,7 +106,10 @@ BEGIN
) )
SELECT * FROM rf WHERE lower(dur) >= _mind SELECT * FROM rf WHERE lower(dur) >= _mind
) )
,bali AS ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--insert the rolled balances
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,ins AS (
INSERT INTO INSERT INTO
evt.bal (acct, fspr, obal, debits, credits, cbal) evt.bal (acct, fspr, obal, debits, credits, cbal)
SELECT SELECT
@ -107,7 +120,7 @@ BEGIN
,credits ,credits
,cbal ,cbal
FROM FROM
seq bld
ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET
obal = EXCLUDED.obal obal = EXCLUDED.obal
,debits = EXCLUDED.debits ,debits = EXCLUDED.debits
@ -116,21 +129,30 @@ BEGIN
,prop = evt.bal.prop || EXCLUDED.prop ,prop = evt.bal.prop || EXCLUDED.prop
RETURNING * RETURNING *
) )
,n as ( -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--determine all fiscal periods invovled in the insert
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
,touched as (
SELECT DISTINCT SELECT DISTINCT
fspr fspr
FROM FROM
bali ins
) )
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
--update evt.fspr to reflect touched by gl
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
UPDATE UPDATE
evt.fspr f evt.fspr f
SET SET
prop = COALESCE(f.prop,'{}'::JSONB) || '{"gltouch":"yes"}'::jsonb prop = COALESCE(f.prop,'{}'::JSONB) || '{"gltouch":"yes"}'::jsonb
FROM FROM
n touched t
WHERE WHERE
f.id = n.fspr; f.id = t.fspr;
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--this is to catch up all the other accounts if actually necessary
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
PERFORM evt.balrf(); PERFORM evt.balrf();
RETURN NULL; RETURN NULL;