---Upgrade Script for 2.1 to 2.2.0 - PINES version, part 2 --csharp
+--Upgrade Script for 2.1 to 2.2.0
-- Don't require use of -vegversion=something
\set eg_version '''2.2.0'''
+-- DROP objects that might have existed from a prior run of 0526
+-- Yes this is ironic.
+DROP TABLE IF EXISTS config.db_patch_dependencies;
+ALTER TABLE config.upgrade_log DROP COLUMN IF EXISTS applied_to;
+DROP FUNCTION IF EXISTS evergreen.upgrade_list_applied_deprecates(TEXT);
+DROP FUNCTION IF EXISTS evergreen.upgrade_list_applied_supersedes(TEXT);
+
+BEGIN;
+INSERT INTO config.upgrade_log (version) VALUES ('2.2.0');
+
+INSERT INTO config.upgrade_log (version) VALUES ('0526'); --miker
+
+CREATE TABLE config.db_patch_dependencies (
+ db_patch TEXT PRIMARY KEY,
+ supersedes TEXT[],
+ deprecates TEXT[]
+);
+
+CREATE OR REPLACE FUNCTION evergreen.array_overlap_check (/* field */) RETURNS TRIGGER AS $$
+DECLARE
+ fld TEXT;
+ cnt INT;
+BEGIN
+ fld := TG_ARGV[1];
+ EXECUTE 'SELECT COUNT(*) FROM '|| TG_TABLE_SCHEMA ||'.'|| TG_TABLE_NAME ||' WHERE '|| fld ||' && ($1).'|| fld INTO cnt USING NEW;
+ IF cnt > 0 THEN
+ RAISE EXCEPTION 'Cannot insert duplicate array into field % of table %', fld, TG_TABLE_SCHEMA ||'.'|| TG_TABLE_NAME;
+ END IF;
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER no_overlapping_sups
+ BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
+ FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('supersedes');
+
+CREATE TRIGGER no_overlapping_deps
+ BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
+ FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
+
+ALTER TABLE config.upgrade_log
+ ADD COLUMN applied_to TEXT;
+
+-- Provide a named type for patching functions
+CREATE TYPE evergreen.patch AS (patch TEXT);
+
+-- List applied db patches that are deprecated by (and block the application of) my_db_patch
+CREATE OR REPLACE FUNCTION evergreen.upgrade_list_applied_deprecates ( my_db_patch TEXT ) RETURNS SETOF evergreen.patch AS $$
+ SELECT DISTINCT l.version
+ FROM config.upgrade_log l
+ JOIN config.db_patch_dependencies d ON (l.version::TEXT[] && d.deprecates)
+ WHERE d.db_patch = $1
+$$ LANGUAGE SQL;
+
+-- List applied db patches that are superseded by (and block the application of) my_db_patch
+CREATE OR REPLACE FUNCTION evergreen.upgrade_list_applied_supersedes ( my_db_patch TEXT ) RETURNS SETOF evergreen.patch AS $$
+ SELECT DISTINCT l.version
+ FROM config.upgrade_log l
+ JOIN config.db_patch_dependencies d ON (l.version::TEXT[] && d.supersedes)
+ WHERE d.db_patch = $1
+$$ LANGUAGE SQL;
+
+-- List applied db patches that deprecates (and block the application of) my_db_patch
+CREATE OR REPLACE FUNCTION evergreen.upgrade_list_applied_deprecated ( my_db_patch TEXT ) RETURNS TEXT AS $$
+ SELECT db_patch
+ FROM config.db_patch_dependencies
+ WHERE ARRAY[$1]::TEXT[] && deprecates
+$$ LANGUAGE SQL;
+
+-- List applied db patches that supersedes (and block the application of) my_db_patch
+CREATE OR REPLACE FUNCTION evergreen.upgrade_list_applied_superseded ( my_db_patch TEXT ) RETURNS TEXT AS $$
+ SELECT db_patch
+ FROM config.db_patch_dependencies
+ WHERE ARRAY[$1]::TEXT[] && supersedes
+$$ LANGUAGE SQL;
+
+-- Make sure that no deprecated or superseded db patches are currently applied
+CREATE OR REPLACE FUNCTION evergreen.upgrade_verify_no_dep_conflicts ( my_db_patch TEXT ) RETURNS BOOL AS $$
+ SELECT COUNT(*) = 0
+ FROM (SELECT * FROM evergreen.upgrade_list_applied_deprecates( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_supersedes( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_deprecated( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_superseded( $1 ))x
+$$ LANGUAGE SQL;
+
+-- Raise an exception if there are, in fact, dep/sup confilct
+CREATE OR REPLACE FUNCTION evergreen.upgrade_deps_block_check ( my_db_patch TEXT, my_applied_to TEXT ) RETURNS BOOL AS $$
+DECLARE
+ deprecates TEXT;
+ supersedes TEXT;
+BEGIN
+ IF NOT evergreen.upgrade_verify_no_dep_conflicts( my_db_patch ) THEN
+ SELECT STRING_AGG(patch, ', ') INTO deprecates FROM evergreen.upgrade_list_applied_deprecates(my_db_patch);
+ SELECT STRING_AGG(patch, ', ') INTO supersedes FROM evergreen.upgrade_list_applied_supersedes(my_db_patch);
+ RAISE EXCEPTION '
+Upgrade script % can not be applied:
+ applied deprecated scripts %
+ applied superseded scripts %
+ deprecated by %
+ superseded by %',
+ my_db_patch,
+ ARRAY_AGG(evergreen.upgrade_list_applied_deprecates(my_db_patch)),
+ ARRAY_AGG(evergreen.upgrade_list_applied_supersedes(my_db_patch)),
+ evergreen.upgrade_list_applied_deprecated(my_db_patch),
+ evergreen.upgrade_list_applied_superseded(my_db_patch);
+ END IF;
+
+ INSERT INTO config.upgrade_log (version, applied_to) VALUES (my_db_patch, my_applied_to);
+ RETURN TRUE;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Evergreen DB patch 0536.schema.lazy_circ-barcode_lookup.sql
+--
+-- FIXME: insert description of change, if needed
+--
+
+-- check whether patch can be applied
+INSERT INTO config.upgrade_log (version) VALUES ('0536');
+
+INSERT INTO config.org_unit_setting_type ( name, label, description, datatype) VALUES ( 'circ.staff_client.actor_on_checkout', 'Load patron from Checkout', 'When scanning barcodes into Checkout auto-detect if a new patron barcode is scanned and auto-load the new patron.', 'bool');
+
+CREATE TABLE config.barcode_completion (
+ id SERIAL PRIMARY KEY,
+ active BOOL NOT NULL DEFAULT true,
+ org_unit INT NOT NULL REFERENCES actor.org_unit (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
+ prefix TEXT,
+ suffix TEXT,
+ length INT NOT NULL DEFAULT 0,
+ padding TEXT,
+ padding_end BOOL NOT NULL DEFAULT false,
+ asset BOOL NOT NULL DEFAULT true,
+ actor BOOL NOT NULL DEFAULT true
+);
+
+CREATE TYPE evergreen.barcode_set AS (type TEXT, id BIGINT, barcode TEXT);
+
+CREATE OR REPLACE FUNCTION evergreen.get_barcodes(select_ou INT, type TEXT, in_barcode TEXT) RETURNS SETOF evergreen.barcode_set AS $$
+DECLARE
+ cur_barcode TEXT;
+ barcode_len INT;
+ completion_len INT;
+ asset_barcodes TEXT[];
+ actor_barcodes TEXT[];
+ do_asset BOOL = false;
+ do_serial BOOL = false;
+ do_booking BOOL = false;
+ do_actor BOOL = false;
+ completion_set config.barcode_completion%ROWTYPE;
+BEGIN
+
+ IF position('asset' in type) > 0 THEN
+ do_asset = true;
+ END IF;
+ IF position('serial' in type) > 0 THEN
+ do_serial = true;
+ END IF;
+ IF position('booking' in type) > 0 THEN
+ do_booking = true;
+ END IF;
+ IF do_asset OR do_serial OR do_booking THEN
+ asset_barcodes = asset_barcodes || in_barcode;
+ END IF;
+ IF position('actor' in type) > 0 THEN
+ do_actor = true;
+ actor_barcodes = actor_barcodes || in_barcode;
+ END IF;
+
+ barcode_len := length(in_barcode);
+
+ FOR completion_set IN
+ SELECT * FROM config.barcode_completion
+ WHERE active
+ AND org_unit IN (SELECT aou.id FROM actor.org_unit_ancestors(select_ou) aou)
+ LOOP
+ IF completion_set.prefix IS NULL THEN
+ completion_set.prefix := '';
+ END IF;
+ IF completion_set.suffix IS NULL THEN
+ completion_set.suffix := '';
+ END IF;
+ IF completion_set.length = 0 OR completion_set.padding IS NULL OR length(completion_set.padding) = 0 THEN
+ cur_barcode = completion_set.prefix || in_barcode || completion_set.suffix;
+ ELSE
+ completion_len = completion_set.length - length(completion_set.prefix) - length(completion_set.suffix);
+ IF completion_len >= barcode_len THEN
+ IF completion_set.padding_end THEN
+ cur_barcode = rpad(in_barcode, completion_len, completion_set.padding);
+ ELSE
+ cur_barcode = lpad(in_barcode, completion_len, completion_set.padding);
+ END IF;
+ cur_barcode = completion_set.prefix || cur_barcode || completion_set.suffix;
+ END IF;
+ END IF;
+ IF completion_set.actor THEN
+ actor_barcodes = actor_barcodes || cur_barcode;
+ END IF;
+ IF completion_set.asset THEN
+ asset_barcodes = asset_barcodes || cur_barcode;
+ END IF;
+ END LOOP;
+
+ IF do_asset AND do_serial THEN
+ RETURN QUERY SELECT 'asset'::TEXT, id, barcode FROM ONLY asset.copy WHERE barcode = ANY(asset_barcodes) AND deleted = false;
+ RETURN QUERY SELECT 'serial'::TEXT, id, barcode FROM serial.unit WHERE barcode = ANY(asset_barcodes) AND deleted = false;
+ ELSIF do_asset THEN
+ RETURN QUERY SELECT 'asset'::TEXT, id, barcode FROM asset.copy WHERE barcode = ANY(asset_barcodes) AND deleted = false;
+ ELSIF do_serial THEN
+ RETURN QUERY SELECT 'serial'::TEXT, id, barcode FROM serial.unit WHERE barcode = ANY(asset_barcodes) AND deleted = false;
+ END IF;
+ IF do_booking THEN
+ RETURN QUERY SELECT 'booking'::TEXT, id::BIGINT, barcode FROM booking.resource WHERE barcode = ANY(asset_barcodes);
+ END IF;
+ IF do_actor THEN
+ RETURN QUERY SELECT 'actor'::TEXT, c.usr::BIGINT, c.barcode FROM actor.card c JOIN actor.usr u ON c.usr = u.id WHERE c.barcode = ANY(actor_barcodes) AND c.active AND NOT u.deleted ORDER BY usr;
+ END IF;
+ RETURN;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMENT ON FUNCTION evergreen.get_barcodes(INT, TEXT, TEXT) IS $$
+Given user input, find an appropriate barcode in the proper class.
+
+Will add prefix/suffix information to do so, and return all results.
+$$;
+
+
+
+INSERT INTO config.upgrade_log (version) VALUES ('0537'); --miker
+
+DROP FUNCTION evergreen.upgrade_deps_block_check(text,text);
+DROP FUNCTION evergreen.upgrade_verify_no_dep_conflicts(text);
+DROP FUNCTION evergreen.upgrade_list_applied_deprecated(text);
+DROP FUNCTION evergreen.upgrade_list_applied_superseded(text);
+
+-- List applied db patches that deprecates (and block the application of) my_db_patch
+CREATE FUNCTION evergreen.upgrade_list_applied_deprecated ( my_db_patch TEXT ) RETURNS SETOF TEXT AS $$
+ SELECT db_patch
+ FROM config.db_patch_dependencies
+ WHERE ARRAY[$1]::TEXT[] && deprecates
+$$ LANGUAGE SQL;
+
+-- List applied db patches that supersedes (and block the application of) my_db_patch
+CREATE FUNCTION evergreen.upgrade_list_applied_superseded ( my_db_patch TEXT ) RETURNS SETOF TEXT AS $$
+ SELECT db_patch
+ FROM config.db_patch_dependencies
+ WHERE ARRAY[$1]::TEXT[] && supersedes
+$$ LANGUAGE SQL;
+
+-- Make sure that no deprecated or superseded db patches are currently applied
+CREATE FUNCTION evergreen.upgrade_verify_no_dep_conflicts ( my_db_patch TEXT ) RETURNS BOOL AS $$
+ SELECT COUNT(*) = 0
+ FROM (SELECT * FROM evergreen.upgrade_list_applied_deprecates( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_supersedes( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_deprecated( $1 )
+ UNION
+ SELECT * FROM evergreen.upgrade_list_applied_superseded( $1 ))x
+$$ LANGUAGE SQL;
+
+-- Raise an exception if there are, in fact, dep/sup confilct
+CREATE FUNCTION evergreen.upgrade_deps_block_check ( my_db_patch TEXT, my_applied_to TEXT ) RETURNS BOOL AS $$
+BEGIN
+ IF NOT evergreen.upgrade_verify_no_dep_conflicts( my_db_patch ) THEN
+ RAISE EXCEPTION '
+Upgrade script % can not be applied:
+ applied deprecated scripts %
+ applied superseded scripts %
+ deprecated by %
+ superseded by %',
+ my_db_patch,
+ ARRAY_ACCUM(evergreen.upgrade_list_applied_deprecates(my_db_patch)),
+ ARRAY_ACCUM(evergreen.upgrade_list_applied_supersedes(my_db_patch)),
+ evergreen.upgrade_list_applied_deprecated(my_db_patch),
+ evergreen.upgrade_list_applied_superseded(my_db_patch);
+ END IF;
+
+ INSERT INTO config.upgrade_log (version, applied_to) VALUES (my_db_patch, my_applied_to);
+ RETURN TRUE;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+INSERT INTO config.upgrade_log (version) VALUES ('0544');
+
+INSERT INTO config.usr_setting_type
+( name, opac_visible, label, description, datatype) VALUES
+( 'circ.collections.exempt',
+ FALSE,
+ oils_i18n_gettext('circ.collections.exempt', 'Collections: Exempt', 'cust', 'description'),
+ oils_i18n_gettext('circ.collections.exempt', 'User is exempt from collections tracking/processing', 'cust', 'description'),
+ 'bool'
+);
+
+
+
+SELECT evergreen.upgrade_deps_block_check('0545', :eg_version);
+
+INSERT INTO permission.perm_list VALUES
+ (507, 'ABORT_TRANSIT_ON_LOST', oils_i18n_gettext(507, 'Allows a user to abort a transit on a copy with status of LOST', 'ppl', 'description')),
+ (508, 'ABORT_TRANSIT_ON_MISSING', oils_i18n_gettext(508, 'Allows a user to abort a transit on a copy with status of MISSING', 'ppl', 'description'));
+
+--- stock Circulation Administrator group
+
+INSERT INTO permission.grp_perm_map ( grp, perm, depth, grantable )
+ SELECT
+ 4,
+ id,
+ 0,
+ 't'
+ FROM permission.perm_list
+ WHERE code in ('ABORT_TRANSIT_ON_LOST', 'ABORT_TRANSIT_ON_MISSING');
+
+-- Evergreen DB patch 0546.schema.sip_statcats.sql
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0546', :eg_version);
+
+CREATE TABLE actor.stat_cat_sip_fields (
+ field CHAR(2) PRIMARY KEY,
+ name TEXT NOT NULL,
+ one_only BOOL NOT NULL DEFAULT FALSE
+);
+COMMENT ON TABLE actor.stat_cat_sip_fields IS $$
+Actor Statistical Category SIP Fields
+
+Contains the list of valid SIP Field identifiers for
+Statistical Categories.
+$$;
+ALTER TABLE actor.stat_cat
+ ADD COLUMN sip_field CHAR(2) REFERENCES actor.stat_cat_sip_fields(field) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
+ ADD COLUMN sip_format TEXT;
+
+CREATE FUNCTION actor.stat_cat_check() RETURNS trigger AS $func$
+DECLARE
+ sipfield actor.stat_cat_sip_fields%ROWTYPE;
+ use_count INT;
+BEGIN
+ IF NEW.sip_field IS NOT NULL THEN
+ SELECT INTO sipfield * FROM actor.stat_cat_sip_fields WHERE field = NEW.sip_field;
+ IF sipfield.one_only THEN
+ SELECT INTO use_count count(id) FROM actor.stat_cat WHERE sip_field = NEW.sip_field AND id != NEW.id;
+ IF use_count > 0 THEN
+ RAISE EXCEPTION 'Sip field cannot be used twice';
+ END IF;
+ END IF;
+ END IF;
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER actor_stat_cat_sip_update_trigger
+ BEFORE INSERT OR UPDATE ON actor.stat_cat FOR EACH ROW
+ EXECUTE PROCEDURE actor.stat_cat_check();
+
+CREATE TABLE asset.stat_cat_sip_fields (
+ field CHAR(2) PRIMARY KEY,
+ name TEXT NOT NULL,
+ one_only BOOL NOT NULL DEFAULT FALSE
+);
+COMMENT ON TABLE asset.stat_cat_sip_fields IS $$
+Asset Statistical Category SIP Fields
+
+Contains the list of valid SIP Field identifiers for
+Statistical Categories.
+$$;
+
+ALTER TABLE asset.stat_cat
+ ADD COLUMN sip_field CHAR(2) REFERENCES asset.stat_cat_sip_fields(field) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED,
+ ADD COLUMN sip_format TEXT;
+
+CREATE FUNCTION asset.stat_cat_check() RETURNS trigger AS $func$
+DECLARE
+ sipfield asset.stat_cat_sip_fields%ROWTYPE;
+ use_count INT;
+BEGIN
+ IF NEW.sip_field IS NOT NULL THEN
+ SELECT INTO sipfield * FROM asset.stat_cat_sip_fields WHERE field = NEW.sip_field;
+ IF sipfield.one_only THEN
+ SELECT INTO use_count count(id) FROM asset.stat_cat WHERE sip_field = NEW.sip_field AND id != NEW.id;
+ IF use_count > 0 THEN
+ RAISE EXCEPTION 'Sip field cannot be used twice';
+ END IF;
+ END IF;
+ END IF;
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL;
+
+CREATE TRIGGER asset_stat_cat_sip_update_trigger
+ BEFORE INSERT OR UPDATE ON asset.stat_cat FOR EACH ROW
+ EXECUTE PROCEDURE asset.stat_cat_check();
+
+
+
+SELECT evergreen.upgrade_deps_block_check('0548', :eg_version); -- dbwells
+
+\qecho This redoes the original part 1 of 0547 which did not apply to rel_2_1,
+\qecho and is being added for the sake of clarity
+
+-- delete errant inserts from 0545 (group 4 is NOT the circulation admin group)
+DELETE FROM permission.grp_perm_map WHERE grp = 4 AND perm IN (
+ SELECT id FROM permission.perm_list
+ WHERE code in ('ABORT_TRANSIT_ON_LOST', 'ABORT_TRANSIT_ON_MISSING')
+);
+
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable)
+ SELECT
+ pgt.id, perm.id, aout.depth, TRUE
+ FROM
+ permission.grp_tree pgt,
+ permission.perm_list perm,
+ actor.org_unit_type aout
+ WHERE
+ pgt.name = 'Circulation Administrator' AND
+ aout.name = 'Consortium' AND
+ perm.code IN (
+ 'ABORT_TRANSIT_ON_LOST',
+ 'ABORT_TRANSIT_ON_MISSING'
+ ) AND NOT EXISTS (
+ SELECT 1
+ FROM permission.grp_perm_map AS map
+ WHERE
+ map.grp = pgt.id
+ AND map.perm = perm.id
+ );
+
+-- Evergreen DB patch XXXX.data.transit-checkin-interval.sql
+--
+-- New org unit setting "circ.transit.min_checkin_interval"
+-- New TRANSIT_CHECKIN_INTERVAL_BLOCK.override permission
+--
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0549', :eg_version);
+
+INSERT INTO config.org_unit_setting_type ( name, label, description, datatype ) VALUES (
+ 'circ.transit.min_checkin_interval',
+ oils_i18n_gettext(
+ 'circ.transit.min_checkin_interval',
+ 'Circ: Minimum Transit Checkin Interval',
+ 'coust',
+ 'label'
+ ),
+ oils_i18n_gettext(
+ 'circ.transit.min_checkin_interval',
+ 'In-Transit items checked in this close to the transit start time will be prevented from checking in',
+ 'coust',
+ 'label'
+ ),
+ 'interval'
+);
+
+INSERT INTO permission.perm_list ( id, code, description ) VALUES (
+ 509,
+ 'TRANSIT_CHECKIN_INTERVAL_BLOCK.override',
+ oils_i18n_gettext(
+ 509,
+ 'Allows a user to override the TRANSIT_CHECKIN_INTERVAL_BLOCK event',
+ 'ppl',
+ 'description'
+ )
+);
+
+-- add the perm to the default circ admin group
+INSERT INTO permission.grp_perm_map (grp, perm, depth, grantable)
+ SELECT
+ pgt.id, perm.id, aout.depth, TRUE
+ FROM
+ permission.grp_tree pgt,
+ permission.perm_list perm,
+ actor.org_unit_type aout
+ WHERE
+ pgt.name = 'Circulation Administrator' AND
+ aout.name = 'System' AND
+ perm.code IN ( 'TRANSIT_CHECKIN_INTERVAL_BLOCK.override' );
+
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0550', :eg_version);
+
+INSERT INTO config.org_unit_setting_type ( name, label, description, datatype ) VALUES (
+ 'org.patron_opt_boundary',
+ oils_i18n_gettext(
+ 'org.patron_opt_boundary',
+ 'Circ: Patron Opt-In Boundary',
+ 'coust',
+ 'label'
+ ),
+ oils_i18n_gettext(
+ 'org.patron_opt_boundary',
+ 'This determines at which depth above which patrons must be opted in, and below which patrons will be assumed to be opted in.',
+ 'coust',
+ 'label'
+ ),
+ 'integer'
+);
+
+INSERT INTO config.org_unit_setting_type ( name, label, description, datatype ) VALUES (
+ 'org.patron_opt_default',
+ oils_i18n_gettext(
+ 'org.patron_opt_default',
+ 'Circ: Patron Opt-In Default',
+ 'coust',
+ 'label'
+ ),
+ oils_i18n_gettext(
+ 'org.patron_opt_default',
+ 'This is the default depth at which a patron is opted in; it is calculated as an org unit relative to the current workstation.',
+ 'coust',
+ 'label'
+ ),
+ 'integer'
+);
+
-- Evergreen DB patch 0562.schema.copy_active_date.sql
--
-- Active Date
1
);
+-- Evergreen DB patch 0663.schema.archive_circ_stat_cats.sql
+--
+-- Enables users to set copy and patron stat cats to be archivable
+-- for the purposes of statistics even after the circs are aged.
+--
+
+-- check whether patch can be applied
+SELECT evergreen.upgrade_deps_block_check('0663', :eg_version);
+
+-- New tables
+
+CREATE TABLE action.archive_actor_stat_cat (
+ id BIGSERIAL PRIMARY KEY,
+ xact BIGINT NOT NULL,
+ stat_cat INT NOT NULL,
+ value TEXT NOT NULL
+);
+
+CREATE TABLE action.archive_asset_stat_cat (
+ id BIGSERIAL PRIMARY KEY,
+ xact BIGINT NOT NULL,
+ stat_cat INT NOT NULL,
+ value TEXT NOT NULL
+);
+
+-- Add columns to existing tables
+
+-- Archive Flag Columns
+ALTER TABLE actor.stat_cat
+ ADD COLUMN checkout_archive BOOL NOT NULL DEFAULT FALSE;
+ALTER TABLE asset.stat_cat
+ ADD COLUMN checkout_archive BOOL NOT NULL DEFAULT FALSE;
+
+-- Circulation copy column
+ALTER TABLE action.circulation
+ ADD COLUMN copy_location INT NULL REFERENCES asset.copy_location(id) DEFERRABLE INITIALLY DEFERRED;
+
+-- Create trigger function to auto-fill the copy_location field
+CREATE OR REPLACE FUNCTION action.fill_circ_copy_location () RETURNS TRIGGER AS $$
+BEGIN
+ SELECT INTO NEW.copy_location location FROM asset.copy WHERE id = NEW.target_copy;
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Create trigger function to auto-archive stat cat entries
+CREATE OR REPLACE FUNCTION action.archive_stat_cats () RETURNS TRIGGER AS $$
+BEGIN
+ INSERT INTO action.archive_actor_stat_cat(xact, stat_cat, value)
+ SELECT NEW.id, asceum.stat_cat, asceum.stat_cat_entry
+ FROM actor.stat_cat_entry_usr_map asceum
+ JOIN actor.stat_cat sc ON asceum.stat_cat = sc.id
+ WHERE NEW.usr = asceum.target_usr AND sc.checkout_archive;
+ INSERT INTO action.archive_asset_stat_cat(xact, stat_cat, value)
+ SELECT NEW.id, ascecm.stat_cat, asce.value
+ FROM asset.stat_cat_entry_copy_map ascecm
+ JOIN asset.stat_cat sc ON ascecm.stat_cat = sc.id
+ JOIN asset.stat_cat_entry asce ON ascecm.stat_cat_entry = asce.id
+ WHERE NEW.target_copy = ascecm.owning_copy AND sc.checkout_archive;
+ RETURN NULL;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Apply triggers
+CREATE TRIGGER fill_circ_copy_location_tgr BEFORE INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE action.fill_circ_copy_location();
+CREATE TRIGGER archive_stat_cats_tgr AFTER INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE action.archive_stat_cats();
+
+-- Ensure all triggers are disabled for speedy updates!
+ALTER TABLE action.circulation DISABLE TRIGGER ALL;
+
+-- Update view to use circ's copy_location field instead of the copy's current copy_location field
+CREATE OR REPLACE VIEW action.all_circulation AS
+ SELECT id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
+ copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
+ circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date,
+ stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine,
+ max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule,
+ max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ
+ FROM action.aged_circulation
+ UNION ALL
+ SELECT DISTINCT circ.id,COALESCE(a.post_code,b.post_code) AS usr_post_code, p.home_ou AS usr_home_ou, p.profile AS usr_profile, EXTRACT(YEAR FROM p.dob)::INT AS usr_birth_year,
+ cp.call_number AS copy_call_number, circ.copy_location, cn.owning_lib AS copy_owning_lib, cp.circ_lib AS copy_circ_lib,
+ cn.record AS copy_bib_record, circ.xact_start, circ.xact_finish, circ.target_copy, circ.circ_lib, circ.circ_staff, circ.checkin_staff,
+ circ.checkin_lib, circ.renewal_remaining, circ.grace_period, circ.due_date, circ.stop_fines_time, circ.checkin_time, circ.create_time, circ.duration,
+ circ.fine_interval, circ.recurring_fine, circ.max_fine, circ.phone_renewal, circ.desk_renewal, circ.opac_renewal, circ.duration_rule,
+ circ.recurring_fine_rule, circ.max_fine_rule, circ.stop_fines, circ.workstation, circ.checkin_workstation, circ.checkin_scan_time,
+ circ.parent_circ
+ FROM action.circulation circ
+ JOIN asset.copy cp ON (circ.target_copy = cp.id)
+ JOIN asset.call_number cn ON (cp.call_number = cn.id)
+ JOIN actor.usr p ON (circ.usr = p.id)
+ LEFT JOIN actor.usr_address a ON (p.mailing_address = a.id)
+ LEFT JOIN actor.usr_address b ON (p.billing_address = b.id);
+
+-- Update action.circulation with real copy_location numbers instead of all NULL
+DO $$BEGIN RAISE WARNING 'We are about to do an update on every row in action.circulation. This may take a while. %', timeofday(); END;$$;
+UPDATE action.circulation circ SET copy_location = ac.location FROM asset.copy ac WHERE ac.id = circ.target_copy;
+
+-- Set not null/default on new column, re-enable triggers
+ALTER TABLE action.circulation
+ ALTER COLUMN copy_location SET NOT NULL,
+ ALTER COLUMN copy_location SET DEFAULT 1,
+ ENABLE TRIGGER ALL;
+
-- Evergreen DB patch 0664.schema.hold-current-shelf-lib.sql
--
--
metabib.full_rec a JOIN metabib.full_rec b USING (record)
WHERE
a.tag = 'LDR' AND a.value LIKE '______g%'
- AND b.tag = '007' AND b.value LIKE 'v___s%')
- AND NOT deleted; -- csharp
+ AND b.tag = '007' AND b.value LIKE 'v___s%');
UPDATE config.internal_flag SET enabled = same_marc WHERE name = 'ingest.reingest.force_on_same_marc';
END;
$FUNC$;