add btree indexes to storage_cids and state_cids node_type; new db schema
This commit is contained in:
parent
95419285e5
commit
5e6fb5b81b
@ -16,6 +16,7 @@ CREATE TABLE eth.header_cids (
|
|||||||
bloom BYTEA NOT NULL,
|
bloom BYTEA NOT NULL,
|
||||||
timestamp NUMERIC NOT NULL,
|
timestamp NUMERIC NOT NULL,
|
||||||
times_validated INTEGER NOT NULL DEFAULT 1,
|
times_validated INTEGER NOT NULL DEFAULT 1,
|
||||||
|
base_fee BIGINT,
|
||||||
UNIQUE (block_number, block_hash)
|
UNIQUE (block_number, block_hash)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
@ -9,6 +9,7 @@ CREATE TABLE eth.transaction_cids (
|
|||||||
dst VARCHAR(66) NOT NULL,
|
dst VARCHAR(66) NOT NULL,
|
||||||
src VARCHAR(66) NOT NULL,
|
src VARCHAR(66) NOT NULL,
|
||||||
tx_data BYTEA,
|
tx_data BYTEA,
|
||||||
|
tx_type BYTEA,
|
||||||
UNIQUE (header_id, tx_hash)
|
UNIQUE (header_id, tx_hash)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
@ -57,6 +57,8 @@ 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_path_index ON eth.state_cids USING btree (state_path);
|
||||||
|
|
||||||
|
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
|
||||||
|
|
||||||
-- storage node indexes
|
-- storage node indexes
|
||||||
CREATE INDEX storage_state_id_index ON eth.storage_cids USING btree (state_id);
|
CREATE INDEX storage_state_id_index ON eth.storage_cids USING btree (state_id);
|
||||||
|
|
||||||
@ -68,6 +70,8 @@ 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_path_index ON eth.storage_cids USING btree (storage_path);
|
||||||
|
|
||||||
|
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
|
||||||
|
|
||||||
-- state accounts indexes
|
-- state accounts indexes
|
||||||
CREATE INDEX account_state_id_index ON eth.state_accounts USING btree (state_id);
|
CREATE INDEX account_state_id_index ON eth.state_accounts USING btree (state_id);
|
||||||
|
|
||||||
@ -79,6 +83,7 @@ DROP INDEX eth.storage_root_index;
|
|||||||
DROP INDEX eth.account_state_id_index;
|
DROP INDEX eth.account_state_id_index;
|
||||||
|
|
||||||
-- storage node indexes
|
-- storage node indexes
|
||||||
|
DROP INDEX eth.storage_node_type_index;
|
||||||
DROP INDEX eth.storage_path_index;
|
DROP INDEX eth.storage_path_index;
|
||||||
DROP INDEX eth.storage_mh_index;
|
DROP INDEX eth.storage_mh_index;
|
||||||
DROP INDEX eth.storage_cid_index;
|
DROP INDEX eth.storage_cid_index;
|
||||||
@ -86,6 +91,7 @@ DROP INDEX eth.storage_leaf_key_index;
|
|||||||
DROP INDEX eth.storage_state_id_index;
|
DROP INDEX eth.storage_state_id_index;
|
||||||
|
|
||||||
-- state node indexes
|
-- state node indexes
|
||||||
|
DROP INDEX eth.state_node_type_index;
|
||||||
DROP INDEX eth.state_path_index;
|
DROP INDEX eth.state_path_index;
|
||||||
DROP INDEX eth.state_mh_index;
|
DROP INDEX eth.state_mh_index;
|
||||||
DROP INDEX eth.state_cid_index;
|
DROP INDEX eth.state_cid_index;
|
||||||
@ -118,4 +124,4 @@ DROP INDEX eth.state_root_index;
|
|||||||
DROP INDEX eth.header_mh_index;
|
DROP INDEX eth.header_mh_index;
|
||||||
DROP INDEX eth.header_cid_index;
|
DROP INDEX eth.header_cid_index;
|
||||||
DROP INDEX eth.block_hash_index;
|
DROP INDEX eth.block_hash_index;
|
||||||
DROP INDEX eth.block_number_index;
|
DROP INDEX eth.block_number_index;
|
||||||
|
@ -1,14 +1,14 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
-- +goose StatementBegin
|
-- +goose StatementBegin
|
||||||
-- returns if a storage node at the provided path was removed in the range >= the provided height and <= the provided block hash
|
-- returns if a storage node at the provided path was removed in the range > the provided height and <= the provided block hash
|
||||||
CREATE OR REPLACE FUNCTION was_storage_removed(path BYTEA, height BIGINT, hash VARCHAR(66)) RETURNS BOOLEAN
|
CREATE OR REPLACE FUNCTION was_storage_removed(path BYTEA, height BIGINT, hash VARCHAR(66)) RETURNS BOOLEAN
|
||||||
AS $$
|
AS $$
|
||||||
SELECT exists(SELECT 1
|
SELECT exists(SELECT 1
|
||||||
FROM eth.storage_cids
|
FROM eth.storage_cids
|
||||||
INNER JOIN eth.state_cids ON (storage_cids.state_id = state_cids.id)
|
INNER JOIN eth.state_cids ON (storage_cids.state_id = state_cids.id)
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
|
||||||
WHERE storage_path = path
|
WHERE storage_path = path
|
||||||
AND block_number >= height
|
AND block_number > height
|
||||||
AND block_number <= (SELECT block_number
|
AND block_number <= (SELECT block_number
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE block_hash = hash)
|
WHERE block_hash = hash)
|
||||||
@ -23,7 +23,7 @@ CREATE OR REPLACE FUNCTION was_state_removed(path BYTEA, height BIGINT, hash VAR
|
|||||||
AS $$
|
AS $$
|
||||||
SELECT exists(SELECT 1
|
SELECT exists(SELECT 1
|
||||||
FROM eth.state_cids
|
FROM eth.state_cids
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
|
||||||
WHERE state_path = path
|
WHERE state_path = path
|
||||||
AND block_number > height
|
AND block_number > height
|
||||||
AND block_number <= (SELECT block_number
|
AND block_number <= (SELECT block_number
|
||||||
@ -43,26 +43,26 @@ CREATE TYPE child_result AS (
|
|||||||
CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS
|
CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
DECLARE
|
||||||
child_height INT;
|
child_height INT;
|
||||||
temp_child eth.header_cids;
|
temp_child eth.header_cids;
|
||||||
new_child_result child_result;
|
new_child_result child_result;
|
||||||
BEGIN
|
BEGIN
|
||||||
child_height = height + 1;
|
child_height = height + 1;
|
||||||
-- short circuit if there are no children
|
-- short circuit if there are no children
|
||||||
SELECT exists(SELECT 1
|
SELECT exists(SELECT 1
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE parent_hash = hash
|
WHERE parent_hash = hash
|
||||||
AND block_number = child_height
|
AND block_number = child_height
|
||||||
LIMIT 1)
|
LIMIT 1)
|
||||||
INTO new_child_result.has_child;
|
INTO new_child_result.has_child;
|
||||||
-- collect all the children for this header
|
-- collect all the children for this header
|
||||||
IF new_child_result.has_child THEN
|
IF new_child_result.has_child THEN
|
||||||
FOR temp_child IN
|
FOR temp_child IN
|
||||||
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
|
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
|
||||||
LOOP
|
LOOP
|
||||||
new_child_result.children = array_append(new_child_result.children, temp_child);
|
new_child_result.children = array_append(new_child_result.children, temp_child);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
END IF;
|
END IF;
|
||||||
RETURN new_child_result;
|
RETURN new_child_result;
|
||||||
END
|
END
|
||||||
$BODY$
|
$BODY$
|
||||||
@ -73,7 +73,7 @@ LANGUAGE 'plpgsql';
|
|||||||
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS
|
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
DECLARE
|
||||||
canonical_header eth.header_cids;
|
canonical_header eth.header_cids;
|
||||||
canonical_child eth.header_cids;
|
canonical_child eth.header_cids;
|
||||||
header eth.header_cids;
|
header eth.header_cids;
|
||||||
current_child_result child_result;
|
current_child_result child_result;
|
||||||
@ -92,25 +92,25 @@ BEGIN
|
|||||||
current_header_with_child = header;
|
current_header_with_child = header;
|
||||||
-- and add the children to the growing set of child headers
|
-- and add the children to the growing set of child headers
|
||||||
child_headers = array_cat(child_headers, current_child_result.children);
|
child_headers = array_cat(child_headers, current_child_result.children);
|
||||||
END IF;
|
END IF;
|
||||||
END LOOP;
|
END LOOP;
|
||||||
-- if none of the headers had children, none is more canonical than the other
|
-- if none of the headers had children, none is more canonical than the other
|
||||||
IF has_children_count = 0 THEN
|
IF has_children_count = 0 THEN
|
||||||
-- return the first one selected
|
-- return the first one selected
|
||||||
SELECT * INTO canonical_header FROM unnest(headers) LIMIT 1;
|
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
|
-- if only one header had children, it can be considered the heaviest/canonical header of the set
|
||||||
ELSIF has_children_count = 1 THEN
|
ELSIF has_children_count = 1 THEN
|
||||||
-- return the only header with a child
|
-- return the only header with a child
|
||||||
canonical_header = current_header_with_child;
|
canonical_header = current_header_with_child;
|
||||||
-- if there are multiple headers with children
|
-- if there are multiple headers with children
|
||||||
ELSE
|
ELSE
|
||||||
-- find the canonical header from the child set
|
-- find the canonical header from the child set
|
||||||
canonical_child = canonical_header_from_array(child_headers);
|
canonical_child = canonical_header_from_array(child_headers);
|
||||||
-- the header that is parent to this header, is the canonical header at this level
|
-- the header that is parent to this header, is the canonical header at this level
|
||||||
SELECT * INTO canonical_header FROM unnest(headers)
|
SELECT * INTO canonical_header FROM unnest(headers)
|
||||||
WHERE block_hash = canonical_child.parent_hash;
|
WHERE block_hash = canonical_child.parent_hash;
|
||||||
END IF;
|
END IF;
|
||||||
RETURN canonical_header;
|
RETURN canonical_header;
|
||||||
END
|
END
|
||||||
$BODY$
|
$BODY$
|
||||||
LANGUAGE 'plpgsql';
|
LANGUAGE 'plpgsql';
|
||||||
@ -120,17 +120,17 @@ LANGUAGE 'plpgsql';
|
|||||||
CREATE OR REPLACE FUNCTION canonical_header_id(height BIGINT) RETURNS INTEGER AS
|
CREATE OR REPLACE FUNCTION canonical_header_id(height BIGINT) RETURNS INTEGER AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
DECLARE
|
||||||
canonical_header eth.header_cids;
|
canonical_header eth.header_cids;
|
||||||
headers eth.header_cids[];
|
headers eth.header_cids[];
|
||||||
header_count INT;
|
header_count INT;
|
||||||
temp_header eth.header_cids;
|
temp_header eth.header_cids;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- collect all headers at this height
|
-- collect all headers at this height
|
||||||
FOR temp_header IN
|
FOR temp_header IN
|
||||||
SELECT * FROM eth.header_cids WHERE block_number = height
|
SELECT * FROM eth.header_cids WHERE block_number = height
|
||||||
LOOP
|
LOOP
|
||||||
headers = array_append(headers, temp_header);
|
headers = array_append(headers, temp_header);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
-- count the number of headers collected
|
-- count the number of headers collected
|
||||||
header_count = array_length(headers, 1);
|
header_count = array_length(headers, 1);
|
||||||
-- if we have less than 1 header, return NULL
|
-- if we have less than 1 header, return NULL
|
||||||
@ -140,10 +140,10 @@ END LOOP;
|
|||||||
ELSIF header_count = 1 THEN
|
ELSIF header_count = 1 THEN
|
||||||
RETURN headers[1].id;
|
RETURN headers[1].id;
|
||||||
-- if we have multiple headers we need to determine which one is canonical
|
-- if we have multiple headers we need to determine which one is canonical
|
||||||
ELSE
|
ELSE
|
||||||
canonical_header = canonical_header_from_array(headers);
|
canonical_header = canonical_header_from_array(headers);
|
||||||
RETURN canonical_header.id;
|
RETURN canonical_header.id;
|
||||||
END IF;
|
END IF;
|
||||||
END;
|
END;
|
||||||
$BODY$
|
$BODY$
|
||||||
LANGUAGE 'plpgsql';
|
LANGUAGE 'plpgsql';
|
||||||
|
15
migrations/00015_create_access_list_table.sql
Normal file
15
migrations/00015_create_access_list_table.sql
Normal file
@ -0,0 +1,15 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.access_list_element (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
tx_id INTEGER NOT NULL REFERENCES eth.transaction_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
index INTEGER NOT NULL,
|
||||||
|
address VARCHAR(66),
|
||||||
|
storage_keys VARCHAR(66)[],
|
||||||
|
UNIQUE (tx_id, index)
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX accesss_list_element_address_index ON eth.access_list_element USING btree (address);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP INDEX eth.accesss_list_element_address_index;
|
||||||
|
DROP TABLE eth.access_list_element;
|
83
schema.sql
83
schema.sql
@ -2,8 +2,8 @@
|
|||||||
-- PostgreSQL database dump
|
-- PostgreSQL database dump
|
||||||
--
|
--
|
||||||
|
|
||||||
-- Dumped from database version 12.4
|
-- Dumped from database version 14beta3
|
||||||
-- Dumped by pg_dump version 12.4
|
-- Dumped by pg_dump version 14beta3
|
||||||
|
|
||||||
SET statement_timeout = 0;
|
SET statement_timeout = 0;
|
||||||
SET lock_timeout = 0;
|
SET lock_timeout = 0;
|
||||||
@ -47,7 +47,8 @@ CREATE TABLE eth.header_cids (
|
|||||||
uncle_root character varying(66) NOT NULL,
|
uncle_root character varying(66) NOT NULL,
|
||||||
bloom bytea NOT NULL,
|
bloom bytea NOT NULL,
|
||||||
"timestamp" numeric NOT NULL,
|
"timestamp" numeric NOT NULL,
|
||||||
times_validated integer DEFAULT 1 NOT NULL
|
times_validated integer DEFAULT 1 NOT NULL,
|
||||||
|
base_fee bigint
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
@ -103,33 +104,6 @@ end;
|
|||||||
$_$;
|
$_$;
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: canonical_header(bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.canonical_header(height bigint) RETURNS integer
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
current_weight INT;
|
|
||||||
heaviest_weight INT DEFAULT 0;
|
|
||||||
heaviest_id INT;
|
|
||||||
r eth.header_cids%ROWTYPE;
|
|
||||||
BEGIN
|
|
||||||
FOR r IN SELECT * FROM eth.header_cids
|
|
||||||
WHERE block_number = height
|
|
||||||
LOOP
|
|
||||||
SELECT INTO current_weight * FROM header_weight(r.block_hash);
|
|
||||||
IF current_weight > heaviest_weight THEN
|
|
||||||
heaviest_weight := current_weight;
|
|
||||||
heaviest_id := r.id;
|
|
||||||
END IF;
|
|
||||||
END LOOP;
|
|
||||||
RETURN heaviest_id;
|
|
||||||
END
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: canonical_header_from_array(eth.header_cids[]); Type: FUNCTION; Schema: public; Owner: -
|
-- Name: canonical_header_from_array(eth.header_cids[]); Type: FUNCTION; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
@ -216,17 +190,6 @@ END;
|
|||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: ethHeaderCidByBlockNumber(bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public."ethHeaderCidByBlockNumber"(n bigint) RETURNS SETOF eth.header_cids
|
|
||||||
LANGUAGE sql STABLE
|
|
||||||
AS $_$
|
|
||||||
SELECT * FROM eth.header_cids WHERE block_number=$1 ORDER BY id
|
|
||||||
$_$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
@ -255,33 +218,11 @@ BEGIN
|
|||||||
new_child_result.children = array_append(new_child_result.children, temp_child);
|
new_child_result.children = array_append(new_child_result.children, temp_child);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
END IF;
|
END IF;
|
||||||
RETURN new_child_result;
|
RETURN new_child_result;
|
||||||
END
|
END
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: header_weight(character varying); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.header_weight(hash character varying) RETURNS bigint
|
|
||||||
LANGUAGE sql
|
|
||||||
AS $$
|
|
||||||
WITH RECURSIVE validator AS (
|
|
||||||
SELECT block_hash, parent_hash, block_number
|
|
||||||
FROM eth.header_cids
|
|
||||||
WHERE block_hash = hash
|
|
||||||
UNION
|
|
||||||
SELECT eth.header_cids.block_hash, eth.header_cids.parent_hash, eth.header_cids.block_number
|
|
||||||
FROM eth.header_cids
|
|
||||||
INNER JOIN validator
|
|
||||||
ON eth.header_cids.parent_hash = validator.block_hash
|
|
||||||
AND eth.header_cids.block_number = validator.block_number + 1
|
|
||||||
)
|
|
||||||
SELECT COUNT(*) FROM validator;
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: was_state_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
|
-- Name: was_state_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
@ -1061,6 +1002,13 @@ CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key)
|
|||||||
CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
|
CREATE INDEX state_mh_index ON eth.state_cids USING btree (mh_key);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: state_node_type_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: state_path_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: state_path_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -1096,6 +1044,13 @@ CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_lea
|
|||||||
CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
|
CREATE INDEX storage_mh_index ON eth.storage_cids USING btree (mh_key);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: storage_node_type_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: storage_path_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: storage_path_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
Loading…
Reference in New Issue
Block a user