Stamped upgrade script for ACQ fund view repairs
authorBill Erickson <berick@esilibrary.com>
Thu, 22 Sep 2011 15:10:09 +0000 (11:10 -0400)
committerBill Erickson <berick@esilibrary.com>
Thu, 22 Sep 2011 15:23:29 +0000 (11:23 -0400)
At the heart of this change is the need to force acq.fund_debit_total to
return exactly 1 row per fund, instead of 1 per fund + encumbrance
value.  However, such a change required rearranging a number of
dependent views.

Also added acq.fund_spent_balance to the set of views that needs
dropping and re-building.

Minor SQL format change to match surrounding code in schema file

See also https://bugs.launchpad.net/evergreen/+bug/800477

Signed-off-by: Bill Erickson <berick@esilibrary.com>
Open-ILS/src/sql/Pg/002.schema.config.sql
Open-ILS/src/sql/Pg/200.schema.acq.sql
Open-ILS/src/sql/Pg/upgrade/0628.schema.acq_fund_view_repairs.sql [new file with mode: 0644]
Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477 [deleted file]

index 71a6fa6..bc501a3 100644 (file)
@@ -57,7 +57,7 @@ CREATE TABLE config.upgrade_log (
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0624'); -- miker/tsbere
+INSERT INTO config.upgrade_log (version) VALUES ('0628'); -- jamesrf/berick
 
 CREATE TABLE config.bib_source (
        id              SERIAL  PRIMARY KEY,
index 9f8dbd3..92cb0bf 100644 (file)
@@ -2459,33 +2459,33 @@ 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,
-           SUM(COALESCE(fund_debit.amount, 0::numeric)) AS amount
+    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
+        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
+    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;
+        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
+    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
+        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);
+    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,
diff --git a/Open-ILS/src/sql/Pg/upgrade/0628.schema.acq_fund_view_repairs.sql b/Open-ILS/src/sql/Pg/upgrade/0628.schema.acq_fund_view_repairs.sql
new file mode 100644 (file)
index 0000000..9138d7c
--- /dev/null
@@ -0,0 +1,52 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0628');
+
+-- acq.fund_combined_balance and acq.fund_spent_balance are unchanged,
+-- however we need to drop them 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_spent_balance;
+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);
+
+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;
diff --git a/Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477 b/Open-ILS/src/sql/Pg/upgrade/xxxx.schema.acq_lp800477
deleted file mode 100644 (file)
index dc21cd0..0000000
+++ /dev/null
@@ -1,34 +0,0 @@
-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;