postgres: add index for task_run_file_input(input_file_id) #608
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Deleting untracked file_inputs from the database takes a very long time.
The table has a multicolumn b-tree index for both it's columns.
The input_file_id file is the second part of the index which still
requires the full index to be scanned1:
Constraints on columns to the right of these columns are checked in
the index, so they save visits to the table proper, but they do not
reduce the portion of the index that has to be scanned.
Create an index for the input_file_id column.
Comparison of the query:
EXPLAIN SELECT id FROM input_file WHERE NOT EXISTS (SELECT 1 FROM task_run_file_input AS trfi WHERE input_file.id = trfi.input_file_id);
Without index:
Gather (cost=2102870.71..2331530.97 rows=51672 width=4)
Workers Planned: 2
-> Parallel Hash Anti Join (cost=2101870.71..2325363.77 rows=21530 width=4)
Hash Cond: (input_file.id = trfi.input_file_id)
-> Parallel Index Only Scan using input_file_pkey on input_file (cost=0.42..1127.35 rows=28633 width=4)
-> Parallel Hash (cost=1170539.13..1170539.13 rows=56766813 width=4)
-> Parallel Seq Scan on task_run_file_input trfi (cost=0.00..1170539.13 rows=56766813 width=4)
With index:
Gather (cost=1000.99..24457.81 rows=51672 width=4) (actual time=194.390..206.568 rows=0 loops=1)
Workers Planned: 2
Workers Launched: 2
-> Nested Loop Anti Join (cost=0.99..18290.61 rows=21530 width=4) (actual time=153.282..153.283 rows=0 loops=3)
-> Parallel Index Only Scan using input_file_pkey on input_file (cost=0.42..1127.35 rows=28633 width=4) (actual time=0.035..13.810 rows=22907 loops=3)
Heap Fetches: 19485
-> Index Only Scan using task_run_file_input_input_file_id_idx on task_run_file_input trfi (cost=0.57..157.21 rows=7992 width=4) (actual time=0.006..0.006 rows=1 loops=68720)
Index Cond: (input_file_id = input_file.id)
Heap Fetches: 1352
Footnotes
https://www.postgresql.org/docs/current/indexes-multicolumn.html ↩