sqldb: implement iterator support for NodeUpdatesInHorizon

In this commit, we update the SQL store implementation to support the
new iterator-based API for NodeUpdatesInHorizon. This includes adding a
new SQL query that supports efficient pagination through result sets.

The SQL implementation uses cursor-based pagination with configurable
batch sizes, allowing efficient iteration over large result sets without
loading everything into memory. The query is optimized to use indexes
effectively and minimize database round trips.

New SQL query GetNodesByLastUpdateRange is updated to support:
  * Cursor-based pagination using (last_update, pub_key) compound cursor
  * Optional filtering for public nodes only
  * Configurable batch sizes via MaxResults parameter
This commit is contained in:
Olaoluwa Osuntokun
2025-08-04 17:36:45 -07:00
parent 069888b51a
commit c69971c20b
3 changed files with 159 additions and 39 deletions

View File

@@ -1969,16 +1969,55 @@ const getNodesByLastUpdateRange = `-- name: GetNodesByLastUpdateRange :many
SELECT id, version, pub_key, alias, last_update, color, signature
FROM graph_nodes
WHERE last_update >= $1
AND last_update < $2
AND last_update <= $2
-- Pagination: We use (last_update, pub_key) as a compound cursor.
-- This ensures stable ordering and allows us to resume from where we left off.
-- We use COALESCE with -1 as sentinel since timestamps are always positive.
AND (
-- Include rows with last_update greater than cursor (or all rows if cursor is -1)
last_update > COALESCE($3, -1)
OR
-- For rows with same last_update, use pub_key as tiebreaker
(last_update = COALESCE($3, -1)
AND pub_key > $4)
)
-- Optional filter for public nodes only
AND (
-- If only_public is false or not provided, include all nodes
COALESCE($5, FALSE) IS FALSE
OR
-- For V1 protocol, a node is public if it has at least one public channel.
-- A public channel has bitcoin_1_signature set (channel announcement received).
EXISTS (
SELECT 1
FROM graph_channels c
WHERE c.version = 1
AND c.bitcoin_1_signature IS NOT NULL
AND (c.node_id_1 = graph_nodes.id OR c.node_id_2 = graph_nodes.id)
)
)
ORDER BY last_update ASC, pub_key ASC
LIMIT COALESCE($6, 999999999)
`
type GetNodesByLastUpdateRangeParams struct {
StartTime sql.NullInt64
EndTime sql.NullInt64
StartTime sql.NullInt64
EndTime sql.NullInt64
LastUpdate sql.NullInt64
LastPubKey []byte
OnlyPublic interface{}
MaxResults interface{}
}
func (q *Queries) GetNodesByLastUpdateRange(ctx context.Context, arg GetNodesByLastUpdateRangeParams) ([]GraphNode, error) {
rows, err := q.db.QueryContext(ctx, getNodesByLastUpdateRange, arg.StartTime, arg.EndTime)
rows, err := q.db.QueryContext(ctx, getNodesByLastUpdateRange,
arg.StartTime,
arg.EndTime,
arg.LastUpdate,
arg.LastPubKey,
arg.OnlyPublic,
arg.MaxResults,
)
if err != nil {
return nil, err
}

View File

@@ -164,7 +164,35 @@ ORDER BY node_id, type, position;
SELECT *
FROM graph_nodes
WHERE last_update >= @start_time
AND last_update < @end_time;
AND last_update <= @end_time
-- Pagination: We use (last_update, pub_key) as a compound cursor.
-- This ensures stable ordering and allows us to resume from where we left off.
-- We use COALESCE with -1 as sentinel since timestamps are always positive.
AND (
-- Include rows with last_update greater than cursor (or all rows if cursor is -1)
last_update > COALESCE(sqlc.narg('last_update'), -1)
OR
-- For rows with same last_update, use pub_key as tiebreaker
(last_update = COALESCE(sqlc.narg('last_update'), -1)
AND pub_key > sqlc.narg('last_pub_key'))
)
-- Optional filter for public nodes only
AND (
-- If only_public is false or not provided, include all nodes
COALESCE(sqlc.narg('only_public'), FALSE) IS FALSE
OR
-- For V1 protocol, a node is public if it has at least one public channel.
-- A public channel has bitcoin_1_signature set (channel announcement received).
EXISTS (
SELECT 1
FROM graph_channels c
WHERE c.version = 1
AND c.bitcoin_1_signature IS NOT NULL
AND (c.node_id_1 = graph_nodes.id OR c.node_id_2 = graph_nodes.id)
)
)
ORDER BY last_update ASC, pub_key ASC
LIMIT COALESCE(sqlc.narg('max_results'), 999999999);
-- name: DeleteNodeAddresses :exec
DELETE FROM graph_node_addresses