Improve performance of device deletion by adding missing index. (#18582)
<ol>
<li>
Reorder columns in `event_txn_id_device_id_txn_id` index \
This now satisfies the foreign key on `(user_id, device_id)` making
reverse lookups, as needed for device deletions, more efficient.
This improves device deletion performance by on the order of 8 to 10×
on matrix.org.
</li>
</ol>
Rationale:
## On the `event_txn_id_device_id` table:
We currently have this index:
```sql
-- This ensures that there is only one mapping per (room_id, user_id, device_id, txn_id) tuple.
CREATE UNIQUE INDEX IF NOT EXISTS event_txn_id_device_id_txn_id
ON event_txn_id_device_id(room_id, user_id, device_id, txn_id);
```
The main way we use this table is
```python
return await self.db_pool.simple_select_one_onecol(
table="event_txn_id_device_id",
keyvalues={
"room_id": room_id,
"user_id": user_id,
"device_id": device_id,
"txn_id": txn_id,
},
retcol="event_id",
allow_none=True,
desc="get_event_id_from_transaction_id_and_device_id",
)
```
But this foreign key is relatively unsupported, making deletions in
the devices table inefficient (full index scan on the above index):
```sql
FOREIGN KEY (user_id, device_id)
REFERENCES devices (user_id, device_id) ON DELETE CASCADE
```
I propose re-ordering the columns in that index to: `(user_id,
device_id, room_id, txn_id)` (by replacing it).
That way the foreign key back-check can rely on the prefix of this
index, but it's still useful for the original purpose it was made for.
It doesn't take any extra disk space and does not harm write performance
(because the same amount of writing work needs to be performed).
---------
Signed-off-by: Olivier 'reivilibre <oliverw@matrix.org>
This commit is contained in:
1
changelog.d/18582.bugfix
Normal file
1
changelog.d/18582.bugfix
Normal file
@@ -0,0 +1 @@
|
||||
Improve performance of device deletion by adding missing index.
|
||||
@@ -349,6 +349,19 @@ class EventsWorkerStore(SQLBaseStore):
|
||||
where_clause="type = 'm.room.member'",
|
||||
)
|
||||
|
||||
# Added to support efficient reverse lookups on the foreign key
|
||||
# (user_id, device_id) when deleting devices.
|
||||
# We already had a UNIQUE index on these 4 columns but out-of-order
|
||||
# so replace that one.
|
||||
self.db_pool.updates.register_background_index_update(
|
||||
update_name="event_txn_id_device_id_txn_id2",
|
||||
index_name="event_txn_id_device_id_txn_id2",
|
||||
table="event_txn_id_device_id",
|
||||
columns=("user_id", "device_id", "room_id", "txn_id"),
|
||||
unique=True,
|
||||
replaces_index="event_txn_id_device_id_txn_id",
|
||||
)
|
||||
|
||||
def get_un_partial_stated_events_token(self, instance_name: str) -> int:
|
||||
return (
|
||||
self._un_partial_stated_events_stream_id_gen.get_current_token_for_writer(
|
||||
|
||||
@@ -0,0 +1,15 @@
|
||||
--
|
||||
-- This file is licensed under the Affero General Public License (AGPL) version 3.
|
||||
--
|
||||
-- Copyright (C) 2025 New Vector, Ltd
|
||||
--
|
||||
-- This program is free software: you can redistribute it and/or modify
|
||||
-- it under the terms of the GNU Affero General Public License as
|
||||
-- published by the Free Software Foundation, either version 3 of the
|
||||
-- License, or (at your option) any later version.
|
||||
--
|
||||
-- See the GNU Affero General Public License for more details:
|
||||
-- <https://www.gnu.org/licenses/agpl-3.0.html>.
|
||||
|
||||
INSERT INTO background_updates (ordering, update_name, progress_json) VALUES
|
||||
(9207, 'event_txn_id_device_id_txn_id2', '{}');
|
||||
Reference in New Issue
Block a user