From: miker Date: Wed, 6 Feb 2008 03:32:02 +0000 (+0000) Subject: some views to simplify calculating fund balances which take mixed amount and percent... X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=2c1ab30f6bb39b86dc59678f2b66f14cca53f3fd;p=Evergreen.git some views to simplify calculating fund balances which take mixed amount and percent allocations into account git-svn-id: svn://svn.open-ils.org/ILS/branches/acq-experiment@8651 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- diff --git a/Open-ILS/src/sql/Pg/200.schema.acq.sql b/Open-ILS/src/sql/Pg/200.schema.acq.sql index 88f11273e1..d704c68c16 100644 --- a/Open-ILS/src/sql/Pg/200.schema.acq.sql +++ b/Open-ILS/src/sql/Pg/200.schema.acq.sql @@ -213,6 +213,57 @@ CREATE TABLE acq.fund_allocation ( CONSTRAINT allocation_amount_or_percent CHECK ((percent IS NULL AND amount IS NOT NULL) OR (percent IS NOT NULL AND amount IS NULL)) ); +CREATE OR REPLACE VIEW acq.fund_allocation_total AS + SELECT fund, + SUM(amount)::NUMERIC(100,2) AS amount + FROM ( + SELECT fund, + SUM(amount)::NUMERIC(100,2) AS amount + FROM acq.fund_allocation + WHERE percent IS NULL + GROUP BY 1 + UNION ALL + SELECT fund, + SUM( (SELECT SUM(amount) FROM acq.funding_source_credit c WHERE c.funding_source = a.funding_source) * (a.percent/100.0) )::NUMERIC(100,2) AS amount + FROM acq.fund_allocation a + WHERE a.amount IS NULL + GROUP BY 1 + ) x + GROUP BY 1; + +CREATE OR REPLACE VIEW acq.fund_debit_total AS + SELECT id AS fund, + encumberance, + SUM(amount) AS amount + FROM acq.fund_debit + GROUP BY 1,2; + +CREATE OR REPLACE VIEW acq.fund_encumberance_total AS + SELECT fund, + SUM(amount) AS amount + FROM acq.fund_debit_total + WHERE encumberance IS TRUE + GROUP BY 1; + +CREATE OR REPLACE VIEW acq.fund_spent_total AS + SELECT fund, + SUM(amount) AS amount + FROM acq.fund_debit_total + WHERE encumberance IS FALSE + GROUP BY 1; + +CREATE OR REPLACE VIEW acq.fund_combined_balance AS + SELECT c.fund, + c.amount - COALESCE(d.amount,0.0) AS amount + FROM acq.fund_allocation_total c + LEFT JOIN acq.fund_debit_total d USING (fund); + +CREATE OR REPLACE VIEW acq.fund_spent_balance AS + SELECT c.fund, + c.amount - COALESCE(d.amount,0.0) AS amount + FROM acq.fund_allocation_total c + LEFT JOIN acq.fund_spent_total d USING (fund); + COMMIT;