Addresses LP#800477 where some acq views calculate the totals incorrectly or in unexp...
authorJames Fournie <jfournie@sitka.bclibraries.ca>
Mon, 19 Sep 2011 23:01:01 +0000 (16:01 -0700)
committerBill Erickson <berick@esilibrary.com>
Thu, 22 Sep 2011 15:18:39 +0000 (11:18 -0400)
Signed-off-by: James Fournie <jfournie@sitka.bclibraries.ca>
Signed-off-by: Bill Erickson <berick@esilibrary.com>
Open-ILS/src/sql/Pg/200.schema.acq.sql
Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477 [new file with mode: 0644]

index b566ff5..9276248 100644 (file)
@@ -2460,27 +2460,27 @@ CREATE OR REPLACE VIEW acq.fund_allocation_total AS
     GROUP BY 1;
 
 CREATE OR REPLACE VIEW acq.fund_debit_total AS
-    SELECT  fund.id AS fund,
-            fund_debit.encumbrance AS encumbrance,
-                       SUM( COALESCE( fund_debit.amount, 0 ) ) AS amount
-      FROM acq.fund AS fund
-            LEFT JOIN acq.fund_debit AS fund_debit
-                ON ( fund.id = fund_debit.fund )
-      GROUP BY 1,2;
+    SELECT fund.id AS fund,
+           SUM(COALESCE(fund_debit.amount, 0::numeric)) AS amount
+    FROM acq.fund fund
+          LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund
+    GROUP BY fund.id;
 
 CREATE OR REPLACE VIEW acq.fund_encumbrance_total AS
-    SELECT  fund,
-            SUM(amount) AS amount
-      FROM  acq.fund_debit_total
-      WHERE encumbrance IS TRUE
-      GROUP BY 1;
+    SELECT fund.id AS fund,
+           SUM(COALESCE(fund_debit.amount, 0::numeric)) AS amount
+    FROM acq.fund fund
+          LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund
+    WHERE fund_debit.encumbrance
+    GROUP BY fund.id;
 
 CREATE OR REPLACE VIEW acq.fund_spent_total AS
-    SELECT  fund,
-            SUM(amount) AS amount
-      FROM  acq.fund_debit_total
-      WHERE encumbrance IS FALSE
-      GROUP BY 1;
+    SELECT fund.id AS fund,
+           SUM(COALESCE(fund_debit.amount, 0::numeric)) AS amount
+    FROM acq.fund fund
+          LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund
+    WHERE NOT fund_debit.encumbrance
+    GROUP BY fund.id;
 
 CREATE OR REPLACE VIEW acq.fund_combined_balance AS
     SELECT  c.fund,
diff --git a/Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477 b/Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477
new file mode 100644 (file)
index 0000000..dc21cd0
--- /dev/null
@@ -0,0 +1,34 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version, install_date) VALUES ('XXXXXXX',now());
+
+-- acq.fund_combined_balance is unchanged however we need to drop it to recreate the other views
+-- we need to drop all our views because we change the number of columns
+-- for example, debit_total does not need an encumberance column when we have a sepearate total for that
+
+DROP VIEW acq.fund_combined_balance;
+DROP VIEW acq.fund_encumbrance_total;
+DROP VIEW acq.fund_spent_total;
+DROP VIEW acq.fund_debit_total;
+
+CREATE OR REPLACE VIEW acq.fund_debit_total AS
+ SELECT fund.id AS fund, sum(COALESCE(fund_debit.amount, 0::numeric)) AS amount
+   FROM acq.fund fund
+   LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund
+  GROUP BY fund.id;
+
+CREATE OR REPLACE VIEW acq.fund_encumbrance_total AS
+SELECT fund.id AS fund, sum(COALESCE(fund_debit.amount, 0::numeric)) AS amount FROM acq.fund fund
+   LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund WHERE fund_debit.encumbrance GROUP BY fund.id;
+
+CREATE OR REPLACE VIEW acq.fund_spent_total AS
+SELECT fund.id AS fund, sum(COALESCE(fund_debit.amount, 0::numeric)) AS amount FROM acq.fund fund
+   LEFT JOIN acq.fund_debit fund_debit ON fund.id = fund_debit.fund WHERE NOT fund_debit.encumbrance GROUP BY fund.id;
+
+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);
+
+
+COMMIT;