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/00009_create_eth_storage_cids_table.sql b/db/migrations/00009_create_eth_storage_cids_table.sql index 12c15e9..a59efad 100644 --- a/db/migrations/00009_create_eth_storage_cids_table.sql +++ b/db/migrations/00009_create_eth_storage_cids_table.sql @@ -2,7 +2,7 @@ CREATE TABLE IF NOT EXISTS eth.storage_cids ( block_number BIGINT NOT NULL, header_id VARCHAR(66) NOT NULL, - state_path BYTEA NOT NULL, + state_leaf_key BYTEA NOT NULL, storage_leaf_key VARCHAR(66), cid TEXT NOT NULL, storage_path BYTEA NOT NULL, @@ -10,8 +10,8 @@ CREATE TABLE IF NOT EXISTS eth.storage_cids ( diff BOOLEAN NOT NULL DEFAULT FALSE, mh_key TEXT NOT NULL, FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, - PRIMARY KEY (storage_path, state_path, header_id) + FOREIGN KEY (state_leaf_key, header_id) REFERENCES eth.state_cids (state_leaf_key, header_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, + PRIMARY KEY (storage_path, state_leaf_key, header_id) ); -- +goose Down diff --git a/db/migrations/00014_create_cid_indexes.sql b/db/migrations/00014_create_cid_indexes.sql index 2624d40..3c08b16 100644 --- a/db/migrations/00014_create_cid_indexes.sql +++ b/db/migrations/00014_create_cid_indexes.sql @@ -36,7 +36,7 @@ CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type); -- storage node indexes CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number); -CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path); +CREATE INDEX storage_state_leaf_key_index ON eth.storage_cids USING btree (state_leaf_key); CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key); CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid); CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number); @@ -90,7 +90,7 @@ DROP INDEX eth.storage_header_id_index; DROP INDEX eth.storage_mh_block_number_index; DROP INDEX eth.storage_cid_index; DROP INDEX eth.storage_leaf_key_index; -DROP INDEX eth.storage_state_path_index; +DROP INDEX eth.storage_state_leaf_key_index; DROP INDEX eth.storage_block_number_index; -- state node indexes 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/00016_create_ipld_pk_constraint.sql b/db/post_batch_processing_migrations/00016_create_ipld_pk_constraint.sql deleted file mode 100644 index 29d04b4..0000000 --- a/db/post_batch_processing_migrations/00016_create_ipld_pk_constraint.sql +++ /dev/null @@ -1,7 +0,0 @@ --- +goose Up -ALTER TABLE public.blocks -ADD CONSTRAINT pk_public_blocks PRIMARY KEY (key, block_number); - --- +goose Down -ALTER TABLE public.blocks -DROP CONSTRAINT pk_public_blocks; diff --git a/db/post_batch_processing_migrations/00017_update_db_version.sql b/db/post_batch_processing_migrations/00017_update_db_version.sql deleted file mode 100644 index f969943..0000000 --- a/db/post_batch_processing_migrations/00017_update_db_version.sql +++ /dev/null @@ -1,8 +0,0 @@ --- +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()); - --- +goose Down -DELETE FROM public.db_version WHERE version = 'v3.0.0'; -INSERT INTO public.db_version (singleton, version) VALUES (true, 'v0.3.2') -ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v0.3.2', NOW()); diff --git a/db/post_batch_processing_migrations/00018_create_log_indexes.sql b/db/post_batch_processing_migrations/00018_create_log_indexes.sql deleted file mode 100644 index 260cfb2..0000000 --- a/db/post_batch_processing_migrations/00018_create_log_indexes.sql +++ /dev/null @@ -1,15 +0,0 @@ --- +goose Up -CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key); -CREATE INDEX block_number_index ON eth.header_cids USING brin (block_number); -CREATE INDEX header_block_hash_index ON eth.header_cids USING btree (block_hash); -CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id); -CREATE INDEX tx_tx_hash_index ON eth.transaction_cids USING btree (tx_hash); -CREATE INDEX log_cids_index ON eth.log_cids USING btree (rct_id, index); - --- +goose Down -DROP INDEX eth.log_cids_index; -DROP INDEX eth.tx_tx_hash_index; -DROP INDEX eth.tx_header_id_index; -DROP INDEX eth.header_block_hash_index; -DROP INDEX eth.block_number_index; -DROP INDEX eth.log_mh_index; diff --git a/db/post_batch_processing_migrations/00019_create_log_mhk_fk.sql b/db/post_batch_processing_migrations/00019_create_log_mhk_fk.sql deleted file mode 100644 index 6eacc3d..0000000 --- a/db/post_batch_processing_migrations/00019_create_log_mhk_fk.sql +++ /dev/null @@ -1,9 +0,0 @@ --- +goose Up -ALTER TABLE eth.log_cids -ADD CONSTRAINT fk_log_leaf_mh_key - FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - --- +goose Down -ALTER TABLE eth.log_cids -DROP CONSTRAINT fk_log_leaf_mh_key; diff --git a/db/post_batch_processing_migrations/00020_disable_log_indexes_and_drop_mhk_fk.sql b/db/post_batch_processing_migrations/00020_disable_log_indexes_and_drop_mhk_fk.sql deleted file mode 100644 index 115ad49..0000000 --- a/db/post_batch_processing_migrations/00020_disable_log_indexes_and_drop_mhk_fk.sql +++ /dev/null @@ -1,53 +0,0 @@ --- +goose Up -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.log_cids' -); -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.transaction_cids' -); -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.header_cids' -); - -ALTER TABLE eth.log_cids -DROP CONSTRAINT fk_log_leaf_mh_key; - --- +goose Down -ALTER TABLE eth.log_cids -ADD CONSTRAINT fk_log_leaf_mh_key - FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.header_cids' -); -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.transaction_cids' -); -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.log_cids' -); diff --git a/db/post_batch_processing_migrations/00021_reenable_and_drop_log_indexes.sql b/db/post_batch_processing_migrations/00021_reenable_and_drop_log_indexes.sql deleted file mode 100644 index 6f05115..0000000 --- a/db/post_batch_processing_migrations/00021_reenable_and_drop_log_indexes.sql +++ /dev/null @@ -1,53 +0,0 @@ --- +goose Up -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.header_cids' -); -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.transaction_cids' -); -UPDATE pg_index -SET indisready=true -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.log_cids' -); - -DROP INDEX eth.tx_header_id_index; -DROP INDEX eth.block_number_index; -DROP INDEX eth.log_mh_index; - --- +goose Down -CREATE INDEX log_mh_index ON eth.log_cids USING btree (leaf_mh_key); -CREATE INDEX block_number_index ON eth.header_cids USING brin (block_number); -CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id); - -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.log_cids' -); -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.transaction_cids' -); -UPDATE pg_index -SET indisready=false -WHERE indrelid = ( - SELECT oid - FROM pg_class - WHERE relname='eth.header_cids' -); diff --git a/db/post_batch_processing_migrations/00022_drop_non_unique_indexes.sql b/db/post_batch_processing_migrations/00022_drop_non_unique_indexes.sql deleted file mode 100644 index f43aa5a..0000000 --- a/db/post_batch_processing_migrations/00022_drop_non_unique_indexes.sql +++ /dev/null @@ -1,9 +0,0 @@ --- +goose Up -DROP INDEX eth.log_cids_index; -DROP INDEX eth.tx_tx_hash_index; -DROP INDEX eth.header_block_hash_index; - --- +goose Down -CREATE INDEX header_block_hash_index ON eth.header_cids USING btree (block_hash); -CREATE INDEX tx_tx_hash_index ON eth.transaction_cids USING btree (tx_hash); -CREATE INDEX log_cids_index ON eth.log_cids USING btree (rct_id, index); diff --git a/db/post_batch_processing_migrations/00023_create_pk_constraints_part1.sql b/db/post_batch_processing_migrations/00023_create_pk_constraints_part1.sql deleted file mode 100644 index 700d273..0000000 --- a/db/post_batch_processing_migrations/00023_create_pk_constraints_part1.sql +++ /dev/null @@ -1,25 +0,0 @@ --- +goose Up -ALTER TABLE public.nodes -ADD CONSTRAINT pk_public_nodes PRIMARY KEY (node_id); - -ALTER TABLE eth.header_cids -ADD CONSTRAINT pk_eth_header_cids PRIMARY KEY (block_hash); - -ALTER TABLE eth.uncle_cids -ADD CONSTRAINT pk_eth_uncle_cids PRIMARY KEY (block_hash); - -ALTER TABLE eth.transaction_cids -ADD CONSTRAINT pk_eth_transaction_cids PRIMARY KEY (tx_hash); - --- +goose Down -ALTER TABLE eth.transaction_cids -DROP CONSTRAINT pk_eth_transaction_cids; - -ALTER TABLE eth.uncle_cids -DROP CONSTRAINT pk_eth_uncle_cids; - -ALTER TABLE eth.header_cids -DROP CONSTRAINT pk_eth_header_cids; - -ALTER TABLE public.nodes -DROP CONSTRAINT pk_public_nodes; diff --git a/db/post_batch_processing_migrations/00024_create_pk_constraints_part2.sql b/db/post_batch_processing_migrations/00024_create_pk_constraints_part2.sql deleted file mode 100644 index 66ae071..0000000 --- a/db/post_batch_processing_migrations/00024_create_pk_constraints_part2.sql +++ /dev/null @@ -1,37 +0,0 @@ --- +goose Up -ALTER TABLE eth.receipt_cids -ADD CONSTRAINT pk_eth_receipt_cids PRIMARY KEY (tx_id); - -ALTER TABLE eth.access_list_elements -ADD CONSTRAINT pk_eth_access_list_elements PRIMARY KEY (tx_id, index); - -ALTER TABLE eth.log_cids -ADD CONSTRAINT pk_eth_log_cids PRIMARY KEY (rct_id, index); - -ALTER TABLE eth.state_cids -ADD CONSTRAINT pk_eth_state_cids PRIMARY KEY (state_path, header_id); - -ALTER TABLE eth.storage_cids -ADD CONSTRAINT pk_eth_storage_cids PRIMARY KEY (storage_path, state_path, header_id); - -ALTER TABLE eth.state_accounts -ADD CONSTRAINT pk_eth_state_accounts PRIMARY KEY (state_path, header_id); - --- +goose Down -ALTER TABLE eth.state_accounts -DROP CONSTRAINT pk_eth_state_accounts; - -ALTER TABLE eth.storage_cids -DROP CONSTRAINT pk_eth_storage_cids; - -ALTER TABLE eth.state_cids -DROP CONSTRAINT pk_eth_state_cids; - -ALTER TABLE eth.log_cids -DROP CONSTRAINT pk_eth_log_cids; - -ALTER TABLE eth.access_list_elements -DROP CONSTRAINT pk_eth_access_list_elements; - -ALTER TABLE eth.receipt_cids -DROP CONSTRAINT pk_eth_receipt_cids; diff --git a/db/post_batch_processing_migrations/00025_make_tables_logged.sql b/db/post_batch_processing_migrations/00025_make_tables_logged.sql deleted file mode 100644 index 9f73688..0000000 --- a/db/post_batch_processing_migrations/00025_make_tables_logged.sql +++ /dev/null @@ -1,25 +0,0 @@ --- +goose Up -ALTER TABLE public.blocks SET LOGGED; -ALTER TABLE public.nodes SET LOGGED; -ALTER TABLE eth.header_cids SET LOGGED; -ALTER TABLE eth.uncle_cids SET LOGGED; -ALTER TABLE eth.transaction_cids SET LOGGED; -ALTER TABLE eth.receipt_cids SET LOGGED; -ALTER TABLE eth.state_cids SET LOGGED; -ALTER TABLE eth.storage_cids SET LOGGED; -ALTER TABLE eth.state_accounts SET LOGGED; -ALTER TABLE eth.access_list_elements SET LOGGED; -ALTER TABLE eth.log_cids SET LOGGED; - --- +goose Down -ALTER TABLE public.blocks SET UNLOGGED; -ALTER TABLE public.nodes SET UNLOGGED; -ALTER TABLE eth.header_cids SET UNLOGGED; -ALTER TABLE eth.uncle_cids SET UNLOGGED; -ALTER TABLE eth.transaction_cids SET UNLOGGED; -ALTER TABLE eth.receipt_cids SET UNLOGGED; -ALTER TABLE eth.state_cids SET UNLOGGED; -ALTER TABLE eth.storage_cids SET UNLOGGED; -ALTER TABLE eth.state_accounts SET UNLOGGED; -ALTER TABLE eth.access_list_elements SET UNLOGGED; -ALTER TABLE eth.log_cids SET UNLOGGED; diff --git a/db/post_batch_processing_migrations/00026_create_fk_relations.sql b/db/post_batch_processing_migrations/00026_create_fk_relations.sql deleted file mode 100644 index 1f5a54a..0000000 --- a/db/post_batch_processing_migrations/00026_create_fk_relations.sql +++ /dev/null @@ -1,129 +0,0 @@ --- +goose Up -ALTER TABLE eth.header_cids -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) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.uncle_cids -ADD CONSTRAINT fk_uncle_header_id - FOREIGN KEY (header_id) REFERENCES eth.header_cids (block_hash) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.transaction_cids -ADD CONSTRAINT fk_tx_mh_key - FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.transaction_cids -ADD CONSTRAINT fk_tx_header_id - FOREIGN KEY (header_id) REFERENCES eth.header_cids (block_hash) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.receipt_cids -ADD CONSTRAINT fk_rct_leaf_mh_key - FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.receipt_cids -ADD CONSTRAINT fk_rct_tx_id - FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids (tx_hash) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.state_cids -ADD CONSTRAINT fk_state_mh_key - FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.state_cids -ADD CONSTRAINT fk_state_header_id - FOREIGN KEY (header_id) REFERENCES eth.header_cids (block_hash) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.storage_cids -ADD CONSTRAINT fk_storage_mh_key - FOREIGN KEY (mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.storage_cids -ADD CONSTRAINT fk_storage_header_id_state_path - FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.state_accounts -ADD CONSTRAINT fk_account_header_id_state_path - FOREIGN KEY (state_path, header_id) REFERENCES eth.state_cids (state_path, header_id) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.access_list_elements -ADD CONSTRAINT fk_access_list_tx_id - FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids (tx_hash) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.log_cids -ADD CONSTRAINT fk_log_leaf_mh_key - FOREIGN KEY (leaf_mh_key, block_number) REFERENCES public.blocks (key, block_number) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - -ALTER TABLE eth.log_cids -ADD CONSTRAINT fk_log_rct_id - FOREIGN KEY (rct_id) REFERENCES eth.receipt_cids (tx_id) - ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; - --- +goose Down -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; - -ALTER TABLE eth.uncle_cids -DROP CONSTRAINT fk_uncle_header_id; - -ALTER TABLE eth.transaction_cids -DROP CONSTRAINT fk_tx_mh_key; - -ALTER TABLE eth.transaction_cids -DROP CONSTRAINT fk_tx_header_id; - -ALTER TABLE eth.receipt_cids -DROP CONSTRAINT fk_rct_leaf_mh_key; - -ALTER TABLE eth.receipt_cids -DROP CONSTRAINT fk_rct_tx_id; - -ALTER TABLE eth.state_cids -DROP CONSTRAINT fk_state_mh_key; - -ALTER TABLE eth.state_cids -DROP CONSTRAINT fk_state_header_id; - -ALTER TABLE eth.storage_cids -DROP CONSTRAINT fk_storage_mh_key; - -ALTER TABLE eth.storage_cids -DROP CONSTRAINT fk_storage_header_id_state_path; - -ALTER TABLE eth.state_accounts -DROP CONSTRAINT fk_account_header_id_state_path; - -ALTER TABLE eth.access_list_elements -DROP CONSTRAINT fk_access_list_tx_id; - -ALTER TABLE eth.log_cids -DROP CONSTRAINT fk_log_leaf_mh_key; - -ALTER TABLE eth.log_cids -DROP CONSTRAINT fk_log_rct_id; diff --git a/db/post_batch_processing_migrations/00027_create_postgraphile_comments.sql b/db/post_batch_processing_migrations/00027_create_postgraphile_comments.sql deleted file mode 100644 index f3ce2e6..0000000 --- a/db/post_batch_processing_migrations/00027_create_postgraphile_comments.sql +++ /dev/null @@ -1,14 +0,0 @@ --- +goose Up -COMMENT ON TABLE public.nodes IS E'@name NodeInfo'; -COMMENT ON TABLE eth.transaction_cids IS E'@name EthTransactionCids'; -COMMENT ON TABLE eth.header_cids IS E'@name EthHeaderCids'; -COMMENT ON COLUMN public.nodes.node_id IS E'@name ChainNodeID'; -COMMENT ON COLUMN eth.header_cids.node_id IS E'@name EthNodeID'; - --- +goose Down - -COMMENT ON TABLE public.nodes IS NULL; -COMMENT ON TABLE eth.transaction_cids IS NULL; -COMMENT ON TABLE eth.header_cids IS NULL; -COMMENT ON COLUMN public.nodes.node_id IS NULL; -COMMENT ON COLUMN eth.header_cids.node_id IS NULL; \ No newline at end of file diff --git a/db/post_batch_processing_migrations/00028_create_cid_indexes.sql b/db/post_batch_processing_migrations/00028_create_cid_indexes.sql deleted file mode 100644 index 2624d40..0000000 --- a/db/post_batch_processing_migrations/00028_create_cid_indexes.sql +++ /dev/null @@ -1,129 +0,0 @@ --- +goose Up --- header indexes -CREATE INDEX header_block_number_index ON eth.header_cids USING brin (block_number); -CREATE UNIQUE INDEX header_cid_index ON eth.header_cids USING btree (cid); -CREATE UNIQUE INDEX header_mh_block_number_index ON eth.header_cids USING btree (mh_key, block_number); -CREATE INDEX state_root_index ON eth.header_cids USING btree (state_root); -CREATE INDEX timestamp_index ON eth.header_cids USING brin (timestamp); - --- uncle indexes -CREATE INDEX uncle_block_number_index ON eth.uncle_cids USING brin (block_number); -CREATE UNIQUE INDEX uncle_mh_block_number_index ON eth.uncle_cids USING btree (mh_key, block_number); -CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id); - --- transaction indexes -CREATE INDEX tx_block_number_index ON eth.transaction_cids USING brin (block_number); -CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id); -CREATE UNIQUE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid); -CREATE UNIQUE 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_src_index ON eth.transaction_cids USING btree (src); - --- receipt indexes -CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number); -CREATE INDEX rct_leaf_cid_index ON eth.receipt_cids USING btree (leaf_cid); -CREATE INDEX rct_leaf_mh_block_number_index ON eth.receipt_cids USING btree (leaf_mh_key, block_number); -CREATE INDEX rct_contract_index ON eth.receipt_cids USING btree (contract); -CREATE INDEX rct_contract_hash_index ON eth.receipt_cids USING btree (contract_hash); - --- state node indexes -CREATE INDEX state_block_number_index ON eth.state_cids USING brin (block_number); -CREATE INDEX state_leaf_key_index ON eth.state_cids USING btree (state_leaf_key); -CREATE INDEX state_cid_index ON eth.state_cids USING btree (cid); -CREATE INDEX state_mh_block_number_index ON eth.state_cids USING btree (mh_key, block_number); -CREATE INDEX state_header_id_index ON eth.state_cids USING btree (header_id); -CREATE INDEX state_node_type_index ON eth.state_cids USING btree (node_type); - --- storage node indexes -CREATE INDEX storage_block_number_index ON eth.storage_cids USING brin (block_number); -CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_path); -CREATE INDEX storage_leaf_key_index ON eth.storage_cids USING btree (storage_leaf_key); -CREATE INDEX storage_cid_index ON eth.storage_cids USING btree (cid); -CREATE INDEX storage_mh_block_number_index ON eth.storage_cids USING btree (mh_key, block_number); -CREATE INDEX storage_header_id_index ON eth.storage_cids USING btree (header_id); -CREATE INDEX storage_node_type_index ON eth.storage_cids USING btree (node_type); - --- state accounts indexes -CREATE INDEX account_block_number_index ON eth.state_accounts USING brin (block_number); -CREATE INDEX account_header_id_index ON eth.state_accounts USING btree (header_id); -CREATE INDEX account_storage_root_index ON eth.state_accounts USING btree (storage_root); - --- access list indexes -CREATE INDEX access_list_block_number_index ON eth.access_list_elements USING brin (block_number); -CREATE INDEX access_list_element_address_index ON eth.access_list_elements USING btree (address); -CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys); - --- log indexes -CREATE INDEX log_block_number_index ON eth.log_cids USING brin (block_number); -CREATE INDEX log_leaf_mh_block_number_index ON eth.log_cids USING btree (leaf_mh_key, block_number); -CREATE INDEX log_cid_index ON eth.log_cids USING btree (leaf_cid); -CREATE INDEX log_address_index ON eth.log_cids USING btree (address); -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_topic2_index ON eth.log_cids USING btree (topic2); -CREATE INDEX log_topic3_index ON eth.log_cids USING btree (topic3); - --- +goose Down --- log indexes -DROP INDEX eth.log_topic3_index; -DROP INDEX eth.log_topic2_index; -DROP INDEX eth.log_topic1_index; -DROP INDEX eth.log_topic0_index; -DROP INDEX eth.log_address_index; -DROP INDEX eth.log_cid_index; -DROP INDEX eth.log_leaf_mh_block_number_index; -DROP INDEX eth.log_block_number_index; - --- access list indexes -DROP INDEX eth.access_list_storage_keys_index; -DROP INDEX eth.access_list_element_address_index; -DROP INDEX eth.access_list_block_number_index; - --- state account indexes -DROP INDEX eth.account_storage_root_index; -DROP index eth.account_header_id_index; -DROP INDEX eth.account_block_number_index; - --- storage node indexes -DROP INDEX eth.storage_node_type_index; -DROP INDEX eth.storage_header_id_index; -DROP INDEX eth.storage_mh_block_number_index; -DROP INDEX eth.storage_cid_index; -DROP INDEX eth.storage_leaf_key_index; -DROP INDEX eth.storage_state_path_index; -DROP INDEX eth.storage_block_number_index; - --- state node indexes -DROP INDEX eth.state_node_type_index; -DROP INDEX eth.state_header_id_index; -DROP INDEX eth.state_mh_block_number_index; -DROP INDEX eth.state_cid_index; -DROP INDEX eth.state_leaf_key_index; -DROP INDEX eth.state_block_number_index; - --- receipt indexes -DROP INDEX eth.rct_contract_hash_index; -DROP INDEX eth.rct_contract_index; -DROP INDEX eth.rct_leaf_mh_block_number_index; -DROP INDEX eth.rct_leaf_cid_index; -DROP INDEX eth.rct_block_number_index; - --- transaction indexes -DROP INDEX eth.tx_src_index; -DROP INDEX eth.tx_dst_index; -DROP INDEX eth.tx_mh_block_number_index; -DROP INDEX eth.tx_cid_index; -DROP INDEX eth.tx_header_id_index; -DROP INDEX eth.tx_block_number_index; - --- uncle indexes -DROP INDEX eth.uncle_block_number_index; -DROP INDEX eth.uncle_mh_block_number_index; -DROP INDEX eth.uncle_header_id_index; - --- header indexes -DROP INDEX eth.timestamp_index; -DROP INDEX eth.state_root_index; -DROP INDEX eth.header_mh_block_number_index; -DROP INDEX eth.header_cid_index; -DROP INDEX eth.header_block_number_index; diff --git a/db/post_batch_processing_migrations/00029_create_stored_functions.sql b/db/post_batch_processing_migrations/00029_create_stored_functions.sql deleted file mode 100644 index dc63fe0..0000000 --- a/db/post_batch_processing_migrations/00029_create_stored_functions.sql +++ /dev/null @@ -1,251 +0,0 @@ --- +goose Up --- +goose StatementBegin --- returns if a state leaf node was removed within the provided block number -CREATE OR REPLACE FUNCTION was_state_leaf_removed(key character varying, hash character varying) - RETURNS boolean 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; -$$ -language sql; --- +goose StatementEnd - --- +goose StatementBegin -CREATE TYPE child_result AS ( - has_child BOOLEAN, - children eth.header_cids[] -); - - -CREATE OR REPLACE FUNCTION has_child(hash VARCHAR(66), height BIGINT) RETURNS child_result AS -$BODY$ -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 -$BODY$ -LANGUAGE 'plpgsql'; --- +goose StatementEnd - --- +goose StatementBegin -CREATE OR REPLACE FUNCTION canonical_header_from_array(headers eth.header_cids[]) RETURNS eth.header_cids AS -$BODY$ -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 -$BODY$ -LANGUAGE 'plpgsql'; --- +goose StatementEnd - --- +goose StatementBegin -CREATE OR REPLACE FUNCTION canonical_header_hash(height BIGINT) RETURNS character varying AS -$BODY$ -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; -$BODY$ -LANGUAGE 'plpgsql'; --- +goose StatementEnd - --- +goose StatementBegin -CREATE TYPE state_node_result AS ( - data BYTEA, - state_leaf_key VARCHAR(66), - cid TEXT, - state_path BYTEA, - node_type INTEGER, - mh_key TEXT -); --- +goose StatementEnd - --- +goose StatementBegin -CREATE OR REPLACE FUNCTION state_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS -$BODY$ -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, that is not a - -- "removed" node-type entry - 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 - 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 - 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 -$BODY$ -LANGUAGE 'plpgsql'; --- +goose StatementEnd - --- +goose StatementBegin -CREATE TYPE storage_node_result AS ( - data BYTEA, - state_path BYTEA, - storage_leaf_key VARCHAR(66), - cid TEXT, - storage_path BYTEA, - node_type INTEGER, - mh_key TEXT -); --- +goose StatementEnd - --- +goose StatementBegin --- this should only be ran after a state_snapshot has been completed --- this should probably be rolled together with state_snapshot into a single procedure... -CREATE OR REPLACE FUNCTION storage_snapshot(starting_height BIGINT, ending_height BIGINT) RETURNS void AS -$BODY$ -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 path, that is not a - -- "removed" node-type entry - SELECT DISTINCT ON (state_path, 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) - 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 - 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 -$BODY$ -LANGUAGE 'plpgsql'; --- +goose StatementEnd - --- +goose Down -DROP FUNCTION storage_snapshot; -DROP TYPE storage_node_result; -DROP FUNCTION state_snapshot; -DROP TYPE state_node_result; -DROP FUNCTION was_state_leaf_removed; -DROP FUNCTION canonical_header_hash; -DROP FUNCTION canonical_header_from_array; -DROP FUNCTION has_child; -DROP TYPE child_result; diff --git a/db/post_batch_processing_migrations/00030_create_postgraphile_triggers.sql b/db/post_batch_processing_migrations/00030_create_postgraphile_triggers.sql deleted file mode 100644 index 097d0b3..0000000 --- a/db/post_batch_processing_migrations/00030_create_postgraphile_triggers.sql +++ /dev/null @@ -1,116 +0,0 @@ --- +goose Up --- Name: graphql_subscription(); Type: FUNCTION; Schema: eth; Owner: - - --- +goose StatementBegin -CREATE FUNCTION eth.graphql_subscription() RETURNS TRIGGER AS $$ -DECLARE -obj jsonb; -BEGIN - IF (TG_TABLE_NAME = 'state_cids') OR (TG_TABLE_NAME = 'state_accounts') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.header_id, - NEW.state_path - ); - ELSIF (TG_TABLE_NAME = 'storage_cids') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.header_id, - NEW.state_path, - NEW.storage_path - ); - ELSIF (TG_TABLE_NAME = 'log_cids')w THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.rct_id, - NEW.index - ); - ELSIF (TG_TABLE_NAME = 'receipt_cids') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.tx_id - ); - ELSIF (TG_TABLE_NAME = 'transaction_cids') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.tx_hash - ); - ELSIF (TG_TABLE_NAME = 'access_list_elements') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.tx_id, - NEW.index - ); - ELSIF (TG_TABLE_NAME = 'uncle_cids') OR (TG_TABLE_NAME = 'header_cids') THEN - obj := json_build_array( - TG_TABLE_NAME, - NEW.block_hash - ); -END IF; - - perform pg_notify('postgraphile:' || TG_RELNAME , json_build_object( - '__node__', obj - )::text - ); -RETURN NEW; -END; -$$ language plpgsql; --- +goose StatementEnd - -CREATE TRIGGER trg_eth_header_cids - AFTER INSERT ON eth.header_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_uncle_cids - AFTER INSERT ON eth.uncle_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_transaction_cids - AFTER INSERT ON eth.transaction_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_receipt_cids - AFTER INSERT ON eth.receipt_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_state_cids - AFTER INSERT ON eth.state_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_log_cids - AFTER INSERT ON eth.log_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_storage_cids - AFTER INSERT ON eth.storage_cids - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_state_accounts - AFTER INSERT ON eth.state_accounts - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - -CREATE TRIGGER trg_eth_access_list_elements - AFTER INSERT ON eth.access_list_elements - FOR EACH ROW - EXECUTE PROCEDURE eth.graphql_subscription(); - --- +goose Down -DROP TRIGGER trg_eth_uncle_cids ON eth.uncle_cids; -DROP TRIGGER trg_eth_transaction_cids ON eth.transaction_cids; -DROP TRIGGER trg_eth_storage_cids ON eth.storage_cids; -DROP TRIGGER trg_eth_state_cids ON eth.state_cids; -DROP TRIGGER trg_eth_state_accounts ON eth.state_accounts; -DROP TRIGGER trg_eth_receipt_cids ON eth.receipt_cids; -DROP TRIGGER trg_eth_header_cids ON eth.header_cids; -DROP TRIGGER trg_eth_log_cids ON eth.log_cids; -DROP TRIGGER trg_eth_access_list_elements ON eth.access_list_elements; - -DROP FUNCTION eth.graphql_subscription(); \ No newline at end of file diff --git a/db/pre_batch_processing_migrations/00001_create_ipfs_blocks_table.sql b/db/pre_batch_processing_migrations/00001_create_ipfs_blocks_table.sql deleted file mode 100644 index b3abc69..0000000 --- a/db/pre_batch_processing_migrations/00001_create_ipfs_blocks_table.sql +++ /dev/null @@ -1,9 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS public.blocks ( - block_number BIGINT NOT NULL, - key TEXT NOT NULL, - data BYTEA NOT NULL -); - --- +goose Down -DROP TABLE public.blocks; diff --git a/db/pre_batch_processing_migrations/00002_create_nodes_table.sql b/db/pre_batch_processing_migrations/00002_create_nodes_table.sql deleted file mode 100644 index f56c14b..0000000 --- a/db/pre_batch_processing_migrations/00002_create_nodes_table.sql +++ /dev/null @@ -1,11 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS nodes ( - genesis_block VARCHAR(66), - network_id VARCHAR, - node_id VARCHAR(128) NOT NULL, - client_name VARCHAR, - chain_id INTEGER DEFAULT 1 -); - --- +goose Down -DROP TABLE nodes; diff --git a/db/pre_batch_processing_migrations/00003_create_eth_schema.sql b/db/pre_batch_processing_migrations/00003_create_eth_schema.sql deleted file mode 100644 index 84d6f4b..0000000 --- a/db/pre_batch_processing_migrations/00003_create_eth_schema.sql +++ /dev/null @@ -1,5 +0,0 @@ --- +goose Up -CREATE SCHEMA eth; - --- +goose Down -DROP SCHEMA eth; \ No newline at end of file diff --git a/db/pre_batch_processing_migrations/00004_create_eth_header_cids_table.sql b/db/pre_batch_processing_migrations/00004_create_eth_header_cids_table.sql deleted file mode 100644 index 972719d..0000000 --- a/db/pre_batch_processing_migrations/00004_create_eth_header_cids_table.sql +++ /dev/null @@ -1,22 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.header_cids ( - block_number BIGINT NOT NULL, - block_hash VARCHAR(66) NOT NULL, - parent_hash VARCHAR(66) NOT NULL, - cid TEXT NOT NULL, - td NUMERIC NOT NULL, - node_id VARCHAR(128) NOT NULL, - reward NUMERIC NOT NULL, - state_root VARCHAR(66) NOT NULL, - tx_root VARCHAR(66) NOT NULL, - receipt_root VARCHAR(66) NOT NULL, - uncle_root VARCHAR(66) NOT NULL, - bloom BYTEA NOT NULL, - timestamp BIGINT NOT NULL, - mh_key TEXT NOT NULL, - times_validated INTEGER NOT NULL DEFAULT 1, - coinbase VARCHAR(66) NOT NULL -); - --- +goose Down -DROP TABLE eth.header_cids; diff --git a/db/pre_batch_processing_migrations/00005_create_eth_uncle_cids_table.sql b/db/pre_batch_processing_migrations/00005_create_eth_uncle_cids_table.sql deleted file mode 100644 index c8d4707..0000000 --- a/db/pre_batch_processing_migrations/00005_create_eth_uncle_cids_table.sql +++ /dev/null @@ -1,13 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.uncle_cids ( - block_number BIGINT NOT NULL, - block_hash VARCHAR(66) NOT NULL, - header_id VARCHAR(66) NOT NULL, - parent_hash VARCHAR(66) NOT NULL, - cid TEXT NOT NULL, - reward NUMERIC NOT NULL, - mh_key TEXT NOT NULL -); - --- +goose Down -DROP TABLE eth.uncle_cids; diff --git a/db/pre_batch_processing_migrations/00006_create_eth_transaction_cids_table.sql b/db/pre_batch_processing_migrations/00006_create_eth_transaction_cids_table.sql deleted file mode 100644 index c7e0163..0000000 --- a/db/pre_batch_processing_migrations/00006_create_eth_transaction_cids_table.sql +++ /dev/null @@ -1,17 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.transaction_cids ( - block_number BIGINT NOT NULL, - header_id VARCHAR(66) NOT NULL, - tx_hash VARCHAR(66) NOT NULL, - cid TEXT NOT NULL, - dst VARCHAR(66) NOT NULL, - src VARCHAR(66) NOT NULL, - index INTEGER NOT NULL, - mh_key TEXT NOT NULL, - tx_data BYTEA, - tx_type INTEGER, - value NUMERIC -); - --- +goose Down -DROP TABLE eth.transaction_cids; diff --git a/db/pre_batch_processing_migrations/00007_create_eth_receipt_cids_table.sql b/db/pre_batch_processing_migrations/00007_create_eth_receipt_cids_table.sql deleted file mode 100644 index fb66ea9..0000000 --- a/db/pre_batch_processing_migrations/00007_create_eth_receipt_cids_table.sql +++ /dev/null @@ -1,15 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.receipt_cids ( - block_number BIGINT NOT NULL, - tx_id VARCHAR(66) NOT NULL, - leaf_cid TEXT NOT NULL, - contract VARCHAR(66), - contract_hash VARCHAR(66), - leaf_mh_key TEXT NOT NULL, - post_state VARCHAR(66), - post_status INTEGER, - log_root VARCHAR(66) -); - --- +goose Down -DROP TABLE eth.receipt_cids; diff --git a/db/pre_batch_processing_migrations/00008_create_eth_state_cids_table.sql b/db/pre_batch_processing_migrations/00008_create_eth_state_cids_table.sql deleted file mode 100644 index bf8214f..0000000 --- a/db/pre_batch_processing_migrations/00008_create_eth_state_cids_table.sql +++ /dev/null @@ -1,14 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.state_cids ( - block_number BIGINT NOT NULL, - header_id VARCHAR(66) NOT NULL, - state_leaf_key VARCHAR(66), - cid TEXT NOT NULL, - state_path BYTEA NOT NULL, - node_type INTEGER NOT NULL, - diff BOOLEAN NOT NULL DEFAULT FALSE, - mh_key TEXT NOT NULL -); - --- +goose Down -DROP TABLE eth.state_cids; diff --git a/db/pre_batch_processing_migrations/00009_create_eth_storage_cids_table.sql b/db/pre_batch_processing_migrations/00009_create_eth_storage_cids_table.sql deleted file mode 100644 index 7ddb8c6..0000000 --- a/db/pre_batch_processing_migrations/00009_create_eth_storage_cids_table.sql +++ /dev/null @@ -1,15 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.storage_cids ( - block_number BIGINT NOT NULL, - header_id VARCHAR(66) NOT NULL, - state_path BYTEA NOT NULL, - storage_leaf_key VARCHAR(66), - cid TEXT NOT NULL, - storage_path BYTEA NOT NULL, - node_type INTEGER NOT NULL, - diff BOOLEAN NOT NULL DEFAULT FALSE, - mh_key TEXT NOT NULL -); - --- +goose Down -DROP TABLE eth.storage_cids; diff --git a/db/pre_batch_processing_migrations/00010_create_eth_state_accounts_table.sql b/db/pre_batch_processing_migrations/00010_create_eth_state_accounts_table.sql deleted file mode 100644 index 51745dc..0000000 --- a/db/pre_batch_processing_migrations/00010_create_eth_state_accounts_table.sql +++ /dev/null @@ -1,13 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.state_accounts ( - block_number BIGINT NOT NULL, - header_id VARCHAR(66) NOT NULL, - state_path BYTEA NOT NULL, - balance NUMERIC NOT NULL, - nonce BIGINT NOT NULL, - code_hash BYTEA NOT NULL, - storage_root VARCHAR(66) NOT NULL -); - --- +goose Down -DROP TABLE eth.state_accounts; diff --git a/db/pre_batch_processing_migrations/00011_create_eth_access_list_elements_table.sql b/db/pre_batch_processing_migrations/00011_create_eth_access_list_elements_table.sql deleted file mode 100644 index fdfd157..0000000 --- a/db/pre_batch_processing_migrations/00011_create_eth_access_list_elements_table.sql +++ /dev/null @@ -1,11 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.access_list_elements ( - block_number BIGINT NOT NULL, - tx_id VARCHAR(66) NOT NULL, - index INTEGER NOT NULL, - address VARCHAR(66), - storage_keys VARCHAR(66)[] -); - --- +goose Down -DROP TABLE eth.access_list_elements; diff --git a/db/pre_batch_processing_migrations/00012_create_eth_log_cids_table.sql b/db/pre_batch_processing_migrations/00012_create_eth_log_cids_table.sql deleted file mode 100644 index be89ec0..0000000 --- a/db/pre_batch_processing_migrations/00012_create_eth_log_cids_table.sql +++ /dev/null @@ -1,18 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS eth.log_cids ( - block_number BIGINT NOT NULL, - leaf_cid TEXT NOT NULL, - leaf_mh_key TEXT NOT NULL, - rct_id VARCHAR(66) NOT NULL, - address VARCHAR(66) NOT NULL, - index INTEGER NOT NULL, - topic0 VARCHAR(66), - topic1 VARCHAR(66), - topic2 VARCHAR(66), - topic3 VARCHAR(66), - log_data BYTEA -); - --- +goose Down --- log indexes -DROP TABLE eth.log_cids; diff --git a/db/pre_batch_processing_migrations/00013_make_tables_unlogged.sql b/db/pre_batch_processing_migrations/00013_make_tables_unlogged.sql deleted file mode 100644 index f56a409..0000000 --- a/db/pre_batch_processing_migrations/00013_make_tables_unlogged.sql +++ /dev/null @@ -1,25 +0,0 @@ --- +goose Up -ALTER TABLE public.blocks SET UNLOGGED; -ALTER TABLE public.nodes SET UNLOGGED; -ALTER TABLE eth.header_cids SET UNLOGGED; -ALTER TABLE eth.uncle_cids SET UNLOGGED; -ALTER TABLE eth.transaction_cids SET UNLOGGED; -ALTER TABLE eth.receipt_cids SET UNLOGGED; -ALTER TABLE eth.state_cids SET UNLOGGED; -ALTER TABLE eth.storage_cids SET UNLOGGED; -ALTER TABLE eth.state_accounts SET UNLOGGED; -ALTER TABLE eth.access_list_elements SET UNLOGGED; -ALTER TABLE eth.log_cids SET UNLOGGED; - --- +goose Down -ALTER TABLE public.blocks SET LOGGED; -ALTER TABLE public.nodes SET LOGGED; -ALTER TABLE eth.header_cids SET LOGGED; -ALTER TABLE eth.uncle_cids SET LOGGED; -ALTER TABLE eth.transaction_cids SET LOGGED; -ALTER TABLE eth.receipt_cids SET LOGGED; -ALTER TABLE eth.state_cids SET LOGGED; -ALTER TABLE eth.storage_cids SET LOGGED; -ALTER TABLE eth.state_accounts SET LOGGED; -ALTER TABLE eth.access_list_elements SET LOGGED; -ALTER TABLE eth.log_cids SET LOGGED; diff --git a/db/pre_batch_processing_migrations/00014_create_eth_db_version_table.sql b/db/pre_batch_processing_migrations/00014_create_eth_db_version_table.sql deleted file mode 100644 index 2cf57e9..0000000 --- a/db/pre_batch_processing_migrations/00014_create_eth_db_version_table.sql +++ /dev/null @@ -1,9 +0,0 @@ --- +goose Up -CREATE TABLE IF NOT EXISTS public.db_version ( - singleton BOOLEAN NOT NULL DEFAULT TRUE UNIQUE CHECK (singleton), - version TEXT NOT NULL, - tstamp TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW() -); - --- +goose Down -DROP TABLE public.db_version; diff --git a/db/pre_batch_processing_migrations/00015_update_db_version.sql b/db/pre_batch_processing_migrations/00015_update_db_version.sql deleted file mode 100644 index 116acd9..0000000 --- a/db/pre_batch_processing_migrations/00015_update_db_version.sql +++ /dev/null @@ -1,6 +0,0 @@ --- +goose Up -INSERT INTO public.db_version (singleton, version) VALUES (true, 'v0.3.2') -ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v0.3.2', NOW()); - --- +goose Down -DELETE FROM public.db_version WHERE version = 'v0.3.2'; diff --git a/scripts/add_nodes.sh b/scripts/add_nodes.sh new file mode 100755 index 0000000..ed5dbed --- /dev/null +++ b/scripts/add_nodes.sh @@ -0,0 +1,138 @@ +#!/bin/bash +# Guards +if [ -z "$1" ] || [ -z "$2" ] || [ -z "$3" ] || [ -z "$4" ] || [ -z "$5" ] + then + echo "Env variables not provided" + echo "Usage: ./ipfs_postgres.sh " + echo "Only is optional" + exit 1 +fi +if [ -z "$6" ] + then + echo "EXECUTE_SQL not set, will not run statements against an access server" + else + echo "EXECUTE_SQL is set, will run stataments against an access server" + echo "Note: this mode is not recommended except in the case when the migration has already been applied with previous + nodes and we need/want to add more while still recording them in the existing migration (and adding their Down statements to said migration)" + echo "Expected environment variables:" + echo "DATABASE_HOSTNAME, DATABASE_NAME, DATABASE_PORT, DATABASE_USER" + echo "For now, DATABASE_PASSWORD will be prompted for on each psql call" +fi + +# Remote DB node info +export MIGRATION_FILE_PATH=$1 +export NODE_NAME=$2 +export NODE_HOST=$3 +export NODE_PORT=$4 +export NODE_DATABASE=$5 +printf "Enter the ${NODE_HOST} database password:\n" +stty -echo +read NODE_PASSWORD +stty echo +export NODE_PASSWORD + +if ! [ -z "$6" ] + then + # Access DB info + echo "heeeeey" + export DATABASE_HOSTNAME=localhost + export DATABASE_PORT=5432 + export DATABASE_USER=vdbm + export DATABASE_NAME=vulcanize_db +fi + +# Array of distributed hypertable names +declare -a tables_names=("public.blocks" "eth.header_cid" "eth.uncle_cids" "eth.transaction_cids" + "eth.receipt_cids" "eth.state_cid" "eth.storage_cids" "eth.state_accounts" + "eth.access_list_elements" "eth.log_cids" + ) +# Array to append Up statements to for later (optional) execution +declare -a up_stmts=() + +echo "Writing Up and Down statements to provided migration file at ${migration_file_path}" + +# Create add node statement +up_add_pg_str="SELECT add_data_node('${NODE_NAME}', host => '${NODE_HOST}', port => ${NODE_PORT}, database => '${NODE_DATABASE}', password => '${NODE_PASSWORD}');" +up_stmts+=(${up_add_pg_str}) + +# Insert at the 3rd line of the file +sed -i.bak '3 i\ +'"${up_add_pg_str}"' +' "${MIGRATION_FILE_PATH}" + +# Check for error +if [[ $? -eq 0 ]]; then + echo "Wrote Up add node statement ${up_add_pg_str}" +else + echo "Could not write Up add node statement ${up_add_pg_str}. Is the migration file path correct?" + exit 1 +fi + +# Create attach node statements +for table_name in "${tables_names[@]}" +do + up_attach_pg_str="SELECT attach_data_node('${NODE_NAME}', '${table_name}', if_not_attached => true);" + up_stmts+=(${up_attach_pg_str}) + # Insert at the 4th line of the file + sed -i.bak '4 i\ +'"${up_attach_pg_str}"' +' "${MIGRATION_FILE_PATH}" + # Check for error + if [[ $? -eq 0 ]]; then + echo "Wrote Up attach node statement ${up_attach_pg_str}" + else + echo "Could not write Up attach node statement ${up_attach_pg_str}. Is the migration file path correct?" + exit 1 + fi +done + +## Create detach and remove node statement +down_attach_pg_str="SELECT detach_data_node('${NODE_NAME}', force => true, if_attached = true);" +down_add_pg_str="SELECT delete_data_node('${NODE_NAME}', force => true, if_attached => true);" + +# Append them at the last line in the file +sed -i.bak '$ a\ +'"${down_attach_pg_str}"' +' "${MIGRATION_FILE_PATH}" +# Check for error +if [[ $? -eq 0 ]]; then + echo "Wrote Down attach node statement ${down_attach_pg_str}" +else + echo "Could not write Down attach node statement ${down_attach_pg_str}. Is the migration file path correct?" + exit 1 +fi +# Append them at the last line in the file +sed -i.bak '$ a\ +'"${down_add_pg_str}"' +' "${MIGRATION_FILE_PATH}" +# Check for error +if [[ $? -eq 0 ]]; then + echo "Wrote Down add node statement ${down_add_pg_str}" +else + echo "Could not write Down add node statement ${down_add_pg_str}. Is the migration file path correct?" + exit 1 +fi + +# Execute Up statements on the server if we are in that mode +if [ -z "$6" ] + then + echo "Done!" + exit 0 +fi + +echo "Executing Up statements against provided server" + +for up_stmt in "${up_stmts[@]}" +do + psql -c '\x' -c "${up_stmt}" -h $DATABASE_HOSTNAME -p $DATABASE_PORT -U $DATABASE_USER -d $DATABASE_NAME -W + # Check for error + if [[ $? -eq 0 ]]; then + echo "Executed Up statement ${up_stmt}}" + else + echo "Could not execute Up statement ${up_stmt}. Is the migration file path correct?" + exit 1 + fi +done + +echo "Done!" +exit 0