From 2816de15a30ce2784065ef334a03b4d31a7f1aaa Mon Sep 17 00:00:00 2001 From: i-norden Date: Wed, 6 Apr 2022 18:44:19 -0500 Subject: [PATCH] migrations for hypertables and distributed hypertables --- .../00004_create_eth_header_cids_table.sql | 2 +- .../00015_create_stored_functions.sql | 2 - db/migrations/00018_update_db_version.sql | 6 +- .../00019_convert_to_hypertables.sql | 67 +++++++++ ...020_convert_to_distributed_hypertables.sql | 128 ++++++++++++++++++ db/migrations/00021_add_data_nodes.sql | 5 + .../00026_create_fk_relations.sql | 8 -- 7 files changed, 204 insertions(+), 14 deletions(-) create mode 100644 db/migrations/00019_convert_to_hypertables.sql create mode 100644 db/migrations/00020_convert_to_distributed_hypertables.sql create mode 100644 db/migrations/00021_add_data_nodes.sql diff --git a/db/migrations/00004_create_eth_header_cids_table.sql b/db/migrations/00004_create_eth_header_cids_table.sql index 607b95a..eb2ed9a 100644 --- a/db/migrations/00004_create_eth_header_cids_table.sql +++ b/db/migrations/00004_create_eth_header_cids_table.sql @@ -5,7 +5,7 @@ CREATE TABLE IF NOT EXISTS eth.header_cids ( parent_hash VARCHAR(66) NOT NULL, cid TEXT NOT NULL, td NUMERIC NOT NULL, - node_id VARCHAR(128) NOT NULL REFERENCES nodes (node_id) ON DELETE CASCADE, + node_id VARCHAR(128) NOT NULL, reward NUMERIC NOT NULL, state_root VARCHAR(66) NOT NULL, tx_root VARCHAR(66) NOT NULL, diff --git a/db/migrations/00015_create_stored_functions.sql b/db/migrations/00015_create_stored_functions.sql index 75b23b9..51a04fd 100644 --- a/db/migrations/00015_create_stored_functions.sql +++ b/db/migrations/00015_create_stored_functions.sql @@ -163,7 +163,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 @@ -218,7 +217,6 @@ BEGIN INNER JOIN public.blocks ON (storage_cids.mh_key, storage_cids.block_number) = (blocks.key, blocks.block_number) 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 diff --git a/db/migrations/00018_update_db_version.sql b/db/migrations/00018_update_db_version.sql index 7b27829..7bf47f0 100644 --- a/db/migrations/00018_update_db_version.sql +++ b/db/migrations/00018_update_db_version.sql @@ -1,6 +1,6 @@ -- +goose Up -INSERT INTO public.db_version (singleton, version) VALUES (true, 'v3.0.0') -ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v3.0.0', NOW()); +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.0') +ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v4.0.0', NOW()); -- +goose Down -DELETE FROM public.db_version WHERE version = 'v3.0.0'; +DELETE FROM public.db_version WHERE version = 'v4.0.0'; diff --git a/db/migrations/00019_convert_to_hypertables.sql b/db/migrations/00019_convert_to_hypertables.sql new file mode 100644 index 0000000..a87f2c9 --- /dev/null +++ b/db/migrations/00019_convert_to_hypertables.sql @@ -0,0 +1,67 @@ +-- +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.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); +SELECT create_hypertable('eth.state_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.storage_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.state_accounts', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.access_list_elements', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.log_cids', 'block_number', migrate_data => true, chunk_time_interval => 32768); + +-- update version +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.0-h') + ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v4.0.0-h', NOW()); + +-- +goose Down +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.0') + ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v4.0.0', NOW()); +-- reversing conversion to hypertable requires migrating all data from every chunk back to a single table +-- create new regular tables +CREATE TABLE eth.log_cids_i (LIKE eth.log_cids INCLUDING ALL); +CREATE TABLE eth.access_list_elements_i (LIKE eth.access_list_elements INCLUDING ALL); +CREATE TABLE eth.state_accounts_i (LIKE eth.state_accounts INCLUDING ALL); +CREATE TABLE eth.storage_cids_i (LIKE eth.storage_cids INCLUDING ALL); +CREATE TABLE eth.state_cids_i (LIKE eth.state_cids INCLUDING ALL); +CREATE TABLE eth.receipt_cids_i (LIKE eth.receipt_cids INCLUDING ALL); +CREATE TABLE eth.transaction_cids_i (LIKE eth.transaction_cids INCLUDING ALL); +CREATE TABLE eth.uncle_cids_i (LIKE eth.uncle_cids INCLUDING ALL); +CREATE TABLE eth.header_cids_i (LIKE eth.header_cids INCLUDING ALL); +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); + +-- drops hypertables +DROP TABLE eth.log_cids; +DROP TABLE eth.access_list_elements; +DROP TABLE eth.state_accounts; +DROP TABLE eth.storage_cids; +DROP TABLE eth.state_cids; +DROP TABLE eth.receipt_cids; +DROP TABLE eth.transaction_cids; +DROP TABLE eth.uncle_cids; +DROP TABLE eth.header_cids; +DROP TABLE public.blocks; + +-- rename new tables +ALTER TABLE eth.log_cids_i RENAME TO eth.log_cids; +ALTER TABLE eth.access_list_elements_i RENAME TO eth.access_list_elements; +ALTER TABLE eth.state_accounts_i RENAME TO eth.state_accounts; +ALTER TABLE eth.storage_cids_i RENAME TO eth.storage_cids; +ALTER TABLE eth.state_cids_i RENAME TO eth.state_cids; +ALTER TABLE eth.receipt_cids_i RENAME TO eth.receipt_cids; +ALTER TABLE eth.transaction_cids_i RENAME TO eth.transaction_cids; +ALTER TABLE eth.uncle_cids_i RENAME TO eth.uncle_cids; +ALTER TABLE eth.header_cids_i RENAME TO eth.header_cids; +ALTER TABLE public.blocks_i RENAME TO public.blocks; diff --git a/db/migrations/00020_convert_to_distributed_hypertables.sql b/db/migrations/00020_convert_to_distributed_hypertables.sql new file mode 100644 index 0000000..8a6ba64 --- /dev/null +++ b/db/migrations/00020_convert_to_distributed_hypertables.sql @@ -0,0 +1,128 @@ +-- +goose Up +-- create new regular tables +CREATE TABLE eth.log_cids_i (LIKE eth.log_cids INCLUDING ALL); +CREATE TABLE eth.access_list_elements_i (LIKE eth.access_list_elements INCLUDING ALL); +CREATE TABLE eth.state_accounts_i (LIKE eth.state_accounts INCLUDING ALL); +CREATE TABLE eth.storage_cids_i (LIKE eth.storage_cids INCLUDING ALL); +CREATE TABLE eth.state_cids_i (LIKE eth.state_cids INCLUDING ALL); +CREATE TABLE eth.receipt_cids_i (LIKE eth.receipt_cids INCLUDING ALL); +CREATE TABLE eth.transaction_cids_i (LIKE eth.transaction_cids INCLUDING ALL); +CREATE TABLE eth.uncle_cids_i (LIKE eth.uncle_cids INCLUDING ALL); +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); + +-- 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); + +-- drops hypertables +DROP TABLE eth.log_cids; +DROP TABLE eth.access_list_elements; +DROP TABLE eth.state_accounts; +DROP TABLE eth.storage_cids; +DROP TABLE eth.state_cids; +DROP TABLE eth.receipt_cids; +DROP TABLE eth.transaction_cids; +DROP TABLE eth.uncle_cids; +DROP TABLE eth.header_cids; +DROP TABLE public.blocks; + +-- rename distributed hypertables +ALTER TABLE eth.log_cids_i RENAME TO eth.log_cids; +ALTER TABLE eth.access_list_elements_i RENAME TO eth.access_list_elements; +ALTER TABLE eth.state_accounts_i RENAME TO eth.state_accounts; +ALTER TABLE eth.storage_cids_i RENAME TO eth.storage_cids; +ALTER TABLE eth.state_cids_i RENAME TO eth.state_cids; +ALTER TABLE eth.receipt_cids_i RENAME TO eth.receipt_cids; +ALTER TABLE eth.transaction_cids_i RENAME TO eth.transaction_cids; +ALTER TABLE eth.uncle_cids_i RENAME TO eth.uncle_cids; +ALTER TABLE eth.header_cids_i RENAME TO eth.header_cids; +ALTER TABLE public.blocks_i RENAME TO public.blocks; + +-- update version +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.00-dh') + ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v4.0.0-dh', NOW()); + +-- +goose Down +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v4.0.0-h') + ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v4.0.0-h', NOW()); +-- reversing conversion to hypertable requires migrating all data from every chunk back to a single table +-- create new regular tables +CREATE TABLE eth.log_cids_i (LIKE eth.log_cids INCLUDING ALL); +CREATE TABLE eth.access_list_elements_i (LIKE eth.access_list_elements INCLUDING ALL); +CREATE TABLE eth.state_accounts_i (LIKE eth.state_accounts INCLUDING ALL); +CREATE TABLE eth.storage_cids_i (LIKE eth.storage_cids INCLUDING ALL); +CREATE TABLE eth.state_cids_i (LIKE eth.state_cids INCLUDING ALL); +CREATE TABLE eth.receipt_cids_i (LIKE eth.receipt_cids INCLUDING ALL); +CREATE TABLE eth.transaction_cids_i (LIKE eth.transaction_cids INCLUDING ALL); +CREATE TABLE eth.uncle_cids_i (LIKE eth.uncle_cids INCLUDING ALL); +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 hypertables +SELECT create_hypertable('public.blocks_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.header_cids_i', 'block_number' migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.uncle_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.transaction_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.receipt_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.state_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.storage_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.state_accounts_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.access_list_elements_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); +SELECT create_hypertable('eth.log_cids_i', 'block_number', migrate_data => true, chunk_time_interval => 32768); + +-- 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); + +-- drops distributed hypertables +DROP TABLE eth.log_cids; +DROP TABLE eth.access_list_elements; +DROP TABLE eth.state_accounts; +DROP TABLE eth.storage_cids; +DROP TABLE eth.state_cids; +DROP TABLE eth.receipt_cids; +DROP TABLE eth.transaction_cids; +DROP TABLE eth.uncle_cids; +DROP TABLE eth.header_cids; +DROP TABLE public.blocks; + +-- rename hypertable tables +ALTER TABLE eth.log_cids_i RENAME TO eth.log_cids; +ALTER TABLE eth.access_list_elements_i RENAME TO eth.access_list_elements; +ALTER TABLE eth.state_accounts_i RENAME TO eth.state_accounts; +ALTER TABLE eth.storage_cids_i RENAME TO eth.storage_cids; +ALTER TABLE eth.state_cids_i RENAME TO eth.state_cids; +ALTER TABLE eth.receipt_cids_i RENAME TO eth.receipt_cids; +ALTER TABLE eth.transaction_cids_i RENAME TO eth.transaction_cids; +ALTER TABLE eth.uncle_cids_i RENAME TO eth.uncle_cids; +ALTER TABLE eth.header_cids_i RENAME TO eth.header_cids; +ALTER TABLE public.blocks_i RENAME TO public.blocks; diff --git a/db/migrations/00021_add_data_nodes.sql b/db/migrations/00021_add_data_nodes.sql new file mode 100644 index 0000000..cd72039 --- /dev/null +++ b/db/migrations/00021_add_data_nodes.sql @@ -0,0 +1,5 @@ +-- +goose Up +-- this is generated by a script + +-- +goose Down +-- this is generated by a script diff --git a/db/post_batch_processing_migrations/00026_create_fk_relations.sql b/db/post_batch_processing_migrations/00026_create_fk_relations.sql index 1f5a54a..1dffa2d 100644 --- a/db/post_batch_processing_migrations/00026_create_fk_relations.sql +++ b/db/post_batch_processing_migrations/00026_create_fk_relations.sql @@ -4,11 +4,6 @@ ADD CONSTRAINT fk_header_mh_key FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; -ALTER TABLE eth.header_cids -ADD CONSTRAINT fk_header_node_id - FOREIGN KEY (node_id) REFERENCES public.nodes (node_id) - ON DELETE CASCADE; - ALTER TABLE eth.uncle_cids ADD CONSTRAINT fk_uncle_mh_key FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) @@ -83,9 +78,6 @@ ADD CONSTRAINT fk_log_rct_id ALTER TABLE eth.header_cids DROP CONSTRAINT fk_header_mh_key; -ALTER TABLE eth.header_cids -DROP CONSTRAINT fk_header_node_id; - ALTER TABLE eth.uncle_cids DROP CONSTRAINT fk_uncle_mh_key;