Skip to content

Add index on starts_at/ends_at for oncall shifts

Sarah Yasonik requested to merge sy-add-shift-timeframe-index into master

What does this MR do?

Adds an index for oncall shifts table on rotation_id/starts_at/ends_at, replacing the existing index on rotation_id.

!52388 (merged) and !50239 (merged) add queries which search the shifts table based on the starts_at and ends_at attributes. These queries would be improved by an index!

Click here for migration output!

Up migration output

$ rails db:migrate
== 20210129225244 AddIndexToOncallShftsOnStartsAtAndEndsAt: migrating =========
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:incident_management_oncall_shifts, [:rotation_id, :starts_at, :ends_at], {:name=>"index_oncall_shifts_on_rotation_id_and_starts_at_and_ends_at", :algorithm=>:concurrently})
   -> 0.0108s
-- execute("SET statement_timeout TO 0")
   -> 0.0001s
-- add_index(:incident_management_oncall_shifts, [:rotation_id, :starts_at, :ends_at], {:name=>"index_oncall_shifts_on_rotation_id_and_starts_at_and_ends_at", :algorithm=>:concurrently})
   -> 0.0255s
-- execute("RESET ALL")
   -> 0.0002s
-- transaction_open?()
   -> 0.0000s
-- indexes(:incident_management_oncall_shifts)
   -> 0.0024s
-- remove_index(:incident_management_oncall_shifts, {:algorithm=>:concurrently, :name=>"index_incident_management_oncall_shifts_on_rotation_id"})
   -> 0.0161s
== 20210129225244 AddIndexToOncallShftsOnStartsAtAndEndsAt: migrated (0.0560s) 
$ bin/rails dbconsole
psql (11.9)
Type "help" for help.

gitlabhq_development=# \d incident_management_oncall_shifts
                                         Table "public.incident_management_oncall_shifts"
     Column     |           Type           | Collation | Nullable |                            Default                            
----------------+--------------------------+-----------+----------+---------------------------------------------------------------
 id             | bigint                   |           | not null | nextval('incident_management_oncall_shifts_id_seq'::regclass)
 rotation_id    | bigint                   |           | not null | 
 participant_id | bigint                   |           | not null | 
 starts_at      | timestamp with time zone |           | not null | 
 ends_at        | timestamp with time zone |           | not null | 
Indexes:
    "incident_management_oncall_shifts_pkey" PRIMARY KEY, btree (id)
    "inc_mgmnt_no_overlapping_oncall_shifts" EXCLUDE USING gist (rotation_id WITH =, tstzrange(starts_at, ends_at, '[)'::text) WITH &&)
    "index_incident_management_oncall_shifts_on_participant_id" btree (participant_id)
    "index_oncall_shifts_on_rotation_id_and_starts_at_and_ends_at" btree (rotation_id, starts_at, ends_at)
Foreign-key constraints:
    "fk_rails_df4feb286a" FOREIGN KEY (rotation_id) REFERENCES incident_management_oncall_rotations(id) ON DELETE CASCADE
    "fk_rails_f6eef06841" FOREIGN KEY (participant_id) REFERENCES incident_management_oncall_participants(id) ON DELETE CASCADE

Down migration output

$ rails db:rollback
== 20210129225244 AddIndexToOncallShftsOnStartsAtAndEndsAt: reverting =========
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:incident_management_oncall_shifts, :rotation_id, {:name=>"index_incident_management_oncall_shifts_on_rotation_id", :algorithm=>:concurrently})
   -> 0.0026s
-- execute("SET statement_timeout TO 0")
   -> 0.0002s
-- add_index(:incident_management_oncall_shifts, :rotation_id, {:name=>"index_incident_management_oncall_shifts_on_rotation_id", :algorithm=>:concurrently})
   -> 0.0040s
-- execute("RESET ALL")
   -> 0.0002s
-- transaction_open?()
   -> 0.0000s
-- indexes(:incident_management_oncall_shifts)
   -> 0.0016s
-- remove_index(:incident_management_oncall_shifts, {:algorithm=>:concurrently, :name=>"index_oncall_shifts_on_rotation_id_and_starts_at_and_ends_at"})
   -> 0.0017s
== 20210129225244 AddIndexToOncallShftsOnStartsAtAndEndsAt: reverted (0.0109s) 
$ bin/rails dbconsole
psql (11.9)
Type "help" for help.

gitlabhq_development=# \d incident_management_oncall_shifts
                                         Table "public.incident_management_oncall_shifts"
     Column     |           Type           | Collation | Nullable |                            Default                            
----------------+--------------------------+-----------+----------+---------------------------------------------------------------
 id             | bigint                   |           | not null | nextval('incident_management_oncall_shifts_id_seq'::regclass)
 rotation_id    | bigint                   |           | not null | 
 participant_id | bigint                   |           | not null | 
 starts_at      | timestamp with time zone |           | not null | 
 ends_at        | timestamp with time zone |           | not null | 
Indexes:
    "incident_management_oncall_shifts_pkey" PRIMARY KEY, btree (id)
    "inc_mgmnt_no_overlapping_oncall_shifts" EXCLUDE USING gist (rotation_id WITH =, tstzrange(starts_at, ends_at, '[)'::text) WITH &&)
    "index_incident_management_oncall_shifts_on_participant_id" btree (participant_id)
    "index_incident_management_oncall_shifts_on_rotation_id" btree (rotation_id)
Foreign-key constraints:
    "fk_rails_df4feb286a" FOREIGN KEY (rotation_id) REFERENCES incident_management_oncall_rotations(id) ON DELETE CASCADE
    "fk_rails_f6eef06841" FOREIGN KEY (participant_id) REFERENCES incident_management_oncall_participants(id) ON DELETE CASCADE

Click here for query info & performance!

As oncall shifts are fairly new, I had to seed my local environment with data. I seeded ~100 projects with oncall management records, giving ~150_000 shift rows.

Total record counts:

Project: 101
OncallShifts: 155611
OncallParticipants: 13637
OncallRotations: 960
OncallSchedules: 309

Raw query - !52388 (merged):

SELECT 
  "incident_management_oncall_shifts".* 
FROM "incident_management_oncall_shifts" 
WHERE "incident_management_oncall_shifts"."rotation_id" IN (
  SELECT "incident_management_oncall_rotations"."id" 
  FROM "incident_management_oncall_rotations" 
  INNER JOIN "incident_management_oncall_schedules" 
    ON "incident_management_oncall_rotations"."oncall_schedule_id" = "incident_management_oncall_schedules"."id" 
  WHERE "incident_management_oncall_schedules"."project_id" = 21
) 
AND (starts_at <= '2020-11-06 18:17:13.730213' AND ends_at > '2020-11-06 18:17:13.730213')

Query plans:

Query plans without index:

Raw query - !50239 (merged):

SELECT "incident_management_oncall_shifts".* 
FROM "incident_management_oncall_shifts" 
WHERE "incident_management_oncall_shifts"."rotation_id" = 71 
AND (tstzrange(starts_at, ends_at, '[)') && tstzrange('2021-01-22 23:55:54.256959', '2021-01-29 23:55:54.257877', '[)')) 
ORDER BY "incident_management_oncall_shifts"."starts_at" DESC

Query plans:

Query plans without index:


Does this MR meet the acceptance criteria?

Conformity

Availability and Testing

Security

If this MR contains changes to processing or storing of credentials or tokens, authorization and authentication methods and other items described in the security review guidelines:

  • Label as security and @ mention @gitlab-com/gl-security/appsec
  • The MR includes necessary changes to maintain consistency between UI, API, email, or other methods
  • Security reports checked/validated by a reviewer from the AppSec team
Edited by Sarah Yasonik

Merge request reports