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

svn at svn.open-ils.org svn at svn.open-ils.org
Wed May 26 11:08:35 EDT 2010


Author: miker
Date: 2010-05-26 11:08:33 -0400 (Wed, 26 May 2010)
New Revision: 16505

Added:
   trunk/Open-ILS/src/sql/Pg/upgrade/0227.schema.address_schema_drift.sql
Modified:
   trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
   trunk/Open-ILS/src/sql/Pg/012.schema.vandelay.sql
   trunk/Open-ILS/src/sql/Pg/030.schema.metabib.sql
   trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
Log:
after nearly 280 schema updates, we had a little drift. this addresses upgrade vs stock substantive differences

Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-05-26 13:27:29 UTC (rev 16504)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-05-26 15:08:33 UTC (rev 16505)
@@ -65,7 +65,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0276'); -- dbs
+INSERT INTO config.upgrade_log (version) VALUES ('0277'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/012.schema.vandelay.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/012.schema.vandelay.sql	2010-05-26 13:27:29 UTC (rev 16504)
+++ trunk/Open-ILS/src/sql/Pg/012.schema.vandelay.sql	2010-05-26 15:08:33 UTC (rev 16505)
@@ -925,6 +925,8 @@
     
     END IF;
 
+    RETURN;
+
 END;
 $$ LANGUAGE PLPGSQL;
 

Modified: trunk/Open-ILS/src/sql/Pg/030.schema.metabib.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/030.schema.metabib.sql	2010-05-26 13:27:29 UTC (rev 16504)
+++ trunk/Open-ILS/src/sql/Pg/030.schema.metabib.sql	2010-05-26 15:08:33 UTC (rev 16505)
@@ -38,7 +38,7 @@
 );
 CREATE TRIGGER metabib_identifier_field_entry_fti_trigger
 	BEFORE UPDATE OR INSERT ON metabib.identifier_field_entry
-	FOR EACH ROW EXECUTE PROCEDURE oils_tsearch2('keyword');
+	FOR EACH ROW EXECUTE PROCEDURE oils_tsearch2('identifier');
 
 CREATE INDEX metabib_identifier_field_entry_index_vector_idx ON metabib.identifier_field_entry USING GIST (index_vector);
 CREATE INDEX metabib_identifier_field_entry_value_idx ON metabib.identifier_field_entry (SUBSTRING(value,1,1024)) WHERE index_vector = ''::TSVECTOR;

Modified: trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2010-05-26 13:27:29 UTC (rev 16504)
+++ trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2010-05-26 15:08:33 UTC (rev 16505)
@@ -100,7 +100,7 @@
 	state		TEXT	NOT NULL,
 	country		TEXT	NOT NULL,
 	post_code	TEXT	NOT NULL,
-	fax_phone	TEXT	NOT NULL
+	fax_phone	TEXT
 );
 
 CREATE TABLE acq.provider_contact (
@@ -754,7 +754,8 @@
 
 CREATE TABLE acq.edi_account (      -- similar tables can extend remote_account for other parts of EG
     provider    INT     NOT NULL REFERENCES acq.provider          (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
-    in_dir      TEXT    -- incoming messages dir (probably different than config.remote_account.path, the outgoing dir)
+    in_dir      TEXT,   -- incoming messages dir (probably different than config.remote_account.path, the outgoing dir)
+    vendcode    TEXT
 ) INHERITS (config.remote_account);
 
 -- We need a UNIQUE constraint here also, to support the FK from acq.provider.edi_default
@@ -786,7 +787,7 @@
     error            TEXT,
     purchase_order   INT             REFERENCES acq.purchase_order
                                      DEFERRABLE INITIALLY DEFERRED,
-	message_type     TEXT            NOT NULL CONSTRAINT valid_type CHECK
+	message_type     TEXT            NOT NULL CONSTRAINT valid_message_type CHECK
 	                                 ( message_type IN (
 									     'ORDERS',
 									     'ORDRSP',

Added: trunk/Open-ILS/src/sql/Pg/upgrade/0227.schema.address_schema_drift.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0227.schema.address_schema_drift.sql	                        (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0227.schema.address_schema_drift.sql	2010-05-26 15:08:33 UTC (rev 16505)
@@ -0,0 +1,222 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0227'); -- miker
+
+-- Use oils_xpath_table instead of pgxml's xpath_table
+CREATE OR REPLACE FUNCTION acq.extract_holding_attr_table (lineitem int, tag text) RETURNS SETOF acq.flat_lineitem_holding_subfield AS $$
+DECLARE
+    counter INT;
+    lida    acq.flat_lineitem_holding_subfield%ROWTYPE;
+BEGIN
+
+    SELECT  COUNT(*) INTO counter
+      FROM  oils_xpath_table(
+                'id',
+                'marc',
+                'acq.lineitem',
+                '//*[@tag="' || tag || '"]',
+                'id=' || lineitem
+            ) as t(i int,c text);
+
+    FOR i IN 1 .. counter LOOP
+        FOR lida IN
+            SELECT  *
+              FROM  (   SELECT  id,i,t,v
+                          FROM  oils_xpath_table(
+                                    'id',
+                                    'marc',
+                                    'acq.lineitem',
+                                    '//*[@tag="' || tag || '"][position()=' || i || ']/*/@code|' ||
+                                        '//*[@tag="' || tag || '"][position()=' || i || ']/*[@code]',
+                                    'id=' || lineitem
+                                ) as t(id int,t text,v text)
+                    )x
+        LOOP
+            RETURN NEXT lida;
+        END LOOP;
+    END LOOP;
+
+    RETURN;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Use the identifier search class tsconfig
+DROP TRIGGER metabib_identifier_field_entry_fti_trigger ON identifier_field_entry;
+CREATE TRIGGER metabib_identifier_field_entry_fti_trigger
+    BEFORE INSERT OR UPDATE ON identifier_field_entry
+    FOR EACH ROW
+    EXECUTE PROCEDURE public.oils_tsearch2('identifier');
+
+-- Return the correct fail_part when the item can't be found
+CREATE OR REPLACE FUNCTION action.item_user_circ_test( circ_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS SETOF action.matrix_test_result AS $func$
+DECLARE
+    user_object        actor.usr%ROWTYPE;
+    standing_penalty    config.standing_penalty%ROWTYPE;
+    item_object        asset.copy%ROWTYPE;
+    item_status_object    config.copy_status%ROWTYPE;
+    item_location_object    asset.copy_location%ROWTYPE;
+    result            action.matrix_test_result;
+    circ_test        config.circ_matrix_matchpoint%ROWTYPE;
+    out_by_circ_mod        config.circ_matrix_circ_mod_test%ROWTYPE;
+    circ_mod_map        config.circ_matrix_circ_mod_test_map%ROWTYPE;
+    hold_ratio          action.hold_stats%ROWTYPE;
+    penalty_type         TEXT;
+    tmp_grp         INT;
+    items_out        INT;
+    context_org_list        INT[];
+    done            BOOL := FALSE;
+BEGIN
+    result.success := TRUE;
+
+    -- Fail if the user is BARRED
+    SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+
+    -- Fail if we couldn't find the user 
+    IF user_object.id IS NULL THEN
+        result.fail_part := 'no_user';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+    -- Fail if we couldn't find the item 
+    IF item_object.id IS NULL THEN
+        result.fail_part := 'no_item';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+        RETURN;
+    END IF;
+
+    SELECT INTO circ_test * FROM action.find_circ_matrix_matchpoint(circ_ou, match_item, match_user, renewal);
+    result.matchpoint := circ_test.id;
+
+    -- Fail if we couldn't find a matchpoint
+    IF result.matchpoint IS NULL THEN
+        result.fail_part := 'no_matchpoint';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    IF user_object.barred IS TRUE THEN
+        result.fail_part := 'actor.usr.barred';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate
+    IF item_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item isn't in a circulateable status on a non-renewal
+    IF NOT renewal AND item_object.status NOT IN ( 0, 7, 8 ) THEN
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    ELSIF renewal AND item_object.status <> 1 THEN
+        result.fail_part := 'asset.copy.status';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the item can't circulate because of the shelving location
+    SELECT INTO item_location_object * FROM asset.copy_location WHERE id = item_object.location;
+    IF item_location_object.circulate IS FALSE THEN
+        result.fail_part := 'asset.copy_location.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( circ_test.org_unit );
+
+    -- Fail if the test is set to hard non-circulating
+    IF circ_test.circulate IS FALSE THEN
+        result.fail_part := 'config.circ_matrix_test.circulate';
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END IF;
+
+    -- Fail if the total copy-hold ratio is too low
+    IF circ_test.total_copy_hold_ratio IS NOT NULL THEN
+        SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item);
+        IF hold_ratio.total_copy_ratio IS NOT NULL AND hold_ratio.total_copy_ratio < circ_test.total_copy_hold_ratio THEN
+            result.fail_part := 'config.circ_matrix_test.total_copy_hold_ratio';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    -- Fail if the available copy-hold ratio is too low
+    IF circ_test.available_copy_hold_ratio IS NOT NULL THEN
+        SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item);
+        IF hold_ratio.available_copy_ratio IS NOT NULL AND hold_ratio.available_copy_ratio < circ_test.available_copy_hold_ratio THEN
+            result.fail_part := 'config.circ_matrix_test.available_copy_hold_ratio';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END IF;
+
+    IF renewal THEN
+        penalty_type = '%RENEW%';
+    ELSE
+        penalty_type = '%CIRC%';
+    END IF;
+
+    FOR standing_penalty IN
+        SELECT  DISTINCT csp.*
+          FROM  actor.usr_standing_penalty usp
+                JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty)
+          WHERE usr = match_user
+                AND usp.org_unit IN ( SELECT * FROM explode_array(context_org_list) )
+                AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+                AND csp.block_list LIKE penalty_type LOOP
+
+        result.fail_part := standing_penalty.name;
+        result.success := FALSE;
+        done := TRUE;
+        RETURN NEXT result;
+    END LOOP;
+
+    -- Fail if the user has too many items with specific circ_modifiers checked out
+    FOR out_by_circ_mod IN SELECT * FROM config.circ_matrix_circ_mod_test WHERE matchpoint = circ_test.id LOOP
+        SELECT  INTO items_out COUNT(*)
+          FROM  action.circulation circ
+            JOIN asset.copy cp ON (cp.id = circ.target_copy)
+          WHERE circ.usr = match_user
+               AND circ.circ_lib IN ( SELECT * FROM explode_array(context_org_list) )
+            AND circ.checkin_time IS NULL
+            AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL)
+            AND cp.circ_modifier IN (SELECT circ_mod FROM config.circ_matrix_circ_mod_test_map WHERE circ_mod_test = out_by_circ_mod.id);
+        IF items_out >= out_by_circ_mod.items_out THEN
+            result.fail_part := 'config.circ_matrix_circ_mod_test';
+            result.success := FALSE;
+            done := TRUE;
+            RETURN NEXT result;
+        END IF;
+    END LOOP;
+
+    -- If we passed everything, return the successful matchpoint id
+    IF NOT done THEN
+        RETURN NEXT result;
+    END IF;
+
+    RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
+COMMIT;



More information about the open-ils-commits mailing list