Skip to content

Commit

Permalink
zcash_client_sqlite: Initial pass at documenting table structures
Browse files Browse the repository at this point in the history
Co-authored-by: Kris Nuttycombe <kris@nutty.land>
  • Loading branch information
str4d and nuttycom committed Jun 18, 2024
1 parent 3599c6a commit 39bf4ca
Showing 1 changed file with 152 additions and 0 deletions.
152 changes: 152 additions & 0 deletions zcash_client_sqlite/src/wallet/db.rs
Original file line number Diff line number Diff line change
@@ -1,9 +1,19 @@
//! Documentation about the wallet database structure.
//!
//! The database structure is managed by [`crate::wallet::init::init_wallet_db`], which
//! applies migrations (defined in `crate::wallet::init::migrations`) that produce the
//! current structure.
//!
//! The SQL code in this module's constants encodes the current database structure, as
//! represented internally by SQLite. We do not use these constants at runtime; instead we
//! check the output of the migrations in `crate::wallet::init::tests::verify_schema`, to
//! pin the expected database structure.

// The constants in this module are only used in tests, but `#[cfg(test)]` prevents them
// from showing up in `cargo doc --document-private-items`.
#![allow(dead_code)]

/// Stores information about the accounts that the wallet is tracking.
pub(super) const TABLE_ACCOUNTS: &str = r#"
CREATE TABLE "accounts" (
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
Expand Down Expand Up @@ -41,6 +51,12 @@ pub(super) const INDEX_ACCOUNTS_UIVK: &str =
pub(super) const INDEX_HD_ACCOUNT: &str =
r#"CREATE UNIQUE INDEX hd_account ON "accounts" (hd_seed_fingerprint, hd_account_index)"#;

/// Stores diversified Unified Addresses that have been generated from accounts in the
/// wallet.
///
/// - The `cached_transparent_receiver_address` column contains the transparent receiver
/// component of the UA. It is cached directly in the table to make account lookups for
/// transparent outputs more efficient, enabling joins to [`TABLE_UTXOS`].
pub(super) const TABLE_ADDRESSES: &str = r#"
CREATE TABLE "addresses" (
account_id INTEGER NOT NULL,
Expand All @@ -55,6 +71,11 @@ CREATE INDEX "addresses_accounts" ON "addresses" (
"account_id" ASC
)"#;

/// Stores information about every block that the wallet has scanned.
///
/// Note that this table does not contain any rows for blocks that the wallet might have
/// observed partial information about (for example, a transparent output fetched and
/// stored in [`TABLE_UTXOS`]). This may change in future.
pub(super) const TABLE_BLOCKS: &str = "
CREATE TABLE blocks (
height INTEGER PRIMARY KEY,
Expand All @@ -66,6 +87,17 @@ CREATE TABLE blocks (
sapling_output_count INTEGER,
orchard_action_count INTEGER)";

/// Stores the wallet's transactions.
///
/// Any transactions that the wallet observes as "belonging to" one of the accounts in
/// [`TABLE_ACCOUNTS`] may be tracked in this table. As a result, this table may contain
/// data that is not recoverable from the chain (for example, transactions created by the
/// wallet that expired before being mined).
///
/// - The `block` column stores the height (in the wallet's chain view) of the mined block
/// containing the transaction. It is `NULL` for transactions that have not yet been
/// observed in scanned blocks, including transactions in the mempool or that have
/// expired.
pub(super) const TABLE_TRANSACTIONS: &str = "
CREATE TABLE transactions (
id_tx INTEGER PRIMARY KEY,
Expand All @@ -79,6 +111,9 @@ CREATE TABLE transactions (
FOREIGN KEY (block) REFERENCES blocks(height)
)";

/// Stores the Sapling notes received by the wallet.
///
/// Note spentness is tracked in [`TABLE_SAPLING_RECEIVED_NOTE_SPENDS`].
pub(super) const TABLE_SAPLING_RECEIVED_NOTES: &str = r#"
CREATE TABLE "sapling_received_notes" (
id INTEGER PRIMARY KEY,
Expand Down Expand Up @@ -106,6 +141,15 @@ CREATE INDEX "sapling_received_notes_tx" ON "sapling_received_notes" (
"tx" ASC
)"#;

/// A junction table between received Sapling notes and the transactions that spend them.
///
/// Only one mined transaction can spend a note. However, transactions created by the
/// wallet may expire before being mined, and the wallet still tracks the fact that the
/// user created the transaction. The junction table enables the "spent-in" relationship
/// between notes and expired transactions to be preserved; note spent-ness is determined
/// by joining this table with [`TABLE_TRANSACTIONS`] and then filtering out transactions
/// where either `transactions.block` is non-null, or `transactions.expiry_height` is not
/// greater than the wallet's view of the chain tip.
pub(super) const TABLE_SAPLING_RECEIVED_NOTE_SPENDS: &str = "
CREATE TABLE sapling_received_note_spends (
sapling_received_note_id INTEGER NOT NULL,
Expand All @@ -119,6 +163,9 @@ CREATE TABLE sapling_received_note_spends (
UNIQUE (sapling_received_note_id, transaction_id)
)";

/// Stores the Orchard notes received by the wallet.
///
/// Note spentness is tracked in [`TABLE_ORCHARD_RECEIVED_NOTE_SPENDS`].
pub(super) const TABLE_ORCHARD_RECEIVED_NOTES: &str = "
CREATE TABLE orchard_received_notes (
id INTEGER PRIMARY KEY,
Expand Down Expand Up @@ -147,6 +194,10 @@ CREATE INDEX orchard_received_notes_tx ON orchard_received_notes (
tx ASC
)"#;

/// A junction table between received Orchard notes and the transactions that spend them.
///
/// This is identical to [`TABLE_SAPLING_RECEIVED_NOTE_SPENDS`]; see its documentation for
/// details.
pub(super) const TABLE_ORCHARD_RECEIVED_NOTE_SPENDS: &str = "
CREATE TABLE orchard_received_note_spends (
orchard_received_note_id INTEGER NOT NULL,
Expand All @@ -160,6 +211,19 @@ CREATE TABLE orchard_received_note_spends (
UNIQUE (orchard_received_note_id, transaction_id)
)";

/// Stores the current UTXO set for the wallet, as well as any transparent outputs
/// previously observed by the wallet.
///
/// Originally this table only stored the current UTXO set (as of latest refresh), and the
/// table was cleared prior to loading in the latest UTXO set. We now upsert instead of
/// insert into the database, meaning that spent outputs are left in the database. This
/// makes it similar to the `*_received_notes` tables in that it can store history, but
/// has several downsides:
/// - The table has incomplete contents for recovered-from-seed wallets.
/// - The table can have inconsistent contents for seeds loaded into multiple wallets
/// simultaneously.
/// - The wallet's transparent balance can be incorrect prior to "transaction enhancement"
/// (downloading the full transaction containing the transparent output spend).
pub(super) const TABLE_UTXOS: &str = r#"
CREATE TABLE "utxos" (
id INTEGER PRIMARY KEY,
Expand All @@ -176,6 +240,13 @@ CREATE TABLE "utxos" (
pub(super) const INDEX_UTXOS_RECEIVED_BY_ACCOUNT: &str =
r#"CREATE INDEX utxos_received_by_account ON "utxos" (received_by_account_id)"#;

/// A junction table between received transparent outputs and the transactions that spend
/// them.
///
/// This is identical to [`TABLE_SAPLING_RECEIVED_NOTE_SPENDS`]; see its documentation for
/// details. Note however that [`TABLE_UTXOS`] and [`TABLE_SAPLING_RECEIVED_NOTES`] are
/// not equivalent, and care must be taken when interpreting the result of joining this
/// table to [`TABLE_UTXOS`].
pub(super) const TABLE_TRANSPARENT_RECEIVED_OUTPUT_SPENDS: &str = "
CREATE TABLE transparent_received_output_spends (
transparent_received_output_id INTEGER NOT NULL,
Expand All @@ -189,6 +260,12 @@ CREATE TABLE transparent_received_output_spends (
UNIQUE (transparent_received_output_id, transaction_id)
)";

/// Stores the outputs of transactions created by the wallet.
///
/// Unlike with outputs received by the wallet, we store sent outputs for all pools in
/// this table, distinguished by the `output_pool` column. The information we want to
/// record for sent outputs is the same across all pools, whereas for received outputs we
/// want to cache pool-specific data.
pub(super) const TABLE_SENT_NOTES: &str = r#"
CREATE TABLE "sent_notes" (
id INTEGER PRIMARY KEY,
Expand Down Expand Up @@ -218,6 +295,13 @@ pub(super) const INDEX_SENT_NOTES_TX: &str = r#"CREATE INDEX sent_notes_tx ON "s
// State for shard trees
//

/// Stores the shards of a [`ShardTree`] for the Sapling commitment tree.
///
/// This table contains a row for each 2^16 subtree of the Sapling note commitment tree,
/// keyed by the index of the shard. The `shard_data` column contains the subtree's data
/// as serialized by [`zcash_client_backend::serialization::shardtree::write_shard`].
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_SAPLING_TREE_SHARDS: &str = "
CREATE TABLE sapling_tree_shards (
shard_index INTEGER PRIMARY KEY,
Expand All @@ -228,6 +312,13 @@ CREATE TABLE sapling_tree_shards (
CONSTRAINT root_unique UNIQUE (root_hash)
)";

/// Stores the "cap" of the Sapling [`ShardTree`].
///
/// This table will only ever have a single row, in which is serialized the 2^16 "cap"
/// of the Sapling note commitment tree, The `cap_data` column contains the cap data
/// as serialized by [`zcash_client_backend::serialization::shardtree::write_shard`].
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_SAPLING_TREE_CAP: &str = "
CREATE TABLE sapling_tree_cap (
-- cap_id exists only to be able to take advantage of `ON CONFLICT`
Expand All @@ -236,12 +327,25 @@ CREATE TABLE sapling_tree_cap (
cap_data BLOB NOT NULL
)";

/// Stores the checkpointed positions in the Sapling [`ShardTree`].
///
/// Each row in this table stores the note commitment tree position of the last Sapling
/// output in the block having height `checkpoint_id`.
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_SAPLING_TREE_CHECKPOINTS: &str = "
CREATE TABLE sapling_tree_checkpoints (
checkpoint_id INTEGER PRIMARY KEY,
position INTEGER
)";

/// Stores metadata about the positions of Sapling notes that have been spent but for
/// which witness information has not yet been removed from the note commitment tree.
///
/// In the process of updating the note commitment tree in response to the addition of
/// a block, it is necessary to temporarily continue to store witness information for
/// each note so that a spent note can be made spendable again after a rollback of the
/// spending block. This table caches the metadata needed for that restoration.
pub(super) const TABLE_SAPLING_TREE_CHECKPOINT_MARKS_REMOVED: &str = "
CREATE TABLE sapling_tree_checkpoint_marks_removed (
checkpoint_id INTEGER NOT NULL,
Expand All @@ -251,6 +355,11 @@ CREATE TABLE sapling_tree_checkpoint_marks_removed (
CONSTRAINT spend_position_unique UNIQUE (checkpoint_id, mark_removed_position)
)";

/// Stores the shards of a [`ShardTree`] for the Orchard commitment tree.
///
/// This is identical to [`TABLE_SAPLING_TREE_SHARDS`]; see its documentation for details.
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_ORCHARD_TREE_SHARDS: &str = "
CREATE TABLE orchard_tree_shards (
shard_index INTEGER PRIMARY KEY,
Expand All @@ -261,6 +370,11 @@ CREATE TABLE orchard_tree_shards (
CONSTRAINT root_unique UNIQUE (root_hash)
)";

/// Stores the "cap" of the Orchard [`ShardTree`].
///
/// This is identical to [`TABLE_SAPLING_TREE_CAP`]; see its documentation for details.
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_ORCHARD_TREE_CAP: &str = "
CREATE TABLE orchard_tree_cap (
-- cap_id exists only to be able to take advantage of `ON CONFLICT`
Expand All @@ -269,12 +383,23 @@ CREATE TABLE orchard_tree_cap (
cap_data BLOB NOT NULL
)";

/// Stores the checkpointed positions in the Orchard [`ShardTree`].
///
/// This is identical to [`TABLE_SAPLING_TREE_CHECKPOINTS`]; see its documentation for
/// details.
///
/// [`ShardTree`]: shardtree::ShardTree
pub(super) const TABLE_ORCHARD_TREE_CHECKPOINTS: &str = "
CREATE TABLE orchard_tree_checkpoints (
checkpoint_id INTEGER PRIMARY KEY,
position INTEGER
)";

/// Stores metadata about the positions of Orchard notes that have been spent but for
/// which witness information has not yet been removed from the note commitment tree.
///
/// This is identical to [`TABLE_SAPLING_TREE_CHECKPOINT_MARKS_REMOVED`]; see its
/// documentation for details.
pub(super) const TABLE_ORCHARD_TREE_CHECKPOINT_MARKS_REMOVED: &str = "
CREATE TABLE orchard_tree_checkpoint_marks_removed (
checkpoint_id INTEGER NOT NULL,
Expand All @@ -288,6 +413,9 @@ CREATE TABLE orchard_tree_checkpoint_marks_removed (
// Scanning
//

/// Stores the [`ScanPriority`] for all block ranges in the wallet's view of the chain.
///
/// [`ScanPriority`]: zcash_client_backend::data_api::scanning::ScanPriority
pub(super) const TABLE_SCAN_QUEUE: &str = "
CREATE TABLE scan_queue (
block_range_start INTEGER NOT NULL,
Expand All @@ -300,6 +428,14 @@ CREATE TABLE scan_queue (
)
)";

/// A map from "transaction locators" to transaction IDs for the current chain state.
///
/// `(block_height, tx_index)` is a "transaction locator"; `tx_index` is an index into the
/// list of transactions for the block at height `block_height` in the chain as currently
/// known to the wallet.
///
/// No foreign key constraint is enforced for `block_height` to [`TABLE_BLOCKS`], to allow
/// loading the nullifier map separately from block scanning.
pub(super) const TABLE_TX_LOCATOR_MAP: &str = "
CREATE TABLE tx_locator_map (
block_height INTEGER NOT NULL,
Expand All @@ -308,6 +444,21 @@ CREATE TABLE tx_locator_map (
PRIMARY KEY (block_height, tx_index)
)";

/// A map from nullifiers to the transaction they were observed in.
///
/// The purpose of this map is to allow non-linear scanning. If the wallet scans a block
/// range `Y..Z` that leaves a gap between the wallet's birthday height and `Y`, then the
/// wallet must assume that any nullifier observed in `Y..Z` might be spending one of its
/// notes (that it has not yet observed), otherwise it will fail to detect those spends
/// and report a too-large balance. Once the wallet has scanned every block between its
/// birthday height and `Y`, the nullifier map contents up to `Z` is no longer necessary
/// and can be dropped.
///
/// The map stores transaction locators instead of transaction IDs for efficiency. SQLite
/// will represent the transaction locator in at most 6 bytes, so a transaction that only
/// spends one shielded note will incur a 12-byte overhead (across both this table and
/// [`TABLE_TX_LOCATOR_MAP`]), but each additional spent note in a transaction saves 26
/// bytes.
pub(super) const TABLE_NULLIFIER_MAP: &str = "
CREATE TABLE nullifier_map (
spend_pool INTEGER NOT NULL,
Expand All @@ -328,6 +479,7 @@ pub(super) const INDEX_NF_MAP_LOCATOR_IDX: &str =
// Internal tables
//

/// Internal table used by [`schemer`] to manage migrations.
pub(super) const TABLE_SCHEMER_MIGRATIONS: &str = "
CREATE TABLE schemer_migrations (
id blob PRIMARY KEY
Expand Down

0 comments on commit 39bf4ca

Please sign in to comment.