diff --git a/db/migrations/00022_create_stored_functions.sql b/db/migrations/00022_create_stored_functions.sql index 9b343cc..1aa42e9 100644 --- a/db/migrations/00022_create_stored_functions.sql +++ b/db/migrations/00022_create_stored_functions.sql @@ -155,26 +155,26 @@ BEGIN 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 + SELECT ARRAY (SELECT DISTINCT ON (state_path) ROW (blocks.data, state_cids.state_leaf_key, state_cids.cid, state_cids.state_path, + state_cids.node_type, state_cids.mh_key) 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; + ORDER BY state_path, state_cids.block_number DESC) + INTO results; -- 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 unnest(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; + FROM unnest(results) r + ON CONFLICT (state_path, header_id, block_number) DO NOTHING; END $BODY$ LANGUAGE 'plpgsql'; @@ -208,29 +208,29 @@ BEGIN 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 + SELECT ARRAY (SELECT DISTINCT ON (state_leaf_key, storage_path) ROW (blocks.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) 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; + ORDER BY state_leaf_key, storage_path, storage_cids.state_path, storage_cids.block_number DESC) + INTO results; -- 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 unnest(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; + FROM unnest(results) r + ON CONFLICT (storage_path, state_path, header_id, block_number) DO NOTHING; END $BODY$ LANGUAGE 'plpgsql';