Added partial index for merge requests
This index is added on `(target_project_id, iid)` and has a `WHERE state = 'opened'` condition. Using this index we can drastically improve the performance of the query used to count the total number of merge requests in a group. Without this index the query would eventually perform the following: -> Index Scan using index_merge_requests_on_target_project_id_and_iid on merge_requests (cost=0.43..4.89 rows=7 width=4) (actual time=0.058..0.353 rows=6 loops=228) Index Cond: (target_project_id = projects.id) Filter: ((state)::text = 'opened'::text) Rows Removed by Filter: 141 Buffers: shared hit=34351 dirtied=1 Out of the ~180 milliseconds the entire query would take, around 170 milliseconds was spent in just this segment. With the index in place, the above segment is turned into the following: -> Index Only Scan using yorick_test on merge_requests (cost=0.42..0.55 rows=7 width=4) (actual time=0.004..0.010 rows=6 loops=228) Index Cond: (target_project_id = projects.id) Heap Fetches: 419 Buffers: shared hit=1381 The index also reduces the total query time to roughly 10 milliseconds.
This commit is contained in:
parent
77d4546eda
commit
709dd23760
2 changed files with 29 additions and 1 deletions
|
@ -0,0 +1,27 @@
|
|||
# See http://doc.gitlab.com/ce/development/migration_style_guide.html
|
||||
# for more information on how to write migrations for GitLab.
|
||||
|
||||
class MergeRequestsTargetIdIidStatePartialIndex < ActiveRecord::Migration
|
||||
include Gitlab::Database::MigrationHelpers
|
||||
|
||||
# Set this constant to true if this migration requires downtime.
|
||||
DOWNTIME = false
|
||||
|
||||
INDEX_NAME = 'index_merge_requests_on_target_project_id_and_iid_opened'
|
||||
|
||||
disable_ddl_transaction!
|
||||
|
||||
def up
|
||||
# On GitLab.com this index will take up roughly 5 MB of space.
|
||||
add_concurrent_index(
|
||||
:merge_requests,
|
||||
[:target_project_id, :iid],
|
||||
where: "state = 'opened'",
|
||||
name: INDEX_NAME
|
||||
)
|
||||
end
|
||||
|
||||
def down
|
||||
remove_concurrent_index_by_name(:merge_requests, INDEX_NAME)
|
||||
end
|
||||
end
|
|
@ -11,7 +11,7 @@
|
|||
#
|
||||
# It's strongly recommended that you check this file into your version control system.
|
||||
|
||||
ActiveRecord::Schema.define(version: 20180521171529) do
|
||||
ActiveRecord::Schema.define(version: 20180524132016) do
|
||||
|
||||
# These are extensions that must be enabled in order to support this database
|
||||
enable_extension "plpgsql"
|
||||
|
@ -1232,6 +1232,7 @@ ActiveRecord::Schema.define(version: 20180521171529) do
|
|||
add_index "merge_requests", ["source_project_id", "source_branch"], name: "index_merge_requests_on_source_project_id_and_source_branch", using: :btree
|
||||
add_index "merge_requests", ["target_branch"], name: "index_merge_requests_on_target_branch", using: :btree
|
||||
add_index "merge_requests", ["target_project_id", "iid"], name: "index_merge_requests_on_target_project_id_and_iid", unique: true, using: :btree
|
||||
add_index "merge_requests", ["target_project_id", "iid"], name: "index_merge_requests_on_target_project_id_and_iid_opened", where: "((state)::text = 'opened'::text)", using: :btree
|
||||
add_index "merge_requests", ["target_project_id", "merge_commit_sha", "id"], name: "index_merge_requests_on_tp_id_and_merge_commit_sha_and_id", using: :btree
|
||||
add_index "merge_requests", ["title"], name: "index_merge_requests_on_title", using: :btree
|
||||
add_index "merge_requests", ["title"], name: "index_merge_requests_on_title_trigram", using: :gin, opclasses: {"title"=>"gin_trgm_ops"}
|
||||
|
|
Loading…
Reference in a new issue