mirror of
https://github.com/lightningnetwork/lnd.git
synced 2025-11-19 18:48:03 +01:00
sqldb: simplify and fixup the existing invoice store schema and queries
This commit attempts to fix some issues with the invoice store's schema that we couldn't foresee before the implementation was finished. This is safe as the schema has not been instantiated yet outside of unit tests. Furthermore the commit updates invoice store SQL queries according to fixes in the schema as well as to prepare the higher level implementation in the upcoming commits.
This commit is contained in:
@@ -1,7 +1,17 @@
|
||||
-- sequences contains all sequences used for invoices.
|
||||
CREATE TABLE invoice_sequences (
|
||||
name TEXT PRIMARY KEY,
|
||||
current_value BIGINT NOT NULL
|
||||
);
|
||||
|
||||
-- Initialize a sequence for the settled index used to track invoice settlement
|
||||
-- to remain compatible with the legacy channeldb implementation.
|
||||
INSERT INTO invoice_sequences(name, current_value) VALUES ('settle_index', 0);
|
||||
|
||||
-- invoices table contains all the information shared by all the invoice types.
|
||||
CREATE TABLE IF NOT EXISTS invoices (
|
||||
-- The id of the invoice. Translates to the AddIndex.
|
||||
id INTEGER PRIMARY KEY,
|
||||
id BIGINT PRIMARY KEY,
|
||||
|
||||
-- The hash for this invoice. The invoice hash will always identify that
|
||||
-- invoice.
|
||||
@@ -10,6 +20,14 @@ CREATE TABLE IF NOT EXISTS invoices (
|
||||
-- The preimage for the hash in this invoice. Some invoices may have this
|
||||
-- field empty, like unsettled hodl invoices or AMP invoices.
|
||||
preimage BLOB,
|
||||
|
||||
-- If settled, the index is set to the current_value+1 of the settle_index
|
||||
-- seuqence in the invoice_sequences table. If not settled, then it is set
|
||||
-- to NULL.
|
||||
settle_index BIGINT,
|
||||
|
||||
-- When the invoice was settled.
|
||||
settled_at TIMESTAMP,
|
||||
|
||||
-- An optional memo to attach along with the invoice.
|
||||
memo TEXT,
|
||||
@@ -31,7 +49,12 @@ CREATE TABLE IF NOT EXISTS invoices (
|
||||
|
||||
-- The encoded payment request for this invoice. Some invoice types may
|
||||
-- not have leave this empty, like Keysends.
|
||||
payment_request TEXT UNIQUE,
|
||||
payment_request TEXT,
|
||||
|
||||
-- Holds the hash of the payment request. This field is used to ensure that
|
||||
-- there are no duplicates in the database. This trick is needed because
|
||||
-- PostgreSQL has a limitiation of 2712 bytes for unique index rows.
|
||||
payment_request_hash BLOB UNIQUE,
|
||||
|
||||
-- The invoice state.
|
||||
state SMALLINT NOT NULL,
|
||||
@@ -58,6 +81,7 @@ CREATE INDEX IF NOT EXISTS invoices_preimage_idx ON invoices(preimage);
|
||||
CREATE INDEX IF NOT EXISTS invoices_payment_addr_idx ON invoices(payment_addr);
|
||||
CREATE INDEX IF NOT EXISTS invoices_state_idx ON invoices(state);
|
||||
CREATE INDEX IF NOT EXISTS invoices_created_at_idx ON invoices(created_at);
|
||||
CREATE INDEX IF NOT EXISTS invoices_settled_at_idx ON invoices(settled_at);
|
||||
|
||||
-- invoice_features contains the feature bits of an invoice.
|
||||
CREATE TABLE IF NOT EXISTS invoice_features (
|
||||
@@ -65,7 +89,7 @@ CREATE TABLE IF NOT EXISTS invoice_features (
|
||||
feature INTEGER NOT NULL,
|
||||
|
||||
-- The invoice id this feature belongs to.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id),
|
||||
invoice_id BIGINT NOT NULL REFERENCES invoices(id) ON DELETE CASCADE,
|
||||
|
||||
-- The feature bit is unique per invoice.
|
||||
UNIQUE (feature, invoice_id)
|
||||
@@ -78,15 +102,15 @@ CREATE INDEX IF NOT EXISTS invoice_feature_invoice_id_idx ON invoice_features(in
|
||||
CREATE TABLE IF NOT EXISTS invoice_htlcs (
|
||||
-- The id for this htlc. Used in foreign keys instead of the
|
||||
-- htlc_id/chan_id combination.
|
||||
id INTEGER PRIMARY KEY,
|
||||
id BIGINT PRIMARY KEY,
|
||||
|
||||
-- Short chan id indicating the htlc's origin. uint64 stored as text.
|
||||
chan_id TEXT NOT NULL,
|
||||
|
||||
-- The uint64 htlc id. This field is a counter so it is safe to store it as
|
||||
-- int64 in the database. The application layer must check that there is no
|
||||
-- overflow when storing/loading this column.
|
||||
htlc_id BIGINT NOT NULL,
|
||||
|
||||
-- Short chan id indicating the htlc's origin. uint64 stored as text.
|
||||
chan_id TEXT NOT NULL,
|
||||
|
||||
-- The htlc's amount in millisatoshis.
|
||||
amount_msat BIGINT NOT NULL,
|
||||
@@ -110,10 +134,10 @@ CREATE TABLE IF NOT EXISTS invoice_htlcs (
|
||||
resolve_time TIMESTAMP,
|
||||
|
||||
-- The id of the invoice this htlc belongs to.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id),
|
||||
invoice_id BIGINT NOT NULL REFERENCES invoices(id) ON DELETE CASCADE,
|
||||
|
||||
-- The htlc_id and chan_id identify the htlc.
|
||||
UNIQUE (htlc_id, chan_id)
|
||||
UNIQUE (chan_id, htlc_id)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS invoice_htlc_invoice_id_idx ON invoice_htlcs(invoice_id);
|
||||
@@ -129,26 +153,8 @@ CREATE TABLE IF NOT EXISTS invoice_htlc_custom_records (
|
||||
value BLOB NOT NULL,
|
||||
|
||||
-- The htlc id this record belongs to.
|
||||
htlc_id BIGINT NOT NULL REFERENCES invoice_htlcs(id)
|
||||
htlc_id BIGINT NOT NULL REFERENCES invoice_htlcs(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS invoice_htlc_custom_records_htlc_id_idx ON invoice_htlc_custom_records(htlc_id);
|
||||
|
||||
-- invoice_payments contains the information of a settled invoice payment.
|
||||
CREATE TABLE IF NOT EXISTS invoice_payments (
|
||||
-- The id for this invoice payment. Translates to SettleIndex.
|
||||
id INTEGER PRIMARY KEY,
|
||||
|
||||
-- When the payment was settled.
|
||||
settled_at TIMESTAMP NOT NULL,
|
||||
|
||||
-- The amount of the payment in millisatoshis. This is the sum of all the
|
||||
-- the htlcs settled for this payment.
|
||||
amount_paid_msat BIGINT NOT NULL,
|
||||
|
||||
-- The invoice id this payment is for.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS invoice_payments_settled_at_idx ON invoice_payments(settled_at);
|
||||
CREATE INDEX IF NOT EXISTS invoice_payments_invoice_id_idx ON invoice_payments(invoice_id);
|
||||
|
||||
@@ -1,5 +1,6 @@
|
||||
-- amp_invoices_payments
|
||||
CREATE TABLE IF NOT EXISTS amp_invoice_payments (
|
||||
-- amp_sub_invoices holds all AMP sub-invoices that belong to a given parent
|
||||
-- invoice.
|
||||
CREATE TABLE IF NOT EXISTS amp_sub_invoices (
|
||||
-- The set id identifying the payment.
|
||||
set_id BLOB PRIMARY KEY,
|
||||
|
||||
@@ -10,26 +11,35 @@ CREATE TABLE IF NOT EXISTS amp_invoice_payments (
|
||||
-- Timestamp of when the first htlc for this payment was accepted.
|
||||
created_at TIMESTAMP NOT NULL,
|
||||
|
||||
-- If settled, the invoice payment related to this set id.
|
||||
settled_index INTEGER REFERENCES invoice_payments(id),
|
||||
-- When the invoice was settled.
|
||||
settled_at TIMESTAMP,
|
||||
|
||||
-- The invoice id this set id is related to.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id)
|
||||
-- If settled, the index is set to the current_value+1 of the settle_index
|
||||
-- seuqence in the invoice_sequences table. If not settled, then it is set
|
||||
-- to NULL.
|
||||
settle_index BIGINT,
|
||||
|
||||
-- The id of the parent invoice this AMP invoice belongs to.
|
||||
invoice_id BIGINT NOT NULL REFERENCES invoices(id) ON DELETE CASCADE,
|
||||
|
||||
-- A unique constraint on the set_id and invoice_id is needed to ensure that
|
||||
-- we don't have two AMP invoices for the same invoice.
|
||||
UNIQUE (set_id, invoice_id)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS amp_invoice_payments_invoice_id_idx ON amp_invoice_payments(invoice_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_sub_invoices_invoice_id_idx ON amp_sub_invoices(invoice_id);
|
||||
|
||||
-- amp_invoice_htlcs contains the complementary information for an htlc related
|
||||
-- to an AMP invoice.
|
||||
CREATE TABLE IF NOT EXISTS amp_invoice_htlcs (
|
||||
CREATE TABLE IF NOT EXISTS amp_sub_invoice_htlcs (
|
||||
-- The invoice id this entry is related to.
|
||||
invoice_id BIGINT NOT NULL REFERENCES invoices(id) ON DELETE CASCADE,
|
||||
|
||||
-- The set id identifying the payment this htlc belongs to.
|
||||
set_id BLOB NOT NULL REFERENCES amp_invoice_payments(set_id),
|
||||
set_id BLOB NOT NULL REFERENCES amp_sub_invoices(set_id) ON DELETE CASCADE,
|
||||
|
||||
-- The id of the htlc this entry blongs to.
|
||||
htlc_id BIGINT NOT NULL REFERENCES invoice_htlcs(id),
|
||||
|
||||
-- The invoice id this entry is related to.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id),
|
||||
htlc_id BIGINT NOT NULL REFERENCES invoice_htlcs(id) ON DELETE CASCADE,
|
||||
|
||||
-- The root share for this amp htlc.
|
||||
root_share BLOB NOT NULL,
|
||||
@@ -48,7 +58,7 @@ CREATE TABLE IF NOT EXISTS amp_invoice_htlcs (
|
||||
preimage BLOB
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_set_id_idx ON amp_invoice_htlcs(set_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_invoice_id_idx ON amp_invoice_htlcs(invoice_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_htlc_id_idx ON amp_invoice_htlcs(htlc_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_invoice_id_idx ON amp_sub_invoice_htlcs(invoice_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_set_id_idx ON amp_sub_invoice_htlcs(set_id);
|
||||
CREATE INDEX IF NOT EXISTS amp_htlcs_htlc_id_idx ON amp_sub_invoice_htlcs(htlc_id);
|
||||
|
||||
|
||||
@@ -1,9 +1,6 @@
|
||||
DROP TABLE IF EXISTS invoice_events;
|
||||
|
||||
DROP INDEX IF EXISTS invoice_events_created_at_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_invoice_id_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_htlc_id_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_set_id_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_added_at_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_event_type_idx;
|
||||
|
||||
DROP INDEX IF EXISTS invoice_events_invoice_id_idx;
|
||||
DROP INDEX IF EXISTS invoice_events_set_id_idx;
|
||||
DROP TABLE IF EXISTS invoice_event_types;
|
||||
|
||||
@@ -1,59 +1,51 @@
|
||||
-- invoice_event_types stores the different types of events that can be emitted
|
||||
-- for invoices.
|
||||
-- invoice_event_types stores the different types of invoice events.
|
||||
CREATE TABLE IF NOT EXISTS invoice_event_types(
|
||||
id INTEGER PRIMARY KEY,
|
||||
|
||||
description TEXT NOT NULL
|
||||
);
|
||||
|
||||
-- invoice_events stores all events related to the node invoices.
|
||||
CREATE TABLE IF NOT EXISTS invoice_events (
|
||||
id INTEGER PRIMARY KEY,
|
||||
|
||||
-- created_at is the creation time of this event.
|
||||
created_at TIMESTAMP NOT NULL,
|
||||
|
||||
-- invoice_id is the reference to the invoice this event was emitted for.
|
||||
invoice_id INTEGER NOT NULL REFERENCES invoices(id),
|
||||
|
||||
-- htlc_id is the reference to the htlc this event was emitted for, may be
|
||||
-- null.
|
||||
htlc_id BIGINT REFERENCES invoice_htlcs(htlc_id),
|
||||
|
||||
-- set_id is the reference to the set_id this event was emitted for, may be
|
||||
-- null.
|
||||
set_id BLOB NOT NULL REFERENCES amp_invoice_payments(set_id),
|
||||
|
||||
-- event_type is the type of this event.
|
||||
event_type INTEGER NOT NULL REFERENCES invoice_event_types(id),
|
||||
|
||||
-- event_metadata is a TLV encoding any relevant information for this kind
|
||||
-- of events.
|
||||
event_metadata BLOB
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_created_at_idx ON invoice_events(created_at);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_invoice_id_idx ON invoice_events(invoice_id);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_htlc_id_idx ON invoice_events(htlc_id);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_set_id_idx ON invoice_events(set_id);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_event_type_idx ON invoice_events(event_type);
|
||||
|
||||
|
||||
-- invoice_event_types defines the different types of events that can be emitted
|
||||
-- for an invoice.
|
||||
-- invoice_event_types defines the different types of invoice events.
|
||||
INSERT INTO invoice_event_types (id, description)
|
||||
VALUES
|
||||
-- invoice_created is the event emitted when an invoice is created.
|
||||
-- invoice_created is the event type used when an invoice is created.
|
||||
(0, 'invoice_created'),
|
||||
-- invoice_canceled is the event emitted when an invoice is canceled.
|
||||
(1, "invoice_canceled"),
|
||||
-- invoice_settled is the event emitted when an invoice is settled.
|
||||
(2, "invoice_settled"),
|
||||
-- setid_created is the event emitted when the first htlc for the set_id is
|
||||
-- received.
|
||||
(3, "setid_created"),
|
||||
-- setid_canceled is the event emitted when the set_id is canceled.
|
||||
(4, "setid_canceled"),
|
||||
-- setid_settled is the event emitted when the set_id is settled.
|
||||
(5, "setid_settled");
|
||||
-- invoice_canceled is the event type used when an invoice is canceled.
|
||||
(1, 'invoice_canceled'),
|
||||
-- invoice_settled is the event type used when an invoice is settled.
|
||||
(2, 'invoice_settled'),
|
||||
-- setid_created is the event type used when an AMP sub invoice
|
||||
-- corresponding to the set_id is created.
|
||||
(3, 'setid_created'),
|
||||
-- setid_canceled is the event type used when an AMP sub invoice
|
||||
-- corresponding to the set_id is canceled.
|
||||
(4, 'setid_canceled'),
|
||||
-- setid_settled is the event type used when an AMP sub invoice
|
||||
-- corresponding to the set_id is settled.
|
||||
(5, 'setid_settled');
|
||||
|
||||
|
||||
-- invoice_events stores all major events related to the node's invoices and
|
||||
-- AMP sub invoices. This table can be used to create a historical view of what
|
||||
-- happened to the node's invoices.
|
||||
CREATE TABLE IF NOT EXISTS invoice_events (
|
||||
id BIGINT PRIMARY KEY,
|
||||
|
||||
-- added_at is the timestamp when this event was added.
|
||||
added_at TIMESTAMP NOT NULL,
|
||||
|
||||
-- event_type is the type of this event.
|
||||
event_type INTEGER NOT NULL REFERENCES invoice_event_types(id) ON DELETE CASCADE,
|
||||
|
||||
-- invoice_id is the reference to the invoice this event was added for.
|
||||
invoice_id BIGINT NOT NULL REFERENCES invoices(id) ON DELETE CASCADE,
|
||||
|
||||
-- set_id is the reference to the AMP sub invoice this event was added for.
|
||||
-- May be NULL if the event is not related to an AMP sub invoice.
|
||||
set_id BLOB REFERENCES amp_sub_invoices(set_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_added_at_idx ON invoice_events(added_at);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_event_type_idx ON invoice_events(event_type);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_invoice_id_idx ON invoice_events(invoice_id);
|
||||
CREATE INDEX IF NOT EXISTS invoice_events_set_id_idx ON invoice_events(set_id);
|
||||
|
||||
Reference in New Issue
Block a user