Merge pull request #120 from cerc-io/ian_v5

v5 part 3
This commit is contained in:
Ian Norden 2023-02-01 21:12:34 -06:00 committed by GitHub
commit 27e923f70d
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
19 changed files with 223 additions and 500 deletions

View File

@ -5,7 +5,7 @@ CREATE TABLE IF NOT EXISTS eth.header_cids (
parent_hash VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
td NUMERIC NOT NULL,
node_id VARCHAR(128) NOT NULL,
node_ids VARCHAR(128)[] NOT NULL,
reward NUMERIC NOT NULL,
state_root VARCHAR(66) NOT NULL,
tx_root VARCHAR(66) NOT NULL,
@ -14,7 +14,6 @@ CREATE TABLE IF NOT EXISTS eth.header_cids (
bloom BYTEA NOT NULL,
timestamp BIGINT NOT NULL,
mh_key TEXT NOT NULL,
times_validated INTEGER NOT NULL DEFAULT 1,
coinbase VARCHAR(66) NOT NULL,
PRIMARY KEY (block_hash, block_number)
);

View File

@ -2,13 +2,17 @@
CREATE TABLE IF NOT EXISTS eth.state_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_leaf_key VARCHAR(66),
state_leaf_key VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
state_path BYTEA NOT NULL,
node_type INTEGER NOT NULL,
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL,
PRIMARY KEY (state_path, header_id, block_number)
balance NUMERIC, -- NULL if "removed"
nonce BIGINT, -- NULL if "removed"
code_hash VARCHAR(66), -- NULL if "removed"
storage_root VARCHAR(66), -- NULL if "removed"
removed BOOLEAN NOT NULL,
PRIMARY KEY (state_leaf_key, header_id, block_number)
);
-- +goose Down

View File

@ -2,14 +2,15 @@
CREATE TABLE IF NOT EXISTS eth.storage_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_path BYTEA NOT NULL,
storage_leaf_key VARCHAR(66),
state_leaf_key VARCHAR(66) NOT NULL,
storage_leaf_key VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
storage_path BYTEA NOT NULL,
node_type INTEGER NOT NULL,
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL,
PRIMARY KEY (storage_path, state_path, header_id, block_number)
val BYTEA, -- NULL if "removed"
removed BOOLEAN NOT NULL,
PRIMARY KEY (storage_leaf_key, state_leaf_key, header_id, block_number)
);
-- +goose Down

View File

@ -1,14 +0,0 @@
-- +goose Up
CREATE TABLE IF NOT EXISTS eth.state_accounts (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_path BYTEA NOT NULL,
balance NUMERIC NOT NULL,
nonce BIGINT NOT NULL,
code_hash VARCHAR(66) NOT NULL,
storage_root VARCHAR(66) NOT NULL,
PRIMARY KEY (state_path, header_id, block_number)
);
-- +goose Down
DROP TABLE eth.state_accounts;

View File

@ -3,7 +3,7 @@ COMMENT ON TABLE public.nodes IS E'@name NodeInfo';
COMMENT ON TABLE eth.transaction_cids IS E'@name EthTransactionCids';
COMMENT ON TABLE eth.header_cids IS E'@name EthHeaderCids';
COMMENT ON COLUMN public.nodes.node_id IS E'@name ChainNodeID';
COMMENT ON COLUMN eth.header_cids.node_id IS E'@name EthNodeID';
COMMENT ON COLUMN eth.header_cids.node_ids IS E'@name EthNodeIDs';
-- +goose Down
@ -11,4 +11,4 @@ COMMENT ON TABLE public.nodes IS NULL;
COMMENT ON TABLE eth.transaction_cids IS NULL;
COMMENT ON TABLE eth.header_cids IS NULL;
COMMENT ON COLUMN public.nodes.node_id IS NULL;
COMMENT ON COLUMN eth.header_cids.node_id IS NULL;
COMMENT ON COLUMN eth.header_cids.node_ids IS NULL;

View File

@ -30,25 +30,23 @@ CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_h
-- state node indexes
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_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);
CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
CREATE INDEX state_removed_index ON eth.state_cids USING btree (removed);
CREATE INDEX state_code_hash_index ON eth.state_cids USING btree (code_hash); -- could be useful for e.g. selecting all the state accounts with the same contract bytecode deployed
CREATE INDEX state_leaf_key_block_number_index ON eth.state_cids(state_leaf_key, block_number DESC);
-- storage node indexes
CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number);
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_state_leaf_key_index ON eth.storage_cids USING btree (state_leaf_key);
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
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_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);
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
CREATE INDEX storage_removed_index ON eth.storage_cids USING btree (removed);
CREATE INDEX storage_leaf_key_block_number_index ON eth.storage_cids(storage_leaf_key, block_number DESC);
-- access list indexes
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
@ -85,27 +83,26 @@ DROP INDEX eth.access_list_storage_keys_index;
DROP INDEX eth.access_list_element_address_index;
DROP INDEX eth.access_list_block_number_index;
-- state account indexes
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_removed_index;
DROP INDEX eth.storage_path_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;
DROP INDEX eth.storage_state_leaf_key_index;
DROP INDEX eth.storage_block_number_index;
DROP INDEX eth.storage_leaf_key_block_number_index;
-- state node indexes
DROP INDEX eth.state_node_type_index;
DROP INDEX eth.state_code_hash_index;
DROP INDEX eth.state_removed_index;
DROP INDEX eth.state_path_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;
DROP INDEX eth.state_leaf_key_block_number_index;
-- receipt indexes
DROP INDEX eth.rct_contract_hash_index;

View File

@ -6,7 +6,7 @@ CREATE FUNCTION eth.graphql_subscription() RETURNS TRIGGER AS $$
DECLARE
obj jsonb;
BEGIN
IF (TG_TABLE_NAME = 'state_cids') OR (TG_TABLE_NAME = 'state_accounts') THEN
IF (TG_TABLE_NAME = 'state_cids') THEN
obj := json_build_array(
TG_TABLE_NAME,
NEW.header_id,
@ -95,11 +95,6 @@ CREATE TRIGGER trg_eth_storage_cids
FOR EACH ROW
EXECUTE PROCEDURE eth.graphql_subscription();
CREATE TRIGGER trg_eth_state_accounts
AFTER INSERT ON eth.state_accounts
FOR EACH ROW
EXECUTE PROCEDURE eth.graphql_subscription();
CREATE TRIGGER trg_eth_access_list_elements
AFTER INSERT ON eth.access_list_elements
FOR EACH ROW
@ -110,10 +105,9 @@ DROP TRIGGER trg_eth_uncle_cids ON eth.uncle_cids;
DROP TRIGGER trg_eth_transaction_cids ON eth.transaction_cids;
DROP TRIGGER trg_eth_storage_cids ON eth.storage_cids;
DROP TRIGGER trg_eth_state_cids ON eth.state_cids;
DROP TRIGGER trg_eth_state_accounts ON eth.state_accounts;
DROP TRIGGER trg_eth_receipt_cids ON eth.receipt_cids;
DROP TRIGGER trg_eth_header_cids ON eth.header_cids;
DROP TRIGGER trg_eth_log_cids ON eth.log_cids;
DROP TRIGGER trg_eth_access_list_elements ON eth.access_list_elements;
DROP FUNCTION eth.graphql_subscription();
DROP FUNCTION eth.graphql_subscription();

View File

@ -6,7 +6,6 @@ SELECT create_hypertable('eth.transaction_cids', 'block_number', migrate_data =>
SELECT create_hypertable('eth.receipt_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.state_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.storage_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.state_accounts', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.access_list_elements', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.log_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
@ -22,7 +21,6 @@ INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.0')
-- create new regular tables
CREATE TABLE eth.log_cids_i (LIKE eth.log_cids INCLUDING ALL);
CREATE TABLE eth.access_list_elements_i (LIKE eth.access_list_elements INCLUDING ALL);
CREATE TABLE eth.state_accounts_i (LIKE eth.state_accounts INCLUDING ALL);
CREATE TABLE eth.storage_cids_i (LIKE eth.storage_cids INCLUDING ALL);
CREATE TABLE eth.state_cids_i (LIKE eth.state_cids INCLUDING ALL);
CREATE TABLE eth.receipt_cids_i (LIKE eth.receipt_cids INCLUDING ALL);
@ -34,7 +32,6 @@ CREATE TABLE public.blocks_i (LIKE public.blocks INCLUDING ALL);
-- migrate data
INSERT INTO eth.log_cids_i (SELECT * FROM eth.log_cids);
INSERT INTO eth.access_list_elements_i (SELECT * FROM eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT * FROM eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT * FROM eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT * FROM eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT * FROM eth.receipt_cids);
@ -46,7 +43,6 @@ INSERT INTO public.blocks_i (SELECT * FROM public.blocks);
-- drop hypertables
DROP TABLE eth.log_cids;
DROP TABLE eth.access_list_elements;
DROP TABLE eth.state_accounts;
DROP TABLE eth.storage_cids;
DROP TABLE eth.state_cids;
DROP TABLE eth.receipt_cids;
@ -58,7 +54,6 @@ DROP TABLE public.blocks;
-- rename new tables
ALTER TABLE eth.log_cids_i RENAME TO log_cids;
ALTER TABLE eth.access_list_elements_i RENAME TO access_list_elements;
ALTER TABLE eth.state_accounts_i RENAME TO state_accounts;
ALTER TABLE eth.storage_cids_i RENAME TO storage_cids;
ALTER TABLE eth.state_cids_i RENAME TO state_cids;
ALTER TABLE eth.receipt_cids_i RENAME TO receipt_cids;

View File

@ -0,0 +1,138 @@
-- +goose Up
-- +goose StatementBegin
-- returns if a state leaf node was removed within the provided block number
CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash character varying)
RETURNS boolean AS $$
SELECT state_cids.removed = true
FROM eth.state_cids
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
WHERE state_leaf_key = key
AND state_cids.block_number <= (SELECT block_number
FROM eth.header_cids
WHERE block_hash = hash)
ORDER BY state_cids.block_number DESC LIMIT 1;
$$
language sql;
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE child_result AS (
has_child BOOLEAN,
children eth.header_cids[]
);
CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS
$BODY$
DECLARE
child_height INT;
temp_child eth.header_cids;
new_child_result child_result;
BEGIN
child_height = height + 1;
-- short circuit if there are no children
SELECT exists(SELECT 1
FROM eth.header_cids
WHERE parent_hash = hash
AND block_number = child_height
LIMIT 1)
INTO new_child_result.has_child;
-- collect all the children for this header
IF new_child_result.has_child THEN
FOR temp_child IN
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
LOOP
new_child_result.children = array_append(new_child_result.children, temp_child);
END LOOP;
END IF;
RETURN new_child_result;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS
$BODY$
DECLARE
canonical_header eth.header_cids;
canonical_child eth.header_cids;
header eth.header_cids;
current_child_result child_result;
child_headers eth.header_cids[];
current_header_with_child eth.header_cids;
has_children_count INT DEFAULT 0;
BEGIN
-- for each header in the provided set
FOREACH header IN ARRAY headers
LOOP
-- check if it has any children
current_child_result = has_child(header.block_hash, header.block_number);
IF current_child_result.has_child THEN
-- if it does, take note
has_children_count = has_children_count + 1;
current_header_with_child = header;
-- and add the children to the growing set of child headers
child_headers = array_cat(child_headers, current_child_result.children);
END IF;
END LOOP;
-- if none of the headers had children, none is more canonical than the other
IF has_children_count = 0 THEN
-- return the first one selected
SELECT * INTO canonical_header FROM unnest(headers) LIMIT 1;
-- if only one header had children, it can be considered the heaviest/canonical header of the set
ELSIF has_children_count = 1 THEN
-- return the only header with a child
canonical_header = current_header_with_child;
-- if there are multiple headers with children
ELSE
-- find the canonical header from the child set
canonical_child = canonical_header_from_array(child_headers);
-- the header that is parent to this header, is the canonical header at this level
SELECT * INTO canonical_header FROM unnest(headers)
WHERE block_hash = canonical_child.parent_hash;
END IF;
RETURN canonical_header;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS
$BODY$
DECLARE
canonical_header eth.header_cids;
headers eth.header_cids[];
header_count INT;
temp_header eth.header_cids;
BEGIN
-- collect all headers at this height
FOR temp_header IN
SELECT * FROM eth.header_cids WHERE block_number = height
LOOP
headers = array_append(headers, temp_header);
END LOOP;
-- count the number of headers collected
header_count = array_length(headers, 1);
-- if we have less than 1 header, return NULL
IF header_count IS NULL OR header_count < 1 THEN
RETURN NULL;
-- if we have one header, return its hash
ELSIF header_count = 1 THEN
RETURN headers[1].block_hash;
-- if we have multiple headers we need to determine which one is canonical
ELSE
canonical_header = canonical_header_from_array(headers);
RETURN canonical_header.block_hash;
END IF;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose Down
DROP FUNCTION was_state_leaf_removed;
DROP FUNCTION canonical_header_hash;
DROP FUNCTION canonical_header_from_array;
DROP FUNCTION has_child;
DROP TYPE child_result;

View File

@ -1,248 +0,0 @@
-- +goose Up
-- +goose StatementBegin
-- returns if a state leaf node was removed within the provided block number
CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash character varying)
RETURNS boolean AS $$
SELECT state_cids.node_type = 3
FROM eth.state_cids
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
WHERE state_leaf_key = key
AND state_cids.block_number <= (SELECT block_number
FROM eth.header_cids
WHERE block_hash = hash)
ORDER BY state_cids.block_number DESC LIMIT 1;
$$
language sql;
-- +goose StatementEnd
-- +goose StatementBegin
CREATE TYPE child_result AS (
has_child BOOLEAN,
children eth.header_cids[]
);
CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS
$BODY$
DECLARE
child_height INT;
temp_child eth.header_cids;
new_child_result child_result;
BEGIN
child_height = height + 1;
-- short circuit if there are no children
SELECT exists(SELECT 1
FROM eth.header_cids
WHERE parent_hash = hash
AND block_number = child_height
LIMIT 1)
INTO new_child_result.has_child;
-- collect all the children for this header
IF new_child_result.has_child THEN
FOR temp_child IN
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
LOOP
new_child_result.children = array_append(new_child_result.children, temp_child);
END LOOP;
END IF;
RETURN new_child_result;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS
$BODY$
DECLARE
canonical_header eth.header_cids;
canonical_child eth.header_cids;
header eth.header_cids;
current_child_result child_result;
child_headers eth.header_cids[];
current_header_with_child eth.header_cids;
has_children_count INT DEFAULT 0;
BEGIN
-- for each header in the provided set
FOREACH header IN ARRAY headers
LOOP
-- check if it has any children
current_child_result = has_child(header.block_hash, header.block_number);
IF current_child_result.has_child THEN
-- if it does, take note
has_children_count = has_children_count + 1;
current_header_with_child = header;
-- and add the children to the growing set of child headers
child_headers = array_cat(child_headers, current_child_result.children);
END IF;
END LOOP;
-- if none of the headers had children, none is more canonical than the other
IF has_children_count = 0 THEN
-- return the first one selected
SELECT * INTO canonical_header FROM unnest(headers) LIMIT 1;
-- if only one header had children, it can be considered the heaviest/canonical header of the set
ELSIF has_children_count = 1 THEN
-- return the only header with a child
canonical_header = current_header_with_child;
-- if there are multiple headers with children
ELSE
-- find the canonical header from the child set
canonical_child = canonical_header_from_array(child_headers);
-- the header that is parent to this header, is the canonical header at this level
SELECT * INTO canonical_header FROM unnest(headers)
WHERE block_hash = canonical_child.parent_hash;
END IF;
RETURN canonical_header;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS
$BODY$
DECLARE
canonical_header eth.header_cids;
headers eth.header_cids[];
header_count INT;
temp_header eth.header_cids;
BEGIN
-- collect all headers at this height
FOR temp_header IN
SELECT * FROM eth.header_cids WHERE block_number = height
LOOP
headers = array_append(headers, temp_header);
END LOOP;
-- count the number of headers collected
header_count = array_length(headers, 1);
-- if we have less than 1 header, return NULL
IF header_count IS NULL OR header_count < 1 THEN
RETURN NULL;
-- if we have one header, return its hash
ELSIF header_count = 1 THEN
RETURN headers[1].block_hash;
-- if we have multiple headers we need to determine which one is canonical
ELSE
canonical_header = canonical_header_from_array(headers);
RETURN canonical_header.block_hash;
END IF;
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
SELECT ARRAY (SELECT DISTINCT ON (state_path) ROW (blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key)
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
ORDER BY state_path, state_cids.block_number DESC)
INTO results;
-- 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 unnest(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 unnest(results) r
ON CONFLICT (state_path, header_id, block_number) 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 state leaf key
SELECT ARRAY (SELECT DISTINCT ON (state_leaf_key, storage_path) ROW (blocks.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)
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
INNER JOIN eth.state_cids
ON (storage_cids.state_path, storage_cids.header_id) = (state_cids.state_path, state_cids.header_id)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
ORDER BY state_leaf_key, storage_path, storage_cids.state_path, storage_cids.block_number DESC)
INTO results;
-- 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 unnest(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 unnest(results) r
ON CONFLICT (storage_path, state_path, header_id, block_number) 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;
DROP FUNCTION has_child;
DROP TYPE child_result;

View File

@ -2,8 +2,8 @@
-- PostgreSQL database dump
--
-- Dumped from database version 14.2
-- Dumped by pg_dump version 14.2
-- Dumped from database version 14.6
-- Dumped by pg_dump version 14.6
SET statement_timeout = 0;
SET lock_timeout = 0;
@ -58,7 +58,7 @@ CREATE TABLE eth.header_cids (
parent_hash character varying(66) NOT NULL,
cid text NOT NULL,
td numeric NOT NULL,
node_id character varying(128) NOT NULL,
node_ids character varying(128)[] NOT NULL,
reward numeric NOT NULL,
state_root character varying(66) NOT NULL,
tx_root character varying(66) NOT NULL,
@ -67,7 +67,6 @@ CREATE TABLE eth.header_cids (
bloom bytea NOT NULL,
"timestamp" bigint NOT NULL,
mh_key text NOT NULL,
times_validated integer DEFAULT 1 NOT NULL,
coinbase character varying(66) NOT NULL
);
@ -80,10 +79,10 @@ COMMENT ON TABLE eth.header_cids IS '@name EthHeaderCids';
--
-- Name: COLUMN header_cids.node_id; Type: COMMENT; Schema: eth; Owner: -
-- Name: COLUMN header_cids.node_ids; Type: COMMENT; Schema: eth; Owner: -
--
COMMENT ON COLUMN eth.header_cids.node_id IS '@name EthNodeID';
COMMENT ON COLUMN eth.header_cids.node_ids IS '@name EthNodeIDs';
--
@ -96,35 +95,6 @@ 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: -
--
@ -135,7 +105,7 @@ CREATE FUNCTION eth.graphql_subscription() RETURNS trigger
DECLARE
obj jsonb;
BEGIN
IF (TG_TABLE_NAME = 'state_cids') OR (TG_TABLE_NAME = 'state_accounts') THEN
IF (TG_TABLE_NAME = 'state_cids') THEN
obj := json_build_array(
TG_TABLE_NAME,
NEW.header_id,
@ -307,87 +277,6 @@ 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
SELECT ARRAY (SELECT DISTINCT ON (state_path) ROW (blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key)
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
ORDER BY state_path, state_cids.block_number DESC)
INTO results;
-- 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 unnest(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 unnest(results) r
ON CONFLICT (state_path, header_id, block_number) 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 state leaf key
SELECT ARRAY (SELECT DISTINCT ON (state_leaf_key, storage_path) ROW (blocks.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)
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
INNER JOIN eth.state_cids
ON (storage_cids.state_path, storage_cids.header_id) = (state_cids.state_path, state_cids.header_id)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
ORDER BY state_leaf_key, storage_path, storage_cids.state_path, storage_cids.block_number DESC)
INTO results;
-- 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 unnest(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 unnest(results) r
ON CONFLICT (storage_path, state_path, header_id, block_number) DO NOTHING;
END
$$;
--
-- Name: was_state_leaf_removed(character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
--
@ -395,7 +284,7 @@ $$;
CREATE FUNCTION public.was_state_leaf_removed(key character varying, hash character varying) RETURNS boolean
LANGUAGE sql
AS $$
SELECT state_cids.node_type = 3
SELECT state_cids.removed = true
FROM eth.state_cids
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
WHERE state_leaf_key = key
@ -467,21 +356,6 @@ CREATE TABLE eth.receipt_cids (
);
--
-- Name: state_accounts; Type: TABLE; Schema: eth; Owner: -
--
CREATE TABLE eth.state_accounts (
block_number bigint NOT NULL,
header_id character varying(66) NOT NULL,
state_path bytea NOT NULL,
balance numeric NOT NULL,
nonce bigint NOT NULL,
code_hash character varying(66) NOT NULL,
storage_root character varying(66) NOT NULL
);
--
-- Name: state_cids; Type: TABLE; Schema: eth; Owner: -
--
@ -489,12 +363,16 @@ CREATE TABLE eth.state_accounts (
CREATE TABLE eth.state_cids (
block_number bigint NOT NULL,
header_id character varying(66) NOT NULL,
state_leaf_key character varying(66),
state_leaf_key character varying(66) NOT NULL,
cid text NOT NULL,
state_path bytea NOT NULL,
node_type integer NOT NULL,
diff boolean DEFAULT false NOT NULL,
mh_key text NOT NULL
mh_key text NOT NULL,
balance numeric,
nonce bigint,
code_hash character varying(66),
storage_root character varying(66),
removed boolean NOT NULL
);
@ -505,13 +383,14 @@ CREATE TABLE eth.state_cids (
CREATE TABLE eth.storage_cids (
block_number bigint NOT NULL,
header_id character varying(66) NOT NULL,
state_path bytea NOT NULL,
storage_leaf_key character varying(66),
state_leaf_key character varying(66) NOT NULL,
storage_leaf_key character varying(66) NOT NULL,
cid text NOT NULL,
storage_path bytea NOT NULL,
node_type integer NOT NULL,
diff boolean DEFAULT false NOT NULL,
mh_key text NOT NULL
mh_key text NOT NULL,
val bytea,
removed boolean NOT NULL
);
@ -826,20 +705,12 @@ ALTER TABLE ONLY eth.receipt_cids
ADD CONSTRAINT receipt_cids_pkey PRIMARY KEY (tx_id, header_id, block_number);
--
-- Name: state_accounts state_accounts_pkey; Type: CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.state_accounts
ADD CONSTRAINT state_accounts_pkey PRIMARY KEY (state_path, header_id, block_number);
--
-- Name: state_cids state_cids_pkey; Type: CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.state_cids
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (state_path, header_id, block_number);
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (state_leaf_key, header_id, block_number);
--
@ -847,7 +718,7 @@ ALTER TABLE ONLY eth.state_cids
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (storage_path, state_path, header_id, block_number);
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (storage_leaf_key, state_leaf_key, header_id, block_number);
--
@ -927,27 +798,6 @@ CREATE INDEX access_list_element_address_index ON eth.access_list_elements USING
CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys);
--
-- Name: account_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number);
--
-- Name: account_header_id_index; Type: INDEX; Schema: eth; Owner: -
--
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);
--
-- Name: header_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
@ -1095,6 +945,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_code_hash_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_code_hash_index ON eth.state_cids USING btree (code_hash);
--
-- Name: state_header_id_index; Type: INDEX; Schema: eth; Owner: -
--
@ -1103,10 +960,10 @@ CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
--
-- Name: state_leaf_key_index; Type: INDEX; Schema: eth; Owner: -
-- Name: state_leaf_key_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key);
CREATE INDEX state_leaf_key_block_number_index ON eth.state_cids USING btree (state_leaf_key, block_number DESC);
--
@ -1117,10 +974,17 @@ CREATE INDEX state_mh_block_number_index ON eth.state_cids USING btree (mh_key,
--
-- Name: state_node_type_index; Type: INDEX; Schema: eth; Owner: -
-- Name: state_path_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
--
-- Name: state_removed_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX state_removed_index ON eth.state_cids USING btree (removed);
--
@ -1152,10 +1016,10 @@ CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id)
--
-- Name: storage_leaf_key_index; Type: INDEX; Schema: eth; Owner: -
-- Name: storage_leaf_key_block_number_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key);
CREATE INDEX storage_leaf_key_block_number_index ON eth.storage_cids USING btree (storage_leaf_key, block_number DESC);
--
@ -1166,17 +1030,24 @@ CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_k
--
-- Name: storage_node_type_index; Type: INDEX; Schema: eth; Owner: -
-- Name: storage_path_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
--
-- Name: storage_state_path_index; Type: INDEX; Schema: eth; Owner: -
-- Name: storage_removed_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path);
CREATE INDEX storage_removed_index ON eth.storage_cids USING btree (removed);
--
-- Name: storage_state_leaf_key_index; Type: INDEX; Schema: eth; Owner: -
--
CREATE INDEX storage_state_leaf_key_index ON eth.storage_cids USING btree (state_leaf_key);
--
@ -1291,13 +1162,6 @@ CREATE TRIGGER trg_eth_log_cids AFTER INSERT ON eth.log_cids FOR EACH ROW EXECUT
CREATE TRIGGER trg_eth_receipt_cids AFTER INSERT ON eth.receipt_cids FOR EACH ROW EXECUTE FUNCTION eth.graphql_subscription();
--
-- Name: state_accounts trg_eth_state_accounts; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER trg_eth_state_accounts AFTER INSERT ON eth.state_accounts FOR EACH ROW EXECUTE FUNCTION eth.graphql_subscription();
--
-- Name: state_cids trg_eth_state_cids; Type: TRIGGER; Schema: eth; Owner: -
--
@ -1354,13 +1218,6 @@ CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.log_cids FOR EACH ROW EXEC
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.receipt_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: state_accounts ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.state_accounts FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: state_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--