Merge pull request #103 from vulcanize/release-v5.0.0
v5 updates part 1
This commit is contained in:
commit
0c62ccc552
@ -10,7 +10,7 @@ CREATE TABLE IF NOT EXISTS eth.header_cids (
|
|||||||
state_root VARCHAR(66) NOT NULL,
|
state_root VARCHAR(66) NOT NULL,
|
||||||
tx_root VARCHAR(66) NOT NULL,
|
tx_root VARCHAR(66) NOT NULL,
|
||||||
receipt_root VARCHAR(66) NOT NULL,
|
receipt_root VARCHAR(66) NOT NULL,
|
||||||
uncle_root VARCHAR(66) NOT NULL,
|
uncles_hash 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,
|
mh_key TEXT NOT NULL,
|
||||||
|
@ -4,7 +4,7 @@ CREATE TABLE IF NOT EXISTS eth.transaction_cids (
|
|||||||
header_id VARCHAR(66) NOT NULL,
|
header_id VARCHAR(66) NOT NULL,
|
||||||
tx_hash VARCHAR(66) NOT NULL,
|
tx_hash VARCHAR(66) NOT NULL,
|
||||||
cid TEXT NOT NULL,
|
cid TEXT NOT NULL,
|
||||||
dst VARCHAR(66) NOT NULL,
|
dst VARCHAR(66),
|
||||||
src VARCHAR(66) NOT NULL,
|
src VARCHAR(66) NOT NULL,
|
||||||
index INTEGER NOT NULL,
|
index INTEGER NOT NULL,
|
||||||
mh_key TEXT NOT NULL,
|
mh_key TEXT NOT NULL,
|
||||||
|
@ -8,7 +8,7 @@ CREATE TABLE IF NOT EXISTS eth.receipt_cids (
|
|||||||
contract_hash VARCHAR(66),
|
contract_hash VARCHAR(66),
|
||||||
leaf_mh_key TEXT NOT NULL,
|
leaf_mh_key TEXT NOT NULL,
|
||||||
post_state VARCHAR(66),
|
post_state VARCHAR(66),
|
||||||
post_status INTEGER,
|
post_status SMALLINT,
|
||||||
log_root VARCHAR(66),
|
log_root VARCHAR(66),
|
||||||
PRIMARY KEY (tx_id, header_id, block_number)
|
PRIMARY KEY (tx_id, header_id, block_number)
|
||||||
);
|
);
|
||||||
|
@ -5,7 +5,7 @@ CREATE TABLE IF NOT EXISTS eth.state_accounts (
|
|||||||
state_path BYTEA NOT NULL,
|
state_path BYTEA NOT NULL,
|
||||||
balance NUMERIC NOT NULL,
|
balance NUMERIC NOT NULL,
|
||||||
nonce BIGINT NOT NULL,
|
nonce BIGINT NOT NULL,
|
||||||
code_hash BYTEA NOT NULL,
|
code_hash VARCHAR(66) NOT NULL,
|
||||||
storage_root VARCHAR(66) NOT NULL,
|
storage_root VARCHAR(66) NOT NULL,
|
||||||
PRIMARY KEY (state_path, header_id, block_number)
|
PRIMARY KEY (state_path, header_id, block_number)
|
||||||
);
|
);
|
||||||
|
@ -18,6 +18,7 @@ CREATE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid, block_number
|
|||||||
CREATE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
|
CREATE 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_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);
|
||||||
|
CREATE INDEX tx_data_index ON eth.transaction_cids USING hash (tx_data);
|
||||||
|
|
||||||
-- receipt indexes
|
-- receipt indexes
|
||||||
CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number);
|
CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number);
|
||||||
@ -64,9 +65,11 @@ CREATE INDEX log_topic0_index ON eth.log_cids USING btree (topic0);
|
|||||||
CREATE INDEX log_topic1_index ON eth.log_cids USING btree (topic1);
|
CREATE INDEX log_topic1_index ON eth.log_cids USING btree (topic1);
|
||||||
CREATE INDEX log_topic2_index ON eth.log_cids USING btree (topic2);
|
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);
|
||||||
|
CREATE INDEX log_data_index ON eth.log_cids USING hash (log_data);
|
||||||
|
|
||||||
-- +goose Down
|
-- +goose Down
|
||||||
-- log indexes
|
-- log indexes
|
||||||
|
DROP INDEX eth.log_data_index;
|
||||||
DROP INDEX eth.log_topic3_index;
|
DROP INDEX eth.log_topic3_index;
|
||||||
DROP INDEX eth.log_topic2_index;
|
DROP INDEX eth.log_topic2_index;
|
||||||
DROP INDEX eth.log_topic1_index;
|
DROP INDEX eth.log_topic1_index;
|
||||||
@ -113,6 +116,7 @@ DROP INDEX eth.rct_header_id_index;
|
|||||||
DROP INDEX eth.rct_block_number_index;
|
DROP INDEX eth.rct_block_number_index;
|
||||||
|
|
||||||
-- transaction indexes
|
-- transaction indexes
|
||||||
|
DROP INDEX eth.tx_data_index;
|
||||||
DROP INDEX eth.tx_src_index;
|
DROP INDEX eth.tx_src_index;
|
||||||
DROP INDEX eth.tx_dst_index;
|
DROP INDEX eth.tx_dst_index;
|
||||||
DROP INDEX eth.tx_mh_block_number_index;
|
DROP INDEX eth.tx_mh_block_number_index;
|
||||||
|
407
schema.sql
407
schema.sql
@ -16,20 +16,6 @@ SET xmloption = content;
|
|||||||
SET client_min_messages = warning;
|
SET client_min_messages = warning;
|
||||||
SET row_security = off;
|
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: -
|
-- Name: eth; Type: SCHEMA; Schema: -; Owner: -
|
||||||
--
|
--
|
||||||
@ -44,87 +30,6 @@ CREATE SCHEMA eth;
|
|||||||
CREATE SCHEMA eth_meta;
|
CREATE SCHEMA eth_meta;
|
||||||
|
|
||||||
|
|
||||||
SET default_tablespace = '';
|
|
||||||
|
|
||||||
SET default_table_access_method = heap;
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: header_cids; Type: TABLE; Schema: eth; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE TABLE eth.header_cids (
|
|
||||||
block_number bigint NOT NULL,
|
|
||||||
block_hash character varying(66) NOT NULL,
|
|
||||||
parent_hash character varying(66) NOT NULL,
|
|
||||||
cid text NOT NULL,
|
|
||||||
td numeric NOT NULL,
|
|
||||||
node_id character varying(128) NOT NULL,
|
|
||||||
reward numeric NOT NULL,
|
|
||||||
state_root character varying(66) NOT NULL,
|
|
||||||
tx_root character varying(66) NOT NULL,
|
|
||||||
receipt_root character varying(66) NOT NULL,
|
|
||||||
uncle_root character varying(66) NOT NULL,
|
|
||||||
bloom bytea NOT NULL,
|
|
||||||
"timestamp" bigint NOT NULL,
|
|
||||||
mh_key text NOT NULL,
|
|
||||||
times_validated integer DEFAULT 1 NOT NULL,
|
|
||||||
coinbase character varying(66) NOT NULL
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: TABLE header_cids; Type: COMMENT; Schema: eth; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
COMMENT ON TABLE eth.header_cids IS '@name EthHeaderCids';
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: COLUMN header_cids.node_id; Type: COMMENT; Schema: eth; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
COMMENT ON COLUMN eth.header_cids.node_id IS '@name EthNodeID';
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: child_result; Type: TYPE; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE TYPE public.child_result AS (
|
|
||||||
has_child boolean,
|
|
||||||
children eth.header_cids[]
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: state_node_result; Type: TYPE; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE TYPE public.state_node_result AS (
|
|
||||||
data bytea,
|
|
||||||
state_leaf_key character varying(66),
|
|
||||||
cid text,
|
|
||||||
state_path bytea,
|
|
||||||
node_type integer,
|
|
||||||
mh_key text
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: storage_node_result; Type: TYPE; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE TYPE public.storage_node_result AS (
|
|
||||||
data bytea,
|
|
||||||
state_path bytea,
|
|
||||||
storage_leaf_key character varying(66),
|
|
||||||
cid text,
|
|
||||||
storage_path bytea,
|
|
||||||
node_type integer,
|
|
||||||
mh_key text
|
|
||||||
);
|
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: graphql_subscription(); Type: FUNCTION; Schema: eth; Owner: -
|
-- Name: graphql_subscription(); Type: FUNCTION; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -151,17 +56,20 @@ BEGIN
|
|||||||
ELSIF (TG_TABLE_NAME = 'log_cids') THEN
|
ELSIF (TG_TABLE_NAME = 'log_cids') THEN
|
||||||
obj := json_build_array(
|
obj := json_build_array(
|
||||||
TG_TABLE_NAME,
|
TG_TABLE_NAME,
|
||||||
|
NEW.header_id,
|
||||||
NEW.rct_id,
|
NEW.rct_id,
|
||||||
NEW.index
|
NEW.index
|
||||||
);
|
);
|
||||||
ELSIF (TG_TABLE_NAME = 'receipt_cids') THEN
|
ELSIF (TG_TABLE_NAME = 'receipt_cids') THEN
|
||||||
obj := json_build_array(
|
obj := json_build_array(
|
||||||
TG_TABLE_NAME,
|
TG_TABLE_NAME,
|
||||||
|
NEW.header_id,
|
||||||
NEW.tx_id
|
NEW.tx_id
|
||||||
);
|
);
|
||||||
ELSIF (TG_TABLE_NAME = 'transaction_cids') THEN
|
ELSIF (TG_TABLE_NAME = 'transaction_cids') THEN
|
||||||
obj := json_build_array(
|
obj := json_build_array(
|
||||||
TG_TABLE_NAME,
|
TG_TABLE_NAME,
|
||||||
|
NEW.header_id,
|
||||||
NEW.tx_hash
|
NEW.tx_hash
|
||||||
);
|
);
|
||||||
ELSIF (TG_TABLE_NAME = 'access_list_elements') THEN
|
ELSIF (TG_TABLE_NAME = 'access_list_elements') THEN
|
||||||
@ -185,223 +93,9 @@ END;
|
|||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
--
|
SET default_tablespace = '';
|
||||||
-- Name: canonical_header_from_array(eth.header_cids[]); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
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
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: canonical_header_hash(bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.canonical_header_hash(height bigint) RETURNS character varying
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
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 hash
|
|
||||||
ELSIF header_count = 1 THEN
|
|
||||||
RETURN headers[1].block_hash;
|
|
||||||
-- if we have multiple headers we need to determine which one is canonical
|
|
||||||
ELSE
|
|
||||||
canonical_header = canonical_header_from_array(headers);
|
|
||||||
RETURN canonical_header.block_hash;
|
|
||||||
END IF;
|
|
||||||
END
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.has_child(hash character varying, height bigint) RETURNS public.child_result
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
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
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: state_snapshot(bigint, bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.state_snapshot(starting_height bigint, ending_height bigint) RETURNS void
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
canonical_hash VARCHAR(66);
|
|
||||||
results state_node_result[];
|
|
||||||
BEGIN
|
|
||||||
-- get the canonical hash for the header at ending_height
|
|
||||||
canonical_hash = canonical_header_hash(ending_height);
|
|
||||||
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
|
|
||||||
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
|
|
||||||
FROM eth.state_cids
|
|
||||||
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
|
|
||||||
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)
|
|
||||||
SELECT ending_height, r.mh_key, r.data
|
|
||||||
FROM results r;
|
|
||||||
-- from the set returned above, insert eth.state_cids records at the ending_height block number
|
|
||||||
-- anchoring all the records to the canonical header found at ending_height
|
|
||||||
INSERT INTO eth.state_cids (block_number, header_id, state_leaf_key, cid, state_path, node_type, diff, mh_key)
|
|
||||||
SELECT ending_height, canonical_hash, r.state_leaf_key, r.cid, r.state_path, r.node_type, false, r.mh_key
|
|
||||||
FROM results r
|
|
||||||
ON CONFLICT (state_path, header_id) DO NOTHING;
|
|
||||||
END
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: storage_snapshot(bigint, bigint); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.storage_snapshot(starting_height bigint, ending_height bigint) RETURNS void
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
canonical_hash VARCHAR(66);
|
|
||||||
results storage_node_result[];
|
|
||||||
BEGIN
|
|
||||||
-- get the canonical hash for the header at ending_height
|
|
||||||
SELECT canonical_header_hash(ending_height) INTO canonical_hash;
|
|
||||||
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 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;
|
|
||||||
-- from the set returned above, insert public.block records at the ending_height block number
|
|
||||||
INSERT INTO public.blocks (block_number, key, data)
|
|
||||||
SELECT ending_height, r.mh_key, r.data
|
|
||||||
FROM results r;
|
|
||||||
-- from the set returned above, insert eth.state_cids records at the ending_height block number
|
|
||||||
-- anchoring all the records to the canonical header found at ending_height
|
|
||||||
INSERT INTO eth.storage_cids (block_number, header_id, state_path, storage_leaf_key, cid, storage_path,
|
|
||||||
node_type, diff, mh_key)
|
|
||||||
SELECT ending_height, canonical_hash, r.state_path, r.storage_leaf_key, r.cid, r.storage_path, r.node_type, false, r.mh_key
|
|
||||||
FROM results r
|
|
||||||
ON CONFLICT (storage_path, state_path, header_id) DO NOTHING;
|
|
||||||
END
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: was_state_leaf_removed(character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.was_state_leaf_removed(key character varying, hash character varying) RETURNS boolean
|
|
||||||
LANGUAGE sql
|
|
||||||
AS $$
|
|
||||||
SELECT state_cids.node_type = 3
|
|
||||||
FROM eth.state_cids
|
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
|
||||||
WHERE state_leaf_key = key
|
|
||||||
AND state_cids.block_number <= (SELECT block_number
|
|
||||||
FROM eth.header_cids
|
|
||||||
WHERE block_hash = hash)
|
|
||||||
ORDER BY state_cids.block_number DESC LIMIT 1;
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
SET default_table_access_method = heap;
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: access_list_elements; Type: TABLE; Schema: eth; Owner: -
|
-- Name: access_list_elements; Type: TABLE; Schema: eth; Owner: -
|
||||||
@ -416,12 +110,51 @@ CREATE TABLE eth.access_list_elements (
|
|||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: header_cids; Type: TABLE; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE TABLE eth.header_cids (
|
||||||
|
block_number bigint NOT NULL,
|
||||||
|
block_hash character varying(66) NOT NULL,
|
||||||
|
parent_hash character varying(66) NOT NULL,
|
||||||
|
cid text NOT NULL,
|
||||||
|
td numeric NOT NULL,
|
||||||
|
node_id character varying(128) NOT NULL,
|
||||||
|
reward numeric NOT NULL,
|
||||||
|
state_root character varying(66) NOT NULL,
|
||||||
|
tx_root character varying(66) NOT NULL,
|
||||||
|
receipt_root character varying(66) NOT NULL,
|
||||||
|
uncles_hash character varying(66) NOT NULL,
|
||||||
|
bloom bytea NOT NULL,
|
||||||
|
"timestamp" bigint NOT NULL,
|
||||||
|
mh_key text NOT NULL,
|
||||||
|
times_validated integer DEFAULT 1 NOT NULL,
|
||||||
|
coinbase character varying(66) NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: TABLE header_cids; Type: COMMENT; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
COMMENT ON TABLE eth.header_cids IS '@name EthHeaderCids';
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: COLUMN header_cids.node_id; Type: COMMENT; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
COMMENT ON COLUMN eth.header_cids.node_id IS '@name EthNodeID';
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: log_cids; Type: TABLE; Schema: eth; Owner: -
|
-- Name: log_cids; Type: TABLE; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
CREATE TABLE eth.log_cids (
|
CREATE TABLE eth.log_cids (
|
||||||
block_number bigint NOT NULL,
|
block_number bigint NOT NULL,
|
||||||
|
header_id character varying(66) 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,
|
||||||
@ -441,13 +174,14 @@ CREATE TABLE eth.log_cids (
|
|||||||
|
|
||||||
CREATE TABLE eth.receipt_cids (
|
CREATE TABLE eth.receipt_cids (
|
||||||
block_number bigint NOT NULL,
|
block_number bigint NOT NULL,
|
||||||
|
header_id character varying(66) 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),
|
||||||
contract_hash character varying(66),
|
contract_hash character varying(66),
|
||||||
leaf_mh_key text NOT NULL,
|
leaf_mh_key text NOT NULL,
|
||||||
post_state character varying(66),
|
post_state character varying(66),
|
||||||
post_status integer,
|
post_status smallint,
|
||||||
log_root character varying(66)
|
log_root character varying(66)
|
||||||
);
|
);
|
||||||
|
|
||||||
@ -462,7 +196,7 @@ CREATE TABLE eth.state_accounts (
|
|||||||
state_path bytea NOT NULL,
|
state_path bytea NOT NULL,
|
||||||
balance numeric NOT NULL,
|
balance numeric NOT NULL,
|
||||||
nonce bigint NOT NULL,
|
nonce bigint NOT NULL,
|
||||||
code_hash bytea NOT NULL,
|
code_hash character varying(66) NOT NULL,
|
||||||
storage_root character varying(66) NOT NULL
|
storage_root character varying(66) NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
@ -509,7 +243,7 @@ CREATE TABLE eth.transaction_cids (
|
|||||||
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,
|
||||||
dst character varying(66) NOT NULL,
|
dst character varying(66),
|
||||||
src character varying(66) NOT NULL,
|
src character varying(66) NOT NULL,
|
||||||
index integer NOT NULL,
|
index integer NOT NULL,
|
||||||
mh_key text NOT NULL,
|
mh_key text NOT NULL,
|
||||||
@ -675,7 +409,7 @@ ALTER TABLE ONLY eth.header_cids
|
|||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.log_cids
|
ALTER TABLE ONLY eth.log_cids
|
||||||
ADD CONSTRAINT log_cids_pkey PRIMARY KEY (rct_id, index, block_number);
|
ADD CONSTRAINT log_cids_pkey PRIMARY KEY (rct_id, index, header_id, block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -683,7 +417,7 @@ ALTER TABLE ONLY eth.log_cids
|
|||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.receipt_cids
|
ALTER TABLE ONLY eth.receipt_cids
|
||||||
ADD CONSTRAINT receipt_cids_pkey PRIMARY KEY (tx_id, block_number);
|
ADD CONSTRAINT receipt_cids_pkey PRIMARY KEY (tx_id, header_id, block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -715,7 +449,7 @@ ALTER TABLE ONLY eth.storage_cids
|
|||||||
--
|
--
|
||||||
|
|
||||||
ALTER TABLE ONLY eth.transaction_cids
|
ALTER TABLE ONLY eth.transaction_cids
|
||||||
ADD CONSTRAINT transaction_cids_pkey PRIMARY KEY (tx_hash, block_number);
|
ADD CONSTRAINT transaction_cids_pkey PRIMARY KEY (tx_hash, header_id, block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -858,6 +592,20 @@ CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number);
|
|||||||
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);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: log_data_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX log_data_index ON eth.log_cids USING hash (log_data);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: log_header_id_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX log_header_id_index ON eth.log_cids USING btree (header_id);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: log_leaf_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: log_leaf_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -914,6 +662,13 @@ CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_h
|
|||||||
CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
|
CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: rct_header_id_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX rct_header_id_index ON eth.receipt_cids USING btree (header_id);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: rct_leaf_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: rct_leaf_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
@ -1044,7 +799,14 @@ CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_num
|
|||||||
-- Name: tx_cid_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: tx_cid_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
CREATE UNIQUE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid, block_number);
|
CREATE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid, block_number);
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: tx_data_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE INDEX tx_data_index ON eth.transaction_cids USING hash (tx_data);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -1065,7 +827,7 @@ CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id);
|
|||||||
-- Name: tx_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
-- Name: tx_mh_block_number_index; Type: INDEX; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
CREATE UNIQUE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
|
CREATE INDEX tx_mh_block_number_index ON eth.transaction_cids USING btree (mh_key, block_number);
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -1096,13 +858,6 @@ 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);
|
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: -
|
-- Name: access_list_elements trg_eth_access_list_elements; Type: TRIGGER; Schema: eth; Owner: -
|
||||||
--
|
--
|
||||||
|
Loading…
Reference in New Issue
Block a user