Commit 14f1a3aa authored by Patrick Bajao's avatar Patrick Bajao

Improve query performance of attention requests count

In https://gitlab.com/gitlab-org/gitlab/-/merge_requests/74800, 2
indexes were added to `merge_request_assignees` and
`merge_request_reviewers` tables to improve the performance of the
finder query for attention requests.

In https://gitlab.com/gitlab-org/gitlab/-/merge_requests/80732, the
finder query was used to show the count of attention requests.

While investigating a bug related to the count, found out that the
count query isn't performant enough. Based on this query plan
(https://console.postgres.ai/gitlab/gitlab-production-tunnel-pg12/sessions/9497/commands/33700),
it takes around 447ms.

It's noticeable that the query plan isn't using the index added on
the first MR when querying the `merge_request_assignees` and
`merge_request_reviewers` tables.

To fix this, narrower indexes are added on both tables for `user_id`
and `state` columns. This also deletes the `state` indexes that
were added before. The query timing dropped to 14ms from 447ms.

Query plan: https://console.postgres.ai/gitlab/gitlab-production-tunnel-pg12/sessions/9497/commands/33717

Changelog: performance
parent 7d6547ce
# frozen_string_literal: true
class AddUserIdAndStateIndexToMergeRequestAssignees < Gitlab::Database::Migration[1.0]
disable_ddl_transaction!
INDEX_NAME = 'index_on_merge_request_assignees_user_id_and_state'
def up
add_concurrent_index :merge_request_assignees, [:user_id, :state], where: 'state = 2', name: INDEX_NAME
end
def down
remove_concurrent_index_by_name :merge_request_assignees, INDEX_NAME
end
end
# frozen_string_literal: true
class AddUserIdAndStateIndexToMergeRequestReviewers < Gitlab::Database::Migration[1.0]
disable_ddl_transaction!
INDEX_NAME = 'index_on_merge_request_reviewers_user_id_and_state'
def up
add_concurrent_index :merge_request_reviewers, [:user_id, :state], where: 'state = 2', name: INDEX_NAME
end
def down
remove_concurrent_index_by_name :merge_request_reviewers, INDEX_NAME
end
end
# frozen_string_literal: true
class RemoveStateIndexOnMergeRequestAssignees < Gitlab::Database::Migration[1.0]
disable_ddl_transaction!
INDEX_NAME = 'index_on_merge_request_assignees_state'
def up
remove_concurrent_index_by_name :merge_request_assignees, INDEX_NAME
end
def down
add_concurrent_index :merge_request_assignees, :state, where: 'state = 2', name: INDEX_NAME
end
end
# frozen_string_literal: true
class RemoveStateIndexOnMergeRequestReviewers < Gitlab::Database::Migration[1.0]
disable_ddl_transaction!
INDEX_NAME = 'index_on_merge_request_reviewers_state'
def up
remove_concurrent_index_by_name :merge_request_reviewers, INDEX_NAME
end
def down
add_concurrent_index :merge_request_reviewers, :state, where: 'state = 2', name: INDEX_NAME
end
end
7d9341440faaf8782bc47a24091148c40d635cc1c980a57999b47aff3d42806d
\ No newline at end of file
1f91d4855c6be0d7baf19f3d63d2efb4ccd8da85a7dcc4ad57fd03891f12fe46
\ No newline at end of file
9a2274c54a0c0393bf0a2ae7985b957364c63952273383c3aa6ff6c5b4655a42
\ No newline at end of file
5eabeb19a1b79c21333eb519cf7419c5424cf1270c97637d07bb2a09946ceaf0
\ No newline at end of file
......@@ -28375,14 +28375,14 @@ CREATE INDEX index_on_issues_closed_incidents_by_project_id_and_closed_at ON iss
CREATE INDEX index_on_label_links_all_columns ON label_links USING btree (target_id, label_id, target_type);
CREATE INDEX index_on_merge_request_assignees_state ON merge_request_assignees USING btree (state) WHERE (state = 2);
CREATE INDEX index_on_merge_request_assignees_updated_state_by_user_id ON merge_request_assignees USING btree (updated_state_by_user_id);
CREATE INDEX index_on_merge_request_reviewers_state ON merge_request_reviewers USING btree (state) WHERE (state = 2);
CREATE INDEX index_on_merge_request_assignees_user_id_and_state ON merge_request_assignees USING btree (user_id, state) WHERE (state = 2);
CREATE INDEX index_on_merge_request_reviewers_updated_state_by_user_id ON merge_request_reviewers USING btree (updated_state_by_user_id);
CREATE INDEX index_on_merge_request_reviewers_user_id_and_state ON merge_request_reviewers USING btree (user_id, state) WHERE (state = 2);
CREATE INDEX index_on_merge_requests_for_latest_diffs ON merge_requests USING btree (target_project_id) INCLUDE (id, latest_merge_request_diff_id);
COMMENT ON INDEX index_on_merge_requests_for_latest_diffs IS 'Index used to efficiently obtain the oldest merge request for a commit SHA';
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment