From 23caf87e3018ba4826ccd753e815fb260c1c3408 Mon Sep 17 00:00:00 2001 From: kexkey Date: Thu, 7 Oct 2021 12:43:53 -0400 Subject: [PATCH] Optimized db with new indexes, added rawtx db --- proxy_docker/app/data/cyphernode.sql | 17 +++++++++ proxy_docker/app/data/rawtx.sql | 27 ++++++++++++++ .../data/sqlmigrate20210928_0.7.0-0.8.0.sh | 17 +++++++++ .../data/sqlmigrate20210928_0.7.0-0.8.0.sql | 25 +++++++++++++ proxy_docker/app/script/batching.sh | 9 ++++- proxy_docker/app/script/computefees.sh | 7 ++-- proxy_docker/app/script/confirmation.sh | 11 +++++- proxy_docker/app/script/sql.sh | 12 +++++-- proxy_docker/app/script/startproxy.sh | 36 ++++++++++--------- proxy_docker/app/script/walletoperations.sh | 4 ++- 10 files changed, 141 insertions(+), 24 deletions(-) create mode 100644 proxy_docker/app/data/rawtx.sql create mode 100644 proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sh create mode 100644 proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sql diff --git a/proxy_docker/app/data/cyphernode.sql b/proxy_docker/app/data/cyphernode.sql index 17a18d6..2f8ae80 100644 --- a/proxy_docker/app/data/cyphernode.sql +++ b/proxy_docker/app/data/cyphernode.sql @@ -30,6 +30,9 @@ CREATE TABLE watching ( CREATE INDEX idx_watching_address ON watching (address); CREATE UNIQUE INDEX idx_watching_01 ON watching (address, callback0conf, callback1conf); CREATE INDEX idx_watching_label ON watching (label); +CREATE INDEX idx_watching_watching ON watching (watching); +CREATE INDEX idx_watching_imported ON watching (imported); +CREATE INDEX idx_watching_watching_by_pub32_id ON watching (watching_by_pub32_id); CREATE TABLE watching_tx ( watching_id INTEGER REFERENCES watching, @@ -38,6 +41,8 @@ CREATE TABLE watching_tx ( amount REAL ); CREATE UNIQUE INDEX idx_watching_tx ON watching_tx (watching_id, tx_id); +CREATE INDEX idx_watching_tx_watching_id ON watching_tx (watching_id); +CREATE INDEX idx_watching_tx_tx_id ON watching_tx (tx_id); CREATE TABLE tx ( id INTEGER PRIMARY KEY AUTOINCREMENT, @@ -63,6 +68,7 @@ CREATE INDEX idx_tx_vsize ON tx (vsize); CREATE INDEX idx_tx_blockhash ON tx (blockhash); CREATE INDEX idx_tx_blockheight ON tx (blockheight); CREATE INDEX idx_tx_blocktime ON tx (blocktime); +CREATE INDEX idx_tx_confirmations ON tx (confirmations); CREATE TABLE recipient ( id INTEGER PRIMARY KEY AUTOINCREMENT, @@ -78,6 +84,10 @@ CREATE TABLE recipient ( ); CREATE INDEX idx_recipient_address ON recipient (address); CREATE INDEX idx_recipient_label ON recipient (label); +CREATE INDEX idx_recipient_calledback ON recipient (calledback); +CREATE INDEX idx_recipient_webhook_url ON recipient (webhook_url); +CREATE INDEX idx_recipient_tx_id ON recipient (tx_id); +CREATE INDEX idx_recipient_batcher_id ON recipient (batcher_id); CREATE TABLE batcher ( id INTEGER PRIMARY KEY AUTOINCREMENT, @@ -101,6 +111,11 @@ CREATE TABLE watching_by_txid ( ); CREATE INDEX idx_watching_by_txid_txid ON watching_by_txid (txid); CREATE UNIQUE INDEX idx_watching_by_txid_1x ON watching_by_txid (txid, callback1conf, callbackxconf); +CREATE INDEX idx_watching_by_txid_watching ON watching_by_txid (watching); +CREATE INDEX idx_watching_by_txid_callback1conf ON watching_by_txid (callback1conf); +CREATE INDEX idx_watching_by_txid_calledback1conf ON watching_by_txid (calledback1conf); +CREATE INDEX idx_watching_by_txid_callbackxconf ON watching_by_txid (callbackxconf); +CREATE INDEX idx_watching_by_txid_calledbackxconf ON watching_by_txid (calledbackxconf); CREATE TABLE stamp ( id INTEGER PRIMARY KEY AUTOINCREMENT, @@ -143,3 +158,5 @@ CREATE TABLE ln_invoice ( ); CREATE INDEX idx_lninvoice_label ON ln_invoice (label); CREATE INDEX idx_lninvoice_bolt11 ON ln_invoice (bolt11); +CREATE INDEX idx_lninvoice_calledback ON ln_invoice (calledback); +CREATE INDEX idx_lninvoice_callback_failed ON ln_invoice (callback_failed); diff --git a/proxy_docker/app/data/rawtx.sql b/proxy_docker/app/data/rawtx.sql new file mode 100644 index 0000000..1028845 --- /dev/null +++ b/proxy_docker/app/data/rawtx.sql @@ -0,0 +1,27 @@ +PRAGMA foreign_keys = ON; + +CREATE TABLE rawtx ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + txid TEXT UNIQUE, + hash TEXT UNIQUE, + confirmations INTEGER DEFAULT 0, + timereceived INTEGER, + fee REAL, + size INTEGER, + vsize INTEGER, + is_replaceable INTEGER, + blockhash TEXT, + blockheight INTEGER, + blocktime INTEGER, + conf_target INTEGER, + raw_tx TEXT, + inserted_ts INTEGER DEFAULT CURRENT_TIMESTAMP +); +CREATE INDEX idx_rawtx_timereceived ON rawtx (timereceived); +CREATE INDEX idx_rawtx_fee ON rawtx (fee); +CREATE INDEX idx_rawtx_size ON rawtx (size); +CREATE INDEX idx_rawtx_vsize ON rawtx (vsize); +CREATE INDEX idx_rawtx_blockhash ON rawtx (blockhash); +CREATE INDEX idx_rawtx_blockheight ON rawtx (blockheight); +CREATE INDEX idx_rawtx_blocktime ON rawtx (blocktime); +CREATE INDEX idx_rawtx_confirmations ON rawtx (confirmations); diff --git a/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sh b/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sh new file mode 100644 index 0000000..1b62004 --- /dev/null +++ b/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sh @@ -0,0 +1,17 @@ +#!/bin/sh + +echo "Checking for rawtx database support in DB..." +if [ ! -e ${DB_FILE}_rawtx ]; then + # rawtx database not found + echo "Migrating database for rawtx database support..." + echo "Backing up current DB..." + cp $DB_FILE $DB_FILE-sqlmigrate20210928_0.7.0-0.8.0 + echo "Altering DB..." + cat sqlmigrate20210928_0.7.0-0.8.0.sql | sqlite3 $DB_FILE + echo "Creating new DB..." + cat rawtx.sql | sqlite3 ${DB_FILE}_rawtx + echo "Inserting table in new DB..." + sqlite3 -cmd ".timeout 25000" ${DB_FILE} "ATTACH DATABASE \"${DB_FILE}_rawtx\" AS other; INSERT INTO other.rawtx SELECT * FROM tx; DETACH other;" +else + echo "rawtx database support migration already done, skipping!" +fi diff --git a/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sql b/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sql new file mode 100644 index 0000000..187da94 --- /dev/null +++ b/proxy_docker/app/data/sqlmigrate20210928_0.7.0-0.8.0.sql @@ -0,0 +1,25 @@ +PRAGMA foreign_keys=off; + +BEGIN TRANSACTION; + +CREATE INDEX idx_watching_watching ON watching (watching); +CREATE INDEX idx_watching_imported ON watching (imported); +CREATE INDEX idx_watching_watching_by_pub32_id ON watching (watching_by_pub32_id); +CREATE INDEX idx_watching_tx_watching_id ON watching_tx (watching_id); +CREATE INDEX idx_watching_tx_tx_id ON watching_tx (tx_id); +CREATE INDEX idx_tx_confirmations ON tx (confirmations); +CREATE INDEX idx_recipient_calledback ON recipient (calledback); +CREATE INDEX idx_recipient_webhook_url ON recipient (webhook_url); +CREATE INDEX idx_recipient_tx_id ON recipient (tx_id); +CREATE INDEX idx_recipient_batcher_id ON recipient (batcher_id); +CREATE INDEX idx_watching_by_txid_watching ON watching_by_txid (watching); +CREATE INDEX idx_watching_by_txid_callback1conf ON watching_by_txid (callback1conf); +CREATE INDEX idx_watching_by_txid_calledback1conf ON watching_by_txid (calledback1conf); +CREATE INDEX idx_watching_by_txid_callbackxconf ON watching_by_txid (callbackxconf); +CREATE INDEX idx_watching_by_txid_calledbackxconf ON watching_by_txid (calledbackxconf); +CREATE INDEX idx_lninvoice_calledback ON ln_invoice (calledback); +CREATE INDEX idx_lninvoice_callback_failed ON ln_invoice (callback_failed); + +COMMIT; + +PRAGMA foreign_keys=on; diff --git a/proxy_docker/app/script/batching.sh b/proxy_docker/app/script/batching.sh index 79f9242..427d9a4 100644 --- a/proxy_docker/app/script/batching.sh +++ b/proxy_docker/app/script/batching.sh @@ -196,6 +196,9 @@ addtobatch() { else # Check if address already pending for this batcher... inserted_id=$(sql "SELECT id FROM recipient WHERE LOWER(address)=LOWER(\"${address}\") AND tx_id IS NULL AND batcher_id=${batcher_id}") + returncode=$? + trace_rc ${returncode} + if [ -n "${inserted_id}" ]; then response='{"result":null,"error":{"code":-32700,"message":"Duplicated address","data":'${request}'}}' @@ -465,9 +468,13 @@ batchspend() { # Get the info on the batch before setting it to done row=$(sql "SELECT COUNT(id), COALESCE(MIN(inserted_ts), 0), COALESCE(SUM(amount), 0.00000000) FROM recipient WHERE tx_id IS NULL AND batcher_id=${batcher_id}") + returncode=$? + trace_rc ${returncode} # Let's insert the txid in our little DB -- then we'll already have it when receiving confirmation - id_inserted=$(sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target, raw_tx) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target}, readfile('batchspend-rawtx-${txid}-$$.blob')); SELECT LAST_INSERT_ROWID();") + sql_rawtx "INSERT OR IGNORE INTO rawtx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target, raw_tx) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target}, readfile('batchspend-rawtx-${txid}-$$.blob'))" + trace_rc $? + id_inserted=$(sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target}); SELECT LAST_INSERT_ROWID();") returncode=$? trace_rc ${returncode} if [ "${returncode}" -eq 0 ]; then diff --git a/proxy_docker/app/script/computefees.sh b/proxy_docker/app/script/computefees.sh index be35197..04d2dee 100644 --- a/proxy_docker/app/script/computefees.sh +++ b/proxy_docker/app/script/computefees.sh @@ -65,7 +65,8 @@ compute_vin_total_amount() do vin_txid=$(echo "${vin_txid_vout}" | tr -d '"' | cut -d '-' -f1) # Check if we already have the tx in our DB - vin_raw_tx=$(sql "SELECT raw_tx FROM tx WHERE txid=\"${vin_txid}\"") + vin_raw_tx=$(sql_rawtx "SELECT raw_tx FROM rawtx WHERE txid=\"${vin_txid}\"") + trace_rc $? if [ -z "${vin_raw_tx}" ]; then txid_already_inserted=false vin_raw_tx=$(get_rawtransaction "${vin_txid}" | tr -d '\n') @@ -94,7 +95,9 @@ compute_vin_total_amount() # Sometimes raw tx are too long to be passed as paramater, so let's write # it to a temp file for it to be read by sqlite3 and then delete the file echo "${vin_raw_tx}" > vin-rawtx-${vin_txid}-$$.blob - sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, size, vsize, blockhash, blockheight, blocktime, raw_tx) VALUES (\"${vin_txid}\", ${vin_hash}, ${vin_confirmations}, ${vin_timereceived}, ${vin_size}, ${vin_vsize}, ${vin_blockhash}, ${vin_blockheight}, ${vin_blocktime}, readfile('vin-rawtx-${vin_txid}-$$.blob'))" + sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, size, vsize, blockhash, blockheight, blocktime) VALUES (\"${vin_txid}\", ${vin_hash}, ${vin_confirmations}, ${vin_timereceived}, ${vin_size}, ${vin_vsize}, ${vin_blockhash}, ${vin_blockheight}, ${vin_blocktime})" + trace_rc $? + sql_rawtx "INSERT OR IGNORE INTO rawtx (txid, hash, confirmations, timereceived, size, vsize, blockhash, blockheight, blocktime, raw_tx) VALUES (\"${vin_txid}\", ${vin_hash}, ${vin_confirmations}, ${vin_timereceived}, ${vin_size}, ${vin_vsize}, ${vin_blockhash}, ${vin_blockheight}, ${vin_blocktime}, readfile('vin-rawtx-${vin_txid}-$$.blob'))" trace_rc $? rm vin-rawtx-${vin_txid}-$$.blob txid_already_inserted=true diff --git a/proxy_docker/app/script/confirmation.sh b/proxy_docker/app/script/confirmation.sh index b03d36f..4dd81d0 100644 --- a/proxy_docker/app/script/confirmation.sh +++ b/proxy_docker/app/script/confirmation.sh @@ -105,7 +105,9 @@ confirmation() { tx_blocktime=$(echo "${tx_details}" | jq '.result.blocktime') fi - sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, blockhash, blockheight, blocktime, raw_tx) VALUES (\"${txid}\", ${tx_hash}, ${tx_nb_conf}, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${tx_blockhash}, ${tx_blockheight}, ${tx_blocktime}, readfile('rawtx-${txid}-$$.blob'))" + sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, blockhash, blockheight, blocktime) VALUES (\"${txid}\", ${tx_hash}, ${tx_nb_conf}, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${tx_blockhash}, ${tx_blockheight}, ${tx_blocktime})" + trace_rc $? + sql_rawtx "INSERT OR IGNORE INTO rawtx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, blockhash, blockheight, blocktime, raw_tx) VALUES (\"${txid}\", ${tx_hash}, ${tx_nb_conf}, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${tx_blockhash}, ${tx_blockheight}, ${tx_blocktime}, readfile('rawtx-${txid}-$$.blob'))" trace_rc $? id_inserted=$(sql "SELECT id FROM tx WHERE txid=\"${txid}\"") @@ -124,6 +126,13 @@ confirmation() { local tx_blocktime=$(echo "${tx_details}" | jq '.result.blocktime') sql "UPDATE tx SET + confirmations=${tx_nb_conf}, + blockhash=${tx_blockhash}, + blockheight=${tx_blockheight}, + blocktime=${tx_blocktime} + WHERE txid=\"${txid}\"" + trace_rc $? + sql_rawtx "UPDATE rawtx SET confirmations=${tx_nb_conf}, blockhash=${tx_blockhash}, blockheight=${tx_blockheight}, diff --git a/proxy_docker/app/script/sql.sh b/proxy_docker/app/script/sql.sh index e410c7f..9bad35b 100644 --- a/proxy_docker/app/script/sql.sh +++ b/proxy_docker/app/script/sql.sh @@ -3,8 +3,16 @@ . ./trace.sh sql() { - trace "sqlite3 -cmd \".timeout 20000\" ${DB_FILE} \"${1}\"" - sqlite3 -cmd ".timeout 20000" ${DB_FILE} "${1}" + trace "sqlite3 -cmd \".timeout 25000\" ${DB_FILE} \"${1}\"" + sqlite3 -cmd ".timeout 25000" ${DB_FILE} "${1}" +# sqlite3 ${DB_FILE} "PRAGMA busy_timeout=20000; ${1}" + + return $? +} + +sql_rawtx() { + trace "sqlite3 -cmd \".timeout 25000\" ${DB_FILE}_rawtx \"${1}\"" + sqlite3 -cmd ".timeout 25000" ${DB_FILE}_rawtx "${1}" # sqlite3 ${DB_FILE} "PRAGMA busy_timeout=20000; ${1}" return $? diff --git a/proxy_docker/app/script/startproxy.sh b/proxy_docker/app/script/startproxy.sh index a865012..d4d3c1f 100644 --- a/proxy_docker/app/script/startproxy.sh +++ b/proxy_docker/app/script/startproxy.sh @@ -10,37 +10,39 @@ export DB_PATH export DB_FILE trim() { - echo -e "$1" | sed -e 's/^[[:space:]]*//' | sed -e 's/[[:space:]]*$//' + echo -e "$1" | sed -e 's/^[[:space:]]*//' | sed -e 's/[[:space:]]*$//' } createCurlConfig() { - if [[ ''$1 == '' ]]; then - echo "Missing file name: Check you *_BTC_NODE_RPC_CFG" - return - fi + if [[ ''$1 == '' ]]; then + echo "Missing file name: Check your *_BTC_NODE_RPC_CFG" + return + fi - if [[ ''$2 == '' ]]; then - echo "Missing content: Check you *_BTC_NODE_RPC_USER" - return - fi + if [[ ''$2 == '' ]]; then + echo "Missing content: Check your *_BTC_NODE_RPC_USER" + return + fi - local user=$( trim $2 ) - echo "user=${user}" > ${1} + local user=$( trim $2 ) + echo "user=${user}" > ${1} } if [ ! -e ${DB_FILE} ]; then - echo "DB not found, creating..." - cat cyphernode.sql | sqlite3 $DB_FILE + echo "DB not found, creating..." + cat cyphernode.sql | sqlite3 $DB_FILE + cat rawtx.sql | sqlite3 ${DB_FILE}_rawtx else - echo "DB found, migrating..." - for script in sqlmigrate*.sh; do - sh $script - done + echo "DB found, migrating..." + for script in sqlmigrate*.sh; do + sh $script + done fi chmod 0600 $DB_FILE +chmod 0600 ${DB_FILE}_rawtx createCurlConfig ${WATCHER_BTC_NODE_RPC_CFG} ${WATCHER_BTC_NODE_RPC_USER} createCurlConfig ${SPENDER_BTC_NODE_RPC_CFG} ${SPENDER_BTC_NODE_RPC_USER} diff --git a/proxy_docker/app/script/walletoperations.sh b/proxy_docker/app/script/walletoperations.sh index 4036476..b734270 100644 --- a/proxy_docker/app/script/walletoperations.sh +++ b/proxy_docker/app/script/walletoperations.sh @@ -73,7 +73,9 @@ spend() { ######################################################################################################## # Let's insert the txid in our little DB -- then we'll already have it when receiving confirmation - sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target, raw_tx) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target}, readfile('spend-rawtx-${txid}-$$.blob'))" + sql "INSERT OR IGNORE INTO tx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target})" + trace_rc $? + sql_rawtx "INSERT OR IGNORE INTO rawtx (txid, hash, confirmations, timereceived, fee, size, vsize, is_replaceable, conf_target, raw_tx) VALUES (\"${txid}\", ${tx_hash}, 0, ${tx_ts_firstseen}, ${fees}, ${tx_size}, ${tx_vsize}, ${tx_replaceable}, ${conf_target}, readfile('spend-rawtx-${txid}-$$.blob'))" trace_rc $? id_inserted=$(sql "SELECT id FROM tx WHERE txid=\"${txid}\"") trace_rc $?