Forward-port 3.0.2 upgrade script
authorDan Wells <dbw2@calvin.edu>
Fri, 1 Dec 2017 21:01:20 +0000 (16:01 -0500)
committerDan Wells <dbw2@calvin.edu>
Fri, 1 Dec 2017 21:01:20 +0000 (16:01 -0500)
Signed-off-by: Dan Wells <dbw2@calvin.edu>
Open-ILS/src/sql/Pg/version-upgrade/3.0.1-3.0.2-upgrade-db.sql [new file with mode: 0644]

diff --git a/Open-ILS/src/sql/Pg/version-upgrade/3.0.1-3.0.2-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/3.0.1-3.0.2-upgrade-db.sql
new file mode 100644 (file)
index 0000000..7c30ed7
--- /dev/null
@@ -0,0 +1,474 @@
+--Upgrade Script for 3.0.1 to 3.0.2
+\set eg_version '''3.0.2'''
+BEGIN;
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('3.0.2', :eg_version);
+
+SELECT evergreen.upgrade_deps_block_check('1079', :eg_version); -- rhamby/cesardv/gmcharlt
+
+CREATE OR REPLACE FUNCTION asset.merge_record_assets( target_record BIGINT, source_record BIGINT ) RETURNS INT AS $func$
+DECLARE
+    moved_objects INT := 0;
+    source_cn     asset.call_number%ROWTYPE;
+    target_cn     asset.call_number%ROWTYPE;
+    metarec       metabib.metarecord%ROWTYPE;
+    hold          action.hold_request%ROWTYPE;
+    ser_rec       serial.record_entry%ROWTYPE;
+    ser_sub       serial.subscription%ROWTYPE;
+    acq_lineitem  acq.lineitem%ROWTYPE;
+    acq_request   acq.user_request%ROWTYPE;
+    booking       booking.resource_type%ROWTYPE;
+    source_part   biblio.monograph_part%ROWTYPE;
+    target_part   biblio.monograph_part%ROWTYPE;
+    multi_home    biblio.peer_bib_copy_map%ROWTYPE;
+    uri_count     INT := 0;
+    counter       INT := 0;
+    uri_datafield TEXT;
+    uri_text      TEXT := '';
+BEGIN
+
+    -- move any 856 entries on records that have at least one MARC-mapped URI entry
+    SELECT  INTO uri_count COUNT(*)
+      FROM  asset.uri_call_number_map m
+            JOIN asset.call_number cn ON (m.call_number = cn.id)
+      WHERE cn.record = source_record;
+
+    IF uri_count > 0 THEN
+        
+        -- This returns more nodes than you might expect:
+        -- 7 instead of 1 for an 856 with $u $y $9
+        SELECT  COUNT(*) INTO counter
+          FROM  oils_xpath_table(
+                    'id',
+                    'marc',
+                    'biblio.record_entry',
+                    '//*[@tag="856"]',
+                    'id=' || source_record
+                ) as t(i int,c text);
+    
+        FOR i IN 1 .. counter LOOP
+            SELECT  '<datafield xmlns="http://www.loc.gov/MARC21/slim"' || 
+                       ' tag="856"' ||
+                       ' ind1="' || FIRST(ind1) || '"'  ||
+                       ' ind2="' || FIRST(ind2) || '">' ||
+                        STRING_AGG(
+                            '<subfield code="' || subfield || '">' ||
+                            regexp_replace(
+                                regexp_replace(
+                                    regexp_replace(data,'&','&amp;','g'),
+                                    '>', '&gt;', 'g'
+                                ),
+                                '<', '&lt;', 'g'
+                            ) || '</subfield>', ''
+                        ) || '</datafield>' INTO uri_datafield
+              FROM  oils_xpath_table(
+                        'id',
+                        'marc',
+                        'biblio.record_entry',
+                        '//*[@tag="856"][position()=' || i || ']/@ind1|' ||
+                        '//*[@tag="856"][position()=' || i || ']/@ind2|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*/@code|' ||
+                        '//*[@tag="856"][position()=' || i || ']/*[@code]',
+                        'id=' || source_record
+                    ) as t(id int,ind1 text, ind2 text,subfield text,data text);
+
+            -- As most of the results will be NULL, protect against NULLifying
+            -- the valid content that we do generate
+            uri_text := uri_text || COALESCE(uri_datafield, '');
+        END LOOP;
+
+        IF uri_text <> '' THEN
+            UPDATE  biblio.record_entry
+              SET   marc = regexp_replace(marc,'(</[^>]*record>)', uri_text || E'\\1')
+              WHERE id = target_record;
+        END IF;
+
+    END IF;
+
+       -- Find and move metarecords to the target record
+       SELECT  INTO metarec *
+         FROM  metabib.metarecord
+         WHERE master_record = source_record;
+
+       IF FOUND THEN
+               UPDATE  metabib.metarecord
+                 SET   master_record = target_record,
+                       mods = NULL
+                 WHERE id = metarec.id;
+
+               moved_objects := moved_objects + 1;
+       END IF;
+
+       -- Find call numbers attached to the source ...
+       FOR source_cn IN SELECT * FROM asset.call_number WHERE record = source_record LOOP
+
+               SELECT  INTO target_cn *
+                 FROM  asset.call_number
+                 WHERE label = source_cn.label
+            AND prefix = source_cn.prefix
+            AND suffix = source_cn.suffix
+                       AND owning_lib = source_cn.owning_lib
+                       AND record = target_record
+                       AND NOT deleted;
+
+               -- ... and if there's a conflicting one on the target ...
+               IF FOUND THEN
+
+                       -- ... move the copies to that, and ...
+                       UPDATE  asset.copy
+                         SET   call_number = target_cn.id
+                         WHERE call_number = source_cn.id;
+
+                       -- ... move V holds to the move-target call number
+                       FOR hold IN SELECT * FROM action.hold_request WHERE target = source_cn.id AND hold_type = 'V' LOOP
+               
+                               UPDATE  action.hold_request
+                                 SET   target = target_cn.id
+                                 WHERE id = hold.id;
+               
+                               moved_objects := moved_objects + 1;
+                       END LOOP;
+        
+            UPDATE asset.call_number SET deleted = TRUE WHERE id = source_cn.id;
+
+               -- ... if not ...
+               ELSE
+                       -- ... just move the call number to the target record
+                       UPDATE  asset.call_number
+                         SET   record = target_record
+                         WHERE id = source_cn.id;
+               END IF;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find T holds targeting the source record ...
+       FOR hold IN SELECT * FROM action.hold_request WHERE target = source_record AND hold_type = 'T' LOOP
+
+               -- ... and move them to the target record
+               UPDATE  action.hold_request
+                 SET   target = target_record
+                 WHERE id = hold.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find serial records targeting the source record ...
+       FOR ser_rec IN SELECT * FROM serial.record_entry WHERE record = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  serial.record_entry
+                 SET   record = target_record
+                 WHERE id = ser_rec.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find serial subscriptions targeting the source record ...
+       FOR ser_sub IN SELECT * FROM serial.subscription WHERE record_entry = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  serial.subscription
+                 SET   record_entry = target_record
+                 WHERE id = ser_sub.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find booking resource types targeting the source record ...
+       FOR booking IN SELECT * FROM booking.resource_type WHERE record = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  booking.resource_type
+                 SET   record = target_record
+                 WHERE id = booking.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find acq lineitems targeting the source record ...
+       FOR acq_lineitem IN SELECT * FROM acq.lineitem WHERE eg_bib_id = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  acq.lineitem
+                 SET   eg_bib_id = target_record
+                 WHERE id = acq_lineitem.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find acq user purchase requests targeting the source record ...
+       FOR acq_request IN SELECT * FROM acq.user_request WHERE eg_bib = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  acq.user_request
+                 SET   eg_bib = target_record
+                 WHERE id = acq_request.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find parts attached to the source ...
+       FOR source_part IN SELECT * FROM biblio.monograph_part WHERE record = source_record LOOP
+
+               SELECT  INTO target_part *
+                 FROM  biblio.monograph_part
+                 WHERE label = source_part.label
+                       AND record = target_record;
+
+               -- ... and if there's a conflicting one on the target ...
+               IF FOUND THEN
+
+                       -- ... move the copy-part maps to that, and ...
+                       UPDATE  asset.copy_part_map
+                         SET   part = target_part.id
+                         WHERE part = source_part.id;
+
+                       -- ... move P holds to the move-target part
+                       FOR hold IN SELECT * FROM action.hold_request WHERE target = source_part.id AND hold_type = 'P' LOOP
+               
+                               UPDATE  action.hold_request
+                                 SET   target = target_part.id
+                                 WHERE id = hold.id;
+               
+                               moved_objects := moved_objects + 1;
+                       END LOOP;
+
+               -- ... if not ...
+               ELSE
+                       -- ... just move the part to the target record
+                       UPDATE  biblio.monograph_part
+                         SET   record = target_record
+                         WHERE id = source_part.id;
+               END IF;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- Find multi_home items attached to the source ...
+       FOR multi_home IN SELECT * FROM biblio.peer_bib_copy_map WHERE peer_record = source_record LOOP
+               -- ... and move them to the target record
+               UPDATE  biblio.peer_bib_copy_map
+                 SET   peer_record = target_record
+                 WHERE id = multi_home.id;
+
+               moved_objects := moved_objects + 1;
+       END LOOP;
+
+       -- And delete mappings where the item's home bib was merged with the peer bib
+       DELETE FROM biblio.peer_bib_copy_map WHERE peer_record = (
+               SELECT (SELECT record FROM asset.call_number WHERE id = call_number)
+               FROM asset.copy WHERE id = target_copy
+       );
+
+    -- Finally, "delete" the source record
+    DELETE FROM biblio.record_entry WHERE id = source_record;
+
+       -- That's all, folks!
+       RETURN moved_objects;
+END;
+$func$ LANGUAGE plpgsql;
+
+
+SELECT evergreen.upgrade_deps_block_check('1080', :eg_version); -- miker/jboyer/gmcharlt
+
+CREATE OR REPLACE FUNCTION asset.cache_copy_visibility () RETURNS TRIGGER as $func$
+DECLARE
+    ocn     asset.call_number%ROWTYPE;
+    ncn     asset.call_number%ROWTYPE;
+    cid     BIGINT;
+BEGIN
+
+    IF TG_TABLE_NAME = 'peer_bib_copy_map' THEN -- Only needs ON INSERT OR DELETE, so handle separately
+        IF TG_OP = 'INSERT' THEN
+            INSERT INTO asset.copy_vis_attr_cache (record, target_copy, vis_attr_vector) VALUES (
+                NEW.peer_record,
+                NEW.target_copy,
+                asset.calculate_copy_visibility_attribute_set(NEW.target_copy)
+            );
+
+            RETURN NEW;
+        ELSIF TG_OP = 'DELETE' THEN
+            DELETE FROM asset.copy_vis_attr_cache
+              WHERE record = OLD.peer_record AND target_copy = OLD.target_copy;
+
+            RETURN OLD;
+        END IF;
+    END IF;
+
+    IF TG_OP = 'INSERT' THEN -- Handles ON INSERT. ON UPDATE is below.
+        IF TG_TABLE_NAME IN ('copy', 'unit') THEN
+            SELECT * INTO ncn FROM asset.call_number cn WHERE id = NEW.call_number;
+            INSERT INTO asset.copy_vis_attr_cache (record, target_copy, vis_attr_vector) VALUES (
+                ncn.record,
+                NEW.id,
+                asset.calculate_copy_visibility_attribute_set(NEW.id)
+            );
+        ELSIF TG_TABLE_NAME = 'record_entry' THEN
+            NEW.vis_attr_vector := biblio.calculate_bib_visibility_attribute_set(NEW.id);
+        END IF;
+
+        RETURN NEW;
+    END IF;
+
+    -- handle items first, since with circulation activity
+    -- their statuses change frequently
+    IF TG_TABLE_NAME IN ('copy', 'unit') THEN -- This handles ON UPDATE OR DELETE. ON INSERT above
+
+        IF TG_OP = 'DELETE' THEN -- Shouldn't get here, normally
+            DELETE FROM asset.copy_vis_attr_cache WHERE target_copy = OLD.id;
+            RETURN OLD;
+        END IF;
+
+        SELECT * INTO ncn FROM asset.call_number cn WHERE id = NEW.call_number;
+
+        IF OLD.deleted <> NEW.deleted THEN
+            IF NEW.deleted THEN
+                DELETE FROM asset.copy_vis_attr_cache WHERE target_copy = OLD.id;
+            ELSE
+                INSERT INTO asset.copy_vis_attr_cache (record, target_copy, vis_attr_vector) VALUES (
+                    ncn.record,
+                    NEW.id,
+                    asset.calculate_copy_visibility_attribute_set(NEW.id)
+                );
+            END IF;
+
+            RETURN NEW;
+        ELSIF OLD.call_number  <> NEW.call_number THEN
+            SELECT * INTO ocn FROM asset.call_number cn WHERE id = OLD.call_number;
+
+            IF ncn.record <> ocn.record THEN
+                UPDATE  biblio.record_entry
+                  SET   vis_attr_vector = biblio.calculate_bib_visibility_attribute_set(ncn.record)
+                  WHERE id = ocn.record;
+
+                -- We have to use a record-specific WHERE clause
+                -- to avoid modifying the entries for peer-bib copies.
+                UPDATE  asset.copy_vis_attr_cache
+                  SET   target_copy = NEW.id,
+                        record = ncn.record
+                  WHERE target_copy = OLD.id
+                        AND record = ocn.record;
+            END IF;
+        END IF;
+
+        IF OLD.location     <> NEW.location OR
+           OLD.status       <> NEW.status OR
+           OLD.opac_visible <> NEW.opac_visible OR
+           OLD.circ_lib     <> NEW.circ_lib
+        THEN
+            -- Any of these could change visibility, but
+            -- we'll save some queries and not try to calculate
+            -- the change directly.  We want to update peer-bib
+            -- entries in this case, unlike above.
+            UPDATE  asset.copy_vis_attr_cache
+              SET   target_copy = NEW.id,
+                    vis_attr_vector = asset.calculate_copy_visibility_attribute_set(NEW.id)
+              WHERE target_copy = OLD.id;
+
+        END IF;
+
+    ELSIF TG_TABLE_NAME = 'call_number' THEN -- Only ON UPDATE. Copy handler will deal with ON INSERT OR DELETE.
+
+        IF OLD.record <> NEW.record THEN
+            IF NEW.label = '##URI##' THEN
+                UPDATE  biblio.record_entry
+                  SET   vis_attr_vector = biblio.calculate_bib_visibility_attribute_set(OLD.record)
+                  WHERE id = OLD.record;
+
+                UPDATE  biblio.record_entry
+                  SET   vis_attr_vector = biblio.calculate_bib_visibility_attribute_set(NEW.record)
+                  WHERE id = NEW.record;
+            END IF;
+
+            UPDATE  asset.copy_vis_attr_cache
+              SET   record = NEW.record,
+                    vis_attr_vector = asset.calculate_copy_visibility_attribute_set(target_copy)
+              WHERE target_copy IN (SELECT id FROM asset.copy WHERE call_number = NEW.id)
+                    AND record = OLD.record;
+
+        ELSIF OLD.owning_lib <> NEW.owning_lib THEN
+            UPDATE  asset.copy_vis_attr_cache
+              SET   vis_attr_vector = asset.calculate_copy_visibility_attribute_set(target_copy)
+              WHERE target_copy IN (SELECT id FROM asset.copy WHERE call_number = NEW.id)
+                    AND record = NEW.record;
+
+            IF NEW.label = '##URI##' THEN
+                UPDATE  biblio.record_entry
+                  SET   vis_attr_vector = biblio.calculate_bib_visibility_attribute_set(OLD.record)
+                  WHERE id = OLD.record;
+            END IF;
+        END IF;
+
+    ELSIF TG_TABLE_NAME = 'record_entry' THEN -- Only handles ON UPDATE OR DELETE
+
+        IF TG_OP = 'DELETE' THEN -- Shouldn't get here, normally
+            DELETE FROM asset.copy_vis_attr_cache WHERE record = OLD.id;
+            RETURN OLD;
+        ELSIF OLD.source <> NEW.source THEN
+            NEW.vis_attr_vector := biblio.calculate_bib_visibility_attribute_set(NEW.id);
+        END IF;
+
+    END IF;
+
+    RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+
+SELECT evergreen.upgrade_deps_block_check('1081', :eg_version); -- jboyer/gmcharlt
+
+DROP TRIGGER IF EXISTS inherit_copy_bucket_item_target_copy_fkey ON container.copy_bucket_item;
+DROP TRIGGER IF EXISTS inherit_import_item_imported_as_fkey ON vandelay.import_item;
+DROP TRIGGER IF EXISTS inherit_asset_copy_note_copy_fkey ON asset.copy_note;
+DROP TRIGGER IF EXISTS inherit_asset_copy_tag_copy_map_copy_fkey ON asset.copy_tag_copy_map;
+
+CREATE CONSTRAINT TRIGGER inherit_copy_bucket_item_target_copy_fkey
+  AFTER UPDATE OR INSERT ON container.copy_bucket_item
+  DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.container_copy_bucket_item_target_copy_inh_fkey();
+CREATE CONSTRAINT TRIGGER inherit_import_item_imported_as_fkey
+  AFTER UPDATE OR INSERT ON vandelay.import_item
+  DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.vandelay_import_item_imported_as_inh_fkey();
+CREATE CONSTRAINT TRIGGER inherit_asset_copy_note_copy_fkey
+  AFTER UPDATE OR INSERT ON asset.copy_note
+  DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_copy_note_owning_copy_inh_fkey();
+CREATE CONSTRAINT TRIGGER inherit_asset_copy_tag_copy_map_copy_fkey
+  AFTER UPDATE OR INSERT ON asset.copy_tag_copy_map
+  DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_copy_tag_copy_map_copy_inh_fkey();
+
+
+
+SELECT evergreen.upgrade_deps_block_check('1082', :eg_version); -- jboyer/gmcharlt
+
+DELETE FROM asset.copy_vis_attr_cache WHERE target_copy IN (SELECT id FROM asset.copy WHERE deleted);
+
+-- Evergreen DB patch XXXX.schema.qualify_unaccent_refs.sql
+--
+-- LP#1671150 Fix unaccent() function call in evergreen.unaccent_and_squash()
+--
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('1083', :eg_version);
+
+CREATE OR REPLACE FUNCTION evergreen.unaccent_and_squash ( IN arg text) RETURNS text
+    IMMUTABLE STRICT AS $$
+        BEGIN
+        RETURN evergreen.lowercase(public.unaccent('public.unaccent', regexp_replace(arg, '[\s[:punct:]]','','g')));
+        END;
+$$ LANGUAGE PLPGSQL;
+
+-- Drop indexes if present, so that we can re-create them
+DROP INDEX IF EXISTS actor.actor_usr_first_given_name_unaccent_idx;
+DROP INDEX IF EXISTS actor.actor_usr_second_given_name_unaccent_idx;
+DROP INDEX IF EXISTS actor.actor_usr_family_name_unaccent_idx; 
+DROP INDEX IF EXISTS actor.actor_usr_usrname_unaccent_idx; 
+
+-- Create (or re-create) indexes -- they may be missing if pg_restore failed to create
+-- them due to the previously unqualified call to unaccent()
+CREATE INDEX actor_usr_first_given_name_unaccent_idx ON actor.usr (evergreen.unaccent_and_squash(first_given_name));
+CREATE INDEX actor_usr_second_given_name_unaccent_idx ON actor.usr (evergreen.unaccent_and_squash(second_given_name));
+CREATE INDEX actor_usr_family_name_unaccent_idx ON actor.usr (evergreen.unaccent_and_squash(family_name));
+CREATE INDEX actor_usr_usrname_unaccent_idx ON actor.usr (evergreen.unaccent_and_squash(usrname));
+
+
+SELECT evergreen.upgrade_deps_block_check('1084', :eg_version);
+
+INSERT INTO config.usr_setting_type (name, label, description, datatype)
+  VALUES ('webstaff.cat.copy.templates', 'Web Client Copy Editor Templates', 'Web Client Copy Editor Templates', 'object');
+
+COMMIT;