Merge pull request #67 from vulcanize/release-v4.0.0-alpha

Fixes + new schema dump
This commit is contained in:
Ian Norden 2022-04-18 09:34:45 -05:00 committed by GitHub
commit b8f713d518
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
14 changed files with 201 additions and 110 deletions

View File

@ -1,7 +1,7 @@
-- +goose Up
CREATE TABLE IF NOT EXISTS eth.header_cids (
block_number BIGINT NOT NULL,
block_hash VARCHAR(66) PRIMARY KEY,
block_hash VARCHAR(66) NOT NULL,
parent_hash VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
td NUMERIC NOT NULL,
@ -16,6 +16,7 @@ CREATE TABLE IF NOT EXISTS eth.header_cids (
mh_key TEXT NOT NULL,
times_validated INTEGER NOT NULL DEFAULT 1,
coinbase VARCHAR(66) NOT NULL,
PRIMARY KEY (block_hash, block_number),
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

View File

@ -1,12 +1,14 @@
-- +goose Up
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,
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,
mh_key TEXT NOT NULL,
PRIMARY KEY (block_hash, block_number),
FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

View File

@ -1,8 +1,8 @@
-- +goose Up
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,
header_id VARCHAR(66) NOT NULL,
tx_hash VARCHAR(66) NOT NULL,
cid TEXT NOT NULL,
dst VARCHAR(66) NOT NULL,
src VARCHAR(66) NOT NULL,
@ -11,6 +11,8 @@ CREATE TABLE IF NOT EXISTS eth.transaction_cids (
tx_data BYTEA,
tx_type INTEGER,
value NUMERIC,
PRIMARY KEY (tx_hash, block_number),
FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

View File

@ -1,7 +1,7 @@
-- +goose Up
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,
tx_id VARCHAR(66) NOT NULL,
leaf_cid TEXT NOT NULL,
contract VARCHAR(66),
contract_hash VARCHAR(66),
@ -9,6 +9,8 @@ CREATE TABLE IF NOT EXISTS eth.receipt_cids (
post_state VARCHAR(66),
post_status INTEGER,
log_root VARCHAR(66),
PRIMARY KEY (tx_id, block_number),
FOREIGN KEY (tx_id, block_number) REFERENCES eth.transaction_cids (tx_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);

View File

@ -1,15 +1,16 @@
-- +goose Up
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,
header_id VARCHAR(66) NOT NULL,
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,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (state_path, header_id)
PRIMARY KEY (state_path, header_id, block_number),
FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids (block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);
-- +goose Down

View File

@ -2,7 +2,7 @@
CREATE TABLE IF NOT EXISTS eth.storage_cids (
block_number BIGINT NOT NULL,
header_id VARCHAR(66) NOT NULL,
state_leaf_key BYTEA NOT NULL,
state_path BYTEA NOT NULL,
storage_leaf_key VARCHAR(66),
cid TEXT NOT NULL,
storage_path BYTEA NOT NULL,
@ -10,8 +10,8 @@ CREATE TABLE IF NOT EXISTS eth.storage_cids (
diff BOOLEAN NOT NULL DEFAULT FALSE,
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 (state_leaf_key, header_id) REFERENCES eth.state_cids (state_leaf_key, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (storage_path, state_leaf_key, header_id)
FOREIGN KEY (state_path, header_id, block_number) REFERENCES eth.state_cids (state_path, header_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (storage_path, state_path, header_id, block_number)
);
-- +goose Down

View File

@ -7,8 +7,8 @@ CREATE TABLE IF NOT EXISTS eth.state_accounts (
nonce BIGINT NOT NULL,
code_hash BYTEA NOT NULL,
storage_root VARCHAR(66) NOT NULL,
FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
PRIMARY KEY (state_path, header_id)
PRIMARY KEY (state_path, header_id, block_number),
FOREIGN KEY (state_path, header_id, block_number) REFERENCES eth.state_cids (state_path, header_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);
-- +goose Down

View File

@ -1,11 +1,12 @@
-- +goose Up
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,
tx_id VARCHAR(66) NOT NULL,
index INTEGER NOT NULL,
address VARCHAR(66),
storage_keys VARCHAR(66)[],
PRIMARY KEY (tx_id, index)
PRIMARY KEY (tx_id, index, block_number),
FOREIGN KEY (tx_id, block_number) REFERENCES eth.transaction_cids (tx_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);
-- +goose Down

View File

@ -3,7 +3,7 @@ CREATE TABLE IF NOT EXISTS eth.log_cids (
block_number BIGINT NOT NULL,
leaf_cid TEXT NOT NULL,
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,
address VARCHAR(66) NOT NULL,
index INTEGER NOT NULL,
topic0 VARCHAR(66),
@ -11,8 +11,9 @@ CREATE TABLE IF NOT EXISTS 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)
PRIMARY KEY (rct_id, index, block_number),
FOREIGN KEY (rct_id, block_number) REFERENCES eth.receipt_cids (tx_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED,
FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
);
-- +goose Down

View File

@ -1,7 +1,7 @@
-- +goose Up
-- header indexes
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, block_number);
CREATE UNIQUE INDEX header_mh_block_number_index ON eth.header_cids USING btree (mh_key, block_number);
CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root);
CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp);
@ -14,7 +14,7 @@ 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_cid_index ON eth.transaction_cids USING btree (cid, block_number);
CREATE UNIQUE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, 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);
@ -36,7 +36,7 @@ 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_leaf_key_index ON eth.storage_cids USING btree (state_leaf_key);
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);
CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number);
@ -90,7 +90,7 @@ DROP INDEX eth.storage_header_id_index;
DROP INDEX eth.storage_mh_block_number_index;
DROP INDEX eth.storage_cid_index;
DROP INDEX eth.storage_leaf_key_index;
DROP INDEX eth.storage_state_leaf_key_index;
DROP INDEX eth.storage_state_path_index;
DROP INDEX eth.storage_block_number_index;
-- state node indexes

View File

@ -154,8 +154,7 @@ BEGIN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the state nodes for this snapshot: the latest state node record at every unique path, that is not a
-- "removed" node-type entry
-- select all of the state nodes for this snapshot: the latest state node record at every unique path
SELECT DISTINCT ON (state_path) blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key
INTO results
@ -208,14 +207,15 @@ BEGIN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique state leaf key
SELECT DISTINCT ON (state_leaf_key, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
storage_cids.cid, storage_cids.storage_path, storage_cids.node_type, storage_cids.mh_key
INTO results
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
INNER JOIN eth.state_cids
ON (storage_cids.state_path, storage_cids.header_id) = (state_cids.state_path, state_cids.header_id)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
ORDER BY state_path, storage_path, block_number DESC;

View File

@ -1,6 +1,6 @@
-- +goose Up
SELECT create_hypertable('public.blocks', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.header_cids', 'block_number' migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.header_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.uncle_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.transaction_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
SELECT create_hypertable('eth.receipt_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768);
@ -32,15 +32,15 @@ CREATE TABLE public.blocks_i (LIKE public.blocks INCLUDING ALL);
-- migrate data
INSERT INTO eth.log_cids_i (SELECT * FROM eth.log_cids);
INSERT INTO eth.access_list_elements_i (SELECT eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT eth.header_cids);
INSERT INTO public.blocks_i (SELECT public.blocks);
INSERT INTO eth.access_list_elements_i (SELECT * FROM eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT * FROM eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT * FROM eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT * FROM eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT * FROM eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT * FROM eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT * FROM eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT * FROM eth.header_cids);
INSERT INTO public.blocks_i (SELECT * FROM public.blocks);
-- drops hypertables
DROP TABLE eth.log_cids;

View File

@ -12,28 +12,28 @@ CREATE TABLE eth.header_cids_i (LIKE eth.header_cids INCLUDING ALL);
CREATE TABLE public.blocks_i (LIKE public.blocks INCLUDING ALL);
-- turn them into distributed hypertables
SELECT create_distributed_hypertable('public.blocks_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.header_cids_i', 'block_number' migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.uncle_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.transaction_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.receipt_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.state_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.storage_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.state_accounts_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.access_list_elements_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.log_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('public.blocks_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.header_cids_i', 'block_number' chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.uncle_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.transaction_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.receipt_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.state_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.storage_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.state_accounts_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.access_list_elements_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
SELECT create_distributed_hypertable('eth.log_cids_i', 'block_number', chunk_time_interval => 32768, replication_factor => 3);
-- migrate data
INSERT INTO eth.log_cids_i (SELECT * FROM eth.log_cids);
INSERT INTO eth.access_list_elements_i (SELECT eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT eth.header_cids);
INSERT INTO public.blocks_i (SELECT public.blocks);
INSERT INTO eth.access_list_elements_i (SELECT * FROM eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT * FROM eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT * FROM eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT * FROM eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT * FROM eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT * FROM eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT * FROM eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT * FROM eth.header_cids);
INSERT INTO public.blocks_i (SELECT * FROM public.blocks);
-- drops hypertables
DROP TABLE eth.log_cids;
@ -93,15 +93,15 @@ SELECT create_hypertable('eth.log_cids_i', 'block_number', migrate_data => true,
-- migrate data
INSERT INTO eth.log_cids_i (SELECT * FROM eth.log_cids);
INSERT INTO eth.access_list_elements_i (SELECT eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT eth.header_cids);
INSERT INTO public.blocks_i (SELECT public.blocks);
INSERT INTO eth.access_list_elements_i (SELECT * FROM eth.access_list_elements);
INSERT INTO eth.state_accounts_i (SELECT * FROM eth.state_accounts);
INSERT INTO eth.storage_cids_i (SELECT * FROM eth.storage_cids);
INSERT INTO eth.state_cids_i (SELECT * FROM eth.state_cids);
INSERT INTO eth.receipt_cids_i (SELECT * FROM eth.receipt_cids);
INSERT INTO eth.transaction_cids_i (SELECT * FROM eth.transaction_cids);
INSERT INTO eth.uncle_cids_i (SELECT * FROM eth.uncle_cids);
INSERT INTO eth.header_cids_i (SELECT * FROM eth.header_cids);
INSERT INTO public.blocks_i (SELECT * FROM public.blocks);
-- drops distributed hypertables
DROP TABLE eth.log_cids;

View File

@ -2,8 +2,8 @@
-- PostgreSQL database dump
--
-- Dumped from database version 14beta3
-- Dumped by pg_dump version 14beta3
-- Dumped from database version 14.2
-- Dumped by pg_dump version 14.2
SET statement_timeout = 0;
SET lock_timeout = 0;
@ -16,6 +16,20 @@ SET xmloption = content;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: timescaledb; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS timescaledb WITH SCHEMA public;
--
-- Name: EXTENSION timescaledb; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION timescaledb IS 'Enables scalable inserts and complex queries for time-series data';
--
-- Name: eth; Type: SCHEMA; Schema: -; Owner: -
--
@ -299,8 +313,7 @@ BEGIN
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the state nodes for this snapshot: the latest state node record at every unique path, that is not a
-- "removed" node-type entry
-- select all of the state nodes for this snapshot: the latest state node record at every unique path
SELECT DISTINCT ON (state_path) blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path,
state_cids.node_type, state_cids.mh_key
INTO results
@ -308,7 +321,6 @@ BEGIN
INNER JOIN public.blocks
ON (state_cids.mh_key, state_cids.block_number) = (blocks.key, blocks.block_number)
WHERE state_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
@ -340,16 +352,16 @@ BEGIN
IF canonical_hash IS NULL THEN
RAISE EXCEPTION 'cannot create state snapshot, no header can be found at height %', ending_height;
END IF;
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique path, that is not a
-- "removed" node-type entry
SELECT DISTINCT ON (state_path, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
-- select all of the storage nodes for this snapshot: the latest storage node record at every unique state leaf key
SELECT DISTINCT ON (state_leaf_key, storage_path) block.data, storage_cids.state_path, storage_cids.storage_leaf_key,
storage_cids.cid, storage_cids.storage_path, storage_cids.node_type, storage_cids.mh_key
INTO results
FROM eth.storage_cids
INNER JOIN public.blocks
ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number)
INNER JOIN eth.state_cids
ON (storage_cids.state_path, storage_cids.header_id) = (state_cids.state_path, state_cids.header_id)
WHERE storage_cids.block_number BETWEEN starting_height AND ending_height
AND node_type BETWEEN 0 AND 2
ORDER BY state_path, storage_path, block_number DESC;
-- from the set returned above, insert public.block records at the ending_height block number
INSERT INTO public.blocks (block_number, key, data)
@ -616,7 +628,7 @@ ALTER TABLE ONLY public.goose_db_version ALTER COLUMN id SET DEFAULT nextval('pu
--
ALTER TABLE ONLY eth.access_list_elements
ADD CONSTRAINT access_list_elements_pkey PRIMARY KEY (tx_id, index);
ADD CONSTRAINT access_list_elements_pkey PRIMARY KEY (tx_id, index, block_number);
--
@ -624,7 +636,7 @@ ALTER TABLE ONLY eth.access_list_elements
--
ALTER TABLE ONLY eth.header_cids
ADD CONSTRAINT header_cids_pkey PRIMARY KEY (block_hash);
ADD CONSTRAINT header_cids_pkey PRIMARY KEY (block_hash, block_number);
--
@ -632,7 +644,7 @@ ALTER TABLE ONLY eth.header_cids
--
ALTER TABLE ONLY eth.log_cids
ADD CONSTRAINT log_cids_pkey PRIMARY KEY (rct_id, index);
ADD CONSTRAINT log_cids_pkey PRIMARY KEY (rct_id, index, block_number);
--
@ -640,7 +652,7 @@ ALTER TABLE ONLY eth.log_cids
--
ALTER TABLE ONLY eth.receipt_cids
ADD CONSTRAINT receipt_cids_pkey PRIMARY KEY (tx_id);
ADD CONSTRAINT receipt_cids_pkey PRIMARY KEY (tx_id, block_number);
--
@ -648,7 +660,7 @@ ALTER TABLE ONLY eth.receipt_cids
--
ALTER TABLE ONLY eth.state_accounts
ADD CONSTRAINT state_accounts_pkey PRIMARY KEY (state_path, header_id);
ADD CONSTRAINT state_accounts_pkey PRIMARY KEY (state_path, header_id, block_number);
--
@ -656,7 +668,7 @@ ALTER TABLE ONLY eth.state_accounts
--
ALTER TABLE ONLY eth.state_cids
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (state_path, header_id);
ADD CONSTRAINT state_cids_pkey PRIMARY KEY (state_path, header_id, block_number);
--
@ -664,7 +676,7 @@ ALTER TABLE ONLY eth.state_cids
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (storage_path, state_path, header_id);
ADD CONSTRAINT storage_cids_pkey PRIMARY KEY (storage_path, state_path, header_id, block_number);
--
@ -672,7 +684,7 @@ ALTER TABLE ONLY eth.storage_cids
--
ALTER TABLE ONLY eth.transaction_cids
ADD CONSTRAINT transaction_cids_pkey PRIMARY KEY (tx_hash);
ADD CONSTRAINT transaction_cids_pkey PRIMARY KEY (tx_hash, block_number);
--
@ -680,7 +692,7 @@ ALTER TABLE ONLY eth.transaction_cids
--
ALTER TABLE ONLY eth.uncle_cids
ADD CONSTRAINT uncle_cids_pkey PRIMARY KEY (block_hash);
ADD CONSTRAINT uncle_cids_pkey PRIMARY KEY (block_hash, block_number);
--
@ -768,7 +780,7 @@ CREATE INDEX header_block_number_index ON eth.header_cids USING brin (block_numb
-- Name: header_cid_index; Type: INDEX; Schema: eth; Owner: -
--
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, block_number);
--
@ -985,7 +997,7 @@ CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_num
-- Name: tx_cid_index; Type: INDEX; Schema: eth; Owner: -
--
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, block_number);
--
@ -1037,6 +1049,13 @@ CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id);
CREATE UNIQUE INDEX uncle_mh_block_number_index ON eth.uncle_cids USING btree (mh_key, block_number);
--
-- Name: blocks_block_number_idx; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX blocks_block_number_idx ON public.blocks USING btree (block_number DESC);
--
-- Name: access_list_elements trg_eth_access_list_elements; Type: TRIGGER; Schema: eth; Owner: -
--
@ -1101,11 +1120,81 @@ CREATE TRIGGER trg_eth_uncle_cids AFTER INSERT ON eth.uncle_cids FOR EACH ROW EX
--
-- Name: access_list_elements access_list_elements_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: access_list_elements ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.access_list_elements FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: header_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.header_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: log_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.log_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: receipt_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.receipt_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: state_accounts ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.state_accounts FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: state_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.state_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: storage_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.storage_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: transaction_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.transaction_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: uncle_cids ts_insert_blocker; Type: TRIGGER; Schema: eth; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON eth.uncle_cids FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: blocks ts_insert_blocker; Type: TRIGGER; Schema: public; Owner: -
--
CREATE TRIGGER ts_insert_blocker BEFORE INSERT ON public.blocks FOR EACH ROW EXECUTE FUNCTION _timescaledb_internal.insert_blocker();
--
-- Name: access_list_elements access_list_elements_tx_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.access_list_elements
ADD CONSTRAINT access_list_elements_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT access_list_elements_tx_id_block_number_fkey FOREIGN KEY (tx_id, block_number) REFERENCES eth.transaction_cids(tx_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
@ -1116,14 +1205,6 @@ ALTER TABLE ONLY eth.header_cids
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;
--
-- Name: header_cids header_cids_node_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.header_cids
ADD CONSTRAINT header_cids_node_id_fkey FOREIGN KEY (node_id) REFERENCES public.nodes(node_id) ON DELETE CASCADE;
--
-- Name: log_cids log_cids_leaf_mh_key_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
@ -1133,11 +1214,11 @@ ALTER TABLE ONLY eth.log_cids
--
-- Name: log_cids log_cids_rct_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: log_cids log_cids_rct_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.log_cids
ADD CONSTRAINT log_cids_rct_id_fkey FOREIGN KEY (rct_id) REFERENCES eth.receipt_cids(tx_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT log_cids_rct_id_block_number_fkey FOREIGN KEY (rct_id, block_number) REFERENCES eth.receipt_cids(tx_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
@ -1149,27 +1230,27 @@ ALTER TABLE ONLY eth.receipt_cids
--
-- Name: receipt_cids receipt_cids_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: receipt_cids receipt_cids_tx_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.receipt_cids
ADD CONSTRAINT receipt_cids_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT receipt_cids_tx_id_block_number_fkey FOREIGN KEY (tx_id, block_number) REFERENCES eth.transaction_cids(tx_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: state_accounts state_accounts_state_path_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: state_accounts state_accounts_state_path_header_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.state_accounts
ADD CONSTRAINT state_accounts_state_path_header_id_fkey FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids(state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT state_accounts_state_path_header_id_block_number_fkey FOREIGN KEY (state_path, header_id, block_number) REFERENCES eth.state_cids(state_path, header_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: state_cids state_cids_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: state_cids state_cids_header_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.state_cids
ADD CONSTRAINT state_cids_header_id_fkey FOREIGN KEY (header_id) REFERENCES eth.header_cids(block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT state_cids_header_id_block_number_fkey FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids(block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
@ -1189,19 +1270,19 @@ ALTER TABLE ONLY eth.storage_cids
--
-- Name: storage_cids storage_cids_state_path_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: storage_cids storage_cids_state_path_header_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.storage_cids
ADD CONSTRAINT storage_cids_state_path_header_id_fkey FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids(state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT storage_cids_state_path_header_id_block_number_fkey FOREIGN KEY (state_path, header_id, block_number) REFERENCES eth.state_cids(state_path, header_id, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
-- Name: transaction_cids transaction_cids_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: transaction_cids transaction_cids_header_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.transaction_cids
ADD CONSTRAINT transaction_cids_header_id_fkey FOREIGN KEY (header_id) REFERENCES eth.header_cids(block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT transaction_cids_header_id_block_number_fkey FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids(block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--
@ -1213,11 +1294,11 @@ ALTER TABLE ONLY eth.transaction_cids
--
-- Name: uncle_cids uncle_cids_header_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
-- Name: uncle_cids uncle_cids_header_id_block_number_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: -
--
ALTER TABLE ONLY eth.uncle_cids
ADD CONSTRAINT uncle_cids_header_id_fkey FOREIGN KEY (header_id) REFERENCES eth.header_cids(block_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
ADD CONSTRAINT uncle_cids_header_id_block_number_fkey FOREIGN KEY (header_id, block_number) REFERENCES eth.header_cids(block_hash, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED;
--