Add canonical column to eth.header_cids (#136)
* Add canonical column to eth.header_cids * NOT NULL * Update stored procedures for new schema. * Switch to sql syntax, since it can be inlined. * Fix indent * Fix indent
This commit is contained in:
parent
66cd1d9e69
commit
1b922dbff3
@ -14,6 +14,7 @@ CREATE TABLE IF NOT EXISTS eth.header_cids (
|
|||||||
bloom BYTEA NOT NULL,
|
bloom BYTEA NOT NULL,
|
||||||
timestamp BIGINT NOT NULL,
|
timestamp BIGINT NOT NULL,
|
||||||
coinbase VARCHAR(66) NOT NULL,
|
coinbase VARCHAR(66) NOT NULL,
|
||||||
|
canonical BOOLEAN NOT NULL DEFAULT TRUE,
|
||||||
PRIMARY KEY (block_hash, block_number)
|
PRIMARY KEY (block_hash, block_number)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
@ -46,7 +46,8 @@ CREATE TYPE header_result AS (
|
|||||||
uncles_hash character varying(66),
|
uncles_hash character varying(66),
|
||||||
bloom bytea,
|
bloom bytea,
|
||||||
"timestamp" bigint,
|
"timestamp" bigint,
|
||||||
coinbase character varying(66)
|
coinbase character varying(66),
|
||||||
|
canonical bool
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TYPE child_result AS (
|
CREATE TYPE child_result AS (
|
||||||
@ -67,12 +68,13 @@ BEGIN
|
|||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE parent_hash = hash
|
WHERE parent_hash = hash
|
||||||
AND block_number = child_height
|
AND block_number = child_height
|
||||||
|
AND canonical = true
|
||||||
LIMIT 1)
|
LIMIT 1)
|
||||||
INTO new_child_result.has_child;
|
INTO new_child_result.has_child;
|
||||||
-- collect all the children for this header
|
-- collect all the children for this header
|
||||||
IF new_child_result.has_child THEN
|
IF new_child_result.has_child THEN
|
||||||
FOR temp_child IN
|
FOR temp_child IN
|
||||||
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
|
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height AND canonical = true
|
||||||
LOOP
|
LOOP
|
||||||
new_child_result.children = array_append(new_child_result.children, temp_child);
|
new_child_result.children = array_append(new_child_result.children, temp_child);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
@ -83,90 +85,17 @@ $BODY$
|
|||||||
LANGUAGE 'plpgsql';
|
LANGUAGE 'plpgsql';
|
||||||
-- +goose StatementEnd
|
-- +goose StatementEnd
|
||||||
|
|
||||||
-- +goose StatementBegin
|
|
||||||
CREATE OR REPLACE FUNCTION canonical_header_from_array(headers header_result[]) RETURNS header_result AS
|
|
||||||
$BODY$
|
|
||||||
DECLARE
|
|
||||||
canonical_header header_result;
|
|
||||||
canonical_child header_result;
|
|
||||||
header header_result;
|
|
||||||
current_child_result child_result;
|
|
||||||
child_headers header_result[];
|
|
||||||
current_header_with_child header_result;
|
|
||||||
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 = get_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
|
-- +goose StatementBegin
|
||||||
CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS
|
CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS
|
||||||
$BODY$
|
$BODY$
|
||||||
DECLARE
|
SELECT block_hash from eth.header_cids WHERE block_number = height AND canonical = true LIMIT 1;
|
||||||
canonical_header header_result;
|
|
||||||
headers header_result[];
|
|
||||||
header_count INT;
|
|
||||||
temp_header header_result;
|
|
||||||
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
|
|
||||||
$BODY$
|
$BODY$
|
||||||
LANGUAGE 'plpgsql';
|
LANGUAGE sql;
|
||||||
-- +goose StatementEnd
|
-- +goose StatementEnd
|
||||||
|
|
||||||
-- +goose Down
|
-- +goose Down
|
||||||
DROP FUNCTION was_state_leaf_removed;
|
DROP FUNCTION was_state_leaf_removed;
|
||||||
DROP FUNCTION was_state_leaf_removed_by_number;
|
DROP FUNCTION was_state_leaf_removed_by_number;
|
||||||
DROP FUNCTION canonical_header_hash;
|
DROP FUNCTION canonical_header_hash;
|
||||||
DROP FUNCTION canonical_header_from_array;
|
|
||||||
DROP FUNCTION get_child;
|
DROP FUNCTION get_child;
|
||||||
DROP TYPE child_result;
|
DROP TYPE child_result;
|
||||||
|
94
schema.sql
94
schema.sql
@ -2,8 +2,8 @@
|
|||||||
-- PostgreSQL database dump
|
-- PostgreSQL database dump
|
||||||
--
|
--
|
||||||
|
|
||||||
-- Dumped from database version 14.6
|
-- Dumped from database version 14.8
|
||||||
-- Dumped by pg_dump version 14.7 (Homebrew)
|
-- Dumped by pg_dump version 14.8 (Ubuntu 14.8-0ubuntu0.22.04.1)
|
||||||
|
|
||||||
SET statement_timeout = 0;
|
SET statement_timeout = 0;
|
||||||
SET lock_timeout = 0;
|
SET lock_timeout = 0;
|
||||||
@ -27,7 +27,7 @@ CREATE EXTENSION IF NOT EXISTS timescaledb WITH SCHEMA public;
|
|||||||
-- Name: EXTENSION timescaledb; Type: COMMENT; Schema: -; Owner: -
|
-- Name: EXTENSION timescaledb; Type: COMMENT; Schema: -; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
COMMENT ON EXTENSION timescaledb IS 'Enables scalable inserts and complex queries for time-series data';
|
COMMENT ON EXTENSION timescaledb IS 'Enables scalable inserts and complex queries for time-series data (Community Edition)';
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
@ -69,7 +69,8 @@ CREATE TYPE public.header_result AS (
|
|||||||
uncles_hash character varying(66),
|
uncles_hash character varying(66),
|
||||||
bloom bytea,
|
bloom bytea,
|
||||||
"timestamp" bigint,
|
"timestamp" bigint,
|
||||||
coinbase character varying(66)
|
coinbase character varying(66),
|
||||||
|
canonical boolean
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
@ -83,89 +84,14 @@ CREATE TYPE public.child_result AS (
|
|||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Name: canonical_header_from_array(public.header_result[]); Type: FUNCTION; Schema: public; Owner: -
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE FUNCTION public.canonical_header_from_array(headers public.header_result[]) RETURNS public.header_result
|
|
||||||
LANGUAGE plpgsql
|
|
||||||
AS $$
|
|
||||||
DECLARE
|
|
||||||
canonical_header header_result;
|
|
||||||
canonical_child header_result;
|
|
||||||
header header_result;
|
|
||||||
current_child_result child_result;
|
|
||||||
child_headers header_result[];
|
|
||||||
current_header_with_child header_result;
|
|
||||||
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 = get_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: -
|
-- Name: canonical_header_hash(bigint); Type: FUNCTION; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
|
|
||||||
CREATE FUNCTION public.canonical_header_hash(height bigint) RETURNS character varying
|
CREATE FUNCTION public.canonical_header_hash(height bigint) RETURNS character varying
|
||||||
LANGUAGE plpgsql
|
LANGUAGE sql
|
||||||
AS $$
|
AS $$
|
||||||
DECLARE
|
SELECT block_hash from eth.header_cids WHERE block_number = height AND canonical = true LIMIT 1;
|
||||||
canonical_header header_result;
|
|
||||||
headers header_result[];
|
|
||||||
header_count INT;
|
|
||||||
temp_header header_result;
|
|
||||||
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
|
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
@ -187,12 +113,13 @@ BEGIN
|
|||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE parent_hash = hash
|
WHERE parent_hash = hash
|
||||||
AND block_number = child_height
|
AND block_number = child_height
|
||||||
|
AND canonical = true
|
||||||
LIMIT 1)
|
LIMIT 1)
|
||||||
INTO new_child_result.has_child;
|
INTO new_child_result.has_child;
|
||||||
-- collect all the children for this header
|
-- collect all the children for this header
|
||||||
IF new_child_result.has_child THEN
|
IF new_child_result.has_child THEN
|
||||||
FOR temp_child IN
|
FOR temp_child IN
|
||||||
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height
|
SELECT * FROM eth.header_cids WHERE parent_hash = hash AND block_number = child_height AND canonical = true
|
||||||
LOOP
|
LOOP
|
||||||
new_child_result.children = array_append(new_child_result.children, temp_child);
|
new_child_result.children = array_append(new_child_result.children, temp_child);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
@ -348,7 +275,8 @@ CREATE TABLE eth.header_cids (
|
|||||||
uncles_hash character varying(66) NOT NULL,
|
uncles_hash character varying(66) NOT NULL,
|
||||||
bloom bytea NOT NULL,
|
bloom bytea NOT NULL,
|
||||||
"timestamp" bigint NOT NULL,
|
"timestamp" bigint NOT NULL,
|
||||||
coinbase character varying(66) NOT NULL
|
coinbase character varying(66) NOT NULL,
|
||||||
|
canonical boolean DEFAULT true NOT NULL
|
||||||
);
|
);
|
||||||
|
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user