Adding address update SQL function.
authorChris Sharp <csharp@georgialibraries.org>
Wed, 15 Oct 2014 21:28:32 +0000 (17:28 -0400)
committerChris Sharp <csharp@georgialibraries.org>
Wed, 15 Oct 2014 21:28:32 +0000 (17:28 -0400)
patron-merge-tools/update_addresses.sql [new file with mode: 0644]

diff --git a/patron-merge-tools/update_addresses.sql b/patron-merge-tools/update_addresses.sql
new file mode 100644 (file)
index 0000000..4b7264a
--- /dev/null
@@ -0,0 +1,35 @@
+-- This was used to update user addresses which were processed by Unique Management Services
+
+DO $FUNC$
+       DECLARE 
+       new_address_id INT;
+       address_data ums.address_data%ROWTYPE;
+       BEGIN
+       FOR address_data IN SELECT uad.*
+       FROM ums.address_data uad
+       WHERE uad.bad_address IS NULL
+       AND uad.street1 IS NOT NULL
+       AND uad.city IS NOT NULL
+       AND uad.postal_code IS NOT NULL
+       LOOP
+       IF (address_data.address_updated = TRUE) THEN
+       RAISE NOTICE 'Processing updated user %', address_data.usr;
+       --- set the addresses with the IDs for each changed row to invalid = true
+       UPDATE actor.usr_address SET valid = FALSE WHERE id = address_data.address_id;
+       --- insert the changed address as a new address belonging to the patron
+       INSERT INTO actor.usr_address (usr, street1, street2, city, state, post_code, county, country,replaces) VALUES (address_data.usr, address_data.street1, address_data.street2, UPPER(address_data.city), UPPER(address_data.state), address_data.postal_code, UPPER(address_data.county_name), 'USA', address_data.address_id) RETURNING id INTO new_address_id;
+       --- insert an alert message into the patron record
+       UPDATE actor.usr SET alert_message = array_to_string(array['NCOA database shows changed address - please verify - PINES Staff (', date(now())::text, '). ', alert_message], '') WHERE id = address_data.usr;
+       -- update patron accounts to use the new addresses
+       UPDATE actor.usr SET mailing_address = new_address_id WHERE mailing_address = address_data.address_id;
+       UPDATE actor.usr SET billing_address = new_address_id WHERE billing_address = address_data.address_id;
+       ELSE
+       RAISE NOTICE 'Processing non-updated usr %', address_data.usr;
+       -- overwrite the old address with the cleaned-up values from the UMS file
+       UPDATE actor.usr_address SET street1 = address_data.street1, street2 = address_data.street2, city = UPPER(address_data.city), state = UPPER(address_data.state), post_code = address_data.postal_code, county = UPPER(address_data.county_name) WHERE id = address_data.address_id;
+       -- insert a note into each patron record
+       INSERT INTO actor.usr_note (usr, creator, title, value) VALUES (address_data.usr, 1, 'Address Update', 'Address standardized during patron database cleanup.  PINES Staff (' || date(now()) || ').');
+       END IF;
+       END LOOP;
+       END;
+$FUNC$;