Improve performance of _get_state_groups_from_groups_txn (#7567)

The query keeps showing up in my slow query log.

This changes the plan under the top-level Sort node from

```
    WindowAgg  (cost=280335.88..292963.15 rows=561212 width=80) (actual time=138.651..160.562 rows=27112 loops=1)
      ->  Sort  (cost=280335.88..281738.91 rows=561212 width=84) (actual time=138.597..140.622 rows=27112 loops=1)
            Sort Key: state_groups_state.type, state_groups_state.state_key, state_groups_state.state_group
            Sort Method: quicksort  Memory: 4581kB
            ->  Nested Loop  (cost=2.83..226745.22 rows=561212 width=84) (actual time=21.548..47.657 rows=27112 loops=1)
                  ->  HashAggregate  (cost=2.27..3.28 rows=101 width=8) (actual time=21.526..21.535 rows=20 loops=1)
                        Group Key: state.state_group
                        ->  CTE Scan on state  (cost=0.00..2.02 rows=101 width=8) (actual time=21.280..21.493 rows=20 loops=1)
                  ->  Index Scan using state_groups_state_type_idx on state_groups_state  (cost=0.56..2189.40 rows=5557 width=84) (actual time=0.005..0.991 rows=1356 loops=20)
                        Index Cond: (state_group = state.state_group)
```

to

```
    Nested Loop  (cost=2.83..226745.22 rows=561212 width=84) (actual time=24.194..52.834 rows=27112 loops=1)
      ->  HashAggregate  (cost=2.27..3.28 rows=101 width=8) (actual time=24.130..24.138 rows=20 loops=1)
            Group Key: state.state_group
            ->  CTE Scan on state  (cost=0.00..2.02 rows=101 width=8) (actual time=23.887..24.113 rows=20 loops=1)
      ->  Index Scan using state_groups_state_type_idx on state_groups_state  (cost=0.56..2189.40 rows=5557 width=84) (actual time=0.016..1.159 rows=1356 loops=20)
            Index Cond: (state_group = state.state_group)
```

This cuts the execution time from ~190ms to ~130ms, i.e. a reduction
of ~30%.

The full plans are visualised at https://explain.depesz.com/s/WpbT and
https://explain.depesz.com/s/KlEk

Signed-off-by: Dagfinn Ilmari Mannsåker <ilmari@ilmari.org>
This commit is contained in:
Dagfinn Ilmari Mannsåker 2020-06-01 15:23:43 +01:00 committed by GitHub
parent 6af9cdca24
commit df8a3cef6b
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
2 changed files with 7 additions and 6 deletions

1
changelog.d/7567.misc Normal file
View file

@ -0,0 +1 @@
Improve query performance for fetching state from a PostgreSQL database.

View file

@ -109,20 +109,20 @@ class StateGroupBackgroundUpdateStore(SQLBaseStore):
SELECT prev_state_group FROM state_group_edges e, state s SELECT prev_state_group FROM state_group_edges e, state s
WHERE s.state_group = e.state_group WHERE s.state_group = e.state_group
) )
SELECT DISTINCT type, state_key, last_value(event_id) OVER ( SELECT DISTINCT ON (type, state_key)
PARTITION BY type, state_key ORDER BY state_group ASC type, state_key, event_id
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING FROM state_groups_state
) AS event_id FROM state_groups_state
WHERE state_group IN ( WHERE state_group IN (
SELECT state_group FROM state SELECT state_group FROM state
) ) %s
ORDER BY type, state_key, state_group DESC
""" """
for group in groups: for group in groups:
args = [group] args = [group]
args.extend(where_args) args.extend(where_args)
txn.execute(sql + where_clause, args) txn.execute(sql % (where_clause,), args)
for row in txn: for row in txn:
typ, state_key, event_id = row typ, state_key, event_id = row
key = (typ, state_key) key = (typ, state_key)