clean up
This commit is contained in:
		
							parent
							
								
									8f89cb98e7
								
							
						
					
					
						commit
						a5642f7ef2
					
				| @ -1,53 +1,53 @@ | ||||
| WITH | ||||
| --startign month | ||||
| startm AS ( | ||||
|     SELECT 1 as m | ||||
| ) | ||||
| ,m AS ( | ||||
|     SELECT | ||||
|         g.s calendar_month | ||||
|         ,startm.m starting_month | ||||
|         ,g.s + CASE WHEN g.s < startm.m THEN startm.m +1 ELSE -startm.m +1 END fisc_month | ||||
|     FROM | ||||
|         generate_series(1,12,1) g(s) | ||||
|         CROSS JOIN startm | ||||
| ) | ||||
| --select * from m | ||||
| INSERT INTO | ||||
|     evt.fspr (id, dur) | ||||
| SELECT  | ||||
|     --TO_CHAR(gs.d,'YYYY.MM.DD')::ltree t1 | ||||
|     ( | ||||
|         --year | ||||
|         to_char(extract(year from gs.d),'FM0000') | ||||
|         --month | ||||
|         ||'.'||to_char(m.fisc_month,'FM00') | ||||
|     )::ltree t2 | ||||
|     ,tstzrange(gs.d,gs.d + '1 month'::interval) r | ||||
| FROM  | ||||
|     generate_series('2018-01-01 00:00'::timestamptz,'2099-12-01 00:00'::timestamptz,'1 month') gs(d) | ||||
|     INNER JOIN m ON | ||||
|         m.calendar_month = extract(month from gs.d) | ||||
| ORDER BY  | ||||
|     gs.d ASC | ||||
| /* | ||||
| INSERT INTO | ||||
|     evt.fspr | ||||
| SELECT  | ||||
|     --TO_CHAR(gs.d,'YYYY.MM.DD')::ltree t1 | ||||
|     ( | ||||
|         --year | ||||
|         to_char(extract(year from gs.d),'FM0000') | ||||
|         --quarter | ||||
|         ||'.'||to_char(m.fq,'FM00') | ||||
|         --month | ||||
|         ||'.'||to_char(m.fm,'FM00') | ||||
|         --day | ||||
|         ||'.'||to_char(extract(day from gs.d),'FM00') | ||||
|     )::ltree t2 | ||||
|     ,tstzrange(gs.d,gs.d + '1 month'::interval) r | ||||
| FROM  | ||||
|     generate_series('2018-01-01 00:00'::timestamptz,'2099-12-01 00:00'::timestamptz,'1 day') gs(d) | ||||
|     INNER JOIN m ON | ||||
|         m.cm = extract(month from gs.d) | ||||
| WITH | ||||
| --startign month | ||||
| startm AS ( | ||||
|     SELECT 1 as m | ||||
| ) | ||||
| ,m AS ( | ||||
|     SELECT | ||||
|         g.s calendar_month | ||||
|         ,startm.m starting_month | ||||
|         ,g.s + CASE WHEN g.s < startm.m THEN startm.m +1 ELSE -startm.m +1 END fisc_month | ||||
|     FROM | ||||
|         generate_series(1,12,1) g(s) | ||||
|         CROSS JOIN startm | ||||
| ) | ||||
| --select * from m | ||||
| INSERT INTO | ||||
|     evt.fspr (id, dur) | ||||
| SELECT  | ||||
|     --TO_CHAR(gs.d,'YYYY.MM.DD')::ltree t1 | ||||
|     ( | ||||
|         --year | ||||
|         to_char(extract(year from gs.d),'FM0000') | ||||
|         --month | ||||
|         ||'.'||to_char(m.fisc_month,'FM00') | ||||
|     )::ltree t2 | ||||
|     ,tstzrange(gs.d,gs.d + '1 month'::interval) r | ||||
| FROM  | ||||
|     generate_series('2018-01-01 00:00'::timestamptz,'2099-12-01 00:00'::timestamptz,'1 month') gs(d) | ||||
|     INNER JOIN m ON | ||||
|         m.calendar_month = extract(month from gs.d) | ||||
| ORDER BY  | ||||
|     gs.d ASC | ||||
| /* | ||||
| INSERT INTO | ||||
|     evt.fspr | ||||
| SELECT  | ||||
|     --TO_CHAR(gs.d,'YYYY.MM.DD')::ltree t1 | ||||
|     ( | ||||
|         --year | ||||
|         to_char(extract(year from gs.d),'FM0000') | ||||
|         --quarter | ||||
|         ||'.'||to_char(m.fq,'FM00') | ||||
|         --month | ||||
|         ||'.'||to_char(m.fm,'FM00') | ||||
|         --day | ||||
|         ||'.'||to_char(extract(day from gs.d),'FM00') | ||||
|     )::ltree t2 | ||||
|     ,tstzrange(gs.d,gs.d + '1 month'::interval) r | ||||
| FROM  | ||||
|     generate_series('2018-01-01 00:00'::timestamptz,'2099-12-01 00:00'::timestamptz,'1 day') gs(d) | ||||
|     INNER JOIN m ON | ||||
|         m.cm = extract(month from gs.d) | ||||
| */ | ||||
| @ -1,59 +0,0 @@ | ||||
| WITH | ||||
| list AS ( | ||||
|     SELECT  | ||||
|         acct | ||||
|         ,min(lower(dur)) minp | ||||
|         ,max(lower(dur)) maxp | ||||
|     FROM | ||||
|         evt.bal b | ||||
|         INNER JOIN evt.fspr f ON | ||||
|             f.id = b.fspr | ||||
|     GROUP BY | ||||
|         acct | ||||
| ) | ||||
| ,seq AS ( | ||||
|     WITH RECURSIVE rf (acct, minp, maxp, id, dur, obal, debits, credits, cbal) AS | ||||
|     ( | ||||
|         SELECT | ||||
|             list.acct | ||||
|             ,list.minp | ||||
|             ,list.maxp | ||||
|             ,f.id | ||||
|             ,f.dur | ||||
|             ,b.obal::numeric(12,2) | ||||
|             ,b.debits::numeric(12,2) | ||||
|             ,b.credits::numeric(12,2) | ||||
|             ,b.cbal::numeric(12,2) | ||||
|         FROM | ||||
|             list | ||||
|             INNER JOIN evt.fspr f ON | ||||
|                 lower(f.dur) = list.minp | ||||
|             LEFT OUTER JOIN evt.bal b ON | ||||
|                 b.acct = list.acct | ||||
|                 AND b.fspr = f.id | ||||
|          | ||||
|         UNION ALL | ||||
| 
 | ||||
|         SELECT | ||||
|             rf.acct | ||||
|             ,rf.minp | ||||
|             ,rf.maxp | ||||
|             ,f.id | ||||
|             ,f.dur | ||||
|             ,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.maxp | ||||
|     ) | ||||
|     select * from rf | ||||
| ) | ||||
| SELECT * FROM seq ORDER BY acct, dur | ||||
| @ -1,90 +0,0 @@ | ||||
| ---------------------------handle balance updates---------------------------------------- | ||||
| 
 | ||||
| CREATE OR REPLACE FUNCTION evt.bal_insert() RETURNS trigger | ||||
|     LANGUAGE plpgsql | ||||
|     AS  | ||||
|     $func$ | ||||
|     BEGIN | ||||
|         WITH | ||||
|         list AS ( | ||||
|             SELECT  | ||||
|                 acct | ||||
|                 ,min(lower(dur)) minp | ||||
|                 ,max(lower(dur)) maxp | ||||
|             FROM | ||||
|                 ins b | ||||
|                 INNER JOIN evt.fspr f ON | ||||
|                     f.id = b.fspr | ||||
|             GROUP BY | ||||
|                 acct | ||||
|         ) | ||||
|         ,seq AS ( | ||||
|             WITH RECURSIVE rf (acct, minp, maxp, id, dur, obal, debits, credits, cbal) AS | ||||
|             ( | ||||
|                 SELECT | ||||
|                     list.acct | ||||
|                     ,list.minp | ||||
|                     ,list.maxp | ||||
|                     ,f.id | ||||
|                     ,f.dur | ||||
|                     ,b.obal::numeric(12,2) | ||||
|                     ,b.debits::numeric(12,2) | ||||
|                     ,b.credits::numeric(12,2) | ||||
|                     ,b.cbal::numeric(12,2) | ||||
|                 FROM | ||||
|                     list | ||||
|                     INNER JOIN evt.fspr f ON | ||||
|                         lower(f.dur) = list.minp | ||||
|                     LEFT OUTER JOIN evt.bal b ON | ||||
|                         b.acct = list.acct | ||||
|                         AND b.fspr = f.id | ||||
|                  | ||||
|                 UNION ALL | ||||
| 
 | ||||
|                 SELECT | ||||
|                     rf.acct | ||||
|                     ,rf.minp | ||||
|                     ,rf.maxp | ||||
|                     ,f.id | ||||
|                     ,f.dur | ||||
|                     ,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.maxp | ||||
|             ) | ||||
|             select * from rf | ||||
|         ) | ||||
|         INSERT INTO | ||||
|             evt.bal (acct, fspr, obal, debits, credits, cbal) | ||||
|         SELECT | ||||
|             acct | ||||
|             ,id | ||||
|             ,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(); | ||||
		Loading…
	
		Reference in New Issue
	
	Block a user