Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

denormalize tables by block_number #51

Merged
merged 2 commits into from
Mar 22, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
6 changes: 4 additions & 2 deletions db/migrations/00001_create_ipfs_blocks_table.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,9 @@
-- +goose Up
CREATE TABLE IF NOT EXISTS public.blocks (
key TEXT PRIMARY KEY,
data BYTEA NOT NULL
block_number BIGINT NOT NULL,
key TEXT UNIQUE NOT NULL,
data BYTEA NOT NULL,
PRIMARY KEY (key, block_number)
);

-- +goose Down
Expand Down
12 changes: 6 additions & 6 deletions db/migrations/00002_create_nodes_table.sql
Original file line number Diff line number Diff line change
@@ -1,10 +1,10 @@
-- +goose Up
CREATE TABLE nodes (
genesis_block VARCHAR(66),
network_id VARCHAR,
node_id VARCHAR(128) PRIMARY KEY,
client_name VARCHAR,
chain_id INTEGER DEFAULT 1
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
Expand Down
7 changes: 4 additions & 3 deletions db/migrations/00004_create_eth_header_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
-- +goose Up
CREATE TABLE eth.header_cids (
CREATE TABLE IF NOT EXISTS eth.header_cids (
block_number BIGINT NOT NULL,
block_hash VARCHAR(66) PRIMARY KEY,
parent_hash VARCHAR(66) NOT NULL,
Expand All @@ -13,9 +13,10 @@ CREATE TABLE eth.header_cids (
uncle_root VARCHAR(66) NOT NULL,
bloom BYTEA NOT NULL,
timestamp BIGINT NOT NULL,
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
mh_key TEXT NOT NULL,
times_validated INTEGER NOT NULL DEFAULT 1,
coinbase VARCHAR(66) NOT NULL
coinbase VARCHAR(66) NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

-- +goose Down
Expand Down
6 changes: 4 additions & 2 deletions db/migrations/00005_create_eth_uncle_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,13 @@
-- +goose Up
CREATE TABLE eth.uncle_cids (
CREATE TABLE IF NOT EXISTS eth.uncle_cids (
block_number BIGINT NOT NULL,
block_hash VARCHAR(66) PRIMARY KEY,
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
parent_hash VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
reward NUMERIC NOT NULL,
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
mh_key TEXT NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

-- +goose Down
Expand Down
8 changes: 5 additions & 3 deletions db/migrations/00006_create_eth_transaction_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,15 +1,17 @@
-- +goose Up
CREATE TABLE eth.transaction_cids (
CREATE TABLE IF NOT EXISTS eth.transaction_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
tx_hash VARCHAR(66) PRIMARY KEY,
cid TEXT NOT NULL,
dst VARCHAR(66) NOT NULL,
src VARCHAR(66) NOT NULL,
index INTEGER NOT NULL,
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
mh_key TEXT NOT NULL,
tx_data BYTEA,
tx_type INTEGER,
value NUMERIC
value NUMERIC,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

-- +goose Down
Expand Down
8 changes: 5 additions & 3 deletions db/migrations/00007_create_eth_receipt_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,15 @@
-- +goose Up
CREATE TABLE eth.receipt_cids (
CREATE TABLE IF NOT EXISTS eth.receipt_cids (
block_number BIGINT NOT NULL,
tx_id VARCHAR(66) PRIMARY KEY REFERENCES eth.transaction_cids (tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
leaf_cid TEXT NOT NULL,
contract VARCHAR(66),
contract_hash VARCHAR(66),
leaf_mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
leaf_mh_key TEXT NOT NULL,
post_state VARCHAR(66),
post_status INTEGER,
log_root VARCHAR(66)
log_root VARCHAR(66),
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

-- +goose Down
Expand Down
6 changes: 4 additions & 2 deletions db/migrations/00008_create_eth_state_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,12 +1,14 @@
-- +goose Up
CREATE TABLE eth.state_cids (
CREATE TABLE IF NOT EXISTS eth.state_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
state_leaf_key VARCHAR(66),
cid TEXT NOT NULL,
state_path BYTEA NOT NULL,
node_type INTEGER NOT NULL,
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
mh_key TEXT NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (header_id, state_path)
);

Expand Down
6 changes: 4 additions & 2 deletions db/migrations/00009_create_eth_storage_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,15 @@
-- +goose Up
CREATE TABLE eth.storage_cids (
CREATE TABLE IF NOT EXISTS eth.storage_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_path BYTEA NOT NULL,
storage_leaf_key VARCHAR(66),
cid TEXT NOT NULL,
storage_path BYTEA NOT NULL,
node_type INTEGER NOT NULL,
diff BOOLEAN NOT NULL DEFAULT FALSE,
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
mh_key TEXT NOT NULL,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (header_id, state_path, storage_path)
);
Expand Down
3 changes: 2 additions & 1 deletion db/migrations/00010_create_eth_state_accounts_table.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
-- +goose Up
CREATE TABLE eth.state_accounts (
CREATE TABLE IF NOT EXISTS eth.state_accounts (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_path BYTEA NOT NULL,
balance NUMERIC NOT NULL,
Expand Down
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
-- +goose Up
CREATE TABLE eth.access_list_elements (
CREATE TABLE IF NOT EXISTS eth.access_list_elements (
block_number BIGINT NOT NULL,
tx_id VARCHAR(66) NOT NULL REFERENCES eth.transaction_cids (tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
index INTEGER NOT NULL,
address VARCHAR(66),
Expand Down
6 changes: 4 additions & 2 deletions db/migrations/00012_create_eth_log_cids_table.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,8 @@
-- +goose Up
CREATE TABLE eth.log_cids (
CREATE TABLE IF NOT EXISTS eth.log_cids (
block_number BIGINT NOT NULL,
leaf_cid TEXT NOT NULL,
leaf_mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
leaf_mh_key TEXT NOT NULL,
rct_id VARCHAR(66) NOT NULL REFERENCES eth.receipt_cids (tx_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
address VARCHAR(66) NOT NULL,
index INTEGER NOT NULL,
Expand All @@ -10,6 +11,7 @@ CREATE TABLE eth.log_cids (
topic2 VARCHAR(66),
topic3 VARCHAR(66),
log_data BYTEA,
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (rct_id, index)
);

Expand Down
20 changes: 18 additions & 2 deletions db/migrations/00014_create_cid_indexes.sql
Original file line number Diff line number Diff line change
@@ -1,35 +1,40 @@
-- +goose Up
-- header indexes
CREATE INDEX block_number_index ON eth.header_cids USING brin (block_number);
CREATE INDEX header_block_number_index ON eth.header_cids USING brin (block_number);
CREATE UNIQUE INDEX header_cid_index ON eth.header_cids USING btree (cid);
CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);

-- uncle indexes
CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number);
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 brin (block_number);
CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
CREATE UNIQUE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid);
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
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 brin (block_number);
CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid);
CREATE INDEX rct_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);
CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash);

-- state node indexes
CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number);
CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key);
CREATE INDEX state_cid_index ON eth.state_cids USING btree (cid);
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_node_type_index ON eth.state_cids USING btree (node_type);

-- storage node indexes
CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number);
CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path);
CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key);
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
Expand All @@ -38,14 +43,17 @@ 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
CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number);
CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_path);
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);

-- access list indexes
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
CREATE INDEX access_list_element_address_index ON eth.access_list_elements USING btree (address);
CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys);

-- log indexes
CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number);
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);
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
Expand All @@ -63,14 +71,17 @@ DROP INDEX eth.log_topic0_index;
DROP INDEX eth.log_address_index;
DROP INDEX eth.log_cid_index;
DROP INDEX eth.log_mh_index;
DROP INDEX eth.log_block_number_index;

-- access list indexes
DROP INDEX eth.access_list_storage_keys_index;
DROP INDEX eth.access_list_element_address_index;
DROP INDEX eth.access_list_block_number_index;

-- state account indexes
DROP INDEX eth.storage_root_index;
DROP index eth.account_state_path_index;
DROP INDEX eth.account_block_number_index;

-- storage node indexes
DROP INDEX eth.storage_node_type_index;
Expand All @@ -79,33 +90,38 @@ DROP INDEX eth.storage_mh_index;
DROP INDEX eth.storage_cid_index;
DROP INDEX eth.storage_leaf_key_index;
DROP INDEX eth.storage_state_path_index;
DROP INDEX eth.storage_block_number_index;

-- state node indexes
DROP INDEX eth.state_node_type_index;
DROP INDEX eth.state_path_index;
DROP INDEX eth.state_mh_index;
DROP INDEX eth.state_cid_index;
DROP INDEX eth.state_leaf_key_index;
DROP INDEX eth.state_block_number_index;

-- receipt indexes
DROP INDEX eth.rct_contract_hash_index;
DROP INDEX eth.rct_contract_index;
DROP INDEX eth.rct_leaf_mh_index;
DROP INDEX eth.rct_leaf_cid_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_mh_index;
DROP INDEX eth.tx_cid_index;
DROP INDEX eth.tx_header_id_index;
DROP INDEX eth.tx_block_number_index;

-- uncle indexes
DROP INDEX eth.uncle_header_id_index;
DROP INDEX eth.uncle_block_number_index;

-- header indexes
DROP INDEX eth.timestamp_index;
DROP INDEX eth.state_root_index;
DROP INDEX eth.header_mh_index;
DROP INDEX eth.header_cid_index;
DROP INDEX eth.block_number_index;
DROP INDEX eth.header_block_number_index;
4 changes: 2 additions & 2 deletions db/migrations/00015_create_stored_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash ch
FROM eth.state_cids
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
WHERE state_leaf_key = key
AND block_number <= (SELECT block_number
AND state_cids.block_number <= (SELECT block_number
FROM eth.header_cids
WHERE block_hash = hash)
ORDER BY block_number DESC LIMIT 1;
ORDER BY state_cids.block_number DESC LIMIT 1;
$$
language sql;
-- +goose StatementEnd
Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
-- +goose Up
ALTER TABLE public.blocks
ADD CONSTRAINT pk_public_blocks PRIMARY KEY (key);
ADD CONSTRAINT pk_public_blocks PRIMARY KEY (key, block_number);

-- +goose Down
ALTER TABLE public.blocks
Expand Down
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
-- +goose Up
ALTER TABLE eth.log_cids
ADD CONSTRAINT fk_log_leaf_mh_key
FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

-- +goose Down
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,7 @@ DROP CONSTRAINT fk_log_leaf_mh_key;
-- +goose Down
ALTER TABLE eth.log_cids
ADD CONSTRAINT fk_log_leaf_mh_key
FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

UPDATE pg_index
Expand Down
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
-- +goose Up
ALTER TABLE eth.header_cids
ADD CONSTRAINT fk_header_mh_key
FOREIGN KEY (mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.header_cids
Expand All @@ -11,7 +11,7 @@ ADD CONSTRAINT fk_header_node_id

ALTER TABLE eth.uncle_cids
ADD CONSTRAINT fk_uncle_mh_key
FOREIGN KEY (mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.uncle_cids
Expand All @@ -21,7 +21,7 @@ ADD CONSTRAINT fk_uncle_header_id

ALTER TABLE eth.transaction_cids
ADD CONSTRAINT fk_tx_mh_key
FOREIGN KEY (mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.transaction_cids
Expand All @@ -31,7 +31,7 @@ ADD CONSTRAINT fk_tx_header_id

ALTER TABLE eth.receipt_cids
ADD CONSTRAINT fk_rct_leaf_mh_key
FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.receipt_cids
Expand All @@ -41,7 +41,7 @@ ADD CONSTRAINT fk_rct_tx_id

ALTER TABLE eth.state_cids
ADD CONSTRAINT fk_state_mh_key
FOREIGN KEY (mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.state_cids
Expand All @@ -51,7 +51,7 @@ ADD CONSTRAINT fk_state_header_id

ALTER TABLE eth.storage_cids
ADD CONSTRAINT fk_storage_mh_key
FOREIGN KEY (mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.storage_cids
Expand All @@ -71,7 +71,7 @@ ADD CONSTRAINT fk_access_list_tx_id

ALTER TABLE eth.log_cids
ADD CONSTRAINT fk_log_leaf_mh_key
FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks (key)
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number)
ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;

ALTER TABLE eth.log_cids
Expand Down
Loading