From df8a3cef6b997f9eb2be7780293a64c873f7580f Mon Sep 17 00:00:00 2001
From: =?UTF-8?q?Dagfinn=20Ilmari=20Manns=C3=A5ker?= <ilmari@ilmari.org>
Date: Mon, 1 Jun 2020 15:23:43 +0100
Subject: [PATCH] Improve performance of _get_state_groups_from_groups_txn
 (#7567)
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

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>
---
 changelog.d/7567.misc                           |  1 +
 synapse/storage/data_stores/state/bg_updates.py | 12 ++++++------
 2 files changed, 7 insertions(+), 6 deletions(-)
 create mode 100644 changelog.d/7567.misc

diff --git a/changelog.d/7567.misc b/changelog.d/7567.misc
new file mode 100644
index 0000000000..b086d5d026
--- /dev/null
+++ b/changelog.d/7567.misc
@@ -0,0 +1 @@
+Improve query performance for fetching state from a PostgreSQL database.
diff --git a/synapse/storage/data_stores/state/bg_updates.py b/synapse/storage/data_stores/state/bg_updates.py
index e8edaf9f7b..ff000bc9ec 100644
--- a/synapse/storage/data_stores/state/bg_updates.py
+++ b/synapse/storage/data_stores/state/bg_updates.py
@@ -109,20 +109,20 @@ class StateGroupBackgroundUpdateStore(SQLBaseStore):
                     SELECT prev_state_group FROM state_group_edges e, state s
                     WHERE s.state_group = e.state_group
                 )
-                SELECT DISTINCT type, state_key, last_value(event_id) OVER (
-                    PARTITION BY type, state_key ORDER BY state_group ASC
-                    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
-                ) AS event_id FROM state_groups_state
+                SELECT DISTINCT ON (type, state_key)
+                    type, state_key, event_id
+                FROM state_groups_state
                 WHERE state_group IN (
                     SELECT state_group FROM state
-                )
+                ) %s
+                ORDER BY type, state_key, state_group DESC
             """
 
             for group in groups:
                 args = [group]
                 args.extend(where_args)
 
-                txn.execute(sql + where_clause, args)
+                txn.execute(sql % (where_clause,), args)
                 for row in txn:
                     typ, state_key, event_id = row
                     key = (typ, state_key)
-- 
GitLab