From: Dan Scott Date: Tue, 17 May 2011 04:29:47 +0000 (-0400) Subject: LP#783486: Improve authority lookup performance X-Git-Url: http://git.equinoxoli.org/?p=evergreen-equinox.git;a=commitdiff_plain;h=d6f8124b33f738bd06e0e83f7b2ba815ad3165bf LP#783486: Improve authority lookup performance Testing showed that the two indexes added herein improve authority lookup performance radically; on a 16 GB RAM database server with 1.1M records, lookup times decreased from 5500 ms to 0.223 ms. Recommended, would EXPLAIN ANALYZE again. Signed-off-by: Dan Scott --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index ee28ea9..4b7b0ef 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -86,7 +86,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 ('0534', :eg_version); -- gmc +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0535', :eg_version); -- dbs CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/011.schema.authority.sql b/Open-ILS/src/sql/Pg/011.schema.authority.sql index 133a243..f48e223 100644 --- a/Open-ILS/src/sql/Pg/011.schema.authority.sql +++ b/Open-ILS/src/sql/Pg/011.schema.authority.sql @@ -37,6 +37,7 @@ CREATE TABLE authority.record_entry ( ); CREATE INDEX authority_record_entry_creator_idx ON authority.record_entry ( creator ); CREATE INDEX authority_record_entry_editor_idx ON authority.record_entry ( editor ); +CREATE INDEX authority_record_deleted_idx ON authority.record_entry(deleted) WHERE deleted IS FALSE OR deleted = false; CREATE TRIGGER a_marcxml_is_well_formed BEFORE INSERT OR UPDATE ON authority.record_entry FOR EACH ROW EXECUTE PROCEDURE biblio.check_marcxml_well_formed(); CREATE TRIGGER b_maintain_901 BEFORE INSERT OR UPDATE ON authority.record_entry FOR EACH ROW EXECUTE PROCEDURE evergreen.maintain_901(); CREATE TRIGGER c_maintain_control_numbers BEFORE INSERT OR UPDATE ON authority.record_entry FOR EACH ROW EXECUTE PROCEDURE maintain_control_numbers(); @@ -84,6 +85,7 @@ CREATE TABLE authority.full_rec ( CREATE INDEX authority_full_rec_record_idx ON authority.full_rec (record); CREATE INDEX authority_full_rec_tag_subfield_idx ON authority.full_rec (tag, subfield); CREATE INDEX authority_full_rec_tag_part_idx ON authority.full_rec (SUBSTRING(tag FROM 2)); +CREATE INDEX authority_full_rec_subfield_a_idx ON authority.full_rec (value) WHERE subfield = 'a'; CREATE TRIGGER authority_full_rec_fti_trigger BEFORE UPDATE OR INSERT ON authority.full_rec FOR EACH ROW EXECUTE PROCEDURE tsearch2(index_vector, value); diff --git a/Open-ILS/src/sql/Pg/upgrade/0535.schema.authority_indexes.sql b/Open-ILS/src/sql/Pg/upgrade/0535.schema.authority_indexes.sql new file mode 100644 index 0000000..cf55c58 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0535.schema.authority_indexes.sql @@ -0,0 +1,9 @@ +BEGIN; + +INSERT INTO config.upgrade_log (version) VALUES ('0535'); --dbs + +CREATE INDEX authority_record_deleted_idx ON authority.record_entry(deleted) WHERE deleted IS FALSE OR deleted = false; + +CREATE INDEX authority_full_rec_subfield_a_idx ON authority.full_rec (value) WHERE subfield = 'a'; + +COMMIT;