mempool/backend/src/repositories/BlocksRepository.ts

565 lines
17 KiB
TypeScript
Raw Normal View History

import { BlockExtended } from '../mempool.interfaces';
import DB from '../database';
import logger from '../logger';
2022-02-09 11:41:05 +01:00
import { Common } from '../api/common';
2022-03-16 17:00:06 +01:00
import { prepareBlock } from '../utils/blocks-utils';
2022-03-25 06:22:22 +01:00
import PoolsRepository from './PoolsRepository';
import HashratesRepository from './HashratesRepository';
class BlocksRepository {
/**
* Save indexed block data in the database
*/
2022-02-08 07:47:43 +01:00
public async $saveBlockInDatabase(block: BlockExtended) {
try {
const query = `INSERT INTO blocks(
height, hash, blockTimestamp, size,
weight, tx_count, coinbase_raw, difficulty,
pool_id, fees, fee_span, median_fee,
reward, version, bits, nonce,
merkle_root, previous_block_hash, avg_fee, avg_fee_rate
) VALUE (
?, ?, FROM_UNIXTIME(?), ?,
?, ?, ?, ?,
2022-02-08 07:47:43 +01:00
?, ?, ?, ?,
?, ?, ?, ?,
?, ?, ?, ?
)`;
const params: any[] = [
block.height,
2022-02-08 07:47:43 +01:00
block.id,
block.timestamp,
block.size,
block.weight,
block.tx_count,
block.extras.coinbaseRaw,
block.difficulty,
block.extras.pool?.id, // Should always be set to something
block.extras.totalFees,
JSON.stringify(block.extras.feeRange),
block.extras.medianFee,
block.extras.reward,
block.version,
block.bits,
block.nonce,
block.merkle_root,
block.previousblockhash,
block.extras.avgFee,
block.extras.avgFeeRate,
];
2022-04-12 08:15:57 +02:00
await DB.query(query, params);
} catch (e: any) {
2022-04-13 09:29:52 +02:00
if (e.errno === 1062) { // ER_DUP_ENTRY - This scenario is possible upon node backend restart
logger.debug(`$saveBlockInDatabase() - Block ${block.height} has already been indexed, ignoring`);
} else {
2022-04-13 09:29:52 +02:00
logger.err('Cannot save indexed block into db. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
}
/**
* Get all block height that have not been indexed between [startHeight, endHeight]
*/
public async $getMissingBlocksBetweenHeights(startHeight: number, endHeight: number): Promise<number[]> {
if (startHeight < endHeight) {
return [];
}
try {
2022-04-12 08:15:57 +02:00
const [rows]: any[] = await DB.query(`
SELECT height
FROM blocks
WHERE height <= ? AND height >= ?
ORDER BY height DESC;
`, [startHeight, endHeight]);
const indexedBlockHeights: number[] = [];
rows.forEach((row: any) => { indexedBlockHeights.push(row.height); });
const seekedBlocks: number[] = Array.from(Array(startHeight - endHeight + 1).keys(), n => n + endHeight).reverse();
const missingBlocksHeights = seekedBlocks.filter(x => indexedBlockHeights.indexOf(x) === -1);
return missingBlocksHeights;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot retrieve blocks list to index. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
/**
2022-02-09 11:41:05 +01:00
* Get empty blocks for one or all pools
*/
public async $countEmptyBlocks(poolId: number | null, interval: string | null = null): Promise<any> {
2022-02-09 11:41:05 +01:00
interval = Common.getSqlInterval(interval);
const params: any[] = [];
let query = `SELECT count(height) as count, pools.id as poolId
FROM blocks
JOIN pools on pools.id = blocks.pool_id
2022-02-09 11:41:05 +01:00
WHERE tx_count = 1`;
if (poolId) {
query += ` AND pool_id = ?`;
params.push(poolId);
}
if (interval) {
query += ` AND blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP by pools.id`;
try {
2022-04-12 08:15:57 +02:00
const [rows] = await DB.query(query, params);
return rows;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot count empty blocks. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
/**
* Get blocks count for a period
*/
public async $blockCount(poolId: number | null, interval: string | null = null): Promise<number> {
2022-02-09 11:41:05 +01:00
interval = Common.getSqlInterval(interval);
2022-02-09 11:41:05 +01:00
const params: any[] = [];
let query = `SELECT count(height) as blockCount
FROM blocks`;
if (poolId) {
query += ` WHERE pool_id = ?`;
params.push(poolId);
}
if (interval) {
if (poolId) {
query += ` AND`;
} else {
query += ` WHERE`;
}
query += ` blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
try {
2022-04-12 08:15:57 +02:00
const [rows] = await DB.query(query, params);
return <number>rows[0].blockCount;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err(`Cannot count blocks for this pool (using offset). Reason: ` + (e instanceof Error ? e.message : e));
throw e;
}
}
2022-02-19 12:45:02 +01:00
/**
* Get blocks count between two dates
2022-03-16 17:00:06 +01:00
* @param poolId
2022-02-19 12:45:02 +01:00
* @param from - The oldest timestamp
* @param to - The newest timestamp
2022-03-16 17:00:06 +01:00
* @returns
2022-02-19 12:45:02 +01:00
*/
public async $blockCountBetweenTimestamp(poolId: number | null, from: number, to: number): Promise<number> {
const params: any[] = [];
let query = `SELECT
count(height) as blockCount,
max(height) as lastBlockHeight
FROM blocks`;
if (poolId) {
query += ` WHERE pool_id = ?`;
params.push(poolId);
}
if (poolId) {
query += ` AND`;
} else {
query += ` WHERE`;
}
query += ` blockTimestamp BETWEEN FROM_UNIXTIME('${from}') AND FROM_UNIXTIME('${to}')`;
2022-02-19 12:45:02 +01:00
try {
2022-04-12 08:15:57 +02:00
const [rows] = await DB.query(query, params);
return <number>rows[0];
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err(`Cannot count blocks for this pool (using timestamps). Reason: ` + (e instanceof Error ? e.message : e));
throw e;
}
2022-02-19 12:45:02 +01:00
}
/**
* Get blocks count for a period
*/
public async $blockCountBetweenHeight(startHeight: number, endHeight: number): Promise<number> {
const params: any[] = [];
let query = `SELECT count(height) as blockCount
FROM blocks
WHERE height <= ${startHeight} AND height >= ${endHeight}`;
try {
const [rows] = await DB.query(query, params);
return <number>rows[0].blockCount;
} catch (e) {
logger.err(`Cannot count blocks for this pool (using offset). Reason: ` + (e instanceof Error ? e.message : e));
throw e;
}
}
/**
* Get the oldest indexed block
*/
public async $oldestBlockTimestamp(): Promise<number> {
const query = `SELECT UNIX_TIMESTAMP(blockTimestamp) as blockTimestamp
FROM blocks
ORDER BY height
2022-02-09 11:41:05 +01:00
LIMIT 1;`;
try {
2022-04-12 08:15:57 +02:00
const [rows]: any[] = await DB.query(query);
if (rows.length <= 0) {
return -1;
}
return <number>rows[0].blockTimestamp;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot get oldest indexed block timestamp. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
2022-02-08 07:47:43 +01:00
/**
* Get blocks mined by a specific mining pool
*/
2022-04-12 08:15:57 +02:00
public async $getBlocksByPool(slug: string, startHeight?: number): Promise<object[]> {
2022-03-25 06:22:22 +01:00
const pool = await PoolsRepository.$getPool(slug);
if (!pool) {
throw new Error(`This mining pool does not exist`);
}
2022-02-09 11:41:05 +01:00
const params: any[] = [];
2022-03-16 17:00:06 +01:00
let query = ` SELECT *, UNIX_TIMESTAMP(blocks.blockTimestamp) as blockTimestamp,
previous_block_hash as previousblockhash
FROM blocks
2022-02-09 11:41:05 +01:00
WHERE pool_id = ?`;
2022-03-25 06:22:22 +01:00
params.push(pool.id);
2022-02-09 11:41:05 +01:00
if (startHeight !== undefined) {
2022-02-09 11:41:05 +01:00
query += ` AND height < ?`;
params.push(startHeight);
}
2022-02-09 11:41:05 +01:00
query += ` ORDER BY height DESC
LIMIT 10`;
try {
2022-04-12 08:15:57 +02:00
const [rows] = await DB.query(query, params);
2022-03-16 17:00:06 +01:00
const blocks: BlockExtended[] = [];
2022-04-12 08:15:57 +02:00
for (const block of <object[]>rows) {
2022-03-16 17:00:06 +01:00
blocks.push(prepareBlock(block));
}
2022-02-09 11:41:05 +01:00
2022-03-16 17:00:06 +01:00
return blocks;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot get blocks for this pool. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
2022-02-08 07:47:43 +01:00
/**
* Get one block by height
*/
public async $getBlockByHeight(height: number): Promise<object | null> {
try {
2022-04-12 08:15:57 +02:00
const [rows]: any[] = await DB.query(`
2022-03-11 14:54:34 +01:00
SELECT *, UNIX_TIMESTAMP(blocks.blockTimestamp) as blockTimestamp,
2022-03-25 06:22:22 +01:00
pools.id as pool_id, pools.name as pool_name, pools.link as pool_link, pools.slug as pool_slug,
2022-03-11 14:54:34 +01:00
pools.addresses as pool_addresses, pools.regexes as pool_regexes,
previous_block_hash as previousblockhash
FROM blocks
JOIN pools ON blocks.pool_id = pools.id
WHERE height = ${height};
`);
if (rows.length <= 0) {
return null;
}
2022-02-08 07:47:43 +01:00
return rows[0];
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err(`Cannot get indexed block ${height}. Reason: ` + (e instanceof Error ? e.message : e));
throw e;
2022-02-08 07:47:43 +01:00
}
}
2022-02-16 13:20:28 +01:00
/**
* Return blocks difficulty
*/
public async $getBlocksDifficulty(interval: string | null): Promise<object[]> {
2022-02-16 13:20:28 +01:00
interval = Common.getSqlInterval(interval);
// :D ... Yeah don't ask me about this one https://stackoverflow.com/a/40303162
// Basically, using temporary user defined fields, we are able to extract all
// difficulty adjustments from the blocks tables.
// This allow use to avoid indexing it in another table.
let query = `
SELECT
*
2022-03-16 17:00:06 +01:00
FROM
(
SELECT
UNIX_TIMESTAMP(blockTimestamp) as timestamp, difficulty, height,
IF(@prevStatus = YT.difficulty, @rn := @rn + 1,
IF(@prevStatus := YT.difficulty, @rn := 1, @rn := 1)
) AS rn
FROM blocks YT
2022-03-16 17:00:06 +01:00
CROSS JOIN
(
SELECT @prevStatus := -1, @rn := 1
) AS var
`;
2022-02-16 13:20:28 +01:00
if (interval) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += `
ORDER BY YT.height
) AS t
WHERE t.rn = 1
ORDER BY t.height
`;
2022-02-16 13:20:28 +01:00
try {
2022-04-12 08:15:57 +02:00
const [rows]: any[] = await DB.query(query);
2022-02-16 13:20:28 +01:00
for (const row of rows) {
delete row['rn'];
}
return rows;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot generate difficulty history. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
2022-02-16 13:20:28 +01:00
}
/**
* Get general block stats
*/
public async $getBlockStats(blockCount: number): Promise<any> {
try {
// We need to use a subquery
const query = `
SELECT MIN(height) as startBlock, MAX(height) as endBlock, SUM(reward) as totalReward, SUM(fees) as totalFee, SUM(tx_count) as totalTx
FROM
(SELECT height, reward, fees, tx_count FROM blocks
ORDER by height DESC
LIMIT ?) as sub`;
2022-04-12 08:15:57 +02:00
const [rows]: any = await DB.query(query, [blockCount]);
return rows[0];
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot generate reward stats. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
/*
* Check if the last 10 blocks chain is valid
*/
public async $validateRecentBlocks(): Promise<boolean> {
try {
2022-04-12 08:15:57 +02:00
const [lastBlocks]: any[] = await DB.query(`SELECT height, hash, previous_block_hash FROM blocks ORDER BY height DESC LIMIT 10`);
for (let i = 0; i < lastBlocks.length - 1; ++i) {
if (lastBlocks[i].previous_block_hash !== lastBlocks[i + 1].hash) {
2022-04-13 09:29:52 +02:00
logger.warn(`Chain divergence detected at block ${lastBlocks[i].height}, re-indexing most recent data`);
return false;
}
}
return true;
} catch (e) {
return true; // Don't do anything if there is a db error
}
}
/**
* Check if the chain of block hash is valid and delete data from the stale branch if needed
*/
public async $validateChain(): Promise<boolean> {
try {
const start = new Date().getTime();
const [blocks]: any[] = await DB.query(`SELECT height, hash, previous_block_hash,
UNIX_TIMESTAMP(blockTimestamp) as timestamp FROM blocks ORDER BY height`);
let currentHeight = 1;
while (currentHeight < blocks.length) {
if (blocks[currentHeight].previous_block_hash !== blocks[currentHeight - 1].hash) {
logger.warn(`Chain divergence detected at block ${blocks[currentHeight - 1].height}, re-indexing newer blocks and hashrates`);
await this.$deleteBlocksFrom(blocks[currentHeight - 1].height);
await HashratesRepository.$deleteHashratesFromTimestamp(blocks[currentHeight - 1].timestamp - 604800);
return false;
}
++currentHeight;
}
logger.info(`${currentHeight} blocks hash validated in ${new Date().getTime() - start} ms`);
return true;
} catch (e) {
logger.err('Cannot validate chain of block hash. Reason: ' + (e instanceof Error ? e.message : e));
return true; // Don't do anything if there is a db error
}
}
/**
* Delete blocks from the database from blockHeight
*/
public async $deleteBlocksFrom(blockHeight: number) {
logger.info(`Delete newer blocks from height ${blockHeight} from the database`);
try {
await DB.query(`DELETE FROM blocks where height >= ${blockHeight}`);
} catch (e) {
logger.err('Cannot delete indexed blocks. Reason: ' + (e instanceof Error ? e.message : e));
}
}
2022-04-08 18:07:13 +02:00
/**
2022-04-13 09:29:52 +02:00
* Get the historical averaged block fees
2022-04-08 18:07:13 +02:00
*/
public async $getHistoricalBlockFees(div: number, interval: string | null): Promise<any> {
try {
2022-04-14 17:21:38 +02:00
let query = `SELECT
CAST(AVG(height) as INT) as avg_height,
CAST(AVG(UNIX_TIMESTAMP(blockTimestamp)) as INT) as timestamp,
2022-04-08 18:07:13 +02:00
CAST(AVG(fees) as INT) as avg_fees
FROM blocks`;
if (interval !== null) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP BY UNIX_TIMESTAMP(blockTimestamp) DIV ${div}`;
2022-04-12 08:15:57 +02:00
const [rows]: any = await DB.query(query);
2022-04-08 18:07:13 +02:00
return rows;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot generate block fees history. Reason: ' + (e instanceof Error ? e.message : e));
2022-04-08 18:07:13 +02:00
throw e;
}
}
2022-04-11 13:57:13 +02:00
/**
* Get the historical averaged block rewards
*/
public async $getHistoricalBlockRewards(div: number, interval: string | null): Promise<any> {
try {
2022-04-14 17:21:38 +02:00
let query = `SELECT
CAST(AVG(height) as INT) as avg_height,
CAST(AVG(UNIX_TIMESTAMP(blockTimestamp)) as INT) as timestamp,
2022-04-11 13:57:13 +02:00
CAST(AVG(reward) as INT) as avg_rewards
FROM blocks`;
if (interval !== null) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP BY UNIX_TIMESTAMP(blockTimestamp) DIV ${div}`;
2022-04-12 08:15:57 +02:00
const [rows]: any = await DB.query(query);
2022-04-11 13:57:13 +02:00
return rows;
} catch (e) {
2022-04-13 09:29:52 +02:00
logger.err('Cannot generate block rewards history. Reason: ' + (e instanceof Error ? e.message : e));
2022-04-11 13:57:13 +02:00
throw e;
}
}
/**
* Get the historical averaged block fee rate percentiles
*/
public async $getHistoricalBlockFeeRates(div: number, interval: string | null): Promise<any> {
try {
2022-04-14 17:21:38 +02:00
let query = `SELECT
CAST(AVG(height) as INT) as avg_height,
CAST(AVG(UNIX_TIMESTAMP(blockTimestamp)) as INT) as timestamp,
CAST(AVG(JSON_EXTRACT(fee_span, '$[0]')) as INT) as avg_fee_0,
CAST(AVG(JSON_EXTRACT(fee_span, '$[1]')) as INT) as avg_fee_10,
CAST(AVG(JSON_EXTRACT(fee_span, '$[2]')) as INT) as avg_fee_25,
CAST(AVG(JSON_EXTRACT(fee_span, '$[3]')) as INT) as avg_fee_50,
CAST(AVG(JSON_EXTRACT(fee_span, '$[4]')) as INT) as avg_fee_75,
CAST(AVG(JSON_EXTRACT(fee_span, '$[5]')) as INT) as avg_fee_90,
CAST(AVG(JSON_EXTRACT(fee_span, '$[6]')) as INT) as avg_fee_100
FROM blocks`;
if (interval !== null) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP BY UNIX_TIMESTAMP(blockTimestamp) DIV ${div}`;
2022-04-15 11:05:58 +02:00
const [rows]: any = await DB.query(query);
return rows;
} catch (e) {
logger.err('Cannot generate block fee rates history. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
/**
* Get the historical averaged block sizes
*/
public async $getHistoricalBlockSizes(div: number, interval: string | null): Promise<any> {
try {
let query = `SELECT
CAST(AVG(height) as INT) as avg_height,
CAST(AVG(UNIX_TIMESTAMP(blockTimestamp)) as INT) as timestamp,
CAST(AVG(size) as INT) as avg_size
FROM blocks`;
if (interval !== null) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP BY UNIX_TIMESTAMP(blockTimestamp) DIV ${div}`;
const [rows]: any = await DB.query(query);
return rows;
} catch (e) {
logger.err('Cannot generate block size and weight history. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
/**
* Get the historical averaged block weights
*/
public async $getHistoricalBlockWeights(div: number, interval: string | null): Promise<any> {
try {
let query = `SELECT
CAST(AVG(height) as INT) as avg_height,
CAST(AVG(UNIX_TIMESTAMP(blockTimestamp)) as INT) as timestamp,
CAST(AVG(weight) as INT) as avg_weight
FROM blocks`;
if (interval !== null) {
query += ` WHERE blockTimestamp BETWEEN DATE_SUB(NOW(), INTERVAL ${interval}) AND NOW()`;
}
query += ` GROUP BY UNIX_TIMESTAMP(blockTimestamp) DIV ${div}`;
const [rows]: any = await DB.query(query);
return rows;
} catch (e) {
logger.err('Cannot generate block size and weight history. Reason: ' + (e instanceof Error ? e.message : e));
throw e;
}
}
}
export default new BlocksRepository();