Merge pull request #974 from nuttycom/wallet/put_tx_record_for_transparent_utxos

zcash_client_sqlite: Remove inner join between `transactions` and `utxos` from `v_transactions`
This commit is contained in:
Kris Nuttycombe 2023-09-19 14:51:24 -06:00 committed by GitHub
commit 0643678fe5
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
4 changed files with 243 additions and 37 deletions

View File

@ -42,6 +42,10 @@ and this library adheres to Rust's notion of
- `FsBlockDbError::CacheMiss` - `FsBlockDbError::CacheMiss`
- `zcash_client_sqlite::FsBlockDb::write_block_metadata` now overwrites any - `zcash_client_sqlite::FsBlockDb::write_block_metadata` now overwrites any
existing metadata entries that have the same height as a new entry. existing metadata entries that have the same height as a new entry.
- The `v_transactions` and `v_tx_outputs` views no longer return the
internal database identifier for the transaction. The `txid` column
should be used instead. The `tx_index`, `expiry_height`, `raw` and
`fee_paid` columns may now be null for received transparent transactions.
### Removed ### Removed
- The empty `wallet::transact` module has been removed. - The empty `wallet::transact` module has been removed.
@ -67,6 +71,8 @@ and this library adheres to Rust's notion of
- `WalletDb::get_transaction` no longer returns an error when called on a transaction - `WalletDb::get_transaction` no longer returns an error when called on a transaction
that has not yet been mined, unless the transaction's consensus branch ID cannot be that has not yet been mined, unless the transaction's consensus branch ID cannot be
determined by other means. determined by other means.
- Fixed an error in `v_transactions` wherein received transparent outputs did not
result in a transaction entry appearing in the transaction history.
## [0.7.1] - 2023-05-17 ## [0.7.1] - 2023-05-17

View File

@ -436,8 +436,9 @@ mod tests {
WITH WITH
notes AS ( notes AS (
SELECT sapling_received_notes.account AS account_id, SELECT sapling_received_notes.account AS account_id,
sapling_received_notes.tx AS id_tx, transactions.block AS block,
2 AS pool, transactions.txid AS txid,
2 AS pool,
sapling_received_notes.value AS value, sapling_received_notes.value AS value,
CASE CASE
WHEN sapling_received_notes.is_change THEN 1 WHEN sapling_received_notes.is_change THEN 1
@ -452,56 +453,59 @@ mod tests {
THEN 0 THEN 0
ELSE 1 ELSE 1
END AS memo_present END AS memo_present
FROM sapling_received_notes FROM sapling_received_notes
JOIN transactions
ON transactions.id_tx = sapling_received_notes.tx
UNION UNION
SELECT utxos.received_by_account AS account_id, SELECT utxos.received_by_account AS account_id,
transactions.id_tx AS id_tx, utxos.height AS block,
utxos.prevout_txid AS txid,
0 AS pool, 0 AS pool,
utxos.value_zat AS value, utxos.value_zat AS value,
0 AS is_change, 0 AS is_change,
1 AS received_count, 1 AS received_count,
0 AS memo_present 0 AS memo_present
FROM utxos FROM utxos
JOIN transactions
ON transactions.txid = utxos.prevout_txid
UNION UNION
SELECT sapling_received_notes.account AS account_id, SELECT sapling_received_notes.account AS account_id,
sapling_received_notes.spent AS id_tx, transactions.block AS block,
2 AS pool, transactions.txid AS txid,
2 AS pool,
-sapling_received_notes.value AS value, -sapling_received_notes.value AS value,
0 AS is_change, 0 AS is_change,
0 AS received_count, 0 AS received_count,
0 AS memo_present 0 AS memo_present
FROM sapling_received_notes FROM sapling_received_notes
WHERE sapling_received_notes.spent IS NOT NULL JOIN transactions
ON transactions.id_tx = sapling_received_notes.spent
), ),
sent_note_counts AS ( sent_note_counts AS (
SELECT sent_notes.from_account AS account_id, SELECT sent_notes.from_account AS account_id,
sent_notes.tx AS id_tx, transactions.txid AS txid,
COUNT(DISTINCT sent_notes.id_note) as sent_notes, COUNT(DISTINCT sent_notes.id_note) as sent_notes,
SUM( SUM(
CASE CASE
WHEN (sent_notes.memo IS NULL OR sent_notes.memo = X'F6') WHEN (sent_notes.memo IS NULL OR sent_notes.memo = X'F6' OR sapling_received_notes.tx IS NOT NULL)
THEN 0 THEN 0
ELSE 1 ELSE 1
END END
) AS memo_count ) AS memo_count
FROM sent_notes FROM sent_notes
JOIN transactions
ON transactions.id_tx = sent_notes.tx
LEFT JOIN sapling_received_notes LEFT JOIN sapling_received_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) = ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sapling_received_notes.output_index) (sapling_received_notes.tx, 2, sapling_received_notes.output_index)
WHERE sapling_received_notes.is_change IS NULL WHERE COALESCE(sapling_received_notes.is_change, 0) = 0
OR sapling_received_notes.is_change = 0 GROUP BY account_id, txid
GROUP BY account_id, id_tx
), ),
blocks_max_height AS ( blocks_max_height AS (
SELECT MAX(blocks.height) as max_height FROM blocks SELECT MAX(blocks.height) as max_height FROM blocks
) )
SELECT notes.account_id AS account_id, SELECT notes.account_id AS account_id,
transactions.id_tx AS id_tx, notes.block AS mined_height,
transactions.block AS mined_height, notes.txid AS txid,
transactions.tx_index AS tx_index, transactions.tx_index AS tx_index,
transactions.txid AS txid,
transactions.expiry_height AS expiry_height, transactions.expiry_height AS expiry_height,
transactions.raw AS raw, transactions.raw AS raw,
SUM(notes.value) AS account_balance_delta, SUM(notes.value) AS account_balance_delta,
@ -513,19 +517,20 @@ mod tests {
blocks.time AS block_time, blocks.time AS block_time,
( (
blocks.height IS NULL blocks.height IS NULL
AND transactions.expiry_height <= blocks_max_height.max_height AND transactions.expiry_height BETWEEN 1 AND blocks_max_height.max_height
) AS expired_unmined ) AS expired_unmined
FROM transactions FROM notes
JOIN notes ON notes.id_tx = transactions.id_tx LEFT JOIN transactions
ON notes.txid = transactions.txid
JOIN blocks_max_height JOIN blocks_max_height
LEFT JOIN blocks ON blocks.height = transactions.block LEFT JOIN blocks ON blocks.height = notes.block
LEFT JOIN sent_note_counts LEFT JOIN sent_note_counts
ON sent_note_counts.account_id = notes.account_id ON sent_note_counts.account_id = notes.account_id
AND sent_note_counts.id_tx = notes.id_tx AND sent_note_counts.txid = notes.txid
GROUP BY notes.account_id, transactions.id_tx".to_owned(), GROUP BY notes.account_id, notes.txid".to_owned(),
// v_tx_outputs // v_tx_outputs
"CREATE VIEW v_tx_outputs AS "CREATE VIEW v_tx_outputs AS
SELECT sapling_received_notes.tx AS id_tx, SELECT transactions.txid AS txid,
2 AS output_pool, 2 AS output_pool,
sapling_received_notes.output_index AS output_index, sapling_received_notes.output_index AS output_index,
sent_notes.from_account AS from_account, sent_notes.from_account AS from_account,
@ -535,11 +540,13 @@ mod tests {
sapling_received_notes.is_change AS is_change, sapling_received_notes.is_change AS is_change,
sapling_received_notes.memo AS memo sapling_received_notes.memo AS memo
FROM sapling_received_notes FROM sapling_received_notes
JOIN transactions
ON transactions.id_tx = sapling_received_notes.tx
LEFT JOIN sent_notes LEFT JOIN sent_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) = ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sent_notes.output_index) (sapling_received_notes.tx, 2, sent_notes.output_index)
UNION UNION
SELECT transactions.id_tx AS id_tx, SELECT utxos.prevout_txid AS txid,
0 AS output_pool, 0 AS output_pool,
utxos.prevout_idx AS output_index, utxos.prevout_idx AS output_index,
NULL AS from_account, NULL AS from_account,
@ -549,10 +556,8 @@ mod tests {
false AS is_change, false AS is_change,
NULL AS memo NULL AS memo
FROM utxos FROM utxos
JOIN transactions
ON transactions.txid = utxos.prevout_txid
UNION UNION
SELECT sent_notes.tx AS id_tx, SELECT transactions.txid AS txid,
sent_notes.output_pool AS output_pool, sent_notes.output_pool AS output_pool,
sent_notes.output_index AS output_index, sent_notes.output_index AS output_index,
sent_notes.from_account AS from_account, sent_notes.from_account AS from_account,
@ -562,11 +567,12 @@ mod tests {
false AS is_change, false AS is_change,
sent_notes.memo AS memo sent_notes.memo AS memo
FROM sent_notes FROM sent_notes
JOIN transactions
ON transactions.id_tx = sent_notes.tx
LEFT JOIN sapling_received_notes LEFT JOIN sapling_received_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) = ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sapling_received_notes.output_index) (sapling_received_notes.tx, 2, sapling_received_notes.output_index)
WHERE sapling_received_notes.is_change IS NULL WHERE COALESCE(sapling_received_notes.is_change, 0) = 0".to_owned(),
OR sapling_received_notes.is_change = 0".to_owned(),
]; ];
let mut views_query = st let mut views_query = st

View File

@ -12,6 +12,7 @@ mod ufvk_support;
mod utxos_table; mod utxos_table;
mod v_sapling_shard_unscanned_ranges; mod v_sapling_shard_unscanned_ranges;
mod v_transactions_net; mod v_transactions_net;
mod v_transactions_transparent_history;
mod wallet_summaries; mod wallet_summaries;
use schemer_rusqlite::RusqliteMigration; use schemer_rusqlite::RusqliteMigration;
@ -39,12 +40,13 @@ pub(super) fn all_migrations<P: consensus::Parameters + 'static>(
// received_notes_nullable_nf // received_notes_nullable_nf
// / | \ // / | \
// shardtree_support nullifier_map sapling_memo_consistency // shardtree_support nullifier_map sapling_memo_consistency
// | // | |
// add_account_birthdays // add_account_birthdays |
// | // | |
// v_sapling_shard_unscanned_ranges // v_sapling_shard_unscanned_ranges |
// | // | |
// wallet_summaries // wallet_summaries |
// v_transactions_transparent_history
vec![ vec![
Box::new(initial_setup::Migration {}), Box::new(initial_setup::Migration {}),
Box::new(utxos_table::Migration {}), Box::new(utxos_table::Migration {}),
@ -76,5 +78,6 @@ pub(super) fn all_migrations<P: consensus::Parameters + 'static>(
params: params.clone(), params: params.clone(),
}), }),
Box::new(wallet_summaries::Migration), Box::new(wallet_summaries::Migration),
Box::new(v_transactions_transparent_history::Migration),
] ]
} }

View File

@ -0,0 +1,191 @@
//! This migration reworks transaction history views to correctly include history
//! of transparent utxos for which we lack complete transaction information.
use std::collections::HashSet;
use schemer_rusqlite::RusqliteMigration;
use uuid::Uuid;
use crate::wallet::init::WalletMigrationError;
use super::sapling_memo_consistency;
pub(super) const MIGRATION_ID: Uuid = Uuid::from_u128(0xaa0a4168_b41b_44c5_a47d_c4c66603cfab);
pub(super) struct Migration;
impl schemer::Migration for Migration {
fn id(&self) -> Uuid {
MIGRATION_ID
}
fn dependencies(&self) -> HashSet<Uuid> {
[sapling_memo_consistency::MIGRATION_ID]
.into_iter()
.collect()
}
fn description(&self) -> &'static str {
"Updates transaction history views to fix potential errors in transparent history."
}
}
impl RusqliteMigration for Migration {
type Error = WalletMigrationError;
fn up(&self, transaction: &rusqlite::Transaction) -> Result<(), Self::Error> {
transaction.execute_batch(
"DROP VIEW v_transactions;
CREATE VIEW v_transactions AS
WITH
notes AS (
SELECT sapling_received_notes.account AS account_id,
transactions.block AS block,
transactions.txid AS txid,
2 AS pool,
sapling_received_notes.value AS value,
CASE
WHEN sapling_received_notes.is_change THEN 1
ELSE 0
END AS is_change,
CASE
WHEN sapling_received_notes.is_change THEN 0
ELSE 1
END AS received_count,
CASE
WHEN (sapling_received_notes.memo IS NULL OR sapling_received_notes.memo = X'F6')
THEN 0
ELSE 1
END AS memo_present
FROM sapling_received_notes
JOIN transactions
ON transactions.id_tx = sapling_received_notes.tx
UNION
SELECT utxos.received_by_account AS account_id,
utxos.height AS block,
utxos.prevout_txid AS txid,
0 AS pool,
utxos.value_zat AS value,
0 AS is_change,
1 AS received_count,
0 AS memo_present
FROM utxos
UNION
SELECT sapling_received_notes.account AS account_id,
transactions.block AS block,
transactions.txid AS txid,
2 AS pool,
-sapling_received_notes.value AS value,
0 AS is_change,
0 AS received_count,
0 AS memo_present
FROM sapling_received_notes
JOIN transactions
ON transactions.id_tx = sapling_received_notes.spent
),
sent_note_counts AS (
SELECT sent_notes.from_account AS account_id,
transactions.txid AS txid,
COUNT(DISTINCT sent_notes.id_note) as sent_notes,
SUM(
CASE
WHEN (sent_notes.memo IS NULL OR sent_notes.memo = X'F6' OR sapling_received_notes.tx IS NOT NULL)
THEN 0
ELSE 1
END
) AS memo_count
FROM sent_notes
JOIN transactions
ON transactions.id_tx = sent_notes.tx
LEFT JOIN sapling_received_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sapling_received_notes.output_index)
WHERE COALESCE(sapling_received_notes.is_change, 0) = 0
GROUP BY account_id, txid
),
blocks_max_height AS (
SELECT MAX(blocks.height) as max_height FROM blocks
)
SELECT notes.account_id AS account_id,
notes.block AS mined_height,
notes.txid AS txid,
transactions.tx_index AS tx_index,
transactions.expiry_height AS expiry_height,
transactions.raw AS raw,
SUM(notes.value) AS account_balance_delta,
transactions.fee AS fee_paid,
SUM(notes.is_change) > 0 AS has_change,
MAX(COALESCE(sent_note_counts.sent_notes, 0)) AS sent_note_count,
SUM(notes.received_count) AS received_note_count,
SUM(notes.memo_present) + MAX(COALESCE(sent_note_counts.memo_count, 0)) AS memo_count,
blocks.time AS block_time,
(
blocks.height IS NULL
AND transactions.expiry_height BETWEEN 1 AND blocks_max_height.max_height
) AS expired_unmined
FROM notes
LEFT JOIN transactions
ON notes.txid = transactions.txid
JOIN blocks_max_height
LEFT JOIN blocks ON blocks.height = notes.block
LEFT JOIN sent_note_counts
ON sent_note_counts.account_id = notes.account_id
AND sent_note_counts.txid = notes.txid
GROUP BY notes.account_id, notes.txid;"
)?;
transaction.execute_batch(
"DROP VIEW v_tx_outputs;
CREATE VIEW v_tx_outputs AS
SELECT transactions.txid AS txid,
2 AS output_pool,
sapling_received_notes.output_index AS output_index,
sent_notes.from_account AS from_account,
sapling_received_notes.account AS to_account,
NULL AS to_address,
sapling_received_notes.value AS value,
sapling_received_notes.is_change AS is_change,
sapling_received_notes.memo AS memo
FROM sapling_received_notes
JOIN transactions
ON transactions.id_tx = sapling_received_notes.tx
LEFT JOIN sent_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sent_notes.output_index)
UNION
SELECT utxos.prevout_txid AS txid,
0 AS output_pool,
utxos.prevout_idx AS output_index,
NULL AS from_account,
utxos.received_by_account AS to_account,
utxos.address AS to_address,
utxos.value_zat AS value,
false AS is_change,
NULL AS memo
FROM utxos
UNION
SELECT transactions.txid AS txid,
sent_notes.output_pool AS output_pool,
sent_notes.output_index AS output_index,
sent_notes.from_account AS from_account,
sapling_received_notes.account AS to_account,
sent_notes.to_address AS to_address,
sent_notes.value AS value,
false AS is_change,
sent_notes.memo AS memo
FROM sent_notes
JOIN transactions
ON transactions.id_tx = sent_notes.tx
LEFT JOIN sapling_received_notes
ON (sent_notes.tx, sent_notes.output_pool, sent_notes.output_index) =
(sapling_received_notes.tx, 2, sapling_received_notes.output_index)
WHERE COALESCE(sapling_received_notes.is_change, 0) = 0;",
)?;
Ok(())
}
fn down(&self, _transaction: &rusqlite::Transaction) -> Result<(), Self::Error> {
panic!("This migration cannot be reverted.");
}
}