update migrations and schema
This commit is contained in:
parent
5886ea5b89
commit
a2c048810a
@ -9,6 +9,7 @@ CREATE TABLE eth.transaction_cids (
|
||||
dst VARCHAR(66) NOT NULL,
|
||||
src VARCHAR(66) NOT NULL,
|
||||
tx_data BYTEA,
|
||||
tx_type BYTEA,
|
||||
UNIQUE (header_id, tx_hash)
|
||||
);
|
||||
|
||||
|
15
statediff/db/migrations/00015_create_access_list_table.sql
Normal file
15
statediff/db/migrations/00015_create_access_list_table.sql
Normal file
@ -0,0 +1,15 @@
|
||||
-- +goose Up
|
||||
CREATE TABLE eth.access_list_entry (
|
||||
id SERIAL PRIMARY KEY,
|
||||
index INTEGER NOT NULL,
|
||||
tx_id INTEGER NOT NULL REFERENCES eth.transaction_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||
address VARCHAR(66),
|
||||
storage_keys VARCHAR(66)[],
|
||||
UNIQUE (tx_id, index)
|
||||
);
|
||||
|
||||
CREATE INDEX accesss_list_address_index ON eth.access_list_entry USING btree (address);
|
||||
|
||||
-- +goose Down
|
||||
DROP INDEX eth.accesss_list_address_index;
|
||||
DROP TABLE eth.access_list_entry;
|
@ -103,6 +103,33 @@ 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: -
|
||||
--
|
||||
@ -111,7 +138,7 @@ CREATE FUNCTION public.canonical_header_from_array(headers eth.header_cids[]) RE
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
canonical_header eth.header_cids;
|
||||
canonical_header eth.header_cids;
|
||||
canonical_child eth.header_cids;
|
||||
header eth.header_cids;
|
||||
current_child_result child_result;
|
||||
@ -130,25 +157,25 @@ BEGIN
|
||||
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;
|
||||
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
|
||||
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
|
||||
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;
|
||||
SELECT * INTO canonical_header FROM unnest(headers)
|
||||
WHERE block_hash = canonical_child.parent_hash;
|
||||
END IF;
|
||||
RETURN canonical_header;
|
||||
END
|
||||
$$;
|
||||
|
||||
@ -161,17 +188,17 @@ CREATE FUNCTION public.canonical_header_id(height bigint) RETURNS integer
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
canonical_header eth.header_cids;
|
||||
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
|
||||
FOR temp_header IN
|
||||
SELECT * FROM eth.header_cids WHERE block_number = height
|
||||
LOOP
|
||||
headers = array_append(headers, temp_header);
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
-- count the number of headers collected
|
||||
header_count = array_length(headers, 1);
|
||||
-- if we have less than 1 header, return NULL
|
||||
@ -181,14 +208,25 @@ END LOOP;
|
||||
ELSIF header_count = 1 THEN
|
||||
RETURN headers[1].id;
|
||||
-- if we have multiple headers we need to determine which one is canonical
|
||||
ELSE
|
||||
ELSE
|
||||
canonical_header = canonical_header_from_array(headers);
|
||||
RETURN canonical_header.id;
|
||||
END IF;
|
||||
RETURN canonical_header.id;
|
||||
END IF;
|
||||
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: -
|
||||
--
|
||||
@ -197,31 +235,53 @@ CREATE FUNCTION public.has_child(hash character varying, height bigint) RETURNS
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
child_height INT;
|
||||
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
|
||||
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
|
||||
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
|
||||
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 LOOP;
|
||||
END IF;
|
||||
RETURN new_child_result;
|
||||
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: -
|
||||
--
|
||||
@ -231,7 +291,7 @@ CREATE FUNCTION public.was_state_removed(path bytea, height bigint, hash charact
|
||||
AS $$
|
||||
SELECT exists(SELECT 1
|
||||
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
|
||||
AND block_number > height
|
||||
AND block_number <= (SELECT block_number
|
||||
@ -251,8 +311,8 @@ CREATE FUNCTION public.was_storage_removed(path bytea, height bigint, hash chara
|
||||
AS $$
|
||||
SELECT exists(SELECT 1
|
||||
FROM eth.storage_cids
|
||||
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.state_cids ON (storage_cids.state_id = state_cids.id)
|
||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.id)
|
||||
WHERE storage_path = path
|
||||
AND block_number > height
|
||||
AND block_number <= (SELECT block_number
|
||||
@ -263,6 +323,39 @@ SELECT exists(SELECT 1
|
||||
$$;
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry; Type: TABLE; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
CREATE TABLE eth.access_list_entry (
|
||||
id integer NOT NULL,
|
||||
index integer NOT NULL,
|
||||
tx_id integer NOT NULL,
|
||||
address character varying(66),
|
||||
storage_keys character varying(66)[]
|
||||
);
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry_id_seq; Type: SEQUENCE; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
CREATE SEQUENCE eth.access_list_entry_id_seq
|
||||
AS integer
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry_id_seq; Type: SEQUENCE OWNED BY; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
ALTER SEQUENCE eth.access_list_entry_id_seq OWNED BY eth.access_list_entry.id;
|
||||
|
||||
|
||||
--
|
||||
-- Name: header_cids_id_seq; Type: SEQUENCE; Schema: eth; Owner: -
|
||||
--
|
||||
@ -441,7 +534,8 @@ CREATE TABLE eth.transaction_cids (
|
||||
mh_key text NOT NULL,
|
||||
dst character varying(66) NOT NULL,
|
||||
src character varying(66) NOT NULL,
|
||||
tx_data bytea
|
||||
tx_data bytea,
|
||||
tx_type bytea
|
||||
);
|
||||
|
||||
|
||||
@ -597,6 +691,13 @@ CREATE SEQUENCE public.nodes_id_seq
|
||||
ALTER SEQUENCE public.nodes_id_seq OWNED BY public.nodes.id;
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry id; Type: DEFAULT; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY eth.access_list_entry ALTER COLUMN id SET DEFAULT nextval('eth.access_list_entry_id_seq'::regclass);
|
||||
|
||||
|
||||
--
|
||||
-- Name: header_cids id; Type: DEFAULT; Schema: eth; Owner: -
|
||||
--
|
||||
@ -660,6 +761,22 @@ ALTER TABLE ONLY public.goose_db_version ALTER COLUMN id SET DEFAULT nextval('pu
|
||||
ALTER TABLE ONLY public.nodes ALTER COLUMN id SET DEFAULT nextval('public.nodes_id_seq'::regclass);
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry access_list_entry_pkey; Type: CONSTRAINT; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY eth.access_list_entry
|
||||
ADD CONSTRAINT access_list_entry_pkey PRIMARY KEY (id);
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry access_list_entry_tx_id_index_key; Type: CONSTRAINT; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY eth.access_list_entry
|
||||
ADD CONSTRAINT access_list_entry_tx_id_index_key UNIQUE (tx_id, index);
|
||||
|
||||
|
||||
--
|
||||
-- Name: header_cids header_cids_block_number_block_hash_key; Type: CONSTRAINT; Schema: eth; Owner: -
|
||||
--
|
||||
@ -804,6 +921,13 @@ ALTER TABLE ONLY public.nodes
|
||||
ADD CONSTRAINT nodes_pkey PRIMARY KEY (id);
|
||||
|
||||
|
||||
--
|
||||
-- Name: accesss_list_address_index; Type: INDEX; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
CREATE INDEX accesss_list_address_index ON eth.access_list_entry USING btree (address);
|
||||
|
||||
|
||||
--
|
||||
-- Name: account_state_id_index; Type: INDEX; Schema: eth; Owner: -
|
||||
--
|
||||
@ -1091,6 +1215,14 @@ CREATE TRIGGER transaction_cids_ai AFTER INSERT ON eth.transaction_cids FOR EACH
|
||||
CREATE TRIGGER uncle_cids_ai AFTER INSERT ON eth.uncle_cids FOR EACH ROW EXECUTE FUNCTION eth.graphql_subscription('uncle_cids', 'id');
|
||||
|
||||
|
||||
--
|
||||
-- Name: access_list_entry access_list_entry_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY eth.access_list_entry
|
||||
ADD CONSTRAINT access_list_entry_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||
|
||||
|
||||
--
|
||||
-- Name: header_cids header_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||
--
|
||||
|
Loading…
Reference in New Issue
Block a user