Do not use INSERT OR REPLACE in SQLite. (#620)

Instead, use `INSERT` and `ON CONFLICT`.  The reason is that in case of
conflicts, the `REPLACE` will trigger a DELETE and then perform an INSERT, as
outlined in the documentation[1], and that may cause a cascade of deletion due
to our FOREIGN KEYs.

Here is the official documentation:

```
When a UNIQUE or PRIMARY KEY constraint violation occurs, the REPLACE algorithm
deletes pre-existing rows that are causing the constraint violation prior to
inserting or updating the current row and the command continues executing
normally. If a NOT NULL constraint violation occurs, the REPLACE conflict
resolution replaces the NULL value with the default value for that column, or
if the column has no default value, then the ABORT algorithm is used. If
a CHECK constraint or foreign key constraint violation occurs, the REPLACE
conflict resolution algorithm works like ABORT.  When the REPLACE conflict
resolution strategy deletes rows in order to satisfy a constraint, delete
triggers fire if and only if recursive triggers are enabled.  The update
hook is not invoked for rows that are deleted by the REPLACE conflict
resolution strategy. Nor does REPLACE increment the change counter. The
exceptional behaviors defined in this paragraph might change in a future
release.
```

[1] https://www.sqlite.org/lang_conflict.html
This commit is contained in:
C
2025-02-28 08:35:29 -03:00
committed by GitHub
parent 062d7be58f
commit 63393056a0
2 changed files with 126 additions and 26 deletions

View File

@@ -205,9 +205,23 @@ WHERE active = 1
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO mint_quote
INSERT INTO mint_quote
(id, amount, unit, request, state, expiry, request_lookup_id, pubkey)
VALUES (?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
amount = excluded.amount,
unit = excluded.unit,
request = excluded.request,
state = excluded.state,
expiry = excluded.expiry,
request_lookup_id = excluded.request_lookup_id
ON CONFLICT(request_lookup_id) DO UPDATE SET
amount = excluded.amount,
unit = excluded.unit,
request = excluded.request,
state = excluded.state,
expiry = excluded.expiry,
id = excluded.id
"#,
)
.bind(quote.id.to_string())
@@ -438,8 +452,8 @@ FROM mint_quote
let mut transaction = self.pool.begin().await.map_err(Error::from)?;
let rec = sqlx::query(
r#"
SELECT *
FROM mint_quote
SELECT *
FROM mint_quote
WHERE state = ?
"#,
)
@@ -502,9 +516,28 @@ WHERE id=?
let mut transaction = self.pool.begin().await.map_err(Error::from)?;
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO melt_quote
INSERT INTO melt_quote
(id, unit, amount, request, fee_reserve, state, expiry, payment_preimage, request_lookup_id, msat_to_pay)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
unit = excluded.unit,
amount = excluded.amount,
request = excluded.request,
fee_reserve = excluded.fee_reserve,
state = excluded.state,
expiry = excluded.expiry,
payment_preimage = excluded.payment_preimage,
request_lookup_id = excluded.request_lookup_id,
msat_to_pay = excluded.msat_to_pay
ON CONFLICT(request_lookup_id) DO UPDATE SET
unit = excluded.unit,
amount = excluded.amount,
request = excluded.request,
fee_reserve = excluded.fee_reserve,
state = excluded.state,
expiry = excluded.expiry,
payment_preimage = excluded.payment_preimage,
id = excluded.id;
"#,
)
.bind(quote.id.to_string())
@@ -690,9 +723,18 @@ WHERE id=?
let mut transaction = self.pool.begin().await.map_err(Error::from)?;
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO keyset
INSERT INTO keyset
(id, unit, active, valid_from, valid_to, derivation_path, max_order, input_fee_ppk, derivation_path_index)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
unit = excluded.unit,
active = excluded.active,
valid_from = excluded.valid_from,
valid_to = excluded.valid_to,
derivation_path = excluded.derivation_path,
max_order = excluded.max_order,
input_fee_ppk = excluded.input_fee_ppk,
derivation_path_index = excluded.derivation_path_index
"#,
)
.bind(keyset.id.to_string())
@@ -1176,9 +1218,14 @@ WHERE keyset_id=?;
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO melt_request
INSERT INTO melt_request
(id, inputs, outputs, method, unit)
VALUES (?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
inputs = excluded.inputs,
outputs = excluded.outputs,
method = excluded.method,
unit = excluded.unit
"#,
)
.bind(melt_request.quote)
@@ -1290,9 +1337,12 @@ WHERE quote_id=?;
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO config
INSERT INTO config
(id, value)
VALUES (?, ?);
VALUES (?, ?)
ON CONFLICT(id) DO UPDATE SET
value = excluded.value
;
"#,
)
.bind("mint_info")
@@ -1361,9 +1411,12 @@ WHERE id=?;
let res = sqlx::query(
r#"
INSERT OR REPLACE INTO config
INSERT INTO config
(id, value)
VALUES (?, ?);
VALUES (?, ?)
ON CONFLICT(id) DO UPDATE SET
value = excluded.value
;
"#,
)
.bind("quote_ttl")

View File

@@ -130,9 +130,22 @@ impl WalletDatabase for WalletSqliteDatabase {
sqlx::query(
r#"
INSERT OR REPLACE INTO mint
INSERT INTO mint
(mint_url, name, pubkey, version, description, description_long, contact, nuts, icon_url, urls, motd, mint_time)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(mint_url) DO UPDATE SET
name = excluded.name,
pubkey = excluded.pubkey,
version = excluded.version,
description = excluded.description,
description_long = excluded.description_long,
contact = excluded.contact,
nuts = excluded.nuts,
icon_url = excluded.icon_url,
urls = excluded.urls,
motd = excluded.motd,
mint_time = excluded.mint_time
;
"#,
)
.bind(mint_url.to_string())
@@ -345,9 +358,18 @@ WHERE id=?
async fn add_mint_quote(&self, quote: MintQuote) -> Result<(), Self::Err> {
sqlx::query(
r#"
INSERT OR REPLACE INTO mint_quote
INSERT INTO mint_quote
(id, mint_url, amount, unit, request, state, expiry, secret_key)
VALUES (?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
mint_url = excluded.mint_url,
amount = excluded.amount,
unit = excluded.unit,
request = excluded.request,
state = excluded.state,
expiry = excluded.expiry,
secret_key = excluded.secret_key
;
"#,
)
.bind(quote.id.to_string())
@@ -429,9 +451,17 @@ WHERE id=?
async fn add_melt_quote(&self, quote: wallet::MeltQuote) -> Result<(), Self::Err> {
sqlx::query(
r#"
INSERT OR REPLACE INTO melt_quote
INSERT INTO melt_quote
(id, unit, amount, request, fee_reserve, state, expiry)
VALUES (?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
unit = excluded.unit,
amount = excluded.amount,
request = excluded.request,
fee_reserve = excluded.fee_reserve,
state = excluded.state,
expiry = excluded.expiry
;
"#,
)
.bind(quote.id.to_string())
@@ -492,9 +522,12 @@ WHERE id=?
async fn add_keys(&self, keys: Keys) -> Result<(), Self::Err> {
sqlx::query(
r#"
INSERT OR REPLACE INTO key
INSERT INTO key
(id, keys)
VALUES (?, ?);
VALUES (?, ?)
ON CONFLICT(id) DO UPDATE SET
keys = excluded.keys
;
"#,
)
.bind(Id::from(&keys).to_string())
@@ -556,9 +589,20 @@ WHERE id=?
for proof in added {
sqlx::query(
r#"
INSERT OR REPLACE INTO proof
INSERT INTO proof
(y, mint_url, state, spending_condition, unit, amount, keyset_id, secret, c, witness)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?);
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(y) DO UPDATE SET
mint_url = excluded.mint_url,
state = excluded.state,
spending_condition = excluded.spending_condition,
unit = excluded.unit,
amount = excluded.amount,
keyset_id = excluded.keyset_id,
secret = excluded.secret,
c = excluded.c,
witness = excluded.witness
;
"#,
)
.bind(proof.y.to_bytes().to_vec())
@@ -765,9 +809,12 @@ WHERE key=?;
) -> Result<(), Self::Err> {
sqlx::query(
r#"
INSERT OR REPLACE INTO nostr_last_checked
INSERT INTO nostr_last_checked
(key, last_check)
VALUES (?, ?);
VALUES (?, ?)
ON CONFLICT(key) DO UPDATE SET
last_check = excluded.last_check
;
"#,
)
.bind(verifying_key.to_bytes().to_vec())