Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
services/horizon: Add (asset, account_id) index to trust_lines table (#…
…4635) Adds a new index to `trust_lines` table on `(asset_type, asset_code, asset_issuer, account_id)` fields. When filtering by `asset` in `/accounts` endpoint the underlying query was using `"trust_lines_by_type_code_issuer" btree (asset_type, asset_code, asset_issuer)` index. This can be slow when querying for a popular asset which (like `USDC`) because when selected trust lines are found by a DB engine, they later need to be sorted by account id. A new index allow quick sorting of found trustlines. ### Query plan without a new index ``` Limit (cost=2760.42..2787.18 rows=10 width=249) (actual time=725.657..734.633 rows=10 loops=1) -> Nested Loop (cost=2760.42..7229.44 rows=1670 width=249) (actual time=725.656..734.631 rows=10 loops=1) -> Gather Merge (cost=2759.86..2950.19 rows=1670 width=57) (actual time=725.622..734.541 rows=10 loops=1) Workers Planned: 1 Workers Launched: 1 -> Sort (cost=1759.85..1762.30 rows=982 width=57) (actual time=719.248..719.275 rows=203 loops=2) Sort Key: trust_lines.account_id Sort Method: external merge Disk: 8104kB Worker 0: Sort Method: external merge Disk: 7472kB -> Parallel Bitmap Heap Scan on trust_lines (cost=24.86..1711.05 rows=982 width=57) (actual time=49.144..656.403 rows=118316 loops=2) Recheck Cond: ((asset_type = 1) AND ((asset_code)::text = 'USDC'::text) AND ((asset_issuer)::text = 'GA5ZSEJYB37JRC5AVCIA5MOP4RHTM335X2KGX3IHOJAPP5RE34K4KZVN'::text)) Rows Removed by Index Recheck: 1905016 Heap Blocks: exact=18001 lossy=87732 -> Bitmap Index Scan on trust_lines_by_type_code_issuer (cost=0.00..24.44 rows=1670 width=0) (actual time=45.137..45.137 rows=236633 loops=1) Index Cond: ((asset_type = 1) AND ((asset_code)::text = 'USDC'::text) AND ((asset_issuer)::text = 'GA5ZSEJYB37JRC5AVCIA5MOP4RHTM335X2KGX3IHOJAPP5RE34K4KZVN'::text)) -> Index Scan using accounts_pkey on accounts (cost=0.56..2.56 rows=1 width=192) (actual time=0.008..0.008 rows=1 loops=10) Index Cond: ((account_id)::text = (trust_lines.account_id)::text) Planning Time: 2.946 ms Execution Time: 738.166 ms (19 rows) ``` ### Query plan **with** a new index ``` Limit (cost=1.25..27.29 rows=10 width=249) (actual time=0.319..0.376 rows=10 loops=1) -> Nested Loop (cost=1.25..4351.51 rows=1670 width=249) (actual time=0.318..0.374 rows=10 loops=1) -> Index Only Scan using trust_lines_by_account_type_code_issuer on trust_lines (cost=0.69..72.26 rows=1670 width=57) (actual time=0.303..0.308 rows=10 loops=1) Index Cond: ((asset_type = 1) AND (asset_code = 'USDC'::text) AND (asset_issuer = 'GA5ZSEJYB37JRC5AVCIA5MOP4RHTM335X2KGX3IHOJAPP5RE34K4KZVN'::text)) Heap Fetches: 0 -> Index Scan using accounts_pkey on accounts (cost=0.56..2.56 rows=1 width=192) (actual time=0.006..0.006 rows=1 loops=10) Index Cond: ((account_id)::text = (trust_lines.account_id)::text) Planning Time: 2.113 ms Execution Time: 0.420 ms (9 rows) ```
- Loading branch information