From 85390cb8cea36dd7d915104f2a948f5cbb8d02cb Mon Sep 17 00:00:00 2001 From: Kris Nuttycombe Date: Wed, 5 Oct 2022 12:59:52 -0600 Subject: [PATCH] Add more information to v_transactions, v_sent_tx, and v_received_tx This adds sent and received note count information, transaction fees, account information, and makes the information returned about sent notes and received notes consistent with one another. --- zcash_client_sqlite/src/wallet/init.rs | 78 +++++++++++------ .../src/wallet/init/migrations.rs | 15 +++- .../init/migrations/add_transaction_views.rs | 87 +++++++++++++------ .../init/migrations/sent_notes_to_internal.rs | 6 +- .../wallet/init/migrations/ufvk_support.rs | 4 +- 5 files changed, 129 insertions(+), 61 deletions(-) diff --git a/zcash_client_sqlite/src/wallet/init.rs b/zcash_client_sqlite/src/wallet/init.rs index cb50cb77c..f6cfa91a4 100644 --- a/zcash_client_sqlite/src/wallet/init.rs +++ b/zcash_client_sqlite/src/wallet/init.rs @@ -380,7 +380,7 @@ mod tests { "CREATE TABLE \"sent_notes\" ( id_note INTEGER PRIMARY KEY, tx INTEGER NOT NULL, - output_pool INTEGER NOT NULL , + output_pool INTEGER NOT NULL, output_index INTEGER NOT NULL, from_account INTEGER NOT NULL, to_address TEXT, @@ -438,16 +438,22 @@ mod tests { } let expected_views = vec![ + // v_transactions "CREATE VIEW v_transactions AS - SELECT id_tx, - mined_height, - tx_index, - txid, - expiry_height, - raw, - SUM(value) + MAX(fee) AS net_value, - SUM(is_change) > 0 AS has_change, - SUM(memo_present) AS memo_count + SELECT notes.id_tx, + notes.mined_height, + notes.tx_index, + notes.txid, + notes.expiry_height, + notes.raw, + SUM(notes.value) + MAX(notes.fee) AS net_value, + MAX(notes.fee) AS fee_paid, + SUM(notes.is_wallet_internal) > 0 AS is_wallet_internal, + SUM(notes.is_change) > 0 AS has_change, + SUM(notes.sent_count) AS sent_note_count, + SUM(notes.received_count) AS received_note_count, + SUM(notes.memo_present) AS memo_count, + blocks.time AS block_time FROM ( SELECT transactions.id_tx AS id_tx, transactions.block AS mined_height, @@ -460,7 +466,16 @@ mod tests { WHEN received_notes.is_change THEN 0 ELSE value END AS value, - received_notes.is_change AS is_change, + 0 AS is_wallet_internal, + CASE + WHEN received_notes.is_change THEN 1 + ELSE 0 + END AS is_change, + CASE + WHEN received_notes.is_change THEN 0 + ELSE 1 + END AS received_count, + 0 AS sent_count, CASE WHEN received_notes.memo IS NULL THEN 0 ELSE 1 @@ -476,20 +491,31 @@ mod tests { transactions.raw AS raw, transactions.fee AS fee, -sent_notes.value AS value, - false AS is_change, + CASE + WHEN sent_notes.from_account = sent_notes.to_account THEN 1 + ELSE 0 + END AS is_wallet_internal, + 0 AS is_change, + 0 AS received_count, + 1 AS sent_count, CASE WHEN sent_notes.memo IS NULL THEN 0 ELSE 1 END AS memo_present FROM transactions JOIN sent_notes ON transactions.id_tx = sent_notes.tx - ) - GROUP BY id_tx", + ) AS notes + LEFT JOIN blocks ON notes.mined_height = blocks.height + GROUP BY notes.id_tx", + // v_tx_received "CREATE VIEW v_tx_received AS SELECT transactions.id_tx AS id_tx, transactions.block AS mined_height, transactions.tx_index AS tx_index, transactions.txid AS txid, + transactions.expiry_height AS expiry_height, + transactions.raw AS raw, + MAX(received_notes.account) AS received_by_account, SUM(received_notes.value) AS received_total, COUNT(received_notes.id_note) AS received_note_count, SUM( @@ -504,29 +530,31 @@ mod tests { ON transactions.id_tx = received_notes.tx LEFT JOIN blocks ON transactions.block = blocks.height - GROUP BY received_notes.tx", + GROUP BY received_notes.tx, received_notes.account", + // v_tx_received "CREATE VIEW v_tx_sent AS - SELECT transactions.id_tx AS id_tx, - transactions.block AS mined_height, - transactions.tx_index AS tx_index, - transactions.txid AS txid, - transactions.expiry_height AS expiry_height, - transactions.raw AS raw, - SUM(sent_notes.value) AS sent_total, - COUNT(sent_notes.id_note) AS sent_note_count, + SELECT transactions.id_tx AS id_tx, + transactions.block AS mined_height, + transactions.tx_index AS tx_index, + transactions.txid AS txid, + transactions.expiry_height AS expiry_height, + transactions.raw AS raw, + MAX(sent_notes.from_account) AS sent_from_account, + SUM(sent_notes.value) AS sent_total, + COUNT(sent_notes.id_note) AS sent_note_count, SUM( CASE WHEN sent_notes.memo IS NULL THEN 0 ELSE 1 END ) AS memo_count, - blocks.time AS block_time + blocks.time AS block_time FROM transactions JOIN sent_notes ON transactions.id_tx = sent_notes.tx LEFT JOIN blocks ON transactions.block = blocks.height - GROUP BY sent_notes.tx", + GROUP BY sent_notes.tx, sent_notes.from_account", ]; let mut views_query = db_data diff --git a/zcash_client_sqlite/src/wallet/init/migrations.rs b/zcash_client_sqlite/src/wallet/init/migrations.rs index a5b122f17..c1fbd0f38 100644 --- a/zcash_client_sqlite/src/wallet/init/migrations.rs +++ b/zcash_client_sqlite/src/wallet/init/migrations.rs @@ -16,6 +16,15 @@ pub(super) fn all_migrations( params: &P, seed: Option>, ) -> Vec>> { + // initial_setup + // / \ + // utxos_table ufvk_support ---------- + // \ \ \ + // \ addresses_table sent_notes_to_internal + // \ / / + // add_utxo_account / + // \ / + // add_transaction_views vec![ Box::new(initial_setup::Migration {}), Box::new(utxos_table::Migration {}), @@ -26,12 +35,12 @@ pub(super) fn all_migrations( Box::new(addresses_table::Migration { params: params.clone(), }), - Box::new(add_transaction_views::Migration { - params: params.clone(), - }), Box::new(add_utxo_account::Migration { _params: params.clone(), }), Box::new(sent_notes_to_internal::Migration {}), + Box::new(add_transaction_views::Migration { + params: params.clone(), + }), ] } diff --git a/zcash_client_sqlite/src/wallet/init/migrations/add_transaction_views.rs b/zcash_client_sqlite/src/wallet/init/migrations/add_transaction_views.rs index 081353d64..8fa1ab23a 100644 --- a/zcash_client_sqlite/src/wallet/init/migrations/add_transaction_views.rs +++ b/zcash_client_sqlite/src/wallet/init/migrations/add_transaction_views.rs @@ -14,7 +14,7 @@ use zcash_primitives::{ }, }; -use super::{ufvk_support, utxos_table}; +use super::{add_utxo_account, sent_notes_to_internal}; use crate::wallet::init::WalletMigrationError; pub(super) const MIGRATION_ID: Uuid = Uuid::from_fields( @@ -34,7 +34,7 @@ impl

schemer::Migration for Migration

{ } fn dependencies(&self) -> HashSet { - [ufvk_support::MIGRATION_ID, utxos_table::MIGRATION_ID] + [add_utxo_account::MIGRATION_ID, sent_notes_to_internal::MIGRATION_ID] .into_iter() .collect() } @@ -146,32 +146,39 @@ impl RusqliteMigration for Migration

{ transaction.execute_batch( "CREATE VIEW v_tx_sent AS - SELECT transactions.id_tx AS id_tx, - transactions.block AS mined_height, - transactions.tx_index AS tx_index, - transactions.txid AS txid, - transactions.expiry_height AS expiry_height, - transactions.raw AS raw, - SUM(sent_notes.value) AS sent_total, - COUNT(sent_notes.id_note) AS sent_note_count, + SELECT transactions.id_tx AS id_tx, + transactions.block AS mined_height, + transactions.tx_index AS tx_index, + transactions.txid AS txid, + transactions.expiry_height AS expiry_height, + transactions.raw AS raw, + MAX(sent_notes.from_account) AS sent_from_account, + SUM(sent_notes.value) AS sent_total, + COUNT(sent_notes.id_note) AS sent_note_count, SUM( CASE WHEN sent_notes.memo IS NULL THEN 0 ELSE 1 END ) AS memo_count, - blocks.time AS block_time + blocks.time AS block_time FROM transactions JOIN sent_notes ON transactions.id_tx = sent_notes.tx LEFT JOIN blocks ON transactions.block = blocks.height - GROUP BY sent_notes.tx; - CREATE VIEW v_tx_received AS + GROUP BY sent_notes.tx, sent_notes.from_account;", + )?; + + transaction.execute_batch( + "CREATE VIEW v_tx_received AS SELECT transactions.id_tx AS id_tx, transactions.block AS mined_height, transactions.tx_index AS tx_index, transactions.txid AS txid, + transactions.expiry_height AS expiry_height, + transactions.raw AS raw, + MAX(received_notes.account) AS received_by_account, SUM(received_notes.value) AS received_total, COUNT(received_notes.id_note) AS received_note_count, SUM( @@ -186,17 +193,25 @@ impl RusqliteMigration for Migration

{ ON transactions.id_tx = received_notes.tx LEFT JOIN blocks ON transactions.block = blocks.height - GROUP BY received_notes.tx; - CREATE VIEW v_transactions AS - SELECT id_tx, - mined_height, - tx_index, - txid, - expiry_height, - raw, - SUM(value) + MAX(fee) AS net_value, - SUM(is_change) > 0 AS has_change, - SUM(memo_present) AS memo_count + GROUP BY received_notes.tx, received_notes.account;", + )?; + + transaction.execute_batch( + "CREATE VIEW v_transactions AS + SELECT notes.id_tx, + notes.mined_height, + notes.tx_index, + notes.txid, + notes.expiry_height, + notes.raw, + SUM(notes.value) + MAX(notes.fee) AS net_value, + MAX(notes.fee) AS fee_paid, + SUM(notes.is_wallet_internal) > 0 AS is_wallet_internal, + SUM(notes.is_change) > 0 AS has_change, + SUM(notes.sent_count) AS sent_note_count, + SUM(notes.received_count) AS received_note_count, + SUM(notes.memo_present) AS memo_count, + blocks.time AS block_time FROM ( SELECT transactions.id_tx AS id_tx, transactions.block AS mined_height, @@ -209,7 +224,16 @@ impl RusqliteMigration for Migration

{ WHEN received_notes.is_change THEN 0 ELSE value END AS value, - received_notes.is_change AS is_change, + 0 AS is_wallet_internal, + CASE + WHEN received_notes.is_change THEN 1 + ELSE 0 + END AS is_change, + CASE + WHEN received_notes.is_change THEN 0 + ELSE 1 + END AS received_count, + 0 AS sent_count, CASE WHEN received_notes.memo IS NULL THEN 0 ELSE 1 @@ -225,15 +249,22 @@ impl RusqliteMigration for Migration

{ transactions.raw AS raw, transactions.fee AS fee, -sent_notes.value AS value, - false AS is_change, + CASE + WHEN sent_notes.from_account = sent_notes.to_account THEN 1 + ELSE 0 + END AS is_wallet_internal, + 0 AS is_change, + 0 AS received_count, + 1 AS sent_count, CASE WHEN sent_notes.memo IS NULL THEN 0 ELSE 1 END AS memo_present FROM transactions JOIN sent_notes ON transactions.id_tx = sent_notes.tx - ) - GROUP BY id_tx;", + ) AS notes + LEFT JOIN blocks ON notes.mined_height = blocks.height + GROUP BY notes.id_tx;", )?; Ok(()) diff --git a/zcash_client_sqlite/src/wallet/init/migrations/sent_notes_to_internal.rs b/zcash_client_sqlite/src/wallet/init/migrations/sent_notes_to_internal.rs index c67777660..3030c4421 100644 --- a/zcash_client_sqlite/src/wallet/init/migrations/sent_notes_to_internal.rs +++ b/zcash_client_sqlite/src/wallet/init/migrations/sent_notes_to_internal.rs @@ -7,7 +7,7 @@ use schemer; use schemer_rusqlite::RusqliteMigration; use uuid::Uuid; -use super::{addresses_table, utxos_table}; +use super::{ufvk_support}; use crate::wallet::init::WalletMigrationError; /// This migration adds the `to_account` field to the `sent_notes` table. @@ -28,7 +28,7 @@ impl schemer::Migration for Migration { } fn dependencies(&self) -> HashSet { - [utxos_table::MIGRATION_ID, addresses_table::MIGRATION_ID] + [ufvk_support::MIGRATION_ID] .into_iter() .collect() } @@ -48,7 +48,7 @@ impl RusqliteMigration for Migration { "CREATE TABLE sent_notes_new ( id_note INTEGER PRIMARY KEY, tx INTEGER NOT NULL, - output_pool INTEGER NOT NULL , + output_pool INTEGER NOT NULL, output_index INTEGER NOT NULL, from_account INTEGER NOT NULL, to_address TEXT, diff --git a/zcash_client_sqlite/src/wallet/init/migrations/ufvk_support.rs b/zcash_client_sqlite/src/wallet/init/migrations/ufvk_support.rs index e4774bda8..2142079aa 100644 --- a/zcash_client_sqlite/src/wallet/init/migrations/ufvk_support.rs +++ b/zcash_client_sqlite/src/wallet/init/migrations/ufvk_support.rs @@ -19,7 +19,7 @@ use zcash_primitives::legacy::keys::IncomingViewingKey; use zcash_client_backend::encoding::AddressCodec; use crate::wallet::{ - init::{migrations::utxos_table, WalletMigrationError}, + init::{migrations::initial_setup, WalletMigrationError}, pool_code, }; @@ -41,7 +41,7 @@ impl

schemer::Migration for Migration

{ } fn dependencies(&self) -> HashSet { - [utxos_table::MIGRATION_ID].into_iter().collect() + [initial_setup::MIGRATION_ID].into_iter().collect() } fn description(&self) -> &'static str {