Skip to content

Commit

Permalink
consolidate migrations
Browse files Browse the repository at this point in the history
  • Loading branch information
Andrew7234 committed Nov 29, 2023
1 parent da6d23a commit 98ad2a3
Show file tree
Hide file tree
Showing 27 changed files with 209 additions and 601 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,14 @@

BEGIN;

-- Create Damask Upgrade Schema with `chain-id`.
-- A schema for tracking on-chain data.
CREATE SCHEMA IF NOT EXISTS chain;
GRANT USAGE ON SCHEMA chain TO PUBLIC;

-- A schema for keeping track of analyzers' internal state/progess.
CREATE SCHEMA IF NOT EXISTS analysis;
GRANT USAGE ON SCHEMA analysis TO PUBLIC;

-- Custom types
CREATE DOMAIN public.uint_numeric NUMERIC(1000,0) CHECK(VALUE >= 0);
CREATE DOMAIN public.uint63 BIGINT CHECK(VALUE >= 0);
Expand All @@ -15,6 +19,7 @@ CREATE DOMAIN public.hex64 TEXT CHECK(VALUE ~ '^[0-9a-f]{64}$');
-- base64(ed25519 public key); from https://github.com/oasisprotocol/oasis-core/blob/f95186e3f15ec64bdd36493cde90be359bd17da8/go/common/crypto/signature/signature.go#L90-L90
CREATE DOMAIN public.base64_ed25519_pubkey TEXT CHECK(VALUE ~ '^[A-Za-z0-9+/]{43}=$');
CREATE DOMAIN public.oasis_addr TEXT CHECK(length(VALUE) = 46 AND VALUE ~ '^oasis1');
CREATE DOMAIN public.eth_addr BYTEA CHECK(length(VALUE) = 20);

-- Block Data
CREATE TABLE chain.blocks
Expand Down Expand Up @@ -284,23 +289,31 @@ CREATE TABLE chain.accounts_related_transactions
);
CREATE INDEX ix_accounts_related_transactions_address_block_index ON chain.accounts_related_transactions (account_address);

-- Tracks the current (consensus) height of the node.
CREATE TABLE chain.latest_node_heights
(
layer TEXT NOT NULL PRIMARY KEY,
height UINT63 NOT NULL
);

-- Indexing Progress Management
CREATE TABLE chain.processed_blocks -- Moved to analysis.processed_blocks in 06_analysis_schema.up.sql
CREATE TABLE analysis.processed_blocks -- Moved to analysis.processed_blocks in 06_analysis_schema.up.sql
(
height UINT63 NOT NULL,
analyzer TEXT NOT NULL,
PRIMARY KEY (analyzer, height),

processed_time TIMESTAMP WITH TIME ZONE, -- NULL if the block is not yet processed.
locked_time TIMESTAMP WITH TIME ZONE NOT NULL
-- is_fast_sync BOOL NOT NULL DEFAULT false, -- Whether the block was analyzed in fast-sync mode or not. Added in 16_fast_sync.sql.
locked_time TIMESTAMP WITH TIME ZONE NOT NULL,
is_fast_sync BOOL NOT NULL DEFAULT false -- Whether the block was analyzed in fast-sync mode or not.
);

CREATE INDEX ix_processed_blocks_analyzer_height_locked_unprocessed ON chain.processed_blocks (analyzer, height, locked_time) WHERE processed_time IS NULL; -- Index for efficient query of unprocessed blocks.
CREATE INDEX ix_processed_blocks_analyzer_height_locked_processed ON chain.processed_blocks (analyzer, height, locked_time, processed_time) WHERE processed_time IS NOT NULL; -- Index for efficient query of processed blocks.
CREATE INDEX ix_processed_blocks_analyzer_height_locked_unprocessed ON analysis.processed_blocks (analyzer, height, locked_time) WHERE processed_time IS NULL; -- Index for efficient query of unprocessed blocks.
CREATE INDEX ix_processed_blocks_analyzer_height_locked_processed ON analysis.processed_blocks (analyzer, height, locked_time, processed_time) WHERE processed_time IS NOT NULL; -- Index for efficient query of processed blocks.

-- Grant others read-only use. This does NOT apply to future tables in the schema.
GRANT SELECT ON ALL TABLES IN SCHEMA chain TO PUBLIC;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA chain TO PUBLIC;
GRANT SELECT ON ALL TABLES IN SCHEMA analysis TO PUBLIC;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA analysis TO PUBLIC;

COMMIT;
1 change: 0 additions & 1 deletion storage/migrations/00_genesis_processing.up.sql

This file was deleted.

Large diffs are not rendered by default.

48 changes: 48 additions & 0 deletions storage/migrations/02_agg_stats.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
-- Initialization of materialized views and tables for aggregate statistics on the consensus layer.

BEGIN;

-- Schema for aggregate statistics.
CREATE SCHEMA IF NOT EXISTS stats;
GRANT USAGE ON SCHEMA stats TO PUBLIC;

-- min5_tx_volume stores the 5-minute tx volumes in 5-minute windows, per layer.
CREATE TABLE stats.min5_tx_volume
(
layer TEXT NOT NULL,
window_end TIMESTAMP WITH TIME ZONE NOT NULL,
tx_volume UINT63 NOT NULL,

PRIMARY KEY (layer, window_end)
);

-- daily_tx_volume stores the sliding window for the number of transactions per day per layer.
CREATE TABLE stats.daily_tx_volume
(
layer TEXT NOT NULL,
window_end TIMESTAMP WITH TIME ZONE NOT NULL,
tx_volume UINT63 NOT NULL,

PRIMARY KEY (layer, window_end)
);
-- Index for efficient query of the daily samples.
CREATE INDEX ix_stats_daily_tx_volume_daily_windows ON stats.daily_tx_volume (layer, window_end) WHERE ((window_end AT TIME ZONE 'UTC')::time = '00:00:00');

-- daily_active_accounts stores the sliding window for the number of unique accounts per day
-- that were involved in transactions.
CREATE TABLE stats.daily_active_accounts
(
layer TEXT NOT NULL,
window_end TIMESTAMP WITH TIME ZONE NOT NULL,
active_accounts UINT63 NOT NULL,

PRIMARY KEY (layer, window_end)
);
-- Index for efficient query of the daily samples.
CREATE INDEX ix_stats_daily_active_accounts_daily_windows ON stats.daily_active_accounts (layer, window_end) WHERE ((window_end AT TIME ZONE 'UTC')::time = '00:00:00');

-- Grant others read-only use. This does NOT apply to future tables in the schema.
GRANT SELECT ON ALL TABLES IN SCHEMA stats TO PUBLIC;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA stats TO PUBLIC;

COMMIT;
66 changes: 0 additions & 66 deletions storage/migrations/03_agg_stats.up.sql

This file was deleted.

38 changes: 0 additions & 38 deletions storage/migrations/05_evm_runtime_bytecode.up.sql

This file was deleted.

59 changes: 59 additions & 0 deletions storage/migrations/05_util_fns.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
-- Helper functions for manipulating oasis data types.
BEGIN;

-------------------------------------
-- Convenience functions for converting between eth-style and oasis-style addresses
-- via lookups in the address_preimages table.

-- Convenience function for retrieving the ethereum address associated with a given oasis address.
CREATE OR REPLACE FUNCTION eth_preimage(addr oasis_addr)
RETURNS BYTEA
LANGUAGE plpgsql
AS $$
BEGIN
DECLARE
result BYTEA;
BEGIN
SELECT pre.address_data
INTO result
FROM chain.address_preimages pre
WHERE pre.address = addr
AND pre.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'
AND pre.context_version = 0;
RETURN result;
END;
END;
$$;

CREATE OR REPLACE FUNCTION derive_oasis_addr(eth_addr bytea)
RETURNS TEXT
LANGUAGE plpgsql
AS $$
BEGIN
DECLARE
result TEXT;
BEGIN
-- Check if the bytea data is exactly 20 bytes in length; this prevents accidentally accepting strings that are hex-encodings of the actual address, or similar.
IF length(eth_addr) <> 20 THEN
RAISE EXCEPTION 'Input address must be a bytea and exactly 20 bytes in length';
END IF;

-- Look up the oasis-style address derived from evs.body.address.
-- The derivation is just a keccak hash and we could theoretically compute it instead of looking it up,
-- but the right hash function will only be easily available in postgres once openssl 3.2 is released
-- (see https://github.com/openssl/openssl/issues/19304) and bundled into a postgres docker image, probably
-- in early 2024.
SELECT pre.address
INTO result
FROM chain.address_preimages pre
WHERE pre.address_data = eth_addr
AND pre.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth'
AND pre.context_version = 0;
RETURN result;
END;
END;
$$;


-------------------------------------
COMMIT;
9 changes: 0 additions & 9 deletions storage/migrations/06_analysis_schema.up.sql

This file was deleted.

16 changes: 0 additions & 16 deletions storage/migrations/07_evm_contract_verification.up.sql

This file was deleted.

16 changes: 0 additions & 16 deletions storage/migrations/08_runtime_events_timestamp.up.sql

This file was deleted.

6 changes: 0 additions & 6 deletions storage/migrations/09_evm_token_total_supply.up.sql

This file was deleted.

8 changes: 0 additions & 8 deletions storage/migrations/10_runtime_address_preimage_idx.up.sql

This file was deleted.

35 changes: 0 additions & 35 deletions storage/migrations/11_agg_stats_refactor.up.sql

This file was deleted.

21 changes: 0 additions & 21 deletions storage/migrations/12_evm_contract_gas.up.sql

This file was deleted.

Loading

0 comments on commit 98ad2a3

Please sign in to comment.