Merge pull request #127 from cerc-io/ian/v5
Modified `get_storage_at` procedures for v5
This commit is contained in:
commit
67dc84205a
@ -1,15 +1,29 @@
|
|||||||
-- +goose Up
|
-- +goose Up
|
||||||
-- +goose StatementBegin
|
-- +goose StatementBegin
|
||||||
-- returns if a state leaf node was removed within the provided block number
|
-- returns whether the state leaf key is vacated (previously existed but now is empty) at the provided block hash
|
||||||
CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash character varying)
|
CREATE OR REPLACE FUNCTION was_state_leaf_removed(v_key VARCHAR(66), v_hash VARCHAR)
|
||||||
RETURNS boolean AS $$
|
RETURNS boolean AS $$
|
||||||
SELECT state_cids.removed = true
|
SELECT state_cids.removed = true
|
||||||
FROM eth.state_cids
|
FROM eth.state_cids
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
WHERE state_leaf_key = key
|
WHERE state_leaf_key = v_key
|
||||||
AND state_cids.block_number <= (SELECT block_number
|
AND state_cids.block_number <= (SELECT block_number
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE block_hash = hash)
|
WHERE block_hash = v_hash)
|
||||||
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
|
$$
|
||||||
|
language sql;
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose StatementBegin
|
||||||
|
-- returns whether the state leaf key is vacated (previously existed but now is empty) at the provided block height
|
||||||
|
CREATE OR REPLACE FUNCTION public.was_state_leaf_removed_by_number(v_key VARCHAR(66), v_block_no BIGINT)
|
||||||
|
RETURNS BOOLEAN AS $$
|
||||||
|
SELECT state_cids.removed = true
|
||||||
|
FROM eth.state_cids
|
||||||
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
|
WHERE state_leaf_key = v_key
|
||||||
|
AND state_cids.block_number <= v_block_no
|
||||||
ORDER BY state_cids.block_number DESC LIMIT 1;
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
$$
|
$$
|
||||||
language sql;
|
language sql;
|
||||||
@ -132,6 +146,7 @@ LANGUAGE 'plpgsql';
|
|||||||
|
|
||||||
-- +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 canonical_header_hash;
|
DROP FUNCTION canonical_header_hash;
|
||||||
DROP FUNCTION canonical_header_from_array;
|
DROP FUNCTION canonical_header_from_array;
|
||||||
DROP FUNCTION has_child;
|
DROP FUNCTION has_child;
|
110
db/migrations/00017_create_get_storage_at_functions.sql
Normal file
110
db/migrations/00017_create_get_storage_at_functions.sql
Normal file
@ -0,0 +1,110 @@
|
|||||||
|
-- +goose Up
|
||||||
|
-- +goose StatementBegin
|
||||||
|
CREATE OR REPLACE FUNCTION public.get_storage_at_by_number(v_state_leaf_key text, v_storage_leaf_key text, v_block_no bigint)
|
||||||
|
RETURNS TABLE
|
||||||
|
(
|
||||||
|
cid TEXT,
|
||||||
|
val BYTEA,
|
||||||
|
block_number BIGINT,
|
||||||
|
removed BOOL,
|
||||||
|
state_leaf_removed BOOL
|
||||||
|
)
|
||||||
|
AS
|
||||||
|
$BODY$
|
||||||
|
DECLARE
|
||||||
|
v_state_path BYTEA;
|
||||||
|
v_header TEXT;
|
||||||
|
v_canonical_header TEXT;
|
||||||
|
BEGIN
|
||||||
|
CREATE TEMP TABLE tmp_tt_stg2
|
||||||
|
(
|
||||||
|
header_id TEXT,
|
||||||
|
cid TEXT,
|
||||||
|
val BYTEA,
|
||||||
|
block_number BIGINT,
|
||||||
|
removed BOOL,
|
||||||
|
state_leaf_removed BOOL
|
||||||
|
) ON COMMIT DROP;
|
||||||
|
|
||||||
|
-- in best case scenario, the latest record we find for the provided keys is for a canonical block
|
||||||
|
INSERT INTO tmp_tt_stg2
|
||||||
|
SELECT storage_cids.header_id,
|
||||||
|
storage_cids.cid,
|
||||||
|
storage_cids.val,
|
||||||
|
storage_cids.block_number,
|
||||||
|
storage_cids.removed,
|
||||||
|
was_state_leaf_removed_by_number(v_state_leaf_key, v_block_no) AS state_leaf_removed
|
||||||
|
FROM eth.storage_cids
|
||||||
|
WHERE storage_leaf_key = v_storage_leaf_key
|
||||||
|
AND storage_cids.state_leaf_key = v_state_leaf_key -- can lookup directly on the leaf key in v5
|
||||||
|
AND storage_cids.block_number <= v_block_no
|
||||||
|
ORDER BY storage_cids.block_number DESC LIMIT 1;
|
||||||
|
|
||||||
|
-- check if result is from canonical state
|
||||||
|
SELECT header_id, canonical_header_hash(tmp_tt_stg2.block_number), tmp_tt_stg2.block_number
|
||||||
|
INTO v_header, v_canonical_header, v_block_no
|
||||||
|
FROM tmp_tt_stg2 LIMIT 1;
|
||||||
|
|
||||||
|
IF v_header IS NULL OR v_header != v_canonical_header THEN
|
||||||
|
RAISE NOTICE 'get_storage_at_by_number: chosen header NULL OR % != canonical header % for block number %, trying again.', v_header, v_canonical_header, v_block_no;
|
||||||
|
TRUNCATE tmp_tt_stg2;
|
||||||
|
-- If we hit on a non-canonical block, we need to go back and do a comprehensive check.
|
||||||
|
-- We try to avoid this to avoid joining between storage_cids and header_cids
|
||||||
|
INSERT INTO tmp_tt_stg2
|
||||||
|
SELECT storage_cids.header_id,
|
||||||
|
storage_cids.cid,
|
||||||
|
storage_cids.val,
|
||||||
|
storage_cids.block_number,
|
||||||
|
storage_cids.removed,
|
||||||
|
was_state_leaf_removed_by_number(
|
||||||
|
v_state_leaf_key,
|
||||||
|
v_block_no
|
||||||
|
) AS state_leaf_removed
|
||||||
|
FROM eth.storage_cids
|
||||||
|
INNER JOIN eth.header_cids ON (
|
||||||
|
storage_cids.header_id = header_cids.block_hash
|
||||||
|
AND storage_cids.block_number = header_cids.block_number
|
||||||
|
)
|
||||||
|
WHERE state_leaf_key = v_state_leaf_key
|
||||||
|
AND storage_leaf_key = v_storage_leaf_key
|
||||||
|
AND storage_cids.block_number <= v_block_no
|
||||||
|
AND header_cids.block_number <= v_block_no
|
||||||
|
AND header_cids.block_hash = (SELECT canonical_header_hash(header_cids.block_number))
|
||||||
|
ORDER BY header_cids.block_number DESC LIMIT 1;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RETURN QUERY SELECT t.cid, t.val, t.block_number, t.removed, t.state_leaf_removed
|
||||||
|
FROM tmp_tt_stg2 AS t LIMIT 1;
|
||||||
|
END
|
||||||
|
$BODY$
|
||||||
|
language 'plpgsql';
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose StatementBegin
|
||||||
|
CREATE OR REPLACE FUNCTION public.get_storage_at_by_hash(v_state_leaf_key TEXT, v_storage_leaf_key text, v_block_hash text)
|
||||||
|
RETURNS TABLE
|
||||||
|
(
|
||||||
|
cid TEXT,
|
||||||
|
val BYTEA,
|
||||||
|
block_number BIGINT,
|
||||||
|
removed BOOL,
|
||||||
|
state_leaf_removed BOOL
|
||||||
|
)
|
||||||
|
AS
|
||||||
|
$BODY$
|
||||||
|
DECLARE
|
||||||
|
v_block_no BIGINT;
|
||||||
|
BEGIN
|
||||||
|
SELECT h.block_number INTO v_block_no FROM eth.header_cids AS h WHERE block_hash = v_block_hash LIMIT 1;
|
||||||
|
IF v_block_no IS NULL THEN
|
||||||
|
RETURN;
|
||||||
|
END IF;
|
||||||
|
RETURN QUERY SELECT * FROM get_storage_at_by_number(v_state_leaf_key, v_storage_leaf_key, v_block_no);
|
||||||
|
END
|
||||||
|
$BODY$
|
||||||
|
LANGUAGE 'plpgsql';
|
||||||
|
-- +goose StatementEnd
|
||||||
|
|
||||||
|
-- +goose Down
|
||||||
|
DROP FUNCTION get_storage_at_by_hash;
|
||||||
|
DROP FUNCTION get_storage_at_by_number;
|
112
schema.sql
112
schema.sql
@ -187,6 +187,96 @@ END
|
|||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: get_storage_at_by_hash(text, text, text); Type: FUNCTION; Schema: public; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE FUNCTION public.get_storage_at_by_hash(v_state_leaf_key text, v_storage_leaf_key text, v_block_hash text) RETURNS TABLE(cid text, val bytea, block_number bigint, removed boolean, state_leaf_removed boolean)
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
v_block_no BIGINT;
|
||||||
|
BEGIN
|
||||||
|
SELECT h.block_number INTO v_block_no FROM eth.header_cids AS h WHERE block_hash = v_block_hash LIMIT 1;
|
||||||
|
IF v_block_no IS NULL THEN
|
||||||
|
RETURN;
|
||||||
|
END IF;
|
||||||
|
RETURN QUERY SELECT * FROM get_storage_at_by_number(v_state_leaf_key, v_storage_leaf_key, v_block_no);
|
||||||
|
END
|
||||||
|
$$;
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: get_storage_at_by_number(text, text, bigint); Type: FUNCTION; Schema: public; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE FUNCTION public.get_storage_at_by_number(v_state_leaf_key text, v_storage_leaf_key text, v_block_no bigint) RETURNS TABLE(cid text, val bytea, block_number bigint, removed boolean, state_leaf_removed boolean)
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
v_state_path BYTEA;
|
||||||
|
v_header TEXT;
|
||||||
|
v_canonical_header TEXT;
|
||||||
|
BEGIN
|
||||||
|
CREATE TEMP TABLE tmp_tt_stg2
|
||||||
|
(
|
||||||
|
header_id TEXT,
|
||||||
|
cid TEXT,
|
||||||
|
val BYTEA,
|
||||||
|
block_number BIGINT,
|
||||||
|
removed BOOL,
|
||||||
|
state_leaf_removed BOOL
|
||||||
|
) ON COMMIT DROP;
|
||||||
|
-- in best case scenario, the latest record we find for the provided keys is for a canonical block
|
||||||
|
INSERT INTO tmp_tt_stg2
|
||||||
|
SELECT storage_cids.header_id,
|
||||||
|
storage_cids.cid,
|
||||||
|
storage_cids.val,
|
||||||
|
storage_cids.block_number,
|
||||||
|
storage_cids.removed,
|
||||||
|
was_state_leaf_removed_by_number(v_state_leaf_key, v_block_no) AS state_leaf_removed
|
||||||
|
FROM eth.storage_cids
|
||||||
|
WHERE storage_leaf_key = v_storage_leaf_key
|
||||||
|
AND storage_cids.state_leaf_key = v_state_leaf_key -- can lookup directly on the leaf key in v5
|
||||||
|
AND storage_cids.block_number <= v_block_no
|
||||||
|
ORDER BY storage_cids.block_number DESC LIMIT 1;
|
||||||
|
-- check if result is from canonical state
|
||||||
|
SELECT header_id, canonical_header_hash(tmp_tt_stg2.block_number), tmp_tt_stg2.block_number
|
||||||
|
INTO v_header, v_canonical_header, v_block_no
|
||||||
|
FROM tmp_tt_stg2 LIMIT 1;
|
||||||
|
IF v_header IS NULL OR v_header != v_canonical_header THEN
|
||||||
|
RAISE NOTICE 'get_storage_at_by_number: chosen header NULL OR % != canonical header % for block number %, trying again.', v_header, v_canonical_header, v_block_no;
|
||||||
|
TRUNCATE tmp_tt_stg2;
|
||||||
|
-- If we hit on a non-canonical block, we need to go back and do a comprehensive check.
|
||||||
|
-- We try to avoid this to avoid joining between storage_cids and header_cids
|
||||||
|
INSERT INTO tmp_tt_stg2
|
||||||
|
SELECT storage_cids.header_id,
|
||||||
|
storage_cids.cid,
|
||||||
|
storage_cids.val,
|
||||||
|
storage_cids.block_number,
|
||||||
|
storage_cids.removed,
|
||||||
|
was_state_leaf_removed_by_number(
|
||||||
|
v_state_leaf_key,
|
||||||
|
v_block_no
|
||||||
|
) AS state_leaf_removed
|
||||||
|
FROM eth.storage_cids
|
||||||
|
INNER JOIN eth.header_cids ON (
|
||||||
|
storage_cids.header_id = header_cids.block_hash
|
||||||
|
AND storage_cids.block_number = header_cids.block_number
|
||||||
|
)
|
||||||
|
WHERE state_leaf_key = v_state_leaf_key
|
||||||
|
AND storage_leaf_key = v_storage_leaf_key
|
||||||
|
AND storage_cids.block_number <= v_block_no
|
||||||
|
AND header_cids.block_number <= v_block_no
|
||||||
|
AND header_cids.block_hash = (SELECT canonical_header_hash(header_cids.block_number))
|
||||||
|
ORDER BY header_cids.block_number DESC LIMIT 1;
|
||||||
|
END IF;
|
||||||
|
RETURN QUERY SELECT t.cid, t.val, t.block_number, t.removed, t.state_leaf_removed
|
||||||
|
FROM tmp_tt_stg2 AS t LIMIT 1;
|
||||||
|
END
|
||||||
|
$$;
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
-- Name: has_child(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
||||||
--
|
--
|
||||||
@ -224,16 +314,32 @@ $$;
|
|||||||
-- Name: was_state_leaf_removed(character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
|
-- 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
|
CREATE FUNCTION public.was_state_leaf_removed(v_key character varying, v_hash character varying) RETURNS boolean
|
||||||
LANGUAGE sql
|
LANGUAGE sql
|
||||||
AS $$
|
AS $$
|
||||||
SELECT state_cids.removed = true
|
SELECT state_cids.removed = true
|
||||||
FROM eth.state_cids
|
FROM eth.state_cids
|
||||||
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
WHERE state_leaf_key = key
|
WHERE state_leaf_key = v_key
|
||||||
AND state_cids.block_number <= (SELECT block_number
|
AND state_cids.block_number <= (SELECT block_number
|
||||||
FROM eth.header_cids
|
FROM eth.header_cids
|
||||||
WHERE block_hash = hash)
|
WHERE block_hash = v_hash)
|
||||||
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
|
||||||
|
--
|
||||||
|
-- Name: was_state_leaf_removed_by_number(character varying, bigint); Type: FUNCTION; Schema: public; Owner: -
|
||||||
|
--
|
||||||
|
|
||||||
|
CREATE FUNCTION public.was_state_leaf_removed_by_number(v_key character varying, v_block_no bigint) RETURNS boolean
|
||||||
|
LANGUAGE sql
|
||||||
|
AS $$
|
||||||
|
SELECT state_cids.removed = true
|
||||||
|
FROM eth.state_cids
|
||||||
|
INNER JOIN eth.header_cids ON (state_cids.header_id = header_cids.block_hash)
|
||||||
|
WHERE state_leaf_key = v_key
|
||||||
|
AND state_cids.block_number <= v_block_no
|
||||||
ORDER BY state_cids.block_number DESC LIMIT 1;
|
ORDER BY state_cids.block_number DESC LIMIT 1;
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user