Skip to content

Create composite index orders(owner, class, true_valid_to)#4133

Merged
jmg-duarte merged 3 commits intomainfrom
jmgd/index
Feb 6, 2026
Merged

Create composite index orders(owner, class, true_valid_to)#4133
jmg-duarte merged 3 commits intomainfrom
jmgd/index

Conversation

@jmg-duarte
Copy link
Contributor

@jmg-duarte jmg-duarte commented Feb 6, 2026

Description

The create_order endpoint is suffering from latency issues due to the user_orders_with_quote being super slow (we've seen up to 50s), this PR adds an index and removes the MATERIALIZE keyword to provide more optimization opportunities for the query planner

Plan before

Nested Loop  (cost=29.14..122.50 rows=1 width=58) (actual time=0.036..0.038 rows=0 loops=1)
  Buffers: shared hit=4
  ->  Nested Loop Anti Join  (cost=28.58..113.92 rows=1 width=79) (actual time=0.036..0.037 rows=0 loops=1)
        Buffers: shared hit=4
        ->  Nested Loop Anti Join  (cost=28.44..97.75 rows=1 width=79) (actual time=0.036..0.037 rows=0 loops=1)
              Buffers: shared hit=4
              ->  Nested Loop Anti Join  (cost=28.17..89.44 rows=1 width=79) (actual time=0.036..0.037 rows=0 loops=1)
                    Buffers: shared hit=4
                    ->  Nested Loop Anti Join  (cost=27.89..73.21 rows=1 width=79) (actual time=0.036..0.037 rows=0 loops=1)
                          Buffers: shared hit=4
                          ->  Bitmap Heap Scan on orders o  (cost=27.62..64.90 rows=1 width=79) (actual time=0.035..0.036 rows=0 loops=1)
                                Recheck Cond: ((true_valid_to >= '4294967295'::bigint) AND (owner = '\xfd659bc79a2b542728e3f372870d22ed31358ed6'::bytea))
                                Filter: ((cancellation_timestamp IS NULL) AND (class = 'limit'::orderclass) AND (((kind = 'sell'::orderkind) AND (COALESCE((SubPlan 1), '0'::numeric) < sell_amount)) OR ((kind = 'buy'::orderkind) AND (COALESCE((SubPlan 2), '0'::numeric) < buy_amount))))
                                Buffers: shared hit=4
                                ->  BitmapAnd  (cost=27.62..27.62 rows=1 width=0) (actual time=0.033..0.034 rows=0 loops=1)
                                      Buffers: shared hit=4
                                      ->  Bitmap Index Scan on orders_true_valid_to  (cost=0.00..4.51 rows=10 width=0) (actual time=0.023..0.023 rows=312 loops=1)
                                            Index Cond: (true_valid_to >= '4294967295'::bigint)
                                            Buffers: shared hit=3
                                      ->  Bitmap Index Scan on order_owner  (cost=0.00..22.86 rows=381 width=0) (actual time=0.003..0.003 rows=0 loops=1)
                                            Index Cond: (owner = '\xfd659bc79a2b542728e3f372870d22ed31358ed6'::bytea)
                                            Buffers: shared hit=1
                                SubPlan 1
                                  ->  Aggregate  (cost=16.62..16.63 rows=1 width=32) (never executed)
                                        ->  Index Scan using trade_order_uid on trades  (cost=0.56..16.61 rows=3 width=11) (never executed)
                                              Index Cond: (order_uid = o.uid)
                                SubPlan 2
                                  ->  Aggregate  (cost=16.62..16.63 rows=1 width=32) (never executed)
                                        ->  Index Scan using trade_order_uid on trades trades_1  (cost=0.56..16.61 rows=3 width=11) (never executed)
                                              Index Cond: (order_uid = o.uid)
                          ->  Index Only Scan using ethflow_refunds_pkey on ethflow_refunds r  (cost=0.27..4.29 rows=1 width=57) (never executed)
                                Index Cond: (order_uid = o.uid)
                                Heap Fetches: 0
                    ->  Index Only Scan using invalidations_order_uid on invalidations i  (cost=0.28..8.29 rows=1 width=57) (never executed)
                          Index Cond: (order_uid = o.uid)
                          Heap Fetches: 0
              ->  Index Only Scan using onchain_order_invalidations_pkey on onchain_order_invalidations oi  (cost=0.27..4.29 rows=1 width=57) (never executed)
                    Index Cond: (uid = o.uid)
                    Heap Fetches: 0
        ->  Index Only Scan using okay_onchain_orders on onchain_placed_orders op  (cost=0.14..8.16 rows=1 width=57) (never executed)
              Index Cond: (uid = o.uid)
              Heap Fetches: 0
  ->  Index Scan using order_quotes_pkey on order_quotes o_quotes  (cost=0.56..8.57 rows=1 width=93) (never executed)
        Index Cond: (order_uid = o.uid)
Planning:
  Buffers: shared hit=95
Planning Time: 0.816 ms
Execution Time: 0.101 ms

Plan after

Hash Anti Join  (cost=2977.50..115918.76 rows=1386 width=67) (actual time=0.012..0.014 rows=0 loops=1)
  Hash Cond: (o.uid = op.uid)
  Buffers: shared hit=4
  ->  Hash Anti Join  (cost=2918.73..115842.49 rows=1386 width=124) (actual time=0.012..0.013 rows=0 loops=1)
        Hash Cond: (o.uid = i.order_uid)
        Buffers: shared hit=4
        ->  Nested Loop  (cost=2798.94..115705.20 rows=1386 width=124) (actual time=0.012..0.013 rows=0 loops=1)
              Buffers: shared hit=4
              ->  Hash Anti Join  (cost=2798.38..103609.69 rows=1412 width=81) (actual time=0.012..0.013 rows=0 loops=1)
                    Hash Cond: (o.uid = oi.uid)
                    Buffers: shared hit=4
                    ->  Hash Anti Join  (cost=2186.48..102979.96 rows=1414 width=81) (actual time=0.012..0.012 rows=0 loops=1)
                          Hash Cond: (o.uid = r.order_uid)
                          Buffers: shared hit=4
                          ->  Index Scan using idx_orders_owner_class_valid on orders o  (cost=0.56..100776.17 rows=1419 width=81) (actual time=0.011..0.012 rows=0 loops=1)
                                Index Cond: ((owner = '\xfd659bc79a2b542728e3f372870d22ed31358ed6'::bytea) AND (class = 'limit'::orderclass) AND (true_valid_to >= '4294967295'::bigint))
                                Filter: ((cancellation_timestamp IS NULL) AND (((kind = 'sell'::orderkind) AND (COALESCE((SubPlan 1), '0'::numeric) < sell_amount)) OR ((kind = 'buy'::orderkind) AND (COALESCE((SubPlan 2), '0'::numeric) < buy_amount))))
                                Buffers: shared hit=4
                                SubPlan 1
                                  ->  Aggregate  (cost=8.60..8.61 rows=1 width=32) (never executed)
                                        ->  Index Only Scan using idx_trades_covering on trades  (cost=0.56..8.59 rows=2 width=9) (never executed)
                                              Index Cond: (order_uid = o.uid)
                                              Heap Fetches: 0
                                SubPlan 2
                                  ->  Aggregate  (cost=8.60..8.61 rows=1 width=32) (never executed)
                                        ->  Index Only Scan using idx_trades_covering on trades trades_1  (cost=0.56..8.59 rows=2 width=11) (never executed)
                                              Index Cond: (order_uid = o.uid)
                                              Heap Fetches: 0
                          ->  Hash  (cost=1515.41..1515.41 rows=53641 width=57) (never executed)
                                ->  Seq Scan on ethflow_refunds r  (cost=0.00..1515.41 rows=53641 width=57) (never executed)
                    ->  Hash  (cost=398.62..398.62 rows=17062 width=57) (never executed)
                          ->  Seq Scan on onchain_order_invalidations oi  (cost=0.00..398.62 rows=17062 width=57) (never executed)
              ->  Index Scan using order_quotes_pkey on order_quotes o_quotes  (cost=0.56..8.57 rows=1 width=100) (never executed)
                    Index Cond: (order_uid = o.uid)
        ->  Hash  (cost=78.24..78.24 rows=3324 width=57) (never executed)
              ->  Seq Scan on invalidations i  (cost=0.00..78.24 rows=3324 width=57) (never executed)
  ->  Hash  (cost=53.80..53.80 rows=398 width=57) (never executed)
        ->  Index Only Scan using okay_onchain_orders on onchain_placed_orders op  (cost=0.27..53.80 rows=398 width=57) (never executed)
              Heap Fetches: 0
Planning:
  Buffers: shared hit=95
Planning Time: 0.833 ms
Execution Time: 0.071 ms

Changes

  • Adding the composite index
  • Dropping the MATERIALIZE

How to test

Create index in prod, push a test image, though this should be an easy win

@jmg-duarte jmg-duarte requested a review from a team as a code owner February 6, 2026 15:07
@github-actions
Copy link

github-actions bot commented Feb 6, 2026

Reminder: Please update the DB Readme and comment whether migrations are reversible (include rollback scripts if applicable).

  • If creating new tables, update the tables list.
  • When adding a new index, consider using CREATE INDEX CONCURRENTLY for tables involved in the critical execution path.
  • For breaking changes, remember that during rollout k8s starts the new autopilot, runs the Flyway migration, and only then shuts down the old pod. That overlap means the previous version can still be processing requests on the migrated schema, so make it compatible first and ship the breaking DB change in the following release.

Caused by:

Copy link
Contributor

@gemini-code-assist gemini-code-assist bot left a comment

Choose a reason for hiding this comment

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

Code Review

The removal of MATERIALIZED and addition of a composite index are sound changes for improving query performance. However, the index can be made more efficient by converting it to a partial index, as detailed in the comment.

@jmg-duarte jmg-duarte added the hotfix Labels PRs that should be applied into production right away label Feb 6, 2026
Copy link
Contributor

@MartinquaXD MartinquaXD left a comment

Choose a reason for hiding this comment

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

Please also update the db readme with the new index there

@jmg-duarte jmg-duarte enabled auto-merge February 6, 2026 15:56
@jmg-duarte jmg-duarte added this pull request to the merge queue Feb 6, 2026
Merged via the queue into main with commit 0512c46 Feb 6, 2026
19 checks passed
@jmg-duarte jmg-duarte deleted the jmgd/index branch February 6, 2026 16:18
@github-actions github-actions bot locked and limited conversation to collaborators Feb 6, 2026
Sign up for free to subscribe to this conversation on GitHub. Already have an account? Sign in.

Labels

hotfix Labels PRs that should be applied into production right away

Projects

None yet

Development

Successfully merging this pull request may close these issues.

2 participants