[open-ils-commits] r15451 - in trunk/Open-ILS: examples src/sql/Pg src/sql/Pg/upgrade (scottmk)
svn at svn.open-ils.org
svn at svn.open-ils.org
Thu Feb 4 23:25:08 EST 2010
Author: scottmk
Date: 2010-02-04 23:25:05 -0500 (Thu, 04 Feb 2010)
New Revision: 15451
Added:
trunk/Open-ILS/src/sql/Pg/upgrade/0151.schema.acq.spending-limits.sql
Modified:
trunk/Open-ILS/examples/fm_IDL.xml
trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql
trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
Log:
1. Add two new columns to actor.org_unit: spend_warning_percent and
spend_limit_percent. These define, by org unit, spending levels
that should trigger either a warning or a firm limit for a fund.
2. Added corresponding columns to the auditor.actor_org_unit_history table.
3. In order to make the above work: raarranged way we create the
actor.org_unit table so that we define it with the fiscal_calendar
column and add the associated foreign key constraint later.
4. Add a fiscal_calendar column to the auditor.actor_org_unit_history
table (correcting an oversight on a previous commit).
5. Created two new functions to look up the default spending levels
for a given org unit. Where the spending level is undefined, the
functions look for a spending level defined for a parent org unit,
ultimately defaulting if necessary to a hard-coded value.
M Open-ILS/src/sql/Pg/005.schema.actors.sql
M Open-ILS/src/sql/Pg/999.functions.global.sql
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/0151.schema.acq.spending-limits.sql
M Open-ILS/examples/fm_IDL.xml
Modified: trunk/Open-ILS/examples/fm_IDL.xml
===================================================================
--- trunk/Open-ILS/examples/fm_IDL.xml 2010-02-04 21:13:30 UTC (rev 15450)
+++ trunk/Open-ILS/examples/fm_IDL.xml 2010-02-05 04:25:05 UTC (rev 15451)
@@ -3154,6 +3154,8 @@
<field reporter:label="Phone Number" name="phone" reporter:datatype="text"/>
<field reporter:label="OPAC Visible" name="opac_visible" reporter:datatype="bool"/>
<field reporter:label="Fiscal Calendar" name="fiscal_calendar" reporter:datatype="link"/>
+ <field reporter:label="Spend Warning Percent" name="spend_warning_percent" reporter:datatype="int"/>
+ <field reporter:label="Spend Limit Percent" name="spend_limit_percent" reporter:datatype="int"/>
<field reporter:label="Users" name="users" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Closed Dates" name="closed_dates" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Circulations" name="circulations" oils_persist:virtual="true" reporter:datatype="link"/>
Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2010-02-04 21:13:30 UTC (rev 15450)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2010-02-05 04:25:05 UTC (rev 15451)
@@ -51,7 +51,7 @@
install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-INSERT INTO config.upgrade_log (version) VALUES ('0150'); -- dbs
+INSERT INTO config.upgrade_log (version) VALUES ('0151'); -- Scott McKellar
CREATE TABLE config.bib_source (
id SERIAL PRIMARY KEY,
Modified: trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql 2010-02-04 21:13:30 UTC (rev 15450)
+++ trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql 2010-02-05 04:25:05 UTC (rev 15451)
@@ -339,7 +339,12 @@
name TEXT NOT NULL UNIQUE,
email TEXT,
phone TEXT,
- opac_visible BOOL NOT NULL DEFAULT TRUE
+ opac_visible BOOL NOT NULL DEFAULT TRUE,
+ fiscal_calendar INT NOT NULL DEFAULT 1, -- foreign key constraint to be added later
+ spend_warning_percent INT CONSTRAINT spend_warning_percent_limit
+ CHECK( spend_warning_percent <= 100 ),
+ spend_limit_percent INT CONSTRAINT spend_limit_percent_limit
+ CHECK( spend_limit_percent <= 100 )
);
CREATE INDEX actor_org_unit_parent_ou_idx ON actor.org_unit (parent_ou);
CREATE INDEX actor_org_unit_ou_type_idx ON actor.org_unit (ou_type);
Modified: trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql 2010-02-04 21:13:30 UTC (rev 15450)
+++ trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql 2010-02-05 04:25:05 UTC (rev 15451)
@@ -623,11 +623,9 @@
'Default'
);
-ALTER TABLE actor.org_unit
-ADD COLUMN fiscal_calendar INT NOT NULL
- REFERENCES acq.fiscal_calendar( id )
- DEFERRABLE INITIALLY DEFERRED
- DEFAULT 1;
+ALTER TABLE actor.org_unit ADD FOREIGN KEY
+ (fiscal_calendar) REFERENCES acq.fiscal_calendar( id )
+ DEFERRABLE INITIALLY DEFERRED;
CREATE TABLE acq.fiscal_year (
id SERIAL PRIMARY KEY,
Modified: trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/999.functions.global.sql 2010-02-04 21:13:30 UTC (rev 15450)
+++ trunk/Open-ILS/src/sql/Pg/999.functions.global.sql 2010-02-05 04:25:05 UTC (rev 15451)
@@ -1113,3 +1113,87 @@
CREATE TRIGGER aaa_indexing_ingest_or_delete AFTER INSERT OR UPDATE ON biblio.record_entry FOR EACH ROW EXECUTE PROCEDURE biblio.indexing_ingest_or_delete ();
CREATE TRIGGER bbb_simple_rec_trigger AFTER INSERT OR UPDATE ON biblio.record_entry FOR EACH ROW EXECUTE PROCEDURE reporter.simple_rec_trigger ();
+CREATE OR REPLACE FUNCTION acq.default_spend_limit( org_unit_id IN INT )
+RETURNS INTEGER AS $$
+DECLARE
+ org INT;
+ key_id INT;
+ percent INT;
+ parent INT;
+BEGIN
+ org := org_unit_id;
+ WHILE percent IS NULL LOOP
+ SELECT
+ id,
+ spend_limit_percent,
+ parent_ou
+ INTO
+ key_id,
+ percent,
+ parent
+ FROM
+ actor.org_unit
+ WHERE
+ id = org;
+ --
+ IF key_id IS NULL THEN
+ RAISE EXCEPTION 'Org_unit id % is not valid', org_unit_id;
+ END IF;
+ --
+ IF parent IS NULL THEN
+ EXIT;
+ ELSE
+ org := parent;
+ END IF;
+ END LOOP;
+ --
+ IF percent IS NULL THEN
+ RETURN 0; -- Last-ditch default
+ ELSE
+ RETURN percent;
+ END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION acq.default_warning_limit( org_unit_id IN INT )
+RETURNS INTEGER AS $$
+DECLARE
+ org INT;
+ key_id INT;
+ percent INT;
+ parent INT;
+BEGIN
+ org := org_unit_id;
+ WHILE percent IS NULL LOOP
+ SELECT
+ id,
+ spend_warning_percent,
+ parent_ou
+ INTO
+ key_id,
+ percent,
+ parent
+ FROM
+ actor.org_unit
+ WHERE
+ id = org;
+ --
+ IF key_id IS NULL THEN
+ RAISE EXCEPTION 'Org_unit id % is not valid', org_unit_id;
+ END IF;
+ --
+ IF parent IS NULL THEN
+ EXIT;
+ ELSE
+ org := parent;
+ END IF;
+ END LOOP;
+ --
+ IF percent IS NULL THEN
+ RETURN 10; -- Last-ditch default
+ ELSE
+ RETURN percent;
+ END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
Added: trunk/Open-ILS/src/sql/Pg/upgrade/0151.schema.acq.spending-limits.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0151.schema.acq.spending-limits.sql (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0151.schema.acq.spending-limits.sql 2010-02-05 04:25:05 UTC (rev 15451)
@@ -0,0 +1,113 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0151'); -- Scott McKellar
+
+ALTER TABLE actor.org_unit
+ ADD COLUMN spend_warning_percent INT
+ CONSTRAINT spend_warning_percent_limit
+ CHECK( spend_warning_percent <= 100 );
+
+ALTER TABLE actor.org_unit
+ ADD COLUMN spend_limit_percent INT
+ CONSTRAINT spend_limit_percent_limit
+ CHECK( spend_limit_percent <= 100 );
+
+CREATE OR REPLACE FUNCTION acq.default_spend_limit( org_unit_id IN INT )
+RETURNS INTEGER AS $$
+DECLARE
+ org INT;
+ key_id INT;
+ percent INT;
+ parent INT;
+BEGIN
+ org := org_unit_id;
+ WHILE percent IS NULL LOOP
+ SELECT
+ id,
+ spend_limit_percent,
+ parent_ou
+ INTO
+ key_id,
+ percent,
+ parent
+ FROM
+ actor.org_unit
+ WHERE
+ id = org;
+ --
+ IF key_id IS NULL THEN
+ RAISE EXCEPTION 'Org_unit id % is not valid', org_unit_id;
+ END IF;
+ --
+ IF parent IS NULL THEN
+ EXIT;
+ ELSE
+ org := parent;
+ END IF;
+ END LOOP;
+ --
+ IF percent IS NULL THEN
+ RETURN 0; -- Last-ditch default
+ ELSE
+ RETURN percent;
+ END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
+CREATE OR REPLACE FUNCTION acq.default_warning_limit( org_unit_id IN INT )
+RETURNS INTEGER AS $$
+DECLARE
+ org INT;
+ key_id INT;
+ percent INT;
+ parent INT;
+BEGIN
+ org := org_unit_id;
+ WHILE percent IS NULL LOOP
+ SELECT
+ id,
+ spend_warning_percent,
+ parent_ou
+ INTO
+ key_id,
+ percent,
+ parent
+ FROM
+ actor.org_unit
+ WHERE
+ id = org;
+ --
+ IF key_id IS NULL THEN
+ RAISE EXCEPTION 'Org_unit id % is not valid', org_unit_id;
+ END IF;
+ --
+ IF parent IS NULL THEN
+ EXIT;
+ ELSE
+ org := parent;
+ END IF;
+ END LOOP;
+ --
+ IF percent IS NULL THEN
+ RETURN 10; -- Last-ditch default
+ ELSE
+ RETURN percent;
+ END IF;
+END;
+$$ LANGUAGE 'plpgsql';
+
+COMMIT;
+
+-- If there is no auditor schema, the following ALTERs
+-- will fail, and that's okay. The first one will fail
+-- if the fiscal_calendar column is already present.
+
+ALTER TABLE auditor.actor_org_unit_history
+ ADD COLUMN fiscal_calendar INT;
+
+ALTER TABLE auditor.actor_org_unit_history
+ ADD COLUMN spend_warning_percent INT;
+
+ALTER TABLE auditor.actor_org_unit_history
+ ADD COLUMN spend_limit_percent INT;
+
More information about the open-ils-commits
mailing list