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

adds postgres index to support efficient querying via Watch API #2143

Merged
merged 1 commit into from
Nov 26, 2024

Conversation

vroldanbet
Copy link
Contributor

@vroldanbet vroldanbet commented Nov 26, 2024

we identified Watch API was causing a full table scan on large postgres-backed SpiceDB, overloading the database.

This commit adds an index that reduces the execution time of relationship changes to be emitted via Watch API by more than three orders of magnitude on tables with several gigabytes worth of data.

before

EXPLAIN ANALYZE SELECT namespace, object_id, relation, userset_namespace, userset_object_id, userset_relation, caveat_name, caveat_context, created_xid, deleted_xid FROM relation_tuple WHERE ((created_xid <= '878
 66205'::xid8 AND created_xid >= '87866205'::xid8) OR (deleted_xid <= '87866205'::xid8 AND deleted_xid >= '87866205'::xid8))
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| QUERY PLAN                                                                                                                                                               |
|--------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
| Gather  (cost=1000.00..746993.87 rows=1 width=93) (actual time=3419.469..3422.016 rows=2 loops=1)                                                                        |
|   Workers Planned: 2                                                                                                                                                     |
|   Workers Launched: 2                                                                                                                                                    |
|   ->  Parallel Seq Scan on relation_tuple  (cost=0.00..745993.77 rows=1 width=93) (actual time=2616.575..3417.699 rows=1 loops=3)                                        |
|         Filter: (((created_xid <= '87866205'::xid8) AND (created_xid >= '87866205'::xid8)) OR ((deleted_xid <= '87866205'::xid8) AND (deleted_xid >= '87866205'::xid8))) |
|         Rows Removed by Filter: 11009862                                                                                                                                 |
| Planning Time: 0.121 ms                                                                                                                                                  |
| Execution Time: 3422.036 ms                                                                                                                                              |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
EXPLAIN 8
Time: 3.427s (3 seconds), executed in: 3.424s (3 seconds)

after

EXPLAIN ANALYZE SELECT namespace, object_id, relation, userset_namespace, userset_object_id, userset_relation, caveat_name, caveat_context, created_xid, deleted_xid FROM relation_tuple WHERE ((created_xid <= '87866205'::xid8 AND created_xid >= '87866205'::xid8) OR (deleted_xid <= '87866205'::xid8 AND deleted_xid >= '87866205'::xid8))
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| QUERY PLAN                                                                                                                                                                |
|---------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
| Gather  (cost=4338.98..564481.00 rows=165155 width=93) (actual time=5.126..5.380 rows=0 loops=1)                                                                          |
|   Workers Planned: 2                                                                                                                                                      |
|   Workers Launched: 2                                                                                                                                                     |
|   ->  Parallel Bitmap Heap Scan on relation_tuple  (cost=3338.98..546965.50 rows=68815 width=93) (actual time=0.087..0.087 rows=0 loops=3)                                |
|         Recheck Cond: (((created_xid <= '878'::xid8) AND (created_xid >= '87866205'::xid8)) OR ((deleted_xid <= '87866205'::xid8) AND (deleted_xid >= '87866205'::xid8))) |
|         ->  BitmapOr  (cost=3338.98..3338.98 rows=165155 width=0) (actual time=0.014..0.015 rows=0 loops=1)                                                               |
|               ->  Bitmap Index Scan on ix_watch_index  (cost=0.00..3227.99 rows=165155 width=0) (actual time=0.008..0.008 rows=0 loops=1)                                 |
|                     Index Cond: ((created_xid <= '878'::xid8) AND (created_xid >= '87866205'::xid8))                                                                      |
|               ->  Bitmap Index Scan on ix_gc_index  (cost=0.00..28.42 rows=1 width=0) (actual time=0.006..0.006 rows=0 loops=1)                                           |
|                     Index Cond: ((deleted_xid <= '87866205'::xid8) AND (deleted_xid >= '87866205'::xid8))                                                                 |
| Planning Time: 0.195 ms                                                                                                                                                   |
| Execution Time: 5.408 ms    

we identified Watch API was causing a full table scan on
large postgres-backed SpiceDB, overloading the database.

This commit adds an index that reduces the execution time
of relationship changes to be emitted via Watch API by
more than three orders of magnitude on tables with several
gigabytes worth of data.
@github-actions github-actions bot added the area/datastore Affects the storage system label Nov 26, 2024
@vroldanbet vroldanbet self-assigned this Nov 26, 2024
@vroldanbet vroldanbet changed the title adds index to support efficient querying of Watch API adds postgres index to support efficient querying via Watch API Nov 26, 2024
@vroldanbet vroldanbet marked this pull request as ready for review November 26, 2024 12:37
@vroldanbet vroldanbet requested a review from a team as a code owner November 26, 2024 12:37
@vroldanbet vroldanbet enabled auto-merge November 26, 2024 13:54
"github.com/jackc/pgx/v5"
)

const addWatchAPIIndexToRelationTupleTable = `CREATE INDEX CONCURRENTLY IF NOT EXISTS ix_watch_index ON relation_tuple (created_xid);`
Copy link

Choose a reason for hiding this comment

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

just a thought for later: since the query also filters on deleted_xid, we might want to try a composite index on (created_xid, deleted_xid) down the line.

CREATE INDEX CONCURRENTLY IF NOT EXISTS ix_watch_index ON relation_tuple (created_xid, deleted_xid);

It could make queries with both columns even faster by improving how rows are filtered. Definitely not a blocker tho.

Copy link
Contributor Author

Choose a reason for hiding this comment

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

I tried the composite index and it didn't give any extra value, because we already have an index for deleted_xid that was selected. So it didn't improve the situation, neither made it worse, it was equally performing.

@vroldanbet vroldanbet added this pull request to the merge queue Nov 26, 2024
Merged via the queue into main with commit 96b3ec5 Nov 26, 2024
22 checks passed
@vroldanbet vroldanbet deleted the add-pg-watch-api-index branch November 26, 2024 14:28
@github-actions github-actions bot locked and limited conversation to collaborators Nov 26, 2024
Sign up for free to subscribe to this conversation on GitHub. Already have an account? Sign in.
Labels
area/datastore Affects the storage system
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants