mirror of
https://github.com/aljazceru/lightning.git
synced 2026-01-08 16:44:22 +01:00
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.
This commit is contained in:
committed by
Christian Decker
parent
5a5cf8c696
commit
3433ff5e15
10
wallet/db.c
10
wallet/db.c
@@ -2,8 +2,10 @@
|
||||
|
||||
#include <bitcoin/script.h>
|
||||
#include <ccan/array_size/array_size.h>
|
||||
#include <ccan/build_assert/build_assert.h>
|
||||
#include <ccan/mem/mem.h>
|
||||
#include <ccan/tal/str/str.h>
|
||||
#include <common/htlc_state.h>
|
||||
#include <common/key_derive.h>
|
||||
#include <common/onionreply.h>
|
||||
#include <common/version.h>
|
||||
@@ -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. */
|
||||
|
||||
@@ -2707,10 +2707,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)) {
|
||||
@@ -2753,10 +2759,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)) {
|
||||
|
||||
Reference in New Issue
Block a user