X-Git-Url: http://git.equinoxoli.org/?p=migration-tools.git;a=blobdiff_plain;f=sql%2Fbase%2Fbase.sql;h=84c35f326478583da2dde0019cd47b846e3b02e3;hp=00a2424878eef89b4e451514c057ce112dcfe4fa;hb=8783c6c281d0aca08c1b88d1067d80a24a513696;hpb=ee7d8c5529b1de5141a2dacd1c8dec57703ee350 diff --git a/sql/base/base.sql b/sql/base/base.sql index 00a2424..84c35f3 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -23,7 +23,7 @@ -- SELECT migration_tools.build('foo'); -- SELECT * FROM foo.fields_requiring_mapping; -- \d foo.actor_usr --- create some incoming ILS specific staging tables, like CREATE foo.legacy_items ( l_barcode TEXT, .. ) INHERITS foo.asset_copy; +-- create some incoming ILS specific staging tables, like CREATE foo.legacy_items ( l_barcode TEXT, .. ) INHERITS (foo.asset_copy); -- Do some mapping, like UPDATE foo.legacy_items SET barcode = TRIM(BOTH ' ' FROM l_barcode); -- Then, to move into production, do: select migration_tools.insert_base_into_production('foo') @@ -117,7 +117,7 @@ CREATE OR REPLACE FUNCTION migration_tools.init (TEXT) RETURNS VOID AS $$ END; PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.config;' ); PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.config ( key TEXT UNIQUE, value TEXT);' ); - PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''production_tables'', ''asset.call_number,asset.call_number_prefix,asset.call_number_suffix,asset.copy_location,asset.copy,asset.stat_cat,asset.stat_cat_entry,asset.stat_cat_entry_copy_map,asset.copy_note,actor.usr,actor.card,actor.usr_address,actor.stat_cat,actor.stat_cat_entry,actor.stat_cat_entry_usr_map,actor.usr_note,actor.usr_standing_penalty,action.circulation,action.hold_request,action.hold_notification,action.hold_request_note,action.hold_transit_copy,action.transit_copy,money.grocery,money.billing,money.cash_payment,money.forgive_payment,acq.provider,acq.provider_address,acq.provider_note,acq.fund,acq.fund_allocation,acq.fund_tag,acq.funding_source,acq.funding_source_credit,acq.lineitem,acq.purchase_order,acq.po_item,acq.invoice,acq.invoice_item,acq.invoice_entry,acq.lineitem_detail,acq.fund_debit,acq.fund_transfer,acq.po_note,config.circ_matrix_matchpoint,config.circ_matrix_limit_set_map,config.hold_matrix_matchpoint'' );' ); + PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''production_tables'', ''asset.call_number,asset.call_number_prefix,asset.call_number_suffix,asset.copy_location,asset.copy,asset.stat_cat,asset.stat_cat_entry,asset.stat_cat_entry_copy_map,asset.copy_note,actor.usr,actor.card,actor.usr_address,actor.stat_cat,actor.stat_cat_entry,actor.stat_cat_entry_usr_map,actor.usr_note,actor.usr_standing_penalty,actor.usr_setting,action.circulation,action.hold_request,action.hold_notification,action.hold_request_note,action.hold_transit_copy,action.transit_copy,money.grocery,money.billing,money.cash_payment,money.forgive_payment,acq.provider,acq.provider_address,acq.provider_note,acq.provider_contact,acq.provider_contact_address,acq.fund,acq.fund_allocation,acq.fund_tag,acq.fund_tag_map,acq.funding_source,acq.funding_source_credit,acq.lineitem,acq.purchase_order,acq.po_item,acq.invoice,acq.invoice_item,acq.invoice_entry,acq.lineitem_detail,acq.fund_debit,acq.fund_transfer,acq.po_note,config.circ_matrix_matchpoint,config.circ_matrix_limit_set_map,config.hold_matrix_matchpoint,asset.copy_tag,asset.copy_tag_copy_map,config.copy_tag_type,serial.item,serial.item_note,serial.record_entry,biblio.record_entry'' );' ); PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''country_code'', ''USA'' );' ); PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.fields_requiring_mapping;' ); PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.fields_requiring_mapping( table_schema TEXT, table_name TEXT, column_name TEXT, data_type TEXT);' ); @@ -244,7 +244,7 @@ CREATE OR REPLACE FUNCTION migration_tools.build_specific_base_staging_table (TE BEGIN base_staging_table = REPLACE( production_table, '.', '_' ); --RAISE INFO 'In migration_tools.build_specific_base_staging_table(%,%) -> %', migration_schema, production_table, base_staging_table; - PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.' || base_staging_table || ' ( LIKE ' || production_table || ' INCLUDING DEFAULTS EXCLUDING CONSTRAINTS );' ); + PERFORM migration_tools.exec( $1, 'CREATE UNLOGGED TABLE ' || migration_schema || '.' || base_staging_table || ' ( LIKE ' || production_table || ' INCLUDING DEFAULTS EXCLUDING CONSTRAINTS );' ); PERFORM migration_tools.exec( $1, ' INSERT INTO ' || migration_schema || '.fields_requiring_mapping SELECT table_schema, table_name, column_name, data_type @@ -380,43 +380,134 @@ CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_last_first_middle_and_ prefix := 'Dr.'; temp := REGEXP_REPLACE( temp, E'DR\.\\s*', '', 'i' ); END IF; - IF temp ilike '%JR%' THEN + IF temp ilike '%JR.%' THEN suffix := 'Jr.'; - temp := REGEXP_REPLACE( temp, E'JR\.?\\s*', '', 'i' ); + temp := REGEXP_REPLACE( temp, E'JR\.\\s*', '', 'i' ); END IF; IF temp ilike '%JR,%' THEN suffix := 'Jr.'; temp := REGEXP_REPLACE( temp, E'JR,\\s*', ',', 'i' ); END IF; - IF temp ilike '%SR%' THEN + IF temp ilike '%SR.%' THEN suffix := 'Sr.'; - temp := REGEXP_REPLACE( temp, E'SR\.?\\s*', '', 'i' ); + temp := REGEXP_REPLACE( temp, E'SR\.\\s*', '', 'i' ); END IF; IF temp ilike '%SR,%' THEN suffix := 'Sr.'; temp := REGEXP_REPLACE( temp, E'SR,\\s*', ',', 'i' ); END IF; - IF temp ilike '%III%' THEN + IF temp like '%III%' THEN suffix := 'III'; - temp := REGEXP_REPLACE( temp, E'III', '', 'i' ); + temp := REGEXP_REPLACE( temp, E'III', '' ); END IF; - IF temp ilike '%II%' THEN + IF temp like '%II%' THEN suffix := 'II'; - temp := REGEXP_REPLACE( temp, E'II', '', 'i' ); + temp := REGEXP_REPLACE( temp, E'II', '' ); END IF; - IF temp ilike '%IV%' THEN + IF temp like '%IV%' THEN suffix := 'IV'; - temp := REGEXP_REPLACE( temp, E'IV', '', 'i' ); + temp := REGEXP_REPLACE( temp, E'IV', '' ); END IF; + temp := REGEXP_REPLACE( temp, '\(\)', ''); family_name := BTRIM( REGEXP_REPLACE(temp,E'^(\\S+).*$',E'\\1') ); + family_name := REGEXP_REPLACE( family_name, ',', '' ); first_given_name := CASE WHEN temp ~ E'^\\S+$' THEN 'N/A' ELSE BTRIM( REGEXP_REPLACE(temp,E'^\\S+\\s+(\\S+).*$',E'\\1') ) END; + first_given_name := REGEXP_REPLACE( first_given_name, ',', '' ); second_given_name := CASE WHEN temp ~ E'^\\S+$' THEN '' ELSE BTRIM( REGEXP_REPLACE(temp,E'^\\S+\\s+\\S+\\s*(.*)$',E'\\1') ) END; + second_given_name := REGEXP_REPLACE( second_given_name, ',', '' ); RETURN ARRAY[ family_name, prefix, first_given_name, second_given_name, suffix ]; END; $$ LANGUAGE PLPGSQL STRICT IMMUTABLE; +CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_fuller_last_first_middle_and_random_affix (TEXT) RETURNS TEXT[] AS $$ + DECLARE + full_name TEXT := $1; + temp TEXT; + family_name TEXT := ''; + first_given_name TEXT := ''; + second_given_name TEXT := ''; + suffix TEXT := ''; + prefix TEXT := ''; + BEGIN + temp := BTRIM(full_name); + -- Use values, not structure, for prefix/suffix, unless we come up with a better idea + --IF temp ~ '^\S{2,}\.' THEN + -- prefix := REGEXP_REPLACE(temp, '^(\S{2,}\.).*$','\1'); + -- temp := BTRIM(REGEXP_REPLACE(temp, '^\S{2,}\.(.*)$','\1')); + --END IF; + --IF temp ~ '\S{2,}\.$' THEN + -- suffix := REGEXP_REPLACE(temp, '^.*(\S{2,}\.)$','\1'); + -- temp := REGEXP_REPLACE(temp, '^(.*)\S{2,}\.$','\1'); + --END IF; + IF temp ilike '%MR.%' THEN + prefix := 'Mr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'MR\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%MRS.%' THEN + prefix := 'Mrs.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'MRS\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%MS.%' THEN + prefix := 'Ms.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'MS\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%DR.%' THEN + prefix := 'Dr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'DR\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%JR.%' THEN + suffix := 'Jr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'JR\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%JR,%' THEN + suffix := 'Jr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'JR,\\s*', ',', 'i' )); + END IF; + IF temp ilike '%SR.%' THEN + suffix := 'Sr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'SR\.\\s*', '', 'i' )); + END IF; + IF temp ilike '%SR,%' THEN + suffix := 'Sr.'; + temp := BTRIM(REGEXP_REPLACE( temp, E'SR,\\s*', ',', 'i' )); + END IF; + IF temp like '%III%' THEN + suffix := 'III'; + temp := BTRIM(REGEXP_REPLACE( temp, E'III', '' )); + END IF; + IF temp like '%II%' THEN + suffix := 'II'; + temp := BTRIM(REGEXP_REPLACE( temp, E'II', '' )); + END IF; + + IF temp ~ ',' THEN + family_name = BTRIM(REGEXP_REPLACE(temp,'^(.*?,).*$','\1')); + temp := BTRIM(REPLACE( temp, family_name, '' )); + family_name := REPLACE( family_name, ',', '' ); + IF temp ~ ' ' THEN + first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(.+)\s(.+)$','\1') ); + second_given_name := BTRIM( REGEXP_REPLACE(temp,'^(.+)\s(.+)$','\2') ); + ELSE + first_given_name := temp; + second_given_name := ''; + END IF; + ELSE + IF temp ~ '^\S+\s+\S+\s+\S+$' THEN + first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\1') ); + second_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\2') ); + family_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\3') ); + ELSE + first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)$','\1') ); + second_given_name := temp; + family_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)$','\2') ); + END IF; + END IF; + + RETURN ARRAY[ family_name, prefix, first_given_name, second_given_name, suffix ]; + END; +$$ LANGUAGE PLPGSQL STRICT IMMUTABLE; CREATE OR REPLACE FUNCTION migration_tools.address_parse_out_citystatezip (TEXT) RETURNS TEXT[] AS $$ DECLARE @@ -448,6 +539,90 @@ CREATE OR REPLACE FUNCTION migration_tools.address_parse_out_citystatezip (TEXT) END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- try to parse data like this: 100 MAIN ST$COVINGTON, GA 30016 +CREATE OR REPLACE FUNCTION migration_tools.parse_out_address (TEXT) RETURNS TEXT[] AS $$ + DECLARE + fullstring TEXT := $1; + address1 TEXT := ''; + address2 TEXT := ''; + scratch1 TEXT := ''; + scratch2 TEXT := ''; + city TEXT := ''; + state TEXT := ''; + zip TEXT := ''; + BEGIN + zip := CASE + WHEN fullstring ~ E'\\d\\d\\d\\d\\d' + THEN REGEXP_REPLACE( fullstring, E'^.*(\\d\\d\\d\\d\\d-?\\d*).*$', E'\\1' ) + ELSE '' + END; + fullstring := REGEXP_REPLACE( fullstring, E'^(.*)\\d\\d\\d\\d\\d-?\\d*(.*)$', E'\\1\\2'); + + IF fullstring ~ ',' THEN + state := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\2'); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\1'); + ELSE + IF fullstring ~ E'\\s+[A-Z][A-Z]\\s*$' THEN + state := REGEXP_REPLACE( fullstring, E'^.*,?\\s+([A-Z][A-Z])\\s*$', E'\\1' ); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s+[A-Z][A-Z](\\s*)$', E'\\1\\2' ); + ELSE + IF fullstring ~ E'^\\S+$' THEN + scratch1 := fullstring; + state := 'N/A'; + ELSE + state := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\2'); + scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\1'); + END IF; + END IF; + END IF; + + IF scratch1 ~ '[\$]' THEN + scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\1'); + city := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\2'); + ELSE + IF scratch1 ~ '\s' THEN + scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\1'); + city := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\2'); + ELSE + scratch2 := 'N/A'; + city := scratch1; + END IF; + END IF; + + IF scratch2 ~ '^\d' THEN + address1 := scratch2; + address2 := ''; + ELSE + address1 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\1'); + address2 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\2'); + END IF; + + RETURN ARRAY[ + TRIM(BOTH ' ' FROM address1) + ,TRIM(BOTH ' ' FROM address2) + ,TRIM(BOTH ' ' FROM city) + ,TRIM(BOTH ' ' FROM state) + ,TRIM(BOTH ' ' FROM zip) + ]; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.parse_out_address2 (TEXT) RETURNS TEXT AS $$ + my ($address) = @_; + + use Geo::StreetAddress::US; + + my $a = Geo::StreetAddress::US->parse_location($address); + + return [ + "$a->{number} $a->{prefix} $a->{street} $a->{type} $a->{suffix}" + ,"$a->{sec_unit_type} $a->{sec_unit_num}" + ,$a->{city} + ,$a->{state} + ,$a->{zip} + ]; +$$ LANGUAGE PLPERLU STABLE; + CREATE OR REPLACE FUNCTION migration_tools.rebarcode (o TEXT, t BIGINT) RETURNS TEXT AS $$ DECLARE n TEXT := o; @@ -768,6 +943,24 @@ CREATE OR REPLACE FUNCTION migration_tools.attempt_hz_date (TEXT,TEXT) RETURNS D END; $$ LANGUAGE PLPGSQL STRICT STABLE; +CREATE OR REPLACE FUNCTION migration_tools.attempt_sierra_timestamp (TEXT,TEXT) RETURNS TIMESTAMP AS $$ + DECLARE + attempt_value ALIAS FOR $1; + fail_value ALIAS FOR $2; + output TIMESTAMP; + BEGIN + output := REGEXP_REPLACE(attempt_value,E'^(..)(..)(..)(..)(..)$',E'20\\1-\\2-\\3 \\4:\\5')::TIMESTAMP; + RETURN output; + EXCEPTION + WHEN OTHERS THEN + FOR output IN + EXECUTE 'SELECT ' || quote_literal(fail_value) || '::TIMESTAMP AS a;' + LOOP + RETURN output; + END LOOP; + END; +$$ LANGUAGE PLPGSQL STRICT STABLE; + CREATE OR REPLACE FUNCTION migration_tools.attempt_money (TEXT,TEXT) RETURNS NUMERIC(8,2) AS $$ DECLARE attempt_value ALIAS FOR $1; @@ -905,6 +1098,51 @@ CREATE OR REPLACE FUNCTION migration_tools.add_code39mod43_checkdigit (TEXT) RET return $barcode . $checkdigit; $$ LANGUAGE PLPERLU STRICT STABLE; +-- add_mod16_checkdigit +-- $barcode source barcode +-- +-- https://www.activebarcode.com/codes/checkdigit/modulo16.html + +CREATE OR REPLACE FUNCTION migration_tools.add_mod16_checkdigit (TEXT) RETURNS TEXT AS $$ + my $barcode = shift; + + my @digits = split //, $barcode; + my $total = 0; + foreach $digit (@digits) { + if ($digit =~ /[0-9]/) { $total += $digit; + } elsif ($digit eq '-') { $total += 10; + } elsif ($digit eq '$') { $total += 11; + } elsif ($digit eq ':') { $total += 12; + } elsif ($digit eq '/') { $total += 13; + } elsif ($digit eq '.') { $total += 14; + } elsif ($digit eq '+') { $total += 15; + } elsif ($digit eq 'A') { $total += 16; + } elsif ($digit eq 'B') { $total += 17; + } elsif ($digit eq 'C') { $total += 18; + } elsif ($digit eq 'D') { $total += 19; + } else { die "invalid digit <$digit>"; + } + } + my $remainder = $total % 16; + my $difference = 16 - $remainder; + my $checkdigit; + if ($difference < 10) { $checkdigit = $difference; + } elsif ($difference == 10) { $checkdigit = '-'; + } elsif ($difference == 11) { $checkdigit = '$'; + } elsif ($difference == 12) { $checkdigit = ':'; + } elsif ($difference == 13) { $checkdigit = '/'; + } elsif ($difference == 14) { $checkdigit = '.'; + } elsif ($difference == 15) { $checkdigit = '+'; + } elsif ($difference == 16) { $checkdigit = 'A'; + } elsif ($difference == 17) { $checkdigit = 'B'; + } elsif ($difference == 18) { $checkdigit = 'C'; + } elsif ($difference == 19) { $checkdigit = 'D'; + } else { die "error calculating checkdigit"; + } + + return $barcode . $checkdigit; +$$ LANGUAGE PLPERLU STRICT STABLE; + CREATE OR REPLACE FUNCTION migration_tools.attempt_phone (TEXT,TEXT) RETURNS TEXT AS $$ DECLARE phone TEXT := $1; @@ -2377,6 +2615,21 @@ CREATE OR REPLACE FUNCTION migration_tools.duplicate_template_but_change_delay ( END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +CREATE OR REPLACE FUNCTION migration_tools.get_marc_leader (TEXT) RETURNS TEXT AS $$ + my ($marcxml) = @_; + + use MARC::Record; + use MARC::File::XML; + use MARC::Field; + + my $field; + eval { + my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8'); + $field = $marc->leader(); + }; + return $field; +$$ LANGUAGE PLPERLU STABLE; + CREATE OR REPLACE FUNCTION migration_tools.get_marc_tag (TEXT, TEXT, TEXT, TEXT) RETURNS TEXT AS $$ my ($marcxml, $tag, $subfield, $delimiter) = @_; @@ -2445,3 +2698,1170 @@ CREATE OR REPLACE FUNCTION migration_tools.find_circ_matrix_matchpoint (INTEGER) ) ); $$ LANGUAGE SQL; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN) RETURNS VOID AS $$ + DECLARE + test ALIAS FOR $1; + BEGIN + IF NOT test THEN + RAISE EXCEPTION 'assertion'; + END IF; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT) RETURNS VOID AS $$ + DECLARE + test ALIAS FOR $1; + msg ALIAS FOR $2; + BEGIN + IF NOT test THEN + RAISE EXCEPTION '%', msg; + END IF; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT,TEXT) RETURNS TEXT AS $$ + DECLARE + test ALIAS FOR $1; + fail_msg ALIAS FOR $2; + success_msg ALIAS FOR $3; + BEGIN + IF NOT test THEN + RAISE EXCEPTION '%', fail_msg; + END IF; + RETURN success_msg; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- push bib sequence and return starting value for reserved range +CREATE OR REPLACE FUNCTION migration_tools.push_bib_sequence(INTEGER) RETURNS BIGINT AS $$ + DECLARE + bib_count ALIAS FOR $1; + output BIGINT; + BEGIN + PERFORM setval('biblio.record_entry_id_seq',(SELECT MAX(id) FROM biblio.record_entry) + bib_count + 2000); + FOR output IN + SELECT CEIL(MAX(id)/1000)*1000+1000 FROM biblio.record_entry WHERE id < (SELECT last_value FROM biblio.record_entry_id_seq) + LOOP + RETURN output; + END LOOP; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- set a new salted password + +CREATE OR REPLACE FUNCTION migration_tools.set_salted_passwd(INTEGER,TEXT) RETURNS BOOLEAN AS $$ + DECLARE + usr_id ALIAS FOR $1; + plain_passwd ALIAS FOR $2; + plain_salt TEXT; + md5_passwd TEXT; + BEGIN + + SELECT actor.create_salt('main') INTO plain_salt; + + SELECT MD5(plain_passwd) INTO md5_passwd; + + PERFORM actor.set_passwd(usr_id, 'main', MD5(plain_salt || md5_passwd), plain_salt); + + RETURN TRUE; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + + +-- convenience functions for handling copy_location maps + +CREATE OR REPLACE FUNCTION migration_tools.handle_shelf (TEXT,TEXT,TEXT,INTEGER) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + org_shortname ALIAS FOR $3; + org_range ALIAS FOR $4; + proceed BOOLEAN; + org INTEGER; + org_list INTEGER[]; + o INTEGER; + BEGIN + EXECUTE 'SELECT EXISTS ( + SELECT 1 + FROM information_schema.columns + WHERE table_schema = $1 + AND table_name = $2 + and column_name = ''desired_shelf'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_shelf'; + END IF; + + SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname; + IF org IS NULL THEN + RAISE EXCEPTION 'Cannot find org by shortname'; + END IF; + + SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org ); + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_shelf'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_shelf INTEGER'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' 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 + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' 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; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_shelf <> '''' AND x_shelf IS NULL), + ''Cannot find a desired location'', + ''Found all desired locations'' + );'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience functions for handling circmod maps + +CREATE OR REPLACE FUNCTION migration_tools.handle_circmod (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_circmod'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_circmod'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_circmod'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_circmod TEXT'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_circmod = code FROM config.circ_modifier b' + || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.code))'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_circmod = code FROM config.circ_modifier b' + || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.name))' + || ' AND x_circmod IS NULL'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_circmod = code FROM config.circ_modifier b' + || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.description))' + || ' AND x_circmod IS NULL'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_circmod <> '''' AND x_circmod IS NULL), + ''Cannot find a desired circulation modifier'', + ''Found all desired circulation modifiers'' + );'; + + 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 functions for handling org maps + +CREATE OR REPLACE FUNCTION migration_tools.handle_org (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_org'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_org'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_org'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_org INTEGER'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_org = id FROM actor.org_unit b' + || ' WHERE BTRIM(a.desired_org) = BTRIM(b.shortname)'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_org <> '''' AND x_org IS NULL), + ''Cannot find a desired org unit'', + ''Found all desired org units'' + );'; + + 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 $$ + 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_not_migrate'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_not_migrate'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_migrate'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_migrate BOOLEAN'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_migrate = CASE' + || ' WHEN BTRIM(desired_not_migrate) = ''TRUE'' THEN FALSE' + || ' WHEN BTRIM(desired_not_migrate) = ''DNM'' THEN FALSE' + || ' WHEN BTRIM(desired_not_migrate) = ''FALSE'' THEN TRUE' + || ' WHEN BTRIM(desired_not_migrate) = ''Migrate'' THEN TRUE' + || ' WHEN BTRIM(desired_not_migrate) = '''' THEN TRUE' + || ' END'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE x_migrate IS NULL), + ''Not all desired_not_migrate values understood'', + ''All desired_not_migrate values understood'' + );'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for handling desired_profile + +CREATE OR REPLACE FUNCTION migration_tools.handle_profile (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_profile'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_profile'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_profile'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_profile INTEGER'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_profile = id FROM permission.grp_tree b' + || ' WHERE BTRIM(UPPER(a.desired_profile)) = BTRIM(UPPER(b.name))'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_profile <> '''' AND x_profile IS NULL), + ''Cannot find a desired profile'', + ''Found all desired profiles'' + );'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +-- convenience function for handling desired actor stat cats + +CREATE OR REPLACE FUNCTION migration_tools.vivicate_actor_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc. + org_shortname ALIAS FOR $4; + proceed BOOLEAN; + org INTEGER; + org_list INTEGER[]; + sc TEXT; + sce TEXT; + BEGIN + + SELECT 'desired_sc' || field_suffix INTO sc; + SELECT 'desired_sce' || field_suffix INTO sce; + + 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, sc; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sc; + 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_name, sce; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sce; + END IF; + + SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname; + IF org IS NULL THEN + RAISE EXCEPTION 'Cannot find org by shortname'; + END IF; + SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org ); + + -- caller responsible for their own truncates though we try to prevent duplicates + EXECUTE 'INSERT INTO actor_stat_cat (owner, name) + SELECT DISTINCT + $1 + ,BTRIM('||sc||') + FROM + ' || quote_ident(table_name) || ' + WHERE + NULLIF(BTRIM('||sc||'),'''') IS NOT NULL + AND NOT EXISTS ( + SELECT id + FROM actor.stat_cat + WHERE owner = ANY ($2) + AND name = BTRIM('||sc||') + ) + AND NOT EXISTS ( + SELECT id + FROM actor_stat_cat + WHERE owner = ANY ($2) + AND name = BTRIM('||sc||') + ) + ORDER BY 2;' + USING org, org_list; + + EXECUTE 'INSERT INTO actor_stat_cat_entry (stat_cat, owner, value) + SELECT DISTINCT + COALESCE( + (SELECT id + FROM actor.stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name)) + ,(SELECT id + FROM actor_stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name)) + ) + ,$1 + ,BTRIM('||sce||') + FROM + ' || quote_ident(table_name) || ' + WHERE + NULLIF(BTRIM('||sc||'),'''') IS NOT NULL + AND NULLIF(BTRIM('||sce||'),'''') IS NOT NULL + AND NOT EXISTS ( + SELECT id + FROM actor.stat_cat_entry + WHERE stat_cat = ( + SELECT id + FROM actor.stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name) + ) AND value = BTRIM('||sce||') + ) + AND NOT EXISTS ( + SELECT id + FROM actor_stat_cat_entry + WHERE stat_cat = ( + SELECT id + FROM actor_stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name) + ) AND value = BTRIM('||sce||') + ) + ORDER BY 1,3;' + USING org, org_list; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_actor_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc. + org_shortname ALIAS FOR $4; + proceed BOOLEAN; + org INTEGER; + org_list INTEGER[]; + o INTEGER; + sc TEXT; + sce TEXT; + BEGIN + SELECT 'desired_sc' || field_suffix INTO sc; + SELECT 'desired_sce' || field_suffix INTO sce; + 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, sc; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sc; + 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_name, sce; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sce; + END IF; + + SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname; + IF org IS NULL THEN + RAISE EXCEPTION 'Cannot find org by shortname'; + END IF; + + SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org ); + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_sc' || field_suffix; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_sc' || field_suffix || ' INTEGER'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_sce' || field_suffix; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_sce' || field_suffix || ' INTEGER'; + + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' + SET + x_sc' || field_suffix || ' = id + FROM + (SELECT id, name, owner FROM actor_stat_cat + UNION SELECT id, name, owner FROM actor.stat_cat) u + WHERE + BTRIM(UPPER(u.name)) = BTRIM(UPPER(' || sc || ')) + AND u.owner = ANY ($1);' + USING org_list; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' + SET + x_sce' || field_suffix || ' = id + FROM + (SELECT id, stat_cat, owner, value FROM actor_stat_cat_entry + UNION SELECT id, stat_cat, owner, value FROM actor.stat_cat_entry) u + WHERE + u.stat_cat = x_sc' || field_suffix || ' + AND BTRIM(UPPER(u.value)) = BTRIM(UPPER(' || sce || ')) + AND u.owner = ANY ($1);' + USING org_list; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sc' || field_suffix || ' <> '''' AND x_sc' || field_suffix || ' IS NULL), + ''Cannot find a desired stat cat'', + ''Found all desired stat cats'' + );'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sce' || field_suffix || ' <> '''' AND x_sce' || field_suffix || ' IS NULL), + ''Cannot find a desired stat cat entry'', + ''Found all desired stat cat entries'' + );'; + + 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 migration_tools.add_sf9(TEXT,TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.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 migration_tools.add_sf9(BIGINT, TEXT, TEXT, REGCLASS); +CREATE OR REPLACE FUNCTION migration_tools.add_sf9(bib_id BIGINT, target_u_text TEXT, sf9_text TEXT, bib_table REGCLASS) + RETURNS BOOLEAN AS +$BODY$ +DECLARE + source_xml TEXT; + new_xml TEXT; + r BOOLEAN; +BEGIN + + EXECUTE 'SELECT marc FROM ' || bib_table || ' WHERE id = ' || bib_id INTO source_xml; + + SELECT add_sf9(source_xml, target_u_text, sf9_text) INTO new_xml; + + r = FALSE; + new_xml = '$_$' || new_xml || '$_$'; + + IF new_xml != source_xml THEN + EXECUTE 'UPDATE ' || bib_table || ' 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 = b.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 = b.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 = b.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 = b.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; + +-- convenience function for handling desired asset stat cats + +CREATE OR REPLACE FUNCTION migration_tools.vivicate_asset_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc. + org_shortname ALIAS FOR $4; + proceed BOOLEAN; + org INTEGER; + org_list INTEGER[]; + sc TEXT; + sce TEXT; + BEGIN + + SELECT 'desired_sc' || field_suffix INTO sc; + SELECT 'desired_sce' || field_suffix INTO sce; + + 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, sc; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sc; + 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_name, sce; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sce; + END IF; + + SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname; + IF org IS NULL THEN + RAISE EXCEPTION 'Cannot find org by shortname'; + END IF; + SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org ); + + -- caller responsible for their own truncates though we try to prevent duplicates + EXECUTE 'INSERT INTO asset_stat_cat (owner, name) + SELECT DISTINCT + $1 + ,BTRIM('||sc||') + FROM + ' || quote_ident(table_name) || ' + WHERE + NULLIF(BTRIM('||sc||'),'''') IS NOT NULL + AND NOT EXISTS ( + SELECT id + FROM asset.stat_cat + WHERE owner = ANY ($2) + AND name = BTRIM('||sc||') + ) + AND NOT EXISTS ( + SELECT id + FROM asset_stat_cat + WHERE owner = ANY ($2) + AND name = BTRIM('||sc||') + ) + ORDER BY 2;' + USING org, org_list; + + EXECUTE 'INSERT INTO asset_stat_cat_entry (stat_cat, owner, value) + SELECT DISTINCT + COALESCE( + (SELECT id + FROM asset.stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name)) + ,(SELECT id + FROM asset_stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name)) + ) + ,$1 + ,BTRIM('||sce||') + FROM + ' || quote_ident(table_name) || ' + WHERE + NULLIF(BTRIM('||sc||'),'''') IS NOT NULL + AND NULLIF(BTRIM('||sce||'),'''') IS NOT NULL + AND NOT EXISTS ( + SELECT id + FROM asset.stat_cat_entry + WHERE stat_cat = ( + SELECT id + FROM asset.stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name) + ) AND value = BTRIM('||sce||') + ) + AND NOT EXISTS ( + SELECT id + FROM asset_stat_cat_entry + WHERE stat_cat = ( + SELECT id + FROM asset_stat_cat + WHERE owner = ANY ($2) + AND BTRIM('||sc||') = BTRIM(name) + ) AND value = BTRIM('||sce||') + ) + ORDER BY 1,3;' + USING org, org_list; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_asset_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$ + DECLARE + table_schema ALIAS FOR $1; + table_name ALIAS FOR $2; + field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc. + org_shortname ALIAS FOR $4; + proceed BOOLEAN; + org INTEGER; + org_list INTEGER[]; + o INTEGER; + sc TEXT; + sce TEXT; + BEGIN + SELECT 'desired_sc' || field_suffix INTO sc; + SELECT 'desired_sce' || field_suffix INTO sce; + 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, sc; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sc; + 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_name, sce; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column %', sce; + END IF; + + SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname; + IF org IS NULL THEN + RAISE EXCEPTION 'Cannot find org by shortname'; + END IF; + + SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org ); + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_sc' || field_suffix; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_sc' || field_suffix || ' INTEGER'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_sce' || field_suffix; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_sce' || field_suffix || ' INTEGER'; + + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' + SET + x_sc' || field_suffix || ' = id + FROM + (SELECT id, name, owner FROM asset_stat_cat + UNION SELECT id, name, owner FROM asset.stat_cat) u + WHERE + BTRIM(UPPER(u.name)) = BTRIM(UPPER(' || sc || ')) + AND u.owner = ANY ($1);' + USING org_list; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' + SET + x_sce' || field_suffix || ' = id + FROM + (SELECT id, stat_cat, owner, value FROM asset_stat_cat_entry + UNION SELECT id, stat_cat, owner, value FROM asset.stat_cat_entry) u + WHERE + u.stat_cat = x_sc' || field_suffix || ' + AND BTRIM(UPPER(u.value)) = BTRIM(UPPER(' || sce || ')) + AND u.owner = ANY ($1);' + USING org_list; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sc' || field_suffix || ' <> '''' AND x_sc' || field_suffix || ' IS NULL), + ''Cannot find a desired stat cat'', + ''Found all desired stat cats'' + );'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sce' || field_suffix || ' <> '''' AND x_sce' || field_suffix || ' IS NULL), + ''Cannot find a desired stat cat entry'', + ''Found all desired stat cat entries'' + );'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +DROP FUNCTION IF EXISTS migration_tools.btrim_lcolumns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.btrim_lcolumns(s_name TEXT, t_name TEXT) RETURNS BOOLEAN + LANGUAGE plpgsql +AS $function$ +DECLARE + c_name TEXT; +BEGIN + + FOR c_name IN SELECT column_name FROM information_schema.columns WHERE + table_name = t_name + AND table_schema = s_name + AND (data_type='text' OR data_type='character varying') + AND column_name like 'l_%' + LOOP + EXECUTE FORMAT('UPDATE ' || s_name || '.' || t_name || ' SET ' || c_name || ' = BTRIM(' || c_name || ')'); + END LOOP; + + RETURN TRUE; +END +$function$; + +DROP FUNCTION IF EXISTS migration_tools.null_empty_lcolumns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.null_empty_lcolumns(s_name TEXT, t_name TEXT) RETURNS BOOLEAN + LANGUAGE plpgsql +AS $function$ +DECLARE + c_name TEXT; +BEGIN + + FOR c_name IN SELECT column_name FROM information_schema.columns WHERE + table_name = t_name + AND table_schema = s_name + AND (data_type='text' OR data_type='character varying') + AND column_name like 'l_%' + LOOP + EXECUTE FORMAT('UPDATE ' || s_name || '.' || t_name || ' SET ' || c_name || ' = NULL WHERE ' || c_name || ' = '''' '); + END LOOP; + + RETURN TRUE; +END +$function$; +