X-Git-Url: http://git.equinoxoli.org/?p=migration-tools.git;a=blobdiff_plain;f=sql%2Fbase%2Fbase.sql;h=59b67388ad4bf2610517246393ed968ba8d66d02;hp=e734e45f889ca8fe6650fc0ce08ed52af28a5f46;hb=97d3c06d4fe2a6050868121a55f14ff4d5298226;hpb=83485be24771e35a5f4130b3b330eadca8facb61 diff --git a/sql/base/base.sql b/sql/base/base.sql index e734e45..59b6738 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -2751,6 +2751,7 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_shelf (TEXT,TEXT,TEXT,INTEGER) || ' SET x_shelf = id FROM asset_copy_location b' || ' WHERE BTRIM(UPPER(a.desired_shelf)) = BTRIM(UPPER(b.name))' || ' AND b.owning_lib = $1' + || ' AND NOT b.deleted' USING org; FOREACH o IN ARRAY org_list LOOP @@ -2758,6 +2759,7 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_shelf (TEXT,TEXT,TEXT,INTEGER) || ' SET x_shelf = id FROM asset.copy_location b' || ' WHERE BTRIM(UPPER(a.desired_shelf)) = BTRIM(UPPER(b.name))' || ' AND b.owning_lib = $1 AND x_shelf IS NULL' + || ' AND NOT b.deleted' USING o; END LOOP; @@ -2819,6 +2821,45 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_circmod (TEXT,TEXT) RETURNS VO END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- convenience functions for handling item status maps + +CREATE OR REPLACE FUNCTION migration_tools.handle_status (TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = ''desired_status'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_status'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_status'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_status INTEGER'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_status = id FROM config.copy_status b' + || ' WHERE BTRIM(UPPER(a.desired_status)) = BTRIM(UPPER(b.name))'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_status <> '''' AND x_status IS NULL), + ''Cannot find a desired copy status'', + ''Found all desired copy statuses'' + );'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + -- convenience function for handling desired_not_migrate CREATE OR REPLACE FUNCTION migration_tools.handle_not_migrate (TEXT,TEXT) RETURNS VOID AS $$ @@ -3108,3 +3149,365 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_actor_sc_and_sce (TEXT,TEXT,TE END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- convenience functions for adding shelving locations +DROP FUNCTION IF EXISTS migration_tools.find_shelf(INT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.find_shelf(org_id INT, shelf_name TEXT) RETURNS INTEGER AS $$ +DECLARE + return_id INT; + d INT; + cur_id INT; +BEGIN + SELECT INTO d MAX(distance) FROM actor.org_unit_ancestors_distance(org_id); + WHILE d >= 0 + LOOP + SELECT INTO cur_id id FROM actor.org_unit_ancestor_at_depth(org_id,d); + SELECT INTO return_id id FROM asset.copy_location WHERE owning_lib = cur_id AND name ILIKE shelf_name; + IF return_id IS NOT NULL THEN + RETURN return_id; + END IF; + d := d - 1; + END LOOP; + + RETURN NULL; +END +$$ LANGUAGE plpgsql; + +-- may remove later but testing using this with new migration scripts and not loading acls until go live + +DROP FUNCTION IF EXISTS migration_tools.find_mig_shelf(INT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.find_mig_shelf(org_id INT, shelf_name TEXT) RETURNS INTEGER AS $$ +DECLARE + return_id INT; + d INT; + cur_id INT; +BEGIN + SELECT INTO d MAX(distance) FROM actor.org_unit_ancestors_distance(org_id); + WHILE d >= 0 + LOOP + SELECT INTO cur_id id FROM actor.org_unit_ancestor_at_depth(org_id,d); + + SELECT INTO return_id id FROM + (SELECT * FROM asset.copy_location UNION ALL SELECT * FROM asset_copy_location) x + WHERE owning_lib = cur_id AND name ILIKE shelf_name; + IF return_id IS NOT NULL THEN + RETURN return_id; + END IF; + d := d - 1; + END LOOP; + + RETURN NULL; +END +$$ LANGUAGE plpgsql; + +-- alternate adding subfield 9 function in that it adds them to existing tags where the 856$u matches a correct value only +DROP FUNCTION IF EXISTS add_sf9(TEXT,TEXT,TEXT); +CREATE OR REPLACE FUNCTION add_sf9(marc TEXT, partial_u TEXT, new_9 TEXT) + RETURNS TEXT + LANGUAGE plperlu +AS $function$ +use strict; +use warnings; + +use MARC::Record; +use MARC::File::XML (BinaryEncoding => 'utf8'); + +binmode(STDERR, ':bytes'); +binmode(STDOUT, ':utf8'); +binmode(STDERR, ':utf8'); + +my $marc_xml = shift; +my $matching_u_text = shift; +my $new_9_to_set = shift; + +$marc_xml =~ s/(.........)./${1}a/; + +eval { + $marc_xml = MARC::Record->new_from_xml($marc_xml); +}; +if ($@) { + #elog("could not parse $bibid: $@\n"); + import MARC::File::XML (BinaryEncoding => 'utf8'); + return; +} + +my @uris = $marc_xml->field('856'); +return unless @uris; + +foreach my $field (@uris) { + my $sfu = $field->subfield('u'); + my $ind2 = $field->indicator('2'); + if (!defined $ind2) { next; } + if ($ind2 ne '0') { next; } + if (!defined $sfu) { next; } + if ($sfu =~ m/$matching_u_text/) { + $field->add_subfields( '9' => $new_9_to_set ); + last; + } +} + +return $marc_xml->as_xml_record(); + +$function$; + +DROP FUNCTION IF EXISTS add_sf9(INTEGER, TEXT, TEXT); +CREATE OR REPLACE FUNCTION add_sf9(bib_id INTEGER, target_u_text TEXT, sf9_text TEXT) + RETURNS BOOLEAN AS +$BODY$ +DECLARE + source_xml TEXT; + new_xml TEXT; + r BOOLEAN; +BEGIN + + SELECT marc FROM biblio.record_entry WHERE id = bib_id INTO source_xml; + + SELECT add_sf9(source_xml, target_u_text, sf9_text) INTO new_xml; + + r = FALSE; + + IF new_xml != source_xml THEN + UPDATE biblio.record_entry SET marc = new_xml WHERE id = bib_id; + r = TRUE; + END IF; + + RETURN r; + +END; +$BODY$ LANGUAGE plpgsql; + +-- convenience function for linking to the item staging table + +CREATE OR REPLACE FUNCTION migration_tools.handle_item_barcode (TEXT,TEXT,TEXT,TEXT,BOOLEAN) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + foreign_column_name ALIAS FOR $3; + main_column_name ALIAS FOR $4; + btrim_desired ALIAS FOR $5; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_name, foreign_column_name; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_name, foreign_column_name; + END IF; + + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = ''asset_copy_legacy'' + and column_name = $2 + )' INTO proceed USING table_schema, main_column_name; + IF NOT proceed THEN + RAISE EXCEPTION 'No %.asset_copy_legacy with column %', table_schema, main_column_name; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_item'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_item BIGINT'; + + IF btrim_desired THEN + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_item = id FROM asset_copy_legacy b' + || ' WHERE BTRIM(a.' || quote_ident(foreign_column_name) + || ') = BTRIM(b.' || quote_ident(main_column_name) || ')'; + ELSE + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_item = id FROM asset_copy_legacy b' + || ' WHERE a.' || quote_ident(foreign_column_name) + || ' = b.' || quote_ident(main_column_name); + END IF; + + --EXECUTE 'SELECT migration_tools.assert( + -- NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE ' || quote_ident(foreign_column_name) || ' <> '''' AND x_item IS NULL), + -- ''Cannot link every barcode'', + -- ''Every barcode linked'' + --);'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for linking to the user staging table + +CREATE OR REPLACE FUNCTION migration_tools.handle_user_barcode (TEXT,TEXT,TEXT,TEXT,BOOLEAN) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + foreign_column_name ALIAS FOR $3; + main_column_name ALIAS FOR $4; + btrim_desired ALIAS FOR $5; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_name, foreign_column_name; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_name, foreign_column_name; + END IF; + + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = ''actor_usr_legacy'' + and column_name = $2 + )' INTO proceed USING table_schema, main_column_name; + IF NOT proceed THEN + RAISE EXCEPTION 'No %.actor_usr_legacy with column %', table_schema, main_column_name; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_user'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_user INTEGER'; + + IF btrim_desired THEN + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_user = id FROM actor_usr_legacy b' + || ' WHERE BTRIM(a.' || quote_ident(foreign_column_name) + || ') = BTRIM(b.' || quote_ident(main_column_name) || ')'; + ELSE + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_user = id FROM actor_usr_legacy b' + || ' WHERE a.' || quote_ident(foreign_column_name) + || ' = b.' || quote_ident(main_column_name); + END IF; + + --EXECUTE 'SELECT migration_tools.assert( + -- NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE ' || quote_ident(foreign_column_name) || ' <> '''' AND x_user IS NULL), + -- ''Cannot link every barcode'', + -- ''Every barcode linked'' + --);'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for linking two tables +-- e.g. select migration_tools.handle_link(:'migschema','asset_copy','barcode','test_foo','l_barcode','x_acp_id',false); +CREATE OR REPLACE FUNCTION migration_tools.handle_link (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,BOOLEAN) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_a ALIAS FOR $2; + column_a ALIAS FOR $3; + table_b ALIAS FOR $4; + column_b ALIAS FOR $5; + column_x ALIAS FOR $6; + btrim_desired ALIAS FOR $7; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_a, column_a; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_a, column_a; + END IF; + + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_b, column_b; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_b, column_b; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' DROP COLUMN IF EXISTS ' || quote_ident(column_x); + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' ADD COLUMN ' || quote_ident(column_x) || ' BIGINT'; + + IF btrim_desired THEN + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = id FROM ' || quote_ident(table_a) || ' a' + || ' WHERE BTRIM(a.' || quote_ident(column_a) + || ') = BTRIM(b.' || quote_ident(column_b) || ')'; + ELSE + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = id FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b); + END IF; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for linking two tables, but copying column w into column x instead of "id" +-- e.g. select migration_tools.handle_link2(:'migschema','asset_copy','barcode','test_foo','l_barcode','id','x_acp_id',false); +CREATE OR REPLACE FUNCTION migration_tools.handle_link2 (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,BOOLEAN) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_a ALIAS FOR $2; + column_a ALIAS FOR $3; + table_b ALIAS FOR $4; + column_b ALIAS FOR $5; + column_w ALIAS FOR $6; + column_x ALIAS FOR $7; + btrim_desired ALIAS FOR $8; + proceed BOOLEAN; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_a, column_a; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_a, column_a; + END IF; + + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = $3 + )' INTO proceed USING table_schema, table_b, column_b; + IF NOT proceed THEN + RAISE EXCEPTION '%.% missing column %', table_schema, table_b, column_b; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' DROP COLUMN IF EXISTS ' || quote_ident(column_x); + EXECUTE 'ALTER TABLE ' + || quote_ident(table_b) + || ' ADD COLUMN ' || quote_ident(column_x) || ' TEXT'; + + IF btrim_desired THEN + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = ' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE BTRIM(a.' || quote_ident(column_a) + || ') = BTRIM(b.' || quote_ident(column_b) || ')'; + ELSE + EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = ' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b); + END IF; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE;