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

Conversation

cylewitruk
Copy link
Member

@cylewitruk cylewitruk commented Dec 19, 2024

Description

Closes: #1170

Changes

Adds the SQL-side of pseudo-materialized views for the canonical blockchains, keyed on the bitcoin chain tip. It's intended that the materialize_canonical_chains function is called after each Bitcoin block has been processed (but that's not included here).

Testing Information

The added script has been run and tested against a local copy of the signer database from testnet using the get_last_key_rotation() query. The updated query I used (below) reduced the execution time on my local machine from 0.2 seconds to 0.002:

select 
    rkt.txid,
    rkt.address,
    rkt.aggregate_key,
    rkt.signer_set,
    rkt.signatures_required
from rotate_keys_transactions rkt 
inner join stacks_transactions st on st.txid = rkt.txid
inner join canonical_chains cc 
    on cc.stacks_block_hash = st.block_hash 
    and cc.bitcoin_chain_tip = '\x9F654F6D199EB6691B560A2CE2511F600D21E2F350549855488A75CC7FAF7D59'
order by 
    cc.stacks_block_height desc, 
    cc.stacks_block_hash desc, 
    rkt.created_at desc
limit 1

Usage

Materialization

To materialize chains for a specific chain tip, the following is used (i.e.):

select materialize_canonical_chains('\xC27D8425AAA7196C890D1B65916311FAC5411415BB66F01B885B8A665FD72606', 1000);

In a successful case, this will return the number of rows written. If the chain has already been materialized for the given chain tip, it will return -1 so that the caller can decide how the situation should be handled.

Statistics

If you want to get a little statistics, the following can be interesting:

select 
    count(distinct bitcoin_chain_tip) as chain_tips, 
    count(distinct bitcoin_block_hash) as block_count, 
    count(*) as total 
from canonical_chains;

Views

There are three views included in this change which are for convenience:

  • canonical_chains
  • canonical_bitcoin_chain
  • canonical_stacks_chain

Example usage of them:

select * from canonical_chains;

select * from canonical_bitcoin_chain 
where bitcoin_chain_tip = '\x9F654F6D199EB6691B560A2CE2511F600D21E2F350549855488A75CC7FAF7D59' 
order by bitcoin_block_height desc;

select * from canonical_stacks_chain 
where bitcoin_chain_tip = '\x9F654F6D199EB6691B560A2CE2511F600D21E2F350549855488A75CC7FAF7D59' 
order by stacks_block_height desc;

@cylewitruk cylewitruk added the sbtc signer binary The sBTC Bootstrap Signer. label Dec 19, 2024
@cylewitruk cylewitruk added this to the sBTC: Release polish milestone Dec 19, 2024
@cylewitruk cylewitruk self-assigned this Dec 19, 2024
Copy link
Contributor

@djordon djordon left a comment

Choose a reason for hiding this comment

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

Very nice! I had some nits.

Also, I'm not sure if we want two tables, one table with bitcoin blocks and another with bitcoin and stacks blocks. That might make sense, but maybe it's not worth it.

signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
signer/migrations/0011__materialized_chains.sql Outdated Show resolved Hide resolved
@cylewitruk
Copy link
Member Author

Also, I'm not sure if we want two tables, one table with bitcoin blocks and another with bitcoin and stacks blocks. That might make sense, but maybe it's not worth it.

I think that keeping them consolidated at the moment makes the most sense -- at least unless/until we find a motivation for them to be separated. This solution is a little bit more OLAP mindset than OLTP, where we try to do more work up-front to avoid needing more work (joins) later.

@cylewitruk
Copy link
Member Author

One thing we need to consider is that functions like get_last_key_rotation() don't use a context window, which means that we wouldn't be able to use this together with a context window as the last key rotation might slide out-of-scope since it (should) happen so seldom. The idea with the context window in this case is to try to minimize both processing time and storage.

So maybe we should rethink that (and similar) functions separately -- i.e. if we should get it from the contract at each block instead, or have a separate materialization of context-window-free data -- or if we should just always materialize back to the last utxo or key rotation (whichever comes last) and let it take the space it needs?

Just thinking out loud..

blocks.bitcoin_anchor
FROM sbtc_signer.stacks_blocks blocks
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.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
sbtc signer binary The sBTC Bootstrap Signer.
Projects
Status: In Review
Development

Successfully merging this pull request may close these issues.

[Feature]: Materialized database views for canonical chains
3 participants