denormalize tables by block_number so that we can partition all tables by block_number for purposes of sharding
This commit is contained in:
parent
bba8a410f8
commit
1dc12460dc
@ -1,7 +1,9 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE IF NOT EXISTS public.blocks (
|
CREATE TABLE IF NOT EXISTS public.blocks (
|
||||||
key TEXT PRIMARY KEY,
|
block_number BIGINT NOT NULL,
|
||||||
data BYTEA NOT NULL
|
key TEXT UNIQUE NOT NULL,
|
||||||
|
data BYTEA NOT NULL,
|
||||||
|
PRIMARY KEY (key, block_number)
|
||||||
);
|
);
|
||||||
|
|
||||||
-- +goose Down
|
-- +goose Down
|
||||||
|
@ -13,9 +13,10 @@ CREATE TABLE eth.header_cids (
|
|||||||
uncle_root VARCHAR(66) NOT NULL,
|
uncle_root VARCHAR(66) NOT NULL,
|
||||||
bloom BYTEA NOT NULL,
|
bloom BYTEA NOT NULL,
|
||||||
timestamp BIGINT 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,
|
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
|
-- +goose Down
|
||||||
|
@ -1,11 +1,13 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.uncle_cids (
|
CREATE TABLE eth.uncle_cids (
|
||||||
|
block_number BIGINT NOT NULL,
|
||||||
block_hash VARCHAR(66) PRIMARY KEY,
|
block_hash VARCHAR(66) PRIMARY KEY,
|
||||||
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
parent_hash VARCHAR(66) NOT NULL,
|
parent_hash VARCHAR(66) NOT NULL,
|
||||||
cid TEXT NOT NULL,
|
cid TEXT NOT NULL,
|
||||||
reward NUMERIC 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
|
-- +goose Down
|
||||||
|
@ -1,15 +1,17 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.transaction_cids (
|
CREATE TABLE 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,
|
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
tx_hash VARCHAR(66) PRIMARY KEY,
|
tx_hash VARCHAR(66) PRIMARY KEY,
|
||||||
cid TEXT NOT NULL,
|
cid TEXT NOT NULL,
|
||||||
dst VARCHAR(66) NOT NULL,
|
dst VARCHAR(66) NOT NULL,
|
||||||
src VARCHAR(66) NOT NULL,
|
src VARCHAR(66) NOT NULL,
|
||||||
index INTEGER 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_data BYTEA,
|
||||||
tx_type INTEGER,
|
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
|
-- +goose Down
|
||||||
|
@ -1,13 +1,15 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.receipt_cids (
|
CREATE TABLE 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,
|
tx_id VARCHAR(66) PRIMARY KEY REFERENCES eth.transaction_cids (tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
leaf_cid TEXT NOT NULL,
|
leaf_cid TEXT NOT NULL,
|
||||||
contract VARCHAR(66),
|
contract VARCHAR(66),
|
||||||
contract_hash 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_state VARCHAR(66),
|
||||||
post_status INTEGER,
|
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
|
-- +goose Down
|
||||||
|
@ -1,12 +1,14 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.state_cids (
|
CREATE TABLE 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,
|
header_id VARCHAR(66) NOT NULL REFERENCES eth.header_cids (block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
state_leaf_key VARCHAR(66),
|
state_leaf_key VARCHAR(66),
|
||||||
cid TEXT NOT NULL,
|
cid TEXT NOT NULL,
|
||||||
state_path BYTEA NOT NULL,
|
state_path BYTEA NOT NULL,
|
||||||
node_type INTEGER NOT NULL,
|
node_type INTEGER NOT NULL,
|
||||||
diff BOOLEAN NOT NULL DEFAULT FALSE,
|
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)
|
PRIMARY KEY (header_id, state_path)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
@ -1,5 +1,6 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.storage_cids (
|
CREATE TABLE eth.storage_cids (
|
||||||
|
block_number BIGINT NOT NULL,
|
||||||
header_id VARCHAR(66) NOT NULL,
|
header_id VARCHAR(66) NOT NULL,
|
||||||
state_path BYTEA NOT NULL,
|
state_path BYTEA NOT NULL,
|
||||||
storage_leaf_key VARCHAR(66),
|
storage_leaf_key VARCHAR(66),
|
||||||
@ -7,7 +8,8 @@ CREATE TABLE eth.storage_cids (
|
|||||||
storage_path BYTEA NOT NULL,
|
storage_path BYTEA NOT NULL,
|
||||||
node_type INTEGER NOT NULL,
|
node_type INTEGER NOT NULL,
|
||||||
diff BOOLEAN NOT NULL DEFAULT FALSE,
|
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,
|
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)
|
PRIMARY KEY (header_id, state_path, storage_path)
|
||||||
);
|
);
|
||||||
|
@ -1,5 +1,6 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.state_accounts (
|
CREATE TABLE eth.state_accounts (
|
||||||
|
block_number BIGINT NOT NULL,
|
||||||
header_id VARCHAR(66) NOT NULL,
|
header_id VARCHAR(66) NOT NULL,
|
||||||
state_path BYTEA NOT NULL,
|
state_path BYTEA NOT NULL,
|
||||||
balance NUMERIC NOT NULL,
|
balance NUMERIC NOT NULL,
|
||||||
|
@ -1,5 +1,6 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.access_list_elements (
|
CREATE TABLE 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,
|
tx_id VARCHAR(66) NOT NULL REFERENCES eth.transaction_cids (tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
index INTEGER NOT NULL,
|
index INTEGER NOT NULL,
|
||||||
address VARCHAR(66),
|
address VARCHAR(66),
|
||||||
|
@ -1,7 +1,8 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
CREATE TABLE eth.log_cids (
|
CREATE TABLE eth.log_cids (
|
||||||
|
block_number BIGINT NOT NULL,
|
||||||
leaf_cid TEXT 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,
|
rct_id VARCHAR(66) NOT NULL REFERENCES eth.receipt_cids (tx_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
address VARCHAR(66) NOT NULL,
|
address VARCHAR(66) NOT NULL,
|
||||||
index INTEGER NOT NULL,
|
index INTEGER NOT NULL,
|
||||||
@ -10,6 +11,7 @@ CREATE TABLE eth.log_cids (
|
|||||||
topic2 VARCHAR(66),
|
topic2 VARCHAR(66),
|
||||||
topic3 VARCHAR(66),
|
topic3 VARCHAR(66),
|
||||||
log_data BYTEA,
|
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)
|
PRIMARY KEY (rct_id, index)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
@ -1,15 +1,17 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
-- header indexes
|
-- 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_cid_index ON eth.header_cids USING btree (cid);
|
||||||
CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
|
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 state_root_index ON eth.header_cids USING btree (state_root);
|
||||||
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);
|
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);
|
||||||
|
|
||||||
-- uncle indexes
|
-- 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);
|
CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id);
|
||||||
|
|
||||||
-- transaction indexes
|
-- 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 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_cid_index ON eth.transaction_cids USING btree (cid);
|
||||||
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
|
CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
|
||||||
@ -17,12 +19,14 @@ CREATE INDEX tx_dst_index ON eth.transaction_cids USING btree (dst);
|
|||||||
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
|
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
|
||||||
|
|
||||||
-- receipt indexes
|
-- 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_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_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_index ON eth.receipt_cids USING btree (contract);
|
||||||
CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash);
|
CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash);
|
||||||
|
|
||||||
-- state node indexes
|
-- 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_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_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_mh_index ON eth.state_cids USING btree (mh_key);
|
||||||
@ -30,6 +34,7 @@ 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);
|
CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type);
|
||||||
|
|
||||||
-- storage node indexes
|
-- 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_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_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key);
|
||||||
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
|
CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid);
|
||||||
@ -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);
|
CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type);
|
||||||
|
|
||||||
-- state accounts indexes
|
-- 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 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);
|
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);
|
||||||
|
|
||||||
-- 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_element_address_index ON eth.access_list_elements USING btree (address);
|
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);
|
CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys);
|
||||||
|
|
||||||
-- log indexes
|
-- 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_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_cid_index ON eth.log_cids USING btree (leaf_cid);
|
||||||
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
|
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
|
||||||
@ -63,14 +71,17 @@ DROP INDEX eth.log_topic0_index;
|
|||||||
DROP INDEX eth.log_address_index;
|
DROP INDEX eth.log_address_index;
|
||||||
DROP INDEX eth.log_cid_index;
|
DROP INDEX eth.log_cid_index;
|
||||||
DROP INDEX eth.log_mh_index;
|
DROP INDEX eth.log_mh_index;
|
||||||
|
DROP INDEX eth.log_block_number_index;
|
||||||
|
|
||||||
-- access list indexes
|
-- access list indexes
|
||||||
DROP INDEX eth.access_list_storage_keys_index;
|
DROP INDEX eth.access_list_storage_keys_index;
|
||||||
DROP INDEX eth.access_list_element_address_index;
|
DROP INDEX eth.access_list_element_address_index;
|
||||||
|
DROP INDEX eth.access_list_block_number_index;
|
||||||
|
|
||||||
-- state account indexes
|
-- state account indexes
|
||||||
DROP INDEX eth.storage_root_index;
|
DROP INDEX eth.storage_root_index;
|
||||||
DROP index eth.account_state_path_index;
|
DROP index eth.account_state_path_index;
|
||||||
|
DROP INDEX eth.account_block_number_index;
|
||||||
|
|
||||||
-- storage node indexes
|
-- storage node indexes
|
||||||
DROP INDEX eth.storage_node_type_index;
|
DROP INDEX eth.storage_node_type_index;
|
||||||
@ -79,6 +90,7 @@ DROP INDEX eth.storage_mh_index;
|
|||||||
DROP INDEX eth.storage_cid_index;
|
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_path_index;
|
DROP INDEX eth.storage_state_path_index;
|
||||||
|
DROP INDEX eth.storage_block_number_index;
|
||||||
|
|
||||||
-- state node indexes
|
-- state node indexes
|
||||||
DROP INDEX eth.state_node_type_index;
|
DROP INDEX eth.state_node_type_index;
|
||||||
@ -86,12 +98,14 @@ DROP INDEX eth.state_path_index;
|
|||||||
DROP INDEX eth.state_mh_index;
|
DROP INDEX eth.state_mh_index;
|
||||||
DROP INDEX eth.state_cid_index;
|
DROP INDEX eth.state_cid_index;
|
||||||
DROP INDEX eth.state_leaf_key_index;
|
DROP INDEX eth.state_leaf_key_index;
|
||||||
|
DROP INDEX eth.state_block_number_index;
|
||||||
|
|
||||||
-- receipt indexes
|
-- receipt indexes
|
||||||
DROP INDEX eth.rct_contract_hash_index;
|
DROP INDEX eth.rct_contract_hash_index;
|
||||||
DROP INDEX eth.rct_contract_index;
|
DROP INDEX eth.rct_contract_index;
|
||||||
DROP INDEX eth.rct_leaf_mh_index;
|
DROP INDEX eth.rct_leaf_mh_index;
|
||||||
DROP INDEX eth.rct_leaf_cid_index;
|
DROP INDEX eth.rct_leaf_cid_index;
|
||||||
|
DROP INDEX eth.rct_block_number_index;
|
||||||
|
|
||||||
-- transaction indexes
|
-- transaction indexes
|
||||||
DROP INDEX eth.tx_src_index;
|
DROP INDEX eth.tx_src_index;
|
||||||
@ -99,13 +113,15 @@ DROP INDEX eth.tx_dst_index;
|
|||||||
DROP INDEX eth.tx_mh_index;
|
DROP INDEX eth.tx_mh_index;
|
||||||
DROP INDEX eth.tx_cid_index;
|
DROP INDEX eth.tx_cid_index;
|
||||||
DROP INDEX eth.tx_header_id_index;
|
DROP INDEX eth.tx_header_id_index;
|
||||||
|
DROP INDEX eth.tx_block_number_index;
|
||||||
|
|
||||||
-- uncle indexes
|
-- uncle indexes
|
||||||
DROP INDEX eth.uncle_header_id_index;
|
DROP INDEX eth.uncle_header_id_index;
|
||||||
|
DROP INDEX eth.uncle_block_number_index;
|
||||||
|
|
||||||
-- header indexes
|
-- header indexes
|
||||||
DROP INDEX eth.timestamp_index;
|
DROP INDEX eth.timestamp_index;
|
||||||
DROP INDEX eth.state_root_index;
|
DROP INDEX eth.state_root_index;
|
||||||
DROP INDEX eth.header_mh_index;
|
DROP INDEX eth.header_mh_index;
|
||||||
DROP INDEX eth.header_cid_index;
|
DROP INDEX eth.header_cid_index;
|
||||||
DROP INDEX eth.block_number_index;
|
DROP INDEX eth.header_block_number_index;
|
||||||
|
@ -7,10 +7,10 @@ CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash ch
|
|||||||
FROM eth.state_cids
|
FROM eth.state_cids
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
WHERE state_leaf_key = key
|
WHERE state_leaf_key = key
|
||||||
AND block_number <= (SELECT block_number
|
AND state_cids.block_number <= (SELECT block_number
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE block_hash = hash)
|
WHERE block_hash = hash)
|
||||||
ORDER BY block_number DESC LIMIT 1;
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
$$
|
$$
|
||||||
language sql;
|
language sql;
|
||||||
-- +goose StatementEnd
|
-- +goose StatementEnd
|
||||||
|
111
schema.sql
111
schema.sql
@ -265,10 +265,10 @@ CREATE FUNCTION public.was_state_leaf_removed(key character varying, hash charac
|
|||||||
FROM eth.state_cids
|
FROM eth.state_cids
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
WHERE state_leaf_key = key
|
WHERE state_leaf_key = key
|
||||||
AND block_number <= (SELECT block_number
|
AND state_cids.block_number <= (SELECT block_number
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE block_hash = hash)
|
WHERE block_hash = hash)
|
||||||
ORDER BY block_number DESC LIMIT 1;
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
@ -277,6 +277,7 @@ $$;
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.access_list_elements (
|
CREATE TABLE eth.access_list_elements (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
tx_id character varying(66) NOT NULL,
|
tx_id character varying(66) NOT NULL,
|
||||||
index integer NOT NULL,
|
index integer NOT NULL,
|
||||||
address character varying(66),
|
address character varying(66),
|
||||||
@ -289,6 +290,7 @@ CREATE TABLE eth.access_list_elements (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.log_cids (
|
CREATE TABLE eth.log_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
leaf_cid text NOT NULL,
|
leaf_cid text NOT NULL,
|
||||||
leaf_mh_key text NOT NULL,
|
leaf_mh_key text NOT NULL,
|
||||||
rct_id character varying(66) NOT NULL,
|
rct_id character varying(66) NOT NULL,
|
||||||
@ -307,6 +309,7 @@ CREATE TABLE eth.log_cids (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.receipt_cids (
|
CREATE TABLE eth.receipt_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
tx_id character varying(66) NOT NULL,
|
tx_id character varying(66) NOT NULL,
|
||||||
leaf_cid text NOT NULL,
|
leaf_cid text NOT NULL,
|
||||||
contract character varying(66),
|
contract character varying(66),
|
||||||
@ -323,6 +326,7 @@ CREATE TABLE eth.receipt_cids (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.state_accounts (
|
CREATE TABLE eth.state_accounts (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
header_id character varying(66) NOT NULL,
|
header_id character varying(66) NOT NULL,
|
||||||
state_path bytea NOT NULL,
|
state_path bytea NOT NULL,
|
||||||
balance numeric NOT NULL,
|
balance numeric NOT NULL,
|
||||||
@ -337,6 +341,7 @@ CREATE TABLE eth.state_accounts (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.state_cids (
|
CREATE TABLE eth.state_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
header_id character varying(66) NOT NULL,
|
header_id character varying(66) NOT NULL,
|
||||||
state_leaf_key character varying(66),
|
state_leaf_key character varying(66),
|
||||||
cid text NOT NULL,
|
cid text NOT NULL,
|
||||||
@ -352,6 +357,7 @@ CREATE TABLE eth.state_cids (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.storage_cids (
|
CREATE TABLE eth.storage_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
header_id character varying(66) NOT NULL,
|
header_id character varying(66) NOT NULL,
|
||||||
state_path bytea NOT NULL,
|
state_path bytea NOT NULL,
|
||||||
storage_leaf_key character varying(66),
|
storage_leaf_key character varying(66),
|
||||||
@ -368,6 +374,7 @@ CREATE TABLE eth.storage_cids (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.transaction_cids (
|
CREATE TABLE eth.transaction_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
header_id character varying(66) NOT NULL,
|
header_id character varying(66) NOT NULL,
|
||||||
tx_hash character varying(66) NOT NULL,
|
tx_hash character varying(66) NOT NULL,
|
||||||
cid text NOT NULL,
|
cid text NOT NULL,
|
||||||
@ -393,6 +400,7 @@ COMMENT ON TABLE eth.transaction_cids IS '@name EthTransactionCids';
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.uncle_cids (
|
CREATE TABLE eth.uncle_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
block_hash character varying(66) NOT NULL,
|
block_hash character varying(66) NOT NULL,
|
||||||
header_id character varying(66) NOT NULL,
|
header_id character varying(66) NOT NULL,
|
||||||
parent_hash character varying(66) NOT NULL,
|
parent_hash character varying(66) NOT NULL,
|
||||||
@ -407,6 +415,7 @@ CREATE TABLE eth.uncle_cids (
|
|||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE public.blocks (
|
CREATE TABLE public.blocks (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
key text NOT NULL,
|
key text NOT NULL,
|
||||||
data bytea NOT NULL
|
data bytea NOT NULL
|
||||||
);
|
);
|
||||||
@ -562,12 +571,20 @@ ALTER TABLE ONLY eth.uncle_cids
|
|||||||
ADD CONSTRAINT uncle_cids_pkey PRIMARY KEY (block_hash);
|
ADD CONSTRAINT uncle_cids_pkey PRIMARY KEY (block_hash);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: blocks blocks_key_key; Type: CONSTRAINT; Schema: public; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
ALTER TABLE ONLY public.blocks
|
||||||
|
ADD CONSTRAINT blocks_key_key UNIQUE (key);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: blocks blocks_pkey; Type: CONSTRAINT; Schema: public; Owner: -
|
-- Name: blocks blocks_pkey; Type: CONSTRAINT; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY public.blocks
|
ALTER TABLE ONLY public.blocks
|
||||||
ADD CONSTRAINT blocks_pkey PRIMARY KEY (key);
|
ADD CONSTRAINT blocks_pkey PRIMARY KEY (key, block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -594,6 +611,13 @@ ALTER TABLE ONLY public.nodes
|
|||||||
ADD CONSTRAINT nodes_pkey PRIMARY KEY (node_id);
|
ADD CONSTRAINT nodes_pkey PRIMARY KEY (node_id);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: access_list_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: access_list_element_address_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: access_list_element_address_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -608,6 +632,13 @@ CREATE INDEX access_list_element_address_index ON eth.access_list_elements USING
|
|||||||
CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys);
|
CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: account_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: account_state_path_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: account_state_path_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -616,10 +647,10 @@ CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_p
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: block_number_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: header_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
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);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -643,6 +674,13 @@ CREATE UNIQUE INDEX header_mh_index ON eth.header_cids USING btree (mh_key);
|
|||||||
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
|
CREATE INDEX log_address_index ON eth.log_cids USING btree (address);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: log_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: log_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: log_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -685,6 +723,13 @@ CREATE INDEX log_topic2_index ON eth.log_cids USING btree (topic2);
|
|||||||
CREATE INDEX log_topic3_index ON eth.log_cids USING btree (topic3);
|
CREATE INDEX log_topic3_index ON eth.log_cids USING btree (topic3);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: rct_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: rct_contract_hash_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: rct_contract_hash_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -713,6 +758,13 @@ 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_leaf_mh_index ON eth.receipt_cids USING btree (leaf_mh_key);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: state_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: state_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: state_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -755,6 +807,13 @@ CREATE INDEX state_path_index ON eth.state_cids USING btree (state_path);
|
|||||||
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
|
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: storage_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: storage_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: storage_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -811,6 +870,13 @@ CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_pat
|
|||||||
CREATE INDEX timestamp_index ON eth.header_cids USING brin ("timestamp");
|
CREATE INDEX timestamp_index ON eth.header_cids USING brin ("timestamp");
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: tx_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: tx_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: tx_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -846,6 +912,13 @@ CREATE UNIQUE INDEX tx_mh_index ON eth.transaction_cids USING btree (mh_key);
|
|||||||
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
|
CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: uncle_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: uncle_header_id_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: uncle_header_id_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -925,11 +998,11 @@ ALTER TABLE ONLY eth.access_list_elements
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: header_cids header_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: header_cids header_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.header_cids
|
ALTER TABLE ONLY eth.header_cids
|
||||||
ADD CONSTRAINT header_cids_mh_key_fkey FOREIGN KEY (mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT header_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -941,11 +1014,11 @@ ALTER TABLE ONLY eth.header_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: log_cids log_cids_leaf_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: log_cids log_cids_leaf_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.log_cids
|
ALTER TABLE ONLY eth.log_cids
|
||||||
ADD CONSTRAINT log_cids_leaf_mh_key_fkey FOREIGN KEY (leaf_mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT log_cids_leaf_mh_key_block_number_fkey FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -957,11 +1030,11 @@ ALTER TABLE ONLY eth.log_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: receipt_cids receipt_cids_leaf_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: receipt_cids receipt_cids_leaf_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.receipt_cids
|
ALTER TABLE ONLY eth.receipt_cids
|
||||||
ADD CONSTRAINT receipt_cids_leaf_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_block_number_fkey FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -989,11 +1062,11 @@ ALTER TABLE ONLY eth.state_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: state_cids state_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: state_cids state_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.state_cids
|
ALTER TABLE ONLY eth.state_cids
|
||||||
ADD CONSTRAINT state_cids_mh_key_fkey FOREIGN KEY (mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT state_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -1005,11 +1078,11 @@ ALTER TABLE ONLY eth.storage_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: storage_cids storage_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: storage_cids storage_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.storage_cids
|
ALTER TABLE ONLY eth.storage_cids
|
||||||
ADD CONSTRAINT storage_cids_mh_key_fkey FOREIGN KEY (mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT storage_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -1021,11 +1094,11 @@ ALTER TABLE ONLY eth.transaction_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: transaction_cids transaction_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: transaction_cids transaction_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.transaction_cids
|
ALTER TABLE ONLY eth.transaction_cids
|
||||||
ADD CONSTRAINT transaction_cids_mh_key_fkey FOREIGN KEY (mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT transaction_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -1037,11 +1110,11 @@ ALTER TABLE ONLY eth.uncle_cids
|
|||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: uncle_cids uncle_cids_mh_key_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
-- Name: uncle_cids uncle_cids_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.uncle_cids
|
ALTER TABLE ONLY eth.uncle_cids
|
||||||
ADD CONSTRAINT uncle_cids_mh_key_fkey FOREIGN KEY (mh_key) REFERENCES public.blocks(key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
ADD CONSTRAINT uncle_cids_mh_key_block_number_fkey FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks(key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
|
Loading…
Reference in New Issue
Block a user