From: dbs Date: Fri, 24 Apr 2009 02:24:13 +0000 (+0000) Subject: Finally, something that works. X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=0326c0a5cb322d0c9f944b6e79e1c151fd151462;p=contrib%2FConifer.git Finally, something that works. It's ugly. Let's see if it's right. git-svn-id: svn://svn.open-ils.org/ILS-Contrib/conifer/trunk@382 6d9bc8c9-1ec2-4278-b937-99fde70a366f --- diff --git a/tools/migration-scripts/windsor_patrons.sql b/tools/migration-scripts/windsor_patrons.sql index bf26fb4ed0..3b5c455d7b 100644 --- a/tools/migration-scripts/windsor_patrons.sql +++ b/tools/migration-scripts/windsor_patrons.sql @@ -5,10 +5,10 @@ DROP TABLE staging_note; BEGIN; -CREATE TABLE staging_patron (username TEXT, profile TEXT, identity_type TEXT, password TEXT, standing INTEGER, identity_type2 TEXT, identity_value TEXT, name_prefix TEXT, first_given_name TEXT, second_given_name TEXT, family_name TEXT, name_suffix TEXT, day_phone TEXT, evening_phone TEXT, other_phone TEXT, alert_message TEXT, home_library TEXT, active BOOLEAN, barred BOOLEAN, deleted BOOLEAN, create_date DATE, expire_date DATE); -CREATE TABLE staging_patron_address (barcode TEXT, address_type TEXT, street_1 TEXT, street_2 TEXT, city TEXT, county TEXT, province TEXT, country TEXT, postal_code TEXT); -CREATE TABLE staging_barcode (barcode TEXT, old_barcode TEXT, active BOOLEAN); -CREATE TABLE staging_note (barcode TEXT, create_date TEXT, publicly_visible BOOLEAN, title TEXT, note TEXT, create_date2 TEXT); +CREATE TABLE staging_patron (idfield SERIAL NOT NULL, username TEXT, profile TEXT, identity_type TEXT, password TEXT, standing INTEGER, identity_type2 TEXT, identity_value TEXT, name_prefix TEXT, first_given_name TEXT, second_given_name TEXT, family_name TEXT, name_suffix TEXT, day_phone TEXT, evening_phone TEXT, other_phone TEXT, alert_message TEXT, home_library TEXT, active BOOLEAN, barred BOOLEAN, deleted BOOLEAN, create_date DATE, expire_date DATE); +CREATE TABLE staging_patron_address (idfield SERIAL NOT NULL, barcode TEXT, address_type TEXT, street_1 TEXT, street_2 TEXT, city TEXT, county TEXT, province TEXT, country TEXT, postal_code TEXT); +CREATE TABLE staging_barcode (idfield SERIAL NOT NULL, barcode TEXT, old_barcode TEXT, active BOOLEAN); +CREATE TABLE staging_note (idfield SERIAL NOT NULL, barcode TEXT, create_date TEXT, publicly_visible BOOLEAN, title TEXT, note TEXT, create_date2 TEXT); COPY staging_patron (username, profile, identity_type, password, standing, identity_type2, identity_value, name_prefix, first_given_name, second_given_name, family_name, name_suffix, day_phone, evening_phone, other_phone, alert_message, home_library, active, barred, deleted, create_date, expire_date) FROM '/home/dbs/conifer/windsor_patron_load_base.csv'; COPY staging_patron_address (barcode, address_type, street_1, street_2, city, county, province, country, postal_code) FROM '/home/dbs/conifer/windsor_patron_load_addresses.csv'; @@ -16,54 +16,85 @@ COPY staging_barcode (barcode, old_barcode, active) FROM '/home/dbs/conifer/wind COPY staging_note (barcode, create_date, publicly_visible, title, note, create_date2) FROM '/home/dbs/conifer/windsor_patron_load_notes.csv'; COMMIT; --- Let's find our duplicate usernames -SELECT trim(both from username), identity_value, COUNT(username) as ucount -FROM staging_patron -GROUP BY username, identity_value -HAVING COUNT(username) > 1 -ORDER BY ucount DESC; - --- Now let's find our duplicate barcodes -SELECT trim(both from username), identity_value, COUNT(identity_value) as ucount -FROM staging_patron -GROUP BY username, identity_value -HAVING COUNT(identity_value) > 1 -ORDER BY ucount DESC; - --- Get the distinct set of values for dupe usernames --- including active/barred/deleted status, just in case -SELECT DISTINCT trim(both from username), identity_value, active, barred, deleted -FROM staging_patrons -WHERE username IN ( - SELECT username - FROM staging_patrons - GROUP BY username - HAVING count(username) > 1 -); +---- Let's find our duplicate usernames +--SELECT trim(both from username), identity_value, COUNT(username) as ucount +--FROM staging_patron +--GROUP BY username, identity_value +--HAVING COUNT(username) > 1 +--ORDER BY ucount DESC; +-- +---- Now let's find our duplicate barcodes +--SELECT trim(both from username), identity_value, COUNT(identity_value) as ucount +--FROM staging_patron +--GROUP BY username, identity_value +--HAVING COUNT(identity_value) > 1 +--ORDER BY ucount DESC; +-- +---- Get the distinct set of values for dupe usernames +---- including active/barred/deleted status, just in case +--SELECT DISTINCT trim(both from username), identity_value, active, barred, deleted +--FROM staging_patron +--WHERE username IN ( +-- SELECT username +-- FROM staging_patron +-- GROUP BY username +-- HAVING count(username) > 1 +--); +-- +---- Do the barcodes for dupe usernames exist over in the staging_barcode table? +--SELECT DISTINCT TRIM(p.username) AS uname, p.identity_value, +-- CASE +-- WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE barcode = p.identity_value AND active = 't') THEN 'active new' +-- WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE old_barcode = p.identity_value AND active = 't') THEN 'active old' +-- WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE barcode = p.identity_value AND active = 'f') THEN 'inactive new' +-- WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE old_barcode = p.identity_value AND active = 'f') THEN 'inactive old' +-- ELSE 'not found' +-- END AS barcode_state +-- FROM staging_patron p +-- WHERE p.identity_value IN ( +-- SELECT DISTINCT identity_value +-- FROM staging_patron +-- WHERE username IN ( +-- SELECT username +-- FROM staging_patron +-- GROUP BY username +-- HAVING COUNT(username) > 1 +-- ) +-- ) +-- ORDER BY uname +--; +-- +-- Get rid of the username dupes in a savage manner; last one entered wins +DELETE FROM staging_patron + WHERE idfield NOT IN ( + SELECT MAX(dt.idfield) --- Do the barcodes for dupe usernames exist over in the staging_barcode table? -SELECT DISTINCT TRIM(BOTH FROM p.username) AS uname, p.identity_value, - CASE - WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE barcode = p.identity_value AND active = 't') THEN 'active new' - WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE old_barcode = p.identity_value AND active = 't') THEN 'active old' - WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE barcode = p.identity_value AND active = 'f') THEN 'inactive new' - WHEN p.identity_value IN (SELECT barcode FROM staging_barcode WHERE old_barcode = p.identity_value AND active = 'f') THEN 'inactive old' - ELSE 'not found' - END AS barcode_state - FROM staging_patron p - WHERE p.identity_value IN ( - SELECT DISTINCT identity_value - FROM staging_patrons - WHERE username IN ( - SELECT username - FROM staging_patrons - GROUP BY username - HAVING COUNT(username) > 1 - ) + FROM staging_patron dt + GROUP BY dt.username ) - ORDER BY uname ; +DELETE FROM staging_patron + WHERE idfield NOT IN ( + SELECT MAX(dt.idfield) + + FROM staging_patron dt + GROUP BY dt.identity_value + ) +; + +-- And get rid of duplicate (old) barcodes +DELETE FROM staging_barcode + WHERE idfield NOT IN ( + SELECT MAX(dt.idfield) + + FROM staging_barcode dt + GROUP BY dt.old_barcode + ) +; + +SELECT COUNT(*) FROM staging_patron; + BEGIN; INSERT INTO actor.usr (profile, usrname, passwd, standing, ident_type, ident_value, first_given_name, second_given_name, family_name, day_phone, home_ou, active, barred, deleted, alert_message, create_date, expire_date) @@ -124,7 +155,78 @@ INSERT INTO actor.usr (profile, usrname, passwd, standing, ident_type, ident_val patron.expire_date::DATE as expire_date FROM staging_patron patron; +-- Now we need to generate actor.card entries +INSERT INTO actor.card (usr, barcode, active) + SELECT au.id, au.ident_value, 't' + FROM actor.usr au + WHERE au.ident_value IS NOT NULL + AND au.ident_value NOT IN (SELECT barcode FROM actor.card) + AND au.id > 1 +; + +UPDATE actor.usr au SET card = ( + SELECT ac.id + FROM actor.card ac + WHERE ac.barcode = au.ident_value + AND au.card IS NULL + AND au.id > 1 +); + +-- Get rid of the "old" barcodes that we inserted into actor.usr +DELETE FROM staging_barcode + WHERE old_barcode IN (SELECT barcode FROM actor.card); + +INSERT INTO actor.card (usr, barcode, active) + SELECT au.id, sb.old_barcode, sb.active + FROM staging_barcode sb + INNER JOIN actor.usr au + ON (sb.barcode = au.ident_value AND au.id > 1) + WHERE sb.old_barcode IS NOT NULL + AND sb.old_barcode NOT IN (SELECT barcode FROM actor.card) +; + +UPDATE staging_patron_address + SET county = NULL + WHERE TRIM(county) = ''; + +UPDATE staging_patron_address + SET address_type = NULL + WHERE TRIM(address_type) = ''; + +INSERT INTO actor.usr_address (usr, address_type, street1, street2, city, state, county, country, post_code) + SELECT DISTINCT + ac.usr, + TRIM(sa.address_type), + TRIM(sa.street_1), + TRIM(sa.street_2), + TRIM(sa.city), + TRIM(sa.province), + TRIM(sa.county), + TRIM(sa.country), + TRIM(sa.postal_code) + FROM staging_patron_address sa + INNER JOIN actor.card ac ON (ac.barcode = sa.barcode) +; + +-- This is how we're getting this set of dates +SET DateStyle TO 'DMY'; + +INSERT INTO actor.usr_note (usr, creator, create_date, pub, title, value) + SELECT + ac.usr, + 1, -- We don't have the real creator in the staging table, so make it admin + CASE + WHEN TRIM(create_date) != '' THEN sn.create_date::DATE + ELSE '01-May-00'::DATE + END AS create_date, + sn.publicly_visible, + TRIM(sn.title), + TRIM(sn.note) + FROM staging_note sn + INNER JOIN actor.card ac ON (ac.barcode = sn.barcode) +; + --COMMIT; -ROLLBACK; +--ROLLBACK; -- vim: et:ts=4:sw=4: