Merge pull request #2 from vulcanize/migrations_and_schema
db schema and migrations
This commit is contained in:
commit
525e342bf2
8
migrations/00001_create_ipfs_blocks_table.sql
Normal file
8
migrations/00001_create_ipfs_blocks_table.sql
Normal file
@ -0,0 +1,8 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE IF NOT EXISTS public.blocks (
|
||||||
|
key TEXT UNIQUE NOT NULL,
|
||||||
|
data BYTEA NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE public.blocks;
|
13
migrations/00002_create_nodes_table.sql
Normal file
13
migrations/00002_create_nodes_table.sql
Normal file
@ -0,0 +1,13 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE nodes (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
client_name VARCHAR,
|
||||||
|
genesis_block VARCHAR(66),
|
||||||
|
network_id VARCHAR,
|
||||||
|
node_id VARCHAR(128),
|
||||||
|
chain_id INTEGER DEFAULT 1,
|
||||||
|
CONSTRAINT node_uc UNIQUE (genesis_block, network_id, node_id, chain_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE nodes;
|
5
migrations/00003_create_eth_schema.sql
Normal file
5
migrations/00003_create_eth_schema.sql
Normal file
@ -0,0 +1,5 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE SCHEMA eth;
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP SCHEMA eth;
|
23
migrations/00004_create_eth_header_cids_table.sql
Normal file
23
migrations/00004_create_eth_header_cids_table.sql
Normal file
@ -0,0 +1,23 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.header_cids (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
block_number BIGINT NOT NULL,
|
||||||
|
block_hash VARCHAR(66) NOT NULL,
|
||||||
|
parent_hash VARCHAR(66) NOT NULL,
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
td NUMERIC NOT NULL,
|
||||||
|
node_id INTEGER NOT NULL REFERENCES nodes (id) ON DELETE CASCADE,
|
||||||
|
reward NUMERIC NOT NULL,
|
||||||
|
state_root VARCHAR(66) NOT NULL,
|
||||||
|
tx_root VARCHAR(66) NOT NULL,
|
||||||
|
receipt_root VARCHAR(66) NOT NULL,
|
||||||
|
uncle_root VARCHAR(66) NOT NULL,
|
||||||
|
bloom BYTEA NOT NULL,
|
||||||
|
timestamp NUMERIC NOT NULL,
|
||||||
|
times_validated INTEGER NOT NULL DEFAULT 1,
|
||||||
|
UNIQUE (block_number, block_hash)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.header_cids;
|
14
migrations/00005_create_eth_uncle_cids_table.sql
Normal file
14
migrations/00005_create_eth_uncle_cids_table.sql
Normal file
@ -0,0 +1,14 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.uncle_cids (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
header_id INTEGER NOT NULL REFERENCES eth.header_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
block_hash VARCHAR(66) NOT NULL,
|
||||||
|
parent_hash VARCHAR(66) NOT NULL,
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
reward NUMERIC NOT NULL,
|
||||||
|
UNIQUE (header_id, block_hash)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.uncle_cids;
|
16
migrations/00006_create_eth_transaction_cids_table.sql
Normal file
16
migrations/00006_create_eth_transaction_cids_table.sql
Normal file
@ -0,0 +1,16 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.transaction_cids (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
header_id INTEGER NOT NULL REFERENCES eth.header_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
tx_hash VARCHAR(66) NOT NULL,
|
||||||
|
index INTEGER NOT NULL,
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
dst VARCHAR(66) NOT NULL,
|
||||||
|
src VARCHAR(66) NOT NULL,
|
||||||
|
tx_data BYTEA,
|
||||||
|
UNIQUE (header_id, tx_hash)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.transaction_cids;
|
20
migrations/00007_create_eth_receipt_cids_table.sql
Normal file
20
migrations/00007_create_eth_receipt_cids_table.sql
Normal file
@ -0,0 +1,20 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.receipt_cids (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
tx_id INTEGER NOT NULL REFERENCES eth.transaction_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
contract VARCHAR(66),
|
||||||
|
contract_hash VARCHAR(66),
|
||||||
|
topic0s VARCHAR(66)[],
|
||||||
|
topic1s VARCHAR(66)[],
|
||||||
|
topic2s VARCHAR(66)[],
|
||||||
|
topic3s VARCHAR(66)[],
|
||||||
|
log_contracts VARCHAR(66)[],
|
||||||
|
post_state VARCHAR(66),
|
||||||
|
post_status INTEGER,
|
||||||
|
UNIQUE (tx_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.receipt_cids;
|
15
migrations/00008_create_eth_state_cids_table.sql
Normal file
15
migrations/00008_create_eth_state_cids_table.sql
Normal file
@ -0,0 +1,15 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.state_cids (
|
||||||
|
id BIGSERIAL PRIMARY KEY,
|
||||||
|
header_id INTEGER NOT NULL REFERENCES eth.header_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
state_leaf_key VARCHAR(66),
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
state_path BYTEA,
|
||||||
|
node_type INTEGER NOT NULL,
|
||||||
|
diff BOOLEAN NOT NULL DEFAULT FALSE,
|
||||||
|
UNIQUE (header_id, state_path)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.state_cids;
|
15
migrations/00009_create_eth_storage_cids_table.sql
Normal file
15
migrations/00009_create_eth_storage_cids_table.sql
Normal file
@ -0,0 +1,15 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.storage_cids (
|
||||||
|
id BIGSERIAL PRIMARY KEY,
|
||||||
|
state_id BIGINT NOT NULL REFERENCES eth.state_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
storage_leaf_key VARCHAR(66),
|
||||||
|
cid TEXT NOT NULL,
|
||||||
|
mh_key TEXT NOT NULL REFERENCES public.blocks (key) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
storage_path BYTEA,
|
||||||
|
node_type INTEGER NOT NULL,
|
||||||
|
diff BOOLEAN NOT NULL DEFAULT FALSE,
|
||||||
|
UNIQUE (state_id, storage_path)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.storage_cids;
|
13
migrations/00010_create_eth_state_accouts_table.sql
Normal file
13
migrations/00010_create_eth_state_accouts_table.sql
Normal file
@ -0,0 +1,13 @@
|
|||||||
|
-- +goose Up
|
||||||
|
CREATE TABLE eth.state_accounts (
|
||||||
|
id SERIAL PRIMARY KEY,
|
||||||
|
state_id BIGINT NOT NULL REFERENCES eth.state_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
|
||||||
|
balance NUMERIC NOT NULL,
|
||||||
|
nonce INTEGER NOT NULL,
|
||||||
|
code_hash BYTEA NOT NULL,
|
||||||
|
storage_root VARCHAR(66) NOT NULL,
|
||||||
|
UNIQUE (state_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TABLE eth.state_accounts;
|
6
migrations/00011_create_postgraphile_comments.sql
Normal file
6
migrations/00011_create_postgraphile_comments.sql
Normal file
@ -0,0 +1,6 @@
|
|||||||
|
-- +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_id IS E'@name EthNodeID';
|
69
migrations/00012_potgraphile_triggers.sql
Normal file
69
migrations/00012_potgraphile_triggers.sql
Normal file
@ -0,0 +1,69 @@
|
|||||||
|
-- +goose Up
|
||||||
|
-- +goose StatementBegin
|
||||||
|
CREATE FUNCTION eth.graphql_subscription() returns TRIGGER as $$
|
||||||
|
declare
|
||||||
|
table_name text = TG_ARGV[0];
|
||||||
|
attribute text = TG_ARGV[1];
|
||||||
|
id text;
|
||||||
|
begin
|
||||||
|
execute 'select $1.' || quote_ident(attribute)
|
||||||
|
using new
|
||||||
|
into id;
|
||||||
|
perform pg_notify('postgraphile:' || table_name,
|
||||||
|
json_build_object(
|
||||||
|
'__node__', json_build_array(
|
||||||
|
table_name,
|
||||||
|
id
|
||||||
|
)
|
||||||
|
)::text
|
||||||
|
);
|
||||||
|
return new;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql;
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
CREATE TRIGGER header_cids_ai
|
||||||
|
after INSERT ON eth.header_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('header_cids', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER receipt_cids_ai
|
||||||
|
after INSERT ON eth.receipt_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('receipt_cids', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER state_accounts_ai
|
||||||
|
after INSERT ON eth.state_accounts
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('state_accounts', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER state_cids_ai
|
||||||
|
after INSERT ON eth.state_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('state_cids', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER storage_cids_ai
|
||||||
|
after INSERT ON eth.storage_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('storage_cids', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER transaction_cids_ai
|
||||||
|
after INSERT ON eth.transaction_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('transaction_cids', 'id');
|
||||||
|
|
||||||
|
CREATE TRIGGER uncle_cids_ai
|
||||||
|
after INSERT ON eth.uncle_cids
|
||||||
|
for each row
|
||||||
|
execute procedure eth.graphql_subscription('uncle_cids', 'id');
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP TRIGGER uncle_cids_ai ON eth.uncle_cids;
|
||||||
|
DROP TRIGGER transaction_cids_ai ON eth.transaction_cids;
|
||||||
|
DROP TRIGGER storage_cids_ai ON eth.storage_cids;
|
||||||
|
DROP TRIGGER state_cids_ai ON eth.state_cids;
|
||||||
|
DROP TRIGGER state_accounts_ai ON eth.state_accounts;
|
||||||
|
DROP TRIGGER receipt_cids_ai ON eth.receipt_cids;
|
||||||
|
DROP TRIGGER header_cids_ai ON eth.header_cids;
|
||||||
|
|
||||||
|
DROP FUNCTION eth.graphql_subscription();
|
121
migrations/00013_create_cid_indexes.sql
Normal file
121
migrations/00013_create_cid_indexes.sql
Normal file
@ -0,0 +1,121 @@
|
|||||||
|
-- +goose Up
|
||||||
|
-- header indexes
|
||||||
|
CREATE INDEX block_number_index ON eth.header_cids USING brin (block_number);
|
||||||
|
|
||||||
|
CREATE INDEX block_hash_index ON eth.header_cids USING btree (block_hash);
|
||||||
|
|
||||||
|
CREATE INDEX header_cid_index ON eth.header_cids USING btree (cid);
|
||||||
|
|
||||||
|
CREATE 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);
|
||||||
|
|
||||||
|
-- transaction indexes
|
||||||
|
CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
|
||||||
|
|
||||||
|
CREATE INDEX tx_hash_index ON eth.transaction_cids USING btree (tx_hash);
|
||||||
|
|
||||||
|
CREATE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid);
|
||||||
|
|
||||||
|
CREATE 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_tx_id_index ON eth.receipt_cids USING btree (tx_id);
|
||||||
|
|
||||||
|
CREATE INDEX rct_cid_index ON eth.receipt_cids USING btree (cid);
|
||||||
|
|
||||||
|
CREATE INDEX rct_mh_index ON eth.receipt_cids USING btree (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);
|
||||||
|
|
||||||
|
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);
|
||||||
|
|
||||||
|
-- state node indexes
|
||||||
|
CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id);
|
||||||
|
|
||||||
|
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);
|
||||||
|
|
||||||
|
-- storage node indexes
|
||||||
|
CREATE INDEX storage_state_id_index ON eth.storage_cids USING btree (state_id);
|
||||||
|
|
||||||
|
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_mh_index ON eth.storage_cids USING btree (mh_key);
|
||||||
|
|
||||||
|
CREATE INDEX storage_path_index ON eth.storage_cids USING btree (storage_path);
|
||||||
|
|
||||||
|
-- state accounts indexes
|
||||||
|
CREATE INDEX account_state_id_index ON eth.state_accounts USING btree (state_id);
|
||||||
|
|
||||||
|
CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root);
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
-- state account indexes
|
||||||
|
DROP INDEX eth.storage_root_index;
|
||||||
|
DROP INDEX eth.account_state_id_index;
|
||||||
|
|
||||||
|
-- storage node indexes
|
||||||
|
DROP INDEX eth.storage_path_index;
|
||||||
|
DROP INDEX eth.storage_mh_index;
|
||||||
|
DROP INDEX eth.storage_cid_index;
|
||||||
|
DROP INDEX eth.storage_leaf_key_index;
|
||||||
|
DROP INDEX eth.storage_state_id_index;
|
||||||
|
|
||||||
|
-- state node indexes
|
||||||
|
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_header_id_index;
|
||||||
|
|
||||||
|
-- receipt indexes
|
||||||
|
DROP INDEX eth.rct_log_contract_index;
|
||||||
|
DROP INDEX eth.rct_topic3_index;
|
||||||
|
DROP INDEX eth.rct_topic2_index;
|
||||||
|
DROP INDEX eth.rct_topic1_index;
|
||||||
|
DROP INDEX eth.rct_topic0_index;
|
||||||
|
DROP INDEX eth.rct_contract_hash_index;
|
||||||
|
DROP INDEX eth.rct_contract_index;
|
||||||
|
DROP INDEX eth.rct_mh_index;
|
||||||
|
DROP INDEX eth.rct_cid_index;
|
||||||
|
DROP INDEX eth.rct_tx_id_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_hash_index;
|
||||||
|
DROP INDEX eth.tx_header_id_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_hash_index;
|
||||||
|
DROP INDEX eth.block_number_index;
|
158
migrations/00014_create_stored_functions.sql
Normal file
158
migrations/00014_create_stored_functions.sql
Normal file
@ -0,0 +1,158 @@
|
|||||||
|
-- +goose Up
|
||||||
|
-- +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 TYPE child_result AS (
|
||||||
|
has_child BOOLEAN,
|
||||||
|
children eth.header_cids[]
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS
|
||||||
|
$BODY$
|
||||||
|
DECLARE
|
||||||
|
child_height INT;
|
||||||
|
temp_child eth.header_cids;
|
||||||
|
new_child_result child_result;
|
||||||
|
BEGIN
|
||||||
|
child_height = height + 1;
|
||||||
|
-- short circuit if there are no children
|
||||||
|
SELECT exists(SELECT 1
|
||||||
|
FROM eth.header_cids
|
||||||
|
WHERE parent_hash = hash
|
||||||
|
AND block_number = child_height
|
||||||
|
LIMIT 1)
|
||||||
|
INTO new_child_result.has_child;
|
||||||
|
-- collect all the children for this header
|
||||||
|
IF new_child_result.has_child THEN
|
||||||
|
FOR temp_child IN
|
||||||
|
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
|
||||||
|
LOOP
|
||||||
|
new_child_result.children = array_append(new_child_result.children, temp_child);
|
||||||
|
END LOOP;
|
||||||
|
END IF;
|
||||||
|
RETURN new_child_result;
|
||||||
|
END
|
||||||
|
$BODY$
|
||||||
|
LANGUAGE 'plpgsql';
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose StatementBegin
|
||||||
|
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS
|
||||||
|
$BODY$
|
||||||
|
DECLARE
|
||||||
|
canonical_header eth.header_cids;
|
||||||
|
canonical_child eth.header_cids;
|
||||||
|
header eth.header_cids;
|
||||||
|
current_child_result child_result;
|
||||||
|
child_headers eth.header_cids[];
|
||||||
|
current_header_with_child eth.header_cids;
|
||||||
|
has_children_count INT DEFAULT 0;
|
||||||
|
BEGIN
|
||||||
|
-- for each header in the provided set
|
||||||
|
FOREACH header IN ARRAY headers
|
||||||
|
LOOP
|
||||||
|
-- check if it has any children
|
||||||
|
current_child_result = has_child(header.block_hash, header.block_number);
|
||||||
|
IF current_child_result.has_child THEN
|
||||||
|
-- if it does, take note
|
||||||
|
has_children_count = has_children_count + 1;
|
||||||
|
current_header_with_child = header;
|
||||||
|
-- and add the children to the growing set of child headers
|
||||||
|
child_headers = array_cat(child_headers, current_child_result.children);
|
||||||
|
END IF;
|
||||||
|
END LOOP;
|
||||||
|
-- if none of the headers had children, none is more canonical than the other
|
||||||
|
IF has_children_count = 0 THEN
|
||||||
|
-- return the first one selected
|
||||||
|
SELECT * INTO canonical_header FROM unnest(headers) LIMIT 1;
|
||||||
|
-- if only one header had children, it can be considered the heaviest/canonical header of the set
|
||||||
|
ELSIF has_children_count = 1 THEN
|
||||||
|
-- return the only header with a child
|
||||||
|
canonical_header = current_header_with_child;
|
||||||
|
-- if there are multiple headers with children
|
||||||
|
ELSE
|
||||||
|
-- find the canonical header from the child set
|
||||||
|
canonical_child = canonical_header_from_array(child_headers);
|
||||||
|
-- the header that is parent to this header, is the canonical header at this level
|
||||||
|
SELECT * INTO canonical_header FROM unnest(headers)
|
||||||
|
WHERE block_hash = canonical_child.parent_hash;
|
||||||
|
END IF;
|
||||||
|
RETURN canonical_header;
|
||||||
|
END
|
||||||
|
$BODY$
|
||||||
|
LANGUAGE 'plpgsql';
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose StatementBegin
|
||||||
|
CREATE OR REPLACE FUNCTION canonical_header_id(height BIGINT) RETURNS INTEGER AS
|
||||||
|
$BODY$
|
||||||
|
DECLARE
|
||||||
|
canonical_header eth.header_cids;
|
||||||
|
headers eth.header_cids[];
|
||||||
|
header_count INT;
|
||||||
|
temp_header eth.header_cids;
|
||||||
|
BEGIN
|
||||||
|
-- collect all headers at this height
|
||||||
|
FOR temp_header IN
|
||||||
|
SELECT * FROM eth.header_cids WHERE block_number = height
|
||||||
|
LOOP
|
||||||
|
headers = array_append(headers, temp_header);
|
||||||
|
END LOOP;
|
||||||
|
-- count the number of headers collected
|
||||||
|
header_count = array_length(headers, 1);
|
||||||
|
-- if we have less than 1 header, return NULL
|
||||||
|
IF header_count IS NULL OR header_count < 1 THEN
|
||||||
|
RETURN NULL;
|
||||||
|
-- if we have one header, return its id
|
||||||
|
ELSIF header_count = 1 THEN
|
||||||
|
RETURN headers[1].id;
|
||||||
|
-- if we have multiple headers we need to determine which one is canonical
|
||||||
|
ELSE
|
||||||
|
canonical_header = canonical_header_from_array(headers);
|
||||||
|
RETURN canonical_header.id;
|
||||||
|
END IF;
|
||||||
|
END;
|
||||||
|
$BODY$
|
||||||
|
LANGUAGE 'plpgsql';
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP FUNCTION was_storage_removed;
|
||||||
|
DROP FUNCTION was_state_removed;
|
||||||
|
DROP FUNCTION canonical_header_id;
|
||||||
|
DROP FUNCTION canonical_header_from_array;
|
||||||
|
DROP FUNCTION has_child;
|
||||||
|
DROP TYPE child_result;
|
1333
schema.sql
Normal file
1333
schema.sql
Normal file
File diff suppressed because it is too large
Load Diff
Loading…
Reference in New Issue
Block a user