X-Git-Url: http://git.equinoxoli.org/?p=migration-tools.git;a=blobdiff_plain;f=sql%2Fbase%2Fbase.sql;h=b435a667347c156dab51d592a257c078054ef7aa;hp=e6dc71ff91327adb03ff1f764f11a8f881673d39;hb=da0881a95d08d653877723aad92460935cd942e6;hpb=53a11b628416da91c21ecd98f868508f54e894ee diff --git a/sql/base/base.sql b/sql/base/base.sql index e6dc71f..b435a66 100644 --- a/sql/base/base.sql +++ b/sql/base/base.sql @@ -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,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'' );' ); + 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);' ); @@ -287,6 +287,31 @@ CREATE OR REPLACE FUNCTION migration_tools.insert_into_production (TEXT,TEXT) RE END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_first_middle_last_comma_suffix (TEXT) RETURNS TEXT[] AS $$ + DECLARE + full_name TEXT := $1; + before_comma TEXT; + family_name TEXT := ''; + first_given_name TEXT := ''; + second_given_name TEXT := ''; + suffix TEXT := ''; + prefix TEXT := ''; + BEGIN + before_comma := BTRIM( REGEXP_REPLACE(full_name,E'^(.+),.+$',E'\\1') ); + suffix := CASE WHEN full_name ~ ',' THEN BTRIM( REGEXP_REPLACE(full_name,E'^.+,(.+)$',E'\\1') ) ELSE '' END; + + IF suffix = before_comma THEN + suffix := ''; + END IF; + + family_name := BTRIM( REGEXP_REPLACE(before_comma,E'^.+\\s(.+)$',E'\\1') ); + first_given_name := BTRIM( REGEXP_REPLACE(before_comma,E'^(.+?)\\s.+$',E'\\1') ); + second_given_name := BTRIM( CASE WHEN before_comma ~ '^.+\s.+\s.+$' THEN REGEXP_REPLACE(before_comma,E'^.+\\s(.+)\\s.+$',E'\\1') ELSE '' END ); + + 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_last_comma_prefix_first_middle_suffix (TEXT) RETURNS TEXT[] AS $$ DECLARE full_name TEXT := $1; @@ -607,6 +632,569 @@ CREATE OR REPLACE FUNCTION migration_tools.parse_out_address (TEXT) RETURNS TEXT 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; + +-- FIXME: there's probably a more efficient way to implement this +CREATE OR REPLACE FUNCTION migration_tools.normalize_address_suffix (TEXT) RETURNS TEXT AS $$ + DECLARE + street1 TEXT := $1; + _r RECORD; + BEGIN + DROP TABLE IF EXISTS mig_usps_suffixes; + CREATE TEMP TABLE mig_usps_suffixes ( suffix_from TEXT, suffix_to TEXT ); + INSERT INTO mig_usps_suffixes VALUES + ('ALLEE','ALY'), + ('ALLEY','ALY'), + ('ALLY','ALY'), + ('ALY','ALY'), + ('ANEX','ANX'), + ('ANNEX','ANX'), + ('ANNX','ANX'), + ('ANX','ANX'), + ('ARCADE','ARC'), + ('ARC','ARC'), + ('AV','AVE'), + ('AVE','AVE'), + ('AVEN','AVE'), + ('AVENU','AVE'), + ('AVENUE','AVE'), + ('AVN','AVE'), + ('AVNUE','AVE'), + ('BAYOO','BYU'), + ('BAYOU','BYU'), + ('BCH','BCH'), + ('BEACH','BCH'), + ('BEND','BND'), + ('BLF','BLF'), + ('BLUF','BLF'), + ('BLUFF','BLF'), + ('BLUFFS','BLFS'), + ('BLVD','BLVD'), + ('BND','BND'), + ('BOT','BTM'), + ('BOTTM','BTM'), + ('BOTTOM','BTM'), + ('BOUL','BLVD'), + ('BOULEVARD','BLVD'), + ('BOULV','BLVD'), + ('BRANCH','BR'), + ('BR','BR'), + ('BRDGE','BRG'), + ('BRG','BRG'), + ('BRIDGE','BRG'), + ('BRK','BRK'), + ('BRNCH','BR'), + ('BROOK','BRK'), + ('BROOKS','BRKS'), + ('BTM','BTM'), + ('BURG','BG'), + ('BURGS','BGS'), + ('BYPA','BYP'), + ('BYPAS','BYP'), + ('BYPASS','BYP'), + ('BYP','BYP'), + ('BYPS','BYP'), + ('CAMP','CP'), + ('CANYN','CYN'), + ('CANYON','CYN'), + ('CAPE','CPE'), + ('CAUSEWAY','CSWY'), + ('CAUSWAY','CSWY'), + ('CEN','CTR'), + ('CENT','CTR'), + ('CENTER','CTR'), + ('CENTERS','CTRS'), + ('CENTR','CTR'), + ('CENTRE','CTR'), + ('CIRC','CIR'), + ('CIR','CIR'), + ('CIRCL','CIR'), + ('CIRCLE','CIR'), + ('CIRCLES','CIRS'), + ('CK','CRK'), + ('CLB','CLB'), + ('CLF','CLF'), + ('CLFS','CLFS'), + ('CLIFF','CLF'), + ('CLIFFS','CLFS'), + ('CLUB','CLB'), + ('CMP','CP'), + ('CNTER','CTR'), + ('CNTR','CTR'), + ('CNYN','CYN'), + ('COMMON','CMN'), + ('COR','COR'), + ('CORNER','COR'), + ('CORNERS','CORS'), + ('CORS','CORS'), + ('COURSE','CRSE'), + ('COURT','CT'), + ('COURTS','CTS'), + ('COVE','CV'), + ('COVES','CVS'), + ('CP','CP'), + ('CPE','CPE'), + ('CRCL','CIR'), + ('CRCLE','CIR'), + ('CR','CRK'), + ('CRECENT','CRES'), + ('CREEK','CRK'), + ('CRESCENT','CRES'), + ('CRES','CRES'), + ('CRESENT','CRES'), + ('CREST','CRST'), + ('CRK','CRK'), + ('CROSSING','XING'), + ('CROSSROAD','XRD'), + ('CRSCNT','CRES'), + ('CRSE','CRSE'), + ('CRSENT','CRES'), + ('CRSNT','CRES'), + ('CRSSING','XING'), + ('CRSSNG','XING'), + ('CRT','CT'), + ('CSWY','CSWY'), + ('CT','CT'), + ('CTR','CTR'), + ('CTS','CTS'), + ('CURVE','CURV'), + ('CV','CV'), + ('CYN','CYN'), + ('DALE','DL'), + ('DAM','DM'), + ('DIV','DV'), + ('DIVIDE','DV'), + ('DL','DL'), + ('DM','DM'), + ('DR','DR'), + ('DRIV','DR'), + ('DRIVE','DR'), + ('DRIVES','DRS'), + ('DRV','DR'), + ('DVD','DV'), + ('DV','DV'), + ('ESTATE','EST'), + ('ESTATES','ESTS'), + ('EST','EST'), + ('ESTS','ESTS'), + ('EXP','EXPY'), + ('EXPRESS','EXPY'), + ('EXPRESSWAY','EXPY'), + ('EXPR','EXPY'), + ('EXPW','EXPY'), + ('EXPY','EXPY'), + ('EXTENSION','EXT'), + ('EXTENSIONS','EXTS'), + ('EXT','EXT'), + ('EXTN','EXT'), + ('EXTNSN','EXT'), + ('EXTS','EXTS'), + ('FALL','FALL'), + ('FALLS','FLS'), + ('FERRY','FRY'), + ('FIELD','FLD'), + ('FIELDS','FLDS'), + ('FLAT','FLT'), + ('FLATS','FLTS'), + ('FLD','FLD'), + ('FLDS','FLDS'), + ('FLS','FLS'), + ('FLT','FLT'), + ('FLTS','FLTS'), + ('FORD','FRD'), + ('FORDS','FRDS'), + ('FOREST','FRST'), + ('FORESTS','FRST'), + ('FORGE','FRG'), + ('FORGES','FRGS'), + ('FORG','FRG'), + ('FORK','FRK'), + ('FORKS','FRKS'), + ('FORT','FT'), + ('FRD','FRD'), + ('FREEWAY','FWY'), + ('FREEWY','FWY'), + ('FRG','FRG'), + ('FRK','FRK'), + ('FRKS','FRKS'), + ('FRRY','FRY'), + ('FRST','FRST'), + ('FRT','FT'), + ('FRWAY','FWY'), + ('FRWY','FWY'), + ('FRY','FRY'), + ('FT','FT'), + ('FWY','FWY'), + ('GARDEN','GDN'), + ('GARDENS','GDNS'), + ('GARDN','GDN'), + ('GATEWAY','GTWY'), + ('GATEWY','GTWY'), + ('GATWAY','GTWY'), + ('GDN','GDN'), + ('GDNS','GDNS'), + ('GLEN','GLN'), + ('GLENS','GLNS'), + ('GLN','GLN'), + ('GRDEN','GDN'), + ('GRDN','GDN'), + ('GRDNS','GDNS'), + ('GREEN','GRN'), + ('GREENS','GRNS'), + ('GRN','GRN'), + ('GROVE','GRV'), + ('GROVES','GRVS'), + ('GROV','GRV'), + ('GRV','GRV'), + ('GTWAY','GTWY'), + ('GTWY','GTWY'), + ('HARB','HBR'), + ('HARBOR','HBR'), + ('HARBORS','HBRS'), + ('HARBR','HBR'), + ('HAVEN','HVN'), + ('HAVN','HVN'), + ('HBR','HBR'), + ('HEIGHT','HTS'), + ('HEIGHTS','HTS'), + ('HGTS','HTS'), + ('HIGHWAY','HWY'), + ('HIGHWY','HWY'), + ('HILL','HL'), + ('HILLS','HLS'), + ('HIWAY','HWY'), + ('HIWY','HWY'), + ('HL','HL'), + ('HLLW','HOLW'), + ('HLS','HLS'), + ('HOLLOW','HOLW'), + ('HOLLOWS','HOLW'), + ('HOLW','HOLW'), + ('HOLWS','HOLW'), + ('HRBOR','HBR'), + ('HT','HTS'), + ('HTS','HTS'), + ('HVN','HVN'), + ('HWAY','HWY'), + ('HWY','HWY'), + ('INLET','INLT'), + ('INLT','INLT'), + ('IS','IS'), + ('ISLAND','IS'), + ('ISLANDS','ISS'), + ('ISLANDS','SLNDS'), + ('ISLANDS','SS'), + ('ISLE','ISLE'), + ('ISLES','ISLE'), + ('ISLND','IS'), + ('I','SLNDS'), + ('ISS','ISS'), + ('JCTION','JCT'), + ('JCT','JCT'), + ('JCTN','JCT'), + ('JCTNS','JCTS'), + ('JCTS','JCTS'), + ('JUNCTION','JCT'), + ('JUNCTIONS','JCTS'), + ('JUNCTN','JCT'), + ('JUNCTON','JCT'), + ('KEY','KY'), + ('KEYS','KYS'), + ('KNL','KNL'), + ('KNLS','KNLS'), + ('KNOL','KNL'), + ('KNOLL','KNL'), + ('KNOLLS','KNLS'), + ('KY','KY'), + ('KYS','KYS'), + ('LAKE','LK'), + ('LAKES','LKS'), + ('LA','LN'), + ('LANDING','LNDG'), + ('LAND','LAND'), + ('LANE','LN'), + ('LANES','LN'), + ('LCK','LCK'), + ('LCKS','LCKS'), + ('LDGE','LDG'), + ('LDG','LDG'), + ('LF','LF'), + ('LGT','LGT'), + ('LIGHT','LGT'), + ('LIGHTS','LGTS'), + ('LK','LK'), + ('LKS','LKS'), + ('LNDG','LNDG'), + ('LNDNG','LNDG'), + ('LN','LN'), + ('LOAF','LF'), + ('LOCK','LCK'), + ('LOCKS','LCKS'), + ('LODGE','LDG'), + ('LODG','LDG'), + ('LOOP','LOOP'), + ('LOOPS','LOOP'), + ('MALL','MALL'), + ('MANOR','MNR'), + ('MANORS','MNRS'), + ('MDW','MDW'), + ('MDWS','MDWS'), + ('MEADOW','MDW'), + ('MEADOWS','MDWS'), + ('MEDOWS','MDWS'), + ('MEWS','MEWS'), + ('MILL','ML'), + ('MILLS','MLS'), + ('MISSION','MSN'), + ('MISSN','MSN'), + ('ML','ML'), + ('MLS','MLS'), + ('MNR','MNR'), + ('MNRS','MNRS'), + ('MNTAIN','MTN'), + ('MNT','MT'), + ('MNTN','MTN'), + ('MNTNS','MTNS'), + ('MOTORWAY','MTWY'), + ('MOUNTAIN','MTN'), + ('MOUNTAINS','MTNS'), + ('MOUNTIN','MTN'), + ('MOUNT','MT'), + ('MSN','MSN'), + ('MSSN','MSN'), + ('MTIN','MTN'), + ('MT','MT'), + ('MTN','MTN'), + ('NCK','NCK'), + ('NECK','NCK'), + ('ORCHARD','ORCH'), + ('ORCH','ORCH'), + ('ORCHRD','ORCH'), + ('OVAL','OVAL'), + ('OVERPASS','OPAS'), + ('OVL','OVAL'), + ('PARK','PARK'), + ('PARKS','PARK'), + ('PARKWAY','PKWY'), + ('PARKWAYS','PKWY'), + ('PARKWY','PKWY'), + ('PASSAGE','PSGE'), + ('PASS','PASS'), + ('PATH','PATH'), + ('PATHS','PATH'), + ('PIKE','PIKE'), + ('PIKES','PIKE'), + ('PINE','PNE'), + ('PINES','PNES'), + ('PK','PARK'), + ('PKWAY','PKWY'), + ('PKWY','PKWY'), + ('PKWYS','PKWY'), + ('PKY','PKWY'), + ('PLACE','PL'), + ('PLAINES','PLNS'), + ('PLAIN','PLN'), + ('PLAINS','PLNS'), + ('PLAZA','PLZ'), + ('PLN','PLN'), + ('PLNS','PLNS'), + ('PL','PL'), + ('PLZA','PLZ'), + ('PLZ','PLZ'), + ('PNES','PNES'), + ('POINT','PT'), + ('POINTS','PTS'), + ('PORT','PRT'), + ('PORTS','PRTS'), + ('PRAIRIE','PR'), + ('PRARIE','PR'), + ('PRK','PARK'), + ('PR','PR'), + ('PRR','PR'), + ('PRT','PRT'), + ('PRTS','PRTS'), + ('PT','PT'), + ('PTS','PTS'), + ('RADIAL','RADL'), + ('RADIEL','RADL'), + ('RADL','RADL'), + ('RAD','RADL'), + ('RAMP','RAMP'), + ('RANCHES','RNCH'), + ('RANCH','RNCH'), + ('RAPID','RPD'), + ('RAPIDS','RPDS'), + ('RDGE','RDG'), + ('RDG','RDG'), + ('RDGS','RDGS'), + ('RD','RD'), + ('RDS','RDS'), + ('REST','RST'), + ('RIDGE','RDG'), + ('RIDGES','RDGS'), + ('RIVER','RIV'), + ('RIV','RIV'), + ('RIVR','RIV'), + ('RNCH','RNCH'), + ('RNCHS','RNCH'), + ('ROAD','RD'), + ('ROADS','RDS'), + ('ROUTE','RTE'), + ('ROW','ROW'), + ('RPD','RPD'), + ('RPDS','RPDS'), + ('RST','RST'), + ('RUE','RUE'), + ('RUN','RUN'), + ('RVR','RIV'), + ('SHL','SHL'), + ('SHLS','SHLS'), + ('SHOAL','SHL'), + ('SHOALS','SHLS'), + ('SHOAR','SHR'), + ('SHOARS','SHRS'), + ('SHORE','SHR'), + ('SHORES','SHRS'), + ('SHR','SHR'), + ('SHRS','SHRS'), + ('SKYWAY','SKWY'), + ('SMT','SMT'), + ('SPG','SPG'), + ('SPGS','SPGS'), + ('SPNG','SPG'), + ('SPNGS','SPGS'), + ('SPRING','SPG'), + ('SPRINGS','SPGS'), + ('SPRNG','SPG'), + ('SPRNGS','SPGS'), + ('SPUR','SPUR'), + ('SPURS','SPUR'), + ('SQRE','SQ'), + ('SQR','SQ'), + ('SQRS','SQS'), + ('SQ','SQ'), + ('SQUARE','SQ'), + ('SQUARES','SQS'), + ('SQU','SQ'), + ('STA','STA'), + ('STATION','STA'), + ('STATN','STA'), + ('STN','STA'), + ('STRA','STRA'), + ('STRAVEN','STRA'), + ('STRAVENUE','STRA'), + ('STRAVE','STRA'), + ('STRAVN','STRA'), + ('STRAV','STRA'), + ('STREAM','STRM'), + ('STREETS','STS'), + ('STREET','ST'), + ('STREME','STRM'), + ('STRM','STRM'), + ('STR','ST'), + ('STRT','ST'), + ('STRVN','STRA'), + ('STRVNUE','STRA'), + ('ST','ST'), + ('SUMIT','SMT'), + ('SUMITT','SMT'), + ('SUMMIT','SMT'), + ('TERRACE','TER'), + ('TERR','TER'), + ('TER','TER'), + ('THROUGHWAY','TRWY'), + ('TPKE','TPKE'), + ('TPK','TPKE'), + ('TRACES','TRCE'), + ('TRACE','TRCE'), + ('TRACKS','TRAK'), + ('TRACK','TRAK'), + ('TRAFFICWAY','TRFY'), + ('TRAILS','TRL'), + ('TRAIL','TRL'), + ('TRAK','TRAK'), + ('TRCE','TRCE'), + ('TRFY','TRFY'), + ('TRKS','TRAK'), + ('TRK','TRAK'), + ('TRLS','TRL'), + ('TRL','TRL'), + ('TRNPK','TPKE'), + ('TRPK','TPKE'), + ('TR','TRL'), + ('TUNEL','TUNL'), + ('TUNLS','TUNL'), + ('TUNL','TUNL'), + ('TUNNELS','TUNL'), + ('TUNNEL','TUNL'), + ('TUNNL','TUNL'), + ('TURNPIKE','TPKE'), + ('TURNPK','TPKE'), + ('UNDERPASS','UPAS'), + ('UNIONS','UNS'), + ('UNION','UN'), + ('UN','UN'), + ('VALLEYS','VLYS'), + ('VALLEY','VLY'), + ('VALLY','VLY'), + ('VDCT','IA'), + ('VIADCT','VIA'), + ('VIADUCT','IA'), + ('VIADUCT','VIA'), + ('VIA','VIA'), + ('VIEWS','VWS'), + ('VIEW','VW'), + ('VILLAGES','VLGS'), + ('VILLAGE','VLG'), + ('VILLAG','VLG'), + ('VILLE','VL'), + ('VILLG','VLG'), + ('VILLIAGE','VLG'), + ('VILL','VLG'), + ('VISTA','VIS'), + ('VIST','VIS'), + ('VIS','VIS'), + ('VLGS','VLGS'), + ('VLG','VLG'), + ('VLLY','VLY'), + ('VL','VL'), + ('VLYS','VLYS'), + ('VLY','VLY'), + ('VSTA','VIS'), + ('VST','VIS'), + ('VWS','VWS'), + ('VW','VW'), + ('WALKS','WALK'), + ('WALK','WALK'), + ('WALL','WALL'), + ('WAYS','WAYS'), + ('WAY','WAY'), + ('WELLS','WLS'), + ('WELL','WL'), + ('WLS','WLS'), + ('WY','WAY'), + ('XING','XING'); + FOR _r IN (SELECT * FROM mig_usps_suffixes) LOOP + street1 := REGEXP_REPLACE( street1, ' ' || _r.suffix_from || '$', ' ' || _r.suffix_to, 'i'); + END LOOP; + RETURN street1; + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + CREATE OR REPLACE FUNCTION migration_tools.rebarcode (o TEXT, t BIGINT) RETURNS TEXT AS $$ DECLARE n TEXT := o; @@ -1082,6 +1670,47 @@ 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 = '+'; + } 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; @@ -1517,6 +2146,56 @@ END; $$ LANGUAGE plpgsql; +-- TODO: make another version of the procedure below that can work with specified copy staging tables +-- The following should track the logic of OpenILS::Application::AppUtils::get_copy_price +CREATE OR REPLACE FUNCTION migration_tools.get_copy_price( item BIGINT ) RETURNS NUMERIC AS $$ +DECLARE + context_lib INT; + charge_lost_on_zero BOOLEAN; + min_price NUMERIC; + max_price NUMERIC; + default_price NUMERIC; + working_price NUMERIC; + +BEGIN + + SELECT INTO context_lib CASE WHEN call_number = -1 THEN circ_lib ELSE owning_lib END + FROM asset.copy ac, asset.call_number acn WHERE ac.call_number = acn.id AND ac.id = item; + + SELECT INTO charge_lost_on_zero value + FROM actor.org_unit_ancestor_setting('circ.charge_lost_on_zero',context_lib); + + SELECT INTO min_price value + FROM actor.org_unit_ancestor_setting('circ.min_item_price',context_lib); + + SELECT INTO max_price value + FROM actor.org_unit_ancestor_setting('circ.max_item_price',context_lib); + + SELECT INTO default_price value + FROM actor.org_unit_ancestor_setting('cat.default_item_price',context_lib); + + SELECT INTO working_price price FROM asset.copy WHERE id = item; + + IF (working_price IS NULL OR (working_price = 0 AND charge_lost_on_zero)) THEN + working_price := default_price; + END IF; + + IF (max_price IS NOT NULL AND working_price > max_price) THEN + working_price := max_price; + END IF; + + IF (min_price IS NOT NULL AND working_price < min_price) THEN + IF (working_price <> 0 OR charge_lost_on_zero IS NULL OR charge_lost_on_zero) THEN + working_price := min_price; + END IF; + END IF; + + RETURN working_price; + +END; + +$$ LANGUAGE plpgsql; + CREATE OR REPLACE FUNCTION migration_tools.apply_circ_matrix_to_specific_circ( tablename TEXT, circ BIGINT ) RETURNS VOID AS $$ -- Usage: @@ -1591,7 +2270,7 @@ BEGIN recurring_fine = rrf.normal, max_fine = CASE rmf.is_percent - WHEN TRUE THEN (rmf.amount / 100.0) * ac.price + WHEN TRUE THEN (rmf.amount / 100.0) * migration_tools.get_copy_price(ac.id) ELSE rmf.amount END, renewal_remaining = rcd.max_renewals, @@ -2217,6 +2896,24 @@ BEGIN END; $FUNC$ LANGUAGE PLPGSQL; +CREATE OR REPLACE FUNCTION migration_tools.split_rows_on_column_with_delimiter(schemaname TEXT, tablename TEXT, matchcol TEXT, delimiter TEXT) RETURNS VOID AS $FUNC$ +DECLARE + id BIGINT; + loopq TEXT; + cols TEXT[]; + splitst TEXT; +BEGIN + loopq := 'SELECT id FROM ' || schemaname || '.' || tablename || ' WHERE ' || matchcol || ' ~ $1 ORDER BY id'; + SELECT ARRAY_AGG(column_name::TEXT) INTO cols FROM information_schema.columns WHERE table_schema = schemaname AND table_name = tablename AND column_name <> 'id' AND column_name <> matchcol; + FOR id IN EXECUTE loopq USING delimiter LOOP + RAISE NOTICE 'splitting row from %.% with id = %', schemaname, tablename, id; + splitst := 'INSERT INTO ' || schemaname || '.' || tablename || ' (' || ARRAY_TO_STRING(cols, ',') || ', ' || matchcol || ') SELECT ' || ARRAY_TO_STRING(cols, ',') || ', s.token ' || + ' FROM ' || schemaname || '.' || tablename || ' t, UNNEST(STRING_TO_ARRAY(t.' || matchcol || ', $2)) s(token) WHERE id = $1'; + EXECUTE splitst USING id, delimiter; + END LOOP; +END; +$FUNC$ LANGUAGE PLPGSQL; + CREATE OR REPLACE FUNCTION migration_tools.merge_marc_fields( TEXT, TEXT, TEXT[] ) RETURNS TEXT AS $func$ use strict; @@ -2554,6 +3251,107 @@ CREATE OR REPLACE FUNCTION migration_tools.duplicate_template_but_change_delay ( END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- example: SELECT * FROM migration_tools.duplicate_templates(3,'{5,6}'); +CREATE OR REPLACE FUNCTION migration_tools.duplicate_templates (INTEGER, INTEGER[]) RETURNS VOID AS $$ + DECLARE + org ALIAS FOR $1; + target_event_defs ALIAS FOR $2; + BEGIN + DROP TABLE IF EXISTS new_atevdefs; + CREATE TEMP TABLE new_atevdefs (atevdef INTEGER); + FOR i IN array_lower(target_event_defs,1) .. array_upper(target_event_defs,1) LOOP + INSERT INTO action_trigger.event_definition ( + active + ,owner + ,name + ,hook + ,validator + ,reactor + ,cleanup_success + ,cleanup_failure + ,delay + ,max_delay + ,usr_field + ,opt_in_setting + ,delay_field + ,group_field + ,template + ,granularity + ,repeat_delay + ) SELECT + 'f' + ,org + ,name || ' (clone of '||target_event_defs[i]||')' + ,hook + ,validator + ,reactor + ,cleanup_success + ,cleanup_failure + ,delay + ,max_delay + ,usr_field + ,opt_in_setting + ,delay_field + ,group_field + ,template + ,granularity + ,repeat_delay + FROM + action_trigger.event_definition + WHERE + id = target_event_defs[i] + ; + RAISE INFO 'created atevdef with id = %', currval('action_trigger.event_definition_id_seq'); + INSERT INTO new_atevdefs SELECT currval('action_trigger.event_definition_id_seq'); + INSERT INTO action_trigger.environment ( + event_def + ,path + ,collector + ,label + ) SELECT + currval('action_trigger.event_definition_id_seq') + ,path + ,collector + ,label + FROM + action_trigger.environment + WHERE + event_def = target_event_defs[i] + ; + INSERT INTO action_trigger.event_params ( + event_def + ,param + ,value + ) SELECT + currval('action_trigger.event_definition_id_seq') + ,param + ,value + FROM + action_trigger.event_params + WHERE + event_def = target_event_defs[i] + ; + END LOOP; + RAISE INFO '-- UPDATE action_trigger.event_definition SET active = TRUE WHERE id in (%);', (SELECT array_to_string(array_agg(atevdef),',') from new_atevdefs); + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.reset_event (BIGINT) RETURNS VOID AS $$ + UPDATE + action_trigger.event + SET + start_time = NULL + ,update_time = NULL + ,complete_time = NULL + ,update_process = NULL + ,state = 'pending' + ,template_output = NULL + ,error_output = NULL + ,async_output = NULL + WHERE + id = $1; +$$ LANGUAGE SQL; + CREATE OR REPLACE FUNCTION migration_tools.get_marc_leader (TEXT) RETURNS TEXT AS $$ my ($marcxml) = @_; @@ -2928,7 +3726,10 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_not_migrate (TEXT,TEXT) RETURN 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) = ''Do Not Migrate'' 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'; @@ -2941,6 +3742,64 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_not_migrate (TEXT,TEXT) RETURN END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- convenience function for handling desired_not_migrate + +CREATE OR REPLACE FUNCTION migration_tools.handle_barred_or_blocked (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_barred_or_blocked'' + )' INTO proceed USING table_schema, table_name; + IF NOT proceed THEN + RAISE EXCEPTION 'Missing column desired_barred_or_blocked'; + END IF; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_barred'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_barred BOOLEAN'; + + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' DROP COLUMN IF EXISTS x_blocked'; + EXECUTE 'ALTER TABLE ' + || quote_ident(table_name) + || ' ADD COLUMN x_blocked BOOLEAN'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_barred = CASE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Barred'' THEN TRUE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Blocked'' THEN FALSE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Neither'' THEN FALSE' + || ' WHEN BTRIM(desired_barred_or_blocked) = '''' THEN FALSE' + || ' END'; + + EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' + || ' SET x_blocked = CASE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Blocked'' THEN TRUE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Barred'' THEN FALSE' + || ' WHEN BTRIM(desired_barred_or_blocked) = ''Neither'' THEN FALSE' + || ' WHEN BTRIM(desired_barred_or_blocked) = '''' THEN FALSE' + || ' END'; + + EXECUTE 'SELECT migration_tools.assert( + NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE x_barred IS NULL or x_blocked IS NULL), + ''Not all desired_barred_or_blocked values understood'', + ''All desired_barred_or_blocked 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 $$ @@ -2968,7 +3827,7 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_profile (TEXT,TEXT) RETURNS VO || ' ADD COLUMN x_profile INTEGER'; EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' - || ' SET x_profile = id FROM permission.grp_tree b' + || ' SET x_profile = b.id FROM permission.grp_tree b' || ' WHERE BTRIM(UPPER(a.desired_profile)) = BTRIM(UPPER(b.name))'; EXECUTE 'SELECT migration_tools.assert( @@ -3077,6 +3936,7 @@ CREATE OR REPLACE FUNCTION migration_tools.vivicate_actor_sc_and_sce (TEXT,TEXT, WHERE owner = ANY ($2) AND BTRIM('||sc||') = BTRIM(name) ) AND value = BTRIM('||sce||') + AND owner = ANY ($2) ) AND NOT EXISTS ( SELECT id @@ -3087,6 +3947,7 @@ CREATE OR REPLACE FUNCTION migration_tools.vivicate_actor_sc_and_sce (TEXT,TEXT, WHERE owner = ANY ($2) AND BTRIM('||sc||') = BTRIM(name) ) AND value = BTRIM('||sce||') + AND owner = ANY ($2) ) ORDER BY 1,3;' USING org, org_list; @@ -3238,9 +4099,9 @@ BEGIN 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) +-- yet another subfield 9 function, this one only adds the $9 if the ind1 = 1 or 4 and ind2 = 0 or 1 +DROP FUNCTION IF EXISTS migration_tools.strict_add_sf9(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.strict_add_sf9(marc TEXT, new_9 TEXT) RETURNS TEXT LANGUAGE plperlu AS $function$ @@ -3255,7 +4116,6 @@ 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/; @@ -3266,75 +4126,211 @@ eval { if ($@) { #elog("could not parse $bibid: $@\n"); import MARC::File::XML (BinaryEncoding => 'utf8'); - return; + return $marc_xml; } my @uris = $marc_xml->field('856'); -return unless @uris; +return $marc_xml->as_xml_record() unless @uris; foreach my $field (@uris) { - my $sfu = $field->subfield('u'); + my $ind1 = $field->indicator('1'); + if (!defined $ind1) { next; } + if ($ind1 ne '1' && $ind1 ne '4') { next; } 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; - } + if ($ind2 ne '0' && $ind2 ne '1') { next; } + $field->add_subfields( '9' => $new_9_to_set ); } 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 +-- yet another subfield 9 function, this one only adds the $9 and forces +-- ind1 = 4 if not already ind1 = 1 or 4 and ind2 = 0 if not already ind2 = 0 or 1 +DROP FUNCTION IF EXISTS migration_tools.force_add_sf9(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.force_add_sf9(marc TEXT, new_9 TEXT) + RETURNS TEXT + LANGUAGE plperlu +AS $function$ +use strict; +use warnings; - SELECT marc FROM biblio.record_entry WHERE id = bib_id INTO source_xml; +use MARC::Record; +use MARC::File::XML (BinaryEncoding => 'utf8'); - SELECT add_sf9(source_xml, target_u_text, sf9_text) INTO new_xml; +binmode(STDERR, ':bytes'); +binmode(STDOUT, ':utf8'); +binmode(STDERR, ':utf8'); - r = FALSE; +my $marc_xml = shift; +my $new_9_to_set = shift; - IF new_xml != source_xml THEN - UPDATE biblio.record_entry SET marc = new_xml WHERE id = bib_id; - r = TRUE; - END IF; +$marc_xml =~ s/(.........)./${1}a/; - RETURN r; +eval { + $marc_xml = MARC::Record->new_from_xml($marc_xml); +}; +if ($@) { + #elog("could not parse $bibid: $@\n"); + import MARC::File::XML (BinaryEncoding => 'utf8'); + return $marc_xml; +} -END; -$BODY$ LANGUAGE plpgsql; +my @uris = $marc_xml->field('856'); +return $marc_xml->as_xml_record() unless @uris; --- convenience function for linking to the item staging table +foreach my $field (@uris) { + my $ind1 = $field->indicator('1'); + if (!defined $ind1) { next; } + if ($ind1 ne '1' && $ind1 ne '4') { $field->set_indicator(1,'4'); } + my $ind2 = $field->indicator('2'); + if (!defined $ind2) { next; } + if ($ind2 ne '0' && $ind2 ne '1') { $field->set_indicator(2,'0'); } + $field->add_subfields( '9' => $new_9_to_set ); +} -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; +return $marc_xml->as_xml_record(); + +$function$; + +-- 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/ or $matching_u_text eq 'pineapple') { + $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 migration_tools.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; + +-- strip marc tag +DROP FUNCTION IF EXISTS migration_tools.strip_tag(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.strip_tag(marc TEXT, tag 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 $tag = 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 $marc_xml; +} + +my @fields = $marc_xml->field($tag); +return $marc_xml->as_xml_record() unless @fields; + +$marc_xml->delete_fields(@fields); + +return $marc_xml->as_xml_record(); + +$function$; + +-- 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 @@ -3356,12 +4352,12 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_item_barcode (TEXT,TEXT,TEXT,T IF btrim_desired THEN EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' - || ' SET x_item = id FROM asset_copy_legacy b' + || ' 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 = id FROM asset_copy_legacy b' + || ' 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; @@ -3417,12 +4413,12 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_user_barcode (TEXT,TEXT,TEXT,T IF btrim_desired THEN EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a' - || ' SET x_user = id FROM actor_usr_legacy b' + || ' 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 = id FROM actor_usr_legacy b' + || ' 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; @@ -3480,12 +4476,12 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_link (TEXT,TEXT,TEXT,TEXT,TEXT IF btrim_desired THEN EXECUTE 'UPDATE ' || quote_ident(table_b) || ' b' - || ' SET ' || quote_ident(column_x) || ' = id FROM ' || quote_ident(table_a) || ' a' + || ' SET ' || quote_ident(column_x) || ' = a.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' + || ' SET ' || quote_ident(column_x) || ' = a.id FROM ' || quote_ident(table_a) || ' a' || ' WHERE a.' || quote_ident(column_a) || ' = b.' || quote_ident(column_b); END IF; @@ -3538,12 +4534,12 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_link2 (TEXT,TEXT,TEXT,TEXT,TEX 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' + || ' SET ' || quote_ident(column_x) || ' = a.' || 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' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' || ' WHERE a.' || quote_ident(column_a) || ' = b.' || quote_ident(column_b); END IF; @@ -3551,6 +4547,259 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_link2 (TEXT,TEXT,TEXT,TEXT,TEX END; $$ LANGUAGE PLPGSQL STRICT VOLATILE; +-- convenience function for linking two tables, but copying column w into column x instead of "id". Unlike handle_link2, this one won't drop the target column, and it also doesn't have a final boolean argument for btrim +-- e.g. select migration_tools.handle_link3(:'migschema','asset_copy','barcode','test_foo','l_barcode','id','x_acp_id'); +CREATE OR REPLACE FUNCTION migration_tools.handle_link3 (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b); + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_link3_skip_null_or_empty_string (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b) + || ' AND NULLIF(a.' || quote_ident(column_w) || ','''') IS NOT NULL'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_link3_skip_null (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b) + || ' AND a.' || quote_ident(column_w) || ' IS NOT NULL'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_link3_skip_true (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b) + || ' AND a.' || quote_ident(column_w) || ' IS NOT TRUE'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_link3_skip_false (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = a.' || quote_ident(column_w) || ' FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b) + || ' AND a.' || quote_ident(column_w) || ' IS NOT FALSE'; + + END; +$$ LANGUAGE PLPGSQL STRICT VOLATILE; + +CREATE OR REPLACE FUNCTION migration_tools.handle_link3_concat_skip_null (TEXT,TEXT,TEXT,TEXT,TEXT,TEXT,TEXT) 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; + 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 'UPDATE ' || quote_ident(table_b) || ' b' + || ' SET ' || quote_ident(column_x) || ' = CONCAT_WS('' ; '',b.' || quote_ident(column_x) || ',a.' || quote_ident(column_w) || ') FROM ' || quote_ident(table_a) || ' a' + || ' WHERE a.' || quote_ident(column_a) + || ' = b.' || quote_ident(column_b) + || ' AND NULLIF(a.' || quote_ident(column_w) || ','''') IS NOT NULL'; + + 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 $$ @@ -3648,6 +4897,7 @@ CREATE OR REPLACE FUNCTION migration_tools.vivicate_asset_sc_and_sce (TEXT,TEXT, WHERE owner = ANY ($2) AND BTRIM('||sc||') = BTRIM(name) ) AND value = BTRIM('||sce||') + AND owner = ANY ($2) ) AND NOT EXISTS ( SELECT id @@ -3658,6 +4908,7 @@ CREATE OR REPLACE FUNCTION migration_tools.vivicate_asset_sc_and_sce (TEXT,TEXT, WHERE owner = ANY ($2) AND BTRIM('||sc||') = BTRIM(name) ) AND value = BTRIM('||sce||') + AND owner = ANY ($2) ) ORDER BY 1,3;' USING org, org_list; @@ -3758,3 +5009,85 @@ CREATE OR REPLACE FUNCTION migration_tools.handle_asset_sc_and_sce (TEXT,TEXT,TE 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.btrim_columns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.btrim_columns(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') + 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$; + +DROP FUNCTION IF EXISTS migration_tools.null_empty_columns(TEXT,TEXT); +CREATE OR REPLACE FUNCTION migration_tools.null_empty_columns(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') + LOOP + EXECUTE FORMAT('UPDATE ' || s_name || '.' || t_name || ' SET ' || c_name || ' = NULL WHERE ' || c_name || ' = '''' '); + END LOOP; + + RETURN TRUE; +END +$function$;