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

services/horizon/internal/db2/history: Improve effects for liquidity pool query #4065

Merged

Conversation

tamirms
Copy link
Contributor

@tamirms tamirms commented Nov 11, 2021

PR Checklist

PR Structure

  • This PR has reasonably narrow scope (if not, break it down into smaller PRs).
  • This PR avoids mixing refactoring changes with feature changes (split into two PRs
    otherwise).
  • This PR's title starts with name of package that is most changed in the PR, ex.
    services/friendbot, or all or doc if the changes are broad or impact many
    packages.

Thoroughness

  • This PR adds tests for the most critical parts of the new functionality or fixes.
  • I've updated any docs (developer docs, .md
    files, etc... affected by this change). Take a look in the docs folder for a given service,
    like this one.

Release planning

  • I've updated the relevant CHANGELOG (here for Horizon) if
    needed with deprecations, added features, breaking changes, and DB schema changes.
  • I've decided if this PR requires a new major/minor version according to
    semver, or if it's mainly a patch change. The PR is targeted at the next
    release branch if it's not a patch change.

What

Currently, requests to /liquidity_pools/{liquidity_pool_id}/effects are timing out. Because the query to fetch effects for a given liquidity pool is running too slowly.

This is the query and its explain analyze output:

EXPLAIN ANALYZE
    SELECT heff.*, hacc.address
    FROM history_effects heff
        LEFT JOIN history_accounts hacc ON hacc.id = heff.history_account_id
        INNER JOIN history_operation_liquidity_pools holp ON holp.history_operation_id = heff.history_operation_id
        INNER JOIN history_liquidity_pools hlp ON hlp.id = holp.history_liquidity_pool_id
    WHERE hlp.liquidity_pool_id = '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a'
    AND (
        heff.history_operation_id <= 164234051842568193
        AND (
            heff.history_operation_id < 164234051842568193 OR
            (heff.history_operation_id = 164234051842568193 AND heff.order < 100)
        )
    )
    ORDER BY heff.history_operation_id desc, heff.order desc LIMIT 200;


                                                                                                                        QUERY PLAN                                                                                                                        
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=6664.46..7235.72 rows=200 width=400) (actual time=1898.922..10541.273 rows=31 loops=1)
   ->  Nested Loop Left Join  (cost=6664.46..4729460.20 rows=1653457 width=400) (actual time=1898.922..10541.266 rows=31 loops=1)
         ->  Merge Join  (cost=6664.02..3708989.82 rows=1653457 width=343) (actual time=1898.903..10541.120 rows=31 loops=1)
               Merge Cond: (heff.history_operation_id = holp.history_operation_id)
               ->  Index Scan Backward using hist_e_by_order on history_effects heff  (cost=0.70..216913827.42 rows=1295626157 width=343) (actual time=0.008..8737.246 rows=23646018 loops=1)
                     Index Cond: (history_operation_id <= '164234051842568193'::bigint)
                     Filter: ((history_operation_id < '164234051842568193'::bigint) OR ((history_operation_id = '164234051842568193'::bigint) AND ("order" < 100)))
               ->  Materialize  (cost=0.71..48350.74 rows=961 width=8) (actual time=187.702..497.966 rows=30 loops=1)
                     ->  Nested Loop  (cost=0.71..48348.34 rows=961 width=8) (actual time=187.700..497.951 rows=14 loops=1)
                           Join Filter: (holp.history_liquidity_pool_id = hlp.id)
                           Rows Removed by Join Filter: 1257401
                           ->  Index Scan Backward using index_history_operation_liquidity_pools_on_operation_id on history_operation_liquidity_pools holp  (cost=0.43..29522.23 rows=1254921 width=16) (actual time=0.010..189.357 rows=1257415 loops=1)
                           ->  Materialize  (cost=0.28..2.30 rows=1 width=8) (actual time=0.000..0.000 rows=1 loops=1257415)
                                 ->  Index Scan using index_history_liquidity_pools_on_liquidity_pool_id on history_liquidity_pools hlp  (cost=0.28..2.29 rows=1 width=8) (actual time=0.018..0.018 rows=1 loops=1)
                                       Index Cond: (liquidity_pool_id = '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a'::text)
         ->  Index Scan using index_history_accounts_on_id on history_accounts hacc  (cost=0.43..0.62 rows=1 width=65) (actual time=0.004..0.004 rows=1 loops=31)
               Index Cond: (id = heff.history_account_id)
 Planning time: 0.774 ms
 Execution time: 10541.309 ms
(19 rows)

The history_effects table does not have a foreign key which links to the liquidity pools table. However, the history_effects table does have an indexed column on operation id and we have a history_operation_liquidity_pools table which tracks operations occurring on liquidity pools:

CREATE TABLE history_operation_liquidity_pools (
    history_operation_id bigint NOT NULL,
    history_liquidity_pool_id bigint NOT NULL
)

CREATE TABLE history_liquidity_pools (
    id bigint NOT NULL DEFAULT nextval('history_liquidity_pools_id_seq'::regclass),
    liquidity_pool_id text NOT NULL
);

Note that history_operation_liquidity_pools does not store the liquidity pool id as a string. Instead, there is a layer of indirection where we map liquidity pool id strings to integer ids in history_liquidity_pools.

Given all these tables we are able to construct the query to select effects for a given liquidity pool by joining history_effects with history_operation_liquidity_pools so that we can find all operation ids which involve our liquidity pool and then query for all effects occurring on those operation ids. We also need to join on history_liquidity_pools so we can determine the integer liquidity pool id from the given liquidity pool string.

The remaining part of the query is for handling paging logic (we page on heff.history_operation_id and heff.order).

I think the reason why the query is running slowly is because of the number of joins.

To speed up /liquidity_pools/{liquidity_pool_id}/effects I broke down the original select query into two separate queries which we execute in horizon.

In the first query, we find all operation ids impacted by a given liquidity pool id string:

EXPLAIN ANALYZE
    SELECT holp.history_operation_id
    FROM history_operation_liquidity_pools holp
    WHERE holp.history_liquidity_pool_id = (SELECT id  FROM history_liquidity_pools WHERE liquidity_pool_id =  '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a')
    ORDER BY holp.history_operation_id desc LIMIT 200;
                                                                                                     QUERY PLAN                                                                                                     
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=2.72..2435.95 rows=200 width=8) (actual time=9.884..24.228 rows=14 loops=1)
   InitPlan 1 (returns $0)
     ->  Index Scan using index_history_liquidity_pools_on_liquidity_pool_id on history_liquidity_pools  (cost=0.28..2.29 rows=1 width=8) (actual time=0.015..0.016 rows=1 loops=1)
           Index Cond: (liquidity_pool_id = '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a'::text)
   ->  Index Only Scan Backward using index_history_operation_liquidity_pools_on_ids on history_operation_liquidity_pools holp  (cost=0.43..15852.90 rows=1303 width=8) (actual time=9.884..24.225 rows=14 loops=1)
         Index Cond: (history_liquidity_pool_id = $0)
         Heap Fetches: 14
 Planning time: 0.079 ms
 Execution time: 24.252 ms
(9 rows)

This query runs very quickly.

Next, we select all rows from the history_effects table which have a history_operation_id contained in the result of the previous query:

EXPLAIN ANALYZE
    SELECT heff.*, hacc.address
    FROM history_effects heff
        LEFT JOIN history_accounts hacc ON hacc.id = heff.history_account_id
    WHERE heff.history_operation_id IN (164104399664291842,164104395369385985,164041972314189825,164030221283438594,164030221283438593,164030040894693377,164029950700220418,163955527507095553,163955510327619585,163947697782059010,163947697782059009,163713433085222913,163710894761938946,163710894761938945)
    AND (
        heff.history_operation_id <= 164234051842568193
        AND (
            heff.history_operation_id < 164234051842568193 OR
            (heff.history_operation_id = 164234051842568193 AND heff.order < 100)
        )
    )
    ORDER BY heff.history_operation_id desc, heff.order desc LIMIT 200;

                                                                                                                                                                                                  QUERY PLAN                                                                                                                                                                                                   
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=1.14..533.20 rows=200 width=400) (actual time=0.041..0.196 rows=31 loops=1)
   ->  Nested Loop Left Join  (cost=1.14..63608.62 rows=23910 width=400) (actual time=0.041..0.193 rows=31 loops=1)
         ->  Index Scan Backward using hist_e_by_order on history_effects heff  (cost=0.70..12308.34 rows=23910 width=343) (actual time=0.016..0.094 rows=31 loops=1)
               Index Cond: ((history_operation_id = ANY ('{164104399664291842,164104395369385985,164041972314189825,164030221283438594,164030221283438593,164030040894693377,164029950700220418,163955527507095553,163955510327619585,163947697782059010,163947697782059009,163713433085222913,163710894761938946,163710894761938945}'::bigint[])) AND (history_operation_id <= '164234051842568193'::bigint))
         ->  Index Scan using index_history_accounts_on_id on history_accounts hacc  (cost=0.43..2.15 rows=1 width=65) (actual time=0.003..0.003 rows=1 loops=31)
               Index Cond: (id = heff.history_account_id)
 Planning time: 0.521 ms
 Execution time: 0.219 ms
(8 rows)

This query also runs very quickly. It appears that removing the joins on history_operation_liquidity_pools and history_liquidity_pools is what improved the query.

I also tried modifying the original query to use subqueries, eg:

SELECT heff.*, hacc.address
FROM history_effects heff
    LEFT JOIN history_accounts hacc ON hacc.id = heff.history_account_id
WHERE heff.history_operation_id IN (                                                                                                                                                                                                     SELECT holp.history_operation_id FROM history_operation_liquidity_pools holp                                                                                                                                                             WHERE holp.history_liquidity_pool_id = 771
    SELECT holp.history_operation_id
    FROM history_operation_liquidity_pools holp
    WHERE holp.history_liquidity_pool_id = (SELECT id  FROM history_liquidity_pools WHERE liquidity_pool_id =  '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a')
    ORDER BY holp.history_operation_id desc LIMIT 200
)
ORDER BY heff.history_operation_id desc, heff.order desc LIMIT 200;

However, those queries performed just as badly as the original query which used joins.

@tamirms tamirms changed the base branch from master to release-horizon-v2.11.0 November 12, 2021 07:14
@tamirms tamirms marked this pull request as ready for review November 12, 2021 08:02
@tamirms tamirms requested a review from a team November 12, 2021 08:02
Copy link
Contributor

@bartekn bartekn left a comment

Choose a reason for hiding this comment

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

LGTM but I wonder if the problem is connected to the index itself. We have:

    "index_history_operation_liquidity_pools_on_ids" UNIQUE, btree (history_operation_id, history_liquidity_pool_id)

But we usually query this table like history_liquidity_pool_id = X AND history_operation_id >= Y. So the fields in the index should be reversed with history_liquidity_pool_id being the first field.

@2opremio
Copy link
Contributor

Nice finding!!

I think we have a similar query for claimable balances (and maybe also accounts?).

I think we should update those too

@tamirms
Copy link
Contributor Author

tamirms commented Nov 12, 2021

@bartekn I added the reversed index you suggested in staging:

CREATE UNIQUE INDEX reverse_index_history_operation_liquidity_pools_on_ids ON history_operation_liquidity_pools USING btree (history_liquidity_pool_id, history_operation_id);

but it did not improve the query

                                                                                                                QUERY PLAN                                                                                                                
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Limit  (cost=2154.10..3339.32 rows=200 width=400) (actual time=1579.397..7140.251 rows=31 loops=1)
   ->  Nested Loop Left Join  (cost=2154.10..9877228.73 rows=1666370 width=400) (actual time=1579.396..7140.243 rows=31 loops=1)
         ->  Merge Join  (cost=2153.66..7316171.67 rows=1666370 width=343) (actual time=1579.383..7140.115 rows=31 loops=1)
               Merge Cond: (heff.history_operation_id = holp.history_operation_id)
               ->  Index Scan Backward using hist_e_by_order on history_effects heff  (cost=0.70..438221929.96 rows=1295235625 width=343) (actual time=0.007..5936.076 rows=23646018 loops=1)
                     Index Cond: (history_operation_id <= '164234051842568193'::bigint)
                     Filter: ((history_operation_id < '164234051842568193'::bigint) OR ((history_operation_id = '164234051842568193'::bigint) AND ("order" < 100)))
               ->  Sort  (cost=1292.34..1294.76 rows=969 width=8) (actual time=0.033..0.040 rows=30 loops=1)
                     Sort Key: holp.history_operation_id DESC
                     Sort Method: quicksort  Memory: 25kB
                     ->  Nested Loop  (cost=0.71..1244.28 rows=969 width=8) (actual time=0.016..0.028 rows=14 loops=1)
                           ->  Index Scan using index_history_liquidity_pools_on_liquidity_pool_id on history_liquidity_pools hlp  (cost=0.28..2.29 rows=1 width=8) (actual time=0.008..0.008 rows=1 loops=1)
                                 Index Cond: (liquidity_pool_id = '11599a4543d6dbc8a86cc32f20c8ec09570e479c89ffc85e09aedf20dcf1bb8a'::text)
                           ->  Index Only Scan using reverse_index_history_operation_liquidity_pools_on_ids on history_operation_liquidity_pools holp  (cost=0.43..1228.62 rows=1336 width=16) (actual time=0.007..0.017 rows=14 loops=1)
                                 Index Cond: (history_liquidity_pool_id = hlp.id)
                                 Heap Fetches: 14
         ->  Index Scan using index_history_accounts_on_id on history_accounts hacc  (cost=0.43..1.54 rows=1 width=65) (actual time=0.003..0.003 rows=1 loops=31)
               Index Cond: (id = heff.history_account_id)
 Planning time: 0.841 ms
 Execution time: 7140.293 ms
(20 rows)

EDIT: actually it did improve the query compared to the original but the improvement is not as significant as the rewritten query in this PR

@tamirms
Copy link
Contributor Author

tamirms commented Nov 12, 2021

I think we have a similar query for claimable balances (and maybe also accounts?).

I think we should update those too

We do not have an endpoint for querying claimable balance effects. But, if we were to add one we definitely need to mimic the pattern in this PR.

As for account effects, we do join on the accounts table. I'd need to do more testing to see if the query would be more performant without the join.

@bartekn
Copy link
Contributor

bartekn commented Nov 12, 2021

EDIT: actually it did improve the query compared to the original but the improvement is not as significant as the rewritten query in this PR

I wonder if we can drop old and create new reversed index now that LP effects table is still small. Up to you!

@tamirms
Copy link
Contributor Author

tamirms commented Nov 12, 2021

I wonder if we can drop old and create new reversed index now that LP effects table is still small. Up to you!

I think we can do it in the next release

@tamirms tamirms merged commit c7b9e2f into stellar:release-horizon-v2.11.0 Nov 12, 2021
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.

3 participants