From: Chris Sharp Date: Tue, 21 Sep 2021 20:22:43 +0000 (-0400) Subject: LP#1207533: Stamp upgrade scripts, minor typo correction X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=4d267c5617e85520a8280cee946bda5c3ddb062d;p=evergreen%2Ftadl.git LP#1207533: Stamp upgrade scripts, minor typo correction Signed-off-by: Chris Sharp --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 55bc324e63..715d1b1ca0 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -92,7 +92,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1290', :eg_version); -- tlittle / lstratton / gmcharlt +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1293', :eg_version); -- phasefx / miker / ddale / csharp CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1291.schema.triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/1291.schema.triggered_event_log.sql new file mode 100644 index 0000000000..ffbf505859 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1291.schema.triggered_event_log.sql @@ -0,0 +1,59 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1291', :eg_version); + +-- context_usr_path TEXT, -- for optimizing action_trigger.event +-- context_library_path TEXT, -- ''' +-- context_bib_path TEXT, -- ''' +ALTER TABLE action_trigger.event_definition ADD COLUMN context_usr_path TEXT; +ALTER TABLE action_trigger.event_definition ADD COLUMN context_library_path TEXT; +ALTER TABLE action_trigger.event_definition ADD COLUMN context_bib_path TEXT; + +-- context_user INT REFERENCES actor.usr (id), +-- context_library INT REFERENCES actor.org_unit (id), +-- context_bib BIGINT REFERENCES biblio.record_entry (id) +ALTER TABLE action_trigger.event ADD COLUMN context_user INT REFERENCES actor.usr (id); +ALTER TABLE action_trigger.event ADD COLUMN context_library INT REFERENCES actor.org_unit (id); +ALTER TABLE action_trigger.event ADD COLUMN context_bib BIGINT REFERENCES biblio.record_entry (id); +CREATE INDEX atev_context_user ON action_trigger.event (context_user); +CREATE INDEX atev_context_library ON action_trigger.event (context_library); + +UPDATE + action_trigger.event_definition +SET + context_usr_path = 'usr', + context_library_path = 'circ_lib', + context_bib_path = 'target_copy.call_number.record' +WHERE + hook IN ( + SELECT key FROM action_trigger.hook WHERE core_type = 'circ' + ) +; + +UPDATE + action_trigger.event_definition +SET + context_usr_path = 'usr', + context_library_path = 'pickup_lib', + context_bib_path = 'bib_rec' +WHERE + hook IN ( + SELECT key FROM action_trigger.hook WHERE core_type = 'ahr' + ) +; + +-- Retroactively setting context_user and context_library on existing rows in action_trigger.event: +-- This is not done by default because it'll likely take a long time depending on the Evergreen +-- installation. You may want to do this out-of-band with the upgrade if you want to do this at all. +-- +-- \pset format unaligned +-- \t +-- \o update_action_trigger_events_for_circs.sql +-- SELECT 'UPDATE action_trigger.event e SET context_user = c.usr, context_library = c.circ_lib, context_bib = cn.record FROM action.circulation c, asset.copy i, asset.call_number cn WHERE c.id = e.target AND c.target_copy = i.id AND i.call_number = cn.id AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.circulation c WHERE e.target = c.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ')) ORDER BY e.id DESC; +-- \o +-- \o update_action_trigger_events_for_holds.sql +-- SELECT 'UPDATE action_trigger.event e SET context_user = h.usr, context_library = h.pickup_lib, context_bib = r.bib_record FROM action.hold_request h, reporter.hold_request_record r WHERE h.id = e.target AND h.id = r.id AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.hold_request h WHERE e.target = h.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'ahr')) ORDER BY e.id DESC; +-- \o + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/upgrade/1292.functions.triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/1292.functions.triggered_event_log.sql new file mode 100644 index 0000000000..5653b72883 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1292.functions.triggered_event_log.sql @@ -0,0 +1,407 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1292', :eg_version); + +CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$ +DECLARE +found char := 'N'; +BEGIN + + -- If there are any renewals for this circulation, don't archive or delete + -- it yet. We'll do so later, when we archive and delete the renewals. + + SELECT 'Y' INTO found + FROM action.circulation + WHERE parent_circ = OLD.id + LIMIT 1; + + IF found = 'Y' THEN + RETURN NULL; -- don't delete + END IF; + + -- Archive a copy of the old row to action.aged_circulation + + INSERT INTO action.aged_circulation + (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, + auto_renewal, auto_renewal_remaining) + 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, + auto_renewal, auto_renewal_remaining + FROM action.all_circulation WHERE id = OLD.id; + + -- Migrate billings and payments to aged tables + + SELECT 'Y' INTO found FROM config.global_flag + WHERE name = 'history.money.age_with_circs' AND enabled; + + IF found = 'Y' THEN + PERFORM money.age_billings_and_payments_for_xact(OLD.id); + END IF; + + -- Break the link with the user in action_trigger.event (warning: event_output may essentially have this information) + UPDATE + action_trigger.event e + SET + context_user = NULL + FROM + action.all_circulation c + WHERE + c.id = OLD.id + AND e.context_user = c.usr + AND e.target = c.id + AND e.event_def IN ( + SELECT id + FROM action_trigger.event_definition + WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ') + ) + ; + + RETURN OLD; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION actor.usr_purge_data( + src_usr IN INTEGER, + specified_dest_usr IN INTEGER +) RETURNS VOID AS $$ +DECLARE + suffix TEXT; + renamable_row RECORD; + dest_usr INTEGER; +BEGIN + + IF specified_dest_usr IS NULL THEN + dest_usr := 1; -- Admin user on stock installs + ELSE + dest_usr := specified_dest_usr; + END IF; + + -- action_trigger.event (even doing this, event_output may--and probably does--contain PII and should have a retention/removal policy) + UPDATE action_trigger.event SET context_user = dest_usr WHERE context_user = src_usr; + + -- acq.* + UPDATE acq.fund_allocation SET allocator = dest_usr WHERE allocator = src_usr; + UPDATE acq.lineitem SET creator = dest_usr WHERE creator = src_usr; + UPDATE acq.lineitem SET editor = dest_usr WHERE editor = src_usr; + UPDATE acq.lineitem SET selector = dest_usr WHERE selector = src_usr; + UPDATE acq.lineitem_note SET creator = dest_usr WHERE creator = src_usr; + UPDATE acq.lineitem_note SET editor = dest_usr WHERE editor = src_usr; + UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr; + DELETE FROM acq.lineitem_usr_attr_definition WHERE usr = src_usr; + + -- Update with a rename to avoid collisions + FOR renamable_row in + SELECT id, name + FROM acq.picklist + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE acq.picklist + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + UPDATE acq.picklist SET creator = dest_usr WHERE creator = src_usr; + UPDATE acq.picklist SET editor = dest_usr WHERE editor = src_usr; + UPDATE acq.po_note SET creator = dest_usr WHERE creator = src_usr; + UPDATE acq.po_note SET editor = dest_usr WHERE editor = src_usr; + UPDATE acq.purchase_order SET owner = dest_usr WHERE owner = src_usr; + UPDATE acq.purchase_order SET creator = dest_usr WHERE creator = src_usr; + UPDATE acq.purchase_order SET editor = dest_usr WHERE editor = src_usr; + UPDATE acq.claim_event SET creator = dest_usr WHERE creator = src_usr; + + -- action.* + DELETE FROM action.circulation WHERE usr = src_usr; + UPDATE action.circulation SET circ_staff = dest_usr WHERE circ_staff = src_usr; + UPDATE action.circulation SET checkin_staff = dest_usr WHERE checkin_staff = src_usr; + UPDATE action.hold_notification SET notify_staff = dest_usr WHERE notify_staff = src_usr; + UPDATE action.hold_request SET fulfillment_staff = dest_usr WHERE fulfillment_staff = src_usr; + UPDATE action.hold_request SET requestor = dest_usr WHERE requestor = src_usr; + DELETE FROM action.hold_request WHERE usr = src_usr; + UPDATE action.in_house_use SET staff = dest_usr WHERE staff = src_usr; + UPDATE action.non_cat_in_house_use SET staff = dest_usr WHERE staff = src_usr; + DELETE FROM action.non_cataloged_circulation WHERE patron = src_usr; + UPDATE action.non_cataloged_circulation SET staff = dest_usr WHERE staff = src_usr; + DELETE FROM action.survey_response WHERE usr = src_usr; + UPDATE action.fieldset SET owner = dest_usr WHERE owner = src_usr; + DELETE FROM action.usr_circ_history WHERE usr = src_usr; + + -- actor.* + DELETE FROM actor.card WHERE usr = src_usr; + DELETE FROM actor.stat_cat_entry_usr_map WHERE target_usr = src_usr; + DELETE FROM actor.usr_privacy_waiver WHERE usr = src_usr; + + -- The following update is intended to avoid transient violations of a foreign + -- key constraint, whereby actor.usr_address references itself. It may not be + -- necessary, but it does no harm. + UPDATE actor.usr_address SET replaces = NULL + WHERE usr = src_usr AND replaces IS NOT NULL; + DELETE FROM actor.usr_address WHERE usr = src_usr; + DELETE FROM actor.usr_note WHERE usr = src_usr; + UPDATE actor.usr_note SET creator = dest_usr WHERE creator = src_usr; + DELETE FROM actor.usr_org_unit_opt_in WHERE usr = src_usr; + UPDATE actor.usr_org_unit_opt_in SET staff = dest_usr WHERE staff = src_usr; + DELETE FROM actor.usr_setting WHERE usr = src_usr; + DELETE FROM actor.usr_standing_penalty WHERE usr = src_usr; + UPDATE actor.usr_standing_penalty SET staff = dest_usr WHERE staff = src_usr; + + -- asset.* + UPDATE asset.call_number SET creator = dest_usr WHERE creator = src_usr; + UPDATE asset.call_number SET editor = dest_usr WHERE editor = src_usr; + UPDATE asset.call_number_note SET creator = dest_usr WHERE creator = src_usr; + UPDATE asset.copy SET creator = dest_usr WHERE creator = src_usr; + UPDATE asset.copy SET editor = dest_usr WHERE editor = src_usr; + UPDATE asset.copy_note SET creator = dest_usr WHERE creator = src_usr; + + -- auditor.* + DELETE FROM auditor.actor_usr_address_history WHERE id = src_usr; + DELETE FROM auditor.actor_usr_history WHERE id = src_usr; + UPDATE auditor.asset_call_number_history SET creator = dest_usr WHERE creator = src_usr; + UPDATE auditor.asset_call_number_history SET editor = dest_usr WHERE editor = src_usr; + UPDATE auditor.asset_copy_history SET creator = dest_usr WHERE creator = src_usr; + UPDATE auditor.asset_copy_history SET editor = dest_usr WHERE editor = src_usr; + UPDATE auditor.biblio_record_entry_history SET creator = dest_usr WHERE creator = src_usr; + UPDATE auditor.biblio_record_entry_history SET editor = dest_usr WHERE editor = src_usr; + + -- biblio.* + UPDATE biblio.record_entry SET creator = dest_usr WHERE creator = src_usr; + UPDATE biblio.record_entry SET editor = dest_usr WHERE editor = src_usr; + UPDATE biblio.record_note SET creator = dest_usr WHERE creator = src_usr; + UPDATE biblio.record_note SET editor = dest_usr WHERE editor = src_usr; + + -- container.* + -- Update buckets with a rename to avoid collisions + FOR renamable_row in + SELECT id, name + FROM container.biblio_record_entry_bucket + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE container.biblio_record_entry_bucket + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + FOR renamable_row in + SELECT id, name + FROM container.call_number_bucket + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE container.call_number_bucket + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + FOR renamable_row in + SELECT id, name + FROM container.copy_bucket + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE container.copy_bucket + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + FOR renamable_row in + SELECT id, name + FROM container.user_bucket + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE container.user_bucket + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + DELETE FROM container.user_bucket_item WHERE target_user = src_usr; + + -- money.* + DELETE FROM money.billable_xact WHERE usr = src_usr; + DELETE FROM money.collections_tracker WHERE usr = src_usr; + UPDATE money.collections_tracker SET collector = dest_usr WHERE collector = src_usr; + + -- permission.* + DELETE FROM permission.usr_grp_map WHERE usr = src_usr; + DELETE FROM permission.usr_object_perm_map WHERE usr = src_usr; + DELETE FROM permission.usr_perm_map WHERE usr = src_usr; + DELETE FROM permission.usr_work_ou_map WHERE usr = src_usr; + + -- reporter.* + -- Update with a rename to avoid collisions + BEGIN + FOR renamable_row in + SELECT id, name + FROM reporter.output_folder + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE reporter.output_folder + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + BEGIN + UPDATE reporter.report SET owner = dest_usr WHERE owner = src_usr; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + -- Update with a rename to avoid collisions + BEGIN + FOR renamable_row in + SELECT id, name + FROM reporter.report_folder + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE reporter.report_folder + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + BEGIN + UPDATE reporter.schedule SET runner = dest_usr WHERE runner = src_usr; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + BEGIN + UPDATE reporter.template SET owner = dest_usr WHERE owner = src_usr; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + -- Update with a rename to avoid collisions + BEGIN + FOR renamable_row in + SELECT id, name + FROM reporter.template_folder + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE reporter.template_folder + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + EXCEPTION WHEN undefined_table THEN + -- do nothing + END; + + -- vandelay.* + -- Update with a rename to avoid collisions + FOR renamable_row in + SELECT id, name + FROM vandelay.queue + WHERE owner = src_usr + LOOP + suffix := ' (' || src_usr || ')'; + LOOP + BEGIN + UPDATE vandelay.queue + SET owner = dest_usr, name = name || suffix + WHERE id = renamable_row.id; + EXCEPTION WHEN unique_violation THEN + suffix := suffix || ' '; + CONTINUE; + END; + EXIT; + END LOOP; + END LOOP; + + UPDATE vandelay.session_tracker SET usr = dest_usr WHERE usr = src_usr; + + -- NULL-ify addresses last so other cleanup (e.g. circ anonymization) + -- can access the information before deletion. + UPDATE actor.usr SET + active = FALSE, + card = NULL, + mailing_address = NULL, + billing_address = NULL + WHERE id = src_usr; + +END; +$$ LANGUAGE plpgsql; + +COMMIT; diff --git a/Open-ILS/src/sql/Pg/upgrade/1293.schema.item_triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/1293.schema.item_triggered_event_log.sql new file mode 100644 index 0000000000..79d4049285 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1293.schema.item_triggered_event_log.sql @@ -0,0 +1,85 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1293', :eg_version); + +INSERT INTO config.workstation_setting_type + (name, grp, datatype, label) +VALUES ( + 'eg.grid.item.event_grid', 'gui', 'object', + oils_i18n_gettext( + 'eg.grid.item.event_grid', + 'Grid Config: item.event_grid', + 'cwst', 'label') +), ( + 'eg.grid.patron.event_grid', 'gui', 'object', + oils_i18n_gettext( + 'eg.grid.patron.event_grid', + 'Grid Config: patron.event_grid', + 'cwst', 'label') +); + +DROP TRIGGER IF EXISTS action_trigger_event_context_item_trig ON action_trigger.event; + +-- Create a NULLABLE version of the fake-copy-fkey trigger function. +CREATE OR REPLACE FUNCTION evergreen.fake_fkey_tgr () RETURNS TRIGGER AS $F$ +DECLARE + copy_id BIGINT; +BEGIN + EXECUTE 'SELECT ($1).' || quote_ident(TG_ARGV[0]) INTO copy_id USING NEW; + IF copy_id IS NOT NULL THEN + PERFORM * FROM asset.copy WHERE id = copy_id; + IF NOT FOUND THEN + RAISE EXCEPTION 'Key (%.%=%) does not exist in asset.copy', TG_TABLE_SCHEMA, TG_TABLE_NAME, copy_id; + END IF; + END IF; + RETURN NULL; +END; +$F$ LANGUAGE PLPGSQL; + + +-- context_item_path TEXT, -- for optimizing action_trigger.event +ALTER TABLE action_trigger.event_definition ADD COLUMN context_item_path TEXT; + +-- context_item BIGINT REFERENCES asset.copy (id) +ALTER TABLE action_trigger.event ADD COLUMN context_item BIGINT; +CREATE INDEX atev_context_item ON action_trigger.event (context_item); + +UPDATE + action_trigger.event_definition +SET + context_item_path = 'target_copy' +WHERE + hook IN ( + SELECT key FROM action_trigger.hook WHERE core_type = 'circ' + ) +; + +UPDATE + action_trigger.event_definition +SET + context_item_path = 'current_copy' +WHERE + hook IN ( + SELECT key FROM action_trigger.hook WHERE core_type = 'ahr' + ) +; + +-- Retroactively setting context_item on existing rows in action_trigger.event: +-- This is not done by default because it'll likely take a long time depending on the Evergreen +-- installation. You may want to do this out-of-band with the upgrade if you want to do this at all. +-- +-- \pset format unaligned +-- \t +-- \o update_action_trigger_events_for_circs.sql +-- SELECT 'UPDATE action_trigger.event e SET context_item = c.target_copy FROM action.circulation c WHERE c.id = e.target AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.circulation c WHERE e.target = c.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ')) ORDER BY e.id DESC; +-- \o +-- \o update_action_trigger_events_for_holds.sql +-- SELECT 'UPDATE action_trigger.event e SET context_item = h.current_copy FROM action.hold_request h WHERE h.id = e.target AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.hold_request h WHERE e.target = h.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'ahr')) ORDER BY e.id DESC; +-- \o + +COMMIT; + +CREATE TRIGGER action_trigger_event_context_item_trig + AFTER INSERT OR UPDATE ON action_trigger.event + FOR EACH ROW EXECUTE PROCEDURE evergreen.fake_fkey_tgr('context_item'); + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.triggered_event_log.sql deleted file mode 100644 index 203a6b3fd5..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.triggered_event_log.sql +++ /dev/null @@ -1,59 +0,0 @@ -BEGIN; - -SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); - --- context_usr_path TEXT, -- for optimizing action_trigger.event --- context_library_path TEXT, -- ''' --- context_bib_path TEXT, -- ''' -ALTER TABLE action_trigger.event_definition ADD COLUMN context_usr_path TEXT; -ALTER TABLE action_trigger.event_definition ADD COLUMN context_library_path TEXT; -ALTER TABLE action_trigger.event_definition ADD COLUMN context_bib_path TEXT; - --- context_user INT REFERENCES actor.usr (id), --- context_library INT REFERENCES actor.org_unit (id), --- context_bib BIGINT REFERENCES biblio.record_entry (id) -ALTER TABLE action_trigger.event ADD COLUMN context_user INT REFERENCES actor.usr (id); -ALTER TABLE action_trigger.event ADD COLUMN context_library INT REFERENCES actor.org_unit (id); -ALTER TABLE action_trigger.event ADD COLUMN context_bib BIGINT REFERENCES biblio.record_entry (id); -CREATE INDEX atev_context_user ON action_trigger.event (context_user); -CREATE INDEX atev_context_library ON action_trigger.event (context_library); - -UPDATE - action_trigger.event_definition -SET - context_usr_path = 'usr', - context_library_path = 'circ_lib', - context_bib_path = 'target_copy.call_number.record' -WHERE - hook IN ( - SELECT key FROM action_trigger.hook WHERE core_type = 'circ' - ) -; - -UPDATE - action_trigger.event_definition -SET - context_usr_path = 'usr', - context_library_path = 'pickup_lib', - context_bib_path = 'bib_rec' -WHERE - hook IN ( - SELECT key FROM action_trigger.hook WHERE core_type = 'ahr' - ) -; - --- Retroactively setting context_user and context_library on existing rows in action_trigger.event: --- This is not done by default because it'll likely take a long time depending on the Evergreen --- installation. You may want to do this out-of-band with the upgrade if you want to do this at all. --- --- \pset format unaligned --- \t --- \o update_action_trigger_events_for_circs.sql --- SELECT 'UPDATE action_trigger.event e SET context_user = c.usr, context_library = c.circ_lib, context_bib = cn.record FROM action.circulation c, asset.copy i, asset.call_number cn WHERE c.id = e.target AND c.target_copy = i.id AND i.call_number = cn.id AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.circulation c WHERE e.target = c.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ')) ORDER BY e.id DESC; --- \o --- \o update_action_trigger_events_for_holds.sql --- SELECT 'UPDATE action_trigger.event e SET context_user = h.usr, context_library = h.pickup_lib, context_bib = r.bib_record FROM action.hold_request h, reporter.hold_request_record r WHERE h.id = e.target AND h.id = r.id AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.hold_request h WHERE e.target = h.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'ahr')) ORDER BY e.id DESC; --- \o - -COMMIT; - diff --git a/Open-ILS/src/sql/Pg/upgrade/YYYY.functions.triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/YYYY.functions.triggered_event_log.sql deleted file mode 100644 index 987fe255d4..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/YYYY.functions.triggered_event_log.sql +++ /dev/null @@ -1,407 +0,0 @@ -BEGIN; - -SELECT evergreen.upgrade_deps_block_check('YYYY', :eg_version); - -CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$ -DECLARE -found char := 'N'; -BEGIN - - -- If there are any renewals for this circulation, don't archive or delete - -- it yet. We'll do so later, when we archive and delete the renewals. - - SELECT 'Y' INTO found - FROM action.circulation - WHERE parent_circ = OLD.id - LIMIT 1; - - IF found = 'Y' THEN - RETURN NULL; -- don't delete - END IF; - - -- Archive a copy of the old row to action.aged_circulation - - INSERT INTO action.aged_circulation - (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, - auto_renewal, auto_renewal_remaining) - 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, - auto_renewal, auto_renewal_remaining - FROM action.all_circulation WHERE id = OLD.id; - - -- Migrate billings and payments to aged tables - - SELECT 'Y' INTO found FROM config.global_flag - WHERE name = 'history.money.age_with_circs' AND enabled; - - IF found = 'Y' THEN - PERFORM money.age_billings_and_payments_for_xact(OLD.id); - END IF; - - -- Break the link with the user in action_trigger.event (warning: event_output may essentially have this information) - UPDATE - action_trigger.event e - SET - context_user = NULL - FROM - action.all_circulation c - WHERE - c.id = OLD.id - AND e.context_user = c.usr - AND e.target = c.id - AND e.event_def IN ( - SELECT id - FROM action_trigger.event_definition - WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ') - ) - ; - - RETURN OLD; -END; -$$ LANGUAGE 'plpgsql'; - -CREATE OR REPLACE FUNCTION actor.usr_purge_data( - src_usr IN INTEGER, - specified_dest_usr IN INTEGER -) RETURNS VOID AS $$ -DECLARE - suffix TEXT; - renamable_row RECORD; - dest_usr INTEGER; -BEGIN - - IF specified_dest_usr IS NULL THEN - dest_usr := 1; -- Admin user on stock installs - ELSE - dest_usr := specified_dest_usr; - END IF; - - -- action_trigger.event (even doing this, event_output may--and probably does--contain PII and should have a retention/removal policy) - UPDATE action_trigger.event SET context_user = dest_usr WHERE context_user = src_usr; - - -- acq.* - UPDATE acq.fund_allocation SET allocator = dest_usr WHERE allocator = src_usr; - UPDATE acq.lineitem SET creator = dest_usr WHERE creator = src_usr; - UPDATE acq.lineitem SET editor = dest_usr WHERE editor = src_usr; - UPDATE acq.lineitem SET selector = dest_usr WHERE selector = src_usr; - UPDATE acq.lineitem_note SET creator = dest_usr WHERE creator = src_usr; - UPDATE acq.lineitem_note SET editor = dest_usr WHERE editor = src_usr; - UPDATE acq.invoice SET closed_by = dest_usr WHERE closed_by = src_usr; - DELETE FROM acq.lineitem_usr_attr_definition WHERE usr = src_usr; - - -- Update with a rename to avoid collisions - FOR renamable_row in - SELECT id, name - FROM acq.picklist - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE acq.picklist - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - UPDATE acq.picklist SET creator = dest_usr WHERE creator = src_usr; - UPDATE acq.picklist SET editor = dest_usr WHERE editor = src_usr; - UPDATE acq.po_note SET creator = dest_usr WHERE creator = src_usr; - UPDATE acq.po_note SET editor = dest_usr WHERE editor = src_usr; - UPDATE acq.purchase_order SET owner = dest_usr WHERE owner = src_usr; - UPDATE acq.purchase_order SET creator = dest_usr WHERE creator = src_usr; - UPDATE acq.purchase_order SET editor = dest_usr WHERE editor = src_usr; - UPDATE acq.claim_event SET creator = dest_usr WHERE creator = src_usr; - - -- action.* - DELETE FROM action.circulation WHERE usr = src_usr; - UPDATE action.circulation SET circ_staff = dest_usr WHERE circ_staff = src_usr; - UPDATE action.circulation SET checkin_staff = dest_usr WHERE checkin_staff = src_usr; - UPDATE action.hold_notification SET notify_staff = dest_usr WHERE notify_staff = src_usr; - UPDATE action.hold_request SET fulfillment_staff = dest_usr WHERE fulfillment_staff = src_usr; - UPDATE action.hold_request SET requestor = dest_usr WHERE requestor = src_usr; - DELETE FROM action.hold_request WHERE usr = src_usr; - UPDATE action.in_house_use SET staff = dest_usr WHERE staff = src_usr; - UPDATE action.non_cat_in_house_use SET staff = dest_usr WHERE staff = src_usr; - DELETE FROM action.non_cataloged_circulation WHERE patron = src_usr; - UPDATE action.non_cataloged_circulation SET staff = dest_usr WHERE staff = src_usr; - DELETE FROM action.survey_response WHERE usr = src_usr; - UPDATE action.fieldset SET owner = dest_usr WHERE owner = src_usr; - DELETE FROM action.usr_circ_history WHERE usr = src_usr; - - -- actor.* - DELETE FROM actor.card WHERE usr = src_usr; - DELETE FROM actor.stat_cat_entry_usr_map WHERE target_usr = src_usr; - DELETE FROM actor.usr_privacy_waiver WHERE usr = src_usr; - - -- The following update is intended to avoid transient violations of a foreign - -- key constraint, whereby actor.usr_address references itself. It may not be - -- necessary, but it does no harm. - UPDATE actor.usr_address SET replaces = NULL - WHERE usr = src_usr AND replaces IS NOT NULL; - DELETE FROM actor.usr_address WHERE usr = src_usr; - DELETE FROM actor.usr_note WHERE usr = src_usr; - UPDATE actor.usr_note SET creator = dest_usr WHERE creator = src_usr; - DELETE FROM actor.usr_org_unit_opt_in WHERE usr = src_usr; - UPDATE actor.usr_org_unit_opt_in SET staff = dest_usr WHERE staff = src_usr; - DELETE FROM actor.usr_setting WHERE usr = src_usr; - DELETE FROM actor.usr_standing_penalty WHERE usr = src_usr; - UPDATE actor.usr_standing_penalty SET staff = dest_usr WHERE staff = src_usr; - - -- asset.* - UPDATE asset.call_number SET creator = dest_usr WHERE creator = src_usr; - UPDATE asset.call_number SET editor = dest_usr WHERE editor = src_usr; - UPDATE asset.call_number_note SET creator = dest_usr WHERE creator = src_usr; - UPDATE asset.copy SET creator = dest_usr WHERE creator = src_usr; - UPDATE asset.copy SET editor = dest_usr WHERE editor = src_usr; - UPDATE asset.copy_note SET creator = dest_usr WHERE creator = src_usr; - - -- auditor.* - DELETE FROM auditor.actor_usr_address_history WHERE id = src_usr; - DELETE FROM auditor.actor_usr_history WHERE id = src_usr; - UPDATE auditor.asset_call_number_history SET creator = dest_usr WHERE creator = src_usr; - UPDATE auditor.asset_call_number_history SET editor = dest_usr WHERE editor = src_usr; - UPDATE auditor.asset_copy_history SET creator = dest_usr WHERE creator = src_usr; - UPDATE auditor.asset_copy_history SET editor = dest_usr WHERE editor = src_usr; - UPDATE auditor.biblio_record_entry_history SET creator = dest_usr WHERE creator = src_usr; - UPDATE auditor.biblio_record_entry_history SET editor = dest_usr WHERE editor = src_usr; - - -- biblio.* - UPDATE biblio.record_entry SET creator = dest_usr WHERE creator = src_usr; - UPDATE biblio.record_entry SET editor = dest_usr WHERE editor = src_usr; - UPDATE biblio.record_note SET creator = dest_usr WHERE creator = src_usr; - UPDATE biblio.record_note SET editor = dest_usr WHERE editor = src_usr; - - -- container.* - -- Update buckets with a rename to avoid collisions - FOR renamable_row in - SELECT id, name - FROM container.biblio_record_entry_bucket - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE container.biblio_record_entry_bucket - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - FOR renamable_row in - SELECT id, name - FROM container.call_number_bucket - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE container.call_number_bucket - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - FOR renamable_row in - SELECT id, name - FROM container.copy_bucket - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE container.copy_bucket - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - FOR renamable_row in - SELECT id, name - FROM container.user_bucket - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE container.user_bucket - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - DELETE FROM container.user_bucket_item WHERE target_user = src_usr; - - -- money.* - DELETE FROM money.billable_xact WHERE usr = src_usr; - DELETE FROM money.collections_tracker WHERE usr = src_usr; - UPDATE money.collections_tracker SET collector = dest_usr WHERE collector = src_usr; - - -- permission.* - DELETE FROM permission.usr_grp_map WHERE usr = src_usr; - DELETE FROM permission.usr_object_perm_map WHERE usr = src_usr; - DELETE FROM permission.usr_perm_map WHERE usr = src_usr; - DELETE FROM permission.usr_work_ou_map WHERE usr = src_usr; - - -- reporter.* - -- Update with a rename to avoid collisions - BEGIN - FOR renamable_row in - SELECT id, name - FROM reporter.output_folder - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE reporter.output_folder - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - BEGIN - UPDATE reporter.report SET owner = dest_usr WHERE owner = src_usr; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - -- Update with a rename to avoid collisions - BEGIN - FOR renamable_row in - SELECT id, name - FROM reporter.report_folder - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE reporter.report_folder - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - BEGIN - UPDATE reporter.schedule SET runner = dest_usr WHERE runner = src_usr; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - BEGIN - UPDATE reporter.template SET owner = dest_usr WHERE owner = src_usr; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - -- Update with a rename to avoid collisions - BEGIN - FOR renamable_row in - SELECT id, name - FROM reporter.template_folder - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE reporter.template_folder - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - EXCEPTION WHEN undefined_table THEN - -- do nothing - END; - - -- vandelay.* - -- Update with a rename to avoid collisions - FOR renamable_row in - SELECT id, name - FROM vandelay.queue - WHERE owner = src_usr - LOOP - suffix := ' (' || src_usr || ')'; - LOOP - BEGIN - UPDATE vandelay.queue - SET owner = dest_usr, name = name || suffix - WHERE id = renamable_row.id; - EXCEPTION WHEN unique_violation THEN - suffix := suffix || ' '; - CONTINUE; - END; - EXIT; - END LOOP; - END LOOP; - - UPDATE vandelay.session_tracker SET usr = dest_usr WHERE usr = src_usr; - - -- NULL-ify addresses last so other cleanup (e.g. circ anonymization) - -- can access the information before deletion. - UPDATE actor.usr SET - active = FALSE, - card = NULL, - mailing_address = NULL, - billing_address = NULL - WHERE id = src_usr; - -END; -$$ LANGUAGE plpgsql; - -COMMIT; diff --git a/Open-ILS/src/sql/Pg/upgrade/ZZZZ.schema.item_triggered_event_log.sql b/Open-ILS/src/sql/Pg/upgrade/ZZZZ.schema.item_triggered_event_log.sql deleted file mode 100644 index 57882a373a..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/ZZZZ.schema.item_triggered_event_log.sql +++ /dev/null @@ -1,85 +0,0 @@ -BEGIN; - -SELECT evergreen.upgrade_deps_block_check('ZZZZ', :eg_version); - -INSERT INTO config.workstation_setting_type - (name, grp, datatype, label) -VALUES ( - 'eg.grid.item.event_grid', 'gui', 'object', - oils_i18n_gettext( - 'eg.grid.item.event_grid', - 'Grid Config: item.event_grid', - 'cwst', 'label') -), ( - 'eg.grid.patron.event_grid', 'gui', 'object', - oils_i18n_gettext( - 'eg.grid.patron.event_grid', - 'Grid Config: patron.event_grid', - 'cwst', 'label') -); - -DROP TRIGGER IF EXISTS action_trigger_event_context_item_trig ON action_trigger.event; - --- Create a NULLABLE version of the fake-copy-fkey trigger function. -CREATE OR REPLACE FUNCTION evergreen.fake_fkey_tgr () RETURNS TRIGGER AS $F$ -DECLARE - copy_id BIGINT; -BEGIN - EXECUTE 'SELECT ($1).' || quote_ident(TG_ARGV[0]) INTO copy_id USING NEW; - IF copy_id IS NOT NULL THEN - PERFORM * FROM asset.copy WHERE id = copy_id; - IF NOT FOUND THEN - RAISE EXCEPTION 'Key (%.%=%) does not exist in asset.copy', TG_TABLE_SCHEMA, TG_TABLE_NAME, copy_id; - END IF; - END IF; - RETURN NULL; -END; -$F$ LANGUAGE PLPGSQL; - - --- context_item_path TEXT, -- for optimizing action_trigger.event -ALTER TABLE action_trigger.event_definition ADD COLUMN context_item_path TEXT; - --- context_item BIGINT REFERENCES asset.copy (id) -ALTER TABLE action_trigger.event ADD COLUMN context_item BIGINT; -CREATE INDEX atev_context_item ON action_trigger.event (context_item); - -UPDATE - action_trigger.event_definition -SET - context_item_path = 'target_copy' -WHERE - hook IN ( - SELECT key FROM action_trigger.hook WHERE core_type = 'circ' - ) -; - -UPDATE - action_trigger.event_definition -SET - context_item_path = 'current_copy' -WHERE - hook IN ( - SELECT key FROM action_trigger.hook WHERE core_type = 'ahr' - ) -; - --- Retroactively setting context_item on existing rows in action_trigger.event: --- This is not done by default because it'll likely take a long time depending on the Evergreen --- installation. You may want to do this out-of-band with the upgrade if you want to do this at all. --- --- \pset format unaligned --- \t --- \o update_action_trigger_events_for_circs.sql --- SELECT 'UPDATE action_trigger.event e SET context_item = c.target_copy FROM action.circulation cWHERE c.id = e.target AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.circulation c WHERE e.target = c.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'circ')) ORDER BY e.id DESC; --- \o --- \o update_action_trigger_events_for_holds.sql --- SELECT 'UPDATE action_trigger.event e SET context_item = h.current_copy FROM action.hold_request h WHERE h.id = e.target AND e.id = ' || e.id || ' RETURNING ' || e.id || ';' FROM action_trigger.event e, action.hold_request h WHERE e.target = h.id AND e.event_def IN (SELECT id FROM action_trigger.event_definition WHERE hook in (SELECT key FROM action_trigger.hook WHERE core_type = 'ahr')) ORDER BY e.id DESC; --- \o - -COMMIT; - -CREATE TRIGGER action_trigger_event_context_item_trig - AFTER INSERT OR UPDATE ON action_trigger.event - FOR EACH ROW EXECUTE PROCEDURE evergreen.fake_fkey_tgr('context_item'); -