1 -- Copyright 2009-2012, Equinox Software, Inc.
3 -- This program is free software; you can redistribute it and/or
4 -- modify it under the terms of the GNU General Public License
5 -- as published by the Free Software Foundation; either version 2
6 -- of the License, or (at your option) any later version.
8 -- This program is distributed in the hope that it will be useful,
9 -- but WITHOUT ANY WARRANTY; without even the implied warranty of
10 -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
11 -- GNU General Public License for more details.
13 -- You should have received a copy of the GNU General Public License
14 -- along with this program; if not, write to the Free Software
15 -- Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.
17 --------------------------------------------------------------------------
18 -- An example of how to use:
20 -- DROP SCHEMA foo CASCADE; CREATE SCHEMA foo;
22 -- SELECT migration_tools.init('foo');
23 -- SELECT migration_tools.build('foo');
24 -- SELECT * FROM foo.fields_requiring_mapping;
26 -- create some incoming ILS specific staging tables, like CREATE foo.legacy_items ( l_barcode TEXT, .. ) INHERITS (foo.asset_copy);
27 -- Do some mapping, like UPDATE foo.legacy_items SET barcode = TRIM(BOTH ' ' FROM l_barcode);
28 -- Then, to move into production, do: select migration_tools.insert_base_into_production('foo')
30 CREATE SCHEMA migration_tools;
32 CREATE OR REPLACE FUNCTION migration_tools.production_tables (TEXT) RETURNS TEXT[] AS $$
34 migration_schema ALIAS FOR $1;
38 EXECUTE 'SELECT string_to_array(value,'','') AS tables FROM ' || migration_schema || '.config WHERE key = ''production_tables'';'
43 $$ LANGUAGE PLPGSQL STRICT STABLE;
45 CREATE OR REPLACE FUNCTION migration_tools.country_code (TEXT) RETURNS TEXT AS $$
47 migration_schema ALIAS FOR $1;
51 EXECUTE 'SELECT value FROM ' || migration_schema || '.config WHERE key = ''country_code'';'
56 $$ LANGUAGE PLPGSQL STRICT STABLE;
59 CREATE OR REPLACE FUNCTION migration_tools.log (TEXT,TEXT,INTEGER) RETURNS VOID AS $$
61 migration_schema ALIAS FOR $1;
65 EXECUTE 'INSERT INTO ' || migration_schema || '.sql_log ( sql, row_count ) VALUES ( ' || quote_literal(sql) || ', ' || nrows || ' );';
67 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
69 CREATE OR REPLACE FUNCTION migration_tools.exec (TEXT,TEXT) RETURNS VOID AS $$
71 migration_schema ALIAS FOR $1;
75 EXECUTE 'UPDATE ' || migration_schema || '.sql_current SET sql = ' || quote_literal(sql) || ';';
76 --RAISE INFO '%', sql;
78 GET DIAGNOSTICS nrows = ROW_COUNT;
79 PERFORM migration_tools.log(migration_schema,sql,nrows);
82 RAISE EXCEPTION '!!!!!!!!!!! state = %, msg = %, sql = %', SQLSTATE, SQLERRM, sql;
84 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
86 CREATE OR REPLACE FUNCTION migration_tools.debug_exec (TEXT,TEXT) RETURNS VOID AS $$
88 migration_schema ALIAS FOR $1;
92 EXECUTE 'UPDATE ' || migration_schema || '.sql_current SET sql = ' || quote_literal(sql) || ';';
93 RAISE INFO 'debug_exec sql = %', sql;
95 GET DIAGNOSTICS nrows = ROW_COUNT;
96 PERFORM migration_tools.log(migration_schema,sql,nrows);
99 RAISE EXCEPTION '!!!!!!!!!!! state = %, msg = %, sql = %', SQLSTATE, SQLERRM, sql;
101 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
103 CREATE OR REPLACE FUNCTION migration_tools.init (TEXT) RETURNS VOID AS $$
105 migration_schema ALIAS FOR $1;
108 EXECUTE 'DROP TABLE IF EXISTS ' || migration_schema || '.sql_current;';
109 EXECUTE 'CREATE TABLE ' || migration_schema || '.sql_current ( sql TEXT);';
110 EXECUTE 'INSERT INTO ' || migration_schema || '.sql_current ( sql ) VALUES ( '''' );';
112 SELECT 'CREATE TABLE ' || migration_schema || '.sql_log ( time TIMESTAMP NOT NULL DEFAULT NOW(), row_count INTEGER, sql TEXT );' INTO STRICT sql;
116 RAISE INFO '!!!!!!!!!!! state = %, msg = %, sql = %', SQLSTATE, SQLERRM, sql;
118 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.config;' );
119 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.config ( key TEXT UNIQUE, value TEXT);' );
120 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'' );' );
121 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''country_code'', ''USA'' );' );
122 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.fields_requiring_mapping;' );
123 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || '.fields_requiring_mapping( table_schema TEXT, table_name TEXT, column_name TEXT, data_type TEXT);' );
124 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.base_profile_map;' );
125 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || E'.base_profile_map (
128 transcribed_perm_group TEXT,
136 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_profile_map'', ''base_profile_map'' );' );
137 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.base_item_dynamic_field_map;' );
138 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || E'.base_item_dynamic_field_map (
140 evergreen_field TEXT,
141 evergreen_value TEXT,
142 evergreen_datatype TEXT,
150 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf1_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field1,legacy_value1);' );
151 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf2_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field2,legacy_value2);' );
152 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_item_dynamic_lf3_idx ON ' || migration_schema || '.base_item_dynamic_field_map (legacy_field3,legacy_value3);' );
153 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_item_dynamic_field_map'', ''base_item_dynamic_field_map'' );' );
154 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.base_copy_location_map;' );
155 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || E'.base_copy_location_map (
158 holdable BOOLEAN NOT NULL DEFAULT TRUE,
159 hold_verify BOOLEAN NOT NULL DEFAULT FALSE,
160 opac_visible BOOLEAN NOT NULL DEFAULT TRUE,
161 circulate BOOLEAN NOT NULL DEFAULT TRUE,
162 transcribed_location TEXT,
170 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_base_copy_location_lf1_idx ON ' || migration_schema || '.base_copy_location_map (legacy_field1,legacy_value1);' );
171 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_base_copy_location_lf2_idx ON ' || migration_schema || '.base_copy_location_map (legacy_field2,legacy_value2);' );
172 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_base_copy_location_lf3_idx ON ' || migration_schema || '.base_copy_location_map (legacy_field3,legacy_value3);' );
173 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_base_copy_location_loc_idx ON ' || migration_schema || '.base_copy_location_map (transcribed_location);' );
174 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_copy_location_map'', ''base_copy_location_map'' );' );
175 PERFORM migration_tools.exec( $1, 'DROP TABLE IF EXISTS ' || migration_schema || '.base_circ_field_map;' );
176 PERFORM migration_tools.exec( $1, 'CREATE TABLE ' || migration_schema || E'.base_circ_field_map (
194 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_circ_dynamic_lf1_idx ON ' || migration_schema || '.base_circ_field_map (item_field1,item_value1);' );
195 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_circ_dynamic_lf2_idx ON ' || migration_schema || '.base_circ_field_map (item_field2,item_value2);' );
196 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_circ_dynamic_lf3_idx ON ' || migration_schema || '.base_circ_field_map (patron_field1,patron_value1);' );
197 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_circ_dynamic_lf4_idx ON ' || migration_schema || '.base_circ_field_map (patron_field2,patron_value2);' );
198 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''base_circ_field_map'', ''base_circ_field_map'' );' );
201 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_init'', now() );' );
203 WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_init'';' );
206 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
208 CREATE OR REPLACE FUNCTION migration_tools.build (TEXT) RETURNS VOID AS $$
210 migration_schema ALIAS FOR $1;
211 production_tables TEXT[];
213 --RAISE INFO 'In migration_tools.build(%)', migration_schema;
214 SELECT migration_tools.production_tables(migration_schema) INTO STRICT production_tables;
215 PERFORM migration_tools.build_base_staging_tables(migration_schema,production_tables);
216 PERFORM migration_tools.exec( $1, 'CREATE UNIQUE INDEX ' || migration_schema || '_patron_barcode_key ON ' || migration_schema || '.actor_card ( barcode );' );
217 PERFORM migration_tools.exec( $1, 'CREATE UNIQUE INDEX ' || migration_schema || '_patron_usrname_key ON ' || migration_schema || '.actor_usr ( usrname );' );
218 PERFORM migration_tools.exec( $1, 'CREATE UNIQUE INDEX ' || migration_schema || '_copy_barcode_key ON ' || migration_schema || '.asset_copy ( barcode );' );
219 PERFORM migration_tools.exec( $1, 'CREATE UNIQUE INDEX ' || migration_schema || '_copy_id_key ON ' || migration_schema || '.asset_copy ( id );' );
220 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_callnum_record_idx ON ' || migration_schema || '.asset_call_number ( record );' );
221 PERFORM migration_tools.exec( $1, 'CREATE INDEX ' || migration_schema || '_callnum_upper_label_id_lib_idx ON ' || migration_schema || '.asset_call_number ( UPPER(label),id,owning_lib );' );
222 PERFORM migration_tools.exec( $1, 'CREATE UNIQUE INDEX ' || migration_schema || '_callnum_label_once_per_lib ON ' || migration_schema || '.asset_call_number ( record,owning_lib,label,prefix,suffix );' );
224 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
226 CREATE OR REPLACE FUNCTION migration_tools.build_base_staging_tables (TEXT,TEXT[]) RETURNS VOID AS $$
228 migration_schema ALIAS FOR $1;
229 production_tables ALIAS FOR $2;
231 --RAISE INFO 'In migration_tools.build_base_staging_tables(%,%)', migration_schema, production_tables;
232 FOR i IN array_lower(production_tables,1) .. array_upper(production_tables,1) LOOP
233 PERFORM migration_tools.build_specific_base_staging_table(migration_schema,production_tables[i]);
236 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
238 CREATE OR REPLACE FUNCTION migration_tools.build_specific_base_staging_table (TEXT,TEXT) RETURNS VOID AS $$
240 migration_schema ALIAS FOR $1;
241 production_table ALIAS FOR $2;
242 base_staging_table TEXT;
245 base_staging_table = REPLACE( production_table, '.', '_' );
246 --RAISE INFO 'In migration_tools.build_specific_base_staging_table(%,%) -> %', migration_schema, production_table, base_staging_table;
247 PERFORM migration_tools.exec( $1, 'CREATE UNLOGGED TABLE ' || migration_schema || '.' || base_staging_table || ' ( LIKE ' || production_table || ' INCLUDING DEFAULTS EXCLUDING CONSTRAINTS );' );
248 PERFORM migration_tools.exec( $1, '
249 INSERT INTO ' || migration_schema || '.fields_requiring_mapping
250 SELECT table_schema, table_name, column_name, data_type
251 FROM information_schema.columns
252 WHERE table_schema = ''' || migration_schema || ''' AND table_name = ''' || base_staging_table || ''' AND is_nullable = ''NO'' AND column_default IS NULL;
255 SELECT table_schema, table_name, column_name, data_type
256 FROM information_schema.columns
257 WHERE table_schema = migration_schema AND table_name = base_staging_table AND is_nullable = 'NO' AND column_default IS NULL
259 PERFORM migration_tools.exec( $1, 'ALTER TABLE ' || columns.table_schema || '.' || columns.table_name || ' ALTER COLUMN ' || columns.column_name || ' DROP NOT NULL;' );
262 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
264 CREATE OR REPLACE FUNCTION migration_tools.insert_base_into_production (TEXT) RETURNS VOID AS $$
266 migration_schema ALIAS FOR $1;
267 production_tables TEXT[];
269 --RAISE INFO 'In migration_tools.insert_into_production(%)', migration_schema;
270 SELECT migration_tools.production_tables(migration_schema) INTO STRICT production_tables;
271 FOR i IN array_lower(production_tables,1) .. array_upper(production_tables,1) LOOP
272 PERFORM migration_tools.insert_into_production(migration_schema,production_tables[i]);
275 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
277 CREATE OR REPLACE FUNCTION migration_tools.insert_into_production (TEXT,TEXT) RETURNS VOID AS $$
279 migration_schema ALIAS FOR $1;
280 production_table ALIAS FOR $2;
281 base_staging_table TEXT;
284 base_staging_table = REPLACE( production_table, '.', '_' );
285 --RAISE INFO 'In migration_tools.insert_into_production(%,%) -> %', migration_schema, production_table, base_staging_table;
286 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || production_table || ' SELECT * FROM ' || migration_schema || '.' || base_staging_table || ';' );
288 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
290 CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_last_comma_prefix_first_middle_suffix (TEXT) RETURNS TEXT[] AS $$
292 full_name TEXT := $1;
294 family_name TEXT := '';
295 first_given_name TEXT := '';
296 second_given_name TEXT := '';
301 -- Use values, not structure, for prefix/suffix, unless we come up with a better idea
302 IF temp ilike '%MR.%' THEN
304 temp := REGEXP_REPLACE( temp, E'MR\.\\s*', '', 'i' );
306 IF temp ilike '%MRS.%' THEN
308 temp := REGEXP_REPLACE( temp, E'MRS\.\\s*', '', 'i' );
310 IF temp ilike '%MS.%' THEN
312 temp := REGEXP_REPLACE( temp, E'MS\.\\s*', '', 'i' );
314 IF temp ilike '%DR.%' THEN
316 temp := REGEXP_REPLACE( temp, E'DR\.\\s*', '', 'i' );
318 IF temp ilike '%JR%' THEN
320 temp := REGEXP_REPLACE( temp, E'JR\.?\\s*', '', 'i' );
322 IF temp ilike '%JR,%' THEN
324 temp := REGEXP_REPLACE( temp, E'JR,\\s*', ',', 'i' );
326 IF temp ilike '%SR%' THEN
328 temp := REGEXP_REPLACE( temp, E'SR\.?\\s*', '', 'i' );
330 IF temp ilike '%SR,%' THEN
332 temp := REGEXP_REPLACE( temp, E'SR,\\s*', ',', 'i' );
334 IF temp ~ E'\\sII$' THEN
336 temp := REGEXP_REPLACE( temp, E'II$', '', 'i' );
338 IF temp ~ E'\\sIII$' THEN
340 temp := REGEXP_REPLACE( temp, E'III$', '', 'i' );
342 IF temp ~ E'\\sIV$' THEN
344 temp := REGEXP_REPLACE( temp, E'IV$', '', 'i' );
347 family_name := BTRIM( REGEXP_REPLACE(temp,E'^([^,]*)\\s*,.*$',E'\\1') );
348 first_given_name := BTRIM( CASE WHEN temp ~ ',' THEN REGEXP_REPLACE(temp,E'^[^,]*\\s*,\\s*([^,\\s]*)\\s*.*$',E'\\1') ELSE 'N/A' END );
349 second_given_name := BTRIM( CASE WHEN temp ~ ',' THEN REGEXP_REPLACE(temp,E'^[^,]*\\s*,\\s*[^,\\s]*\\s*(.*)$',E'\\1') ELSE '' END );
351 RETURN ARRAY[ family_name, prefix, first_given_name, second_given_name, suffix ];
353 $$ LANGUAGE PLPGSQL STRICT IMMUTABLE;
355 CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_last_first_middle_and_random_affix (TEXT) RETURNS TEXT[] AS $$
357 full_name TEXT := $1;
359 family_name TEXT := '';
360 first_given_name TEXT := '';
361 second_given_name TEXT := '';
366 -- Use values, not structure, for prefix/suffix, unless we come up with a better idea
367 IF temp ilike '%MR.%' THEN
369 temp := REGEXP_REPLACE( temp, E'MR\.\\s*', '', 'i' );
371 IF temp ilike '%MRS.%' THEN
373 temp := REGEXP_REPLACE( temp, E'MRS\.\\s*', '', 'i' );
375 IF temp ilike '%MS.%' THEN
377 temp := REGEXP_REPLACE( temp, E'MS\.\\s*', '', 'i' );
379 IF temp ilike '%DR.%' THEN
381 temp := REGEXP_REPLACE( temp, E'DR\.\\s*', '', 'i' );
383 IF temp ilike '%JR.%' THEN
385 temp := REGEXP_REPLACE( temp, E'JR\.\\s*', '', 'i' );
387 IF temp ilike '%JR,%' THEN
389 temp := REGEXP_REPLACE( temp, E'JR,\\s*', ',', 'i' );
391 IF temp ilike '%SR.%' THEN
393 temp := REGEXP_REPLACE( temp, E'SR\.\\s*', '', 'i' );
395 IF temp ilike '%SR,%' THEN
397 temp := REGEXP_REPLACE( temp, E'SR,\\s*', ',', 'i' );
399 IF temp like '%III%' THEN
401 temp := REGEXP_REPLACE( temp, E'III', '' );
403 IF temp like '%II%' THEN
405 temp := REGEXP_REPLACE( temp, E'II', '' );
407 IF temp like '%IV%' THEN
409 temp := REGEXP_REPLACE( temp, E'IV', '' );
412 temp := REGEXP_REPLACE( temp, '\(\)', '');
413 family_name := BTRIM( REGEXP_REPLACE(temp,E'^(\\S+).*$',E'\\1') );
414 family_name := REGEXP_REPLACE( family_name, ',', '' );
415 first_given_name := CASE WHEN temp ~ E'^\\S+$' THEN 'N/A' ELSE BTRIM( REGEXP_REPLACE(temp,E'^\\S+\\s+(\\S+).*$',E'\\1') ) END;
416 first_given_name := REGEXP_REPLACE( first_given_name, ',', '' );
417 second_given_name := CASE WHEN temp ~ E'^\\S+$' THEN '' ELSE BTRIM( REGEXP_REPLACE(temp,E'^\\S+\\s+\\S+\\s*(.*)$',E'\\1') ) END;
418 second_given_name := REGEXP_REPLACE( second_given_name, ',', '' );
420 RETURN ARRAY[ family_name, prefix, first_given_name, second_given_name, suffix ];
422 $$ LANGUAGE PLPGSQL STRICT IMMUTABLE;
424 CREATE OR REPLACE FUNCTION migration_tools.name_parse_out_fuller_last_first_middle_and_random_affix (TEXT) RETURNS TEXT[] AS $$
426 full_name TEXT := $1;
428 family_name TEXT := '';
429 first_given_name TEXT := '';
430 second_given_name TEXT := '';
434 temp := BTRIM(full_name);
435 -- Use values, not structure, for prefix/suffix, unless we come up with a better idea
436 --IF temp ~ '^\S{2,}\.' THEN
437 -- prefix := REGEXP_REPLACE(temp, '^(\S{2,}\.).*$','\1');
438 -- temp := BTRIM(REGEXP_REPLACE(temp, '^\S{2,}\.(.*)$','\1'));
440 --IF temp ~ '\S{2,}\.$' THEN
441 -- suffix := REGEXP_REPLACE(temp, '^.*(\S{2,}\.)$','\1');
442 -- temp := REGEXP_REPLACE(temp, '^(.*)\S{2,}\.$','\1');
444 IF temp ilike '%MR.%' THEN
446 temp := BTRIM(REGEXP_REPLACE( temp, E'MR\.\\s*', '', 'i' ));
448 IF temp ilike '%MRS.%' THEN
450 temp := BTRIM(REGEXP_REPLACE( temp, E'MRS\.\\s*', '', 'i' ));
452 IF temp ilike '%MS.%' THEN
454 temp := BTRIM(REGEXP_REPLACE( temp, E'MS\.\\s*', '', 'i' ));
456 IF temp ilike '%DR.%' THEN
458 temp := BTRIM(REGEXP_REPLACE( temp, E'DR\.\\s*', '', 'i' ));
460 IF temp ilike '%JR.%' THEN
462 temp := BTRIM(REGEXP_REPLACE( temp, E'JR\.\\s*', '', 'i' ));
464 IF temp ilike '%JR,%' THEN
466 temp := BTRIM(REGEXP_REPLACE( temp, E'JR,\\s*', ',', 'i' ));
468 IF temp ilike '%SR.%' THEN
470 temp := BTRIM(REGEXP_REPLACE( temp, E'SR\.\\s*', '', 'i' ));
472 IF temp ilike '%SR,%' THEN
474 temp := BTRIM(REGEXP_REPLACE( temp, E'SR,\\s*', ',', 'i' ));
476 IF temp like '%III%' THEN
478 temp := BTRIM(REGEXP_REPLACE( temp, E'III', '' ));
480 IF temp like '%II%' THEN
482 temp := BTRIM(REGEXP_REPLACE( temp, E'II', '' ));
486 family_name = BTRIM(REGEXP_REPLACE(temp,'^(.*?,).*$','\1'));
487 temp := BTRIM(REPLACE( temp, family_name, '' ));
488 family_name := REPLACE( family_name, ',', '' );
490 first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(.+)\s(.+)$','\1') );
491 second_given_name := BTRIM( REGEXP_REPLACE(temp,'^(.+)\s(.+)$','\2') );
493 first_given_name := temp;
494 second_given_name := '';
497 IF temp ~ '^\S+\s+\S+\s+\S+$' THEN
498 first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\1') );
499 second_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\2') );
500 family_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)\s*(\S+)$','\3') );
502 first_given_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)$','\1') );
503 second_given_name := temp;
504 family_name := BTRIM( REGEXP_REPLACE(temp,'^(\S+)\s*(\S+)$','\2') );
508 RETURN ARRAY[ family_name, prefix, first_given_name, second_given_name, suffix ];
510 $$ LANGUAGE PLPGSQL STRICT IMMUTABLE;
512 CREATE OR REPLACE FUNCTION migration_tools.address_parse_out_citystatezip (TEXT) RETURNS TEXT[] AS $$
514 city_state_zip TEXT := $1;
519 zip := CASE WHEN city_state_zip ~ E'\\d\\d\\d\\d\\d' THEN REGEXP_REPLACE( city_state_zip, E'^.*(\\d\\d\\d\\d\\d-?\\d*).*$', E'\\1' ) ELSE '' END;
520 city_state_zip := REGEXP_REPLACE( city_state_zip, E'^(.*)\\d\\d\\d\\d\\d-?\\d*(.*)$', E'\\1\\2');
521 IF city_state_zip ~ ',' THEN
522 state := REGEXP_REPLACE( city_state_zip, E'^(.*),(.*)$', E'\\2');
523 city := REGEXP_REPLACE( city_state_zip, E'^(.*),(.*)$', E'\\1');
525 IF city_state_zip ~ E'\\s+[A-Z][A-Z]\\s*$' THEN
526 state := REGEXP_REPLACE( city_state_zip, E'^.*,?\\s+([A-Z][A-Z])\\s*$', E'\\1' );
527 city := REGEXP_REPLACE( city_state_zip, E'^(.*?),?\\s+[A-Z][A-Z](\\s*)$', E'\\1\\2' );
529 IF city_state_zip ~ E'^\\S+$' THEN
530 city := city_state_zip;
533 state := REGEXP_REPLACE( city_state_zip, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\2');
534 city := REGEXP_REPLACE( city_state_zip, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\1');
538 RETURN ARRAY[ TRIM(BOTH ' ' FROM city), TRIM(BOTH ' ' FROM state), TRIM(BOTH ' ' FROM zip) ];
540 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
542 -- try to parse data like this: 100 MAIN ST$COVINGTON, GA 30016
543 CREATE OR REPLACE FUNCTION migration_tools.parse_out_address (TEXT) RETURNS TEXT[] AS $$
545 fullstring TEXT := $1;
555 WHEN fullstring ~ E'\\d\\d\\d\\d\\d'
556 THEN REGEXP_REPLACE( fullstring, E'^.*(\\d\\d\\d\\d\\d-?\\d*).*$', E'\\1' )
559 fullstring := REGEXP_REPLACE( fullstring, E'^(.*)\\d\\d\\d\\d\\d-?\\d*(.*)$', E'\\1\\2');
561 IF fullstring ~ ',' THEN
562 state := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\2');
563 scratch1 := REGEXP_REPLACE( fullstring, E'^(.*),(.*)$', E'\\1');
565 IF fullstring ~ E'\\s+[A-Z][A-Z]\\s*$' THEN
566 state := REGEXP_REPLACE( fullstring, E'^.*,?\\s+([A-Z][A-Z])\\s*$', E'\\1' );
567 scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s+[A-Z][A-Z](\\s*)$', E'\\1\\2' );
569 IF fullstring ~ E'^\\S+$' THEN
570 scratch1 := fullstring;
573 state := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\2');
574 scratch1 := REGEXP_REPLACE( fullstring, E'^(.*?),?\\s*(\\S+)\\s*$', E'\\1');
579 IF scratch1 ~ '[\$]' THEN
580 scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\1');
581 city := REGEXP_REPLACE( scratch1, E'^(.+)[\$](.+?)$', E'\\2');
583 IF scratch1 ~ '\s' THEN
584 scratch2 := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\1');
585 city := REGEXP_REPLACE( scratch1, E'^(.+)\\s+(.+?)$', E'\\2');
592 IF scratch2 ~ '^\d' THEN
593 address1 := scratch2;
596 address1 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\1');
597 address2 := REGEXP_REPLACE( scratch2, E'^(.+?)(\\d.+)$', E'\\2');
601 TRIM(BOTH ' ' FROM address1)
602 ,TRIM(BOTH ' ' FROM address2)
603 ,TRIM(BOTH ' ' FROM city)
604 ,TRIM(BOTH ' ' FROM state)
605 ,TRIM(BOTH ' ' FROM zip)
608 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
610 CREATE OR REPLACE FUNCTION migration_tools.parse_out_address2 (TEXT) RETURNS TEXT AS $$
613 use Geo::StreetAddress::US;
615 my $a = Geo::StreetAddress::US->parse_location($address);
618 "$a->{number} $a->{prefix} $a->{street} $a->{type} $a->{suffix}"
619 ,"$a->{sec_unit_type} $a->{sec_unit_num}"
624 $$ LANGUAGE PLPERLU STABLE;
626 CREATE OR REPLACE FUNCTION migration_tools.rebarcode (o TEXT, t BIGINT) RETURNS TEXT AS $$
630 IF o ~ E'^\\d+$' AND o !~ E'^0' AND length(o) < 19 THEN -- for reference, the max value for a bigint is 9223372036854775807. May also want to consider the case where folks want to add prefixes to non-numeric barcodes
631 IF o::BIGINT < t THEN
638 $$ LANGUAGE PLPGSQL STRICT IMMUTABLE;
640 CREATE OR REPLACE FUNCTION migration_tools.base_profile_map (TEXT) RETURNS TEXT AS $$
642 migration_schema ALIAS FOR $1;
646 EXECUTE 'SELECT ''' || migration_schema || '.'' || value FROM ' || migration_schema || '.config WHERE key = ''base_profile_map'';'
651 $$ LANGUAGE PLPGSQL STRICT STABLE;
653 CREATE OR REPLACE FUNCTION migration_tools.base_item_dynamic_field_map (TEXT) RETURNS TEXT AS $$
655 migration_schema ALIAS FOR $1;
659 EXECUTE 'SELECT ''' || migration_schema || '.'' || value FROM ' || migration_schema || '.config WHERE key = ''base_item_dynamic_field_map'';'
664 $$ LANGUAGE PLPGSQL STRICT STABLE;
666 CREATE OR REPLACE FUNCTION migration_tools.base_copy_location_map (TEXT) RETURNS TEXT AS $$
668 migration_schema ALIAS FOR $1;
672 EXECUTE 'SELECT ''' || migration_schema || '.'' || value FROM ' || migration_schema || '.config WHERE key = ''base_copy_location_map'';'
677 $$ LANGUAGE PLPGSQL STRICT STABLE;
679 CREATE OR REPLACE FUNCTION migration_tools.base_circ_field_map (TEXT) RETURNS TEXT AS $$
681 migration_schema ALIAS FOR $1;
685 EXECUTE 'SELECT ''' || migration_schema || '.'' || value FROM ' || migration_schema || '.config WHERE key = ''base_circ_field_map'';'
690 $$ LANGUAGE PLPGSQL STRICT STABLE;
692 CREATE OR REPLACE FUNCTION migration_tools.map_base_patron_profile (TEXT,TEXT,INTEGER) RETURNS VOID AS $$
694 migration_schema ALIAS FOR $1;
696 patron_table ALIAS FOR $2;
697 default_patron_profile ALIAS FOR $3;
700 sql_where1 TEXT := '';
701 sql_where2 TEXT := '';
702 sql_where3 TEXT := '';
705 SELECT migration_tools.base_profile_map(migration_schema) INTO STRICT profile_map;
707 EXECUTE 'SELECT * FROM ' || profile_map || E' ORDER BY id;'
709 sql_update := 'UPDATE ' || patron_table || ' AS u SET profile = perm_grp_id FROM ' || profile_map || ' AS m WHERE ';
710 sql_where1 := NULLIF(output.legacy_field1,'') || ' = ' || quote_literal( output.legacy_value1 ) || ' AND legacy_field1 = ' || quote_literal(output.legacy_field1) || ' AND legacy_value1 = ' || quote_literal(output.legacy_value1);
711 sql_where2 := NULLIF(output.legacy_field2,'') || ' = ' || quote_literal( output.legacy_value2 ) || ' AND legacy_field2 = ' || quote_literal(output.legacy_field2) || ' AND legacy_value2 = ' || quote_literal(output.legacy_value2);
712 sql_where3 := NULLIF(output.legacy_field3,'') || ' = ' || quote_literal( output.legacy_value3 ) || ' AND legacy_field3 = ' || quote_literal(output.legacy_field3) || ' AND legacy_value3 = ' || quote_literal(output.legacy_value3);
713 sql := sql_update || COALESCE(sql_where1,'') || CASE WHEN sql_where1 <> '' AND sql_where2<> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where2,'') || CASE WHEN sql_where2 <> '' AND sql_where3 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where3,'') || ';';
714 --RAISE INFO 'sql = %', sql;
715 PERFORM migration_tools.exec( $1, sql );
717 PERFORM migration_tools.exec( $1, 'UPDATE ' || patron_table || ' AS u SET profile = ' || quote_literal(default_patron_profile) || ' WHERE profile IS NULL;' );
719 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_base_patron_mapping_profile'', now() );' );
721 WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_base_patron_mapping_profile'';' );
724 $$ LANGUAGE PLPGSQL STRICT STABLE;
726 CREATE OR REPLACE FUNCTION migration_tools.map_base_item_table_dynamic (TEXT,TEXT) RETURNS VOID AS $$
728 migration_schema ALIAS FOR $1;
730 item_table ALIAS FOR $2;
733 sql_where1 TEXT := '';
734 sql_where2 TEXT := '';
735 sql_where3 TEXT := '';
738 SELECT migration_tools.base_item_dynamic_field_map(migration_schema) INTO STRICT field_map;
740 EXECUTE 'SELECT * FROM ' || field_map || E' ORDER BY id;'
742 sql_update := 'UPDATE ' || item_table || ' AS i SET ' || output.evergreen_field || E' = ' || quote_literal(output.evergreen_value) || '::' || output.evergreen_datatype || E' FROM ' || field_map || ' AS m WHERE ';
743 sql_where1 := NULLIF(output.legacy_field1,'') || ' = ' || quote_literal( output.legacy_value1 ) || ' AND legacy_field1 = ' || quote_literal(output.legacy_field1) || ' AND legacy_value1 = ' || quote_literal(output.legacy_value1);
744 sql_where2 := NULLIF(output.legacy_field2,'') || ' = ' || quote_literal( output.legacy_value2 ) || ' AND legacy_field2 = ' || quote_literal(output.legacy_field2) || ' AND legacy_value2 = ' || quote_literal(output.legacy_value2);
745 sql_where3 := NULLIF(output.legacy_field3,'') || ' = ' || quote_literal( output.legacy_value3 ) || ' AND legacy_field3 = ' || quote_literal(output.legacy_field3) || ' AND legacy_value3 = ' || quote_literal(output.legacy_value3);
746 sql := sql_update || COALESCE(sql_where1,'') || CASE WHEN sql_where1 <> '' AND sql_where2<> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where2,'') || CASE WHEN sql_where2 <> '' AND sql_where3 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where3,'') || ';';
747 --RAISE INFO 'sql = %', sql;
748 PERFORM migration_tools.exec( $1, sql );
751 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_base_item_mapping_dynamic'', now() );' );
753 WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_base_item_mapping_dynamic'';' );
756 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
758 CREATE OR REPLACE FUNCTION migration_tools.map_base_item_table_locations (TEXT,TEXT) RETURNS VOID AS $$
760 migration_schema ALIAS FOR $1;
761 base_copy_location_map TEXT;
762 item_table ALIAS FOR $2;
765 sql_where1 TEXT := '';
766 sql_where2 TEXT := '';
767 sql_where3 TEXT := '';
770 SELECT migration_tools.base_copy_location_map(migration_schema) INTO STRICT base_copy_location_map;
772 EXECUTE 'SELECT * FROM ' || base_copy_location_map || E' ORDER BY id;'
774 sql_update := 'UPDATE ' || item_table || ' AS i SET location = m.location FROM ' || base_copy_location_map || ' AS m WHERE ';
775 sql_where1 := NULLIF(output.legacy_field1,'') || ' = ' || quote_literal( output.legacy_value1 ) || ' AND legacy_field1 = ' || quote_literal(output.legacy_field1) || ' AND legacy_value1 = ' || quote_literal(output.legacy_value1);
776 sql_where2 := NULLIF(output.legacy_field2,'') || ' = ' || quote_literal( output.legacy_value2 ) || ' AND legacy_field2 = ' || quote_literal(output.legacy_field2) || ' AND legacy_value2 = ' || quote_literal(output.legacy_value2);
777 sql_where3 := NULLIF(output.legacy_field3,'') || ' = ' || quote_literal( output.legacy_value3 ) || ' AND legacy_field3 = ' || quote_literal(output.legacy_field3) || ' AND legacy_value3 = ' || quote_literal(output.legacy_value3);
778 sql := sql_update || COALESCE(sql_where1,'') || CASE WHEN sql_where1 <> '' AND sql_where2<> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where2,'') || CASE WHEN sql_where2 <> '' AND sql_where3 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where3,'') || ';';
779 --RAISE INFO 'sql = %', sql;
780 PERFORM migration_tools.exec( $1, sql );
783 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_base_item_mapping_locations'', now() );' );
785 WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_base_item_mapping_locations'';' );
788 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
790 -- circulate loan period max renewals max out fine amount fine interval max fine item field 1 item value 1 item field 2 item value 2 patron field 1 patron value 1 patron field 2 patron value 2
791 CREATE OR REPLACE FUNCTION migration_tools.map_base_circ_table_dynamic (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$
793 migration_schema ALIAS FOR $1;
795 circ_table ALIAS FOR $2;
796 item_table ALIAS FOR $3;
797 patron_table ALIAS FOR $4;
800 sql_where1 TEXT := '';
801 sql_where2 TEXT := '';
802 sql_where3 TEXT := '';
803 sql_where4 TEXT := '';
806 SELECT migration_tools.base_circ_field_map(migration_schema) INTO STRICT field_map;
808 EXECUTE 'SELECT * FROM ' || field_map || E' ORDER BY id;'
810 sql_update := 'UPDATE ' || circ_table || ' AS c SET duration = ' || quote_literal(output.loan_period) || '::INTERVAL, renewal_remaining = ' || quote_literal(output.max_renewals) || '::INTEGER, recuring_fine = ' || quote_literal(output.fine_amount) || '::NUMERIC(6,2), fine_interval = ' || quote_literal(output.fine_interval) || '::INTERVAL, max_fine = ' || quote_literal(output.max_fine) || '::NUMERIC(6,2) FROM ' || field_map || ' AS m, ' || item_table || ' AS i, ' || patron_table || ' AS u WHERE c.usr = u.id AND c.target_copy = i.id AND ';
811 sql_where1 := NULLIF(output.item_field1,'') || ' = ' || quote_literal( output.item_value1 ) || ' AND item_field1 = ' || quote_literal(output.item_field1) || ' AND item_value1 = ' || quote_literal(output.item_value1);
812 sql_where2 := NULLIF(output.item_field2,'') || ' = ' || quote_literal( output.item_value2 ) || ' AND item_field2 = ' || quote_literal(output.item_field2) || ' AND item_value2 = ' || quote_literal(output.item_value2);
813 sql_where3 := NULLIF(output.patron_field1,'') || ' = ' || quote_literal( output.patron_value1 ) || ' AND patron_field1 = ' || quote_literal(output.patron_field1) || ' AND patron_value1 = ' || quote_literal(output.patron_value1);
814 sql_where4 := NULLIF(output.patron_field2,'') || ' = ' || quote_literal( output.patron_value2 ) || ' AND patron_field2 = ' || quote_literal(output.patron_field2) || ' AND patron_value2 = ' || quote_literal(output.patron_value2);
815 sql := sql_update || COALESCE(sql_where1,'') || CASE WHEN sql_where1 <> '' AND sql_where2<> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where2,'') || CASE WHEN sql_where2 <> '' AND sql_where3 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where3,'') || CASE WHEN sql_where3 <> '' AND sql_where4 <> '' THEN ' AND ' ELSE '' END || COALESCE(sql_where4,'') || ';';
816 --RAISE INFO 'sql = %', sql;
817 PERFORM migration_tools.exec( $1, sql );
820 PERFORM migration_tools.exec( $1, 'INSERT INTO ' || migration_schema || '.config (key,value) VALUES ( ''last_base_circ_field_mapping'', now() );' );
822 WHEN OTHERS THEN PERFORM migration_tools.exec( $1, 'UPDATE ' || migration_schema || '.config SET value = now() WHERE key = ''last_base_circ_field_mapping'';' );
825 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
828 -- $barcode source barcode
829 -- $prefix prefix to add to barcode, NULL = add no prefix
830 -- $maxlen maximum length of barcode; default to 14 if left NULL
831 -- $pad padding string to apply to left of source barcode before adding
832 -- prefix and suffix; set to NULL or '' if no padding is desired
833 -- $suffix suffix to add to barcode, NULL = add no suffix
835 -- Returns a new string consisting of prefix concatenated with padded barcode and suffix.
836 -- If new barcode would be longer than $maxlen, the original barcode is returned instead.
838 CREATE OR REPLACE FUNCTION migration_tools.expand_barcode (TEXT, TEXT, INTEGER, TEXT, TEXT) RETURNS TEXT AS $$
839 my ($barcode, $prefix, $maxlen, $pad, $suffix) = @_;
842 return unless defined $barcode;
844 $prefix = '' unless defined $prefix;
846 $pad = '0' unless defined $pad;
847 $suffix = '' unless defined $suffix;
849 # bail out if adding prefix and suffix would bring new barcode over max length
850 return $barcode if (length($prefix) + length($barcode) + length($suffix)) > $maxlen;
852 my $new_barcode = $barcode;
854 my $pad_length = $maxlen - length($prefix) - length($suffix);
855 if (length($barcode) < $pad_length) {
856 # assuming we always want padding on the left
857 # also assuming that it is possible to have the pad string be longer than 1 character
858 $new_barcode = substr($pad x ($pad_length - length($barcode)), 0, $pad_length - length($barcode)) . $new_barcode;
862 # bail out if adding prefix and suffix would bring new barcode over max length
863 return $barcode if (length($prefix) + length($new_barcode) + length($suffix)) > $maxlen;
865 return "$prefix$new_barcode$suffix";
866 $$ LANGUAGE PLPERLU STABLE;
868 -- remove previous version of this function
869 DROP FUNCTION IF EXISTS migration_tools.attempt_cast(TEXT, TEXT, TEXT);
871 CREATE OR REPLACE FUNCTION migration_tools.attempt_cast (TEXT, TEXT) RETURNS TEXT AS $$
873 attempt_value ALIAS FOR $1;
874 datatype ALIAS FOR $2;
876 EXECUTE 'SELECT ' || quote_literal(attempt_value) || '::' || datatype || ' AS a;';
877 RETURN attempt_value;
879 WHEN OTHERS THEN RETURN NULL;
881 $$ LANGUAGE PLPGSQL STRICT STABLE;
883 CREATE OR REPLACE FUNCTION migration_tools.attempt_date (TEXT,TEXT) RETURNS DATE AS $$
885 attempt_value ALIAS FOR $1;
886 fail_value ALIAS FOR $2;
890 EXECUTE 'SELECT ' || quote_literal(REGEXP_REPLACE(attempt_value,'^(\d\d)(\d\d)(\d\d)$','\1-\2-\3')) || '::date AS a;'
897 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::date AS a;'
902 $$ LANGUAGE PLPGSQL STRICT STABLE;
904 CREATE OR REPLACE FUNCTION migration_tools.attempt_timestamptz (TEXT,TEXT) RETURNS TIMESTAMPTZ AS $$
906 attempt_value ALIAS FOR $1;
907 fail_value ALIAS FOR $2;
911 EXECUTE 'SELECT ' || quote_literal(attempt_value) || '::TIMESTAMPTZ AS a;'
918 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::TIMESTAMPTZ AS a;'
923 $$ LANGUAGE PLPGSQL STRICT STABLE;
925 CREATE OR REPLACE FUNCTION migration_tools.attempt_hz_date (TEXT,TEXT) RETURNS DATE AS $$
927 attempt_value ALIAS FOR $1;
928 fail_value ALIAS FOR $2;
932 EXECUTE E'SELECT (\'1970-01-01\'::date + \'' || attempt_value || E' days\'::interval)::date AS a;'
939 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::date AS a;'
944 $$ LANGUAGE PLPGSQL STRICT STABLE;
946 CREATE OR REPLACE FUNCTION migration_tools.attempt_sierra_timestamp (TEXT,TEXT) RETURNS TIMESTAMP AS $$
948 attempt_value ALIAS FOR $1;
949 fail_value ALIAS FOR $2;
952 output := REGEXP_REPLACE(attempt_value,E'^(..)(..)(..)(..)(..)$',E'20\\1-\\2-\\3 \\4:\\5')::TIMESTAMP;
957 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::TIMESTAMP AS a;'
962 $$ LANGUAGE PLPGSQL STRICT STABLE;
964 CREATE OR REPLACE FUNCTION migration_tools.attempt_money (TEXT,TEXT) RETURNS NUMERIC(8,2) AS $$
966 attempt_value ALIAS FOR $1;
967 fail_value ALIAS FOR $2;
971 EXECUTE 'SELECT ' || quote_literal(REPLACE(REPLACE(attempt_value,'$',''),',','')) || '::NUMERIC(8,2) AS a;'
978 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::NUMERIC(8,2) AS a;'
983 $$ LANGUAGE PLPGSQL STRICT STABLE;
985 CREATE OR REPLACE FUNCTION migration_tools.attempt_money6 (TEXT,TEXT) RETURNS NUMERIC(6,2) AS $$
987 attempt_value ALIAS FOR $1;
988 fail_value ALIAS FOR $2;
992 EXECUTE 'SELECT ' || quote_literal(REPLACE(REPLACE(attempt_value,'$',''),',','')) || '::NUMERIC(6,2) AS a;'
999 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::NUMERIC(6,2) AS a;'
1004 $$ LANGUAGE PLPGSQL STRICT STABLE;
1006 CREATE OR REPLACE FUNCTION migration_tools.attempt_money_from_pennies (TEXT,TEXT) RETURNS NUMERIC(8,2) AS $$
1008 attempt_value ALIAS FOR $1;
1009 fail_value ALIAS FOR $2;
1010 output NUMERIC(8,2);
1012 IF length(regexp_replace(attempt_value,'^0+','')) > 10 THEN
1013 RAISE EXCEPTION 'too many digits';
1016 EXECUTE 'SELECT ' || quote_literal((left(lpad(regexp_replace(attempt_value,'^0+',''),10,'0'),-2) || '.' || right(lpad(regexp_replace(attempt_value,'^0+',''),10,'0'),2))::numeric(8,2)) || '::NUMERIC(8,2) AS a;'
1023 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::NUMERIC(8,2) AS a;'
1028 $$ LANGUAGE PLPGSQL STRICT STABLE;
1030 CREATE OR REPLACE FUNCTION migration_tools.attempt_money_from_pennies6 (TEXT,TEXT) RETURNS NUMERIC(6,2) AS $$
1032 attempt_value ALIAS FOR $1;
1033 fail_value ALIAS FOR $2;
1034 output NUMERIC(6,2);
1036 IF length(regexp_replace(attempt_value,'^0+','')) > 8 THEN
1037 RAISE EXCEPTION 'too many digits';
1040 EXECUTE 'SELECT ' || quote_literal((left(lpad(regexp_replace(attempt_value,'^0+',''),8,'0'),-2) || '.' || right(lpad(regexp_replace(attempt_value,'^0+',''),8,'0'),2))::numeric(6,2)) || '::NUMERIC(6,2) AS a;'
1047 EXECUTE 'SELECT ' || quote_literal(fail_value) || '::NUMERIC(6,2) AS a;'
1052 $$ LANGUAGE PLPGSQL STRICT STABLE;
1054 -- add_codabar_checkdigit
1055 -- $barcode source barcode
1057 -- If the source string is 13 or 14 characters long and contains only digits, adds or replaces the 14
1058 -- character with a checkdigit computed according to the usual algorithm for library barcodes
1059 -- using the Codabar symbology - see <http://www.makebarcode.com/specs/codabar.html>. If the
1060 -- input string does not meet those requirements, it is returned unchanged.
1062 CREATE OR REPLACE FUNCTION migration_tools.add_codabar_checkdigit (TEXT) RETURNS TEXT AS $$
1063 my $barcode = shift;
1065 return $barcode if $barcode !~ /^\d{13,14}$/;
1066 $barcode = substr($barcode, 0, 13); # ignore 14th digit
1067 my @digits = split //, $barcode;
1069 $total += $digits[$_] foreach (1, 3, 5, 7, 9, 11);
1070 $total += (2 * $digits[$_] >= 10) ? (2 * $digits[$_] - 9) : (2 * $digits[$_]) foreach (0, 2, 4, 6, 8, 10, 12);
1071 my $remainder = $total % 10;
1072 my $checkdigit = ($remainder == 0) ? $remainder : 10 - $remainder;
1073 return $barcode . $checkdigit;
1074 $$ LANGUAGE PLPERLU STRICT STABLE;
1076 -- add_code39mod43_checkdigit
1077 -- $barcode source barcode
1079 -- If the source string is 13 or 14 characters long and contains only valid
1080 -- Code 39 mod 43 characters, adds or replaces the 14th
1081 -- character with a checkdigit computed according to the usual algorithm for library barcodes
1082 -- using the Code 39 mod 43 symbology - see <http://en.wikipedia.org/wiki/Code_39#Code_39_mod_43>. If the
1083 -- input string does not meet those requirements, it is returned unchanged.
1085 CREATE OR REPLACE FUNCTION migration_tools.add_code39mod43_checkdigit (TEXT) RETURNS TEXT AS $$
1086 my $barcode = shift;
1088 return $barcode if $barcode !~ /^[0-9A-Z. $\/+%-]{13,14}$/;
1089 $barcode = substr($barcode, 0, 13); # ignore 14th character
1091 my @valid_chars = split //, '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ-. $/+%';
1092 my %nums = map { $valid_chars[$_] => $_ } (0..42);
1095 $total += $nums{$_} foreach split(//, $barcode);
1096 my $remainder = $total % 43;
1097 my $checkdigit = $valid_chars[$remainder];
1098 return $barcode . $checkdigit;
1099 $$ LANGUAGE PLPERLU STRICT STABLE;
1101 -- add_mod16_checkdigit
1102 -- $barcode source barcode
1104 -- https://www.activebarcode.com/codes/checkdigit/modulo16.html
1106 CREATE OR REPLACE FUNCTION migration_tools.add_mod16_checkdigit (TEXT) RETURNS TEXT AS $$
1107 my $barcode = shift;
1109 my @digits = split //, $barcode;
1111 foreach $digit (@digits) {
1112 if ($digit =~ /[0-9]/) { $total += $digit;
1113 } elsif ($digit eq '-') { $total += 10;
1114 } elsif ($digit eq '$') { $total += 11;
1115 } elsif ($digit eq ':') { $total += 12;
1116 } elsif ($digit eq '/') { $total += 13;
1117 } elsif ($digit eq '.') { $total += 14;
1118 } elsif ($digit eq '+') { $total += 15;
1119 } elsif ($digit eq 'A') { $total += 16;
1120 } elsif ($digit eq 'B') { $total += 17;
1121 } elsif ($digit eq 'C') { $total += 18;
1122 } elsif ($digit eq 'D') { $total += 19;
1123 } else { die "invalid digit <$digit>";
1126 my $remainder = $total % 16;
1127 my $difference = 16 - $remainder;
1129 if ($difference < 10) { $checkdigit = $difference;
1130 } elsif ($difference == 10) { $checkdigit = '-';
1131 } elsif ($difference == 11) { $checkdigit = '$';
1132 } elsif ($difference == 12) { $checkdigit = ':';
1133 } elsif ($difference == 13) { $checkdigit = '/';
1134 } elsif ($difference == 14) { $checkdigit = '.';
1135 } elsif ($difference == 15) { $checkdigit = '+';
1136 } else { die "error calculating checkdigit";
1139 return $barcode . $checkdigit;
1140 $$ LANGUAGE PLPERLU STRICT STABLE;
1142 CREATE OR REPLACE FUNCTION migration_tools.attempt_phone (TEXT,TEXT) RETURNS TEXT AS $$
1145 areacode TEXT := $2;
1148 n_digits INTEGER := 0;
1151 temp := REGEXP_REPLACE(temp, '^1*[^0-9]*(?=[0-9])', '');
1152 temp := REGEXP_REPLACE(temp, '[^0-9]*([0-9]{3})[^0-9]*([0-9]{3})[^0-9]*([0-9]{4})', E'\\1-\\2-\\3');
1153 n_digits := LENGTH(REGEXP_REPLACE(REGEXP_REPLACE(temp, '(.*)?[a-zA-Z].*', E'\\1') , '[^0-9]', '', 'g'));
1154 IF n_digits = 7 AND areacode <> '' THEN
1155 temp := REGEXP_REPLACE(temp, '[^0-9]*([0-9]{3})[^0-9]*([0-9]{4})', E'\\1-\\2');
1156 output := (areacode || '-' || temp);
1163 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
1165 CREATE OR REPLACE FUNCTION migration_tools.set_leader (TEXT, INT, TEXT) RETURNS TEXT AS $$
1166 my ($marcxml, $pos, $value) = @_;
1169 use MARC::File::XML;
1173 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
1174 my $leader = $marc->leader();
1175 substr($leader, $pos, 1) = $value;
1176 $marc->leader($leader);
1177 $xml = $marc->as_xml_record;
1178 $xml =~ s/^<\?.+?\?>$//mo;
1180 $xml =~ s/>\s+</></sgo;
1183 $$ LANGUAGE PLPERLU STABLE;
1185 CREATE OR REPLACE FUNCTION migration_tools.set_008 (TEXT, INT, TEXT) RETURNS TEXT AS $$
1186 my ($marcxml, $pos, $value) = @_;
1189 use MARC::File::XML;
1193 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
1194 my $f008 = $marc->field('008');
1197 my $field = $f008->data();
1198 substr($field, $pos, 1) = $value;
1199 $f008->update($field);
1200 $xml = $marc->as_xml_record;
1201 $xml =~ s/^<\?.+?\?>$//mo;
1203 $xml =~ s/>\s+</></sgo;
1207 $$ LANGUAGE PLPERLU STABLE;
1210 CREATE OR REPLACE FUNCTION migration_tools.is_staff_profile (INT) RETURNS BOOLEAN AS $$
1212 profile ALIAS FOR $1;
1214 RETURN CASE WHEN 'Staff' IN (select (permission.grp_ancestors(profile)).name) THEN TRUE ELSE FALSE END;
1216 $$ LANGUAGE PLPGSQL STRICT STABLE;
1219 CREATE OR REPLACE FUNCTION migration_tools.is_blank (TEXT) RETURNS BOOLEAN AS $$
1221 RETURN CASE WHEN $1 = '' THEN TRUE ELSE FALSE END;
1223 $$ LANGUAGE PLPGSQL STRICT STABLE;
1226 CREATE OR REPLACE FUNCTION migration_tools.insert_tags (TEXT, TEXT) RETURNS TEXT AS $$
1228 my ($marcxml, $tags) = @_;
1231 use MARC::File::XML;
1236 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
1237 my $to_insert = MARC::Record->new_from_xml("<record>$tags</record>", 'UTF-8');
1239 my @incumbents = ();
1241 foreach my $field ( $marc->fields() ) {
1242 push @incumbents, $field->as_formatted();
1245 foreach $field ( $to_insert->fields() ) {
1246 if (!grep {$_ eq $field->as_formatted()} @incumbents) {
1247 $marc->insert_fields_ordered( ($field) );
1251 $xml = $marc->as_xml_record;
1252 $xml =~ s/^<\?.+?\?>$//mo;
1254 $xml =~ s/>\s+</></sgo;
1259 $$ LANGUAGE PLPERLU STABLE;
1261 CREATE OR REPLACE FUNCTION migration_tools.apply_circ_matrix( tablename TEXT ) RETURNS VOID AS $$
1265 -- First make sure the circ matrix is loaded and the circulations
1266 -- have been staged to the extent possible (but at the very least
1267 -- circ_lib, target_copy, usr, and *_renewal). User profiles and
1268 -- circ modifiers must also be in place.
1270 -- SELECT migration_tools.apply_circ_matrix('m_pioneer.action_circulation');
1278 this_duration_rule INT;
1280 this_max_fine_rule INT;
1281 rcd config.rule_circ_duration%ROWTYPE;
1282 rrf config.rule_recurring_fine%ROWTYPE;
1283 rmf config.rule_max_fine%ROWTYPE;
1290 EXECUTE 'SELECT COUNT(*) FROM ' || tablename || ';' INTO n_circs;
1292 FOR circ IN EXECUTE ('SELECT id FROM ' || tablename) LOOP
1294 -- Fetch the correct rules for this circulation
1301 WHEN phone_renewal OR desk_renewal OR opac_renewal THEN TRUE
1304 FROM ' || tablename || ' WHERE id = ' || circ || ';')
1305 INTO circ_lib, target_copy, usr, is_renewal ;
1307 INTO this_duration_rule,
1311 recurring_fine_rule,
1313 FROM action.item_user_circ_test(
1319 SELECT INTO rcd * FROM config.rule_circ_duration
1320 WHERE id = this_duration_rule;
1321 SELECT INTO rrf * FROM config.rule_recurring_fine
1322 WHERE id = this_fine_rule;
1323 SELECT INTO rmf * FROM config.rule_max_fine
1324 WHERE id = this_max_fine_rule;
1326 -- Apply the rules to this circulation
1327 EXECUTE ('UPDATE ' || tablename || ' c
1329 duration_rule = rcd.name,
1330 recurring_fine_rule = rrf.name,
1331 max_fine_rule = rmf.name,
1332 duration = rcd.normal,
1333 recurring_fine = rrf.normal,
1336 WHEN TRUE THEN (rmf.amount / 100.0) * ac.price
1339 renewal_remaining = rcd.max_renewals
1341 config.rule_circ_duration rcd,
1342 config.rule_recurring_fine rrf,
1343 config.rule_max_fine rmf,
1346 rcd.id = ' || this_duration_rule || ' AND
1347 rrf.id = ' || this_fine_rule || ' AND
1348 rmf.id = ' || this_max_fine_rule || ' AND
1349 ac.id = c.target_copy AND
1350 c.id = ' || circ || ';');
1352 -- Keep track of where we are in the process
1354 IF (n % 100 = 0) THEN
1355 RAISE INFO '%', n || ' of ' || n_circs
1356 || ' (' || (100*n/n_circs) || '%) circs updated.';
1364 $$ LANGUAGE plpgsql;
1366 CREATE OR REPLACE FUNCTION migration_tools.apply_circ_matrix_before_20( tablename TEXT ) RETURNS VOID AS $$
1370 -- First make sure the circ matrix is loaded and the circulations
1371 -- have been staged to the extent possible (but at the very least
1372 -- circ_lib, target_copy, usr, and *_renewal). User profiles and
1373 -- circ modifiers must also be in place.
1375 -- SELECT migration_tools.apply_circ_matrix('m_pioneer.action_circulation');
1383 this_duration_rule INT;
1385 this_max_fine_rule INT;
1386 rcd config.rule_circ_duration%ROWTYPE;
1387 rrf config.rule_recurring_fine%ROWTYPE;
1388 rmf config.rule_max_fine%ROWTYPE;
1395 EXECUTE 'SELECT COUNT(*) FROM ' || tablename || ';' INTO n_circs;
1397 FOR circ IN EXECUTE ('SELECT id FROM ' || tablename) LOOP
1399 -- Fetch the correct rules for this circulation
1406 WHEN phone_renewal OR desk_renewal OR opac_renewal THEN TRUE
1409 FROM ' || tablename || ' WHERE id = ' || circ || ';')
1410 INTO circ_lib, target_copy, usr, is_renewal ;
1412 INTO this_duration_rule,
1418 FROM action.find_circ_matrix_matchpoint(
1424 SELECT INTO rcd * FROM config.rule_circ_duration
1425 WHERE id = this_duration_rule;
1426 SELECT INTO rrf * FROM config.rule_recurring_fine
1427 WHERE id = this_fine_rule;
1428 SELECT INTO rmf * FROM config.rule_max_fine
1429 WHERE id = this_max_fine_rule;
1431 -- Apply the rules to this circulation
1432 EXECUTE ('UPDATE ' || tablename || ' c
1434 duration_rule = rcd.name,
1435 recuring_fine_rule = rrf.name,
1436 max_fine_rule = rmf.name,
1437 duration = rcd.normal,
1438 recuring_fine = rrf.normal,
1441 WHEN TRUE THEN (rmf.amount / 100.0) * ac.price
1444 renewal_remaining = rcd.max_renewals
1446 config.rule_circ_duration rcd,
1447 config.rule_recuring_fine rrf,
1448 config.rule_max_fine rmf,
1451 rcd.id = ' || this_duration_rule || ' AND
1452 rrf.id = ' || this_fine_rule || ' AND
1453 rmf.id = ' || this_max_fine_rule || ' AND
1454 ac.id = c.target_copy AND
1455 c.id = ' || circ || ';');
1457 -- Keep track of where we are in the process
1459 IF (n % 100 = 0) THEN
1460 RAISE INFO '%', n || ' of ' || n_circs
1461 || ' (' || (100*n/n_circs) || '%) circs updated.';
1469 $$ LANGUAGE plpgsql;
1471 CREATE OR REPLACE FUNCTION migration_tools.apply_circ_matrix_after_20( tablename TEXT ) RETURNS VOID AS $$
1475 -- First make sure the circ matrix is loaded and the circulations
1476 -- have been staged to the extent possible (but at the very least
1477 -- circ_lib, target_copy, usr, and *_renewal). User profiles and
1478 -- circ modifiers must also be in place.
1480 -- SELECT migration_tools.apply_circ_matrix('m_pioneer.action_circulation');
1488 this_duration_rule INT;
1490 this_max_fine_rule INT;
1491 rcd config.rule_circ_duration%ROWTYPE;
1492 rrf config.rule_recurring_fine%ROWTYPE;
1493 rmf config.rule_max_fine%ROWTYPE;
1500 EXECUTE 'SELECT COUNT(*) FROM ' || tablename || ';' INTO n_circs;
1502 FOR circ IN EXECUTE ('SELECT id FROM ' || tablename) LOOP
1504 -- Fetch the correct rules for this circulation
1511 WHEN phone_renewal OR desk_renewal OR opac_renewal THEN TRUE
1514 FROM ' || tablename || ' WHERE id = ' || circ || ';')
1515 INTO circ_lib, target_copy, usr, is_renewal ;
1517 INTO this_duration_rule,
1520 (matchpoint).duration_rule,
1521 (matchpoint).recurring_fine_rule,
1522 (matchpoint).max_fine_rule
1523 FROM action.find_circ_matrix_matchpoint(
1529 SELECT INTO rcd * FROM config.rule_circ_duration
1530 WHERE id = this_duration_rule;
1531 SELECT INTO rrf * FROM config.rule_recurring_fine
1532 WHERE id = this_fine_rule;
1533 SELECT INTO rmf * FROM config.rule_max_fine
1534 WHERE id = this_max_fine_rule;
1536 -- Apply the rules to this circulation
1537 EXECUTE ('UPDATE ' || tablename || ' c
1539 duration_rule = rcd.name,
1540 recurring_fine_rule = rrf.name,
1541 max_fine_rule = rmf.name,
1542 duration = rcd.normal,
1543 recurring_fine = rrf.normal,
1546 WHEN TRUE THEN (rmf.amount / 100.0) * ac.price
1549 renewal_remaining = rcd.max_renewals,
1550 grace_period = rrf.grace_period
1552 config.rule_circ_duration rcd,
1553 config.rule_recurring_fine rrf,
1554 config.rule_max_fine rmf,
1557 rcd.id = ' || this_duration_rule || ' AND
1558 rrf.id = ' || this_fine_rule || ' AND
1559 rmf.id = ' || this_max_fine_rule || ' AND
1560 ac.id = c.target_copy AND
1561 c.id = ' || circ || ';');
1563 -- Keep track of where we are in the process
1565 IF (n % 100 = 0) THEN
1566 RAISE INFO '%', n || ' of ' || n_circs
1567 || ' (' || (100*n/n_circs) || '%) circs updated.';
1575 $$ LANGUAGE plpgsql;
1577 CREATE OR REPLACE FUNCTION migration_tools.apply_circ_matrix_to_specific_circ( tablename TEXT, circ BIGINT ) RETURNS VOID AS $$
1581 -- First make sure the circ matrix is loaded and the circulations
1582 -- have been staged to the extent possible (but at the very least
1583 -- circ_lib, target_copy, usr, and *_renewal). User profiles and
1584 -- circ modifiers must also be in place.
1586 -- SELECT migration_tools.apply_circ_matrix_to_specific_circ('m_nwrl.action_circulation', 18391960);
1594 this_duration_rule INT;
1596 this_max_fine_rule INT;
1597 rcd config.rule_circ_duration%ROWTYPE;
1598 rrf config.rule_recurring_fine%ROWTYPE;
1599 rmf config.rule_max_fine%ROWTYPE;
1605 --EXECUTE 'SELECT COUNT(*) FROM ' || tablename || ';' INTO n_circs;
1607 --FOR circ IN EXECUTE ('SELECT id FROM ' || tablename) LOOP
1609 -- Fetch the correct rules for this circulation
1616 WHEN phone_renewal OR desk_renewal OR opac_renewal THEN TRUE
1619 FROM ' || tablename || ' WHERE id = ' || circ || ';')
1620 INTO circ_lib, target_copy, usr, is_renewal ;
1622 INTO this_duration_rule,
1625 (matchpoint).duration_rule,
1626 (matchpoint).recurring_fine_rule,
1627 (matchpoint).max_fine_rule
1628 FROM action.find_circ_matrix_matchpoint(
1634 SELECT INTO rcd * FROM config.rule_circ_duration
1635 WHERE id = this_duration_rule;
1636 SELECT INTO rrf * FROM config.rule_recurring_fine
1637 WHERE id = this_fine_rule;
1638 SELECT INTO rmf * FROM config.rule_max_fine
1639 WHERE id = this_max_fine_rule;
1641 -- Apply the rules to this circulation
1642 EXECUTE ('UPDATE ' || tablename || ' c
1644 duration_rule = rcd.name,
1645 recurring_fine_rule = rrf.name,
1646 max_fine_rule = rmf.name,
1647 duration = rcd.normal,
1648 recurring_fine = rrf.normal,
1651 WHEN TRUE THEN (rmf.amount / 100.0) * ac.price
1654 renewal_remaining = rcd.max_renewals,
1655 grace_period = rrf.grace_period
1657 config.rule_circ_duration rcd,
1658 config.rule_recurring_fine rrf,
1659 config.rule_max_fine rmf,
1662 rcd.id = ' || this_duration_rule || ' AND
1663 rrf.id = ' || this_fine_rule || ' AND
1664 rmf.id = ' || this_max_fine_rule || ' AND
1665 ac.id = c.target_copy AND
1666 c.id = ' || circ || ';');
1668 -- Keep track of where we are in the process
1670 IF (n % 100 = 0) THEN
1671 RAISE INFO '%', n || ' of ' || n_circs
1672 || ' (' || (100*n/n_circs) || '%) circs updated.';
1680 $$ LANGUAGE plpgsql;
1685 CREATE OR REPLACE FUNCTION migration_tools.stage_not_applicable_asset_stat_cats( schemaname TEXT ) RETURNS VOID AS $$
1687 -- USAGE: Make sure the stat_cat and stat_cat_entry tables are populated, including exactly one 'Not Applicable' entry per stat cat.
1688 -- Then SELECT migration_tools.stage_not_applicable_asset_stat_cats('m_foo');
1690 -- TODO: Make a variant that will go directly to production tables -- which would be useful for retrofixing the absence of N/A cats.
1691 -- TODO: Add a similar tool for actor stat cats, which behave differently.
1694 c TEXT := schemaname || '.asset_copy_legacy';
1695 sc TEXT := schemaname || '.asset_stat_cat';
1696 sce TEXT := schemaname || '.asset_stat_cat_entry';
1697 scecm TEXT := schemaname || '.asset_stat_cat_entry_copy_map';
1703 FOR stat_cat IN EXECUTE ('SELECT id FROM ' || sc) LOOP
1705 EXECUTE ('SELECT id FROM ' || sce || ' WHERE stat_cat = ' || stat_cat || E' AND value = \'Not Applicable\';') INTO stat_cat_entry;
1707 EXECUTE ('INSERT INTO ' || scecm || ' (owning_copy, stat_cat, stat_cat_entry)
1708 SELECT c.id, ' || stat_cat || ', ' || stat_cat_entry || ' FROM ' || c || ' c WHERE c.id NOT IN
1709 (SELECT owning_copy FROM ' || scecm || ' WHERE stat_cat = ' || stat_cat || ');');
1716 $$ LANGUAGE plpgsql;
1718 CREATE OR REPLACE FUNCTION migration_tools.assign_standing_penalties ( ) RETURNS VOID AS $$
1720 -- USAGE: Once circulation data has been loaded, and group penalty thresholds have been set up, run this.
1721 -- This will assign standing penalties as needed.
1729 FOR org_unit IN EXECUTE ('SELECT DISTINCT org_unit FROM permission.grp_penalty_threshold;') LOOP
1731 FOR usr IN EXECUTE ('SELECT id FROM actor.usr WHERE NOT deleted;') LOOP
1733 EXECUTE('SELECT actor.calculate_system_penalties(' || usr || ', ' || org_unit || ');');
1743 $$ LANGUAGE plpgsql;
1746 CREATE OR REPLACE FUNCTION migration_tools.insert_metarecords_for_pristine_database () RETURNS VOID AS $$
1749 INSERT INTO metabib.metarecord (fingerprint, master_record)
1750 SELECT DISTINCT ON (b.fingerprint) b.fingerprint, b.id
1751 FROM biblio.record_entry b
1753 AND b.id IN (SELECT r.id FROM biblio.record_entry r LEFT JOIN metabib.metarecord_source_map k ON (k.source = r.id) WHERE k.id IS NULL AND r.fingerprint IS NOT NULL)
1754 AND NOT EXISTS ( SELECT 1 FROM metabib.metarecord WHERE fingerprint = b.fingerprint )
1755 ORDER BY b.fingerprint, b.quality DESC;
1756 INSERT INTO metabib.metarecord_source_map (metarecord, source)
1758 FROM biblio.record_entry r
1759 JOIN metabib.metarecord m USING (fingerprint)
1760 WHERE NOT r.deleted;
1763 $$ LANGUAGE plpgsql;
1766 CREATE OR REPLACE FUNCTION migration_tools.insert_metarecords_for_incumbent_database () RETURNS VOID AS $$
1769 INSERT INTO metabib.metarecord (fingerprint, master_record)
1770 SELECT DISTINCT ON (b.fingerprint) b.fingerprint, b.id
1771 FROM biblio.record_entry b
1773 AND b.id IN (SELECT r.id FROM biblio.record_entry r LEFT JOIN metabib.metarecord_source_map k ON (k.source = r.id) WHERE k.id IS NULL AND r.fingerprint IS NOT NULL)
1774 AND NOT EXISTS ( SELECT 1 FROM metabib.metarecord WHERE fingerprint = b.fingerprint )
1775 ORDER BY b.fingerprint, b.quality DESC;
1776 INSERT INTO metabib.metarecord_source_map (metarecord, source)
1778 FROM biblio.record_entry r
1779 JOIN metabib.metarecord m USING (fingerprint)
1781 AND r.id IN (SELECT b.id FROM biblio.record_entry b LEFT JOIN metabib.metarecord_source_map k ON (k.source = b.id) WHERE k.id IS NULL);
1784 $$ LANGUAGE plpgsql;
1787 CREATE OR REPLACE FUNCTION migration_tools.create_cards( schemaname TEXT ) RETURNS VOID AS $$
1789 -- USAGE: Make sure the patrons are staged in schemaname.actor_usr_legacy and have 'usrname' assigned.
1790 -- Then SELECT migration_tools.create_cards('m_foo');
1793 u TEXT := schemaname || '.actor_usr_legacy';
1794 c TEXT := schemaname || '.actor_card';
1798 EXECUTE ('DELETE FROM ' || c || ';');
1799 EXECUTE ('INSERT INTO ' || c || ' (usr, barcode) SELECT id, usrname FROM ' || u || ';');
1800 EXECUTE ('UPDATE ' || u || ' u SET card = c.id FROM ' || c || ' c WHERE c.usr = u.id;');
1806 $$ LANGUAGE plpgsql;
1809 CREATE OR REPLACE FUNCTION migration_tools.insert_856_9_conditional (TEXT, TEXT) RETURNS TEXT AS $$
1811 ## USAGE: UPDATE biblio.record_entry SET marc = migration_tools.insert_856_9(marc, 'ABC') WHERE [...];
1813 my ($marcxml, $shortname) = @_;
1816 use MARC::File::XML;
1821 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
1823 foreach my $field ( $marc->field('856') ) {
1824 if ( scalar(grep( /(contentreserve|netlibrary|overdrive)\.com/i, $field->subfield('u'))) > 0 &&
1825 ! ( $field->as_string('9') =~ m/$shortname/ ) ) {
1826 $field->add_subfields( '9' => $shortname );
1827 $field->update( ind2 => '0');
1831 $xml = $marc->as_xml_record;
1832 $xml =~ s/^<\?.+?\?>$//mo;
1834 $xml =~ s/>\s+</></sgo;
1839 $$ LANGUAGE PLPERLU STABLE;
1841 CREATE OR REPLACE FUNCTION migration_tools.insert_856_9 (TEXT, TEXT) RETURNS TEXT AS $$
1843 ## USAGE: UPDATE biblio.record_entry SET marc = migration_tools.insert_856_9(marc, 'ABC') WHERE [...];
1845 my ($marcxml, $shortname) = @_;
1848 use MARC::File::XML;
1853 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
1855 foreach my $field ( $marc->field('856') ) {
1856 if ( ! $field->as_string('9') ) {
1857 $field->add_subfields( '9' => $shortname );
1861 $xml = $marc->as_xml_record;
1862 $xml =~ s/^<\?.+?\?>$//mo;
1864 $xml =~ s/>\s+</></sgo;
1869 $$ LANGUAGE PLPERLU STABLE;
1872 CREATE OR REPLACE FUNCTION migration_tools.change_call_number(copy_id BIGINT, new_label TEXT, cn_class BIGINT) RETURNS VOID AS $$
1884 -- Bail out if asked to change the label to ##URI##
1885 IF new_label = '##URI##' THEN
1889 -- Gather information
1890 SELECT call_number INTO old_volume FROM asset.copy WHERE id = copy_id;
1891 SELECT record INTO bib FROM asset.call_number WHERE id = old_volume;
1892 SELECT owning_lib, label INTO owner, old_label FROM asset.call_number WHERE id = old_volume;
1894 -- Bail out if the label already is ##URI##
1895 IF old_label = '##URI##' THEN
1899 -- Bail out if the call number label is already correct
1900 IF new_volume = old_volume THEN
1904 -- Check whether we already have a destination volume available
1905 SELECT id INTO new_volume FROM asset.call_number
1908 owning_lib = owner AND
1909 label = new_label AND
1912 -- Create destination volume if needed
1914 INSERT INTO asset.call_number (creator, editor, record, owning_lib, label, label_class)
1915 VALUES (1, 1, bib, owner, new_label, cn_class);
1916 SELECT id INTO new_volume FROM asset.call_number
1919 owning_lib = owner AND
1920 label = new_label AND
1924 -- Move copy to destination
1925 UPDATE asset.copy SET call_number = new_volume WHERE id = copy_id;
1927 -- Delete source volume if it is now empty
1928 SELECT id INTO remainder FROM asset.copy WHERE call_number = old_volume AND NOT deleted;
1930 DELETE FROM asset.call_number WHERE id = old_volume;
1935 $$ LANGUAGE plpgsql;
1937 CREATE OR REPLACE FUNCTION migration_tools.zip_to_city_state_county (TEXT) RETURNS TEXT[] AS $$
1942 open (FH, '<', '/openils/var/data/zips.txt') or return ('No File Found', 'No File Found', 'No File Found');
1946 my ($junk, $state, $city, $zip, $foo, $bar, $county, $baz, $morejunk) = split(/\|/);
1947 $zipdata{$zip} = [$city, $state, $county];
1950 if (defined $zipdata{$input}) {
1951 my ($city, $state, $county) = @{$zipdata{$input}};
1952 return [$city, $state, $county];
1953 } elsif (defined $zipdata{substr $input, 0, 5}) {
1954 my ($city, $state, $county) = @{$zipdata{substr $input, 0, 5}};
1955 return [$city, $state, $county];
1957 return ['ZIP not found', 'ZIP not found', 'ZIP not found'];
1960 $$ LANGUAGE PLPERLU STABLE;
1962 CREATE OR REPLACE FUNCTION migration_tools.check_ou_depth ( ) RETURNS VOID AS $$
1969 errors_found BOOLEAN;
1971 parent_shortname TEXT;
1977 type_parent_depth INT;
1982 errors_found := FALSE;
1984 -- Checking actor.org_unit_type
1986 FOR type_id IN EXECUTE ('SELECT id FROM actor.org_unit_type ORDER BY id;') LOOP
1988 SELECT depth FROM actor.org_unit_type WHERE id = type_id INTO type_depth;
1989 SELECT parent FROM actor.org_unit_type WHERE id = type_id INTO type_parent;
1991 IF type_parent IS NOT NULL THEN
1993 SELECT depth FROM actor.org_unit_type WHERE id = type_parent INTO type_parent_depth;
1995 IF type_depth - type_parent_depth <> 1 THEN
1996 SELECT name FROM actor.org_unit_type WHERE id = type_id INTO ou_type_name;
1997 SELECT name FROM actor.org_unit_type WHERE id = type_parent INTO parent_type;
1998 RAISE INFO 'The % org unit type has a depth of %, but its parent org unit type, %, has a depth of %.',
1999 ou_type_name, type_depth, parent_type, type_parent_depth;
2000 errors_found := TRUE;
2008 -- Checking actor.org_unit
2010 FOR ou IN EXECUTE ('SELECT id FROM actor.org_unit ORDER BY shortname;') LOOP
2012 SELECT parent_ou FROM actor.org_unit WHERE id = ou INTO ou_parent;
2013 SELECT t.depth FROM actor.org_unit_type t, actor.org_unit o WHERE o.ou_type = t.id and o.id = ou INTO org_unit_depth;
2014 SELECT t.depth FROM actor.org_unit_type t, actor.org_unit o WHERE o.ou_type = t.id and o.id = ou_parent INTO parent_depth;
2015 SELECT shortname FROM actor.org_unit WHERE id = ou INTO ou_shortname;
2016 SELECT shortname FROM actor.org_unit WHERE id = ou_parent INTO parent_shortname;
2017 SELECT t.name FROM actor.org_unit_type t, actor.org_unit o WHERE o.ou_type = t.id and o.id = ou INTO ou_type_name;
2018 SELECT t.name FROM actor.org_unit_type t, actor.org_unit o WHERE o.ou_type = t.id and o.id = ou_parent INTO parent_type;
2020 IF ou_parent IS NOT NULL THEN
2022 IF (org_unit_depth - parent_depth <> 1) OR (
2023 (SELECT parent FROM actor.org_unit_type WHERE name = ou_type_name) <> (SELECT id FROM actor.org_unit_type WHERE name = parent_type)
2025 RAISE INFO '% (org unit %) is a % (depth %) but its parent, % (org unit %), is a % (depth %).',
2026 ou_shortname, ou, ou_type_name, org_unit_depth, parent_shortname, ou_parent, parent_type, parent_depth;
2027 errors_found := TRUE;
2034 IF NOT errors_found THEN
2035 RAISE INFO 'No errors found.';
2042 $$ LANGUAGE plpgsql;
2045 CREATE OR REPLACE FUNCTION migration_tools.refresh_opac_visible_copies ( ) RETURNS VOID AS $$
2049 DELETE FROM asset.opac_visible_copies;
2051 INSERT INTO asset.opac_visible_copies (id, circ_lib, record)
2053 cp.id, cp.circ_lib, cn.record
2056 JOIN asset.call_number cn ON (cn.id = cp.call_number)
2057 JOIN actor.org_unit a ON (cp.circ_lib = a.id)
2058 JOIN asset.copy_location cl ON (cp.location = cl.id)
2059 JOIN config.copy_status cs ON (cp.status = cs.id)
2060 JOIN biblio.record_entry b ON (cn.record = b.id)
2069 cp.id NOT IN (SELECT id FROM asset.opac_visible_copies);
2073 $$ LANGUAGE plpgsql;
2076 CREATE OR REPLACE FUNCTION migration_tools.change_owning_lib(copy_id BIGINT, new_owning_lib INTEGER) RETURNS VOID AS $$
2082 old_owning_lib INTEGER;
2088 -- Gather information
2089 SELECT call_number INTO old_volume FROM asset.copy WHERE id = copy_id;
2090 SELECT record INTO bib FROM asset.call_number WHERE id = old_volume;
2091 SELECT owning_lib, label INTO old_owning_lib, old_label FROM asset.call_number WHERE id = old_volume;
2093 -- Bail out if the new_owning_lib is not the ID of an org_unit
2094 IF new_owning_lib NOT IN (SELECT id FROM actor.org_unit) THEN
2096 '% is not a valid actor.org_unit ID; no change made.',
2101 -- Bail out discreetly if the owning_lib is already correct
2102 IF new_owning_lib = old_owning_lib THEN
2106 -- Check whether we already have a destination volume available
2107 SELECT id INTO new_volume FROM asset.call_number
2110 owning_lib = new_owning_lib AND
2111 label = old_label AND
2114 -- Create destination volume if needed
2116 INSERT INTO asset.call_number (creator, editor, record, owning_lib, label)
2117 VALUES (1, 1, bib, new_owning_lib, old_label);
2118 SELECT id INTO new_volume FROM asset.call_number
2121 owning_lib = new_owning_lib AND
2122 label = old_label AND
2126 -- Move copy to destination
2127 UPDATE asset.copy SET call_number = new_volume WHERE id = copy_id;
2129 -- Delete source volume if it is now empty
2130 SELECT id INTO remainder FROM asset.copy WHERE call_number = old_volume AND NOT deleted;
2132 DELETE FROM asset.call_number WHERE id = old_volume;
2137 $$ LANGUAGE plpgsql;
2140 CREATE OR REPLACE FUNCTION migration_tools.change_owning_lib(copy_id BIGINT, new_owner TEXT) RETURNS VOID AS $$
2142 -- You can use shortnames with this function, which looks up the org unit ID and passes it to change_owning_lib(BIGINT,INTEGER).
2145 new_owning_lib INTEGER;
2149 -- Parse the new_owner as an org unit ID or shortname
2150 IF new_owner IN (SELECT shortname FROM actor.org_unit) THEN
2151 SELECT id INTO new_owning_lib FROM actor.org_unit WHERE shortname = new_owner;
2152 PERFORM migration_tools.change_owning_lib(copy_id, new_owning_lib);
2153 ELSIF new_owner ~ E'^[0-9]+$' THEN
2154 IF new_owner::INTEGER IN (SELECT id FROM actor.org_unit) THEN
2157 E'You don\'t need to put the actor.org_unit ID in quotes; '
2158 || E'if you put it in quotes, I\'m going to try to parse it as a shortname first.';
2159 new_owning_lib := new_owner::INTEGER;
2160 PERFORM migration_tools.change_owning_lib(copy_id, new_owning_lib);
2164 '% is not a valid actor.org_unit shortname or ID; no change made.',
2171 $$ LANGUAGE plpgsql;
2173 CREATE OR REPLACE FUNCTION migration_tools.marc_parses( TEXT ) RETURNS BOOLEAN AS $func$
2176 use MARC::File::XML (BinaryEncoding => 'UTF-8');
2179 MARC::Charset->assume_unicode(1);
2184 my $r = MARC::Record->new_from_xml( $xml );
2185 my $output_xml = $r->as_xml_record();
2193 $func$ LANGUAGE PLPERLU;
2194 COMMENT ON FUNCTION migration_tools.marc_parses(TEXT) IS 'Return boolean indicating if MARCXML string is parseable by MARC::File::XML';
2196 CREATE OR REPLACE FUNCTION migration_tools.simple_export_library_config(dir TEXT, orgs INT[]) RETURNS VOID AS $FUNC$
2198 EXECUTE $$COPY (SELECT * FROM actor.hours_of_operation WHERE id IN ($$ ||
2199 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2200 $$) TO '$$ || dir || $$/actor_hours_of_operation'$$;
2201 EXECUTE $$COPY (SELECT org_unit, close_start, close_end, reason FROM actor.org_unit_closed WHERE org_unit IN ($$ ||
2202 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2203 $$) TO '$$ || dir || $$/actor_org_unit_closed'$$;
2204 EXECUTE $$COPY (SELECT org_unit, name, value FROM actor.org_unit_setting WHERE org_unit IN ($$ ||
2205 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2206 $$) TO '$$ || dir || $$/actor_org_unit_setting'$$;
2207 EXECUTE $$COPY (SELECT name, owning_lib, holdable, hold_verify, opac_visible, circulate FROM asset.copy_location WHERE owning_lib IN ($$ ||
2208 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2209 $$) TO '$$ || dir || $$/asset_copy_location'$$;
2210 EXECUTE $$COPY (SELECT grp, org_unit, penalty, threshold FROM permission.grp_penalty_threshold WHERE org_unit IN ($$ ||
2211 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2212 $$) TO '$$ || dir || $$/permission_grp_penalty_threshold'$$;
2213 EXECUTE $$COPY (SELECT owning_lib, label, label_sortkey FROM asset.call_number_prefix WHERE owning_lib IN ($$ ||
2214 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2215 $$) TO '$$ || dir || $$/asset_call_number_prefix'$$;
2216 EXECUTE $$COPY (SELECT owning_lib, label, label_sortkey FROM asset.call_number_suffix WHERE owning_lib IN ($$ ||
2217 ARRAY_TO_STRING(orgs, ',') || $$)$$ ||
2218 $$) TO '$$ || dir || $$/asset_call_number_suffix'$$;
2219 EXECUTE $$COPY config.rule_circ_duration TO '$$ || dir || $$/config_rule_circ_duration'$$;
2220 EXECUTE $$COPY config.rule_age_hold_protect TO '$$ || dir || $$/config_rule_age_hold_protect'$$;
2221 EXECUTE $$COPY config.rule_max_fine TO '$$ || dir || $$/config_rule_max_fine'$$;
2222 EXECUTE $$COPY config.rule_recurring_fine TO '$$ || dir || $$/config_rule_recurring_fine'$$;
2223 EXECUTE $$COPY permission.grp_tree TO '$$ || dir || $$/permission_grp_tree'$$;
2225 $FUNC$ LANGUAGE PLPGSQL;
2227 CREATE OR REPLACE FUNCTION migration_tools.simple_import_library_config(dir TEXT) RETURNS VOID AS $FUNC$
2229 EXECUTE $$COPY actor.hours_of_operation FROM '$$ || dir || $$/actor_hours_of_operation'$$;
2230 EXECUTE $$COPY actor.org_unit_closed (org_unit, close_start, close_end, reason) FROM '$$ || dir || $$/actor_org_unit_closed'$$;
2231 EXECUTE $$COPY actor.org_unit_setting (org_unit, name, value) FROM '$$ || dir || $$/actor_org_unit_setting'$$;
2232 EXECUTE $$COPY asset.copy_location (name, owning_lib, holdable, hold_verify, opac_visible, circulate) FROM '$$ || dir || $$/asset_copy_location'$$;
2233 EXECUTE $$COPY permission.grp_penalty_threshold (grp, org_unit, penalty, threshold) FROM '$$ || dir || $$/permission_grp_penalty_threshold'$$;
2234 EXECUTE $$COPY asset.call_number_prefix (owning_lib, label, label_sortkey) FROM '$$ || dir || $$/asset_call_number_prefix'$$;
2235 EXECUTE $$COPY asset.call_number_suffix (owning_lib, label, label_sortkey) FROM '$$ || dir || $$/asset_call_number_suffix'$$;
2237 -- import any new circ rules
2238 PERFORM migration_tools.simple_import_new_rows_by_value(dir, 'config', 'rule_circ_duration', 'id', 'name');
2239 PERFORM migration_tools.simple_import_new_rows_by_value(dir, 'config', 'rule_age_hold_protect', 'id', 'name');
2240 PERFORM migration_tools.simple_import_new_rows_by_value(dir, 'config', 'rule_max_fine', 'id', 'name');
2241 PERFORM migration_tools.simple_import_new_rows_by_value(dir, 'config', 'rule_recurring_fine', 'id', 'name');
2243 -- and permission groups
2244 PERFORM migration_tools.simple_import_new_rows_by_value(dir, 'permission', 'grp_tree', 'id', 'name');
2247 $FUNC$ LANGUAGE PLPGSQL;
2250 CREATE OR REPLACE FUNCTION migration_tools.simple_import_new_rows_by_value(dir TEXT, schemaname TEXT, tablename TEXT, idcol TEXT, matchcol TEXT) RETURNS VOID AS $FUNC$
2259 EXECUTE $$DROP TABLE IF EXISTS tmp_$$ || tablename;
2260 EXECUTE $$CREATE TEMPORARY TABLE tmp_$$ || tablename || $$ AS SELECT * FROM $$ || schemaname || '.' || tablename || $$ LIMIT 0$$;
2261 EXECUTE $$COPY tmp_$$ || tablename || $$ FROM '$$ || dir || '/' || schemaname || '_' || tablename || $$'$$;
2262 loopq := 'SELECT ' || matchcol || ' FROM tmp_' || tablename || ' ORDER BY ' || idcol;
2263 existsq := 'SELECT COUNT(*) FROM ' || schemaname || '.' || tablename || ' WHERE ' || matchcol || ' = $1';
2264 SELECT ARRAY_AGG(column_name::TEXT) INTO cols FROM information_schema.columns WHERE table_schema = schemaname AND table_name = tablename AND column_name <> idcol;
2265 FOR name IN EXECUTE loopq LOOP
2266 EXECUTE existsq INTO ct USING name;
2268 RAISE NOTICE 'inserting %.% row for %', schemaname, tablename, name;
2269 copyst := 'INSERT INTO ' || schemaname || '.' || tablename || ' (' || ARRAY_TO_STRING(cols, ',') || ') SELECT ' || ARRAY_TO_STRING(cols, ',') ||
2270 ' FROM tmp_' || tablename || ' WHERE ' || matchcol || ' = $1';
2271 EXECUTE copyst USING name;
2275 $FUNC$ LANGUAGE PLPGSQL;
2277 CREATE OR REPLACE FUNCTION migration_tools.merge_marc_fields( TEXT, TEXT, TEXT[] ) RETURNS TEXT AS $func$
2283 use MARC::File::XML (BinaryEncoding => 'UTF-8');
2286 MARC::Charset->assume_unicode(1);
2288 my $target_xml = shift;
2289 my $source_xml = shift;
2295 eval { $target = MARC::Record->new_from_xml( $target_xml ); };
2299 eval { $source = MARC::Record->new_from_xml( $source_xml ); };
2304 my $source_id = $source->subfield('901', 'c');
2305 $source_id = $source->subfield('903', 'a') unless $source_id;
2306 my $target_id = $target->subfield('901', 'c');
2307 $target_id = $target->subfield('903', 'a') unless $target_id;
2309 my %existing_fields;
2310 foreach my $tag (@$tags) {
2311 my %existing_fields = map { $_->as_formatted() => 1 } $target->field($tag);
2312 my @to_add = grep { not exists $existing_fields{$_->as_formatted()} } $source->field($tag);
2313 $target->insert_fields_ordered(map { $_->clone() } @to_add);
2315 elog(NOTICE, "Merged $tag tag(s) from $source_id to $target_id");
2319 my $xml = $target->as_xml_record;
2320 $xml =~ s/^<\?.+?\?>$//mo;
2322 $xml =~ s/>\s+</></sgo;
2326 $func$ LANGUAGE PLPERLU;
2327 COMMENT ON FUNCTION migration_tools.merge_marc_fields( TEXT, TEXT, TEXT[] ) IS 'Given two MARCXML strings and an array of tags, returns MARCXML representing the merge of the specified fields from the second MARCXML record into the first.';
2329 CREATE OR REPLACE FUNCTION migration_tools.make_stub_bib (text[], text[]) RETURNS TEXT AS $func$
2335 use MARC::File::XML (BinaryEncoding => 'UTF-8');
2338 my $in_tags = shift;
2339 my $in_values = shift;
2341 # hack-and-slash parsing of array-passed-as-string;
2342 # this can go away once everybody is running Postgres 9.1+
2343 my $csv = Text::CSV->new({binary => 1});
2346 my $status = $csv->parse($in_tags);
2347 my $tags = [ $csv->fields() ];
2348 $in_values =~ s/^{//;
2349 $in_values =~ s/}$//;
2350 $status = $csv->parse($in_values);
2351 my $values = [ $csv->fields() ];
2353 my $marc = MARC::Record->new();
2355 $marc->leader('00000nam a22000007 4500');
2356 $marc->append_fields(MARC::Field->new('008', '000000s 000 eng d'));
2358 foreach my $i (0..$#$tags) {
2360 if ($tags->[$i] =~ /^(\d{3})([0-9a-z])$/) {
2363 $marc->append_fields(MARC::Field->new($tag, ' ', ' ', $sf => $values->[$i])) if $values->[$i] !~ /^\s*$/ and $values->[$i] ne 'NULL';
2364 } elsif ($tags->[$i] =~ /^(\d{3})$/) {
2366 $marc->append_fields(MARC::Field->new($tag, $values->[$i])) if $values->[$i] !~ /^\s*$/ and $values->[$i] ne 'NULL';
2370 my $xml = $marc->as_xml_record;
2371 $xml =~ s/^<\?.+?\?>$//mo;
2373 $xml =~ s/>\s+</></sgo;
2377 $func$ LANGUAGE PLPERLU;
2378 COMMENT ON FUNCTION migration_tools.make_stub_bib (text[], text[]) IS $$Simple function to create a stub MARCXML bib from a set of columns.
2379 The first argument is an array of tag/subfield specifiers, e.g., ARRAY['001', '245a', '500a'].
2380 The second argument is an array of text containing the values to plug into each field.
2381 If the value for a given field is NULL or the empty string, it is not inserted.
2384 CREATE OR REPLACE FUNCTION migration_tools.set_indicator (TEXT, TEXT, INTEGER, CHAR(1)) RETURNS TEXT AS $func$
2386 my ($marcxml, $tag, $pos, $value) = @_;
2389 use MARC::File::XML (BinaryEncoding => 'UTF-8');
2393 MARC::Charset->assume_unicode(1);
2395 elog(ERROR, 'indicator position must be either 1 or 2') unless $pos =~ /^[12]$/;
2396 elog(ERROR, 'MARC tag must be numeric') unless $tag =~ /^\d{3}$/;
2397 elog(ERROR, 'MARC tag must not be control field') if $tag =~ /^00/;
2398 elog(ERROR, 'Value must be exactly one character') unless $value =~ /^.$/;
2402 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
2404 foreach my $field ($marc->field($tag)) {
2405 $field->update("ind$pos" => $value);
2407 $xml = $marc->as_xml_record;
2408 $xml =~ s/^<\?.+?\?>$//mo;
2410 $xml =~ s/>\s+</></sgo;
2414 $func$ LANGUAGE PLPERLU;
2416 COMMENT ON FUNCTION migration_tools.set_indicator(TEXT, TEXT, INTEGER, CHAR(1)) IS $$Set indicator value of a specified MARC field.
2417 The first argument is a MARCXML string.
2418 The second argument is a MARC tag.
2419 The third argument is the indicator position, either 1 or 2.
2420 The fourth argument is the character to set the indicator value to.
2421 All occurences of the specified field will be changed.
2422 The function returns the revised MARCXML string.$$;
2424 CREATE OR REPLACE FUNCTION migration_tools.create_staff_user(
2429 first_name TEXT DEFAULT '',
2430 last_name TEXT DEFAULT ''
2431 ) RETURNS VOID AS $func$
2433 RAISE NOTICE '%', org ;
2434 INSERT INTO actor.usr (usrname, passwd, ident_type, first_given_name, family_name, home_ou, profile)
2435 SELECT username, password, 1, first_name, last_name, aou.id, pgt.id
2436 FROM actor.org_unit aou, permission.grp_tree pgt
2437 WHERE aou.shortname = org
2438 AND pgt.name = perm_group;
2443 -- example: SELECT * FROM migration_tools.duplicate_template(5,'{3,4}');
2444 CREATE OR REPLACE FUNCTION migration_tools.duplicate_template (INTEGER, INTEGER[]) RETURNS VOID AS $$
2446 target_event_def ALIAS FOR $1;
2449 DROP TABLE IF EXISTS new_atevdefs;
2450 CREATE TEMP TABLE new_atevdefs (atevdef INTEGER);
2451 FOR i IN array_lower(orgs,1) .. array_upper(orgs,1) LOOP
2452 INSERT INTO action_trigger.event_definition (
2473 ,name || ' (clone of '||target_event_def||')'
2489 action_trigger.event_definition
2491 id = target_event_def
2493 RAISE INFO 'created atevdef with id = %', currval('action_trigger.event_definition_id_seq');
2494 INSERT INTO new_atevdefs SELECT currval('action_trigger.event_definition_id_seq');
2495 INSERT INTO action_trigger.environment (
2501 currval('action_trigger.event_definition_id_seq')
2506 action_trigger.environment
2508 event_def = target_event_def
2510 INSERT INTO action_trigger.event_params (
2515 currval('action_trigger.event_definition_id_seq')
2519 action_trigger.event_params
2521 event_def = target_event_def
2524 RAISE INFO '-- UPDATE action_trigger.event_definition SET active = CASE WHEN id = % THEN FALSE ELSE TRUE END WHERE id in (%,%);', target_event_def, target_event_def, (SELECT array_to_string(array_agg(atevdef),',') from new_atevdefs);
2526 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2528 -- example: SELECT * FROM migration_tools.duplicate_template_but_change_delay(5,'{3,4}','00:30:00'::INTERVAL);
2529 CREATE OR REPLACE FUNCTION migration_tools.duplicate_template_but_change_delay (INTEGER, INTEGER[], INTERVAL) RETURNS VOID AS $$
2531 target_event_def ALIAS FOR $1;
2533 new_interval ALIAS FOR $3;
2535 DROP TABLE IF EXISTS new_atevdefs;
2536 CREATE TEMP TABLE new_atevdefs (atevdef INTEGER);
2537 FOR i IN array_lower(orgs,1) .. array_upper(orgs,1) LOOP
2538 INSERT INTO action_trigger.event_definition (
2559 ,name || ' (clone of '||target_event_def||')'
2575 action_trigger.event_definition
2577 id = target_event_def
2579 RAISE INFO 'created atevdef with id = %', currval('action_trigger.event_definition_id_seq');
2580 INSERT INTO new_atevdefs SELECT currval('action_trigger.event_definition_id_seq');
2581 INSERT INTO action_trigger.environment (
2587 currval('action_trigger.event_definition_id_seq')
2592 action_trigger.environment
2594 event_def = target_event_def
2596 INSERT INTO action_trigger.event_params (
2601 currval('action_trigger.event_definition_id_seq')
2605 action_trigger.event_params
2607 event_def = target_event_def
2610 RAISE INFO '-- UPDATE action_trigger.event_definition SET active = CASE WHEN id = % THEN FALSE ELSE TRUE END WHERE id in (%,%);', target_event_def, target_event_def, (SELECT array_to_string(array_agg(atevdef),',') from new_atevdefs);
2612 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2614 -- example: SELECT * FROM migration_tools.duplicate_templates(3,'{5,6}');
2615 CREATE OR REPLACE FUNCTION migration_tools.duplicate_templates (INTEGER, INTEGER[]) RETURNS VOID AS $$
2618 target_event_defs ALIAS FOR $2;
2620 DROP TABLE IF EXISTS new_atevdefs;
2621 CREATE TEMP TABLE new_atevdefs (atevdef INTEGER);
2622 FOR i IN array_lower(target_event_defs,1) .. array_upper(target_event_defs,1) LOOP
2623 INSERT INTO action_trigger.event_definition (
2644 ,name || ' (clone of '||target_event_defs[i]||')'
2660 action_trigger.event_definition
2662 id = target_event_defs[i]
2664 RAISE INFO 'created atevdef with id = %', currval('action_trigger.event_definition_id_seq');
2665 INSERT INTO new_atevdefs SELECT currval('action_trigger.event_definition_id_seq');
2666 INSERT INTO action_trigger.environment (
2672 currval('action_trigger.event_definition_id_seq')
2677 action_trigger.environment
2679 event_def = target_event_defs[i]
2681 INSERT INTO action_trigger.event_params (
2686 currval('action_trigger.event_definition_id_seq')
2690 action_trigger.event_params
2692 event_def = target_event_defs[i]
2695 RAISE INFO '-- UPDATE action_trigger.event_definition SET active = TRUE WHERE id in (%);', (SELECT array_to_string(array_agg(atevdef),',') from new_atevdefs);
2697 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2699 CREATE OR REPLACE FUNCTION migration_tools.reset_event (BIGINT) RETURNS VOID AS $$
2701 action_trigger.event
2705 ,complete_time = NULL
2706 ,update_process = NULL
2708 ,template_output = NULL
2709 ,error_output = NULL
2710 ,async_output = NULL
2715 CREATE OR REPLACE FUNCTION migration_tools.get_marc_leader (TEXT) RETURNS TEXT AS $$
2719 use MARC::File::XML;
2724 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
2725 $field = $marc->leader();
2728 $$ LANGUAGE PLPERLU STABLE;
2730 CREATE OR REPLACE FUNCTION migration_tools.get_marc_tag (TEXT, TEXT, TEXT, TEXT) RETURNS TEXT AS $$
2731 my ($marcxml, $tag, $subfield, $delimiter) = @_;
2734 use MARC::File::XML;
2739 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
2740 $field = $marc->field($tag);
2742 return $field->as_string($subfield,$delimiter);
2743 $$ LANGUAGE PLPERLU STABLE;
2745 CREATE OR REPLACE FUNCTION migration_tools.get_marc_tags (TEXT, TEXT, TEXT, TEXT) RETURNS TEXT[] AS $$
2746 my ($marcxml, $tag, $subfield, $delimiter) = @_;
2749 use MARC::File::XML;
2754 my $marc = MARC::Record->new_from_xml($marcxml, 'UTF-8');
2755 @fields = $marc->field($tag);
2758 foreach my $field (@fields) {
2759 push @texts, $field->as_string($subfield,$delimiter);
2762 $$ LANGUAGE PLPERLU STABLE;
2764 CREATE OR REPLACE FUNCTION migration_tools.find_hold_matrix_matchpoint (INTEGER) RETURNS INTEGER AS $$
2765 SELECT action.find_hold_matrix_matchpoint(
2766 (SELECT pickup_lib FROM action.hold_request WHERE id = $1),
2767 (SELECT request_lib FROM action.hold_request WHERE id = $1),
2768 (SELECT current_copy FROM action.hold_request WHERE id = $1),
2769 (SELECT usr FROM action.hold_request WHERE id = $1),
2770 (SELECT requestor FROM action.hold_request WHERE id = $1)
2774 CREATE OR REPLACE FUNCTION migration_tools.find_hold_matrix_matchpoint2 (INTEGER) RETURNS SETOF action.matrix_test_result AS $$
2775 SELECT action.hold_request_permit_test(
2776 (SELECT pickup_lib FROM action.hold_request WHERE id = $1),
2777 (SELECT request_lib FROM action.hold_request WHERE id = $1),
2778 (SELECT current_copy FROM action.hold_request WHERE id = $1),
2779 (SELECT usr FROM action.hold_request WHERE id = $1),
2780 (SELECT requestor FROM action.hold_request WHERE id = $1)
2784 CREATE OR REPLACE FUNCTION migration_tools.find_circ_matrix_matchpoint (INTEGER) RETURNS SETOF action.found_circ_matrix_matchpoint AS $$
2785 SELECT action.find_circ_matrix_matchpoint(
2786 (SELECT circ_lib FROM action.circulation WHERE id = $1),
2787 (SELECT target_copy FROM action.circulation WHERE id = $1),
2788 (SELECT usr FROM action.circulation WHERE id = $1),
2790 NULLIF(phone_renewal,false),
2791 NULLIF(desk_renewal,false),
2792 NULLIF(opac_renewal,false),
2794 ) FROM action.circulation WHERE id = $1
2799 CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN) RETURNS VOID AS $$
2804 RAISE EXCEPTION 'assertion';
2807 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2809 CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT) RETURNS VOID AS $$
2815 RAISE EXCEPTION '%', msg;
2818 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2820 CREATE OR REPLACE FUNCTION migration_tools.assert (BOOLEAN,TEXT,TEXT) RETURNS TEXT AS $$
2823 fail_msg ALIAS FOR $2;
2824 success_msg ALIAS FOR $3;
2827 RAISE EXCEPTION '%', fail_msg;
2831 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2833 -- push bib sequence and return starting value for reserved range
2834 CREATE OR REPLACE FUNCTION migration_tools.push_bib_sequence(INTEGER) RETURNS BIGINT AS $$
2836 bib_count ALIAS FOR $1;
2839 PERFORM setval('biblio.record_entry_id_seq',(SELECT MAX(id) FROM biblio.record_entry) + bib_count + 2000);
2841 SELECT CEIL(MAX(id)/1000)*1000+1000 FROM biblio.record_entry WHERE id < (SELECT last_value FROM biblio.record_entry_id_seq)
2846 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2848 -- set a new salted password
2850 CREATE OR REPLACE FUNCTION migration_tools.set_salted_passwd(INTEGER,TEXT) RETURNS BOOLEAN AS $$
2852 usr_id ALIAS FOR $1;
2853 plain_passwd ALIAS FOR $2;
2858 SELECT actor.create_salt('main') INTO plain_salt;
2860 SELECT MD5(plain_passwd) INTO md5_passwd;
2862 PERFORM actor.set_passwd(usr_id, 'main', MD5(plain_salt || md5_passwd), plain_salt);
2867 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2870 -- convenience functions for handling copy_location maps
2872 CREATE OR REPLACE FUNCTION migration_tools.handle_shelf (TEXT,TEXT,TEXT,INTEGER) RETURNS VOID AS $$
2874 table_schema ALIAS FOR $1;
2875 table_name ALIAS FOR $2;
2876 org_shortname ALIAS FOR $3;
2877 org_range ALIAS FOR $4;
2883 EXECUTE 'SELECT EXISTS (
2885 FROM information_schema.columns
2886 WHERE table_schema = $1
2888 and column_name = ''desired_shelf''
2889 )' INTO proceed USING table_schema, table_name;
2891 RAISE EXCEPTION 'Missing column desired_shelf';
2894 SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname;
2896 RAISE EXCEPTION 'Cannot find org by shortname';
2899 SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org );
2901 EXECUTE 'ALTER TABLE '
2902 || quote_ident(table_name)
2903 || ' DROP COLUMN IF EXISTS x_shelf';
2904 EXECUTE 'ALTER TABLE '
2905 || quote_ident(table_name)
2906 || ' ADD COLUMN x_shelf INTEGER';
2908 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
2909 || ' SET x_shelf = id FROM asset_copy_location b'
2910 || ' WHERE BTRIM(UPPER(a.desired_shelf)) = BTRIM(UPPER(b.name))'
2911 || ' AND b.owning_lib = $1'
2912 || ' AND NOT b.deleted'
2915 FOREACH o IN ARRAY org_list LOOP
2916 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
2917 || ' SET x_shelf = id FROM asset.copy_location b'
2918 || ' WHERE BTRIM(UPPER(a.desired_shelf)) = BTRIM(UPPER(b.name))'
2919 || ' AND b.owning_lib = $1 AND x_shelf IS NULL'
2920 || ' AND NOT b.deleted'
2924 EXECUTE 'SELECT migration_tools.assert(
2925 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_shelf <> '''' AND x_shelf IS NULL),
2926 ''Cannot find a desired location'',
2927 ''Found all desired locations''
2931 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2933 -- convenience functions for handling circmod maps
2935 CREATE OR REPLACE FUNCTION migration_tools.handle_circmod (TEXT,TEXT) RETURNS VOID AS $$
2937 table_schema ALIAS FOR $1;
2938 table_name ALIAS FOR $2;
2941 EXECUTE 'SELECT EXISTS (
2943 FROM information_schema.columns
2944 WHERE table_schema = $1
2946 and column_name = ''desired_circmod''
2947 )' INTO proceed USING table_schema, table_name;
2949 RAISE EXCEPTION 'Missing column desired_circmod';
2952 EXECUTE 'ALTER TABLE '
2953 || quote_ident(table_name)
2954 || ' DROP COLUMN IF EXISTS x_circmod';
2955 EXECUTE 'ALTER TABLE '
2956 || quote_ident(table_name)
2957 || ' ADD COLUMN x_circmod TEXT';
2959 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
2960 || ' SET x_circmod = code FROM config.circ_modifier b'
2961 || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.code))';
2963 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
2964 || ' SET x_circmod = code FROM config.circ_modifier b'
2965 || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.name))'
2966 || ' AND x_circmod IS NULL';
2968 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
2969 || ' SET x_circmod = code FROM config.circ_modifier b'
2970 || ' WHERE BTRIM(UPPER(a.desired_circmod)) = BTRIM(UPPER(b.description))'
2971 || ' AND x_circmod IS NULL';
2973 EXECUTE 'SELECT migration_tools.assert(
2974 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_circmod <> '''' AND x_circmod IS NULL),
2975 ''Cannot find a desired circulation modifier'',
2976 ''Found all desired circulation modifiers''
2980 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
2982 -- convenience functions for handling item status maps
2984 CREATE OR REPLACE FUNCTION migration_tools.handle_status (TEXT,TEXT) RETURNS VOID AS $$
2986 table_schema ALIAS FOR $1;
2987 table_name ALIAS FOR $2;
2990 EXECUTE 'SELECT EXISTS (
2992 FROM information_schema.columns
2993 WHERE table_schema = $1
2995 and column_name = ''desired_status''
2996 )' INTO proceed USING table_schema, table_name;
2998 RAISE EXCEPTION 'Missing column desired_status';
3001 EXECUTE 'ALTER TABLE '
3002 || quote_ident(table_name)
3003 || ' DROP COLUMN IF EXISTS x_status';
3004 EXECUTE 'ALTER TABLE '
3005 || quote_ident(table_name)
3006 || ' ADD COLUMN x_status INTEGER';
3008 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
3009 || ' SET x_status = id FROM config.copy_status b'
3010 || ' WHERE BTRIM(UPPER(a.desired_status)) = BTRIM(UPPER(b.name))';
3012 EXECUTE 'SELECT migration_tools.assert(
3013 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_status <> '''' AND x_status IS NULL),
3014 ''Cannot find a desired copy status'',
3015 ''Found all desired copy statuses''
3019 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3021 -- convenience functions for handling org maps
3023 CREATE OR REPLACE FUNCTION migration_tools.handle_org (TEXT,TEXT) RETURNS VOID AS $$
3025 table_schema ALIAS FOR $1;
3026 table_name ALIAS FOR $2;
3029 EXECUTE 'SELECT EXISTS (
3031 FROM information_schema.columns
3032 WHERE table_schema = $1
3034 and column_name = ''desired_org''
3035 )' INTO proceed USING table_schema, table_name;
3037 RAISE EXCEPTION 'Missing column desired_org';
3040 EXECUTE 'ALTER TABLE '
3041 || quote_ident(table_name)
3042 || ' DROP COLUMN IF EXISTS x_org';
3043 EXECUTE 'ALTER TABLE '
3044 || quote_ident(table_name)
3045 || ' ADD COLUMN x_org INTEGER';
3047 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
3048 || ' SET x_org = id FROM actor.org_unit b'
3049 || ' WHERE BTRIM(a.desired_org) = BTRIM(b.shortname)';
3051 EXECUTE 'SELECT migration_tools.assert(
3052 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_org <> '''' AND x_org IS NULL),
3053 ''Cannot find a desired org unit'',
3054 ''Found all desired org units''
3058 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3060 -- convenience function for handling desired_not_migrate
3062 CREATE OR REPLACE FUNCTION migration_tools.handle_not_migrate (TEXT,TEXT) RETURNS VOID AS $$
3064 table_schema ALIAS FOR $1;
3065 table_name ALIAS FOR $2;
3068 EXECUTE 'SELECT EXISTS (
3070 FROM information_schema.columns
3071 WHERE table_schema = $1
3073 and column_name = ''desired_not_migrate''
3074 )' INTO proceed USING table_schema, table_name;
3076 RAISE EXCEPTION 'Missing column desired_not_migrate';
3079 EXECUTE 'ALTER TABLE '
3080 || quote_ident(table_name)
3081 || ' DROP COLUMN IF EXISTS x_migrate';
3082 EXECUTE 'ALTER TABLE '
3083 || quote_ident(table_name)
3084 || ' ADD COLUMN x_migrate BOOLEAN';
3086 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
3087 || ' SET x_migrate = CASE'
3088 || ' WHEN BTRIM(desired_not_migrate) = ''TRUE'' THEN FALSE'
3089 || ' WHEN BTRIM(desired_not_migrate) = ''DNM'' THEN FALSE'
3090 || ' WHEN BTRIM(desired_not_migrate) = ''FALSE'' THEN TRUE'
3091 || ' WHEN BTRIM(desired_not_migrate) = ''Migrate'' THEN TRUE'
3092 || ' WHEN BTRIM(desired_not_migrate) = '''' THEN TRUE'
3095 EXECUTE 'SELECT migration_tools.assert(
3096 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE x_migrate IS NULL),
3097 ''Not all desired_not_migrate values understood'',
3098 ''All desired_not_migrate values understood''
3102 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3104 -- convenience function for handling desired_profile
3106 CREATE OR REPLACE FUNCTION migration_tools.handle_profile (TEXT,TEXT) RETURNS VOID AS $$
3108 table_schema ALIAS FOR $1;
3109 table_name ALIAS FOR $2;
3112 EXECUTE 'SELECT EXISTS (
3114 FROM information_schema.columns
3115 WHERE table_schema = $1
3117 and column_name = ''desired_profile''
3118 )' INTO proceed USING table_schema, table_name;
3120 RAISE EXCEPTION 'Missing column desired_profile';
3123 EXECUTE 'ALTER TABLE '
3124 || quote_ident(table_name)
3125 || ' DROP COLUMN IF EXISTS x_profile';
3126 EXECUTE 'ALTER TABLE '
3127 || quote_ident(table_name)
3128 || ' ADD COLUMN x_profile INTEGER';
3130 EXECUTE 'UPDATE ' || quote_ident(table_name) || ' a'
3131 || ' SET x_profile = id FROM permission.grp_tree b'
3132 || ' WHERE BTRIM(UPPER(a.desired_profile)) = BTRIM(UPPER(b.name))';
3134 EXECUTE 'SELECT migration_tools.assert(
3135 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_profile <> '''' AND x_profile IS NULL),
3136 ''Cannot find a desired profile'',
3137 ''Found all desired profiles''
3141 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3143 -- convenience function for handling desired actor stat cats
3145 CREATE OR REPLACE FUNCTION migration_tools.vivicate_actor_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$
3147 table_schema ALIAS FOR $1;
3148 table_name ALIAS FOR $2;
3149 field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc.
3150 org_shortname ALIAS FOR $4;
3158 SELECT 'desired_sc' || field_suffix INTO sc;
3159 SELECT 'desired_sce' || field_suffix INTO sce;
3161 EXECUTE 'SELECT EXISTS (
3163 FROM information_schema.columns
3164 WHERE table_schema = $1
3166 and column_name = $3
3167 )' INTO proceed USING table_schema, table_name, sc;
3169 RAISE EXCEPTION 'Missing column %', sc;
3171 EXECUTE 'SELECT EXISTS (
3173 FROM information_schema.columns
3174 WHERE table_schema = $1
3176 and column_name = $3
3177 )' INTO proceed USING table_schema, table_name, sce;
3179 RAISE EXCEPTION 'Missing column %', sce;
3182 SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname;
3184 RAISE EXCEPTION 'Cannot find org by shortname';
3186 SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org );
3188 -- caller responsible for their own truncates though we try to prevent duplicates
3189 EXECUTE 'INSERT INTO actor_stat_cat (owner, name)
3194 ' || quote_ident(table_name) || '
3196 NULLIF(BTRIM('||sc||'),'''') IS NOT NULL
3200 WHERE owner = ANY ($2)
3201 AND name = BTRIM('||sc||')
3206 WHERE owner = ANY ($2)
3207 AND name = BTRIM('||sc||')
3210 USING org, org_list;
3212 EXECUTE 'INSERT INTO actor_stat_cat_entry (stat_cat, owner, value)
3217 WHERE owner = ANY ($2)
3218 AND BTRIM('||sc||') = BTRIM(name))
3221 WHERE owner = ANY ($2)
3222 AND BTRIM('||sc||') = BTRIM(name))
3227 ' || quote_ident(table_name) || '
3229 NULLIF(BTRIM('||sc||'),'''') IS NOT NULL
3230 AND NULLIF(BTRIM('||sce||'),'''') IS NOT NULL
3233 FROM actor.stat_cat_entry
3237 WHERE owner = ANY ($2)
3238 AND BTRIM('||sc||') = BTRIM(name)
3239 ) AND value = BTRIM('||sce||')
3243 FROM actor_stat_cat_entry
3247 WHERE owner = ANY ($2)
3248 AND BTRIM('||sc||') = BTRIM(name)
3249 ) AND value = BTRIM('||sce||')
3252 USING org, org_list;
3254 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3256 CREATE OR REPLACE FUNCTION migration_tools.handle_actor_sc_and_sce (TEXT,TEXT,TEXT,TEXT) RETURNS VOID AS $$
3258 table_schema ALIAS FOR $1;
3259 table_name ALIAS FOR $2;
3260 field_suffix ALIAS FOR $3; -- for distinguishing between desired_sce1, desired_sce2, etc.
3261 org_shortname ALIAS FOR $4;
3269 SELECT 'desired_sc' || field_suffix INTO sc;
3270 SELECT 'desired_sce' || field_suffix INTO sce;
3271 EXECUTE 'SELECT EXISTS (
3273 FROM information_schema.columns
3274 WHERE table_schema = $1
3276 and column_name = $3
3277 )' INTO proceed USING table_schema, table_name, sc;
3279 RAISE EXCEPTION 'Missing column %', sc;
3281 EXECUTE 'SELECT EXISTS (
3283 FROM information_schema.columns
3284 WHERE table_schema = $1
3286 and column_name = $3
3287 )' INTO proceed USING table_schema, table_name, sce;
3289 RAISE EXCEPTION 'Missing column %', sce;
3292 SELECT id INTO org FROM actor.org_unit WHERE shortname = org_shortname;
3294 RAISE EXCEPTION 'Cannot find org by shortname';
3297 SELECT INTO org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( org );
3299 EXECUTE 'ALTER TABLE '
3300 || quote_ident(table_name)
3301 || ' DROP COLUMN IF EXISTS x_sc' || field_suffix;
3302 EXECUTE 'ALTER TABLE '
3303 || quote_ident(table_name)
3304 || ' ADD COLUMN x_sc' || field_suffix || ' INTEGER';
3305 EXECUTE 'ALTER TABLE '
3306 || quote_ident(table_name)
3307 || ' DROP COLUMN IF EXISTS x_sce' || field_suffix;
3308 EXECUTE 'ALTER TABLE '
3309 || quote_ident(table_name)
3310 || ' ADD COLUMN x_sce' || field_suffix || ' INTEGER';
3313 EXECUTE 'UPDATE ' || quote_ident(table_name) || '
3315 x_sc' || field_suffix || ' = id
3317 (SELECT id, name, owner FROM actor_stat_cat
3318 UNION SELECT id, name, owner FROM actor.stat_cat) u
3320 BTRIM(UPPER(u.name)) = BTRIM(UPPER(' || sc || '))
3321 AND u.owner = ANY ($1);'
3324 EXECUTE 'UPDATE ' || quote_ident(table_name) || '
3326 x_sce' || field_suffix || ' = id
3328 (SELECT id, stat_cat, owner, value FROM actor_stat_cat_entry
3329 UNION SELECT id, stat_cat, owner, value FROM actor.stat_cat_entry) u
3331 u.stat_cat = x_sc' || field_suffix || '
3332 AND BTRIM(UPPER(u.value)) = BTRIM(UPPER(' || sce || '))
3333 AND u.owner = ANY ($1);'
3336 EXECUTE 'SELECT migration_tools.assert(
3337 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sc' || field_suffix || ' <> '''' AND x_sc' || field_suffix || ' IS NULL),
3338 ''Cannot find a desired stat cat'',
3339 ''Found all desired stat cats''
3342 EXECUTE 'SELECT migration_tools.assert(
3343 NOT EXISTS (SELECT 1 FROM ' || quote_ident(table_name) || ' WHERE desired_sce' || field_suffix || ' <> '''' AND x_sce' || field_suffix || ' IS NULL),
3344 ''Cannot find a desired stat cat entry'',
3345 ''Found all desired stat cat entries''
3349 $$ LANGUAGE PLPGSQL STRICT VOLATILE;
3351 -- convenience functions for adding shelving locations
3352 DROP FUNCTION IF EXISTS migration_tools.find_shelf(INT,TEXT);
3353 CREATE OR REPLACE FUNCTION migration_tools.find_shelf(org_id INT, shelf_name TEXT) RETURNS INTEGER AS $$
3359 SELECT INTO d MAX(distance) FROM actor.org_unit_ancestors_distance(org_id);
3362 SELECT INTO cur_id id FROM actor.org_unit_ancestor_at_depth(org_id,d);
3363 SELECT INTO return_id id FROM asset.copy_location WHERE owning_lib = cur_id AND name ILIKE shelf_name;
3364 IF return_id IS NOT NULL THEN
3372 $$ LANGUAGE plpgsql;
3374 -- may remove later but testing using this with new migration scripts and not loading acls until go live
3376 DROP FUNCTION IF EXISTS migration_tools.find_mig_shelf(INT,TEXT);
3377 CREATE OR REPLACE FUNCTION migration_tools.find_mig_shelf(org_id INT, shelf_name TEXT) RETURNS INTEGER AS $$
3383 SELECT INTO d MAX(distance) FROM actor.org_unit_ancestors_distance(org_id);
3386 SELECT INTO cur_id id FROM actor.org_unit_ancestor_at_depth(org_id,d);
3388 SELECT INTO return_id id FROM
3389 (SELECT * FROM asset.copy_location UNION ALL SELECT * FROM asset_copy_location) x
3390 WHERE owning_lib = cur_id AND name ILIKE shelf_name;
3391 IF return_id IS NOT NULL THEN
3399 $$ LANGUAGE plpgsql;
3401 -- yet another subfield 9 function, this one only adds the $9 if the ind1 = 1 or 4 and ind2 = 0 or 1
3402 DROP FUNCTION IF EXISTS migration_tools.strict_add_sf9(TEXT,TEXT);
3403 CREATE OR REPLACE FUNCTION migration_tools.strict_add_sf9(marc TEXT, new_9 TEXT)
3411 use MARC::File::XML (BinaryEncoding => 'utf8');
3413 binmode(STDERR, ':bytes');
3414 binmode(STDOUT, ':utf8');
3415 binmode(STDERR, ':utf8');
3417 my $marc_xml = shift;
3418 my $new_9_to_set = shift;
3420 $marc_xml =~ s/(<leader>.........)./${1}a/;
3423 $marc_xml = MARC::Record->new_from_xml($marc_xml);
3426 #elog("could not parse $bibid: $@\n");
3427 import MARC::File::XML (BinaryEncoding => 'utf8');
3431 my @uris = $marc_xml->field('856');
3432 return $marc_xml->as_xml_record() unless @uris;
3434 foreach my $field (@uris) {
3435 my $ind1 = $field->indicator('1');
3436 if (!defined $ind1) { next; }
3437 if ($ind1 ne '1' && $ind1 ne '4') { next; }
3438 my $ind2 = $field->indicator('2');
3439 if (!defined $ind2) { next; }
3440 if ($ind2 ne '0' && $ind2 ne '1') { next; }
3441 $field->add_subfields( '9' => $new_9_to_set );
3444 return $marc_xml->as_xml_record();
3448 -- yet another subfield 9 function, this one only adds the $9 and forces