add trigger for balance inserts
This commit is contained in:
		
							parent
							
								
									a31c910bb7
								
							
						
					
					
						commit
						4869265ea3
					
				
							
								
								
									
										110
									
								
								db_deploy.sql
									
									
									
									
									
								
							
							
						
						
									
										110
									
								
								db_deploy.sql
									
									
									
									
									
								
							| @ -217,3 +217,113 @@ CREATE TRIGGER gl_insert | |||||||
|     REFERENCING NEW TABLE AS ins  |     REFERENCING NEW TABLE AS ins  | ||||||
|     FOR EACH STATEMENT |     FOR EACH STATEMENT | ||||||
|     EXECUTE PROCEDURE evt.gl_insert(); |     EXECUTE PROCEDURE evt.gl_insert(); | ||||||
|  | 
 | ||||||
|  | ---------------------------handle balance updates---------------------------------------- | ||||||
|  | 
 | ||||||
|  | CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger | ||||||
|  |     LANGUAGE plpgsql | ||||||
|  |     AS  | ||||||
|  |     $func$ | ||||||
|  |     BEGIN | ||||||
|  |         WITH | ||||||
|  |         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 | ||||||
|  |         ) | ||||||
|  |         INSERT INTO | ||||||
|  |             evt.bal (Acct, fspr, obal, debits, credits, cbal) | ||||||
|  |         SELECT | ||||||
|  |             acct | ||||||
|  |             ,fspr | ||||||
|  |             ,obal | ||||||
|  |             ,debits | ||||||
|  |             ,credits | ||||||
|  |             ,cbal | ||||||
|  |         FROM | ||||||
|  |             seq | ||||||
|  |         ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET | ||||||
|  |             obal = EXCLUDED.obal | ||||||
|  |             ,debits = EXCLUDED.debits | ||||||
|  |             ,credits = EXCLUDED.credits | ||||||
|  |             ,cbal = EXCLUDED.cbal; | ||||||
|  |         RETURN NULL; | ||||||
|  |     END; | ||||||
|  |     $func$; | ||||||
|  | 
 | ||||||
|  | CREATE TRIGGER bal_insert  | ||||||
|  |     AFTER INSERT ON evt.bal | ||||||
|  |     REFERENCING NEW TABLE AS ins  | ||||||
|  |     FOR EACH STATEMENT | ||||||
|  |     EXECUTE PROCEDURE evt.bal_insert(); | ||||||
| @ -1,4 +1,4 @@ | |||||||
| ---------------------------handle new gl lines---------------------------------------- | ---------------------------handle balance updates---------------------------------------- | ||||||
| 
 | 
 | ||||||
| CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger | CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger | ||||||
|     LANGUAGE plpgsql |     LANGUAGE plpgsql | ||||||
| @ -82,30 +82,22 @@ CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger | |||||||
|             ) |             ) | ||||||
|             SELECT * FROM rf |             SELECT * FROM rf | ||||||
|         ) |         ) | ||||||
|         select * from seq |         INSERT INTO | ||||||
|         ,xseq AS ( |             evt.bal (Acct, fspr, obal, debits, credits, cbal) | ||||||
|         SELECT |         SELECT | ||||||
|             rng.* |             acct | ||||||
|             ,fspr.id |             ,fspr | ||||||
|             ,row_number() OVER (partition by rng.acct, rng.fspr ORDER BY lower(fspr.dur) ASC) rn |             ,obal | ||||||
|             ,coalesce(b.obal,0) obal |             ,debits | ||||||
|             ,coalesce(b.debits,0) debits |             ,credits | ||||||
|             ,coalesce(b.credits,0) credits |             ,cbal | ||||||
|             ,coalesce(b.cbal,0) cbal |  | ||||||
|         FROM |         FROM | ||||||
|             rng |             seq | ||||||
|             INNER JOIN evt.fspr ON |         ON CONFLICT ON CONSTRAINT bal_pk DO UPDATE SET | ||||||
|                 lower(fspr.dur) >= minrange |             obal = EXCLUDED.obal | ||||||
|                 AND lower(fspr.dur) <= maxrange |             ,debits = EXCLUDED.debits | ||||||
|             LEFT OUTER JOIN evt.bal b ON |             ,credits = EXCLUDED.credits | ||||||
|                 b.acct = rng.acct |             ,cbal = EXCLUDED.cbal; | ||||||
|                 AND b.fspr = fspr.id |  | ||||||
|         ORDER BY |  | ||||||
|             rng.acct |  | ||||||
|             ,rng.fspr |  | ||||||
|             ,rn |  | ||||||
|         ) |  | ||||||
|         select * from seq |  | ||||||
|         RETURN NULL; |         RETURN NULL; | ||||||
|     END; |     END; | ||||||
|     $func$; |     $func$; | ||||||
|  | |||||||
		Loading…
	
		Reference in New Issue
	
	Block a user