Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: add sql-side of a pseudo-materialized-view for the blockchains #1171

Open
wants to merge 6 commits into
base: main
Choose a base branch
from
Open
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
190 changes: 190 additions & 0 deletions signer/migrations/0011__materialized_chains.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,190 @@
-- Table used to store the canonical chain instances for the materialized data
-- in `canonical_chain_data`. The primary purpose of this table is to avoid the
-- need to include the 32-byte chain tip in every row of the `canonical_chain_data`
-- and its indexes. This table is also used to enforce the constraint that only
-- one canonical chain can be materialized per chain tip.
CREATE TABLE sbtc_signer.canonical_chain (
id SERIAL NOT NULL PRIMARY KEY,
bitcoin_chain_tip BYTEA NOT NULL
);

-- We only allow one canonical chain materialization per chain tip, and this
-- index enforces that constraint while also allowing for fast lookups by chain
-- tip.
CREATE UNIQUE INDEX uk_canonical_chain_bitcoin_chain_tip ON sbtc_signer.canonical_chain(bitcoin_chain_tip);

-- This table holds the canonical chain information for Bitcoin and Stacks
-- chains keyed by the bitcoin chain tip.
--
-- This table includes one row for each Stacks block which is anchored to a
-- Bitcoin block in the canonical chain. The `bitcoin_chain_tip` column is used
-- to identify the specific chain tip for which the canonical chain is
-- materialized. If no Stacks block(s) exist for a given Bitcoin block, the
-- `stacks_block_hash` and `stacks_block_height` columns will be `NULL` for that
-- Bitcoin block hash.
CREATE TABLE sbtc_signer.canonical_chain_data (
canonical_chain_id INT NOT NULL,
bitcoin_block_hash BYTEA NOT NULL,
bitcoin_block_height BIGINT NOT NULL,
stacks_block_hash BYTEA,
matteojug marked this conversation as resolved.
Show resolved Hide resolved
stacks_block_height BIGINT,

FOREIGN KEY (canonical_chain_id) REFERENCES sbtc_signer.canonical_chain(id),
-- Let's ensure that bitcoin/stacks blocks can't be deleted if they are
-- part of a canonical chain (if/when we implement pruning).
FOREIGN KEY (bitcoin_block_hash) REFERENCES sbtc_signer.bitcoin_blocks(block_hash),
FOREIGN KEY (stacks_block_hash) REFERENCES sbtc_signer.stacks_blocks(block_hash)
);

-- This index acts as our pseudo-PK for the table.
CREATE UNIQUE INDEX uk_canonical_chain_data ON sbtc_signer.canonical_chain_data(canonical_chain_id, bitcoin_block_hash, stacks_block_hash);
-- Indexes to support common queries on the canonical chains data table.
CREATE INDEX ix_canonical_chain_data_bitcoin_block_hash ON sbtc_signer.canonical_chain_data(bitcoin_block_hash);
CREATE INDEX ix_canonical_chain_data_bitcoin_block_height ON sbtc_signer.canonical_chain_data(bitcoin_block_height DESC);
CREATE INDEX ix_canonical_chain_data_stacks_block_hash ON sbtc_signer.canonical_chain_data(stacks_block_hash);
CREATE INDEX ix_canonical_chain_data_stacks_block_height ON sbtc_signer.canonical_chain_data(stacks_block_height DESC);

-- An intermediate view to `canonical_chain` + `canonical_chain_data` which can
-- be used in queries to avoid needing to manually join them. Note that this
-- view will return multiple canonical chains, so you need to filter the results
-- to the specific chain tip which you are interested in.
CREATE VIEW sbtc_signer.canonical_chains AS
SELECT
idx.bitcoin_chain_tip,
dat.bitcoin_block_hash,
dat.bitcoin_block_height,
dat.stacks_block_hash,
dat.stacks_block_height
FROM sbtc_signer.canonical_chain idx
INNER JOIN sbtc_signer.canonical_chain_data dat
ON idx.id = dat.canonical_chain_id;

-- A helper view to get only the canonical Bitcoin chain information from the
-- materialized chain data if you're not interested in Stacks blocks. Note that
-- if used in queries, the `bitcoin_chain_tip` column should be used to filter
-- the results to the specific chain tip which you are interested in. The
-- results are not ordered by block height, so you should do that yourself if
-- you require the results to be ordered.
CREATE VIEW sbtc_signer.canonical_bitcoin_chain AS
SELECT DISTINCT
idx.bitcoin_chain_tip,
dat.bitcoin_block_hash,
dat.bitcoin_block_height
FROM sbtc_signer.canonical_chain idx
INNER JOIN sbtc_signer.canonical_chain_data dat
ON idx.id = dat.canonical_chain_id;

-- A helper view to get only the canonical Stacks chain information from the
-- materialized chain data if you're not interested in Bitcoin blocks. Note that
-- if used in queries, the `bitcoin_chain_tip` column should be used to filter
-- the results to the specific chain tip which you are interested in. The
-- results are not ordered by block height, so you should do that yourself if
-- you require the results to be ordered.
-- This view will also only return rows where the `stacks_block_hash` is not
-- `NULL`, since not all Bitcoin blocks necessarily have Stacks blocks anchored
-- to them (i.e. during chain stalls).
CREATE VIEW sbtc_signer.canonical_stacks_chain AS
SELECT DISTINCT
idx.bitcoin_chain_tip,
dat.stacks_block_hash,
dat.stacks_block_height
FROM sbtc_signer.canonical_chain idx
INNER JOIN sbtc_signer.canonical_chain_data dat
ON idx.id = dat.canonical_chain_id
WHERE dat.stacks_block_hash IS NOT NULL;

-- Function to materialize the canonical chains for a given bitcoin chain tip
-- and the maximum depth of the bitcoin blockchain to consider.
--
-- This function returns the number of rows written to the `canonical_chains`
-- table upon success, and `-1` if rows already exist for the given chain tip.
CREATE OR REPLACE FUNCTION sbtc_signer.materialize_canonical_chains(chain_tip BYTEA, max_depth INT)
matteojug marked this conversation as resolved.
Show resolved Hide resolved
RETURNS INTEGER AS $$
DECLARE
rows_written INTEGER;
canonical_chain_id BIGINT;
BEGIN
-- Check if rows exist with the given chain_tip.
-- If rows exist, return an error code. We only allow one materialized
-- canonical chain per chain tip. We could have relied on the PK returning
-- an error, but this allows the calling application to clearly identify
-- that this is a duplicate chain tip and handle it accordingly.
IF EXISTS (
SELECT 1
FROM sbtc_signer.canonical_chain
WHERE bitcoin_chain_tip = chain_tip
) THEN
RETURN -1; -- Error code indicating rows already exist
END IF;

-- Insert the canonical chain row for the given chain tip, returning
-- the ID of the new row.
INSERT INTO sbtc_signer.canonical_chain (bitcoin_chain_tip)
VALUES (chain_tip)
RETURNING id INTO canonical_chain_id;

-- Materialize the canonical chains from the given bitcoin chain tip.
WITH RECURSIVE
bitcoin AS (
SELECT
block_hash
, parent_hash
, block_height
, 1 as depth
FROM sbtc_signer.bitcoin_blocks
WHERE block_hash = chain_tip

UNION ALL

SELECT
parent.block_hash
, parent.parent_hash
, parent.block_height
, last.depth + 1
FROM sbtc_signer.bitcoin_blocks parent
JOIN bitcoin last ON parent.block_hash = last.parent_hash
WHERE last.depth < max_depth
),
stacks AS (
(SELECT
blocks.block_hash
, blocks.parent_hash
, blocks.block_height
, blocks.bitcoin_anchor
FROM sbtc_signer.stacks_blocks blocks
djordon marked this conversation as resolved.
Show resolved Hide resolved
JOIN bitcoin ON blocks.bitcoin_anchor = bitcoin.block_hash
ORDER BY bitcoin.block_height DESC, bitcoin.block_hash DESC, blocks.block_height DESC, blocks.block_hash DESC
Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This seems to differ a bit from get_stacks_chain_tip: here as tip we pick the "first" (wrt bitcoin blocks we walk) highest stacks block anchored to the bitcoin canonical chain, while in get_stacks_chain_tip we pick the highest stacks block anchored to any bitcoin block in the canonical chain; therefore the two approaches could infer different stacks chains.

I'm not completely sure those two are equivalent in case of reorgs (I don't have a counterexample, just asking for a sanity check I guess), and note that according to the comment in get_stacks_chain_tip we do generate test data that could make those two return different results.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yeah the behavior is different, with the goal here to materialize the actual canonical chains in relation to the Bitcoin canonical chain. Since Stacks can only fork together with Bitcoin now, I'm not sure that this view would ever be different than what we want, especially if both the sBTC signer and Stacks node are using the same Bitcoin node.

We also have a different method of determining the canonical Bitcoin chain than either Stacks-core or Bitcoin (they both use the same calculation, we don't have the same tie-breaking mechanism), so I think there's also always the risk during forks/reorgs that the sBTC signer and the Stacks+Bitcoin nodes have different ideas of what the canonical Bitcoin tip is, with today's implementation, anyway.

But yeah, if for some reason one of our queries wants the Stacks chain-tip regardless the Bitcoin chain then it could still get it from the data in the db.

LIMIT 1)

UNION ALL

SELECT
parent.block_hash
, parent.parent_hash
, parent.block_height
, parent.bitcoin_anchor
FROM sbtc_signer.stacks_blocks parent
JOIN stacks last ON parent.block_hash = last.parent_hash
JOIN bitcoin ON bitcoin.block_hash = parent.bitcoin_anchor
)
INSERT INTO sbtc_signer.canonical_chain_data (
canonical_chain_id
, bitcoin_block_hash
, bitcoin_block_height
, stacks_block_hash
, stacks_block_height
)
SELECT
canonical_chain_id
, bb.block_hash AS bitcoin_block_hash
, bb.block_height AS bitcoin_block_height
, sb.block_hash AS stacks_block_hash
, sb.block_height AS stacks_block_height
FROM bitcoin bb
LEFT JOIN stacks sb ON sb.bitcoin_anchor = bb.block_hash
ORDER BY bb.block_height DESC, sb.block_height DESC;

GET DIAGNOSTICS rows_written = ROW_COUNT;
RETURN rows_written;
END;
$$ LANGUAGE plpgsql;
Loading