mirror of
https://github.com/aljazceru/cyphernode.git
synced 2026-01-04 13:35:28 +01:00
Migrated to postgres and added pub32 tests
This commit is contained in:
164
proxy_docker/app/data/cyphernode.postgresql
Normal file
164
proxy_docker/app/data/cyphernode.postgresql
Normal file
@@ -0,0 +1,164 @@
|
||||
BEGIN;
|
||||
|
||||
CREATE TABLE watching_by_pub32 (
|
||||
id SERIAL PRIMARY KEY,
|
||||
pub32 VARCHAR UNIQUE,
|
||||
label VARCHAR UNIQUE,
|
||||
derivation_path VARCHAR,
|
||||
callback0conf VARCHAR,
|
||||
callback1conf VARCHAR,
|
||||
last_imported_n INTEGER,
|
||||
watching BOOLEAN DEFAULT FALSE,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE TABLE watching (
|
||||
id SERIAL PRIMARY KEY,
|
||||
address VARCHAR,
|
||||
label VARCHAR,
|
||||
watching BOOLEAN DEFAULT FALSE,
|
||||
callback0conf VARCHAR,
|
||||
calledback0conf BOOLEAN DEFAULT FALSE,
|
||||
callback1conf VARCHAR,
|
||||
calledback1conf BOOLEAN DEFAULT FALSE,
|
||||
imported BOOLEAN DEFAULT FALSE,
|
||||
watching_by_pub32_id INTEGER REFERENCES watching_by_pub32,
|
||||
pub32_index INTEGER,
|
||||
event_message VARCHAR,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
CREATE INDEX idx_watching_address ON watching (address);
|
||||
CREATE UNIQUE INDEX idx_watching_01 ON watching (address, COALESCE(callback0conf, ''), COALESCE(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 tx (
|
||||
id SERIAL PRIMARY KEY,
|
||||
txid VARCHAR UNIQUE,
|
||||
hash VARCHAR UNIQUE,
|
||||
confirmations INTEGER DEFAULT 0,
|
||||
timereceived INTEGER,
|
||||
fee REAL,
|
||||
size INTEGER,
|
||||
vsize INTEGER,
|
||||
is_replaceable BOOLEAN,
|
||||
blockhash VARCHAR,
|
||||
blockheight INTEGER,
|
||||
blocktime INTEGER,
|
||||
conf_target INTEGER,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
CREATE INDEX idx_tx_timereceived ON tx (timereceived);
|
||||
CREATE INDEX idx_tx_fee ON tx (fee);
|
||||
CREATE INDEX idx_tx_size ON tx (size);
|
||||
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 watching_tx (
|
||||
watching_id INTEGER REFERENCES watching,
|
||||
tx_id INTEGER REFERENCES tx,
|
||||
vout INTEGER,
|
||||
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 batcher (
|
||||
id SERIAL PRIMARY KEY,
|
||||
label VARCHAR UNIQUE,
|
||||
conf_target INTEGER,
|
||||
feerate REAL,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
INSERT INTO batcher (id, label, conf_target, feerate) VALUES (1, 'default', 6, NULL);
|
||||
|
||||
CREATE TABLE recipient (
|
||||
id SERIAL PRIMARY KEY,
|
||||
address VARCHAR,
|
||||
amount REAL,
|
||||
tx_id INTEGER REFERENCES tx,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
webhook_url VARCHAR,
|
||||
calledback BOOLEAN DEFAULT FALSE,
|
||||
calledback_ts TIMESTAMP,
|
||||
batcher_id INTEGER REFERENCES batcher,
|
||||
label VARCHAR
|
||||
);
|
||||
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 watching_by_txid (
|
||||
id SERIAL PRIMARY KEY,
|
||||
txid VARCHAR,
|
||||
watching BOOLEAN DEFAULT FALSE,
|
||||
callback1conf VARCHAR,
|
||||
calledback1conf BOOLEAN DEFAULT FALSE,
|
||||
callbackxconf VARCHAR,
|
||||
calledbackxconf BOOLEAN DEFAULT FALSE,
|
||||
nbxconf INTEGER,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
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 SERIAL PRIMARY KEY,
|
||||
hash VARCHAR UNIQUE,
|
||||
callbackUrl VARCHAR,
|
||||
requested BOOLEAN DEFAULT FALSE,
|
||||
upgraded BOOLEAN DEFAULT FALSE,
|
||||
calledback BOOLEAN DEFAULT FALSE,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
CREATE INDEX idx_stamp_calledback ON stamp (calledback);
|
||||
|
||||
CREATE TABLE cyphernode_props (
|
||||
id SERIAL PRIMARY KEY,
|
||||
property VARCHAR,
|
||||
value VARCHAR,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
CREATE INDEX idx_cp_property ON cyphernode_props (property);
|
||||
CREATE UNIQUE INDEX idx_cp_propval ON cyphernode_props (property, value);
|
||||
|
||||
INSERT INTO cyphernode_props (property, value) VALUES ('version', '0.1');
|
||||
INSERT INTO cyphernode_props (property, value) VALUES ('pay_index', '0');
|
||||
|
||||
CREATE TABLE ln_invoice (
|
||||
id SERIAL PRIMARY KEY,
|
||||
label VARCHAR UNIQUE,
|
||||
bolt11 VARCHAR UNIQUE,
|
||||
payment_hash VARCHAR,
|
||||
msatoshi INTEGER,
|
||||
status VARCHAR,
|
||||
pay_index INTEGER,
|
||||
msatoshi_received INTEGER,
|
||||
paid_at INTEGER,
|
||||
description VARCHAR,
|
||||
expires_at INTEGER,
|
||||
callback_url VARCHAR,
|
||||
calledback BOOLEAN DEFAULT FALSE,
|
||||
callback_failed BOOLEAN DEFAULT FALSE,
|
||||
inserted_ts TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
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);
|
||||
|
||||
COMMIT;
|
||||
@@ -1,27 +0,0 @@
|
||||
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);
|
||||
@@ -1,17 +1,14 @@
|
||||
#!/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 "Checking for new indexes in DB..."
|
||||
sqlite3 $DB_FILE ".indexes" | grep "idx_watching_watching" > /dev/null
|
||||
if [ "$?" -eq "1" ]; then
|
||||
# idx_watching_watching index not found
|
||||
echo "Migrating database with new indexes..."
|
||||
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!"
|
||||
echo "New indexes migration already done, skipping!"
|
||||
fi
|
||||
|
||||
36
proxy_docker/app/data/sqlmigrate20211105_0.7.0-0.8.0.sh
Normal file
36
proxy_docker/app/data/sqlmigrate20211105_0.7.0-0.8.0.sh
Normal file
@@ -0,0 +1,36 @@
|
||||
#!/bin/sh
|
||||
|
||||
echo "Waiting for postgres to be ready..."
|
||||
(while true ; do psql -h postgres -U cyphernode -c "select 1;" ; [ "$?" -eq "0" ] && break ; sleep 10; done) &
|
||||
wait
|
||||
|
||||
echo "Checking if postgres is setup..."
|
||||
psql -h postgres -U cyphernode -c "\d" | grep "cyphernode_props" > /dev/null
|
||||
if [ "$?" -eq "1" ]; then
|
||||
# if cyphernode_props table doesn't exist, it's probably because database hasn't been setup yet
|
||||
echo "Creating postgres database..."
|
||||
psql -h postgres -f cyphernode.postgresql -U cyphernode
|
||||
|
||||
echo "Extracting and converting sqlite3 data..."
|
||||
cat sqlmigrate20211105_0.7.0-0.8.0_sqlite3-extract.sql | sqlite3 $DB_FILE
|
||||
sed -ie 's/^\(INSERT.*\);$/\1 ON CONFLICT DO NOTHING;/g' sqlmigrate20211105_0.7.0-0.8.0_sqlite3-extracted-data.sql
|
||||
|
||||
echo "...appending postgresql sequences..."
|
||||
echo "
|
||||
select setval('cyphernode_props_id_seq', (SELECT MAX(id) FROM cyphernode_props));
|
||||
select setval('ln_invoice_id_seq', (SELECT MAX(id) FROM ln_invoice));
|
||||
select setval('recipient_id_seq', (SELECT MAX(id) FROM recipient));
|
||||
select setval('stamp_id_seq', (SELECT MAX(id) FROM stamp));
|
||||
select setval('tx_id_seq', (SELECT MAX(id) FROM tx));
|
||||
select setval('watching_by_pub32_id_seq', (SELECT MAX(id) FROM watching_by_pub32));
|
||||
select setval('watching_by_txid_id_seq', (SELECT MAX(id) FROM watching_by_txid));
|
||||
select setval('watching_id_seq', (SELECT MAX(id) FROM watching));
|
||||
select setval('batcher_id_seq', (SELECT MAX(id) FROM batcher));
|
||||
commit;
|
||||
" >> sqlmigrate20211105_0.7.0-0.8.0_sqlite3-extracted-data.sql
|
||||
|
||||
echo "Importing sqlite3 data into postgresql..."
|
||||
psql -h postgres -f sqlmigrate20211105_0.7.0-0.8.0_sqlite3-extracted-data.sql -U cyphernode
|
||||
else
|
||||
echo "New indexes migration already done, skipping!"
|
||||
fi
|
||||
@@ -0,0 +1,24 @@
|
||||
.output sqlmigrate20211105_0.7.0-0.8.0_sqlite3-extracted-data.sql
|
||||
select "BEGIN;";
|
||||
.headers on
|
||||
.mode insert watching_by_pub32
|
||||
select id,pub32,label,derivation_path,callback0conf,callback1conf,last_imported_n,case when watching=1 then 'TRUE' else 'FALSE' end as watching,inserted_ts from watching_by_pub32;
|
||||
.mode insert watching
|
||||
select id,address,label,case when watching=1 then 'TRUE' else 'FALSE' end as watching,callback0conf,case when calledback0conf=1 then 'TRUE' else 'FALSE' end as calledback0conf,callback1conf,case when calledback1conf=1 then 'TRUE' else 'FALSE' end as calledback1conf,case when imported=1 then 'TRUE' else 'FALSE' end as imported,watching_by_pub32_id,pub32_index,event_message,inserted_ts from watching;
|
||||
.mode insert tx
|
||||
select id,txid,hash,confirmations,timereceived,fee,size,vsize,case when is_replaceable=1 then 'TRUE' else 'FALSE' end as is_replaceable,blockhash,blockheight,blocktime,conf_target,inserted_ts from tx;
|
||||
.mode insert watching_tx
|
||||
select * from watching_tx;
|
||||
.mode insert batcher
|
||||
select * from batcher;
|
||||
.mode insert recipient
|
||||
select id,address,amount,tx_id,inserted_ts,webhook_url,case when calledback=1 then 'TRUE' else 'FALSE' end as calledback,calledback_ts,batcher_id,label from recipient;
|
||||
.mode insert watching_by_txid
|
||||
select id,txid,case when watching=1 then 'TRUE' else 'FALSE' end as watching,callback1conf,case when calledback1conf=1 then 'TRUE' else 'FALSE' end as calledback1conf,callbackxconf,case when calledbackxconf=1 then 'TRUE' else 'FALSE' end as calledbackxconf,nbxconf,inserted_ts from watching_by_txid;
|
||||
.mode insert stamp
|
||||
select id,hash,callbackUrl,case when requested=1 then 'TRUE' else 'FALSE' end as requested,case when upgraded=1 then 'TRUE' else 'FALSE' end as upgraded,case when calledback=1 then 'TRUE' else 'FALSE' end as calledback,inserted_ts from stamp;
|
||||
.mode insert cyphernode_props
|
||||
select * from cyphernode_props;
|
||||
.mode insert ln_invoice
|
||||
select id,label,bolt11,payment_hash,msatoshi,status,pay_index,msatoshi_received,paid_at,description,expires_at,callback_url,case when calledback=1 then 'TRUE' else 'FALSE' end as calledback,case when callback_failed=1 then 'TRUE' else 'FALSE' end as callback_failed,inserted_ts from ln_invoice;
|
||||
.quit
|
||||
Reference in New Issue
Block a user