diff --git a/backend/src/api/database-migration.ts b/backend/src/api/database-migration.ts new file mode 100644 index 000000000..eb00dcc53 --- /dev/null +++ b/backend/src/api/database-migration.ts @@ -0,0 +1,178 @@ +import config from '../config'; +import { DB } from '../database'; +import logger from '../logger'; + +class DatabaseMigration { + private static currentVersion = 1; + private queryTimeout = 120000; + + constructor() { } + + public async $initializeOrMigrateDatabase(): Promise { + if (!await this.$checkIfTableExists('statistics')) { + await this.$initializeDatabaseTables(); + } + + if (await this.$checkIfTableExists('state')) { + const databaseSchemaVersion = await this.$getSchemaVersionFromDatabase(); + if (DatabaseMigration.currentVersion > databaseSchemaVersion) { + await this.$migrateTableSchemaFromVersion(databaseSchemaVersion); + } + } else { + await this.$migrateTableSchemaFromVersion(0); + } + } + + private async $initializeDatabaseTables(): Promise { + const connection = await DB.pool.getConnection(); + for (const query of this.getInitializeTableQueries()) { + await connection.query({ sql: query, timeout: this.queryTimeout }); + } + connection.release(); + logger.info(`Initial database tables have been created`); + } + + private async $migrateTableSchemaFromVersion(version: number): Promise { + const connection = await DB.pool.getConnection(); + for (const query of this.getMigrationQueriesFromVersion(version)) { + await connection.query({ sql: query, timeout: this.queryTimeout }); + } + connection.release(); + await this.$updateToLatestSchemaVersion(); + logger.info(`Database schema have been migrated from version ${version} to ${DatabaseMigration.currentVersion} (latest version)`); + } + + private async $getSchemaVersionFromDatabase(): Promise { + const connection = await DB.pool.getConnection(); + const query = `SELECT number FROM state WHERE name = 'schema_version';`; + const [rows] = await connection.query({ sql: query, timeout: this.queryTimeout }); + connection.release(); + return rows[0]['number']; + } + + private async $updateToLatestSchemaVersion(): Promise { + const connection = await DB.pool.getConnection(); + const query = `UPDATE state SET number = ${DatabaseMigration.currentVersion} WHERE name = 'schema_version'`; + const [rows] = await connection.query({ sql: query, timeout: this.queryTimeout }); + connection.release(); + } + + private async $checkIfTableExists(table: string): Promise { + const connection = await DB.pool.getConnection(); + const query = `SELECT COUNT(*) FROM information_schema.tables WHERE table_schema = '${config.DATABASE.DATABASE}' AND TABLE_NAME = '${table}'`; + const [rows] = await connection.query({ sql: query, timeout: this.queryTimeout }); + connection.release(); + return rows[0]['COUNT(*)'] === 1; + } + + private getInitializeTableQueries(): string[] { + const queries: string[] = []; + + queries.push(`CREATE TABLE IF NOT EXISTS statistics ( + id int(11) NOT NULL, + added datetime NOT NULL, + unconfirmed_transactions int(11) UNSIGNED NOT NULL, + tx_per_second float UNSIGNED NOT NULL, + vbytes_per_second int(10) UNSIGNED NOT NULL, + mempool_byte_weight int(10) UNSIGNED NOT NULL, + fee_data longtext NOT NULL, + total_fee double UNSIGNED NOT NULL, + vsize_1 int(11) NOT NULL, + vsize_2 int(11) NOT NULL, + vsize_3 int(11) NOT NULL, + vsize_4 int(11) NOT NULL, + vsize_5 int(11) NOT NULL, + vsize_6 int(11) NOT NULL, + vsize_8 int(11) NOT NULL, + vsize_10 int(11) NOT NULL, + vsize_12 int(11) NOT NULL, + vsize_15 int(11) NOT NULL, + vsize_20 int(11) NOT NULL, + vsize_30 int(11) NOT NULL, + vsize_40 int(11) NOT NULL, + vsize_50 int(11) NOT NULL, + vsize_60 int(11) NOT NULL, + vsize_70 int(11) NOT NULL, + vsize_80 int(11) NOT NULL, + vsize_90 int(11) NOT NULL, + vsize_100 int(11) NOT NULL, + vsize_125 int(11) NOT NULL, + vsize_150 int(11) NOT NULL, + vsize_175 int(11) NOT NULL, + vsize_200 int(11) NOT NULL, + vsize_250 int(11) NOT NULL, + vsize_300 int(11) NOT NULL, + vsize_350 int(11) NOT NULL, + vsize_400 int(11) NOT NULL, + vsize_500 int(11) NOT NULL, + vsize_600 int(11) NOT NULL, + vsize_700 int(11) NOT NULL, + vsize_800 int(11) NOT NULL, + vsize_900 int(11) NOT NULL, + vsize_1000 int(11) NOT NULL, + vsize_1200 int(11) NOT NULL, + vsize_1400 int(11) NOT NULL, + vsize_1600 int(11) NOT NULL, + vsize_1800 int(11) NOT NULL, + vsize_2000 int(11) NOT NULL + ) ENGINE=InnoDB DEFAULT CHARSET=utf8;`); + + queries.push(`ALTER TABLE statistics ADD PRIMARY KEY (id);`); + queries.push(`ALTER TABLE statistics MODIFY id int(11) NOT NULL AUTO_INCREMENT;`); + + return queries; + } + + private getMigrationQueriesFromVersion(version: number): string[] { + const queries: string[] = []; + + if (version < 1) { + if (config.MEMPOOL.NETWORK !== 'liquid') { + queries.push(`UPDATE statistics SET + vsize_1 = vsize_1 + vsize_2, vsize_2 = vsize_3, + vsize_3 = vsize_4, vsize_4 = vsize_5, + vsize_5 = vsize_6, vsize_6 = vsize_8, + vsize_8 = vsize_10, vsize_10 = vsize_12, + vsize_12 = vsize_15, vsize_15 = vsize_20, + vsize_20 = vsize_30, vsize_30 = vsize_40, + vsize_40 = vsize_50, vsize_50 = vsize_60, + vsize_60 = vsize_70, vsize_70 = vsize_80, + vsize_80 = vsize_90, vsize_90 = vsize_100, + vsize_100 = vsize_125, vsize_125 = vsize_150, + vsize_150 = vsize_175, vsize_175 = vsize_200, + vsize_200 = vsize_250, vsize_250 = vsize_300, + vsize_300 = vsize_350, vsize_350 = vsize_400, + vsize_400 = vsize_500, vsize_500 = vsize_600, + vsize_600 = vsize_700, vsize_700 = vsize_800, + vsize_800 = vsize_900, vsize_900 = vsize_1000, + vsize_1000 = vsize_1200, vsize_1200 = vsize_1400, + vsize_1400 = vsize_1800, vsize_1800 = vsize_2000, vsize_2000 = 0`); + } + + queries.push(`CREATE TABLE IF NOT EXISTS elements_pegs ( + block int(11) NOT NULL, + datetime int(11) NOT NULL, + amount bigint(20) NOT NULL, + txid varchar(65) NOT NULL, + txindex int(11) NOT NULL, + bitcoinaddress varchar(100) NOT NULL, + bitcointxid varchar(65) NOT NULL, + bitcoinindex int(11) NOT NULL, + final_tx int(11) NOT NULL + ) ENGINE=InnoDB DEFAULT CHARSET=utf8;`); + + queries.push(`CREATE TABLE IF NOT EXISTS state ( + name varchar(25) NOT NULL, + number int(11) NULL, + string varchar(100) NULL + ) ENGINE=InnoDB DEFAULT CHARSET=utf8;`); + + queries.push(`INSERT INTO state VALUES('schema_version', 0, NULL);`); + queries.push(`INSERT INTO state VALUES('last_elements_block', 0, NULL);`); + } + + return queries; + } +} + +export default new DatabaseMigration(); diff --git a/backend/src/api/liquid/elements-parser.ts b/backend/src/api/liquid/elements-parser.ts index 37e2362e1..a2d4e1546 100644 --- a/backend/src/api/liquid/elements-parser.ts +++ b/backend/src/api/liquid/elements-parser.ts @@ -18,12 +18,12 @@ class ElementsParser { this.isRunning = true; const result = await bitcoinClient.getChainTips(); const tip = result[0].height; - const latestBlock = await this.$getLatestBlockFromDatabase(); - for (let height = latestBlock.block + 1; height <= tip; height++) { + const latestBlockHeight = await this.$getLatestBlockHeightFromDatabase(); + for (let height = latestBlockHeight + 1; height <= tip; height++) { const blockHash: IBitcoinApi.ChainTips = await bitcoinClient.getBlockHash(height); const block: IBitcoinApi.Block = await bitcoinClient.getBlock(blockHash, 2); await this.$parseBlock(block); - await this.$saveLatestBlockToDatabase(block.height, block.time, block.hash); + await this.$saveLatestBlockToDatabase(block.height); } this.isRunning = false; } catch (e) { @@ -92,18 +92,18 @@ class ElementsParser { logger.debug(`Saved L-BTC peg from block height #${height} with TXID ${txid}.`); } - protected async $getLatestBlockFromDatabase(): Promise { + protected async $getLatestBlockHeightFromDatabase(): Promise { const connection = await DB.pool.getConnection(); - const query = `SELECT block, datetime, block_hash FROM last_elements_block`; + const query = `SELECT number FROM state WHERE name = 'last_elements_block'`; const [rows] = await connection.query(query); connection.release(); - return rows[0]; + return rows[0]['number']; } - protected async $saveLatestBlockToDatabase(blockHeight: number, datetime: number, blockHash: string) { + protected async $saveLatestBlockToDatabase(blockHeight: number) { const connection = await DB.pool.getConnection(); - const query = `UPDATE last_elements_block SET block = ?, datetime = ?, block_hash = ?`; - await connection.query(query, [blockHeight, datetime, blockHash]); + const query = `UPDATE state SET number = ? WHERE name = 'last_elements_block'`; + await connection.query(query, [blockHeight]); connection.release(); } } diff --git a/backend/src/index.ts b/backend/src/index.ts index d1bd86994..78c99f016 100644 --- a/backend/src/index.ts +++ b/backend/src/index.ts @@ -21,6 +21,7 @@ import backendInfo from './api/backend-info'; import loadingIndicators from './api/loading-indicators'; import mempool from './api/mempool'; import elementsParser from './api/liquid/elements-parser'; +import databaseMigration from './api/database-migration'; import syncAssets from './sync-assets'; import icons from './api/liquid/icons'; @@ -84,6 +85,11 @@ class Server { if (config.DATABASE.ENABLED) { await checkDbConnection(); + try { + await databaseMigration.$initializeOrMigrateDatabase(); + } catch (e) { + throw new Error(e instanceof Error ? e.message : 'Error'); + } } if (config.STATISTICS.ENABLED && config.DATABASE.ENABLED && cluster.isMaster) { diff --git a/mariadb-structure.sql b/mariadb-structure.sql deleted file mode 100644 index f652a0a54..000000000 --- a/mariadb-structure.sql +++ /dev/null @@ -1,106 +0,0 @@ -SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; -SET time_zone = "+00:00"; - -CREATE TABLE `blocks` ( - `height` int(11) NOT NULL, - `hash` varchar(65) NOT NULL, - `size` int(11) NOT NULL, - `weight` int(11) NOT NULL, - `minFee` int(11) NOT NULL, - `maxFee` int(11) NOT NULL, - `time` int(11) NOT NULL, - `fees` double NOT NULL, - `nTx` int(11) NOT NULL, - `medianFee` double NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8; - -CREATE TABLE `statistics` ( - `id` int(11) NOT NULL, - `added` datetime NOT NULL, - `unconfirmed_transactions` int(11) UNSIGNED NOT NULL, - `tx_per_second` float UNSIGNED NOT NULL, - `vbytes_per_second` int(10) UNSIGNED NOT NULL, - `mempool_byte_weight` int(10) UNSIGNED NOT NULL, - `fee_data` longtext NOT NULL, - `total_fee` double UNSIGNED NOT NULL, - `vsize_1` int(11) NOT NULL, - `vsize_2` int(11) NOT NULL, - `vsize_3` int(11) NOT NULL, - `vsize_4` int(11) NOT NULL, - `vsize_5` int(11) NOT NULL, - `vsize_6` int(11) NOT NULL, - `vsize_8` int(11) NOT NULL, - `vsize_10` int(11) NOT NULL, - `vsize_12` int(11) NOT NULL, - `vsize_15` int(11) NOT NULL, - `vsize_20` int(11) NOT NULL, - `vsize_30` int(11) NOT NULL, - `vsize_40` int(11) NOT NULL, - `vsize_50` int(11) NOT NULL, - `vsize_60` int(11) NOT NULL, - `vsize_70` int(11) NOT NULL, - `vsize_80` int(11) NOT NULL, - `vsize_90` int(11) NOT NULL, - `vsize_100` int(11) NOT NULL, - `vsize_125` int(11) NOT NULL, - `vsize_150` int(11) NOT NULL, - `vsize_175` int(11) NOT NULL, - `vsize_200` int(11) NOT NULL, - `vsize_250` int(11) NOT NULL, - `vsize_300` int(11) NOT NULL, - `vsize_350` int(11) NOT NULL, - `vsize_400` int(11) NOT NULL, - `vsize_500` int(11) NOT NULL, - `vsize_600` int(11) NOT NULL, - `vsize_700` int(11) NOT NULL, - `vsize_800` int(11) NOT NULL, - `vsize_900` int(11) NOT NULL, - `vsize_1000` int(11) NOT NULL, - `vsize_1200` int(11) NOT NULL, - `vsize_1400` int(11) NOT NULL, - `vsize_1600` int(11) NOT NULL, - `vsize_1800` int(11) NOT NULL, - `vsize_2000` int(11) NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8; - -CREATE TABLE `transactions` ( - `blockheight` int(11) NOT NULL, - `txid` varchar(65) NOT NULL, - `fee` double NOT NULL, - `feePerVsize` double NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8; - - -ALTER TABLE `blocks` - ADD PRIMARY KEY (`height`); - -ALTER TABLE `statistics` - ADD PRIMARY KEY (`id`); - -ALTER TABLE `transactions` - ADD PRIMARY KEY (`txid`), - ADD KEY `blockheight` (`blockheight`); - - -ALTER TABLE `statistics` - MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; - -CREATE TABLE `last_elements_block` ( - `block` int(11) NOT NULL, - `datetime` int(11) NOT NULL, - `block_hash` varchar(65) NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8; - -INSERT INTO `last_elements_block` VALUES(0, 0, ''); - -CREATE TABLE `elements_pegs` ( - `block` int(11) NOT NULL, - `datetime` int(11) NOT NULL, - `amount` bigint(20) NOT NULL, - `txid` varchar(65) NOT NULL, - `txindex` int(11) NOT NULL, - `bitcoinaddress` varchar(100) NOT NULL, - `bitcointxid` varchar(65) NOT NULL, - `bitcoinindex` int(11) NOT NULL, - `final_tx` int(11) NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8;