Add new indexes and functions to improve eth_getStorageAt performance. (#116)

* New indexes and functions to implement get_storage_at as a function.

* Update schema.sql.
This commit is contained in:
Thomas E Lackey 2022-11-16 11:31:26 -06:00 committed by i-norden
parent 26d970ed2f
commit 53461a0996
2 changed files with 73 additions and 0 deletions

View File

@ -36,6 +36,7 @@ CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
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_removed_index ON eth.state_cids USING btree (removed); 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_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 -- storage node indexes
CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number); CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number);
@ -45,6 +46,7 @@ CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_k
CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id); CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id);
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_removed_index ON eth.storage_cids USING btree (removed); 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 -- access list indexes
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number); CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
@ -90,6 +92,7 @@ DROP INDEX eth.storage_cid_index;
DROP INDEX eth.storage_leaf_key_index; DROP INDEX eth.storage_leaf_key_index;
DROP INDEX eth.storage_state_leaf_key_index; DROP INDEX eth.storage_state_leaf_key_index;
DROP INDEX eth.storage_block_number_index; DROP INDEX eth.storage_block_number_index;
DROP INDEX eth.storage_leaf_key_block_number_index;
-- state node indexes -- state node indexes
DROP INDEX eth.state_code_hash_index; DROP INDEX eth.state_code_hash_index;
@ -99,6 +102,7 @@ DROP INDEX eth.state_header_id_index;
DROP INDEX eth.state_mh_block_number_index; DROP INDEX eth.state_mh_block_number_index;
DROP INDEX eth.state_cid_index; DROP INDEX eth.state_cid_index;
DROP INDEX eth.state_block_number_index; DROP INDEX eth.state_block_number_index;
DROP INDEX eth.state_leaf_key_block_number_index;
-- receipt indexes -- receipt indexes
DROP INDEX eth.rct_contract_hash_index; DROP INDEX eth.rct_contract_hash_index;

View File

@ -0,0 +1,69 @@
-- +goose Up
-- +goose StatementBegin
CREATE OR REPLACE FUNCTION public.was_state_leaf_removed_by_number(key character varying, blockNo bigint)
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 <= blockNo
ORDER BY state_cids.block_number DESC LIMIT 1;
$$
language sql;
CREATE OR REPLACE FUNCTION public.get_storage_at_by_number(stateLeafKey text, storageLeafKey text, blockNo bigint)
RETURNS TABLE(cid text, mh_key text, block_number bigint, node_type integer, state_leaf_removed bool) LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY SELECT STORAGE_CIDS.CID,
STORAGE_CIDS.MH_KEY,
STORAGE_CIDS.BLOCK_NUMBER,
STORAGE_CIDS.NODE_TYPE,
was_state_leaf_removed_by_number(
stateLeafKey,
blockNo
) AS STATE_LEAF_REMOVED
FROM ETH.STORAGE_CIDS
INNER JOIN ETH.STATE_CIDS ON (
STORAGE_CIDS.HEADER_ID = STATE_CIDS.HEADER_ID
AND STORAGE_CIDS.BLOCK_NUMBER = STATE_CIDS.BLOCK_NUMBER
AND STORAGE_CIDS.STATE_PATH = STATE_CIDS.STATE_PATH
AND STORAGE_CIDS.BLOCK_NUMBER <= blockNo
)
INNER JOIN ETH.HEADER_CIDS ON (
STATE_CIDS.HEADER_ID = HEADER_CIDS.BLOCK_HASH
AND STATE_CIDS.BLOCK_NUMBER = HEADER_CIDS.BLOCK_NUMBER
AND STATE_CIDS.BLOCK_NUMBER <= blockNo
)
WHERE STATE_LEAF_KEY = stateLeafKey
AND STATE_CIDS.BLOCK_NUMBER <= blockNo
AND STORAGE_LEAF_KEY = storageLeafKey
AND STORAGE_CIDS.BLOCK_NUMBER <= blockNo
AND HEADER_CIDS.BLOCK_NUMBER <= blockNo
AND HEADER_CIDS.BLOCK_HASH = (SELECT CANONICAL_HEADER_HASH(HEADER_CIDS.BLOCK_NUMBER))
ORDER BY HEADER_CIDS.BLOCK_NUMBER DESC
LIMIT 1;
END
$$;
CREATE OR REPLACE FUNCTION public.get_storage_at_by_hash(stateLeafKey text, storageLeafKey text, blockHash text)
RETURNS TABLE(cid text, mh_key text, block_number bigint, node_type integer, state_leaf_removed bool) LANGUAGE plpgsql
AS $$
DECLARE
blockNo bigint;
BEGIN
SELECT h.BLOCK_NUMBER INTO blockNo FROM ETH.HEADER_CIDS as h WHERE BLOCK_HASH = blockHash limit 1;
IF blockNo IS NULL THEN
RETURN;
END IF;
RETURN QUERY SELECT * FROM get_storage_at_by_number(stateLeafKey, storageLeafKey, blockNo);
END
$$;
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP FUNCTION public.was_state_leaf_removed_by_number;
DROP FUNCTION public.get_storage_at_by_number;
DROP FUNCTION public.get_storage_at_by_hash;
-- +goose StatementEnd