[open-ils-commits] r14670 - in trunk/Open-ILS/src/sql/Pg: . upgrade (scottmk)

svn at svn.open-ils.org svn at svn.open-ils.org
Thu Oct 29 09:25:01 EDT 2009


Author: scottmk
Date: 2009-10-29 09:25:00 -0400 (Thu, 29 Oct 2009)
New Revision: 14670

Added:
   trunk/Open-ILS/src/sql/Pg/upgrade/0061.schema.acqfa_no_percent.sql
Modified:
   trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
   trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
Log:
Remove the percent column from acq.fund_allocation.  Make the
amount column NOT NULL.

Remove references to the percent column from the views
acq.fund_allocation_total and acq.funding_source_allocation_total.

M    Open-ILS/src/sql/Pg/200.schema.acq.sql
M    Open-ILS/src/sql/Pg/002.schema.config.sql
A    Open-ILS/src/sql/Pg/upgrade/0061.schema.acqfa_no_percent.sql


Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2009-10-29 06:59:14 UTC (rev 14669)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2009-10-29 13:25:00 UTC (rev 14670)
@@ -51,7 +51,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0060'); -- atz
+INSERT INTO config.upgrade_log (version) VALUES ('0061'); -- Scott McKellar
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2009-10-29 06:59:14 UTC (rev 14669)
+++ trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2009-10-29 13:25:00 UTC (rev 14670)
@@ -130,8 +130,7 @@
     id          SERIAL  PRIMARY KEY,
     funding_source        INT     NOT NULL REFERENCES acq.funding_source (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
     fund        INT     NOT NULL REFERENCES acq.fund (id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
-    amount      NUMERIC,
-    percent     NUMERIC CHECK (percent IS NULL OR percent BETWEEN 0.0 AND 100.0),
+    amount      NUMERIC NOT NULL,
     allocator   INT NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
     note        TEXT,
 	create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
@@ -693,21 +692,9 @@
 
 CREATE OR REPLACE VIEW acq.funding_source_allocation_total AS
     SELECT  funding_source,
-            SUM(amount)::NUMERIC(100,2) AS amount
-      FROM (
-            SELECT  funding_source,
-                    SUM(a.amount)::NUMERIC(100,2) AS amount
-              FROM  acq.fund_allocation a
-              WHERE a.percent IS NULL
-              GROUP BY 1
-                            UNION ALL
-            SELECT  funding_source,
-                    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;
+            SUM(a.amount)::NUMERIC(100,2) AS amount
+    FROM  acq.fund_allocation a
+    GROUP BY 1;
 
 CREATE OR REPLACE VIEW acq.funding_source_balance AS
     SELECT  COALESCE(c.funding_source, a.funding_source) AS funding_source,
@@ -718,25 +705,11 @@
 
 CREATE OR REPLACE VIEW acq.fund_allocation_total AS
     SELECT  fund,
-            SUM(amount)::NUMERIC(100,2) AS amount
-      FROM (
-            SELECT  fund,
-                    SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
-              FROM  acq.fund_allocation a
-                    JOIN acq.fund f ON (a.fund = f.id)
-                    JOIN acq.funding_source s ON (a.funding_source = s.id)
-              WHERE a.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) * acq.exchange_ratio(s.currency_type, f.currency_type) * (a.percent/100.0) )::NUMERIC(100,2) AS amount
-              FROM  acq.fund_allocation a
-                    JOIN acq.fund f ON (a.fund = f.id)
-                    JOIN acq.funding_source s ON (a.funding_source = s.id)
-              WHERE a.amount IS NULL
-              GROUP BY 1
-        ) x
-      GROUP BY 1;
+            SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
+    FROM acq.fund_allocation a
+         JOIN acq.fund f ON (a.fund = f.id)
+         JOIN acq.funding_source s ON (a.funding_source = s.id)
+    GROUP BY 1;
 
 CREATE OR REPLACE VIEW acq.fund_debit_total AS
     SELECT  id AS fund,

Added: trunk/Open-ILS/src/sql/Pg/upgrade/0061.schema.acqfa_no_percent.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0061.schema.acqfa_no_percent.sql	                        (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0061.schema.acqfa_no_percent.sql	2009-10-29 13:25:00 UTC (rev 14670)
@@ -0,0 +1,37 @@
+BEGIN;
+
+-- Script to eliminate acq.fund_allocation.percent, which has been moved to the
+-- acq.fund_allocation_percent table.
+
+INSERT INTO config.upgrade_log (version) VALUES ('0061');  -- Scott McKellar
+
+-- If the following step fails, it's probably because there are still some non-null percent values in
+-- acq.fund_allocation.  They should have all been converted to amounts, and then set to null, by a
+-- previous upgrade script, 0049.schema.acq_funding_allocation_percent.sql.  If there are any non-null
+-- values, then either that script didn't run, or it didn't work, or some non-null values slipped in
+-- afterwards.
+
+-- To convert any remaining percents to amounts: create, run, and then drop the temporary stored
+-- procedure acq.fund_alloc_percent_val as defined in 0049.schema.acq_funding_allocation_percent.sql.
+
+ALTER TABLE acq.fund_allocation
+ALTER COLUMN amount SET NOT NULL;
+
+CREATE OR REPLACE VIEW acq.fund_allocation_total AS
+    SELECT  fund,
+            SUM(a.amount * acq.exchange_ratio(s.currency_type, f.currency_type))::NUMERIC(100,2) AS amount
+    FROM acq.fund_allocation a
+         JOIN acq.fund f ON (a.fund = f.id)
+         JOIN acq.funding_source s ON (a.funding_source = s.id)
+    GROUP BY 1;
+
+CREATE OR REPLACE VIEW acq.funding_source_allocation_total AS
+    SELECT  funding_source,
+            SUM(a.amount)::NUMERIC(100,2) AS amount
+    FROM  acq.fund_allocation a
+    GROUP BY 1;
+
+ALTER TABLE acq.fund_allocation
+DROP COLUMN percent;
+
+COMMIT;
\ No newline at end of file



More information about the open-ils-commits mailing list