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

Create Composite Index for xform_id and id fields #2519

Merged
merged 1 commit into from
Nov 24, 2023

Conversation

KipSigei
Copy link
Contributor

@KipSigei KipSigei commented Nov 24, 2023

Changes / Features implemented

  • Create compound Index for xform_id and id fields on the logger_instance table

Steps taken to verify this change does what is intended

Side effects of implementing this change

  • Adds a compound index on (xform_id, id) to enhance performance when running a query with ORDER BY and LIMIT clauses on the logger_instance table
  • Below are the comparisons in execution time before applying the index and after:
    Before
<db_name>=> EXPLAIN ANALYZE SELECT id, json FROM logger_instance WHERE deleted_at IS NULL AND xform_id IN (some_id) ORDER BY id, xform_id LIMIT 1;
                                                                             QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.56..3908.70 rows=1 width=309) (actual time=1717190.801..1717190.803 rows=1 loops=1)
   ->  Index Scan using logger_instance_pkey on logger_instance  (cost=0.56..20576312.78 rows=5265 width=309) (actual time=1717190.799..1717190.800 rows=1 loops=1)
         Filter: ((deleted_at IS NULL) AND (xform_id = <some_id>))
         Rows Removed by Filter: 30625777
 Planning Time: 0.094 ms
 Execution Time: 1717190.835 ms
(6 rows)


Time: 2142197.397 ms (35:42.197)

After

<db_name>=> EXPLAIN ANALYZE SELECT id, uuid FROM logger_instance WHERE deleted_at IS NULL AND xform_id = <some_id> AND media_all_received ORDER BY id ASC LIMIT 1;
                                                                           QUERY PLAN                                                                            
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.56..3.06 rows=1 width=40) (actual time=0.012..0.012 rows=1 loops=1)
   ->  Index Scan using logger_instance_id_xform_id_index on logger_instance  (cost=0.56..13922.40 rows=5575 width=40) (actual time=0.011..0.012 rows=1 loops=1)
         Index Cond: (xform_id = <some_id>)
         Filter: ((deleted_at IS NULL) AND media_all_received)
 Planning Time: 0.098 ms
 Execution Time: 0.023 ms
(6 rows)

Before submitting this PR for review, please make sure you have:

  • Included tests
  • Updated documentation

Closes #2516

@KipSigei KipSigei force-pushed the add-index-for-xform-and-submission-id branch from 903be88 to 38f59cd Compare November 24, 2023 07:37
@KipSigei KipSigei merged commit eebde60 into main Nov 24, 2023
9 checks passed
@KipSigei KipSigei deleted the add-index-for-xform-and-submission-id branch November 24, 2023 12:52
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.

OperationalError: canceling statement due to statement timeout
2 participants