Skip to content

Commit

Permalink
fix: convert chain_tip materialized view into a table (#1751)
Browse files Browse the repository at this point in the history
* feat: chain tip table

* fix: handle reorgs
  • Loading branch information
rafaelcr committed Dec 29, 2023
1 parent c2edd17 commit 09ebc6c
Show file tree
Hide file tree
Showing 13 changed files with 314 additions and 205 deletions.
142 changes: 142 additions & 0 deletions migrations/1700071472495_chain-tip-table.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,142 @@
/* eslint-disable camelcase */

exports.shorthands = undefined;

exports.up = pgm => {
pgm.dropMaterializedView('chain_tip');
pgm.createTable('chain_tip', {
id: {
type: 'bool',
primaryKey: true,
default: true,
},
block_height: {
type: 'integer',
notNull: true,
},
block_count: {
type: 'integer',
notNull: true,
},
block_hash: {
type: 'bytea',
notNull: true,
},
index_block_hash: {
type: 'bytea',
notNull: true,
},
burn_block_height: {
type: 'integer',
notNull: true,
},
microblock_hash: {
type: 'bytea',
},
microblock_sequence: {
type: 'integer',
},
microblock_count: {
type: 'integer',
notNull: true,
},
tx_count: {
type: 'integer',
notNull: true,
},
tx_count_unanchored: {
type: 'integer',
notNull: true,
},
});
pgm.addConstraint('chain_tip', 'chain_tip_one_row', 'CHECK(id)');
pgm.sql(`
WITH block_tip AS (
SELECT block_height, block_hash, index_block_hash, burn_block_height
FROM blocks
WHERE block_height = (SELECT MAX(block_height) FROM blocks WHERE canonical = TRUE)
),
microblock_tip AS (
SELECT microblock_hash, microblock_sequence
FROM microblocks, block_tip
WHERE microblocks.parent_index_block_hash = block_tip.index_block_hash
AND microblock_canonical = true AND canonical = true
ORDER BY microblock_sequence DESC
LIMIT 1
),
microblock_count AS (
SELECT COUNT(*)::INTEGER AS microblock_count
FROM microblocks
WHERE canonical = TRUE AND microblock_canonical = TRUE
),
tx_count AS (
SELECT COUNT(*)::INTEGER AS tx_count
FROM txs
WHERE canonical = TRUE AND microblock_canonical = TRUE
AND block_height <= (SELECT MAX(block_height) FROM blocks WHERE canonical = TRUE)
),
tx_count_unanchored AS (
SELECT COUNT(*)::INTEGER AS tx_count_unanchored
FROM txs
WHERE canonical = TRUE AND microblock_canonical = TRUE
)
INSERT INTO chain_tip (block_height, block_hash, index_block_hash, burn_block_height,
block_count, microblock_hash, microblock_sequence, microblock_count, tx_count,
tx_count_unanchored)
VALUES (
COALESCE((SELECT block_height FROM block_tip), 0),
COALESCE((SELECT block_hash FROM block_tip), ''),
COALESCE((SELECT index_block_hash FROM block_tip), ''),
COALESCE((SELECT burn_block_height FROM block_tip), 0),
COALESCE((SELECT block_height FROM block_tip), 0),
(SELECT microblock_hash FROM microblock_tip),
(SELECT microblock_sequence FROM microblock_tip),
COALESCE((SELECT microblock_count FROM microblock_count), 0),
COALESCE((SELECT tx_count FROM tx_count), 0),
COALESCE((SELECT tx_count_unanchored FROM tx_count_unanchored), 0)
)
`);
};

exports.down = pgm => {
pgm.dropTable('chain_tip');
pgm.createMaterializedView('chain_tip', {}, `
WITH block_tip AS (
SELECT block_height, block_hash, index_block_hash, burn_block_height
FROM blocks
WHERE block_height = (SELECT MAX(block_height) FROM blocks WHERE canonical = TRUE)
),
microblock_tip AS (
SELECT microblock_hash, microblock_sequence
FROM microblocks, block_tip
WHERE microblocks.parent_index_block_hash = block_tip.index_block_hash
AND microblock_canonical = true AND canonical = true
ORDER BY microblock_sequence DESC
LIMIT 1
),
microblock_count AS (
SELECT COUNT(*)::INTEGER AS microblock_count
FROM microblocks
WHERE canonical = TRUE AND microblock_canonical = TRUE
),
tx_count AS (
SELECT COUNT(*)::INTEGER AS tx_count
FROM txs
WHERE canonical = TRUE AND microblock_canonical = TRUE
AND block_height <= (SELECT MAX(block_height) FROM blocks WHERE canonical = TRUE)
),
tx_count_unanchored AS (
SELECT COUNT(*)::INTEGER AS tx_count_unanchored
FROM txs
WHERE canonical = TRUE AND microblock_canonical = TRUE
)
SELECT *, block_tip.block_height AS block_count
FROM block_tip
LEFT JOIN microblock_tip ON TRUE
LEFT JOIN microblock_count ON TRUE
LEFT JOIN tx_count ON TRUE
LEFT JOIN tx_count_unanchored ON TRUE
LIMIT 1
`);
pgm.createIndex('chain_tip', 'block_height', { unique: true });
};
6 changes: 3 additions & 3 deletions src/api/controllers/cache-controller.ts
Original file line number Diff line number Diff line change
Expand Up @@ -251,13 +251,13 @@ async function calculateETag(
switch (etagType) {
case ETagType.chainTip:
try {
const chainTip = await db.getUnanchoredChainTip();
if (!chainTip.found) {
const chainTip = await db.getChainTip();
if (chainTip.block_height === 0) {
// This should never happen unless the API is serving requests before it has synced any
// blocks.
return;
}
return chainTip.result.microblockHash ?? chainTip.result.indexBlockHash;
return chainTip.microblock_hash ?? chainTip.index_block_hash;
} catch (error) {
logger.error(error, 'Unable to calculate chain_tip ETag');
return;
Expand Down
16 changes: 8 additions & 8 deletions src/api/routes/status.ts
Original file line number Diff line number Diff line change
Expand Up @@ -18,15 +18,15 @@ export function createStatusRouter(db: PgStore): express.Router {
response.pox_v1_unlock_height = poxForceUnlockHeights.result.pox1UnlockHeight as number;
response.pox_v2_unlock_height = poxForceUnlockHeights.result.pox2UnlockHeight as number;
}
const chainTip = await db.getUnanchoredChainTip();
if (chainTip.found) {
const chainTip = await db.getChainTip();
if (chainTip.block_height > 0) {
response.chain_tip = {
block_height: chainTip.result.blockHeight,
block_hash: chainTip.result.blockHash,
index_block_hash: chainTip.result.indexBlockHash,
microblock_hash: chainTip.result.microblockHash,
microblock_sequence: chainTip.result.microblockSequence,
burn_block_height: chainTip.result.burnBlockHeight,
block_height: chainTip.block_height,
block_hash: chainTip.block_hash,
index_block_hash: chainTip.index_block_hash,
microblock_hash: chainTip.microblock_hash,
microblock_sequence: chainTip.microblock_sequence,
burn_block_height: chainTip.burn_block_height,
};
}
setETagCacheHeaders(res);
Expand Down
23 changes: 10 additions & 13 deletions src/datastore/common.ts
Original file line number Diff line number Diff line change
Expand Up @@ -743,15 +743,6 @@ export type BlockIdentifier =
| { burnBlockHash: string }
| { burnBlockHeight: number };

export interface DbChainTip {
blockHeight: number;
indexBlockHash: string;
blockHash: string;
microblockHash?: string;
microblockSequence?: number;
burnBlockHeight: number;
}

export interface BlockQueryResult {
block_hash: string;
index_block_hash: string;
Expand Down Expand Up @@ -1455,8 +1446,14 @@ export interface SmartContractInsertValues {
}

export interface DbChainTip {
blockHeight: number;
blockHash: string;
indexBlockHash: string;
burnBlockHeight: number;
block_height: number;
block_count: number;
block_hash: string;
index_block_hash: string;
burn_block_height: number;
microblock_hash?: string;
microblock_sequence?: number;
microblock_count: number;
tx_count: number;
tx_count_unanchored: number;
}
79 changes: 21 additions & 58 deletions src/datastore/pg-store.ts
Original file line number Diff line number Diff line change
Expand Up @@ -252,28 +252,20 @@ export class PgStore {
});
}

async getChainTip(
sql: PgSqlClient
): Promise<{
blockHeight: number;
blockHash: string;
indexBlockHash: string;
burnBlockHeight: number;
}> {
const currentTipBlock = await sql<
{
block_height: number;
block_hash: string;
index_block_hash: string;
burn_block_height: number;
}[]
>`SELECT block_height, block_hash, index_block_hash, burn_block_height FROM chain_tip`;
const height = currentTipBlock[0]?.block_height ?? 0;
async getChainTip(): Promise<DbChainTip> {
const tipResult = await this.sql<DbChainTip[]>`SELECT * FROM chain_tip`;
const tip = tipResult[0];
return {
blockHeight: height,
blockHash: currentTipBlock[0]?.block_hash ?? '',
indexBlockHash: currentTipBlock[0]?.index_block_hash ?? '',
burnBlockHeight: currentTipBlock[0]?.burn_block_height ?? 0,
block_height: tip?.block_height ?? 0,
block_count: tip?.block_count ?? 0,
block_hash: tip?.block_hash ?? '',
index_block_hash: tip?.index_block_hash ?? '',
burn_block_height: tip?.burn_block_height ?? 0,
microblock_hash: tip?.microblock_hash ?? undefined,
microblock_sequence: tip?.microblock_sequence ?? undefined,
microblock_count: tip?.microblock_count ?? 0,
tx_count: tip?.tx_count ?? 0,
tx_count_unanchored: tip?.tx_count_unanchored ?? 0,
};
}

Expand Down Expand Up @@ -368,33 +360,6 @@ export class PgStore {
return this.getPoxForcedUnlockHeightsInternal(this.sql);
}

async getUnanchoredChainTip(): Promise<FoundOrNot<DbChainTip>> {
const result = await this.sql<
{
block_height: number;
index_block_hash: string;
block_hash: string;
microblock_hash: string | null;
microblock_sequence: number | null;
burn_block_height: number;
}[]
>`SELECT block_height, index_block_hash, block_hash, microblock_hash, microblock_sequence, burn_block_height
FROM chain_tip`;
if (result.length === 0) {
return { found: false } as const;
}
const row = result[0];
const chainTipResult: DbChainTip = {
blockHeight: row.block_height,
indexBlockHash: row.index_block_hash,
blockHash: row.block_hash,
microblockHash: row.microblock_hash === null ? undefined : row.microblock_hash,
microblockSequence: row.microblock_sequence === null ? undefined : row.microblock_sequence,
burnBlockHeight: row.burn_block_height,
};
return { found: true, result: chainTipResult };
}

async getBlock(blockIdentifer: BlockIdentifier): Promise<FoundOrNot<DbBlock>> {
return this.getBlockInternal(this.sql, blockIdentifer);
}
Expand Down Expand Up @@ -678,8 +643,8 @@ export class PgStore {

async getUnanchoredTxsInternal(sql: PgSqlClient): Promise<{ txs: DbTx[] }> {
// Get transactions that have been streamed in microblocks but not yet accepted or rejected in an anchor block.
const { blockHeight } = await this.getChainTip(sql);
const unanchoredBlockHeight = blockHeight + 1;
const { block_height } = await this.getChainTip();
const unanchoredBlockHeight = block_height + 1;
const query = await sql<ContractTxQueryResult[]>`
SELECT ${unsafeCols(sql, [...TX_COLUMNS, abiColumn()])}
FROM txs
Expand Down Expand Up @@ -724,9 +689,7 @@ export class PgStore {
});
}

async getAddressNonces(args: {
stxAddress: string;
}): Promise<{
async getAddressNonces(args: { stxAddress: string }): Promise<{
lastExecutedTxNonce: number | null;
lastMempoolTxNonce: number | null;
possibleNextNonce: number;
Expand Down Expand Up @@ -1426,11 +1389,11 @@ export class PgStore {
sql: PgSqlClient,
{ includeUnanchored }: { includeUnanchored: boolean }
): Promise<number> {
const chainTip = await this.getChainTip(sql);
const chainTip = await this.getChainTip();
if (includeUnanchored) {
return chainTip.blockHeight + 1;
return chainTip.block_height + 1;
} else {
return chainTip.blockHeight;
return chainTip.block_height;
}
}

Expand Down Expand Up @@ -2213,9 +2176,9 @@ export class PgStore {

async getStxBalanceAtBlock(stxAddress: string, blockHeight: number): Promise<DbStxBalance> {
return await this.sqlTransaction(async sql => {
const chainTip = await this.getChainTip(sql);
const chainTip = await this.getChainTip();
const blockHeightToQuery =
blockHeight > chainTip.blockHeight ? chainTip.blockHeight : blockHeight;
blockHeight > chainTip.block_height ? chainTip.block_height : blockHeight;
const blockQuery = await this.getBlockByHeightInternal(sql, blockHeightToQuery);
if (!blockQuery.found) {
throw new Error(`Could not find block at height: ${blockHeight}`);
Expand Down
Loading

0 comments on commit 09ebc6c

Please sign in to comment.