Skip to content

Optimize EnvironmentsByDeploymentsFinder query

What does this MR do and why?

When implementing !72781 (merged)

We planned to have this subquery:

  AND EXISTS (
    SELECT 1
    FROM "deployments"
    WHERE "deployments"."environment_id" = "environments"."id"
      AND (ref = $4)
  )

But I forgot to that deployments are scoped by project, and the resulting query is

EXISTS (SELECT "deployments".*
  FROM   "deployments"
  WHERE  "deployments"."project_id" = 50
  AND ( ref = 'main' )
  AND ( environment_id = environments.id )) )

project_id filter forces this query to use index_deployments_on_project_id_and_ref instead of index_deployments_on_environment_id_and_ref which was introduced for this finder

This commit adds unscope(where: :project_id).

Resulting query now is:

SELECT "environments".*
FROM   "environments"
WHERE  "environments"."project_id" = 50
       AND ( "environments"."state" IN ( 'available' ) )
       AND ( EXISTS (SELECT "deployments".*
                     FROM   "deployments"
                     WHERE  ( ref = 'main' )
                            AND ( environment_id = environments.id )) )
ORDER  BY (SELECT Max("deployments"."id")
           FROM   "deployments"
           WHERE  "deployments"."environment_id" = "environments"."id") ASC
          nulls first

It brings execution time from 1.6 minutes to 6 seconds with cold cache: https://console.postgres.ai/gitlab/gitlab-production-tunnel-pg12/sessions/7269/commands/25841 It's still slow, but much better than it was.

Screenshots or screen recordings

These are strongly recommended to assist reviewers and reduce the time to merge your change.

How to set up and validate locally

Numbered steps to set up and validate the change are strongly suggested.

MR acceptance checklist

This checklist encourages us to confirm any changes have been analyzed to reduce risks in quality, performance, reliability, security, and maintainability.

Related to #342715 (closed)

Edited by Vladimir Shushlin

Merge request reports

Loading