mirror of
https://github.com/lightningnetwork/lnd.git
synced 2025-10-11 04:32:42 +02: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,79 +1,67 @@
|
||||
-- name: InsertAMPInvoicePayment :exec
|
||||
INSERT INTO amp_invoice_payments (
|
||||
set_id, state, created_at, settled_index, invoice_id
|
||||
-- name: UpsertAMPSubInvoice :execresult
|
||||
INSERT INTO amp_sub_invoices (
|
||||
set_id, state, created_at, invoice_id
|
||||
) VALUES (
|
||||
$1, $2, $3, $4, $5
|
||||
);
|
||||
$1, $2, $3, $4
|
||||
) ON CONFLICT (set_id, invoice_id) DO NOTHING;
|
||||
|
||||
-- name: SelectAMPInvoicePayments :many
|
||||
SELECT aip.*, ip.*
|
||||
FROM amp_invoice_payments aip LEFT JOIN invoice_payments ip ON aip.settled_index = ip.id
|
||||
WHERE (
|
||||
set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
) AND (
|
||||
aip.settled_index = sqlc.narg('settled_index') OR
|
||||
sqlc.narg('settled_index') IS NULL
|
||||
) AND (
|
||||
aip.invoice_id = sqlc.narg('invoice_id') OR
|
||||
sqlc.narg('invoice_id') IS NULL
|
||||
);
|
||||
-- name: GetAMPInvoiceID :one
|
||||
SELECT invoice_id FROM amp_sub_invoices WHERE set_id = $1;
|
||||
|
||||
-- name: UpdateAMPPayment :exec
|
||||
UPDATE amp_invoice_payments
|
||||
SET state = $1, settled_index = $2
|
||||
WHERE state = 0 AND (
|
||||
set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
) AND (
|
||||
invoice_id = sqlc.narg('invoice_id') OR
|
||||
sqlc.narg('invoice_id') IS NULL
|
||||
);
|
||||
-- name: UpdateAMPSubInvoiceState :exec
|
||||
UPDATE amp_sub_invoices
|
||||
SET state = $2,
|
||||
settle_index = COALESCE(settle_index, $3),
|
||||
settled_at = COALESCE(settled_at, $4)
|
||||
WHERE set_id = $1;
|
||||
|
||||
-- name: InsertAMPInvoiceHTLC :exec
|
||||
INSERT INTO amp_invoice_htlcs (
|
||||
set_id, htlc_id, root_share, child_index, hash, preimage
|
||||
-- name: InsertAMPSubInvoiceHTLC :exec
|
||||
INSERT INTO amp_sub_invoice_htlcs (
|
||||
invoice_id, set_id, htlc_id, root_share, child_index, hash, preimage
|
||||
) VALUES (
|
||||
$1, $2, $3, $4, $5, $6
|
||||
$1, $2, $3, $4, $5, $6, $7
|
||||
);
|
||||
|
||||
-- name: GetAMPInvoiceHTLCsBySetID :many
|
||||
-- name: FetchAMPSubInvoices :many
|
||||
SELECT *
|
||||
FROM amp_invoice_htlcs
|
||||
WHERE set_id = $1;
|
||||
FROM amp_sub_invoices
|
||||
WHERE invoice_id = $1
|
||||
AND (
|
||||
set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
);
|
||||
|
||||
-- name: GetAMPInvoiceHTLCsByInvoiceID :many
|
||||
SELECT *
|
||||
FROM amp_invoice_htlcs
|
||||
WHERE invoice_id = $1;
|
||||
-- name: FetchAMPSubInvoiceHTLCs :many
|
||||
SELECT
|
||||
amp.set_id, amp.root_share, amp.child_index, amp.hash, amp.preimage,
|
||||
invoice_htlcs.*
|
||||
FROM amp_sub_invoice_htlcs amp
|
||||
INNER JOIN invoice_htlcs ON amp.htlc_id = invoice_htlcs.id
|
||||
WHERE amp.invoice_id = $1
|
||||
AND (
|
||||
set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
);
|
||||
|
||||
-- name: GetSetIDHTLCsCustomRecords :many
|
||||
SELECT ihcr.htlc_id, key, value
|
||||
FROM amp_invoice_htlcs aih JOIN invoice_htlc_custom_records ihcr ON aih.id=ihcr.htlc_id
|
||||
WHERE aih.set_id = $1;
|
||||
|
||||
-- name: UpdateAMPInvoiceHTLC :exec
|
||||
UPDATE amp_invoice_htlcs
|
||||
SET preimage = $1
|
||||
WHERE htlc_id = $2;
|
||||
|
||||
-- name: DeleteAMPHTLCCustomRecords :exec
|
||||
WITH htlc_ids AS (
|
||||
SELECT htlc_id
|
||||
FROM amp_invoice_htlcs
|
||||
WHERE invoice_id = $1
|
||||
)
|
||||
DELETE
|
||||
FROM invoice_htlc_custom_records
|
||||
WHERE htlc_id IN (SELECT id FROM htlc_ids);
|
||||
|
||||
-- name: DeleteAMPHTLCs :exec
|
||||
DELETE
|
||||
FROM amp_invoice_htlcs
|
||||
WHERE invoice_id = $1;
|
||||
|
||||
-- name: DeleteAMPInvoiceHTLC :exec
|
||||
DELETE
|
||||
FROM amp_invoice_htlcs
|
||||
WHERE set_id = $1;
|
||||
-- name: FetchSettledAMPSubInvoices :many
|
||||
SELECT
|
||||
a.set_id,
|
||||
a.settle_index as amp_settle_index,
|
||||
a.settled_at as amp_settled_at,
|
||||
i.*
|
||||
FROM amp_sub_invoices a
|
||||
INNER JOIN invoices i ON a.invoice_id = i.id
|
||||
WHERE (
|
||||
a.settle_index >= sqlc.narg('settle_index_get') OR
|
||||
sqlc.narg('settle_index_get') IS NULL
|
||||
) AND (
|
||||
a.settle_index <= sqlc.narg('settle_index_let') OR
|
||||
sqlc.narg('settle_index_let') IS NULL
|
||||
);
|
||||
|
||||
-- name: UpdateAMPSubInvoiceHTLCPreimage :execresult
|
||||
UPDATE amp_sub_invoice_htlcs AS a
|
||||
SET preimage = $4
|
||||
WHERE a.invoice_id = $1 AND a.set_id = $2 AND a.htlc_id = (
|
||||
SELECT id FROM invoice_htlcs AS i WHERE i.htlc_id = $3
|
||||
);
|
||||
|
@@ -1,35 +1,41 @@
|
||||
-- name: InsertInvoiceEvent :exec
|
||||
-- name: OnInvoiceCreated :exec
|
||||
INSERT INTO invoice_events (
|
||||
created_at, invoice_id, htlc_id, set_id, event_type, event_metadata
|
||||
added_at, event_type, invoice_id
|
||||
) VALUES (
|
||||
$1, $2, $3, $4, $5, $6
|
||||
$1, 0, $2
|
||||
);
|
||||
|
||||
-- name: SelectInvoiceEvents :many
|
||||
SELECT *
|
||||
FROM invoice_events
|
||||
WHERE (
|
||||
invoice_id = sqlc.narg('invoice_id') OR
|
||||
sqlc.narg('invoice_id') IS NULL
|
||||
) AND (
|
||||
htlc_id = sqlc.narg('htlc_id') OR
|
||||
sqlc.narg('htlc_id') IS NULL
|
||||
) AND (
|
||||
set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
) AND (
|
||||
event_type = sqlc.narg('event_type') OR
|
||||
sqlc.narg('event_type') IS NULL
|
||||
) AND (
|
||||
created_at >= sqlc.narg('created_after') OR
|
||||
sqlc.narg('created_after') IS NULL
|
||||
) AND (
|
||||
created_at <= sqlc.narg('created_before') OR
|
||||
sqlc.narg('created_before') IS NULL
|
||||
)
|
||||
LIMIT @num_limit OFFSET @num_offset;
|
||||
-- name: OnInvoiceCanceled :exec
|
||||
INSERT INTO invoice_events (
|
||||
added_at, event_type, invoice_id
|
||||
) VALUES (
|
||||
$1, 1, $2
|
||||
);
|
||||
|
||||
-- name: DeleteInvoiceEvents :exec
|
||||
DELETE
|
||||
FROM invoice_events
|
||||
WHERE invoice_id = $1;
|
||||
-- name: OnInvoiceSettled :exec
|
||||
INSERT INTO invoice_events (
|
||||
added_at, event_type, invoice_id
|
||||
) VALUES (
|
||||
$1, 2, $2
|
||||
);
|
||||
|
||||
-- name: OnAMPSubInvoiceCreated :exec
|
||||
INSERT INTO invoice_events (
|
||||
added_at, event_type, invoice_id, set_id
|
||||
) VALUES (
|
||||
$1, 3, $2, $3
|
||||
);
|
||||
|
||||
-- name: OnAMPSubInvoiceCanceled :exec
|
||||
INSERT INTO invoice_events (
|
||||
added_at, event_type, invoice_id, set_id
|
||||
) VALUES (
|
||||
$1, 4, $2, $3
|
||||
);
|
||||
|
||||
-- name: OnAMPSubInvoiceSettled :exec
|
||||
INSERT INTO invoice_events (
|
||||
added_at, event_type, invoice_id, set_id
|
||||
) VALUES (
|
||||
$1, 5, $2, $3
|
||||
);
|
||||
|
@@ -1,10 +1,10 @@
|
||||
-- name: InsertInvoice :one
|
||||
INSERT INTO invoices (
|
||||
hash, preimage, memo, amount_msat, cltv_delta, expiry, payment_addr,
|
||||
payment_request, state, amount_paid_msat, is_amp, is_hodl, is_keysend,
|
||||
created_at
|
||||
payment_request, payment_request_hash, state, amount_paid_msat, is_amp,
|
||||
is_hodl, is_keysend, created_at
|
||||
) VALUES (
|
||||
$1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14
|
||||
$1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15
|
||||
) RETURNING id;
|
||||
|
||||
-- name: InsertInvoiceFeature :exec
|
||||
@@ -19,35 +19,36 @@ SELECT *
|
||||
FROM invoice_features
|
||||
WHERE invoice_id = $1;
|
||||
|
||||
-- name: DeleteInvoiceFeatures :exec
|
||||
DELETE
|
||||
FROM invoice_features
|
||||
WHERE invoice_id = $1;
|
||||
|
||||
-- This method may return more than one invoice if filter using multiple fields
|
||||
-- from different invoices. It is the caller's responsibility to ensure that
|
||||
-- we bubble up an error in those cases.
|
||||
|
||||
-- name: GetInvoice :many
|
||||
SELECT *
|
||||
FROM invoices
|
||||
SELECT i.*
|
||||
FROM invoices i
|
||||
LEFT JOIN amp_sub_invoices a on i.id = a.invoice_id
|
||||
WHERE (
|
||||
id = sqlc.narg('add_index') OR
|
||||
i.id = sqlc.narg('add_index') OR
|
||||
sqlc.narg('add_index') IS NULL
|
||||
) AND (
|
||||
hash = sqlc.narg('hash') OR
|
||||
i.hash = sqlc.narg('hash') OR
|
||||
sqlc.narg('hash') IS NULL
|
||||
) AND (
|
||||
preimage = sqlc.narg('preimage') OR
|
||||
i.preimage = sqlc.narg('preimage') OR
|
||||
sqlc.narg('preimage') IS NULL
|
||||
) AND (
|
||||
payment_addr = sqlc.narg('payment_addr') OR
|
||||
i.payment_addr = sqlc.narg('payment_addr') OR
|
||||
sqlc.narg('payment_addr') IS NULL
|
||||
) AND (
|
||||
a.set_id = sqlc.narg('set_id') OR
|
||||
sqlc.narg('set_id') IS NULL
|
||||
)
|
||||
GROUP BY i.id
|
||||
LIMIT 2;
|
||||
|
||||
-- name: FilterInvoices :many
|
||||
SELECT *
|
||||
SELECT
|
||||
invoices.*
|
||||
FROM invoices
|
||||
WHERE (
|
||||
id >= sqlc.narg('add_index_get') OR
|
||||
@@ -55,6 +56,12 @@ WHERE (
|
||||
) AND (
|
||||
id <= sqlc.narg('add_index_let') OR
|
||||
sqlc.narg('add_index_let') IS NULL
|
||||
) AND (
|
||||
settle_index >= sqlc.narg('settle_index_get') OR
|
||||
sqlc.narg('settle_index_get') IS NULL
|
||||
) AND (
|
||||
settle_index <= sqlc.narg('settle_index_let') OR
|
||||
sqlc.narg('settle_index_let') IS NULL
|
||||
) AND (
|
||||
state = sqlc.narg('state') OR
|
||||
sqlc.narg('state') IS NULL
|
||||
@@ -81,12 +88,25 @@ ORDER BY
|
||||
END DESC
|
||||
LIMIT @num_limit OFFSET @num_offset;
|
||||
|
||||
-- name: UpdateInvoice :exec
|
||||
UPDATE invoices
|
||||
SET preimage=$2, state=$3, amount_paid_msat=$4
|
||||
WHERE id=$1;
|
||||
-- name: UpdateInvoiceState :execresult
|
||||
UPDATE invoices
|
||||
SET state = $2,
|
||||
preimage = COALESCE(preimage, $3),
|
||||
settle_index = COALESCE(settle_index, $4),
|
||||
settled_at = COALESCE(settled_at, $5)
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: DeleteInvoice :exec
|
||||
-- name: UpdateInvoiceAmountPaid :execresult
|
||||
UPDATE invoices
|
||||
SET amount_paid_msat = $2
|
||||
WHERE id = $1;
|
||||
|
||||
-- name: NextInvoiceSettleIndex :one
|
||||
UPDATE invoice_sequences SET current_value = current_value + 1
|
||||
WHERE name = 'settle_index'
|
||||
RETURNING current_value;
|
||||
|
||||
-- name: DeleteInvoice :execresult
|
||||
DELETE
|
||||
FROM invoices
|
||||
WHERE (
|
||||
@@ -96,20 +116,25 @@ WHERE (
|
||||
hash = sqlc.narg('hash') OR
|
||||
sqlc.narg('hash') IS NULL
|
||||
) AND (
|
||||
preimage = sqlc.narg('preimage') OR
|
||||
sqlc.narg('preimage') IS NULL
|
||||
settle_index = sqlc.narg('settle_index') OR
|
||||
sqlc.narg('settle_index') IS NULL
|
||||
) AND (
|
||||
payment_addr = sqlc.narg('payment_addr') OR
|
||||
sqlc.narg('payment_addr') IS NULL
|
||||
);
|
||||
|
||||
-- name: InsertInvoiceHTLC :exec
|
||||
-- name: DeleteCanceledInvoices :execresult
|
||||
DELETE
|
||||
FROM invoices
|
||||
WHERE state = 2;
|
||||
|
||||
-- name: InsertInvoiceHTLC :one
|
||||
INSERT INTO invoice_htlcs (
|
||||
htlc_id, chan_id, amount_msat, total_mpp_msat, accept_height, accept_time,
|
||||
expiry_height, state, resolve_time, invoice_id
|
||||
) VALUES (
|
||||
$1, $2, $3, $4, $5, $6, $7, $8, $9, $10
|
||||
);
|
||||
) RETURNING id;
|
||||
|
||||
-- name: GetInvoiceHTLCs :many
|
||||
SELECT *
|
||||
@@ -118,25 +143,14 @@ WHERE invoice_id = $1;
|
||||
|
||||
-- name: UpdateInvoiceHTLC :exec
|
||||
UPDATE invoice_htlcs
|
||||
SET state=$2, resolve_time=$3
|
||||
WHERE id = $1;
|
||||
SET state=$4, resolve_time=$5
|
||||
WHERE htlc_id = $1 AND chan_id = $2 AND invoice_id = $3;
|
||||
|
||||
-- name: UpdateInvoiceHTLCs :exec
|
||||
UPDATE invoice_htlcs
|
||||
SET state=$2, resolve_time=$3
|
||||
WHERE invoice_id = $1 AND resolve_time IS NULL;
|
||||
|
||||
|
||||
-- name: DeleteInvoiceHTLC :exec
|
||||
DELETE
|
||||
FROM invoice_htlcs
|
||||
WHERE htlc_id = $1;
|
||||
|
||||
-- name: DeleteInvoiceHTLCs :exec
|
||||
DELETE
|
||||
FROM invoice_htlcs
|
||||
WHERE invoice_id = $1;
|
||||
|
||||
-- name: InsertInvoiceHTLCCustomRecord :exec
|
||||
INSERT INTO invoice_htlc_custom_records (
|
||||
key, value, htlc_id
|
||||
@@ -148,49 +162,3 @@ INSERT INTO invoice_htlc_custom_records (
|
||||
SELECT ihcr.htlc_id, key, value
|
||||
FROM invoice_htlcs ih JOIN invoice_htlc_custom_records ihcr ON ih.id=ihcr.htlc_id
|
||||
WHERE ih.invoice_id = $1;
|
||||
|
||||
-- name: DeleteInvoiceHTLCCustomRecords :exec
|
||||
WITH htlc_ids AS (
|
||||
SELECT ih.id
|
||||
FROM invoice_htlcs ih JOIN invoice_htlc_custom_records ihcr ON ih.id=ihcr.htlc_id
|
||||
WHERE ih.invoice_id = $1
|
||||
)
|
||||
DELETE
|
||||
FROM invoice_htlc_custom_records
|
||||
WHERE htlc_id IN (SELECT id FROM htlc_ids);
|
||||
|
||||
-- name: InsertInvoicePayment :one
|
||||
INSERT INTO invoice_payments (
|
||||
invoice_id, amount_paid_msat, settled_at
|
||||
) VALUES (
|
||||
$1, $2, $3
|
||||
) RETURNING id;
|
||||
|
||||
-- name: GetInvoicePayments :many
|
||||
SELECT *
|
||||
FROM invoice_payments
|
||||
WHERE invoice_id = $1;
|
||||
|
||||
-- name: FilterInvoicePayments :many
|
||||
SELECT
|
||||
ip.id AS settle_index, ip.amount_paid_msat, ip.settled_at AS settle_date,
|
||||
i.*
|
||||
FROM invoice_payments ip JOIN invoices i ON ip.invoice_id = i.id
|
||||
WHERE (
|
||||
ip.id >= sqlc.narg('settle_index_get') OR
|
||||
sqlc.narg('settle_index_get') IS NULL
|
||||
) AND (
|
||||
ip.settled_at >= sqlc.narg('settled_after') OR
|
||||
sqlc.narg('settled_after') IS NULL
|
||||
)
|
||||
ORDER BY
|
||||
CASE
|
||||
WHEN sqlc.narg('reverse') = FALSE THEN ip.id
|
||||
ELSE NULL
|
||||
END ASC,
|
||||
CASE
|
||||
WHEN sqlc.narg('reverse') = TRUE THEN ip.id
|
||||
ELSE NULL
|
||||
END DESC
|
||||
LIMIT @num_limit OFFSET @num_offset;
|
||||
|
||||
|
Reference in New Issue
Block a user