diff --git a/storage/migrations/01_consensus.up.sql b/storage/migrations/00_consensus.up.sql similarity index 91% rename from storage/migrations/01_consensus.up.sql rename to storage/migrations/00_consensus.up.sql index 32845d26c..096df7544 100644 --- a/storage/migrations/01_consensus.up.sql +++ b/storage/migrations/00_consensus.up.sql @@ -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); @@ -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 @@ -259,10 +264,9 @@ CREATE TABLE chain.proposals -- If this proposal cancels an existing proposal. cancels UINT63 REFERENCES chain.proposals(id) DEFAULT NULL, - -- Added in 25_consensus_parameters_change_proposals.up.sql -- If this proposal is a "ChangeParameters" proposal. - -- parameters_change_module TEXT, - -- parameters_change BYTEA, + parameters_change_module TEXT, + parameters_change BYTEA, created_at UINT63 NOT NULL, -- EpochTime, i.e. number of epochs since base epoch closes_at UINT63 NOT NULL, -- EpochTime, i.e. number of epochs since base epoch @@ -289,23 +293,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; diff --git a/storage/migrations/00_genesis_processing.up.sql b/storage/migrations/00_genesis_processing.up.sql deleted file mode 100644 index d2b71c45a..000000000 --- a/storage/migrations/00_genesis_processing.up.sql +++ /dev/null @@ -1 +0,0 @@ --- moved to 01_consensus.up.sql diff --git a/storage/migrations/02_runtimes.up.sql b/storage/migrations/01_runtimes.up.sql similarity index 61% rename from storage/migrations/02_runtimes.up.sql rename to storage/migrations/01_runtimes.up.sql index 2be2742f4..1853bce43 100644 --- a/storage/migrations/02_runtimes.up.sql +++ b/storage/migrations/01_runtimes.up.sql @@ -13,8 +13,8 @@ CREATE TABLE chain.runtime_blocks version UINT63 NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL, - block_hash HEX64 NOT NULL, -- Hash of this round's block. Does not reference consensus. - prev_block_hash HEX64 NOT NULL, + block_hash HEX64 NOT NULL, -- Hash of this round's block. Does not reference consensus. + prev_block_hash HEX64 NOT NULL, io_root HEX64 NOT NULL, state_root HEX64 NOT NULL, @@ -45,7 +45,6 @@ CREATE TABLE chain.runtime_transactions fee UINT_NUMERIC NOT NULL, gas_limit UINT63 NOT NULL, gas_used UINT63 NOT NULL, - size UINT31 NOT NULL, -- Transaction contents. @@ -54,9 +53,12 @@ CREATE TABLE chain.runtime_transactions "to" oasis_addr, -- Exact semantics depend on method. Extracted from body; for convenience only. amount UINT_NUMERIC, -- Exact semantics depend on method. Extracted from body; for convenience only. - -- Added in 26_runtime_abi.up.sql - -- evm_fn_name TEXT, - -- evm_fn_params JSONB, + -- For evm.Call transactions, we store both the name of the function and + -- the function parameters. + evm_fn_name TEXT, + -- The function parameter values. Refer to the abi to see the parameter + -- names. Note that the parameters may be unnamed. + evm_fn_params JSONB, -- Encrypted data in encrypted Ethereum-format transactions. evm_encrypted_format call_format, @@ -70,18 +72,27 @@ CREATE TABLE chain.runtime_transactions success BOOLEAN, -- NULL means success is unknown (can happen in confidential runtimes) error_module TEXT, error_code UINT63, - error_message TEXT - -- Added in 19_runtime_tx_errors.up.sql - -- error_message_raw TEXT - -- Added in 26_runtime_abi.up.sql - -- error_params JSONB - -- abi_parsed_at TIMESTAMP WITH TIME ZONE + error_message TEXT, + -- The unparsed transaction error message. The "parsed" version will be + -- identical in the majority of cases. One notable exception are txs that + -- were reverted inside the EVM; for those, the raw msg is abi-encoded. + error_message_raw TEXT, + -- Custom errors may be arbitrarily defined by the contract abi. This field + -- stores the full abi-decoded error object. Note that the error name is + -- stored separately in the existing error_message column. For example, if we + -- have an error like `InsufficientBalance{available: 4, required: 10}`. + -- the error_message column would hold `InsufficientBalance`, and + -- the error_params column would store `{available: 4, required: 10}`. + error_params JSONB, + -- Internal tracking for parsing evm.Call transactions using the contract + -- abi when available. + abi_parsed_at TIMESTAMP WITH TIME ZONE ); CREATE INDEX ix_runtime_transactions_tx_hash ON chain.runtime_transactions USING hash (tx_hash); CREATE INDEX ix_runtime_transactions_tx_eth_hash ON chain.runtime_transactions USING hash (tx_eth_hash); CREATE INDEX ix_runtime_transactions_timestamp ON chain.runtime_transactions (runtime, timestamp); --- CREATE INDEX ix_runtime_transactions_to ON chain.runtime_transactions(runtime, "to"); -- Added in 12_evm_contract_gas.up.sql --- CREATE INDEX ix_runtime_transactions_to_abi_parsed_at ON chain.runtime_transactions (runtime, "to", abi_parsed_at); -- Added in 25_runtime_abi.up.sql +CREATE INDEX ix_runtime_transactions_to ON chain.runtime_transactions(runtime, "to"); +CREATE INDEX ix_runtime_transactions_to_abi_parsed_at ON chain.runtime_transactions (runtime, "to", abi_parsed_at); CREATE TABLE chain.runtime_transaction_signers ( @@ -108,7 +119,6 @@ CREATE TABLE chain.runtime_related_transactions tx_index UINT31 NOT NULL, FOREIGN KEY (runtime, tx_round, tx_index) REFERENCES chain.runtime_transactions(runtime, round, tx_index) DEFERRABLE INITIALLY DEFERRED ); -CREATE INDEX ix_runtime_related_transactions_address ON chain.runtime_related_transactions (runtime, account_address); -- Removed in 13_runtime_indexes.up.sql CREATE INDEX ix_runtime_related_transactions_round_index ON chain.runtime_related_transactions (runtime, tx_round, tx_index); CREATE INDEX ix_runtime_related_transactions_address_round_index ON chain.runtime_related_transactions (runtime, account_address, tx_round, tx_index); @@ -122,8 +132,7 @@ CREATE TABLE chain.runtime_events tx_hash HEX64, tx_eth_hash HEX64, - -- Added in 08_runtime_events_timestamp.up.sql - -- timestamp TIMESTAMP WITH TIME ZONE NOT NULL, + timestamp TIMESTAMP WITH TIME ZONE NOT NULL, -- TODO: add link to openapi spec section with runtime event types. type TEXT NOT NULL, @@ -137,14 +146,30 @@ CREATE TABLE chain.runtime_events -- case for events emitted by verified contracts. evm_log_name TEXT, evm_log_params JSONB, - evm_log_signature BYTEA CHECK (octet_length(evm_log_signature) = 32) + evm_log_signature BYTEA CHECK (octet_length(evm_log_signature) = 32), + + -- Internal tracking for parsing evm.Call events using the contract + -- abi when available. + abi_parsed_at TIMESTAMP WITH TIME ZONE ); CREATE INDEX ix_runtime_events_round ON chain.runtime_events(runtime, round); -- for sorting by round, when there are no filters applied -CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events/*USING hash */(tx_hash); -- updated in 13_runtime_indexes.up.sql -CREATE INDEX ix_runtime_events_tx_eth_hash ON chain.runtime_events/*USING hash */(tx_eth_hash); -- updated in 13_runtime_indexes.up.sql +CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events USING hash (tx_hash); +CREATE INDEX ix_runtime_events_tx_eth_hash ON chain.runtime_events USING hash (tx_eth_hash); CREATE INDEX ix_runtime_events_related_accounts ON chain.runtime_events USING gin(related_accounts); -- for fetching account activity for a given account -CREATE INDEX ix_runtime_events_evm_log_signature ON chain.runtime_events(/* runtime, */evm_log_signature/*, round*/); -- for fetching a certain event type, eg Transfers; updated in 13_runtime_indexes.up.sql +CREATE INDEX ix_runtime_events_evm_log_signature ON chain.runtime_events(runtime, evm_log_signature, round); -- for fetching a certain event type, eg Transfers CREATE INDEX ix_runtime_events_evm_log_params ON chain.runtime_events USING gin(evm_log_params); +CREATE INDEX ix_runtime_events_type ON chain.runtime_events (runtime, type); + +CREATE TABLE chain.runtime_accounts +( + runtime runtime NOT NULL, + address oasis_addr NOT NULL, + PRIMARY KEY (runtime, address), + + num_txs UINT63 NOT NULL DEFAULT 0, + -- Total gas used by all txs addressed to this account. Primarily meaningful for accounts that are contracts. + gas_for_calling UINT63 NOT NULL DEFAULT 0 -- gas used by txs sent to this address +); -- Oasis addresses are derived from a derivation "context" and a piece of -- data, such as an ed25519 public key or an Ethereum address. The derivation @@ -178,9 +203,8 @@ CREATE TABLE chain.address_preimages -- Ethereum address. For a "staking" context, this is the ed25519 pubkey. address_data BYTEA NOT NULL ); --- Added in 10_runtime_address_preimage_idx.up.sql --- CREATE INDEX IF NOT EXISTS ix_address_preimages_address_data ON chain.address_preimages (address_data) --- WHERE context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND context_version = 0; +CREATE INDEX ix_address_preimages_address_data ON chain.address_preimages (address_data) + WHERE context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND context_version = 0; -- -- -- -- -- -- -- -- -- -- -- -- -- Module evm -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- @@ -201,48 +225,25 @@ CREATE TABLE chain.evm_tokens runtime runtime NOT NULL, token_address oasis_addr NOT NULL, PRIMARY KEY (runtime, token_address), - token_type INTEGER NOT NULL, -- 0 = unsupported, X = ERC-X; full spec at https://github.com/oasisprotocol/nexus/blob/v0.0.16/analyzer/runtime/evm.go#L21 + token_type INTEGER, -- 0 = unsupported, X = ERC-X; full spec at https://github.com/oasisprotocol/nexus/blob/v0.0.16/analyzer/runtime/evm.go#L21 token_name TEXT, symbol TEXT, decimals INTEGER, -- NOT an uint because a non-conforming token contract could issue a fake burn event, -- causing a negative dead-reckoned total_supply. - total_supply uint_numeric -- changed to NUMERIC(1000,0) in 09_evm_token_total_supply.up.sql + total_supply NUMERIC(1000,0), - -- Added in 14_evm_token_transfers.up.sql - -- num_transfers UINT63 NOT NULL DEFAULT 0, + num_transfers UINT63 NOT NULL DEFAULT 0, - -- Added in 18_refactor_dead_reckoning.up.go -- Block analyzer bumps this when it sees the mutable fields of the token -- change (e.g. total supply) based on dead reckoning. - -- last_mutate_round UINT63 NOT NULL, + last_mutate_round UINT63 NOT NULL DEFAULT 0, - -- Added in 18_refactor_dead_reckoning.up.go - -- Token analyzer bumps this when it downloads info about the token. - -- last_download_round UINT63 -); - -CREATE TABLE chain.evm_token_analysis -- Moved to analysis.evm_tokens in 06_analysis_schema.up.sql, then dropped (merged into chain.evm_tokens) in 18_refactor_dead_reckoning.up.go -( - runtime runtime NOT NULL, - token_address oasis_addr NOT NULL, - PRIMARY KEY (runtime, token_address), - -- Dead-reckoned total_supply before token metadata is downloaded. - -- NOT an uint because a non-conforming token contract could issue a fake burn event, - -- causing a negative dead-reckoned total_supply. - total_supply uint_numeric, -- changed to NUMERIC(1000,0) in 09_evm_token_total_supply.up.sql - -- Added in 14_evm_token_transfers.up.sql - -- num_transfers UINT63 NOT NULL DEFAULT 0, - - -- Block analyzer bumps this when it sees the mutable fields of the token - -- change (e.g. total supply) based on dead reckoning. - last_mutate_round UINT63 NOT NULL, -- Token analyzer bumps this when it downloads info about the token. last_download_round UINT63 ); -CREATE INDEX ix_evm_token_analysis_stale ON chain.evm_token_analysis (runtime, token_address) WHERE last_download_round IS NULL OR last_mutate_round > last_download_round; -CREATE TABLE chain.evm_token_balance_analysis -- Moved to analysis.evm_token_balances in 06_analysis_schema.up.sql +CREATE TABLE analysis.evm_token_balances -- Moved to analysis.evm_token_balances in 06_analysis_schema.up.sql ( runtime runtime NOT NULL, -- This table is used to track balance querying primarily for EVM tokens (ERC-20, ERC-271, etc), but also for @@ -253,7 +254,7 @@ CREATE TABLE chain.evm_token_balance_analysis -- Moved to analysis.evm_token_ba last_mutate_round UINT63 NOT NULL, last_download_round UINT63 ); -CREATE INDEX ix_evm_token_balance_analysis_stale ON chain.evm_token_balance_analysis (runtime, token_address, account_address) WHERE last_download_round IS NULL OR last_mutate_round > last_download_round; +CREATE INDEX ix_evm_token_balance_analysis_stale ON analysis.evm_token_balances (runtime, token_address, account_address) WHERE last_download_round IS NULL OR last_mutate_round > last_download_round; CREATE TABLE chain.evm_contracts ( @@ -263,19 +264,56 @@ CREATE TABLE chain.evm_contracts -- Can be null if the contract was created by another contract; eg through an evm.Call instead of a standard evm.Create. Tracing must be enabled to fill out this information. creation_tx HEX64, - creation_bytecode BYTEA - -- runtime_bytecode BYTEA -- Added in 05_evm_runtime_bytecode.up.sql - - -- Added in 07_evm_contract_verification.up.sql - -- -- Following fields are only filled out for contracts that have been verified. - -- verification_info_downloaded_at TIMESTAMP WITH TIME ZONE, -- NULL for unverified contracts. - -- abi JSONB, - -- -- Contents of metadata.json, typically produced by the Solidity compiler. - -- compilation_metadata JSONB, - -- -- Each source file is a flat JSON object with keys "name", "content", "path", as returned by Sourcify. - -- source_files JSONB CHECK (jsonb_typeof(source_files)='array'); + creation_bytecode BYTEA, + runtime_bytecode BYTEA, + + -- Following fields are only filled out for contracts that have been verified. + verification_info_downloaded_at TIMESTAMP WITH TIME ZONE, -- NULL for unverified contracts. + abi JSONB, + -- Contents of metadata.json, typically produced by the Solidity compiler. + compilation_metadata JSONB, + -- Each source file is a flat JSON object with keys "name", "content", "path", as returned by Sourcify. + source_files JSONB CHECK (jsonb_typeof(source_files)='array') +); +CREATE INDEX ix_evm_contracts_unverified ON chain.evm_contracts (runtime) WHERE verification_info_downloaded_at IS NULL; + +-- Used to keep track of potential contract addresses, and our progress in +-- downloading their runtime bytecode. ("Runtime" in the sense of ETH terminology +-- which talks about a contract's "runtime bytecode" as opposed to "creation bytecode".) +CREATE TABLE analysis.evm_contract_code ( + runtime runtime NOT NULL, + contract_candidate oasis_addr NOT NULL, + PRIMARY KEY (runtime, contract_candidate), + -- Meaning of is_contract: + -- TRUE: downloaded runtime bytecode + -- FALSE: download failed because `contract_candidate` is not a contract (= does not have code) + -- NULL: not yet attempted + is_contract BOOLEAN ); --- CREATE INDEX ix_evm_contracts_unverified ON chain.evm_contracts (runtime) WHERE verification_info_downloaded_at IS NULL; -- Added in 07_evm_contract_verification.up.sql +-- Allow the analyzer to quickly retrieve addresses that have not been downloaded yet. +CREATE INDEX ix_evm_contract_code_todo ON analysis.evm_contract_code (runtime, contract_candidate) WHERE is_contract IS NULL; + +CREATE TABLE chain.evm_nfts ( + runtime runtime NOT NULL, + token_address oasis_addr NOT NULL, + nft_id uint_numeric NOT NULL, + PRIMARY KEY (runtime, token_address, nft_id), + + last_want_download_round UINT63 NOT NULL, + last_download_round UINT63, + + owner oasis_addr, + num_transfers INT NOT NULL, + metadata JSONB, + metadata_uri TEXT, + metadata_accessed TIMESTAMP, + name TEXT, + description TEXT, + image TEXT +); +CREATE INDEX ix_evm_nfts_stale ON chain.evm_nfts (runtime, token_address, nft_id) WHERE last_download_round IS NULL OR last_want_download_round > last_download_round; +CREATE INDEX ix_evm_nfts_owner ON chain.evm_nfts (runtime, owner, token_address, nft_id); + -- -- -- -- -- -- -- -- -- -- -- -- -- Module accounts -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- @@ -306,59 +344,6 @@ CREATE INDEX ix_runtime_transfers_receiver ON chain.runtime_transfers(receiver); -- -- -- -- -- -- -- -- -- -- -- -- -- Module consensusaccounts -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --- NOTE: Removed in 19_simplify_deposit_withdraw.up.sql --- -- Deposits from the consensus layer into the paratime. --- CREATE TABLE chain.runtime_deposits --- ( --- runtime runtime NOT NULL, --- round UINT63 NOT NULL, --- FOREIGN KEY (runtime, round) REFERENCES chain.runtime_blocks DEFERRABLE INITIALLY DEFERRED, --- -- The `sender` is a consensus account, so this REFERENCES chain.accounts; we omit the FK so --- -- that consensus and paratimes can be indexed independently. --- -- It also REFERENCES chain.address_preimages because the sender signed at least the Deposit tx. --- sender oasis_addr NOT NULL REFERENCES chain.address_preimages DEFERRABLE INITIALLY DEFERRED, --- -- The `receiver` can be any oasis1-form paratime address. --- -- With EVM paratimes, two types of deposits are common: --- -- * Deposit intends to credit a hex-form (eth) account. The user first derives the oasis1-form address, --- -- then uses it as `receiver`. Such a `receiver` address has a secp256k1eth key, an is not valid in --- -- consensus (which only uses ed25519), meaning there is no FK in chain.addresses. --- -- * Deposit intends to credit an ed25519-backed account. These accounts do not exist in classic Ethereum. --- -- The associated hex-form Ethereum address either does not exist or is not knowable. --- -- Regardless, the `receiver` often REFERENCES chain.address_preimages(address), a notable exception --- -- being if the target account hasn't signed any txs yet. --- receiver oasis_addr NOT NULL, --- amount UINT_NUMERIC NOT NULL, -- always in native denomination --- nonce UINT63 NOT NULL, --- -- Optional error data; from https://github.com/oasisprotocol/oasis-sdk/blob/386ba0b99fcd1425c68015e0033a462d9a577835/client-sdk/go/modules/consensusaccounts/types.go#L44-L44 --- module TEXT, --- code UINT63 --- ); --- CREATE INDEX ix_runtime_deposits_sender ON chain.runtime_deposits(sender); --- CREATE INDEX ix_runtime_deposits_receiver ON chain.runtime_deposits(receiver); - --- NOTE: Removed in 19_simplify_deposit_withdraw.up.sql --- -- Withdrawals from the paratime into consensus layer. --- CREATE TABLE chain.runtime_withdraws --- ( --- runtime runtime NOT NULL, --- round UINT63 NOT NULL, --- FOREIGN KEY (runtime, round) REFERENCES chain.runtime_blocks DEFERRABLE INITIALLY DEFERRED, --- -- The `sender` can be any paratime address. (i.e. secp256k1eth-backed OR ed25519-backed; --- -- other are options unlikely in an EVM paratime) --- -- It REFERENCES chain.address_preimages because the sender signed at least the Withdraw tx. --- sender oasis_addr NOT NULL REFERENCES chain.address_preimages DEFERRABLE INITIALLY DEFERRED, --- -- The `receiver` is a consensus account, so this REFERENCES chain.accounts; we omit the FK so --- -- that consensus and paratimes can be indexed independently. --- receiver oasis_addr NOT NULL, --- amount UINT_NUMERIC NOT NULL, -- always in native denomination --- nonce UINT63 NOT NULL, --- -- Optional error data --- module TEXT, --- code UINT63 --- ); --- CREATE INDEX ix_runtime_withdraws_sender ON chain.runtime_withdraws(sender); --- CREATE INDEX ix_runtime_withdraws_receiver ON chain.runtime_withdraws(receiver); - -- Balance of the oasis-sdk native tokens (notably ROSE) in paratimes. CREATE TABLE chain.runtime_sdk_balances ( runtime runtime, @@ -374,5 +359,7 @@ CREATE TABLE chain.runtime_sdk_balances ( -- (We granted already in 01_consensus.up.sql, but the grant does not apply to new tables.) 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; diff --git a/storage/migrations/02_agg_stats.up.sql b/storage/migrations/02_agg_stats.up.sql new file mode 100644 index 000000000..0e6b93579 --- /dev/null +++ b/storage/migrations/02_agg_stats.up.sql @@ -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; diff --git a/storage/migrations/03_agg_stats.up.sql b/storage/migrations/03_agg_stats.up.sql deleted file mode 100644 index 2a563bf2b..000000000 --- a/storage/migrations/03_agg_stats.up.sql +++ /dev/null @@ -1,66 +0,0 @@ --- 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; - --- Rounds a given timestamp down to the nearest 5-minute "bucket" (e.g. 12:34:56 -> 12:30:00). -CREATE FUNCTION floor_5min (ts timestamptz) RETURNS timestamptz AS $$ - SELECT date_trunc('hour', $1) + date_part('minute', $1)::int / 5 * '5 minutes'::interval; -$$ LANGUAGE SQL IMMUTABLE; -GRANT EXECUTE ON FUNCTION floor_5min TO PUBLIC; - - --- min5_tx_volume stores the consensus transaction volume in 5 minute buckets --- This can be used to estimate real time TPS. --- NOTE: This materialized view is NOT refreshed every 5 minutes due to computational cost. -CREATE MATERIALIZED VIEW stats.min5_tx_volume AS - SELECT - 'consensus' AS layer, - floor_5min(b.time) AS window_start, - COUNT(*) AS tx_volume - FROM chain.blocks AS b - JOIN chain.transactions AS t ON b.height = t.block - GROUP BY 2 - - UNION ALL - - SELECT - b.runtime::text AS layer, - floor_5min(b.timestamp) AS window_start, - COUNT(*) AS tx_volume - FROM chain.runtime_blocks AS b - JOIN chain.runtime_transactions AS t ON (b.round = t.round AND b.runtime = t.runtime) - GROUP BY 1, 2; -CREATE UNIQUE INDEX ix_stats_min5_tx_volume_window_start ON stats.min5_tx_volume (layer, window_start); -- A unique index is required for CONCURRENTLY refreshing the view. - --- daily_tx_volume stores the number of transactions per day --- at the consensus layer. -CREATE MATERIALIZED VIEW stats.daily_tx_volume AS - SELECT - layer, - date_trunc ( 'day', sub.window_start ) AS window_start, - SUM(sub.tx_volume) AS tx_volume - FROM stats.min5_tx_volume AS sub - GROUP BY 1, 2; -CREATE UNIQUE INDEX ix_stats_daily_tx_volume_window_start ON stats.daily_tx_volume (layer, window_start); -- A unique index is required for CONCURRENTLY refreshing the view. - --- 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; - -COMMIT; diff --git a/storage/migrations/04_statecheck_snapshots.up.sql b/storage/migrations/03_statecheck_snapshots.up.sql similarity index 100% rename from storage/migrations/04_statecheck_snapshots.up.sql rename to storage/migrations/03_statecheck_snapshots.up.sql diff --git a/storage/migrations/24_fast_sync_temp_tables.up.sql b/storage/migrations/04_fast_sync_temp_tables.up.sql similarity index 100% rename from storage/migrations/24_fast_sync_temp_tables.up.sql rename to storage/migrations/04_fast_sync_temp_tables.up.sql diff --git a/storage/migrations/05_evm_runtime_bytecode.up.sql b/storage/migrations/05_evm_runtime_bytecode.up.sql deleted file mode 100644 index b0ede66fe..000000000 --- a/storage/migrations/05_evm_runtime_bytecode.up.sql +++ /dev/null @@ -1,38 +0,0 @@ -BEGIN; - --- A schema for keeping track of analyzers' internal state/progess. -CREATE SCHEMA IF NOT EXISTS analysis; -GRANT USAGE ON SCHEMA analysis TO PUBLIC; - -CREATE DOMAIN public.eth_addr BYTEA CHECK(length(VALUE) = 20); - --- Used to keep track of potential contract addresses, and our progress in --- downloading their runtime bytecode. ("Runtime" in the sense of ETH terminology --- which talks about a contract's "runtime bytecode" as opposed to "creation bytecode".) -CREATE TABLE analysis.evm_contract_code ( - runtime runtime NOT NULL, - contract_candidate oasis_addr NOT NULL, - PRIMARY KEY (runtime, contract_candidate), - -- Meaning of is_contract: - -- TRUE: downloaded runtime bytecode - -- FALSE: download failed because `contract_candidate` is not a contract (= does not have code) - -- NULL: not yet attempted - is_contract BOOLEAN -); --- Allow the analyzer to quickly retrieve addresses that have not been downloaded yet. -CREATE INDEX ix_evm_contract_code_todo ON analysis.evm_contract_code (runtime, contract_candidate) WHERE is_contract IS NULL; - --- Bootstrap the table with the set of addresses we known are contracts because they are the result of an evm.Create tx. -INSERT INTO analysis.evm_contract_code (runtime, contract_candidate, is_contract) - SELECT runtime, contract_address, NULL - FROM chain.evm_contracts -ON CONFLICT (runtime, contract_candidate) DO NOTHING; - -ALTER TABLE chain.evm_contracts - ADD COLUMN runtime_bytecode BYTEA; - --- Grant others read-only use. This does NOT apply to future tables in the schema. -GRANT SELECT ON ALL TABLES IN SCHEMA analysis TO PUBLIC; -GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA analysis TO PUBLIC; - -COMMIT; diff --git a/storage/migrations/05_util_fns.up.sql b/storage/migrations/05_util_fns.up.sql new file mode 100644 index 000000000..47d6e6bcc --- /dev/null +++ b/storage/migrations/05_util_fns.up.sql @@ -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; diff --git a/storage/migrations/06_analysis_schema.up.sql b/storage/migrations/06_analysis_schema.up.sql deleted file mode 100644 index fdf7e1a92..000000000 --- a/storage/migrations/06_analysis_schema.up.sql +++ /dev/null @@ -1,9 +0,0 @@ --- Moves analysis tables (= those that keep track of analyzers' internal state/progess) to the new `analysis` schema. - -ALTER TABLE chain.processed_blocks SET SCHEMA analysis; - -ALTER TABLE chain.evm_token_analysis SET SCHEMA analysis; -ALTER TABLE analysis.evm_token_analysis RENAME TO evm_tokens; - -ALTER TABLE chain.evm_token_balance_analysis SET SCHEMA analysis; -ALTER TABLE analysis.evm_token_balance_analysis RENAME TO evm_token_balances; diff --git a/storage/migrations/07_evm_contract_verification.up.sql b/storage/migrations/07_evm_contract_verification.up.sql deleted file mode 100644 index 5443b744d..000000000 --- a/storage/migrations/07_evm_contract_verification.up.sql +++ /dev/null @@ -1,16 +0,0 @@ --- Add contract verification fields to evm_contracts table. - -BEGIN; - -ALTER TABLE chain.evm_contracts - ADD COLUMN verification_info_downloaded_at TIMESTAMP WITH TIME ZONE, -- NULL for unverified contracts. - ADD COLUMN abi JSONB, - -- Contents of metadata.json, typically produced by the Solidity compiler. - ADD COLUMN compilation_metadata JSONB, - -- Each source file is a flat JSON object with keys "name", "content", "path", as returned by Sourcify. - ADD COLUMN source_files JSONB CHECK (jsonb_typeof(source_files)='array'); - --- Allow the analyzer to quickly retrieve contracts that have not been verified. -CREATE INDEX ix_evm_contracts_unverified ON chain.evm_contracts (runtime) WHERE verification_info_downloaded_at IS NULL; - -COMMIT; diff --git a/storage/migrations/08_runtime_events_timestamp.up.sql b/storage/migrations/08_runtime_events_timestamp.up.sql deleted file mode 100644 index bb6a38cd2..000000000 --- a/storage/migrations/08_runtime_events_timestamp.up.sql +++ /dev/null @@ -1,16 +0,0 @@ -BEGIN; - -ALTER TABLE chain.runtime_events - ADD COLUMN TIMESTAMP timestamp WITH time zone; - -UPDATE chain.runtime_events AS evs - SET timestamp = blocks.timestamp - FROM chain.runtime_blocks AS blocks - WHERE evs.runtime = blocks.runtime - AND evs.round = blocks.round; - -ALTER TABLE chain.runtime_events - ALTER COLUMN timestamp - SET NOT NULL; - -COMMIT; diff --git a/storage/migrations/09_evm_token_total_supply.up.sql b/storage/migrations/09_evm_token_total_supply.up.sql deleted file mode 100644 index 166e94124..000000000 --- a/storage/migrations/09_evm_token_total_supply.up.sql +++ /dev/null @@ -1,6 +0,0 @@ -BEGIN; - -ALTER TABLE analysis.evm_tokens ALTER COLUMN total_supply type NUMERIC(1000,0); -ALTER TABLE chain.evm_tokens ALTER COLUMN total_supply type NUMERIC(1000,0); - -COMMIT; diff --git a/storage/migrations/10_runtime_address_preimage_idx.up.sql b/storage/migrations/10_runtime_address_preimage_idx.up.sql deleted file mode 100644 index 9a2b7a39c..000000000 --- a/storage/migrations/10_runtime_address_preimage_idx.up.sql +++ /dev/null @@ -1,8 +0,0 @@ -BEGIN; - --- Note: We use `IF NOT EXISTS` because the index has already been added manually in some places. -CREATE INDEX IF NOT EXISTS ix_address_preimages_address_data ON chain.address_preimages (address_data) - WHERE context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND - context_version = 0; - -COMMIT; diff --git a/storage/migrations/11_agg_stats_refactor.up.sql b/storage/migrations/11_agg_stats_refactor.up.sql deleted file mode 100644 index 350cb2649..000000000 --- a/storage/migrations/11_agg_stats_refactor.up.sql +++ /dev/null @@ -1,35 +0,0 @@ --- Drop stats materialized views and replace with tables. -BEGIN; - --- Drop the old materialized views. -DROP MATERIALIZED VIEW IF EXISTS stats.daily_tx_volume; -DROP MATERIALIZED VIEW IF EXISTS stats.min5_tx_volume; - --- Create new tables. - --- 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'); - --- Grant read-only use for newly-created 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; diff --git a/storage/migrations/12_evm_contract_gas.up.sql b/storage/migrations/12_evm_contract_gas.up.sql deleted file mode 100644 index 1f6e9e414..000000000 --- a/storage/migrations/12_evm_contract_gas.up.sql +++ /dev/null @@ -1,21 +0,0 @@ -BEGIN; - -ALTER TABLE chain.evm_contracts - ADD COLUMN gas_used UINT63 NOT NULL DEFAULT 0; -- moved to chain.runtime_accounts.gas_for_calling in 18_refactor_dead_reckoning.up.sql - --- Used in contract upserts. -CREATE INDEX ix_runtime_transactions_to ON chain.runtime_transactions(runtime, "to"); - --- Backfill the table using chain.runtime_transactions -WITH txs AS ( - SELECT runtime, "to", SUM(gas_used) as total_gas - FROM chain.runtime_transactions - GROUP BY runtime, "to" -) -UPDATE chain.evm_contracts as contracts - SET gas_used = txs.total_gas - FROM txs - WHERE contracts.runtime = txs.runtime AND - contracts.contract_address = txs.to; - -COMMIT; diff --git a/storage/migrations/13_runtime_indexes.up.sql b/storage/migrations/13_runtime_indexes.up.sql deleted file mode 100644 index f10f1d50b..000000000 --- a/storage/migrations/13_runtime_indexes.up.sql +++ /dev/null @@ -1,13 +0,0 @@ -BEGIN; - -DROP INDEX chain.ix_runtime_related_transactions_address; -- This index is a prefix of an existing index and therefore unnecessary - -DROP INDEX chain.ix_runtime_events_tx_hash; -DROP INDEX chain.ix_runtime_events_tx_eth_hash; -DROP INDEX chain.ix_runtime_events_evm_log_signature; - -CREATE INDEX ix_runtime_events_tx_hash ON chain.runtime_events USING hash (tx_hash); -CREATE INDEX ix_runtime_events_tx_eth_hash ON chain.runtime_events USING hash (tx_eth_hash); -CREATE INDEX ix_runtime_events_evm_log_signature ON chain.runtime_events(runtime, evm_log_signature, round); - -COMMIT; diff --git a/storage/migrations/14_evm_token_transfers.up.sql b/storage/migrations/14_evm_token_transfers.up.sql deleted file mode 100644 index 234e18d25..000000000 --- a/storage/migrations/14_evm_token_transfers.up.sql +++ /dev/null @@ -1,44 +0,0 @@ -BEGIN; - -ALTER TABLE chain.evm_tokens ADD COLUMN num_transfers UINT63 NOT NULL DEFAULT 0; -ALTER TABLE analysis.evm_tokens ADD COLUMN num_transfers UINT63 NOT NULL DEFAULT 0; - --- Backfill chain.evm_tokens.num_transfers -WITH transfers AS ( - SELECT runtime, DECODE(body ->> 'address', 'base64') AS eth_addr, COUNT(*) AS num_xfers - FROM chain.runtime_events - GROUP BY runtime, eth_addr -) -UPDATE chain.evm_tokens as tokens - SET num_transfers = transfers.num_xfers - FROM transfers - LEFT JOIN chain.address_preimages as preimages - ON - preimages.address_data = transfers.eth_addr AND - preimages.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND - preimages.context_version = 0 - WHERE - tokens.runtime = transfers.runtime AND - tokens.token_address = preimages.address; - --- Backfill analysis.evm_tokens.num_transfers for tokens that haven't been processed yet. --- These values will be inserted into chain.evm_tokens when the token is downloaded. -WITH transfers AS ( - SELECT runtime, DECODE(body ->> 'address', 'base64') AS eth_addr, COUNT(*) AS num_xfers - FROM chain.runtime_events - GROUP BY runtime, eth_addr -) -UPDATE analysis.evm_tokens as tokens - SET num_transfers = transfers.num_xfers - FROM transfers - LEFT JOIN chain.address_preimages as preimages - ON - preimages.address_data = transfers.eth_addr AND - preimages.context_identifier = 'oasis-runtime-sdk/address: secp256k1eth' AND - preimages.context_version = 0 - WHERE - tokens.runtime = transfers.runtime AND - tokens.token_address = preimages.address AND - tokens.last_download_round IS NULL; - -COMMIT; diff --git a/storage/migrations/15_runtime_account_stats.up.sql b/storage/migrations/15_runtime_account_stats.up.sql deleted file mode 100644 index 6e51133d9..000000000 --- a/storage/migrations/15_runtime_account_stats.up.sql +++ /dev/null @@ -1,23 +0,0 @@ -BEGIN; - -CREATE TABLE chain.runtime_accounts -( - runtime runtime NOT NULL, - address oasis_addr NOT NULL, - PRIMARY KEY (runtime, address), - - num_txs UINT63 NOT NULL DEFAULT 0 - -- gas_for_calling UINT63 NOT NULL DEFAULT 0 -- gas used by txs sent to this address -- added in 18_refactor_dead_reckoning.up.sql -); - --- Backfill chain.runtime_accounts -INSERT INTO chain.runtime_accounts (runtime, address, num_txs) - SELECT runtime, account_address, COUNT(*) - FROM chain.runtime_related_transactions - GROUP BY (runtime, account_address); - --- Grant others read-only use. -GRANT SELECT ON ALL TABLES IN SCHEMA chain TO PUBLIC; -GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA chain TO PUBLIC; - -COMMIT; diff --git a/storage/migrations/16_fast_sync.up.sql b/storage/migrations/16_fast_sync.up.sql deleted file mode 100644 index a3e51cc57..000000000 --- a/storage/migrations/16_fast_sync.up.sql +++ /dev/null @@ -1,8 +0,0 @@ --- Add a column to record whether a block was analyzed in fast-sync mode or not. - -BEGIN; - -ALTER TABLE analysis.processed_blocks - ADD COLUMN is_fast_sync BOOL NOT NULL DEFAULT false; - -COMMIT; diff --git a/storage/migrations/17_latest_node_heights.up.sql b/storage/migrations/17_latest_node_heights.up.sql deleted file mode 100644 index fbbcfe0b5..000000000 --- a/storage/migrations/17_latest_node_heights.up.sql +++ /dev/null @@ -1,14 +0,0 @@ -BEGIN; - --- Tracks the current (consensus) height of the node. TODO: expand to paratime heights. -CREATE TABLE chain.latest_node_heights -( - layer TEXT NOT NULL PRIMARY KEY, - height UINT63 NOT NULL -); - --- 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; - -COMMIT; diff --git a/storage/migrations/18_refactor_dead_reckoning.up.sql b/storage/migrations/18_refactor_dead_reckoning.up.sql deleted file mode 100644 index 8e6a35e51..000000000 --- a/storage/migrations/18_refactor_dead_reckoning.up.sql +++ /dev/null @@ -1,108 +0,0 @@ -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; -$$; - - -------------------------------------- --- Moves the chain.evm_contracts.gas_used column to chain.runtime_accounts.gas_for_calling - -ALTER TABLE chain.runtime_accounts - -- Total gas used by all txs addressed to this account. Primarily meaningful for accounts that are contracts. - ADD COLUMN gas_for_calling UINT63 NOT NULL DEFAULT 0; - -UPDATE chain.runtime_accounts as ra - SET gas_for_calling = c.gas_used - FROM chain.evm_contracts c - WHERE c.runtime = ra.runtime AND - c.contract_address = ra.address; - -ALTER TABLE chain.evm_contracts - DROP COLUMN gas_used; - - -------------------------------------- --- Merges the analysis.evm_tokens table into chain.evm_tokens -ALTER TABLE chain.evm_tokens - ALTER COLUMN token_type DROP NOT NULL; -ALTER TABLE chain.evm_tokens - -- Block analyzer bumps this when it sees the mutable fields of the token - -- change (e.g. total supply) based on dead reckoning. - ADD COLUMN last_mutate_round UINT63 NOT NULL DEFAULT 0, - -- Token analyzer bumps this when it downloads info about the token. - ADD COLUMN last_download_round UINT63; - -WITH transfers AS ( - SELECT runtime, DECODE(body ->> 'address', 'base64') AS eth_addr, COUNT(*) AS num_xfers - FROM chain.runtime_events - WHERE evm_log_signature='\xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'::bytea -- ERC-20 and ERC-721 Transfer - GROUP BY runtime, eth_addr -) -INSERT INTO chain.evm_tokens(runtime, token_address, total_supply, num_transfers, last_mutate_round, last_download_round) -SELECT - runtime, - token_address, - total_supply, - num_transfers, - last_mutate_round, - last_download_round -FROM analysis.evm_tokens AS tokens -ON CONFLICT(runtime, token_address) DO UPDATE SET - total_supply = EXCLUDED.total_supply, - num_transfers = EXCLUDED.num_transfers, - last_mutate_round = EXCLUDED.last_mutate_round, - last_download_round = EXCLUDED.last_download_round; - -DROP TABLE analysis.evm_tokens; - -COMMIT; diff --git a/storage/migrations/19_runtime_tx_errors.up.sql b/storage/migrations/19_runtime_tx_errors.up.sql deleted file mode 100644 index 7f904a791..000000000 --- a/storage/migrations/19_runtime_tx_errors.up.sql +++ /dev/null @@ -1,9 +0,0 @@ -BEGIN; - -ALTER TABLE chain.runtime_transactions - -- The unparsed transaction error message. The "parsed" version will be - -- identical in the majority of cases. One notable exception are txs that - -- were reverted inside the EVM; for those, the raw msg is abi-encoded. - ADD COLUMN error_message_raw TEXT; - -COMMIT; diff --git a/storage/migrations/20_simplify_deposit_withdraw.up.sql b/storage/migrations/20_simplify_deposit_withdraw.up.sql deleted file mode 100644 index 8114c2db5..000000000 --- a/storage/migrations/20_simplify_deposit_withdraw.up.sql +++ /dev/null @@ -1,6 +0,0 @@ -BEGIN; - -DROP TABLE IF EXISTS chain.runtime_deposits; -DROP TABLE IF EXISTS chain.runtime_withdraws; - -COMMIT; diff --git a/storage/migrations/21_evm_nfts.up.sql b/storage/migrations/21_evm_nfts.up.sql deleted file mode 100644 index 994a5dba8..000000000 --- a/storage/migrations/21_evm_nfts.up.sql +++ /dev/null @@ -1,26 +0,0 @@ -BEGIN; - -CREATE TABLE chain.evm_nfts ( - runtime runtime NOT NULL, - token_address oasis_addr NOT NULL, - nft_id uint_numeric NOT NULL, - PRIMARY KEY (runtime, token_address, nft_id), - - -- Added in 22_evm_nfts_2.up.sql - -- owner oasis_addr, - -- num_transfers INT NOT NULL, - - last_want_download_round UINT63 NOT NULL, - last_download_round UINT63, - - metadata_uri TEXT, - metadata_accessed TIMESTAMP, - name TEXT, - description TEXT, - image TEXT -); -CREATE INDEX ix_evm_nfts_stale ON chain.evm_nfts (runtime, token_address, nft_id) WHERE last_download_round IS NULL OR last_want_download_round > last_download_round; --- Added in 22_evm_nfts_2.up.sql --- CREATE INDEX ix_evm_nfts_owner ON chain.evm_nfts (runtime, owner, token_address, nft_id); - -COMMIT; diff --git a/storage/migrations/22_evm_nfts.up.sql b/storage/migrations/22_evm_nfts.up.sql deleted file mode 100644 index cd3bbf960..000000000 --- a/storage/migrations/22_evm_nfts.up.sql +++ /dev/null @@ -1,13 +0,0 @@ -BEGIN; - -ALTER TABLE chain.evm_nfts - ADD COLUMN owner oasis_addr, - ADD COLUMN num_transfers INT NOT NULL DEFAULT 0; - -CREATE INDEX ix_evm_nfts_owner ON chain.evm_nfts (runtime, owner, token_address, nft_id); - --- Grant others read-only use. -GRANT SELECT ON ALL TABLES IN SCHEMA chain TO PUBLIC; -GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA chain TO PUBLIC; - -COMMIT; diff --git a/storage/migrations/23_evm_nfts.up.sql b/storage/migrations/23_evm_nfts.up.sql deleted file mode 100644 index 08d206fda..000000000 --- a/storage/migrations/23_evm_nfts.up.sql +++ /dev/null @@ -1,6 +0,0 @@ -BEGIN; - -ALTER TABLE chain.evm_nfts - ADD COLUMN metadata JSONB; - -COMMIT;