Commit 92d3c08f authored by Stan Hu's avatar Stan Hu

Add indexes on deployments to improve environments search

To load diffs and other files, we make two SELECT calls in
`MergeRequest#environments_for`: one for the source branch, and one for
the target branch.

The source branch query makes a subquery:

```sql
SELECT environment_id FROM deployments WHERE project_id = 123 AND ref =
'source_branch'
```

The target branch makes this subquery:

```sql
SELECT environment_id FROM deployments WHERE project_id = 123 AND (ref =
'master' OR tag IS TRUE)
```

Both subqueries were taking over 250 ms to execute. When we add an index
for the deployments table on `(projects_id, ref)`, this execution drops
down to under 5 ms since the table usually has a small number of rows
for the source branch.

Adding a partial index on `projects_id WHERE tag IS TRUE` allows
PostgreSQL to perform two separate indexed scans: one for the ref, and
one for the tag condition. However, this query still takes 60 ms to run
for the gitlab-org/gitlab project because `master` has 10,000+ rows. We
should consider adding a LIMIT in a future iteration.

Closes https://gitlab.com/gitlab-org/gitlab/issues/55353
parent cddef73d
---
title: Add indexes on deployments to improve environments search
merge_request: 21789
author:
type: performance
# frozen_string_literal: true
class AddIndexesToDeploymentsOnProjectIdAndRef < ActiveRecord::Migration[5.2]
include Gitlab::Database::MigrationHelpers
DOWNTIME = false
INDEX_NAME = 'partial_index_deployments_for_project_id_and_tag'.freeze
disable_ddl_transaction!
def up
add_concurrent_index :deployments, [:project_id, :ref]
add_concurrent_index :deployments, [:project_id], where: 'tag IS TRUE', name: INDEX_NAME
end
def down
remove_concurrent_index :deployments, [:project_id, :ref]
remove_concurrent_index :deployments, [:project_id], where: 'tag IS TRUE', name: INDEX_NAME
end
end
......@@ -10,7 +10,7 @@
#
# It's strongly recommended that you check this file into your version control system.
ActiveRecord::Schema.define(version: 2019_12_08_071112) do
ActiveRecord::Schema.define(version: 2019_12_14_175727) do
# These are extensions that must be enabled in order to support this database
enable_extension "pg_trgm"
......@@ -1357,9 +1357,11 @@ ActiveRecord::Schema.define(version: 2019_12_08_071112) do
t.index ["id"], name: "partial_index_deployments_for_legacy_successful_deployments", where: "((finished_at IS NULL) AND (status = 2))"
t.index ["project_id", "id"], name: "index_deployments_on_project_id_and_id", order: { id: :desc }
t.index ["project_id", "iid"], name: "index_deployments_on_project_id_and_iid", unique: true
t.index ["project_id", "ref"], name: "index_deployments_on_project_id_and_ref"
t.index ["project_id", "status", "created_at"], name: "index_deployments_on_project_id_and_status_and_created_at"
t.index ["project_id", "status"], name: "index_deployments_on_project_id_and_status"
t.index ["project_id", "updated_at", "id"], name: "index_deployments_on_project_id_and_updated_at_and_id", order: { updated_at: :desc, id: :desc }
t.index ["project_id"], name: "partial_index_deployments_for_project_id_and_tag", where: "(tag IS TRUE)"
end
create_table "description_versions", force: :cascade do |t|
......
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