Merge pull request #56 from vulcanize/release-v4.0.0-alpha

v4.0.0 alpha
This commit is contained in:
Ian Norden 2022-04-05 19:12:30 -05:00 committed by GitHub
commit f89ea6134f
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
11 changed files with 450 additions and 111 deletions

View File

@ -1,7 +1,7 @@
-- +goose Up
CREATE TABLE IF NOT EXISTS public.blocks (
block_number BIGINT NOT NULL,
key TEXT UNIQUE NOT NULL,
key TEXT NOT NULL,
data BYTEA NOT NULL,
PRIMARY KEY (key, block_number)
);

View File

@ -9,7 +9,7 @@ CREATE TABLE IF NOT EXISTS eth.state_cids (
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (header_id, state_path)
PRIMARY KEY (state_path, header_id)
);
-- +goose Down

View File

@ -10,8 +10,8 @@ CREATE TABLE IF NOT EXISTS eth.storage_cids (
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (header_id, state_path, storage_path)
FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (storage_path, state_path, header_id)
);
-- +goose Down

View File

@ -7,8 +7,8 @@ CREATE TABLE IF NOT EXISTS eth.state_accounts (
nonce BIGINT NOT NULL,
code_hash BYTEA NOT NULL,
storage_root VARCHAR(66) NOT NULL,
FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (header_id, state_path)
FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (state_path, header_id)
);
-- +goose Down

View File

@ -2,26 +2,27 @@
-- header indexes
CREATE INDEX header_block_number_index ON eth.header_cids USING brin (block_number);
CREATE UNIQUE INDEX header_cid_index ON eth.header_cids USING btree (cid);
CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
CREATE UNIQUE INDEX header_mh_block_number_index ON eth.header_cids USING btree (mh_key, block_number);
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);
-- uncle indexes
CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number);
CREATE UNIQUE INDEX uncle_mh_block_number_index ON eth.uncle_cids USING btree (mh_key, block_number);
CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id);
-- transaction indexes
CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_number);
CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
CREATE UNIQUE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid);
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
CREATE UNIQUE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
CREATE INDEX tx_dst_index ON eth.transaction_cids USING btree (dst);
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
-- receipt indexes
CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number);
CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid);
CREATE INDEX rct_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);
CREATE INDEX rct_leaf_mh_block_number_index ON eth.receipt_cids USING btree (leaf_mh_key, block_number);
CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash);
@ -29,8 +30,8 @@ CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_h
CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number);
CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key);
CREATE INDEX state_cid_index ON eth.state_cids USING btree (cid);
CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
CREATE INDEX state_mh_block_number_index ON eth.state_cids USING btree (mh_key, block_number);
CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
-- storage node indexes
@ -38,14 +39,14 @@ CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_nu
CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path);
CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key);
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number);
CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id);
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
-- state accounts indexes
CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number);
CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_path);
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);
CREATE INDEX account_header_id_index ON eth.state_accounts USING btree (header_id);
CREATE INDEX account_storage_root_index ON eth.state_accounts USING btree (storage_root);
-- access list indexes
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
@ -54,7 +55,7 @@ CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gi
-- log indexes
CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number);
CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key);
CREATE INDEX log_leaf_mh_block_number_index ON eth.log_cids USING btree (leaf_mh_key, block_number);
CREATE INDEX log_cid_index ON eth.log_cids USING btree (leaf_cid);
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
CREATE INDEX log_topic0_index ON eth.log_cids USING btree (topic0);
@ -70,7 +71,7 @@ DROP INDEX eth.log_topic1_index;
DROP INDEX eth.log_topic0_index;
DROP INDEX eth.log_address_index;
DROP INDEX eth.log_cid_index;
DROP INDEX eth.log_mh_index;
DROP INDEX eth.log_leaf_mh_block_number_index;
DROP INDEX eth.log_block_number_index;
-- access list indexes
@ -79,14 +80,14 @@ DROP INDEX eth.access_list_element_address_index;
DROP INDEX eth.access_list_block_number_index;
-- state account indexes
DROP INDEX eth.storage_root_index;
DROP index eth.account_state_path_index;
DROP INDEX eth.account_storage_root_index;
DROP index eth.account_header_id_index;
DROP INDEX eth.account_block_number_index;
-- storage node indexes
DROP INDEX eth.storage_node_type_index;
DROP INDEX eth.storage_path_index;
DROP INDEX eth.storage_mh_index;
DROP INDEX eth.storage_header_id_index;
DROP INDEX eth.storage_mh_block_number_index;
DROP INDEX eth.storage_cid_index;
DROP INDEX eth.storage_leaf_key_index;
DROP INDEX eth.storage_state_path_index;
@ -94,8 +95,8 @@ DROP INDEX eth.storage_block_number_index;
-- state node indexes
DROP INDEX eth.state_node_type_index;
DROP INDEX eth.state_path_index;
DROP INDEX eth.state_mh_index;
DROP INDEX eth.state_header_id_index;
DROP INDEX eth.state_mh_block_number_index;
DROP INDEX eth.state_cid_index;
DROP INDEX eth.state_leaf_key_index;
DROP INDEX eth.state_block_number_index;
@ -103,25 +104,26 @@ DROP INDEX eth.state_block_number_index;
-- receipt indexes
DROP INDEX eth.rct_contract_hash_index;
DROP INDEX eth.rct_contract_index;
DROP INDEX eth.rct_leaf_mh_index;
DROP INDEX eth.rct_leaf_mh_block_number_index;
DROP INDEX eth.rct_leaf_cid_index;
DROP INDEX eth.rct_block_number_index;
-- transaction indexes
DROP INDEX eth.tx_src_index;
DROP INDEX eth.tx_dst_index;
DROP INDEX eth.tx_mh_index;
DROP INDEX eth.tx_mh_block_number_index;
DROP INDEX eth.tx_cid_index;
DROP INDEX eth.tx_header_id_index;
DROP INDEX eth.tx_block_number_index;
-- uncle indexes
DROP INDEX eth.uncle_header_id_index;
DROP INDEX eth.uncle_block_number_index;
DROP INDEX eth.uncle_mh_block_number_index;
DROP INDEX eth.uncle_header_id_index;
-- header indexes
DROP INDEX eth.timestamp_index;
DROP INDEX eth.state_root_index;
DROP INDEX eth.header_mh_index;
DROP INDEX eth.header_mh_block_number_index;
DROP INDEX eth.header_cid_index;
DROP INDEX eth.header_block_number_index;

View File

@ -125,12 +125,124 @@ BEGIN
canonical_header = canonical_header_from_array(headers);
RETURN canonical_header.block_hash;
END IF;
END;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE state_node_result AS (
data BYTEA,
state_leaf_key VARCHAR(66),
cid TEXT,
state_path BYTEA,
node_type INTEGER,
mh_key TEXT
);
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION state_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS
$BODY$
DECLARE
canonical_hash VARCHAR(66);
results state_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
canonical_hash = canonical_header_hash(ending_height);
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the state nodes for this snapshot: the latest state node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path) blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key
INTO results
FROM eth.state_cids
INNER JOIN public.blocks
ON (state_cids.mh_key, state_cids.block_number) = (blocks.key, blocks.block_number)
WHERE state_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.state_cids (block_number, header_id, state_leaf_key, cid, state_path, node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_leaf_key, r.cid, r.state_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (state_path, header_id) DO NOTHING;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE storage_node_result AS (
data BYTEA,
state_path BYTEA,
storage_leaf_key VARCHAR(66),
cid TEXT,
storage_path BYTEA,
node_type INTEGER,
mh_key TEXT
);
-- +goose StatementEnd
-- +goose StatementBegin
-- this should only be ran after a state_snapshot has been completed
-- this should probably be rolled together with state_snapshot into a single procedure...
CREATE OR REPLACE FUNCTION storage_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS
$BODY$
DECLARE
canonical_hash VARCHAR(66);
results storage_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
SELECT canonical_header_hash(ending_height) INTO canonical_hash;
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
storage_cids.cid, storage_cids.storage_path, storage_cids.node_type, storage_cids.mh_key
INTO results
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, storage_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.storage_cids (block_number, header_id, state_path, storage_leaf_key, cid, storage_path,
node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_path, r.storage_leaf_key, r.cid, r.storage_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (storage_path, state_path, header_id) DO NOTHING;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose Down
DROP FUNCTION storage_snapshot;
DROP TYPE storage_node_result;
DROP FUNCTION state_snapshot;
DROP TYPE state_node_result;
DROP FUNCTION was_state_leaf_removed;
DROP FUNCTION canonical_header_hash;
DROP FUNCTION canonical_header_from_array;

View File

@ -9,13 +9,13 @@ ALTER TABLE eth.log_cids
ADD CONSTRAINT pk_eth_log_cids PRIMARY KEY (rct_id, index);
ALTER TABLE eth.state_cids
ADD CONSTRAINT pk_eth_state_cids PRIMARY KEY (header_id, state_path);
ADD CONSTRAINT pk_eth_state_cids PRIMARY KEY (state_path, header_id);
ALTER TABLE eth.storage_cids
ADD CONSTRAINT pk_eth_storage_cids PRIMARY KEY (header_id, state_path, storage_path);
ADD CONSTRAINT pk_eth_storage_cids PRIMARY KEY (storage_path, state_path, header_id);
ALTER TABLE eth.state_accounts
ADD CONSTRAINT pk_eth_state_accounts PRIMARY KEY (header_id, state_path);
ADD CONSTRAINT pk_eth_state_accounts PRIMARY KEY (state_path, header_id);
-- +goose Down
ALTER TABLE eth.state_accounts

View File

@ -56,12 +56,12 @@ ADD CONSTRAINT fk_storage_mh_key
ALTER TABLE eth.storage_cids
ADD CONSTRAINT fk_storage_header_id_state_path
FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path)
FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE eth.state_accounts
ADD CONSTRAINT fk_account_header_id_state_path
FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path)
FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE eth.access_list_elements

View File

@ -2,26 +2,27 @@
-- header indexes
CREATE INDEX header_block_number_index ON eth.header_cids USING brin (block_number);
CREATE UNIQUE INDEX header_cid_index ON eth.header_cids USING btree (cid);
CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
CREATE UNIQUE INDEX header_mh_block_number_index ON eth.header_cids USING btree (mh_key, block_number);
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);
-- uncle indexes
CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number);
CREATE UNIQUE INDEX uncle_mh_block_number_index ON eth.uncle_cids USING btree (mh_key, block_number);
CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id);
-- transaction indexes
CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_number);
CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
CREATE UNIQUE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid);
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
CREATE UNIQUE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
CREATE INDEX tx_dst_index ON eth.transaction_cids USING btree (dst);
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
-- receipt indexes
CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number);
CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid);
CREATE INDEX rct_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);
CREATE INDEX rct_leaf_mh_block_number_index ON eth.receipt_cids USING btree (leaf_mh_key, block_number);
CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash);
@ -29,8 +30,8 @@ CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_h
CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number);
CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key);
CREATE INDEX state_cid_index ON eth.state_cids USING btree (cid);
CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
CREATE INDEX state_mh_block_number_index ON eth.state_cids USING btree (mh_key, block_number);
CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
-- storage node indexes
@ -38,14 +39,14 @@ CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_nu
CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path);
CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key);
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number);
CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id);
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
-- state accounts indexes
CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number);
CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_path);
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);
CREATE INDEX account_header_id_index ON eth.state_accounts USING btree (header_id);
CREATE INDEX account_storage_root_index ON eth.state_accounts USING btree (storage_root);
-- access list indexes
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
@ -54,8 +55,8 @@ CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gi
-- log indexes
CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number);
CREATE INDEX log_leaf_mh_block_number_index ON eth.log_cids USING btree (leaf_mh_key, block_number);
CREATE INDEX log_cid_index ON eth.log_cids USING btree (leaf_cid);
CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key);
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
CREATE INDEX log_topic0_index ON eth.log_cids USING btree (topic0);
CREATE INDEX log_topic1_index ON eth.log_cids USING btree (topic1);
@ -69,8 +70,8 @@ DROP INDEX eth.log_topic2_index;
DROP INDEX eth.log_topic1_index;
DROP INDEX eth.log_topic0_index;
DROP INDEX eth.log_address_index;
DROP INDEX eth.log_mh_index;
DROP INDEX eth.log_cid_index;
DROP INDEX eth.log_leaf_mh_block_number_index;
DROP INDEX eth.log_block_number_index;
-- access list indexes
@ -79,14 +80,14 @@ DROP INDEX eth.access_list_element_address_index;
DROP INDEX eth.access_list_block_number_index;
-- state account indexes
DROP INDEX eth.storage_root_index;
DROP index eth.account_state_path_index;
DROP INDEX eth.account_storage_root_index;
DROP index eth.account_header_id_index;
DROP INDEX eth.account_block_number_index;
-- storage node indexes
DROP INDEX eth.storage_node_type_index;
DROP INDEX eth.storage_path_index;
DROP INDEX eth.storage_mh_index;
DROP INDEX eth.storage_header_id_index;
DROP INDEX eth.storage_mh_block_number_index;
DROP INDEX eth.storage_cid_index;
DROP INDEX eth.storage_leaf_key_index;
DROP INDEX eth.storage_state_path_index;
@ -94,8 +95,8 @@ DROP INDEX eth.storage_block_number_index;
-- state node indexes
DROP INDEX eth.state_node_type_index;
DROP INDEX eth.state_path_index;
DROP INDEX eth.state_mh_index;
DROP INDEX eth.state_header_id_index;
DROP INDEX eth.state_mh_block_number_index;
DROP INDEX eth.state_cid_index;
DROP INDEX eth.state_leaf_key_index;
DROP INDEX eth.state_block_number_index;
@ -103,25 +104,26 @@ DROP INDEX eth.state_block_number_index;
-- receipt indexes
DROP INDEX eth.rct_contract_hash_index;
DROP INDEX eth.rct_contract_index;
DROP INDEX eth.rct_leaf_mh_index;
DROP INDEX eth.rct_leaf_mh_block_number_index;
DROP INDEX eth.rct_leaf_cid_index;
DROP INDEX eth.rct_block_number_index;
-- transaction indexes
DROP INDEX eth.tx_src_index;
DROP INDEX eth.tx_dst_index;
DROP INDEX eth.tx_mh_index;
DROP INDEX eth.tx_mh_block_number_index;
DROP INDEX eth.tx_cid_index;
DROP INDEX eth.tx_header_id_index;
DROP INDEX eth.tx_block_number_index;
-- uncle indexes
DROP INDEX eth.uncle_header_id_index;
DROP INDEX eth.uncle_block_number_index;
DROP INDEX eth.uncle_mh_block_number_index;
DROP INDEX eth.uncle_header_id_index;
-- header indexes
DROP INDEX eth.timestamp_index;
DROP INDEX eth.state_root_index;
DROP INDEX eth.header_mh_index;
DROP INDEX eth.header_mh_block_number_index;
DROP INDEX eth.header_cid_index;
DROP INDEX eth.header_block_number_index;

View File

@ -131,7 +131,119 @@ $BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE state_node_result AS (
data BYTEA,
state_leaf_key VARCHAR(66),
cid TEXT,
state_path BYTEA,
node_type INTEGER,
mh_key TEXT
);
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION state_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS
$BODY$
DECLARE
canonical_hash VARCHAR(66);
results state_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
canonical_hash = canonical_header_hash(ending_height);
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the state nodes for this snapshot: the latest state node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path) blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key
INTO results
FROM eth.state_cids
INNER JOIN public.blocks
ON (state_cids.mh_key, state_cids.block_number) = (blocks.key, blocks.block_number)
WHERE state_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.state_cids (block_number, header_id, state_leaf_key, cid, state_path, node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_leaf_key, r.cid, r.state_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (state_path, header_id) DO NOTHING;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE storage_node_result AS (
data BYTEA,
state_path BYTEA,
storage_leaf_key VARCHAR(66),
cid TEXT,
storage_path BYTEA,
node_type INTEGER,
mh_key TEXT
);
-- +goose StatementEnd
-- +goose StatementBegin
-- this should only be ran after a state_snapshot has been completed
-- this should probably be rolled together with state_snapshot into a single procedure...
CREATE OR REPLACE FUNCTION storage_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS
$BODY$
DECLARE
canonical_hash VARCHAR(66);
results storage_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
SELECT canonical_header_hash(ending_height) INTO canonical_hash;
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
storage_cids.cid, storage_cids.storage_path, storage_cids.node_type, storage_cids.mh_key
INTO results
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, storage_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.storage_cids (block_number, header_id, state_path, storage_leaf_key, cid, storage_path,
node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_path, r.storage_leaf_key, r.cid, r.storage_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (storage_path, state_path, header_id) DO NOTHING;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose Down
DROP FUNCTION storage_snapshot;
DROP TYPE storage_node_result;
DROP FUNCTION state_snapshot;
DROP TYPE state_node_result;
DROP FUNCTION was_state_leaf_removed;
DROP FUNCTION canonical_header_hash;
DROP FUNCTION canonical_header_from_array;

View File

@ -75,6 +75,35 @@ CREATE TYPE public.child_result AS (
);
--
-- Name: state_node_result; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE public.state_node_result AS (
data bytea,
state_leaf_key character varying(66),
cid text,
state_path bytea,
node_type integer,
mh_key text
);
--
-- Name: storage_node_result; Type: TYPE; Schema: public; Owner: -
--
CREATE TYPE public.storage_node_result AS (
data bytea,
state_path bytea,
storage_leaf_key character varying(66),
cid text,
storage_path bytea,
node_type integer,
mh_key text
);
--
-- Name: graphql_subscription(); Type: FUNCTION; Schema: eth; Owner: -
--
@ -217,7 +246,7 @@ BEGIN
canonical_header = canonical_header_from_array(headers);
RETURN canonical_header.block_hash;
END IF;
END;
END
$$;
@ -254,6 +283,89 @@ END
$$;
--
-- Name: state_snapshot(bigint, bigint); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.state_snapshot(starting_height bigint, ending_height bigint) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
canonical_hash VARCHAR(66);
results state_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
canonical_hash = canonical_header_hash(ending_height);
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the state nodes for this snapshot: the latest state node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path) blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key
INTO results
FROM eth.state_cids
INNER JOIN public.blocks
ON (state_cids.mh_key, state_cids.block_number) = (blocks.key, blocks.block_number)
WHERE state_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.state_cids (block_number, header_id, state_leaf_key, cid, state_path, node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_leaf_key, r.cid, r.state_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (state_path, header_id) DO NOTHING;
END
$$;
--
-- Name: storage_snapshot(bigint, bigint); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.storage_snapshot(starting_height bigint, ending_height bigint) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
canonical_hash VARCHAR(66);
results storage_node_result[];
BEGIN
-- get the canonical hash for the header at ending_height
SELECT canonical_header_hash(ending_height) INTO canonical_hash;
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
storage_cids.cid, storage_cids.storage_path, storage_cids.node_type, storage_cids.mh_key
INTO results
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, storage_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
SELECT ending_height, r.mh_key, r.data
FROM results r;
-- from the set returned above, insert eth.state_cids records at the ending_height block number
-- anchoring all the records to the canonical header found at ending_height
INSERT INTO eth.storage_cids (block_number, header_id, state_path, storage_leaf_key, cid, storage_path,
node_type, diff, mh_key)
SELECT ending_height, canonical_hash, r.state_path, r.storage_leaf_key, r.cid, r.storage_path, r.node_type, false, r.mh_key
FROM results r
ON CONFLICT (storage_path, state_path, header_id) DO NOTHING;
END
$$;
--
-- Name: was_state_leaf_removed(character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
--
@ -536,7 +648,7 @@ ALTER TABLE ONLY eth.receipt_cids
--
ALTER TABLE ONLY eth.state_accounts
ADD CONSTRAINT state_accounts_pkey PRIMARY KEY (header_id, state_path);
ADD CONSTRAINT state_accounts_pkey PRIMARY KEY (state_path, header_id);
--
@ -544,7 +656,7 @@ ALTER TABLE ONLY eth.state_accounts
--
ALTER TABLE ONLY eth.state_cids
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (header_id, state_path);
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (state_path, header_id);
--
@ -552,7 +664,7 @@ ALTER TABLE ONLY eth.state_cids
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (header_id, state_path, storage_path);
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (storage_path, state_path, header_id);
--
@ -571,14 +683,6 @@ ALTER TABLE ONLY eth.uncle_cids
ADD CONSTRAINT uncle_cids_pkey PRIMARY KEY (block_hash);
--
-- Name: blocks blocks_key_key; Type: CONSTRAINT; Schema: public; Owner: -
--
ALTER TABLE ONLY public.blocks
ADD CONSTRAINT blocks_key_key UNIQUE (key);
--
-- Name: blocks blocks_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--
@ -640,10 +744,17 @@ CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_
--
-- Name: account_state_path_index; Type: INDEX; Schema: eth; Owner: -
-- Name: account_header_id_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_path);
CREATE INDEX account_header_id_index ON eth.state_accounts USING btree (header_id);
--
-- Name: account_storage_root_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX account_storage_root_index ON eth.state_accounts USING btree (storage_root);
--
@ -661,10 +772,10 @@ CREATE UNIQUE INDEX header_cid_index ON eth.header_cids USING btree (cid);
--
-- Name: header_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: header_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
CREATE UNIQUE INDEX header_mh_block_number_index ON eth.header_cids USING btree (mh_key, block_number);
--
@ -689,10 +800,10 @@ CREATE INDEX log_cid_index ON eth.log_cids USING btree (leaf_cid);
--
-- Name: log_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: log_leaf_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key);
CREATE INDEX log_leaf_mh_block_number_index ON eth.log_cids USING btree (leaf_mh_key, block_number);
--
@ -752,10 +863,10 @@ CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid);
--
-- Name: rct_leaf_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: rct_leaf_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX rct_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);
CREATE INDEX rct_leaf_mh_block_number_index ON eth.receipt_cids USING btree (leaf_mh_key, block_number);
--
@ -772,6 +883,13 @@ CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number
CREATE INDEX state_cid_index ON eth.state_cids USING btree (cid);
--
-- Name: state_header_id_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
--
-- Name: state_leaf_key_index; Type: INDEX; Schema: eth; Owner: -
--
@ -780,10 +898,10 @@ CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key)
--
-- Name: state_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: state_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
CREATE INDEX state_mh_block_number_index ON eth.state_cids USING btree (mh_key, block_number);
--
@ -793,13 +911,6 @@ CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
--
-- Name: state_path_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
--
-- Name: state_root_index; Type: INDEX; Schema: eth; Owner: -
--
@ -821,6 +932,13 @@ CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_nu
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
--
-- Name: storage_header_id_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id);
--
-- Name: storage_leaf_key_index; Type: INDEX; Schema: eth; Owner: -
--
@ -829,10 +947,10 @@ CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_lea
--
-- Name: storage_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: storage_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number);
--
@ -842,20 +960,6 @@ CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
--
-- Name: storage_path_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
--
-- Name: storage_root_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);
--
-- Name: storage_state_path_index; Type: INDEX; Schema: eth; Owner: -
--
@ -899,10 +1003,10 @@ CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
--
-- Name: tx_mh_index; Type: INDEX; Schema: eth; Owner: -
-- Name: tx_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
CREATE UNIQUE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
--
@ -926,6 +1030,13 @@ CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number
CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id);
--
-- Name: uncle_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE UNIQUE INDEX uncle_mh_block_number_index ON eth.uncle_cids USING btree (mh_key, block_number);
--
-- Name: access_list_elements trg_eth_access_list_elements; Type: TRIGGER; Schema: eth; Owner: -
--
@ -1046,11 +1157,11 @@ ALTER TABLE ONLY eth.receipt_cids
--
-- Name: state_accounts state_accounts_header_id_state_path_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: state_accounts state_accounts_state_path_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.state_accounts
ADD CONSTRAINT state_accounts_header_id_state_path_fkey FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids(header_id, state_path) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT state_accounts_state_path_header_id_fkey FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids(state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
@ -1069,14 +1180,6 @@ ALTER TABLE ONLY eth.state_cids
ADD CONSTRAINT state_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: storage_cids storage_cids_header_id_state_path_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_header_id_state_path_fkey FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids(header_id, state_path) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: storage_cids storage_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
@ -1085,6 +1188,14 @@ ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: storage_cids storage_cids_state_path_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_state_path_header_id_fkey FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids(state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: transaction_cids transaction_cids_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--