// Bitcoin Dev Kit // Written in 2020 by Alekos Filini // // Copyright (c) 2020-2021 Bitcoin Dev Kit Developers // // This file is licensed under the Apache License, Version 2.0 or the MIT license // , at your option. // You may not use this file except in accordance with one or both of these // licenses. use std::path::Path; use std::path::PathBuf; use bitcoin::consensus::encode::{deserialize, serialize}; use bitcoin::hash_types::Txid; use bitcoin::{OutPoint, Script, Transaction, TxOut}; use crate::database::{BatchDatabase, BatchOperations, Database, SyncTime}; use crate::error::Error; use crate::types::*; use rusqlite::{named_params, Connection}; static MIGRATIONS: &[&str] = &[ "CREATE TABLE version (version INTEGER)", "INSERT INTO version VALUES (1)", "CREATE TABLE script_pubkeys (keychain TEXT, child INTEGER, script BLOB);", "CREATE INDEX idx_keychain_child ON script_pubkeys(keychain, child);", "CREATE INDEX idx_script ON script_pubkeys(script);", "CREATE TABLE utxos (value INTEGER, keychain TEXT, vout INTEGER, txid BLOB, script BLOB);", "CREATE INDEX idx_txid_vout ON utxos(txid, vout);", "CREATE TABLE transactions (txid BLOB, raw_tx BLOB);", "CREATE INDEX idx_txid ON transactions(txid);", "CREATE TABLE transaction_details (txid BLOB, timestamp INTEGER, received INTEGER, sent INTEGER, fee INTEGER, height INTEGER, verified INTEGER DEFAULT 0);", "CREATE INDEX idx_txdetails_txid ON transaction_details(txid);", "CREATE TABLE last_derivation_indices (keychain TEXT, value INTEGER);", "CREATE UNIQUE INDEX idx_indices_keychain ON last_derivation_indices(keychain);", "CREATE TABLE checksums (keychain TEXT, checksum BLOB);", "CREATE INDEX idx_checksums_keychain ON checksums(keychain);", "CREATE TABLE sync_time (id INTEGER PRIMARY KEY, height INTEGER, timestamp INTEGER);", "ALTER TABLE transaction_details RENAME TO transaction_details_old;", "CREATE TABLE transaction_details (txid BLOB, timestamp INTEGER, received INTEGER, sent INTEGER, fee INTEGER, height INTEGER);", "INSERT INTO transaction_details SELECT txid, timestamp, received, sent, fee, height FROM transaction_details_old;", "DROP TABLE transaction_details_old;", "ALTER TABLE utxos ADD COLUMN is_spent;", // drop all data due to possible inconsistencies with duplicate utxos, re-sync required "DELETE FROM checksums;", "DELETE FROM last_derivation_indices;", "DELETE FROM script_pubkeys;", "DELETE FROM sync_time;", "DELETE FROM transaction_details;", "DELETE FROM transactions;", "DELETE FROM utxos;", "DROP INDEX idx_txid_vout;", "CREATE UNIQUE INDEX idx_utxos_txid_vout ON utxos(txid, vout);" ]; /// Sqlite database stored on filesystem /// /// This is a permanent storage solution for devices and platforms that provide a filesystem. /// [`crate::database`] #[derive(Debug)] pub struct SqliteDatabase { /// Path on the local filesystem to store the sqlite file pub path: PathBuf, /// A rusqlite connection object to the sqlite database pub connection: Connection, } impl SqliteDatabase { /// Instantiate a new SqliteDatabase instance by creating a connection /// to the database stored at path pub fn new>(path: T) -> Self { let connection = get_connection(&path).unwrap(); SqliteDatabase { path: PathBuf::from(path.as_ref()), connection, } } fn insert_script_pubkey( &self, keychain: String, child: u32, script: &[u8], ) -> Result { let mut statement = self.connection.prepare_cached("INSERT INTO script_pubkeys (keychain, child, script) VALUES (:keychain, :child, :script)")?; statement.execute(named_params! { ":keychain": keychain, ":child": child, ":script": script })?; Ok(self.connection.last_insert_rowid()) } fn insert_utxo( &self, value: u64, keychain: String, vout: u32, txid: &[u8], script: &[u8], is_spent: bool, ) -> Result { let mut statement = self.connection.prepare_cached("INSERT INTO utxos (value, keychain, vout, txid, script, is_spent) VALUES (:value, :keychain, :vout, :txid, :script, :is_spent) ON CONFLICT(txid, vout) DO UPDATE SET value=:value, keychain=:keychain, script=:script, is_spent=:is_spent")?; statement.execute(named_params! { ":value": value, ":keychain": keychain, ":vout": vout, ":txid": txid, ":script": script, ":is_spent": is_spent, })?; Ok(self.connection.last_insert_rowid()) } fn insert_transaction(&self, txid: &[u8], raw_tx: &[u8]) -> Result { let mut statement = self .connection .prepare_cached("INSERT INTO transactions (txid, raw_tx) VALUES (:txid, :raw_tx)")?; statement.execute(named_params! { ":txid": txid, ":raw_tx": raw_tx, })?; Ok(self.connection.last_insert_rowid()) } fn update_transaction(&self, txid: &[u8], raw_tx: &[u8]) -> Result<(), Error> { let mut statement = self .connection .prepare_cached("UPDATE transactions SET raw_tx=:raw_tx WHERE txid=:txid")?; statement.execute(named_params! { ":txid": txid, ":raw_tx": raw_tx, })?; Ok(()) } fn insert_transaction_details(&self, transaction: &TransactionDetails) -> Result { let (timestamp, height) = match &transaction.confirmation_time { Some(confirmation_time) => ( Some(confirmation_time.timestamp), Some(confirmation_time.height), ), None => (None, None), }; let txid: &[u8] = &transaction.txid; let mut statement = self.connection.prepare_cached("INSERT INTO transaction_details (txid, timestamp, received, sent, fee, height) VALUES (:txid, :timestamp, :received, :sent, :fee, :height)")?; statement.execute(named_params! { ":txid": txid, ":timestamp": timestamp, ":received": transaction.received, ":sent": transaction.sent, ":fee": transaction.fee, ":height": height, })?; Ok(self.connection.last_insert_rowid()) } fn update_transaction_details(&self, transaction: &TransactionDetails) -> Result<(), Error> { let (timestamp, height) = match &transaction.confirmation_time { Some(confirmation_time) => ( Some(confirmation_time.timestamp), Some(confirmation_time.height), ), None => (None, None), }; let txid: &[u8] = &transaction.txid; let mut statement = self.connection.prepare_cached("UPDATE transaction_details SET timestamp=:timestamp, received=:received, sent=:sent, fee=:fee, height=:height WHERE txid=:txid")?; statement.execute(named_params! { ":txid": txid, ":timestamp": timestamp, ":received": transaction.received, ":sent": transaction.sent, ":fee": transaction.fee, ":height": height, })?; Ok(()) } fn insert_last_derivation_index(&self, keychain: String, value: u32) -> Result { let mut statement = self.connection.prepare_cached( "INSERT INTO last_derivation_indices (keychain, value) VALUES (:keychain, :value)", )?; statement.execute(named_params! { ":keychain": keychain, ":value": value, })?; Ok(self.connection.last_insert_rowid()) } fn insert_checksum(&self, keychain: String, checksum: &[u8]) -> Result { let mut statement = self.connection.prepare_cached( "INSERT INTO checksums (keychain, checksum) VALUES (:keychain, :checksum)", )?; statement.execute(named_params! { ":keychain": keychain, ":checksum": checksum, })?; Ok(self.connection.last_insert_rowid()) } fn update_last_derivation_index(&self, keychain: String, value: u32) -> Result<(), Error> { let mut statement = self.connection.prepare_cached( "INSERT INTO last_derivation_indices (keychain, value) VALUES (:keychain, :value) ON CONFLICT(keychain) DO UPDATE SET value=:value WHERE keychain=:keychain", )?; statement.execute(named_params! { ":keychain": keychain, ":value": value, })?; Ok(()) } fn update_sync_time(&self, data: SyncTime) -> Result { let mut statement = self.connection.prepare_cached( "INSERT INTO sync_time (id, height, timestamp) VALUES (0, :height, :timestamp) ON CONFLICT(id) DO UPDATE SET height=:height, timestamp=:timestamp WHERE id = 0", )?; statement.execute(named_params! { ":height": data.block_time.height, ":timestamp": data.block_time.timestamp, })?; Ok(self.connection.last_insert_rowid()) } fn select_script_pubkeys(&self) -> Result, Error> { let mut statement = self .connection .prepare_cached("SELECT script FROM script_pubkeys")?; let mut scripts: Vec