[open-ils-commits] r8651 -
branches/acq-experiment/Open-ILS/src/sql/Pg
svn at svn.open-ils.org
svn at svn.open-ils.org
Tue Feb 5 23:00:26 EST 2008
Author: miker
Date: 2008-02-05 22:32:02 -0500 (Tue, 05 Feb 2008)
New Revision: 8651
Modified:
branches/acq-experiment/Open-ILS/src/sql/Pg/200.schema.acq.sql
Log:
some views to simplify calculating fund balances which take mixed amount and percent allocations into account
Modified: branches/acq-experiment/Open-ILS/src/sql/Pg/200.schema.acq.sql
===================================================================
--- branches/acq-experiment/Open-ILS/src/sql/Pg/200.schema.acq.sql 2008-02-06 02:28:41 UTC (rev 8650)
+++ branches/acq-experiment/Open-ILS/src/sql/Pg/200.schema.acq.sql 2008-02-06 03:32:02 UTC (rev 8651)
@@ -213,6 +213,57 @@
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;
More information about the open-ils-commits
mailing list