diff --git a/Makefile b/Makefile index 5b3e447..c2f57fa 100644 --- a/Makefile +++ b/Makefile @@ -74,6 +74,11 @@ migrate: $(GOOSE) checkdbvars $(GOOSE) -dir db/migrations postgres "$(CONNECT_STRING)" up pg_dump -O -s $(CONNECT_STRING) > schema.sql +## Apply all the migrations used to generate a UML diagram (containing FKs) +.PHONY: migrate_for_uml +migrate_for_uml: $(GOOSE) checkdbvars + $(GOOSE) -dir db/migrations/uml_support postgres "$(CONNECT_STRING)" up + ## Apply migrations to be ran before a batch processing .PHONY: migrate_pre_batch_set migrate_pre_batch_set: $(GOOSE) checkdbvars diff --git a/db/migrations/uml_support/00001_create_ipfs_blocks_table.sql b/db/migrations/uml_support/00001_create_ipfs_blocks_table.sql new file mode 100644 index 0000000..95d432a --- /dev/null +++ b/db/migrations/uml_support/00001_create_ipfs_blocks_table.sql @@ -0,0 +1,13 @@ +-- +goose Up +CREATE SCHEMA ipld; + +CREATE TABLE IF NOT EXISTS ipld.blocks ( + block_number BIGINT NOT NULL, + key TEXT NOT NULL, + data BYTEA NOT NULL, + PRIMARY KEY (key, block_number) +); + +-- +goose Down +DROP TABLE ipld.blocks; +DROP SCHEMA ipld; diff --git a/db/migrations/uml_support/00002_create_nodes_table.sql b/db/migrations/uml_support/00002_create_nodes_table.sql new file mode 100644 index 0000000..aec497c --- /dev/null +++ b/db/migrations/uml_support/00002_create_nodes_table.sql @@ -0,0 +1,11 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS nodes ( + genesis_block VARCHAR(66), + network_id VARCHAR, + node_id VARCHAR(128) PRIMARY KEY, + client_name VARCHAR, + chain_id INTEGER DEFAULT 1 +); + +-- +goose Down +DROP TABLE nodes; diff --git a/db/migrations/uml_support/00003_create_eth_schema.sql b/db/migrations/uml_support/00003_create_eth_schema.sql new file mode 100644 index 0000000..84d6f4b --- /dev/null +++ b/db/migrations/uml_support/00003_create_eth_schema.sql @@ -0,0 +1,5 @@ +-- +goose Up +CREATE SCHEMA eth; + +-- +goose Down +DROP SCHEMA eth; \ No newline at end of file diff --git a/db/migrations/uml_support/00004_create_eth_header_cids_table.sql b/db/migrations/uml_support/00004_create_eth_header_cids_table.sql new file mode 100644 index 0000000..3f76e59 --- /dev/null +++ b/db/migrations/uml_support/00004_create_eth_header_cids_table.sql @@ -0,0 +1,23 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.header_cids ( + block_number BIGINT NOT NULL, + block_hash VARCHAR(66) NOT NULL, + parent_hash VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + td NUMERIC NOT NULL, + node_ids VARCHAR(128)[] NOT NULL, + reward NUMERIC NOT NULL, + state_root VARCHAR(66) NOT NULL, + tx_root VARCHAR(66) NOT NULL, + receipt_root VARCHAR(66) NOT NULL, + uncles_hash VARCHAR(66) NOT NULL, + bloom BYTEA NOT NULL, + timestamp BIGINT NOT NULL, + coinbase VARCHAR(66) NOT NULL, + canonical BOOLEAN NOT NULL DEFAULT TRUE, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + PRIMARY KEY (block_hash, block_number) +); + +-- +goose Down +DROP TABLE eth.header_cids; diff --git a/db/migrations/uml_support/00005_create_eth_uncle_cids_table.sql b/db/migrations/uml_support/00005_create_eth_uncle_cids_table.sql new file mode 100644 index 0000000..666fa15 --- /dev/null +++ b/db/migrations/uml_support/00005_create_eth_uncle_cids_table.sql @@ -0,0 +1,16 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.uncle_cids ( + block_number BIGINT NOT NULL, + block_hash VARCHAR(66) NOT NULL, + header_id VARCHAR(66) NOT NULL, + parent_hash VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + reward NUMERIC NOT NULL, + index INT NOT NULL, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number), + PRIMARY KEY (block_hash, block_number) +); + +-- +goose Down +DROP TABLE eth.uncle_cids; diff --git a/db/migrations/uml_support/00006_create_eth_transaction_cids_table.sql b/db/migrations/uml_support/00006_create_eth_transaction_cids_table.sql new file mode 100644 index 0000000..2b7e8c3 --- /dev/null +++ b/db/migrations/uml_support/00006_create_eth_transaction_cids_table.sql @@ -0,0 +1,18 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.transaction_cids ( + block_number BIGINT NOT NULL, + header_id VARCHAR(66) NOT NULL, + tx_hash VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + dst VARCHAR(66), + src VARCHAR(66) NOT NULL, + index INTEGER NOT NULL, + tx_type INTEGER, + value NUMERIC, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number), + PRIMARY KEY (tx_hash, header_id, block_number) +); + +-- +goose Down +DROP TABLE eth.transaction_cids; diff --git a/db/migrations/uml_support/00007_create_eth_receipt_cids_table.sql b/db/migrations/uml_support/00007_create_eth_receipt_cids_table.sql new file mode 100644 index 0000000..596df36 --- /dev/null +++ b/db/migrations/uml_support/00007_create_eth_receipt_cids_table.sql @@ -0,0 +1,16 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.receipt_cids ( + block_number BIGINT NOT NULL, + header_id VARCHAR(66) NOT NULL, + tx_id VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + contract VARCHAR(66), + post_state VARCHAR(66), + post_status SMALLINT, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number), + PRIMARY KEY (tx_id, header_id, block_number) +); + +-- +goose Down +DROP TABLE eth.receipt_cids; diff --git a/db/migrations/uml_support/00008_create_eth_state_cids_table.sql b/db/migrations/uml_support/00008_create_eth_state_cids_table.sql new file mode 100644 index 0000000..cb45c09 --- /dev/null +++ b/db/migrations/uml_support/00008_create_eth_state_cids_table.sql @@ -0,0 +1,19 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.state_cids ( + block_number BIGINT NOT NULL, + header_id VARCHAR(66) NOT NULL, + state_leaf_key VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + diff BOOLEAN NOT NULL DEFAULT FALSE, + 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, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number), + PRIMARY KEY (state_leaf_key, header_id, block_number) +); + +-- +goose Down +DROP TABLE eth.state_cids; diff --git a/db/migrations/uml_support/00009_create_eth_storage_cids_table.sql b/db/migrations/uml_support/00009_create_eth_storage_cids_table.sql new file mode 100644 index 0000000..5243bf0 --- /dev/null +++ b/db/migrations/uml_support/00009_create_eth_storage_cids_table.sql @@ -0,0 +1,17 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.storage_cids ( + block_number BIGINT NOT NULL, + header_id VARCHAR(66) NOT NULL, + state_leaf_key VARCHAR(66) NOT NULL, + storage_leaf_key VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + diff BOOLEAN NOT NULL DEFAULT FALSE, + val BYTEA, -- NULL if "removed" + removed BOOLEAN NOT NULL, + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (state_leaf_key, header_id, block_number) REFERENCES eth.state_cids (state_leaf_key, header_id, block_number), + PRIMARY KEY (storage_leaf_key, state_leaf_key, header_id, block_number) +); + +-- +goose Down +DROP TABLE eth.storage_cids; diff --git a/db/migrations/uml_support/00010_create_eth_log_cids_table.sql b/db/migrations/uml_support/00010_create_eth_log_cids_table.sql new file mode 100644 index 0000000..01f4d8d --- /dev/null +++ b/db/migrations/uml_support/00010_create_eth_log_cids_table.sql @@ -0,0 +1,20 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.log_cids ( + block_number BIGINT NOT NULL, + header_id VARCHAR(66) NOT NULL, + cid TEXT NOT NULL, + rct_id VARCHAR(66) NOT NULL, + address VARCHAR(66) NOT NULL, + index INTEGER NOT NULL, + topic0 VARCHAR(66), + topic1 VARCHAR(66), + topic2 VARCHAR(66), + topic3 VARCHAR(66), + FOREIGN KEY (cid, block_number) REFERENCES ipld.blocks (key, block_number), + FOREIGN KEY (rct_id, header_id, block_number) REFERENCES eth.receipt_cids (tx_id, header_id, block_number), + PRIMARY KEY (rct_id, index, header_id, block_number) +); + +-- +goose Down +-- log indexes +DROP TABLE eth.log_cids; diff --git a/db/migrations/uml_support/00011_create_postgraphile_comments.sql b/db/migrations/uml_support/00011_create_postgraphile_comments.sql new file mode 100644 index 0000000..6badbe5 --- /dev/null +++ b/db/migrations/uml_support/00011_create_postgraphile_comments.sql @@ -0,0 +1,14 @@ +-- +goose Up +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_ids IS E'@name EthNodeIDs'; + +-- +goose Down + +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_ids IS NULL; diff --git a/db/migrations/uml_support/00012_create_cid_indexes.sql b/db/migrations/uml_support/00012_create_cid_indexes.sql new file mode 100644 index 0000000..7b089c2 --- /dev/null +++ b/db/migrations/uml_support/00012_create_cid_indexes.sql @@ -0,0 +1,101 @@ +-- +goose Up +-- header indexes +CREATE INDEX header_block_number_index ON eth.header_cids USING btree (block_number); +CREATE UNIQUE INDEX header_cid_block_number_index ON eth.header_cids USING btree (cid, block_number); +CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root); +CREATE INDEX timestamp_index ON eth.header_cids USING btree (timestamp); + +-- uncle indexes +CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING btree (block_number); +CREATE UNIQUE INDEX uncle_cid_block_number_index ON eth.uncle_cids USING btree (cid, block_number, index); +CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id); + +-- transaction indexes +CREATE INDEX tx_block_number_index ON eth.transaction_cids USING btree (block_number); +CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id); +CREATE INDEX tx_cid_block_number_index ON eth.transaction_cids USING btree (cid, block_number); +CREATE INDEX tx_dst_index ON eth.transaction_cids USING btree (dst); +CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src); + +-- receipt indexes +CREATE INDEX rct_block_number_index ON eth.receipt_cids USING btree (block_number); +CREATE INDEX rct_header_id_index ON eth.receipt_cids USING btree (header_id); +CREATE INDEX rct_cid_block_number_index ON eth.receipt_cids USING btree (cid, block_number); +CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract); + +-- state node indexes +CREATE INDEX state_block_number_index ON eth.state_cids USING btree (block_number); +CREATE INDEX state_cid_block_number_index ON eth.state_cids USING btree (cid, block_number); +CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id); +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 btree (block_number); +CREATE INDEX storage_state_leaf_key_index ON eth.storage_cids USING btree (state_leaf_key); +CREATE INDEX storage_cid_block_number_index ON eth.storage_cids USING btree (cid, block_number); +CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id); +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); + +-- log indexes +CREATE INDEX log_block_number_index ON eth.log_cids USING btree (block_number); +CREATE INDEX log_header_id_index ON eth.log_cids USING btree (header_id); +CREATE INDEX log_cid_block_number_index ON eth.log_cids USING btree (cid, block_number); +CREATE INDEX log_address_index ON eth.log_cids USING btree (address); +CREATE INDEX log_topic0_index ON eth.log_cids USING btree (topic0); +CREATE INDEX log_topic1_index ON eth.log_cids USING btree (topic1); +CREATE INDEX log_topic2_index ON eth.log_cids USING btree (topic2); +CREATE INDEX log_topic3_index ON eth.log_cids USING btree (topic3); + +-- +goose Down +-- log indexes +DROP INDEX eth.log_topic3_index; +DROP INDEX eth.log_topic2_index; +DROP INDEX eth.log_topic1_index; +DROP INDEX eth.log_topic0_index; +DROP INDEX eth.log_address_index; +DROP INDEX eth.log_cid_block_number_index; +DROP INDEX eth.log_header_id_index; +DROP INDEX eth.log_block_number_index; + +-- storage node indexes +DROP INDEX eth.storage_removed_index; +DROP INDEX eth.storage_header_id_index; +DROP INDEX eth.storage_cid_block_number_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_code_hash_index; +DROP INDEX eth.state_removed_index; +DROP INDEX eth.state_header_id_index; +DROP INDEX eth.state_cid_block_number_index; +DROP INDEX eth.state_block_number_index; +DROP INDEX eth.state_leaf_key_block_number_index; + +-- receipt indexes +DROP INDEX eth.rct_contract_index; +DROP INDEX eth.rct_cid_block_number_index; +DROP INDEX eth.rct_header_id_index; +DROP INDEX eth.rct_block_number_index; + +-- transaction indexes +DROP INDEX eth.tx_src_index; +DROP INDEX eth.tx_dst_index; +DROP INDEX eth.tx_cid_block_number_index; +DROP INDEX eth.tx_header_id_index; +DROP INDEX eth.tx_block_number_index; + +-- uncle indexes +DROP INDEX eth.uncle_block_number_index; +DROP INDEX eth.uncle_cid_block_number_index; +DROP INDEX eth.uncle_header_id_index; + +-- header indexes +DROP INDEX eth.timestamp_index; +DROP INDEX eth.state_root_index; +DROP INDEX eth.header_cid_block_number_index; +DROP INDEX eth.header_block_number_index; diff --git a/db/migrations/uml_support/00013_create_db_version_table.sql b/db/migrations/uml_support/00013_create_db_version_table.sql new file mode 100644 index 0000000..10bcb20 --- /dev/null +++ b/db/migrations/uml_support/00013_create_db_version_table.sql @@ -0,0 +1,12 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS public.db_version ( + singleton BOOLEAN NOT NULL DEFAULT TRUE UNIQUE CHECK (singleton), + version TEXT NOT NULL, + tstamp TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW() +); + +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v5.0.0') + ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v5.0.0', NOW()); + +-- +goose Down +DROP TABLE public.db_version; diff --git a/db/migrations/uml_support/00014_create_eth_meta_schema.sql b/db/migrations/uml_support/00014_create_eth_meta_schema.sql new file mode 100644 index 0000000..448cc91 --- /dev/null +++ b/db/migrations/uml_support/00014_create_eth_meta_schema.sql @@ -0,0 +1,5 @@ +-- +goose Up +CREATE SCHEMA eth_meta; + +-- +goose Down +DROP SCHEMA eth_meta; diff --git a/db/migrations/uml_support/00015_create_watched_addresses_table.sql b/db/migrations/uml_support/00015_create_watched_addresses_table.sql new file mode 100644 index 0000000..a8f009f --- /dev/null +++ b/db/migrations/uml_support/00015_create_watched_addresses_table.sql @@ -0,0 +1,10 @@ +-- +goose Up +CREATE TABLE eth_meta.watched_addresses ( + address VARCHAR(66) PRIMARY KEY, + created_at BIGINT NOT NULL, + watched_at BIGINT NOT NULL, + last_filled_at BIGINT NOT NULL DEFAULT 0 +); + +-- +goose Down +DROP TABLE eth_meta.watched_addresses; diff --git a/db/migrations/uml_support/00016_create_stored_procedures.sql b/db/migrations/uml_support/00016_create_stored_procedures.sql new file mode 100644 index 0000000..776d220 --- /dev/null +++ b/db/migrations/uml_support/00016_create_stored_procedures.sql @@ -0,0 +1,43 @@ +-- +goose Up +-- +goose StatementBegin +-- returns whether the state leaf key is vacated (previously existed but now is empty) at the provided block hash +CREATE OR REPLACE FUNCTION was_state_leaf_removed(v_key VARCHAR(66), v_hash VARCHAR) + 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 = v_key + AND state_cids.block_number <= (SELECT block_number + FROM eth.header_cids + WHERE block_hash = v_hash) + ORDER BY state_cids.block_number DESC LIMIT 1; +$$ +language sql; +-- +goose StatementEnd + +-- +goose StatementBegin +-- returns whether the state leaf key is vacated (previously existed but now is empty) at the provided block height +CREATE OR REPLACE FUNCTION public.was_state_leaf_removed_by_number(v_key VARCHAR(66), v_block_no BIGINT) + 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 = v_key + AND state_cids.block_number <= v_block_no + ORDER BY state_cids.block_number DESC LIMIT 1; +$$ +language sql; +-- +goose StatementEnd + +-- +goose StatementBegin +CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS +$BODY$ + SELECT block_hash from eth.header_cids WHERE block_number = height AND canonical = true LIMIT 1; +$BODY$ +LANGUAGE sql; +-- +goose StatementEnd + +-- +goose Down +DROP FUNCTION was_state_leaf_removed; +DROP FUNCTION was_state_leaf_removed_by_number; +DROP FUNCTION canonical_header_hash; diff --git a/db/migrations/uml_support/00017_create_get_storage_at_functions.sql b/db/migrations/uml_support/00017_create_get_storage_at_functions.sql new file mode 100644 index 0000000..0242b96 --- /dev/null +++ b/db/migrations/uml_support/00017_create_get_storage_at_functions.sql @@ -0,0 +1,110 @@ +-- +goose Up +-- +goose StatementBegin +CREATE OR REPLACE FUNCTION public.get_storage_at_by_number(v_state_leaf_key text, v_storage_leaf_key text, v_block_no bigint) + RETURNS TABLE + ( + cid TEXT, + val BYTEA, + block_number BIGINT, + removed BOOL, + state_leaf_removed BOOL + ) +AS +$BODY$ +DECLARE + v_state_path BYTEA; + v_header TEXT; + v_canonical_header TEXT; +BEGIN + CREATE TEMP TABLE tmp_tt_stg2 + ( + header_id TEXT, + cid TEXT, + val BYTEA, + block_number BIGINT, + removed BOOL, + state_leaf_removed BOOL + ) ON COMMIT DROP; + + -- in best case scenario, the latest record we find for the provided keys is for a canonical block + INSERT INTO tmp_tt_stg2 + SELECT storage_cids.header_id, + storage_cids.cid, + storage_cids.val, + storage_cids.block_number, + storage_cids.removed, + was_state_leaf_removed_by_number(v_state_leaf_key, v_block_no) AS state_leaf_removed + FROM eth.storage_cids + WHERE storage_leaf_key = v_storage_leaf_key + AND storage_cids.state_leaf_key = v_state_leaf_key -- can lookup directly on the leaf key in v5 + AND storage_cids.block_number <= v_block_no + ORDER BY storage_cids.block_number DESC LIMIT 1; + + -- check if result is from canonical state + SELECT header_id, canonical_header_hash(tmp_tt_stg2.block_number) + INTO v_header, v_canonical_header + FROM tmp_tt_stg2 LIMIT 1; + + IF v_header IS NULL OR v_header != v_canonical_header THEN + RAISE NOTICE 'get_storage_at_by_number: chosen header NULL OR % != canonical header % for block number %, trying again.', v_header, v_canonical_header, v_block_no; + TRUNCATE tmp_tt_stg2; + -- If we hit on a non-canonical block, we need to go back and do a comprehensive check. + -- We try to avoid this to avoid joining between storage_cids and header_cids + INSERT INTO tmp_tt_stg2 + SELECT storage_cids.header_id, + storage_cids.cid, + storage_cids.val, + storage_cids.block_number, + storage_cids.removed, + was_state_leaf_removed_by_number( + v_state_leaf_key, + v_block_no + ) AS state_leaf_removed + FROM eth.storage_cids + INNER JOIN eth.header_cids ON ( + storage_cids.header_id = header_cids.block_hash + AND storage_cids.block_number = header_cids.block_number + ) + WHERE state_leaf_key = v_state_leaf_key + AND storage_leaf_key = v_storage_leaf_key + AND storage_cids.block_number <= v_block_no + AND header_cids.block_number <= v_block_no + AND header_cids.block_hash = (SELECT canonical_header_hash(header_cids.block_number)) + ORDER BY header_cids.block_number DESC LIMIT 1; + END IF; + + RETURN QUERY SELECT t.cid, t.val, t.block_number, t.removed, t.state_leaf_removed + FROM tmp_tt_stg2 AS t LIMIT 1; +END +$BODY$ +language 'plpgsql'; +-- +goose StatementEnd + +-- +goose StatementBegin +CREATE OR REPLACE FUNCTION public.get_storage_at_by_hash(v_state_leaf_key TEXT, v_storage_leaf_key text, v_block_hash text) + RETURNS TABLE + ( + cid TEXT, + val BYTEA, + block_number BIGINT, + removed BOOL, + state_leaf_removed BOOL + ) +AS +$BODY$ +DECLARE + v_block_no BIGINT; +BEGIN + SELECT h.block_number INTO v_block_no FROM eth.header_cids AS h WHERE block_hash = v_block_hash LIMIT 1; + IF v_block_no IS NULL THEN + RETURN; + END IF; + RETURN QUERY SELECT * FROM get_storage_at_by_number(v_state_leaf_key, v_storage_leaf_key, v_block_no); +END +$BODY$ +LANGUAGE 'plpgsql'; +-- +goose StatementEnd + +-- +goose Down +DROP FUNCTION get_storage_at_by_hash; +DROP FUNCTION get_storage_at_by_number; diff --git a/vulcanize_db.png b/vulcanize_db.png index 35ee8a6..0a7a02a 100644 Binary files a/vulcanize_db.png and b/vulcanize_db.png differ diff --git a/vulcanize_db.uml b/vulcanize_db.uml index 65094e7..872e959 100644 --- a/vulcanize_db.uml +++ b/vulcanize_db.uml @@ -1,148 +1,109 @@ DATABASE - 407978cb-39e6-453c-b9b7-c4183a4e26ef + 86a0461b-ec84-4911-9aa2-e562b5d7b24c - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.header_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.receipt_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.state_accounts - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.public.nodes - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.uncle_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.public.blocks - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.transaction_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.access_list_elements - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.state_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.public.db_version - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.log_cids - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.public.goose_db_version - 407978cb-39e6-453c-b9b7-c4183a4e26ef.TABLE:vulcanize_test.eth.storage_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.header_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.public.goose_db_version + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.public.nodes + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.log_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.uncle_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.ipld.blocks + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.state_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth_meta.watched_addresses + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.storage_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.transaction_cids + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.public.db_version + 86a0461b-ec84-4911-9aa2-e562b5d7b24c.TABLE:uml_diagram.eth.receipt_cids - - - - - + + + + + + + - - - - - + + + + + + + - - - - - - - - - + + + + + - - - - + + + + - - - - - - - - - + + + + + - - - - - + + + + + + + - - - - - - - - - + + + + + - - - - - + + + + + - - - - - - - - - - - + - - - + - - - - - + + + + + + + - - - - - + + + + + - - - - - + + + - - - - - - - - - - - - - - - - - - - - - - - - - - - + + + + + + + - + Columns