Use PostgreSQL's partial indexes to improve query speeds

Changes update their lastUpdatedOn field frequently, until they get
closed, and then they never almost update it again.  By only indexing
this field when open = 'N' we can allow PostgreSQL to delay making
the index over this column until the change is actually closed.

Changes that are open for an owner are usually a very small subset.
We can improve query performance by indexing only the open changes,
avoiding the need to consider closed changes when scanning for my
own changes.

Very few, if any, changes are ever in the submitted status.  Making
an index over only those currently in the submitted state saves us
quite a bit of time indexing (and searching) the other states that
aren't at all relevant for submission handling.

Signed-off-by: Shawn O. Pearce <sop@google.com>
This commit is contained in:
Shawn O. Pearce
2009-01-14 20:17:31 -08:00
parent 3ffac27940
commit 36f6305fac

View File

@@ -74,13 +74,20 @@ ON account_group_members (group_id);
-- *********************************************************************
-- ChangeAccess
-- covers: byOwnerOpen, byOwnerClosed
CREATE INDEX changes_byOwnerStatus
ON changes (owner_account_id, open, last_updated_on DESC);
-- covers: byOwnerOpen
CREATE INDEX changes_byOwnerOpen
ON changes (owner_account_id, created_on, change_id)
WHERE open = 'Y';
-- covers: byOwnerClosed
CREATE INDEX changes_byOwnerClosed
ON changes (owner_account_id, last_updated_on DESC)
WHERE open = 'N';
-- covers: submitted
CREATE INDEX changes_submitted
ON changes (dest_project_name, dest_branch_name, status, last_updated_on);
ON changes (dest_project_name, dest_branch_name, last_updated_on)
WHERE status = 's';
-- *********************************************************************