Skip to content

Improve performance of stale Ci::Runner queries

What does this MR do and why?

Describe in detail what your merge request does and why.

This MR optimizes the query behind the stale Ci::Runner scope so that it uses UNION ALL instead of OR. This allows making use of the index_ci_runners_on_id_desc_and_contacted_at_desc and index_ci_runners_on_created_at_and_id_desc indices. Previously it was only making use of index_ci_runners_on_created_at_and_id_desc.

Screenshots or screen recordings

Screenshots are required for UI changes, and strongly recommended for all other merge requests.

How to set up and validate locally

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

Database queries

Ci::Runner.stale

Previous query

SQL query
SELECT "ci_runners".*
FROM "ci_runners"
WHERE (ci_runners.created_at < '2022-10-09 13:40:07.110762'
  AND (ci_runners.contacted_at IS NULL
    OR ci_runners.contacted_at < '2022-10-09 13:40:07.110762'))
Query execution plan

https://postgres.ai/console/gitlab/gitlab-production-ci/sessions/14307/commands/50174

 Index Scan using index_ci_runners_on_created_at_and_id_desc on public.ci_runners  (cost=0.43..384168.25 rows=1022535 width=282) (actual time=0.030..2481.873 rows=1434475 loops=1)
   Index Cond: (ci_runners.created_at < '2022-10-09 13:40:07.110762'::timestamp without time zone)
   Filter: ((ci_runners.contacted_at IS NULL) OR (ci_runners.contacted_at < '2022-10-09 13:40:07.110762'::timestamp without time zone))
   Rows Removed by Filter: 178676
   Buffers: shared hit=967790 read=11 dirtied=8
   I/O Timings: read=11.005 write=0.000

New query

SQL query
SELECT "ci_runners".*
FROM "ci_runners"
WHERE "ci_runners"."created_at" < '2022-10-09 16:20:08.524669'
  AND "ci_runners"."id" IN (
    SELECT "ci_runners"."id"
    FROM ((
        SELECT "ci_runners"."id"
        FROM "ci_runners"
        WHERE "ci_runners"."contacted_at" IS NULL)
      UNION ALL (
        SELECT "ci_runners"."id"
        FROM "ci_runners"
        WHERE "ci_runners"."contacted_at" < '2022-10-09 16:20:08.524762')) ci_runners)
Query execution plan

https://postgres.ai/console/gitlab/gitlab-production-ci/sessions/14307/commands/50185

 Append  (cost=0.43..551022.69 rows=1273871 width=282) (actual time=36.163..1985.434 rows=1434488 loops=1)
   Buffers: shared hit=891885
   I/O Timings: read=0.000 write=0.000
   ->  Index Scan using index_ci_runners_on_contacted_at_desc_and_id_desc on public.ci_runners  (cost=0.43..265788.81 rows=633703 width=282) (actual time=36.162..806.536 rows=708888 loops=1)
         Index Cond: (ci_runners.contacted_at IS NULL)
         Filter: (ci_runners.created_at < '2022-10-09 14:18:30.26585'::timestamp without time zone)
         Rows Removed by Filter: 9854
         Buffers: shared hit=257990
         I/O Timings: read=0.000 write=0.000
   ->  Index Scan using index_ci_runners_on_contacted_at_desc_and_id_desc on public.ci_runners ci_runners_1  (cost=0.43..266125.81 rows=640168 width=282) (actual time=0.058..1044.176 rows=725600 loops=1)
         Index Cond: (ci_runners_1.contacted_at < '2022-10-09 14:18:30.265939'::timestamp without time zone)
         Filter: (ci_runners_1.created_at < '2022-10-09 14:18:30.26585'::timestamp without time zone)
         Rows Removed by Filter: 0
         Buffers: shared hit=633895
         I/O Timings: read=0.000 write=0.000

MR acceptance checklist

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

Edited by Pedro Pombeiro

Merge request reports