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

perf: add indexes to tasks and allocations #8757

Merged
merged 2 commits into from
Feb 2, 2024

Conversation

NicholasBlaskey
Copy link
Contributor

Description

Enriching experiments was not using any indexes which we should defiantly add.

	SELECT
		j.job_id AS job,
		BOOL_OR(CASE WHEN a.state = 'PULLING' THEN true ELSE false END) AS pulling,
		BOOL_OR(CASE WHEN a.state = 'STARTING' THEN true ELSE false END) AS starting,
		BOOL_OR(CASE WHEN a.state = 'RUNNING' THEN true ELSE false END) AS running
	FROM
		jobs j
		JOIN tasks t ON t.job_id = j.job_id
		JOIN allocations a ON a.task_id = t.task_id
	WHERE j.job_id in (SELECT unnest(string_to_array(?, ',')))
	GROUP BY j.job_id

Test Plan

No tests needed besides like the cluster not breaking

Commentary (optional)

Checklist

  • Changes have been manually QA'd
  • User-facing API changes need the "User-facing API Change" label.
  • Release notes should be added as a separate file under docs/release-notes/.
    See Release Note for details.
  • Licenses should be included for new code which was copied and/or modified from any external code.

Ticket

Copy link

netlify bot commented Jan 25, 2024

Deploy Preview for determined-ui canceled.

Name Link
🔨 Latest commit a08e75d
🔍 Latest deploy log https://app.netlify.com/sites/determined-ui/deploys/65bceef1cd23360008f479d8

Copy link

codecov bot commented Jan 25, 2024

Codecov Report

All modified and coverable lines are covered by tests ✅

Comparison is base (e873381) 47.70% compared to head (a08e75d) 47.70%.
Report is 2 commits behind head on main.

Additional details and impacted files
@@            Coverage Diff             @@
##             main    #8757      +/-   ##
==========================================
- Coverage   47.70%   47.70%   -0.01%     
==========================================
  Files        1049     1049              
  Lines      167250   167250              
  Branches     2241     2243       +2     
==========================================
- Hits        79792    79791       -1     
- Misses      87300    87301       +1     
  Partials      158      158              
Flag Coverage Δ
backend 43.15% <ø> (-0.01%) ⬇️
harness 64.32% <ø> (ø)
web 42.54% <ø> (ø)

Flags with carried forward coverage won't be shown. Click here to find out more.

see 1 file with indirect coverage changes

@NicholasBlaskey
Copy link
Contributor Author

Example query on anon db without index

                                                                         QUERY PLAN                                                                         
------------------------------------------------------------------------------------------------------------------------------------------------------------
 GroupAggregate  (cost=24536.61..24537.15 rows=18 width=36) (actual time=171.373..171.380 rows=1 loops=1)
   Group Key: j.job_id
   ->  Sort  (cost=24536.61..24536.66 rows=18 width=37) (actual time=171.363..171.370 rows=1 loops=1)
         Sort Key: j.job_id
         Sort Method: quicksort  Memory: 25kB
         ->  Hash Join  (cost=9392.08..24536.24 rows=18 width=37) (actual time=162.867..171.355 rows=1 loops=1)
               Hash Cond: (a.task_id = t.task_id)
               ->  Seq Scan on allocations a  (cost=0.00..13406.44 rows=463344 width=46) (actual time=0.007..64.052 rows=463344 loops=1)
               ->  Hash  (cost=9391.91..9391.91 rows=13 width=67) (actual time=64.821..64.826 rows=1 loops=1)
                     Buckets: 1024  Batches: 1  Memory Usage: 9kB
                     ->  Nested Loop  (cost=0.47..9391.91 rows=13 width=67) (actual time=64.816..64.823 rows=1 loops=1)
                           ->  Hash Join  (cost=0.06..9386.14 rows=13 width=103) (actual time=64.790..64.796 rows=1 loops=1)
                                 Hash Cond: (t.job_id = (unnest('{d699cb50-cb2e-43fe-88ae-5440218ec487}'::text[])))
                                 ->  Seq Scan on tasks t  (cost=0.00..8126.24 rows=335924 width=71) (actual time=0.003..39.682 rows=335924 loops=1)
                                 ->  Hash  (cost=0.05..0.05 rows=1 width=32) (actual time=0.007..0.009 rows=1 loops=1)
                                       Buckets: 1024  Batches: 1  Memory Usage: 9kB
                                       ->  HashAggregate  (cost=0.04..0.05 rows=1 width=32) (actual time=0.005..0.007 rows=1 loops=1)
                                             Group Key: unnest('{d699cb50-cb2e-43fe-88ae-5440218ec487}'::text[])
                                             Batches: 1  Memory Usage: 24kB
                                             ->  ProjectSet  (cost=0.00..0.02 rows=1 width=32) (actual time=0.002..0.003 rows=1 loops=1)
                                                   ->  Result  (cost=0.00..0.01 rows=1 width=0) (actual time=0.000..0.001 rows=1 loops=1)
                           ->  Index Only Scan using jobs_job_id_key on jobs j  (cost=0.42..0.44 rows=1 width=33) (actual time=0.020..0.021 rows=1 loops=1)
                                 Index Cond: (job_id = t.job_id)
                                 Heap Fetches: 0
 Planning Time: 0.740 ms
 Execution Time: 171.437 ms
(26 rows)

after

                                                                      QUERY PLAN                                                                      
------------------------------------------------------------------------------------------------------------------------------------------------------
 HashAggregate  (cost=16.52..16.70 rows=18 width=36) (actual time=0.058..0.059 rows=1 loops=1)
   Group Key: j.job_id
   Batches: 1  Memory Usage: 24kB
   ->  Nested Loop  (cost=1.30..16.20 rows=18 width=37) (actual time=0.053..0.056 rows=1 loops=1)
         ->  Nested Loop  (cost=0.88..5.46 rows=13 width=67) (actual time=0.036..0.038 rows=1 loops=1)
               ->  Nested Loop  (cost=0.45..4.48 rows=1 width=65) (actual time=0.017..0.019 rows=1 loops=1)
                     ->  HashAggregate  (cost=0.04..0.05 rows=1 width=32) (actual time=0.006..0.006 rows=1 loops=1)
                           Group Key: unnest('{d699cb50-cb2e-43fe-88ae-5440218ec487}'::text[])
                           Batches: 1  Memory Usage: 24kB
                           ->  ProjectSet  (cost=0.00..0.02 rows=1 width=32) (actual time=0.002..0.003 rows=1 loops=1)
                                 ->  Result  (cost=0.00..0.01 rows=1 width=0) (actual time=0.001..0.001 rows=1 loops=1)
                     ->  Index Only Scan using jobs_job_id_key on jobs j  (cost=0.42..4.44 rows=1 width=33) (actual time=0.010..0.011 rows=1 loops=1)
                           Index Cond: (job_id = (unnest('{d699cb50-cb2e-43fe-88ae-5440218ec487}'::text[])))
                           Heap Fetches: 0
               ->  Index Scan using ix_tasks_job_id on tasks t  (cost=0.42..0.85 rows=13 width=71) (actual time=0.018..0.018 rows=1 loops=1)
                     Index Cond: (job_id = j.job_id)
         ->  Index Scan using ix_allocations_task_id on allocations a  (cost=0.42..0.73 rows=10 width=46) (actual time=0.016..0.017 rows=1 loops=1)
               Index Cond: (task_id = t.task_id)
 Planning Time: 0.970 ms
 Execution Time: 0.108 ms
(20 rows)

@@ -0,0 +1,3 @@
CREATE INDEX ix_allocations_task_id ON allocations USING btree (task_id);
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nit (non-blocking): btree is the default index method, so you can just do CREATE INDEX ix_allocations_task_id ON allocations (task_id)

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I guess there is a very slight argument for keeping the index type explicit?

It seems we do both in the codebase a bunch

Copy link
Contributor

@amandavialva01 amandavialva01 left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

LGTM, thanks for adding an example of the time cost decrease!

@NicholasBlaskey NicholasBlaskey force-pushed the add_some_indexes_for_enrich_query branch from 22836cf to a08e75d Compare February 2, 2024 13:32
@NicholasBlaskey NicholasBlaskey enabled auto-merge (squash) February 2, 2024 13:35
@NicholasBlaskey NicholasBlaskey merged commit 71db4e1 into main Feb 2, 2024
70 of 85 checks passed
@NicholasBlaskey NicholasBlaskey deleted the add_some_indexes_for_enrich_query branch February 2, 2024 13:47
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants