From 7c63ce43bfed4d2dd39b93236bc1ba52fa6ac8f4 Mon Sep 17 00:00:00 2001 From: ZmnSCPxj jxPCSnmZ Date: Tue, 23 Nov 2021 13:32:44 +0800 Subject: [PATCH] wallet/db.c, wallet/wallet.c: Add a partial index to speed up startup. Closes: #4901 Tested by `EXPLAIN QUERY PLAN` on sqlite3; #4901 shows the result from @whitslack doing a similar partial index on PostgreSQL on his ~1000 chan node. ChangeLog-Added: db: Speed up loading of pending HTLCs during startup by using a partial index. --- wallet/db.c | 10 ++++++++++ wallet/wallet.c | 18 +++++++++++++++--- 2 files changed, 25 insertions(+), 3 deletions(-) diff --git a/wallet/db.c b/wallet/db.c index 4e9eb042bdc6..036765c0d837 100644 --- a/wallet/db.c +++ b/wallet/db.c @@ -2,8 +2,10 @@ #include #include +#include #include #include +#include #include #include #include @@ -858,6 +860,14 @@ static struct migration dbmigrations[] = { /* Issue #4887: reset the payments.id sequence after the migration above. Since this is a SELECT statement that would otherwise fail, make it an INSERT into the `vars` table.*/ {SQL("/*PSQL*/INSERT INTO vars (name, intval) VALUES ('payment_id_reset', setval(pg_get_serial_sequence('payments', 'id'), COALESCE((SELECT MAX(id)+1 FROM payments), 1)))"), NULL}, + + /* Issue #4901: Partial index speeds up startup on nodes with ~1000 channels. */ + {&SQL("CREATE INDEX channel_htlcs_speedup_unresolved_idx" + " ON channel_htlcs(channel_id, direction)" + " WHERE hstate NOT IN (9, 19);") + [BUILD_ASSERT_OR_ZERO( 9 == RCVD_REMOVE_ACK_REVOCATION) + + BUILD_ASSERT_OR_ZERO(19 == SENT_REMOVE_ACK_REVOCATION)], + NULL}, }; /* Leak tracking. */ diff --git a/wallet/wallet.c b/wallet/wallet.c index b26ec943d823..e7ad0f7f923b 100644 --- a/wallet/wallet.c +++ b/wallet/wallet.c @@ -2734,10 +2734,16 @@ bool wallet_htlcs_load_in_for_channel(struct wallet *wallet, " FROM channel_htlcs" " WHERE direction= ?" " AND channel_id= ?" - " AND hstate != ?")); + " AND hstate NOT IN (?, ?)")); db_bind_int(stmt, 0, DIRECTION_INCOMING); db_bind_u64(stmt, 1, chan->dbid); - db_bind_int(stmt, 2, SENT_REMOVE_ACK_REVOCATION); + /* We need to generate `hstate NOT IN (9, 19)` in order to match + * the `WHERE` clause of the database index; incoming HTLCs will + * never actually get the state `RCVD_REMOVE_ACK_REVOCATION`. + * See https://sqlite.org/partialindex.html#queries_using_partial_indexes + */ + db_bind_int(stmt, 2, RCVD_REMOVE_ACK_REVOCATION); /* Not gonna happen. */ + db_bind_int(stmt, 3, SENT_REMOVE_ACK_REVOCATION); db_query_prepared(stmt); while (db_step(stmt)) { @@ -2780,10 +2786,16 @@ bool wallet_htlcs_load_out_for_channel(struct wallet *wallet, " FROM channel_htlcs" " WHERE direction = ?" " AND channel_id = ?" - " AND hstate != ?")); + " AND hstate NOT IN (?, ?)")); db_bind_int(stmt, 0, DIRECTION_OUTGOING); db_bind_u64(stmt, 1, chan->dbid); + /* We need to generate `hstate NOT IN (9, 19)` in order to match + * the `WHERE` clause of the database index; outgoing HTLCs will + * never actually get the state `SENT_REMOVE_ACK_REVOCATION`. + * See https://sqlite.org/partialindex.html#queries_using_partial_indexes + */ db_bind_int(stmt, 2, RCVD_REMOVE_ACK_REVOCATION); + db_bind_int(stmt, 3, SENT_REMOVE_ACK_REVOCATION); /* Not gonna happen. */ db_query_prepared(stmt); while (db_step(stmt)) {