Skip to content

Comments

invoices/sql_store: replace catch-all FilterInvoices with targeted index-friendly queries#10601

Open
ziggie1984 wants to merge 5 commits intolightningnetwork:masterfrom
ziggie1984:invoice-filter-index-optimization
Open

invoices/sql_store: replace catch-all FilterInvoices with targeted index-friendly queries#10601
ziggie1984 wants to merge 5 commits intolightningnetwork:masterfrom
ziggie1984:invoice-filter-index-optimization

Conversation

@ziggie1984
Copy link
Collaborator

Problem

FilterInvoices was a single catch-all query that handled every
list/scan path through a set of optional parameters using the pattern:

(col >= $param OR $param IS NULL)

This pattern is problematic for SQLite's query planner. When a
parameter is NULL the OR branch short-circuits to TRUE for every
row, which means the planner cannot determine at plan time which rows
satisfy the condition. As a result it falls back to a full table
scan
even though suitable indexes exist (invoices_state_idx,
invoices_settle_index_idx, and the primary-key clustered index on
id).

The conditional ORDER BY had the same effect:

ORDER BY CASE WHEN reverse = FALSE OR reverse IS NULL THEN id ELSE NULL END ASC,
         CASE WHEN reverse = TRUE THEN id ELSE NULL END DESC

A CASE expression in ORDER BY prevents the planner from using index
ordering, forcing an explicit sort pass over the full result set.

PostgreSQL's more sophisticated planner can sometimes work around these
patterns via constant-folding or partial index scans, but SQLite cannot,
so every call to ListInvoices, FetchPendingInvoices,
InvoicesSettledSince, and InvoicesAddedSince resulted in a full
table scan regardless of how many invoices were in the database.

Solution

Replace FilterInvoices with five focused queries, each with a single
sargable predicate and a direct ORDER BY:

New query Filter Index used
FetchPendingInvoices WHERE state IN (0, 3) invoices_state_idx
FilterInvoicesBySettleIndex WHERE settle_index >= $1 invoices_settle_index_idx
FilterInvoicesByAddIndex WHERE id >= $1 primary key
FilterInvoicesForward WHERE id >= $1 … ORDER BY id ASC primary key
FilterInvoicesReverse WHERE id <= $1 … ORDER BY id DESC primary key

FilterInvoicesForward and FilterInvoicesReverse replace the general
QueryInvoices path. They accept non-nullable timestamp parameters so
the planner always sees plain range predicates on created_at. When the
caller sets no date filter, Go-side sentinel defaults are used
(time.Unix(0,0) as the lower bound, year 9999 as the upper bound),
following the same convention already established by the payments query.
This avoids OR param IS NULL fallbacks entirely.

The migration is done in three self-compiling commits following an
add → migrate → remove pattern so every commit in the stack builds
independently.

@gemini-code-assist
Copy link

Summary of Changes

Hello @ziggie1984, I'm Gemini Code Assist1! I'm currently reviewing this pull request and will post my feedback shortly. In the meantime, here's a summary to help you and other reviewers quickly get up to speed!

This pull request significantly enhances the performance of invoice querying by refactoring the database interaction layer. The previous FilterInvoices method, a catch-all query, led to inefficient full table scans in SQLite due to its use of OR NULL patterns and CASE expressions in ORDER BY clauses, which hindered the query planner's ability to utilize indexes. The solution replaces this single problematic query with five distinct, highly optimized queries, each designed to leverage specific indexes and provide concrete, non-nullable parameters. This change ensures that invoice retrieval operations are now performed using efficient index scans, drastically improving database performance and scalability.

Highlights

  • Database Performance Optimization: Replaced the single, inefficient FilterInvoices query with five specialized, index-friendly queries to improve database performance, especially for SQLite.
  • SQLite Query Planner Efficiency: Addressed and mitigated SQLite query planner inefficiencies caused by OR NULL patterns and CASE expressions in ORDER BY clauses, which previously led to full table scans.
  • New Invoice Query Methods: Introduced new, targeted invoice filtering methods: FetchPendingInvoices, FilterInvoicesBySettleIndex, FilterInvoicesByAddIndex, FilterInvoicesForward, and FilterInvoicesReverse.
  • Index Utilization: Ensured all new queries are designed to effectively utilize specific database indexes (state, settle_index, primary key) for efficient range scans.
  • Non-Nullable Parameters: Implemented non-nullable timestamp parameters with Go-side default values to provide concrete bounds to the query planner, preventing fallbacks to less efficient query plans.

🧠 New Feature in Public Preview: You can now enable Memory to help Gemini Code Assist learn from your team's feedback. This makes future code reviews more consistent and personalized to your project's style. Click here to enable Memory in your admin console.

Changelog
  • invoices/sql_store.go
    • Removed the FilterInvoices interface method.
    • Added five new interface methods: FetchPendingInvoices, FilterInvoicesBySettleIndex, FilterInvoicesByAddIndex, FilterInvoicesForward, and FilterInvoicesReverse.
    • Updated calls to the old FilterInvoices method in FetchPendingInvoices, InvoicesSettledSince, and InvoicesAddedSince to use the new, specific query methods.
    • Refactored QueryInvoices to use FilterInvoicesForward or FilterInvoicesReverse based on the Reversed flag, including logic for Go-side default timestamp parameters.
  • sqldb/sqlc/invoices.sql.go
    • Removed the filterInvoices SQL constant and its corresponding FilterInvoices Go function and FilterInvoicesParams struct.
    • Added fetchPendingInvoices SQL constant, FetchPendingInvoicesParams struct, and FetchPendingInvoices Go function.
    • Added filterInvoicesByAddIndex SQL constant, FilterInvoicesByAddIndexParams struct, and FilterInvoicesByAddIndex Go function.
    • Added filterInvoicesBySettleIndex SQL constant, FilterInvoicesBySettleIndexParams struct, and FilterInvoicesBySettleIndex Go function.
    • Added filterInvoicesForward SQL constant, FilterInvoicesForwardParams struct, and FilterInvoicesForward Go function.
    • Added filterInvoicesReverse SQL constant, FilterInvoicesReverseParams struct, and FilterInvoicesReverse Go function.
  • sqldb/sqlc/querier.go
    • Removed the FilterInvoices method from the Querier interface.
    • Added FetchPendingInvoices, FilterInvoicesByAddIndex, FilterInvoicesBySettleIndex, FilterInvoicesForward, and FilterInvoicesReverse methods to the Querier interface, along with their respective documentation.
  • sqldb/sqlc/queries/invoices.sql
    • Removed the FilterInvoices SQL query definition.
    • Added new SQL query definitions for FetchPendingInvoices, FilterInvoicesBySettleIndex, FilterInvoicesByAddIndex, FilterInvoicesForward, and FilterInvoicesReverse, each with specific WHERE and ORDER BY clauses designed for index usage.
Activity
  • No human activity has been recorded for this pull request yet.
Using Gemini Code Assist

The full guide for Gemini Code Assist can be found on our documentation page, here are some quick tips.

Invoking Gemini

You can request assistance from Gemini at any point by creating a comment using either /gemini <command> or @gemini-code-assist <command>. Below is a summary of the supported commands on the current page.

Feature Command Description
Code Review /gemini review Performs a code review for the current pull request in its current state.
Pull Request Summary /gemini summary Provides a summary of the current pull request in its current state.
Comment @gemini-code-assist Responds in comments when explicitly tagged, both in pull request comments and review comments.
Help /gemini help Displays a list of available commands.

Customization

To customize Gemini Code Assist for GitHub experience, repository maintainers can create a configuration file and/or provide a custom code review style guide (such as PEP-8 for Python) by creating and adding files to a .gemini/ folder in the base of the repository. Detailed instructions can be found here.

Limitations & Feedback

Gemini Code Assist may make mistakes. Please leave feedback on any instances where its feedback is incorrect or counter productive. You can react with 👍 and 👎 on @gemini-code-assist comments. If you're interested in giving your feedback about your experience with Gemini Code Assist for Github and other Google products, sign up here.

You can also get AI-powered code generation, chat, as well as code reviews directly in the IDE at no cost with the Gemini Code Assist IDE Extension.

Footnotes

  1. Review the Privacy Notices, Generative AI Prohibited Use Policy, Terms of Service, and learn how to configure Gemini Code Assist in GitHub here. Gemini can make mistakes, so double check it and use code with caution.

Copy link

@gemini-code-assist gemini-code-assist bot left a comment

Choose a reason for hiding this comment

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

Code Review

This pull request is a great performance improvement. It replaces a single, inefficient FilterInvoices SQL query with five specialized, index-friendly queries. This change is particularly beneficial for SQLite, as it avoids full table scans by using sargable predicates and direct ORDER BY clauses. The implementation is clean, well-structured, and the new functions are clearly documented. I have one minor suggestion to improve the clarity of a comment in one of the new SQL queries.

Copy link
Collaborator

@lightninglabs-deploy lightninglabs-deploy left a comment

Choose a reason for hiding this comment

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

Review: invoices/sql_store – replace catch-all FilterInvoices with targeted queries

Great PR – the problem description is excellent and the solution is well-structured. Replacing the col >= $param OR $param IS NULL anti-pattern and the dynamic CASE-based ORDER BY with focused queries is the right call for SQLite's planner. The add → migrate → remove commit structure is clean and keeps every commit compilable independently.

A few observations below:

1. Comment/SQL mismatch on FilterInvoicesByAddIndex

The SQL comment and the Go doc comment both say the query returns invoices whose id is "strictly greater than the given value", but the actual SQL predicate is WHERE id >= @add_index_get (greater-than-or-equal). The callers compensate by passing idx + 1, so the runtime behavior is correct, but the doc is misleading about the query's own semantics. I'd suggest updating the comment to say "greater than or equal to" to match the SQL, or noting that the caller is expected to adjust the bound.

(The Gemini bot flagged this too, so just confirming it's a real nit.)

2. SettleIndexGet remains sql.NullInt64

FilterInvoicesBySettleIndexParams.SettleIndexGet is typed as sql.NullInt64 even though the whole point of the refactor is to give the planner concrete, non-nullable values. This happens because settle_index is a nullable column (BIGINT without NOT NULL) and sqlc infers the parameter type from the column. Since the caller always passes a valid sql.NullInt64{Valid: true, ...}, this is functionally fine – but it's a minor inconsistency with the stated design goal. Not blocking, just worth being aware of.

3. NOT @pending_only and query plan implications

The NOT @pending_only OR state IN (0, 3) pattern is a clean replacement for the old CASE WHEN … THEN … END approach, and it works correctly across both SQLite (NOT 0 = 1, NOT 1 = 0) and PostgreSQL.

One thing to keep in mind: because $2 is a bound parameter, the planner still can't constant-fold NOT $2 at prepare time. So when pending_only = true, the planner won't be able to use invoices_state_idx for the state filter – it will rely on the primary-key index for the id >= $1 ORDER BY id scan and apply the state predicate as a post-scan filter. This is almost certainly fine for the QueryInvoices path (where the id range scan is the primary access pattern), but it's worth noting that the dedicated FetchPendingInvoices query is still the right choice when you specifically need state-indexed access.

4. Minor: sentinel defaults could be constants

The sentinel bounds (time.Unix(0, 0).UTC() and time.Date(9999, 12, 31, 23, 59, 59, 0, time.UTC)) are clear, but extracting them as package-level vars or const-like values would make them easier to reuse and document. The PR description mentions this follows "the same convention already established by the payments query" – but I wasn't able to find an equivalent pattern in the payments SQL code, so this might be the first place establishing the convention. A named constant would help future code follow the same pattern consistently.

Overall

This is a solid, well-motivated optimization. The behavioral equivalence looks correct across all five call sites (FetchPendingInvoices, InvoicesSettledSince, InvoicesAddedSince, QueryInvoices forward, and QueryInvoices reverse). The sentinel-default approach for timestamps is clean and avoids the nullable-parameter trap entirely for the forward/reverse paths.

Nice work 👍

// settle_index is >= the given bound, ordered by id ascending. The
// caller must always supply a concrete lower bound so the planner can
// use invoices_settle_index_idx.
FilterInvoicesBySettleIndex(ctx context.Context,
Copy link
Member

Choose a reason for hiding this comment

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

We should add tests for these new variants.

Copy link
Collaborator Author

Choose a reason for hiding this comment

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

Done — all five new query variants now have corresponding tests in invoices/invoices_test.go:

  • FetchPendingInvoicestestFetchPendingInvoicesAccepted (verifies ContractOpen and ContractAccepted are returned, ContractSettled and ContractCanceled are excluded)
  • FilterInvoicesByAddIndextestQueryInvoicesPaginationAddIndex
  • FilterInvoicesBySettleIndextestQueryInvoicesPaginationSettleIndex
  • FilterInvoicesForward / FilterInvoicesReversetestQueryInvoicesPagination (covers both directions)

@ziggie1984 ziggie1984 self-assigned this Feb 21, 2026
@ziggie1984 ziggie1984 added this to the v0.21.0 milestone Feb 21, 2026
@ziggie1984 ziggie1984 force-pushed the invoice-filter-index-optimization branch 2 times, most recently from 88361f9 to 412381c Compare February 21, 2026 14:57
The existing FilterInvoices query uses optional parameters via the
pattern `(col >= param OR param IS NULL)` for every filter. SQLite
cannot use indexes with this pattern because the OR prevents the query
planner from determining at plan time which rows satisfy the condition,
resulting in a full table scan regardless of the available indexes
(invoices_state_idx, invoices_settle_index_idx, and the primary-key
clustered index on id).

Additionally, the conditional ORDER BY:

  ORDER BY CASE WHEN reverse = FALSE ... THEN id ELSE NULL END ASC,
           CASE WHEN reverse = TRUE  ... THEN id ELSE NULL END DESC

prevents the planner from using the index ordering and forces an
explicit sort.

Add five focused replacements, each with a plain sargable predicate and
a direct ORDER BY so the planner can always choose an index scan:

  - FetchPendingInvoices:        WHERE state IN (0, 3)
  - FilterInvoicesBySettleIndex: WHERE settle_index >= $1
  - FilterInvoicesByAddIndex:    WHERE id >= $1
  - FilterInvoicesForward:       WHERE id >= $1 ... ORDER BY id ASC
  - FilterInvoicesReverse:       WHERE id <= $1 ... ORDER BY id DESC

FilterInvoicesForward and FilterInvoicesReverse accept non-nullable
timestamp parameters (created_after, created_before) so the planner
always sees plain range predicates on created_at. Callers supply
Go-side defaults when no date filter is needed, following the same
convention already used by the payments query.

FilterInvoices is kept in this commit so all existing call sites
continue to compile. It will be removed once all callers have been
migrated.
@ziggie1984 ziggie1984 force-pushed the invoice-filter-index-optimization branch from 412381c to d2c4e73 Compare February 21, 2026 15:11
Replace all four FilterInvoices call sites with the focused queries
introduced in the previous commit:

  FetchPendingInvoices   → FetchPendingInvoices
  InvoicesSettledSince   → FilterInvoicesBySettleIndex
  InvoicesAddedSince     → FilterInvoicesByAddIndex
  QueryInvoices          → FilterInvoicesForward / FilterInvoicesReverse

The first three are straight 1:1 swaps — the new params structs carry
only the fields that are actually used, and the removed fields (Reverse,
PendingOnly, unused index bounds) were always left at their zero values.

QueryInvoices is restructured more substantially. The forward/reverse
branch now selects between FilterInvoicesForward and
FilterInvoicesReverse, each of which takes a concrete id bound that is
always set:

  forward: AddIndexGet = IndexOffset + 1   (≥ 1 when IndexOffset = 0)
  reverse: AddIndexLet = IndexOffset - 1   (or MaxInt64 when offset = 0)

Timestamp parameters are changed from nullable (sql.NullTime with
OR-based SQL fallbacks) to always-on Go-side defaults, consistent with
the approach used by the payments query:

  createdAfter  → time.Unix(0, 0).UTC()          (epoch, before any invoice)
  createdBefore → time.Date(9999, 12, 31, …)     (far future, no upper cap)

This ensures the planner always sees plain range predicates on
created_at and can use the invoices_created_at_idx index.

The SQLInvoiceQueries interface is updated to expose the five new
methods and drop FilterInvoices.
All call sites have been migrated to the targeted replacement queries
in the previous commit. Remove FilterInvoices and its associated
params struct from the SQL source and regenerate.
Add testFetchPendingInvoicesAccepted to explicitly verify the state
filtering behaviour of FetchPendingInvoices across all four contract
states:

  ContractOpen     (state 0) – must be returned
  ContractAccepted (state 3) – must be returned
  ContractSettled  (state 1) – must be excluded
  ContractCanceled (state 2) – must be excluded

This directly exercises the `state IN (0, 3)` predicate introduced in
the FetchPendingInvoices SQL query and addresses the review request for
explicit test coverage of the new targeted query variants. The test
runs against the KV, SQLite, and Postgres backends.
@ziggie1984 ziggie1984 force-pushed the invoice-filter-index-optimization branch from d2c4e73 to 1e5e6f2 Compare February 21, 2026 16:06
@ziggie1984
Copy link
Collaborator Author

I analyzed the new queries on a local SQLite instance using EXPLAIN QUERY PLAN to verify that each query uses the expected index rather than a full table scan:

  • FetchPendingInvoices: uses invoices_state_idx (state index scan)
  • FilterInvoicesByAddIndex: uses the primary key (clustered index scan on id)
  • FilterInvoicesBySettleIndex: uses invoices_settle_index_idx (settle index scan)
  • FilterInvoicesForward / FilterInvoicesReverse: use the primary key index for the id range; when pending_only = false (the common case) the state predicate short-circuits to true and adds no overhead

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

3 participants