From: Dan Scott Date: Sun, 16 Jul 2017 21:12:21 +0000 (-0700) Subject: Conifer SQL upgrade tweaks for 2.12 upgrade X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=4a38694b8aea3b875cafd15199bc13a0061acd82;p=contrib%2FConifer.git Conifer SQL upgrade tweaks for 2.12 upgrade Run the conifer-2.12 upgrade at the end. Signed-off-by: Dan Scott --- diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.10.7-2.11.0-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.10.7-2.11.0-upgrade-db.sql index 2b853798a1..ed01e44f3b 100644 --- a/Open-ILS/src/sql/Pg/version-upgrade/2.10.7-2.11.0-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/version-upgrade/2.10.7-2.11.0-upgrade-db.sql @@ -1995,236 +1995,6 @@ END; $p$ LANGUAGE PLPGSQL; - -SELECT evergreen.upgrade_deps_block_check('0985', :eg_version); - -CREATE OR REPLACE FUNCTION metabib.reingest_record_attributes (rid BIGINT, pattr_list TEXT[] DEFAULT NULL, prmarc TEXT DEFAULT NULL, rdeleted BOOL DEFAULT TRUE) RETURNS VOID AS $func$ -DECLARE - transformed_xml TEXT; - rmarc TEXT := prmarc; - tmp_val TEXT; - prev_xfrm TEXT; - normalizer RECORD; - xfrm config.xml_transform%ROWTYPE; - attr_vector INT[] := '{}'::INT[]; - attr_vector_tmp INT[]; - attr_list TEXT[] := pattr_list; - attr_value TEXT[]; - norm_attr_value TEXT[]; - tmp_xml TEXT; - attr_def config.record_attr_definition%ROWTYPE; - ccvm_row config.coded_value_map%ROWTYPE; -BEGIN - - IF attr_list IS NULL OR rdeleted THEN -- need to do the full dance on INSERT or undelete - SELECT ARRAY_AGG(name) INTO attr_list FROM config.record_attr_definition - WHERE ( - tag IS NOT NULL OR - fixed_field IS NOT NULL OR - xpath IS NOT NULL OR - phys_char_sf IS NOT NULL OR - composite - ) AND ( - filter OR sorter - ); - END IF; - - IF rmarc IS NULL THEN - SELECT marc INTO rmarc FROM biblio.record_entry WHERE id = rid; - END IF; - - FOR attr_def IN SELECT * FROM config.record_attr_definition WHERE NOT composite AND name = ANY( attr_list ) ORDER BY format LOOP - - attr_value := '{}'::TEXT[]; - norm_attr_value := '{}'::TEXT[]; - attr_vector_tmp := '{}'::INT[]; - - SELECT * INTO ccvm_row FROM config.coded_value_map c WHERE c.ctype = attr_def.name LIMIT 1; - - -- tag+sf attrs only support SVF - IF attr_def.tag IS NOT NULL THEN -- tag (and optional subfield list) selection - SELECT ARRAY[ARRAY_TO_STRING(ARRAY_AGG(value), COALESCE(attr_def.joiner,' '))] INTO attr_value - FROM (SELECT * FROM metabib.full_rec ORDER BY tag, subfield) AS x - WHERE record = rid - AND tag LIKE attr_def.tag - AND CASE - WHEN attr_def.sf_list IS NOT NULL - THEN POSITION(subfield IN attr_def.sf_list) > 0 - ELSE TRUE - END - GROUP BY tag - ORDER BY tag - LIMIT 1; - - ELSIF attr_def.fixed_field IS NOT NULL THEN -- a named fixed field, see config.marc21_ff_pos_map.fixed_field - attr_value := vandelay.marc21_extract_fixed_field_list(rmarc, attr_def.fixed_field); - - IF NOT attr_def.multi THEN - attr_value := ARRAY[attr_value[1]]; - END IF; - - ELSIF attr_def.xpath IS NOT NULL THEN -- and xpath expression - - SELECT INTO xfrm * FROM config.xml_transform WHERE name = attr_def.format; - - -- See if we can skip the XSLT ... it's expensive - IF prev_xfrm IS NULL OR prev_xfrm <> xfrm.name THEN - -- Can't skip the transform - IF xfrm.xslt <> '---' THEN - transformed_xml := oils_xslt_process(rmarc,xfrm.xslt); - ELSE - transformed_xml := rmarc; - END IF; - - prev_xfrm := xfrm.name; - END IF; - - IF xfrm.name IS NULL THEN - -- just grab the marcxml (empty) transform - SELECT INTO xfrm * FROM config.xml_transform WHERE xslt = '---' LIMIT 1; - prev_xfrm := xfrm.name; - END IF; - - FOR tmp_xml IN SELECT UNNEST(oils_xpath(attr_def.xpath, transformed_xml, ARRAY[ARRAY[xfrm.prefix, xfrm.namespace_uri]])) LOOP - tmp_val := oils_xpath_string( - '//*', - tmp_xml, - COALESCE(attr_def.joiner,' '), - ARRAY[ARRAY[xfrm.prefix, xfrm.namespace_uri]] - ); - IF tmp_val IS NOT NULL AND BTRIM(tmp_val) <> '' THEN - attr_value := attr_value || tmp_val; - EXIT WHEN NOT attr_def.multi; - END IF; - END LOOP; - - ELSIF attr_def.phys_char_sf IS NOT NULL THEN -- a named Physical Characteristic, see config.marc21_physical_characteristic_*_map - SELECT ARRAY_AGG(m.value) INTO attr_value - FROM vandelay.marc21_physical_characteristics(rmarc) v - LEFT JOIN config.marc21_physical_characteristic_value_map m ON (m.id = v.value) - WHERE v.subfield = attr_def.phys_char_sf AND (m.value IS NOT NULL AND BTRIM(m.value) <> '') - AND ( ccvm_row.id IS NULL OR ( ccvm_row.id IS NOT NULL AND v.id IS NOT NULL) ); - - IF NOT attr_def.multi THEN - attr_value := ARRAY[attr_value[1]]; - END IF; - - END IF; - - -- apply index normalizers to attr_value - FOR tmp_val IN SELECT value FROM UNNEST(attr_value) x(value) LOOP - FOR normalizer IN - SELECT n.func AS func, - n.param_count AS param_count, - m.params AS params - FROM config.index_normalizer n - JOIN config.record_attr_index_norm_map m ON (m.norm = n.id) - WHERE attr = attr_def.name - ORDER BY m.pos LOOP - EXECUTE 'SELECT ' || normalizer.func || '(' || - COALESCE( quote_literal( tmp_val ), 'NULL' ) || - CASE - WHEN normalizer.param_count > 0 - THEN ',' || REPLACE(REPLACE(BTRIM(normalizer.params,'[]'),E'\'',E'\\\''),E'"',E'\'') - ELSE '' - END || - ')' INTO tmp_val; - - END LOOP; - IF tmp_val IS NOT NULL AND tmp_val <> '' THEN - -- note that a string that contains only blanks - -- is a valid value for some attributes - norm_attr_value := norm_attr_value || tmp_val; - END IF; - END LOOP; - - IF attr_def.filter THEN - -- Create unknown uncontrolled values and find the IDs of the values - IF ccvm_row.id IS NULL THEN - FOR tmp_val IN SELECT value FROM UNNEST(norm_attr_value) x(value) LOOP - IF tmp_val IS NOT NULL AND BTRIM(tmp_val) <> '' THEN - BEGIN -- use subtransaction to isolate unique constraint violations - INSERT INTO metabib.uncontrolled_record_attr_value ( attr, value ) VALUES ( attr_def.name, tmp_val ); - EXCEPTION WHEN unique_violation THEN END; - END IF; - END LOOP; - - SELECT ARRAY_AGG(id) INTO attr_vector_tmp FROM metabib.uncontrolled_record_attr_value WHERE attr = attr_def.name AND value = ANY( norm_attr_value ); - ELSE - SELECT ARRAY_AGG(id) INTO attr_vector_tmp FROM config.coded_value_map WHERE ctype = attr_def.name AND code = ANY( norm_attr_value ); - END IF; - - -- Add the new value to the vector - attr_vector := attr_vector || attr_vector_tmp; - END IF; - - IF attr_def.sorter THEN - DELETE FROM metabib.record_sorter WHERE source = rid AND attr = attr_def.name; - IF norm_attr_value[1] IS NOT NULL THEN - INSERT INTO metabib.record_sorter (source, attr, value) VALUES (rid, attr_def.name, norm_attr_value[1]); - END IF; - END IF; - - END LOOP; - -/* We may need to rewrite the vlist to contain - the intersection of new values for requested - attrs and old values for ignored attrs. To - do this, we take the old attr vlist and - subtract any values that are valid for the - requested attrs, and then add back the new - set of attr values. */ - - IF ARRAY_LENGTH(pattr_list, 1) > 0 THEN - SELECT vlist INTO attr_vector_tmp FROM metabib.record_attr_vector_list WHERE source = rid; - SELECT attr_vector_tmp - ARRAY_AGG(id::INT) INTO attr_vector_tmp FROM metabib.full_attr_id_map WHERE attr = ANY (pattr_list); - attr_vector := attr_vector || attr_vector_tmp; - END IF; - - -- On to composite attributes, now that the record attrs have been pulled. Processed in name order, so later composite - -- attributes can depend on earlier ones. - PERFORM metabib.compile_composite_attr_cache_init(); - FOR attr_def IN SELECT * FROM config.record_attr_definition WHERE composite AND name = ANY( attr_list ) ORDER BY name LOOP - - FOR ccvm_row IN SELECT * FROM config.coded_value_map c WHERE c.ctype = attr_def.name ORDER BY value LOOP - - tmp_val := metabib.compile_composite_attr( ccvm_row.id ); - CONTINUE WHEN tmp_val IS NULL OR tmp_val = ''; -- nothing to do - - IF attr_def.filter THEN - IF attr_vector @@ tmp_val::query_int THEN - attr_vector = attr_vector + intset(ccvm_row.id); - EXIT WHEN NOT attr_def.multi; - END IF; - END IF; - - IF attr_def.sorter THEN - IF attr_vector @@ tmp_val THEN - DELETE FROM metabib.record_sorter WHERE source = rid AND attr = attr_def.name; - INSERT INTO metabib.record_sorter (source, attr, value) VALUES (rid, attr_def.name, ccvm_row.code); - END IF; - END IF; - - END LOOP; - - END LOOP; - - IF ARRAY_LENGTH(attr_vector, 1) > 0 THEN - IF rdeleted THEN -- initial insert OR revivication - DELETE FROM metabib.record_attr_vector_list WHERE source = rid; - INSERT INTO metabib.record_attr_vector_list (source, vlist) VALUES (rid, attr_vector); - ELSE - UPDATE metabib.record_attr_vector_list SET vlist = attr_vector WHERE source = rid; - END IF; - END IF; - -END; - -$func$ LANGUAGE PLPGSQL; - -CREATE INDEX config_coded_value_map_ctype_idx ON config.coded_value_map (ctype); - - SELECT evergreen.upgrade_deps_block_check('0986', :eg_version); CREATE EXTENSION IF NOT EXISTS unaccent SCHEMA public; @@ -3180,8 +2950,8 @@ INSERT INTO config.copy_status (id, name, holdable, opac_visible) VALUES (18,oil SELECT evergreen.upgrade_deps_block_check('0998', :eg_version); -DROP VIEW IF EXISTS action.all_circulation; -CREATE VIEW action.all_circulation AS +--DROP VIEW IF EXISTS action.all_circulation; +CREATE OR REPLACE VIEW action.all_circulation AS SELECT aged_circulation.id, aged_circulation.usr_post_code, aged_circulation.usr_home_ou, aged_circulation.usr_profile, aged_circulation.usr_birth_year, aged_circulation.copy_call_number, @@ -3349,4 +3119,4 @@ COMMIT; \qecho \qecho UPDATE biblio.record_entry SET id = id WHERE source IS NOT NULL; \qecho -UPDATE biblio.record_entry SET id = id WHERE source IS NOT NULL; +-- UPDATE biblio.record_entry SET id = id WHERE source IS NOT NULL; diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.11.0-2.11.1-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.11.0-2.11.1-upgrade-db.sql index 8042012c1e..03940043d8 100644 --- a/Open-ILS/src/sql/Pg/version-upgrade/2.11.0-2.11.1-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/version-upgrade/2.11.0-2.11.1-upgrade-db.sql @@ -3,107 +3,4 @@ BEGIN; INSERT INTO config.upgrade_log (version, applied_to) VALUES ('2.11.1', :eg_version); -SELECT evergreen.upgrade_deps_block_check('1001', :eg_version); -- stompro/gmcharlt - -CREATE INDEX action_usr_circ_history_usr_idx ON action.usr_circ_history ( usr ); - - -SELECT evergreen.upgrade_deps_block_check('1002', :eg_version); - --- This is a placeholder for the backport of schema update 1002 --- (adding es-ES to the list of locales. This script does nothing for --- rel_2_11 and later. - - -SELECT evergreen.upgrade_deps_block_check('1003', :eg_version); -- gmcharlt/rhamby/csharp - -CREATE OR REPLACE FUNCTION metabib.remap_metarecord_for_bib( bib_id BIGINT, fp TEXT, bib_is_deleted BOOL DEFAULT FALSE, retain_deleted BOOL DEFAULT FALSE ) RETURNS BIGINT AS $func$ -DECLARE - new_mapping BOOL := TRUE; - source_count INT; - old_mr BIGINT; - tmp_mr metabib.metarecord%ROWTYPE; - deleted_mrs BIGINT[]; -BEGIN - - -- We need to make sure we're not a deleted master record of an MR - IF bib_is_deleted THEN - FOR old_mr IN SELECT id FROM metabib.metarecord WHERE master_record = bib_id LOOP - - IF NOT retain_deleted THEN -- Go away for any MR that we're master of, unless retained - DELETE FROM metabib.metarecord_source_map WHERE source = bib_id; - END IF; - - -- Now, are there any more sources on this MR? - SELECT COUNT(*) INTO source_count FROM metabib.metarecord_source_map WHERE metarecord = old_mr; - - IF source_count = 0 AND NOT retain_deleted THEN -- No other records - deleted_mrs := ARRAY_APPEND(deleted_mrs, old_mr); -- Just in case... - DELETE FROM metabib.metarecord WHERE id = old_mr; - - ELSE -- indeed there are. Update it with a null cache and recalcualated master record - UPDATE metabib.metarecord - SET mods = NULL, - master_record = ( SELECT id FROM biblio.record_entry WHERE fingerprint = fp AND NOT deleted ORDER BY quality DESC LIMIT 1) - WHERE id = old_mr; - END IF; - END LOOP; - - ELSE -- insert or update - - FOR tmp_mr IN SELECT m.* FROM metabib.metarecord m JOIN metabib.metarecord_source_map s ON (s.metarecord = m.id) WHERE s.source = bib_id LOOP - - -- Find the first fingerprint-matching - IF old_mr IS NULL AND fp = tmp_mr.fingerprint THEN - old_mr := tmp_mr.id; - new_mapping := FALSE; - - ELSE -- Our fingerprint changed ... maybe remove the old MR - DELETE FROM metabib.metarecord_source_map WHERE metarecord = tmp_mr.id AND source = bib_id; -- remove the old source mapping - SELECT COUNT(*) INTO source_count FROM metabib.metarecord_source_map WHERE metarecord = tmp_mr.id; - IF source_count = 0 THEN -- No other records - deleted_mrs := ARRAY_APPEND(deleted_mrs, tmp_mr.id); - DELETE FROM metabib.metarecord WHERE id = tmp_mr.id; - END IF; - END IF; - - END LOOP; - - -- we found no suitable, preexisting MR based on old source maps - IF old_mr IS NULL THEN - SELECT id INTO old_mr FROM metabib.metarecord WHERE fingerprint = fp; -- is there one for our current fingerprint? - - IF old_mr IS NULL THEN -- nope, create one and grab its id - INSERT INTO metabib.metarecord ( fingerprint, master_record ) VALUES ( fp, bib_id ); - SELECT id INTO old_mr FROM metabib.metarecord WHERE fingerprint = fp; - - ELSE -- indeed there is. update it with a null cache and recalcualated master record - UPDATE metabib.metarecord - SET mods = NULL, - master_record = ( SELECT id FROM biblio.record_entry WHERE fingerprint = fp AND NOT deleted ORDER BY quality DESC LIMIT 1) - WHERE id = old_mr; - END IF; - - ELSE -- there was one we already attached to, update its mods cache and master_record - UPDATE metabib.metarecord - SET mods = NULL, - master_record = ( SELECT id FROM biblio.record_entry WHERE fingerprint = fp AND NOT deleted ORDER BY quality DESC LIMIT 1) - WHERE id = old_mr; - END IF; - - IF new_mapping THEN - INSERT INTO metabib.metarecord_source_map (metarecord, source) VALUES (old_mr, bib_id); -- new source mapping - END IF; - - END IF; - - IF ARRAY_UPPER(deleted_mrs,1) > 0 THEN - UPDATE action.hold_request SET target = old_mr WHERE target IN ( SELECT unnest(deleted_mrs) ) AND hold_type = 'M'; -- if we had to delete any MRs above, make sure their holds are moved - END IF; - - RETURN old_mr; - -END; -$func$ LANGUAGE PLPGSQL; - COMMIT; diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.11.2-2.11.3-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.11.2-2.11.3-upgrade-db.sql index 939403150d..ce9bafdbf3 100644 --- a/Open-ILS/src/sql/Pg/version-upgrade/2.11.2-2.11.3-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/version-upgrade/2.11.2-2.11.3-upgrade-db.sql @@ -21,16 +21,4 @@ CREATE INDEX actor_usr_usrname_unaccent_idx ON actor.usr (evergreen.unaccent_and -SELECT evergreen.upgrade_deps_block_check('1018', :eg_version); - -UPDATE config.org_unit_setting_type - SET view_perm = (SELECT id FROM permission.perm_list - WHERE code = 'VIEW_CREDIT_CARD_PROCESSING' LIMIT 1) - WHERE name LIKE 'credit.processor.stripe%' AND view_perm IS NULL; - -UPDATE config.org_unit_setting_type - SET update_perm = (SELECT id FROM permission.perm_list - WHERE code = 'ADMIN_CREDIT_CARD_PROCESSING' LIMIT 1) - WHERE name LIKE 'credit.processor.stripe%' AND update_perm IS NULL; - COMMIT; diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.11.3-2.12.0-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.11.3-2.12.0-upgrade-db.sql index d97782689c..8ebd8f14f5 100644 --- a/Open-ILS/src/sql/Pg/version-upgrade/2.11.3-2.12.0-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/version-upgrade/2.11.3-2.12.0-upgrade-db.sql @@ -955,20 +955,4 @@ REINDEX INDEX actor.actor_usr_first_given_name_unaccent_idx; REINDEX INDEX actor.actor_usr_second_given_name_unaccent_idx; REINDEX INDEX actor.actor_usr_family_name_unaccent_idx; -\qecho Recalculating bib fingerprints; this may take a while -ALTER TABLE biblio.record_entry DISABLE TRIGGER USER; -UPDATE biblio.record_entry SET fingerprint = biblio.extract_fingerprint(marc) WHERE NOT deleted; -ALTER TABLE biblio.record_entry ENABLE TRIGGER USER; - -\qecho Remapping metarecords -SELECT metabib.remap_metarecord_for_bib(id, fingerprint) -FROM biblio.record_entry -WHERE NOT deleted; - -\qecho Running a browse and reingest of your bib records. It may take a while. -\qecho You may cancel now without losing the effect of the rest of the -\qecho upgrade script, and arrange the reingest later. -\qecho . -SELECT metabib.reingest_metabib_field_entries(id, FALSE, FALSE, TRUE) - FROM biblio.record_entry; diff --git a/Open-ILS/src/sql/Pg/version-upgrade/2.12.0-2.12.1-upgrade-db.sql b/Open-ILS/src/sql/Pg/version-upgrade/2.12.0-2.12.1-upgrade-db.sql index 07753a284e..ae1f3d2b55 100644 --- a/Open-ILS/src/sql/Pg/version-upgrade/2.12.0-2.12.1-upgrade-db.sql +++ b/Open-ILS/src/sql/Pg/version-upgrade/2.12.0-2.12.1-upgrade-db.sql @@ -69,10 +69,3 @@ JOIN config.metabib_field idx ON (map.metabib_field = idx.id) WHERE tag ~ '^6' ORDER BY b.tag; - -\qecho This is a browse-only reingest of your bib records. It may take a while. -\qecho You may cancel now without losing the effect of the rest of the -\qecho upgrade script, and arrange the reingest later. -\qecho . -SELECT metabib.reingest_metabib_field_entries(id, TRUE, FALSE, TRUE) - FROM biblio.record_entry; diff --git a/Open-ILS/src/sql/Pg/version-upgrade/conifer-2.12-upgrade.sql b/Open-ILS/src/sql/Pg/version-upgrade/conifer-2.12-upgrade.sql new file mode 100644 index 0000000000..1b9174b1dd --- /dev/null +++ b/Open-ILS/src/sql/Pg/version-upgrade/conifer-2.12-upgrade.sql @@ -0,0 +1,19 @@ +\qecho Stuff that will take a long time; run at the end +\qecho . + +\qecho Recalculating bib fingerprints; this may take a while +ALTER TABLE biblio.record_entry DISABLE TRIGGER USER; +UPDATE biblio.record_entry SET fingerprint = biblio.extract_fingerprint(marc) WHERE NOT deleted; +ALTER TABLE biblio.record_entry ENABLE TRIGGER USER; + +\qecho Remapping metarecords +SELECT metabib.remap_metarecord_for_bib(id, fingerprint) +FROM biblio.record_entry +WHERE NOT deleted; + +\qecho Running a browse and reingest of your bib records. It may take a while. +\qecho You may cancel now without losing the effect of the rest of the +\qecho upgrade script, and arrange the reingest later. +\qecho . +SELECT metabib.reingest_metabib_field_entries(id, FALSE, FALSE, TRUE) + FROM biblio.record_entry;