Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add an index on org_id, service and created_at to the runs table #342

Conversation

dehort
Copy link
Contributor

@dehort dehort commented Feb 21, 2024

  • research concurrently on the create index
  • test with more data
insights=# explain analyse select "id","labels",case when runs.status='running' and runs.created_at + runs.timeout * interval '1 second' <= now() then 'timeout' else runs.status end as status,"service","created_at","updated_at","url" from "runs" where (org_id = '5318290') and service in ('remediations','config_manager','test') and runs.service = 'remediations' and runs.labels ->> 'playbook-run' = '7978185d-88c8-47f3-8273-bbeaf67d67c9' order by created_at desc,id limit 50;
                                                                                                                                QUERY PLAN                                                     
                                                                            
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------
 Limit  (cost=541.52..541.53 rows=1 width=93) (actual time=1.140..1.141 rows=0 loops=1)
   ->  Sort  (cost=541.52..541.53 rows=1 width=93) (actual time=1.139..1.140 rows=0 loops=1)
         Sort Key: created_at DESC, id
         Sort Method: quicksort  Memory: 25kB
         ->  Seq Scan on runs  (cost=0.00..541.51 rows=1 width=93) (actual time=1.135..1.136 rows=0 loops=1)
               Filter: (((org_id)::text = '5318290'::text) AND ((service)::text = 'remediations'::text) AND ((service)::text = ANY ('{remediations,config_manager,test}'::text[])) AND ((labels
 ->> 'playbook-run'::text) = '7978185d-88c8-47f3-8273-bbeaf67d67c9'::text))
               Rows Removed by Filter: 10000
 Planning Time: 0.088 ms
 Execution Time: 1.156 ms
(9 rows)

Run migrations that apply index

insights=# explain analyse select "id","labels",case when runs.status='running' and runs.created_at + runs.timeout * interval '1 second' <= now() then 'timeout' else runs.status end as status,"service","created_at","updated_at","url" from "runs" where (org_id = '5318290') and service in ('remediations','config_manager','test') and runs.service = 'remediations' and runs.labels ->> 'playbook-run' = '7978185d-88c8-47f3-8273-bbeaf67d67c9' order by created_at desc,id limit 50;
                                                                         QUERY PLAN                                                                          
-------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=6.09..6.09 rows=1 width=93) (actual time=0.013..0.013 rows=0 loops=1)
   ->  Sort  (cost=6.09..6.09 rows=1 width=93) (actual time=0.012..0.012 rows=0 loops=1)
         Sort Key: created_at DESC, id
         Sort Method: quicksort  Memory: 25kB
         ->  Index Scan using runs_org_id_service_created_at_desc_index on runs  (cost=0.29..6.08 rows=1 width=93) (actual time=0.009..0.009 rows=0 loops=1)
               Index Cond: (((org_id)::text = '5318290'::text) AND ((service)::text = 'remediations'::text))
               Filter: ((labels ->> 'playbook-run'::text) = '7978185d-88c8-47f3-8273-bbeaf67d67c9'::text)
 Planning Time: 0.140 ms
 Execution Time: 0.024 ms
(9 rows)

===== count() query - same basic query - just making sure ==============

insights=# explain analyse select count(*) from "runs" where (org_id = '5318290') and service in ('remediations','config_manager','test') and runs.service = 'remediations' and runs.labels ->> 'playbook-run' = '7978185d-88c8-47f3-8273-bbeaf67d67c9';
                                                                                                                             QUERY PLAN                                                        
                                                                      
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
----------------------------------------------------------------------
 Aggregate  (cost=541.50..541.51 rows=1 width=8) (actual time=1.394..1.395 rows=1 loops=1)
   ->  Seq Scan on runs  (cost=0.00..541.50 rows=1 width=0) (actual time=1.391..1.391 rows=0 loops=1)
         Filter: (((org_id)::text = '5318290'::text) AND ((service)::text = 'remediations'::text) AND ((service)::text = ANY ('{remediations,config_manager,test}'::text[])) AND ((labels ->> '
playbook-run'::text) = '7978185d-88c8-47f3-8273-bbeaf67d67c9'::text))
         Rows Removed by Filter: 10000
 Planning Time: 0.094 ms
 Execution Time: 1.410 ms
(6 rows)

Run migrations that apply index

insights=# explain analyse select count(*) from "runs" where (org_id = '5318290') and service in ('remediations','config_manager','test') and runs.service = 'remediations' and runs.labels ->> 'playbook-run' = '7978185d-88c8-47f3-8273-bbeaf67d67c9';
                                                                      QUERY PLAN                                                                      
------------------------------------------------------------------------------------------------------------------------------------------------------
 Aggregate  (cost=6.07..6.08 rows=1 width=8) (actual time=0.014..0.014 rows=1 loops=1)
   ->  Index Scan using runs_org_id_service_created_at_desc_index on runs  (cost=0.29..6.06 rows=1 width=0) (actual time=0.012..0.013 rows=0 loops=1)
         Index Cond: (((org_id)::text = '5318290'::text) AND ((service)::text = 'remediations'::text))
         Filter: ((labels ->> 'playbook-run'::text) = '7978185d-88c8-47f3-8273-bbeaf67d67c9'::text)
 Planning Time: 0.132 ms
 Execution Time: 0.026 ms
(6 rows)

@josejulio
Copy link
Member

awesome! changed from seq_scan to index_scan 👍

@dehort dehort closed this Dec 4, 2024
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants