consolidate migrations

This commit is contained in:
Ian Norden 2021-03-12 09:50:48 -06:00
parent d3f30b621b
commit 86f3f44cac
16 changed files with 131 additions and 296 deletions

View File

@ -5,7 +5,8 @@ CREATE TABLE nodes (
genesis_block VARCHAR(66),
network_id VARCHAR,
node_id VARCHAR(128),
CONSTRAINT node_uc UNIQUE (genesis_block, network_id, node_id)
chain_id INTEGER DEFAULT 1,
CONSTRAINT node_uc UNIQUE (genesis_block, network_id, node_id, chain_id)
);
-- +goose Down

View File

@ -8,7 +8,6 @@ CREATE TABLE eth.transaction_cids (
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,
deployment BOOL NOT NULL,
tx_data BYTEA,
UNIQUE (header_id, tx_hash)
);

View File

@ -11,6 +11,8 @@ CREATE TABLE eth.receipt_cids (
topic2s VARCHAR(66)[],
topic3s VARCHAR(66)[],
log_contracts VARCHAR(66)[],
post_state VARCHAR(66),
post_status INTEGER,
UNIQUE (tx_id)
);

View File

@ -1,6 +1,6 @@
-- +goose Up
CREATE TABLE eth.state_cids (
id SERIAL PRIMARY KEY,
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,

View File

@ -1,7 +1,7 @@
-- +goose Up
CREATE TABLE eth.storage_cids (
id SERIAL PRIMARY KEY,
state_id INTEGER NOT NULL REFERENCES eth.state_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
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,

View File

@ -1,7 +1,7 @@
-- +goose Up
CREATE TABLE eth.state_accounts (
id SERIAL PRIMARY KEY,
state_id INTEGER NOT NULL REFERENCES eth.state_cids (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
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,

View File

@ -1,21 +0,0 @@
-- +goose Up
ALTER TABLE public.nodes
ADD COLUMN chain_id INTEGER DEFAULT 1;
ALTER TABLE public.nodes
DROP CONSTRAINT node_uc;
ALTER TABLE public.nodes
ADD CONSTRAINT node_uc
UNIQUE (genesis_block, network_id, node_id, chain_id);
-- +goose Down
ALTER TABLE public.nodes
DROP CONSTRAINT node_uc;
ALTER TABLE public.nodes
ADD CONSTRAINT node_uc
UNIQUE (genesis_block, network_id, node_id);
ALTER TABLE public.nodes
DROP COLUMN chain_id;

View File

@ -1,4 +1,39 @@
-- +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,
@ -115,6 +150,8 @@ 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;

View File

@ -1,48 +0,0 @@
-- +goose Up
-- +goose StatementBegin
-- returns the number of child headers that reference backwards to the header with the provided hash
CREATE OR REPLACE FUNCTION header_weight(hash VARCHAR(66)) RETURNS BIGINT
AS $$
WITH RECURSIVE validator AS (
SELECT block_hash, parent_hash, block_number
FROM eth.header_cids
WHERE block_hash = hash
UNION
SELECT eth.header_cids.block_hash, eth.header_cids.parent_hash, eth.header_cids.block_number
FROM eth.header_cids
INNER JOIN validator
ON eth.header_cids.parent_hash = validator.block_hash
AND eth.header_cids.block_number = validator.block_number + 1
)
SELECT COUNT(*) FROM validator;
$$ LANGUAGE SQL;
-- +goose StatementEnd
-- +goose StatementBegin
-- returns the id for the header at the provided height which is heaviest
CREATE OR REPLACE FUNCTION canonical_header(height BIGINT) RETURNS INT AS
$BODY$
DECLARE
current_weight INT;
heaviest_weight INT DEFAULT 0;
heaviest_id INT;
r eth.header_cids%ROWTYPE;
BEGIN
FOR r IN SELECT * FROM eth.header_cids
WHERE block_number = height
LOOP
SELECT INTO current_weight * FROM header_weight(r.block_hash);
IF current_weight > heaviest_weight THEN
heaviest_weight := current_weight;
heaviest_id := r.id;
END IF;
END LOOP;
RETURN heaviest_id;
END
$BODY$
LANGUAGE 'plpgsql';
-- +goose StatementEnd
-- +goose Down
DROP FUNCTION header_weight;
DROP FUNCTION canonical_header;

View File

@ -1,7 +0,0 @@
-- +goose Up
ALTER TABLE eth.transaction_cids
DROP COLUMN deployment;
-- +goose Down
ALTER TABLE eth.transaction_cids
ADD COLUMN deployment BOOL NOT NULL DEFAULT FALSE;

View File

@ -1,25 +0,0 @@
-- +goose Up
ALTER TABLE eth.storage_cids
ALTER COLUMN state_id TYPE BIGINT;
ALTER TABLE eth.state_accounts
ALTER COLUMN state_id TYPE BIGINT;
ALTER TABLE eth.state_cids
ALTER COLUMN id TYPE BIGINT;
ALTER TABLE eth.storage_cids
ALTER COLUMN id TYPE BIGINT;
-- +goose Down
ALTER TABLE eth.storage_cids
ALTER COLUMN id TYPE INTEGER;
ALTER TABLE eth.state_cids
ALTER COLUMN id TYPE INTEGER;
ALTER TABLE eth.state_accounts
ALTER COLUMN state_id TYPE INTEGER;
ALTER TABLE eth.storage_cids
ALTER COLUMN state_id TYPE INTEGER;

View File

@ -1,39 +0,0 @@
-- +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 Down
DROP FUNCTION was_storage_removed;
DROP FUNCTION was_state_removed;

View File

@ -1,13 +0,0 @@
-- +goose Up
ALTER TABLE eth.receipt_cids
ADD COLUMN post_state VARCHAR(66);
ALTER TABLE eth.receipt_cids
ADD COLUMN post_status INTEGER;
-- +goose Down
ALTER TABLE eth.receipt_cids
DROP COLUMN post_status;
ALTER TABLE eth.receipt_cids
DROP COLUMN post_state;

View File

@ -103,33 +103,6 @@ end;
$_$;
--
-- Name: canonical_header(bigint); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.canonical_header(height bigint) RETURNS integer
LANGUAGE plpgsql
AS $$
DECLARE
current_weight INT;
heaviest_weight INT DEFAULT 0;
heaviest_id INT;
r eth.header_cids%ROWTYPE;
BEGIN
FOR r IN SELECT * FROM eth.header_cids
WHERE block_number = height
LOOP
SELECT INTO current_weight * FROM header_weight(r.block_hash);
IF current_weight > heaviest_weight THEN
heaviest_weight := current_weight;
heaviest_id := r.id;
END IF;
END LOOP;
RETURN heaviest_id;
END
$$;
--
-- Name: canonical_header_from_array(eth.header_cids[]); Type: FUNCTION; Schema: public; Owner: -
--
@ -249,28 +222,6 @@ END
$$;
--
-- Name: header_weight(character varying); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.header_weight(hash character varying) RETURNS bigint
LANGUAGE sql
AS $$
WITH RECURSIVE validator AS (
SELECT block_hash, parent_hash, block_number
FROM eth.header_cids
WHERE block_hash = hash
UNION
SELECT eth.header_cids.block_hash, eth.header_cids.parent_hash, eth.header_cids.block_number
FROM eth.header_cids
INNER JOIN validator
ON eth.header_cids.parent_hash = validator.block_hash
AND eth.header_cids.block_number = validator.block_number + 1
)
SELECT COUNT(*) FROM validator;
$$;
--
-- Name: was_state_removed(bytea, bigint, character varying); Type: FUNCTION; Schema: public; Owner: -
--
@ -428,7 +379,6 @@ CREATE TABLE eth.state_cids (
--
CREATE SEQUENCE eth.state_cids_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
@ -464,7 +414,6 @@ CREATE TABLE eth.storage_cids (
--
CREATE SEQUENCE eth.storage_cids_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE