From: Jason Stephenson Date: Tue, 2 Mar 2021 14:22:55 +0000 (-0500) Subject: Lp 1703658: Stamp DB Upgrade X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=7c4a18e5ac56971a54afd74b3eb05014541e50c9;p=evergreen%2Fpines.git Lp 1703658: Stamp DB Upgrade Signed-off-by: Jason Stephenson --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index cab9824cd7..2fa3ff4f1d 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -92,7 +92,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1247', :eg_version); -- miker / cburns / sandbergja +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1248', :eg_version); -- JBoyer / Dyrcona CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1248.schema.convert_gist_to_gin.sql b/Open-ILS/src/sql/Pg/upgrade/1248.schema.convert_gist_to_gin.sql new file mode 100644 index 0000000000..2e034a71ce --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1248.schema.convert_gist_to_gin.sql @@ -0,0 +1,91 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('1248', :eg_version); + +DO LANGUAGE plpgsql $$ +DECLARE + ind RECORD; + tablist TEXT; +BEGIN + + -- We only want to mess with gist indexes in stock Evergreen. + -- If you've added your own convert them or don't as you see fit. + PERFORM + FROM pg_index idx + JOIN pg_class cls ON cls.oid=idx.indexrelid + JOIN pg_namespace sc ON sc.oid = cls.relnamespace + JOIN pg_class tab ON tab.oid=idx.indrelid + JOIN pg_attribute at ON (at.attnum = ANY(idx.indkey) AND at.attrelid = tab.oid) + JOIN pg_am am ON am.oid=cls.relam + WHERE am.amname = 'gist' + AND cls.relname IN ( + 'authority_full_rec_index_vector_idx', + 'authority_simple_heading_index_vector_idx', + 'metabib_identifier_field_entry_index_vector_idx', + 'metabib_combined_identifier_field_entry_index_vector_idx', + 'metabib_title_field_entry_index_vector_idx', + 'metabib_combined_title_field_entry_index_vector_idx', + 'metabib_author_field_entry_index_vector_idx', + 'metabib_combined_author_field_entry_index_vector_idx', + 'metabib_subject_field_entry_index_vector_idx', + 'metabib_combined_subject_field_entry_index_vector_idx', + 'metabib_keyword_field_entry_index_vector_idx', + 'metabib_combined_keyword_field_entry_index_vector_idx', + 'metabib_series_field_entry_index_vector_idx', + 'metabib_combined_series_field_entry_index_vector_idx', + 'metabib_full_rec_index_vector_idx' + ); + + IF NOT FOUND THEN + RETURN; + END IF; + + tablist := ''; + + RAISE NOTICE 'Converting GIST indexes into GIN indexes...'; + + FOR ind IN SELECT sc.nspname AS sch, tab.relname AS tab, cls.relname AS idx, at.attname AS col + FROM pg_index idx + JOIN pg_class cls ON cls.oid=idx.indexrelid + JOIN pg_namespace sc ON sc.oid = cls.relnamespace + JOIN pg_class tab ON tab.oid=idx.indrelid + JOIN pg_attribute at ON (at.attnum = ANY(idx.indkey) AND at.attrelid = tab.oid) + JOIN pg_am am ON am.oid=cls.relam + WHERE am.amname = 'gist' + AND cls.relname IN ( + 'authority_full_rec_index_vector_idx', + 'authority_simple_heading_index_vector_idx', + 'metabib_identifier_field_entry_index_vector_idx', + 'metabib_combined_identifier_field_entry_index_vector_idx', + 'metabib_title_field_entry_index_vector_idx', + 'metabib_combined_title_field_entry_index_vector_idx', + 'metabib_author_field_entry_index_vector_idx', + 'metabib_combined_author_field_entry_index_vector_idx', + 'metabib_subject_field_entry_index_vector_idx', + 'metabib_combined_subject_field_entry_index_vector_idx', + 'metabib_keyword_field_entry_index_vector_idx', + 'metabib_combined_keyword_field_entry_index_vector_idx', + 'metabib_series_field_entry_index_vector_idx', + 'metabib_combined_series_field_entry_index_vector_idx', + 'metabib_full_rec_index_vector_idx' + ) + LOOP + -- Move existing index out of the way so there's no difference between new databases and upgraded databases + EXECUTE FORMAT('ALTER INDEX %I.%I RENAME TO %I_gist', ind.sch, ind.idx, ind.idx); + + -- Meet the new index, same as the old index (almost) + EXECUTE FORMAT('CREATE INDEX %I ON %I.%I USING GIN (%I)', ind.idx, ind.sch, ind.tab, ind.col); + + -- And drop the old index + EXECUTE FORMAT('DROP INDEX %I.%I_gist', ind.sch, ind.idx); + + tablist := tablist || ' ' || ind.sch || '.' || ind.tab || E'\n'; + + END LOOP; + + RAISE NOTICE E'Conversion Complete.\n\n You should run a VACUUM ANALYZE on the following tables soon:\n%', tablist; + +END $$; + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.data.dont_get_the_gist.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.data.dont_get_the_gist.sql deleted file mode 100644 index eef84dc5fa..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.data.dont_get_the_gist.sql +++ /dev/null @@ -1,91 +0,0 @@ -BEGIN; - -SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); - -DO LANGUAGE plpgsql $$ -DECLARE - ind RECORD; - tablist TEXT; -BEGIN - - -- We only want to mess with gist indexes in stock Evergreen. - -- If you've added your own convert them or don't as you see fit. - PERFORM - FROM pg_index idx - JOIN pg_class cls ON cls.oid=idx.indexrelid - JOIN pg_namespace sc ON sc.oid = cls.relnamespace - JOIN pg_class tab ON tab.oid=idx.indrelid - JOIN pg_attribute at ON (at.attnum = ANY(idx.indkey) AND at.attrelid = tab.oid) - JOIN pg_am am ON am.oid=cls.relam - WHERE am.amname = 'gist' - AND cls.relname IN ( - 'authority_full_rec_index_vector_idx', - 'authority_simple_heading_index_vector_idx', - 'metabib_identifier_field_entry_index_vector_idx', - 'metabib_combined_identifier_field_entry_index_vector_idx', - 'metabib_title_field_entry_index_vector_idx', - 'metabib_combined_title_field_entry_index_vector_idx', - 'metabib_author_field_entry_index_vector_idx', - 'metabib_combined_author_field_entry_index_vector_idx', - 'metabib_subject_field_entry_index_vector_idx', - 'metabib_combined_subject_field_entry_index_vector_idx', - 'metabib_keyword_field_entry_index_vector_idx', - 'metabib_combined_keyword_field_entry_index_vector_idx', - 'metabib_series_field_entry_index_vector_idx', - 'metabib_combined_series_field_entry_index_vector_idx', - 'metabib_full_rec_index_vector_idx' - ); - - IF NOT FOUND THEN - RETURN; - END IF; - - tablist := ''; - - RAISE NOTICE 'Converting GIST indexes into GIN indexes...'; - - FOR ind IN SELECT sc.nspname AS sch, tab.relname AS tab, cls.relname AS idx, at.attname AS col - FROM pg_index idx - JOIN pg_class cls ON cls.oid=idx.indexrelid - JOIN pg_namespace sc ON sc.oid = cls.relnamespace - JOIN pg_class tab ON tab.oid=idx.indrelid - JOIN pg_attribute at ON (at.attnum = ANY(idx.indkey) AND at.attrelid = tab.oid) - JOIN pg_am am ON am.oid=cls.relam - WHERE am.amname = 'gist' - AND cls.relname IN ( - 'authority_full_rec_index_vector_idx', - 'authority_simple_heading_index_vector_idx', - 'metabib_identifier_field_entry_index_vector_idx', - 'metabib_combined_identifier_field_entry_index_vector_idx', - 'metabib_title_field_entry_index_vector_idx', - 'metabib_combined_title_field_entry_index_vector_idx', - 'metabib_author_field_entry_index_vector_idx', - 'metabib_combined_author_field_entry_index_vector_idx', - 'metabib_subject_field_entry_index_vector_idx', - 'metabib_combined_subject_field_entry_index_vector_idx', - 'metabib_keyword_field_entry_index_vector_idx', - 'metabib_combined_keyword_field_entry_index_vector_idx', - 'metabib_series_field_entry_index_vector_idx', - 'metabib_combined_series_field_entry_index_vector_idx', - 'metabib_full_rec_index_vector_idx' - ) - LOOP - -- Move existing index out of the way so there's no difference between new databases and upgraded databases - EXECUTE FORMAT('ALTER INDEX %I.%I RENAME TO %I_gist', ind.sch, ind.idx, ind.idx); - - -- Meet the new index, same as the old index (almost) - EXECUTE FORMAT('CREATE INDEX %I ON %I.%I USING GIN (%I)', ind.idx, ind.sch, ind.tab, ind.col); - - -- And drop the old index - EXECUTE FORMAT('DROP INDEX %I.%I_gist', ind.sch, ind.idx); - - tablist := tablist || ' ' || ind.sch || '.' || ind.tab || E'\n'; - - END LOOP; - - RAISE NOTICE E'Conversion Complete.\n\n You should run a VACUUM ANALYZE on the following tables soon:\n%', tablist; - -END $$; - -COMMIT; -