[open-ils-commits] r13615 - trunk/Open-ILS/src/sql/Pg (scottmk)

svn at svn.open-ils.org svn at svn.open-ils.org
Thu Jul 16 16:07:06 EDT 2009


Author: scottmk
Date: 2009-07-16 16:07:02 -0400 (Thu, 16 Jul 2009)
New Revision: 13615

Modified:
   trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql
   trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql
   trunk/Open-ILS/src/sql/Pg/070.schema.container.sql
   trunk/Open-ILS/src/sql/Pg/080.schema.money.sql
   trunk/Open-ILS/src/sql/Pg/090.schema.action.sql
   trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
   trunk/Open-ILS/src/sql/Pg/901.audit-tables.sql
Log:
Create a bunch of new indexes so that the new actor.usr_delete
and actor.usr_purge_data procedures won't have to do full 
table scans.

The CREATE INDEX statements are sprinkled across seven different
installation scripts.  Here there are all in one place, for
updating an existing database:

-- 200.schema.acq.sql
CREATE INDEX fund_alloc_allocator_idx ON acq.fund_allocation ( allocator );
CREATE INDEX li_creator_idx           ON acq.lineitem ( creator );
CREATE INDEX li_editor_idx            ON acq.lineitem ( editor );
CREATE INDEX li_selector_idx          ON acq.lineitem ( selector );
CREATE INDEX li_note_creator_idx      ON acq.lineitem_note ( creator );
CREATE INDEX li_note_editor_idx       ON acq.lineitem_note ( editor );
CREATE INDEX li_usr_attr_def_usr_idx  ON acq.lineitem_usr_attr_definition ( usr );
CREATE INDEX acq_picklist_owner_idx   ON acq.picklist ( owner );
CREATE INDEX acq_picklist_creator_idx ON acq.picklist ( creator );
CREATE INDEX acq_picklist_editor_idx  ON acq.picklist ( editor );
CREATE INDEX acq_po_note_creator_idx  ON acq.po_note ( creator );
CREATE INDEX acq_po_note_editor_idx   ON acq.po_note ( editor );
CREATE INDEX po_creator_idx           ON acq.purchase_order ( creator );
CREATE INDEX po_editor_idx            ON acq.purchase_order ( editor );

-- 090.schema.action.sql
CREATE INDEX circ_all_usr_idx                   ON action.circulation ( usr );
CREATE INDEX circ_circ_staff_idx                ON action.circulation ( circ_staff );
CREATE INDEX circ_checkin_staff_idx             ON action.circulation ( checkin_staff );
CREATE INDEX ahn_notify_staff_idx               ON action.hold_notification ( notify_staff );
CREATE INDEX hold_request_fulfillment_staff_idx ON action.hold_request ( fulfillment_staff );
CREATE INDEX hold_request_requestor_idx         ON action.hold_request ( requestor );
CREATE INDEX action_in_house_use_staff_idx      ON action.in_house_use ( staff );
CREATE INDEX non_cat_in_house_use_staff_idx     ON action.non_cat_in_house_use ( staff );
CREATE INDEX action_non_cat_circ_patron_idx     ON action.non_cataloged_circulation ( patron );
CREATE INDEX action_non_cat_circ_staff_idx      ON action.non_cataloged_circulation ( staff );
CREATE INDEX action_survey_response_usr_idx     ON action.survey_response ( usr );

-- 005.schema.actors.sql
CREATE INDEX actor_usr_note_creator_idx           ON actor.usr_note ( creator );
CREATE INDEX usr_org_unit_opt_in_staff_idx        ON actor.usr_org_unit_opt_in ( staff );
CREATE INDEX actor_usr_standing_penalty_staff_idx ON actor.usr_standing_penalty ( staff );

-- 040.schema.asset.sql
CREATE INDEX asset_call_number_note_creator_idx   ON asset.call_number_note ( creator );
CREATE INDEX cp_creator_idx                       ON asset.copy ( creator );
CREATE INDEX cp_editor_idx                        ON asset.copy ( editor );
CREATE INDEX asset_copy_note_creator_idx          ON asset.copy_note ( creator );

-- 901.audit-tables.sql
CREATE INDEX aud_actor_usr_address_hist_id_idx    ON auditor.actor_usr_address_history ( id );
CREATE INDEX aud_actor_usr_hist_id_idx            ON auditor.actor_usr_history ( id );
CREATE INDEX aud_asset_cn_hist_creator_idx        ON auditor.asset_call_number_history ( creator );
CREATE INDEX aud_asset_cn_hist_editor_idx         ON auditor.asset_call_number_history ( editor );
CREATE INDEX aud_asset_cp_hist_creator_idx        ON auditor.asset_copy_history ( creator );
CREATE INDEX aud_asset_cp_hist_editor_idx         ON auditor.asset_copy_history ( editor );
CREATE INDEX aud_bib_rec_entry_hist_creator_idx   ON auditor.biblio_record_entry_history ( creator );
CREATE INDEX aud_bib_rec_entry_hist_editor_idx    ON auditor.biblio_record_entry_history ( editor );

-- 070.schema.container.sql
CREATE INDEX user_bucket_item_target_user_idx     ON container.user_bucket_item ( target_user );

-- 080.schema.money.sql
CREATE INDEX m_c_t_collector_idx                  ON money.collections_tracker ( collector );


Modified: trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/005.schema.actors.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -144,6 +144,7 @@
 	value		TEXT				NOT NULL
 );
 CREATE INDEX actor_usr_note_usr_idx ON actor.usr_note (usr);
+CREATE INDEX actor_usr_note_creator_idx ON actor.usr_note ( creator );
 
 CREATE TABLE actor.usr_setting (
 	id	BIGSERIAL	PRIMARY KEY,
@@ -409,6 +410,7 @@
 	opt_in_ws	INT				NOT NULL REFERENCES actor.workstation (id) DEFERRABLE INITIALLY DEFERRED,
 	CONSTRAINT usr_opt_in_once_per_org_unit UNIQUE (usr,org_unit)
 );
+CREATE INDEX usr_org_unit_opt_in_staff_idx ON actor.usr_org_unit_opt_in ( staff );
 
 CREATE TABLE actor.org_unit_setting (
 	id		BIGSERIAL	PRIMARY KEY,
@@ -523,6 +525,7 @@
 $$;
 
 CREATE INDEX actor_usr_standing_penalty_usr_idx ON actor.usr_standing_penalty (usr);
+CREATE INDEX actor_usr_standing_penalty_staff_idx ON actor.usr_standing_penalty ( staff );
 
 
 COMMIT;

Modified: trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -64,6 +64,8 @@
 CREATE UNIQUE INDEX copy_barcode_key ON asset.copy (barcode) WHERE deleted IS FALSE;
 CREATE INDEX cp_cn_idx ON asset.copy (call_number);
 CREATE INDEX cp_avail_cn_idx ON asset.copy (call_number);
+CREATE INDEX cp_creator_idx  ON asset.copy ( creator );
+CREATE INDEX cp_editor_idx   ON asset.copy ( editor );
 CREATE RULE protect_copy_delete AS ON DELETE TO asset.copy DO INSTEAD UPDATE asset.copy SET deleted = TRUE WHERE OLD.id = asset.copy.id;
 
 CREATE TABLE asset.copy_transparency (
@@ -132,6 +134,7 @@
 	title		TEXT				NOT NULL,
 	value		TEXT				NOT NULL
 );
+CREATE INDEX asset_copy_note_creator_idx ON asset.copy_note ( creator );
 
 CREATE TABLE asset.uri (
     id  SERIAL  PRIMARY KEY,
@@ -177,6 +180,7 @@
 	title		TEXT				NOT NULL,
 	value		TEXT				NOT NULL
 );
+CREATE INDEX asset_call_number_note_creator_idx ON asset.call_number_note ( creator );
 
 CREATE VIEW stats.fleshed_copy AS 
         SELECT  cp.*,

Modified: trunk/Open-ILS/src/sql/Pg/070.schema.container.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/070.schema.container.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/070.schema.container.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -222,6 +222,7 @@
     pos         INT,
 	create_time	TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW()
 );
+CREATE INDEX user_bucket_item_target_user_idx ON container.user_bucket_item ( target_user );
 
 CREATE TABLE container.user_bucket_item_note (
     id      SERIAL      PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/080.schema.money.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/080.schema.money.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/080.schema.money.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -29,6 +29,7 @@
 	enter_time	TIMESTAMP WITH TIME ZONE
 );
 CREATE UNIQUE INDEX m_c_t_usr_collector_location_once_idx ON money.collections_tracker (usr, collector, location);
+CREATE INDEX m_c_t_collector_idx                          ON money.collections_tracker ( collector );
 
 CREATE TABLE money.billable_xact (
 	id          BIGSERIAL			PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/090.schema.action.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/090.schema.action.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/090.schema.action.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -28,6 +28,7 @@
 	org_unit	INT				NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
 	use_time	TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW()
 );
+CREATE INDEX action_in_house_use_staff_idx      ON action.in_house_use ( staff );
 
 CREATE TABLE action.non_cataloged_circulation (
 	id		SERIAL				PRIMARY KEY,
@@ -37,6 +38,8 @@
 	item_type	INT				NOT NULL REFERENCES config.non_cataloged_type (id) DEFERRABLE INITIALLY DEFERRED,
 	circ_time	TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW()
 );
+CREATE INDEX action_non_cat_circ_patron_idx ON action.non_cataloged_circulation ( patron );
+CREATE INDEX action_non_cat_circ_staff_idx  ON action.non_cataloged_circulation ( staff );
 
 CREATE TABLE action.non_cat_in_house_use (
 	id		SERIAL				PRIMARY KEY,
@@ -45,6 +48,7 @@
 	org_unit	INT				NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED,
 	use_time	TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW()
 );
+CREATE INDEX non_cat_in_house_use_staff_idx ON action.non_cat_in_house_use ( staff );
 
 CREATE TABLE action.survey (
 	id		SERIAL				PRIMARY KEY,
@@ -84,6 +88,8 @@
 	answer_date		TIMESTAMP WITH TIME ZONE,
 	effective_date		TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW()
 );
+CREATE INDEX action_survey_response_usr_idx ON action.survey_response ( usr );
+
 CREATE OR REPLACE FUNCTION action.survey_response_answer_date_fixup () RETURNS TRIGGER AS '
 BEGIN
 	NEW.answer_date := NOW();
@@ -125,6 +131,9 @@
 CREATE INDEX circ_checkin_time ON "action".circulation (checkin_time) WHERE checkin_time IS NOT NULL;
 CREATE INDEX circ_circ_lib_idx ON "action".circulation (circ_lib);
 CREATE INDEX circ_open_date_idx ON "action".circulation (xact_start) WHERE xact_finish IS NULL;
+CREATE INDEX circ_all_usr_idx       ON action.circulation ( usr );
+CREATE INDEX circ_circ_staff_idx    ON action.circulation ( circ_staff );
+CREATE INDEX circ_checkin_staff_idx ON action.circulation ( checkin_staff );
 
 CREATE TRIGGER mat_summary_create_tgr AFTER INSERT ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_create ();
 CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON action.circulation FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
@@ -294,6 +303,8 @@
 CREATE INDEX hold_request_pickup_lib_idx ON action.hold_request (pickup_lib);
 CREATE INDEX hold_request_current_copy_idx ON action.hold_request (current_copy);
 CREATE INDEX hold_request_prev_check_time_idx ON action.hold_request (prev_check_time);
+CREATE INDEX hold_request_fulfillment_staff_idx ON action.hold_request ( fulfillment_staff );
+CREATE INDEX hold_request_requestor_idx         ON action.hold_request ( requestor );
 
 
 CREATE TABLE action.hold_request_note (
@@ -323,6 +334,7 @@
 	note		TEXT
 );
 CREATE INDEX ahn_hold_idx ON action.hold_notification (hold);
+CREATE INDEX ahn_notify_staff_idx ON action.hold_notification ( notify_staff );
 
 CREATE TABLE action.hold_copy_map (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/200.schema.acq.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -134,8 +134,8 @@
 	create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
     CONSTRAINT allocation_amount_or_percent CHECK ((percent IS NULL AND amount IS NOT NULL) OR (percent IS NOT NULL AND amount IS NULL))
 );
+CREATE INDEX fund_alloc_allocator_idx ON acq.fund_allocation ( allocator );
 
-
 CREATE TABLE acq.picklist (
 	id		SERIAL				PRIMARY KEY,
 	owner		INT				NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED,
@@ -147,6 +147,9 @@
 	edit_time	TIMESTAMP WITH TIME ZONE	NOT NULL DEFAULT NOW(),
 	CONSTRAINT name_once_per_owner UNIQUE (name,owner)
 );
+CREATE INDEX acq_picklist_owner_idx   ON acq.picklist ( owner );
+CREATE INDEX acq_picklist_creator_idx ON acq.picklist ( creator );
+CREATE INDEX acq_picklist_editor_idx  ON acq.picklist ( editor );
 
 CREATE TABLE acq.purchase_order (
 	id		SERIAL				PRIMARY KEY,
@@ -162,6 +165,8 @@
 CREATE INDEX po_owner_idx ON acq.purchase_order (owner);
 CREATE INDEX po_provider_idx ON acq.purchase_order (provider);
 CREATE INDEX po_state_idx ON acq.purchase_order (state);
+CREATE INDEX po_creator_idx  ON acq.purchase_order ( creator );
+CREATE INDEX po_editor_idx   ON acq.purchase_order ( editor );
 
 CREATE TABLE acq.po_note (
 	id		SERIAL				PRIMARY KEY,
@@ -173,6 +178,8 @@
 	value		TEXT				NOT NULL
 );
 CREATE INDEX po_note_po_idx ON acq.po_note (purchase_order);
+CREATE INDEX acq_po_note_creator_idx  ON acq.po_note ( creator );
+CREATE INDEX acq_po_note_editor_idx   ON acq.po_note ( editor );
 
 CREATE TABLE acq.lineitem (
 	id                  BIGSERIAL                   PRIMARY KEY,
@@ -194,6 +201,9 @@
 );
 CREATE INDEX li_po_idx ON acq.lineitem (purchase_order);
 CREATE INDEX li_pl_idx ON acq.lineitem (picklist);
+CREATE INDEX li_creator_idx   ON acq.lineitem ( creator );
+CREATE INDEX li_editor_idx    ON acq.lineitem ( editor );
+CREATE INDEX li_selector_idx  ON acq.lineitem ( selector );
 
 CREATE TABLE acq.lineitem_note (
 	id		SERIAL				PRIMARY KEY,
@@ -205,6 +215,8 @@
 	value		TEXT				NOT NULL
 );
 CREATE INDEX li_note_li_idx ON acq.lineitem_note (lineitem);
+CREATE INDEX li_note_creator_idx  ON acq.lineitem_note ( creator );
+CREATE INDEX li_note_editor_idx   ON acq.lineitem_note ( editor );
 
 CREATE TABLE acq.lineitem_detail (
     id          BIGSERIAL	PRIMARY KEY,
@@ -252,6 +264,7 @@
 	id		BIGINT	PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq'),
 	usr		INT	NOT NULL REFERENCES actor.usr (id) DEFERRABLE INITIALLY DEFERRED
 ) INHERITS (acq.lineitem_attr_definition);
+CREATE INDEX li_usr_attr_def_usr_idx  ON acq.lineitem_usr_attr_definition ( usr );
 
 CREATE TABLE acq.lineitem_local_attr_definition (
 	id		BIGINT	PRIMARY KEY DEFAULT NEXTVAL('acq.lineitem_attr_definition_id_seq')

Modified: trunk/Open-ILS/src/sql/Pg/901.audit-tables.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/901.audit-tables.sql	2009-07-16 16:25:04 UTC (rev 13614)
+++ trunk/Open-ILS/src/sql/Pg/901.audit-tables.sql	2009-07-16 20:07:02 UTC (rev 13615)
@@ -18,11 +18,24 @@
 BEGIN;
 
 SELECT auditor.create_auditor ( 'actor', 'usr' );
+CREATE INDEX aud_actor_usr_hist_id_idx            ON auditor.actor_usr_history ( id );
+
 SELECT auditor.create_auditor ( 'actor', 'usr_address' );
+CREATE INDEX aud_actor_usr_address_hist_id_idx    ON auditor.actor_usr_address_history ( id );
+
 SELECT auditor.create_auditor ( 'actor', 'org_unit' );
+
 SELECT auditor.create_auditor ( 'biblio', 'record_entry' );
+CREATE INDEX aud_bib_rec_entry_hist_creator_idx   ON auditor.biblio_record_entry_history ( creator );
+CREATE INDEX aud_bib_rec_entry_hist_editor_idx    ON auditor.biblio_record_entry_history ( editor );
+
 SELECT auditor.create_auditor ( 'asset', 'call_number' );
+CREATE INDEX aud_asset_cn_hist_creator_idx        ON auditor.asset_call_number_history ( creator );
+CREATE INDEX aud_asset_cn_hist_editor_idx         ON auditor.asset_call_number_history ( editor );
+
 SELECT auditor.create_auditor ( 'asset', 'copy' );
+CREATE INDEX aud_asset_cp_hist_creator_idx        ON auditor.asset_copy_history ( creator );
+CREATE INDEX aud_asset_cp_hist_editor_idx         ON auditor.asset_copy_history ( editor );
 
 COMMIT;
 



More information about the open-ils-commits mailing list