[open-ils-commits] r13578 - trunk/Open-ILS/src/sql/Pg (scottmk)

svn at svn.open-ils.org svn at svn.open-ils.org
Mon Jul 13 14:03:48 EDT 2009


Author: scottmk
Date: 2009-07-13 14:03:45 -0400 (Mon, 13 Jul 2009)
New Revision: 13578

Modified:
   trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
Log:
Add two functions to the actor schema:

usr_purge_data: purges rows associated with a given user, by either
deleting them or reassigning them to another user.

usr_delete: logically deletes a user; removes personally identifiable
information, and purges associated rows in other tables.


Modified: trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/999.functions.global.sql	2009-07-13 17:29:37 UTC (rev 13577)
+++ trunk/Open-ILS/src/sql/Pg/999.functions.global.sql	2009-07-13 18:03:45 UTC (rev 13578)
@@ -365,6 +365,448 @@
 
 
 
+CREATE OR REPLACE FUNCTION actor.usr_purge_data(
+	src_usr  IN INTEGER,
+	dest_usr IN INTEGER
+) RETURNS VOID AS $$
+DECLARE
+	suffix TEXT;
+	renamable_row RECORD;
+BEGIN
+
+	UPDATE actor.usr SET
+		active = FALSE,
+		card = NULL,
+		mailing_address = NULL,
+		billing_address = NULL
+	WHERE id = 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;
+	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;
+
+	-- 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;
+
+	-- actor.*
+	DELETE FROM actor.card WHERE usr = src_usr;
+	DELETE FROM actor.stat_cat_entry_usr_map WHERE target_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;
+
+	-- 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;
+
+END;
+$$ LANGUAGE plpgsql;
+
+COMMENT ON FUNCTION actor.usr_purge_data(INT, INT) IS $$
+/**
+ * Finds rows dependent on a given row in actor.usr and either deletes them
+ * or reassigns them to a different user.
+ */
+$$;
+
+
+
+CREATE OR REPLACE FUNCTION actor.usr_delete(
+	src_usr  IN INTEGER,
+	dest_usr IN INTEGER
+) RETURNS VOID AS $$
+DECLARE
+	old_profile actor.usr.profile%type;
+	old_home_ou actor.usr.home_ou%type;
+	new_profile actor.usr.profile%type;
+	new_home_ou actor.usr.home_ou%type;
+	new_name    text;
+	new_dob     actor.usr.dob%type;
+BEGIN
+	SELECT
+		id || '-PURGED-' || now(),
+		profile,
+		home_ou,
+		dob
+	INTO
+		new_name,
+		old_profile,
+		old_home_ou,
+		new_dob
+	FROM
+		actor.usr
+	WHERE
+		id = src_usr;
+	--
+	-- Quit if no such user
+	--
+	IF old_profile IS NULL THEN
+		RETURN;
+	END IF;
+	--
+	perform actor.usr_purge_data( src_usr, dest_usr );
+	--
+	-- Find the root org_unit(s).  This would be simpler if we could assume
+	-- that there is only one root.  Theoretically, someday, maybe, there
+	-- could be multiple roots, so we go to some extra trouble to get
+	-- the right ones.
+	--
+	SELECT
+		id
+	INTO
+		new_profile
+	FROM
+		actor.org_unit_ancestors( old_profile )
+	WHERE
+		parent_ou is null;
+	--
+	IF old_home_ou = old_profile THEN
+		new_home_ou := new_profile;
+	ELSE
+		SELECT
+			id
+		INTO
+			new_home_ou
+		FROM
+			actor.org_unit_ancestors( old_home_ou )
+		WHERE
+			parent_ou is null;
+	END IF;
+	--
+	-- Truncate date of birth
+	--
+	IF new_dob IS NOT NULL THEN
+		new_dob := date_trunc( 'year', new_dob );
+	END IF;
+	--
+	UPDATE
+		actor.usr
+		SET
+			card = NULL,
+			profile = new_profile,
+			usrname = new_name,
+			email = NULL,
+			passwd = random()::text,
+			standing = DEFAULT,
+			ident_type = 
+			(
+				SELECT MIN( id )
+				FROM config.identification_type
+			),
+			ident_value = NULL,
+			ident_type2 = NULL,
+			ident_value2 = NULL,
+			net_access_level = DEFAULT,
+			photo_url = NULL,
+			prefix = NULL,
+			first_given_name = new_name,
+			second_given_name = NULL,
+			family_name = new_name,
+			suffix = NULL,
+			alias = NULL,
+			day_phone = NULL,
+			evening_phone = NULL,
+			other_phone = NULL,
+			mailing_address = NULL,
+			billing_address = NULL,
+			home_ou = new_home_ou,
+			dob = new_dob,
+			active = FALSE,
+			master_account = DEFAULT, 
+			super_user = DEFAULT,
+			barred = FALSE,
+			deleted = TRUE,
+			juvenile = DEFAULT,
+			usrgroup = 0,
+			claims_returned_count = DEFAULT,
+			credit_forward_balance = DEFAULT,
+			last_xact_id = DEFAULT,
+			alert_message = NULL,
+			create_date = now(),
+			expire_date = now()
+	WHERE
+		id = src_usr;
+END;
+$$ LANGUAGE plpgsql;
+
+COMMENT ON FUNCTION actor.usr_delete(INT, INT) IS $$
+/**
+ * Logically deletes a user.  Removes personally identifiable information,
+ * and purges associated data in other tables.
+ */
+$$;
+
+
+
 CREATE OR REPLACE FUNCTION actor.approve_pending_address(pending_id INT) RETURNS BIGINT AS $$
 DECLARE
     old_id INT;



More information about the open-ils-commits mailing list