Skip to content

Commit

Permalink
Merge pull request #20 from vulcanize/remove-node-funcs
Browse files Browse the repository at this point in the history
Rename receipt indexes and remove functions.
  • Loading branch information
i-norden authored Oct 7, 2021
2 parents da128aa + dabe5a2 commit 8f927a3
Show file tree
Hide file tree
Showing 4 changed files with 135 additions and 92 deletions.
43 changes: 16 additions & 27 deletions db/migrations/00025_create_eth_log_cids_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,47 +23,36 @@ DROP COLUMN log_contracts,
ADD COLUMN log_root VARCHAR(66);

CREATE INDEX log_rct_id_index ON eth.log_cids USING btree (receipt_id);

CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key);

CREATE INDEX log_cid_index ON eth.log_cids USING btree (leaf_cid);

--
-- Name: log_topic0_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX log_topic0_index ON eth.log_cids USING btree (topic0);


--
-- Name: log_topic1_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX log_topic1_index ON eth.log_cids USING btree (topic1);


--
-- Name: log_topic2_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX log_topic2_index ON eth.log_cids USING btree (topic2);


--
-- Name: log_topic3_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX log_topic3_index ON eth.log_cids USING btree (topic3);


-- +goose Down
-- log indexes

ALTER TABLE eth.receipt_cids
ADD COLUMN topic0s VARCHAR(66)[],
ADD COLUMN topic1s VARCHAR(66)[],
ADD COLUMN topic2s VARCHAR(66)[],
ADD COLUMN topic3s VARCHAR(66)[],
ADD COLUMN log_contracts VARCHAR(66)[],
DROP COLUMN log_root;

CREATE INDEX rct_topic0_index ON eth.receipt_cids USING gin (topic0s);
CREATE INDEX rct_topic1_index ON eth.receipt_cids USING gin (topic1s);
CREATE INDEX rct_topic2_index ON eth.receipt_cids USING gin (topic2s);
CREATE INDEX rct_topic3_index ON eth.receipt_cids USING gin (topic3s);
CREATE INDEX rct_log_contract_index ON eth.receipt_cids USING gin (log_contracts);

DROP INDEX eth.log_rct_id_index;
DROP INDEX eth.log_mh_index;
DROP INDEX eth.log_cid_index;
DROP INDEX eth.log_topic0_index;
DROP INDEX eth.log_topic1_index;
DROP INDEX eth.log_topic2_index;
DROP INDEX eth.log_topic3_index;
DROP INDEX eth.log_rct_id_index;

DROP TABLE eth.log_cids;
69 changes: 63 additions & 6 deletions db/migrations/00027_rename_cid_and_mh_key_in_eth_receipt_cids.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,17 +6,74 @@ ALTER TABLE eth.receipt_cids
RENAME COLUMN mh_key TO leaf_mh_key;

ALTER INDEX eth.rct_mh_index
RENAME TO rct_leaf_cid_index;
RENAME TO rct_leaf_mh_index;

ALTER INDEX eth.rct_cid_index
RENAME TO rct_leaf_mh_key_index;
RENAME TO rct_leaf_cid_index;

ALTER TABLE ONLY eth.receipt_cids
RENAME CONSTRAINT receipt_cids_mh_key_fkey TO receipt_cids_leaf_mh_key_fkey;

DROP FUNCTION header_weight;
DROP FUNCTION canonical_header;

-- +goose Down
DROP INDEX eth.rct_leaf_cid_index;
DROP INDEX eth.rct_leaf_mh_key_index;

ALTER TABLE ONLY eth.receipt_cids
RENAME CONSTRAINT receipt_cids_leaf_mh_key_fkey TO receipt_cids_mh_key_fkey;

ALTER INDEX eth.rct_leaf_cid_index
RENAME TO rct_cid_index;

ALTER INDEX eth.rct_leaf_mh_index
RENAME TO rct_mh_index;

ALTER TABLE eth.receipt_cids
RENAME COLUMN leaf_cid TO cid;

ALTER TABLE eth.receipt_cids
DROP COLUMN leaf_cid,
DROP COLUMN leaf_mh_key;
RENAME COLUMN leaf_mh_key TO mh_key;

-- +goose StatementBegin
-- returns the number of child headers that reference backwards to the header with the provided hash
CREATE OR REPLACE FUNCTION header_weight(hash VARCHAR(66)) RETURNS BIGINT
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;
$$ LANGUAGE SQL;
-- +goose StatementEnd

-- +goose StatementBegin
-- returns the id for the header at the provided height which is heaviest
CREATE OR REPLACE FUNCTION canonical_header(height BIGINT) RETURNS INT AS
$BODY$
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
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
51 changes: 50 additions & 1 deletion db/migrations/00028_add_state_leaf_remove_function.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,9 @@
-- +goose Up

DROP FUNCTION was_storage_removed;
DROP FUNCTION was_state_removed;
DROP FUNCTION "ethHeaderCidByBlockNumber"(bigint);

-- +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)
Expand All @@ -15,6 +20,50 @@ $$
language sql;
-- +goose StatementEnd


-- +goose Down
-- +goose StatementBegin
-- 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
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)
WHERE storage_path = path
AND block_number > height
AND block_number <= (SELECT block_number
FROM eth.header_cids
WHERE block_hash = hash)
AND storage_cids.node_type = 3
LIMIT 1);
$$ LANGUAGE SQL;
-- +goose StatementEnd

-- +goose StatementBegin
-- returns if a state node at the provided path was removed in the range > the provided height and <= the provided block hash
CREATE OR REPLACE FUNCTION was_state_removed(path BYTEA, height BIGINT, hash VARCHAR(66)) RETURNS BOOLEAN
AS $$
SELECT exists(SELECT 1
FROM eth.state_cids
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
FROM eth.header_cids
WHERE block_hash = hash)
AND state_cids.node_type = 3
LIMIT 1);
$$ LANGUAGE SQL;
-- +goose StatementEnd

-- +goose StatementBegin
CREATE FUNCTION "ethHeaderCidByBlockNumber"(n bigint) returns SETOF eth.header_cids
stable
language sql
as
$$
SELECT * FROM eth.header_cids WHERE block_number=$1 ORDER BY id
$$;
-- +goose StatementEnd

DROP FUNCTION was_state_leaf_removed;
64 changes: 6 additions & 58 deletions db/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@
--

-- Dumped from database version 10.12
-- Dumped by pg_dump version 13.4 (Ubuntu 13.4-1.pgdg20.04+1)
-- Dumped by pg_dump version 14.0 (Ubuntu 14.0-1.pgdg20.04+1)

SET statement_timeout = 0;
SET lock_timeout = 0;
Expand Down Expand Up @@ -188,17 +188,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: -
--
Expand Down Expand Up @@ -250,47 +239,6 @@ CREATE FUNCTION public.was_state_leaf_removed(key character varying, hash charac
$$;


--
-- Name: was_state_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
--

CREATE FUNCTION public.was_state_removed(path bytea, height bigint, hash character varying) RETURNS boolean
LANGUAGE sql
AS $$
SELECT exists(SELECT 1
FROM eth.state_cids
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
FROM eth.header_cids
WHERE block_hash = hash)
AND state_cids.node_type = 3
LIMIT 1);
$$;


--
-- Name: was_storage_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
--

CREATE FUNCTION public.was_storage_removed(path bytea, height bigint, hash character varying) RETURNS boolean
LANGUAGE sql
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)
WHERE storage_path = path
AND block_number > height
AND block_number <= (SELECT block_number
FROM eth.header_cids
WHERE block_hash = hash)
AND storage_cids.node_type = 3
LIMIT 1);
$$;


--
-- Name: access_list_element; Type: TABLE; Schema: eth; Owner: -
--
Expand Down Expand Up @@ -1056,14 +1004,14 @@ CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
-- Name: rct_leaf_cid_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_mh_key);
CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid);


--
-- Name: rct_leaf_mh_key_index; Type: INDEX; Schema: eth; Owner: -
-- Name: rct_leaf_mh_index; Type: INDEX; Schema: eth; Owner: -
--

CREATE INDEX rct_leaf_mh_key_index ON eth.receipt_cids USING btree (leaf_cid);
CREATE INDEX rct_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);


--
Expand Down Expand Up @@ -1310,11 +1258,11 @@ ALTER TABLE ONLY eth.log_cids


--
-- Name: receipt_cids receipt_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: receipt_cids receipt_cids_leaf_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--

ALTER TABLE ONLY eth.receipt_cids
ADD CONSTRAINT receipt_cids_mh_key_fkey FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT receipt_cids_leaf_mh_key_fkey FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;


--
Expand Down

0 comments on commit 8f927a3

Please sign in to comment.