diff --git a/Makefile b/Makefile index 58c532b..b486218 100644 --- a/Makefile +++ b/Makefile @@ -56,6 +56,12 @@ migrate: $(GOOSE) checkdbvars $(GOOSE) -dir db/migrations postgres "$(CONNECT_STRING)" up pg_dump -O -s $(CONNECT_STRING) > schema.sql +## Apply all migrations not already run, for the batch processing set +.PHONY: migrate_batch_set +migrate_batch_set: $(GOOSE) checkdbvars + $(GOOSE) -dir db/batch_process_migrations postgres "$(CONNECT_STRING)" up + pg_dump -O -s $(CONNECT_STRING) > schema.sql + ## Create a new migration file .PHONY: new_migration new_migration: $(GOOSE) checkmigname @@ -91,4 +97,4 @@ docker-concise-migration-build: .PHONY: test-migrations test-migrations: $(GOOSE) - ./scripts/test_migration.sh \ No newline at end of file + ./scripts/test_migration.sh diff --git a/db/batch_process_migrations/00001_create_ipfs_blocks_table.sql b/db/batch_process_migrations/00001_create_ipfs_blocks_table.sql index 4b017bc..2925d4d 100644 --- a/db/batch_process_migrations/00001_create_ipfs_blocks_table.sql +++ b/db/batch_process_migrations/00001_create_ipfs_blocks_table.sql @@ -1,6 +1,6 @@ -- +goose Up CREATE TABLE IF NOT EXISTS public.blocks ( - key TEXT PRIMARY KEY, + key TEXT NOT NULL, data BYTEA NOT NULL ); diff --git a/db/batch_process_migrations/00002_create_nodes_table.sql b/db/batch_process_migrations/00002_create_nodes_table.sql index 2a4ecdd..349363f 100644 --- a/db/batch_process_migrations/00002_create_nodes_table.sql +++ b/db/batch_process_migrations/00002_create_nodes_table.sql @@ -3,7 +3,7 @@ CREATE TABLE nodes ( client_name VARCHAR, genesis_block VARCHAR(66), network_id VARCHAR, - node_id VARCHAR(128) PRIMARY KEY, + node_id VARCHAR(128) NOT NULL, chain_id INTEGER DEFAULT 1 ); diff --git a/db/batch_process_migrations/00004_create_eth_header_cids_table.sql b/db/batch_process_migrations/00004_create_eth_header_cids_table.sql index 6754c7e..002ac5b 100644 --- a/db/batch_process_migrations/00004_create_eth_header_cids_table.sql +++ b/db/batch_process_migrations/00004_create_eth_header_cids_table.sql @@ -1,12 +1,12 @@ -- +goose Up CREATE TABLE eth.header_cids ( - block_hash VARCHAR(66) PRIMARY KEY, + block_hash VARCHAR(66) NOT NULL, block_number BIGINT NOT NULL, parent_hash VARCHAR(66) NOT NULL, cid TEXT NOT NULL, mh_key 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/batch_process_migrations/00005_create_eth_uncle_cids_table.sql b/db/batch_process_migrations/00005_create_eth_uncle_cids_table.sql index 5d4ca8a..434b594 100644 --- a/db/batch_process_migrations/00005_create_eth_uncle_cids_table.sql +++ b/db/batch_process_migrations/00005_create_eth_uncle_cids_table.sql @@ -1,6 +1,6 @@ -- +goose Up CREATE TABLE eth.uncle_cids ( - block_hash VARCHAR(66) PRIMARY KEY, + block_hash VARCHAR(66) NOT NULL, header_id VARCHAR(66) NOT NULL, parent_hash VARCHAR(66) NOT NULL, cid TEXT NOT NULL, diff --git a/db/batch_process_migrations/00006_create_eth_transaction_cids_table.sql b/db/batch_process_migrations/00006_create_eth_transaction_cids_table.sql index 5a83ed0..3edf232 100644 --- a/db/batch_process_migrations/00006_create_eth_transaction_cids_table.sql +++ b/db/batch_process_migrations/00006_create_eth_transaction_cids_table.sql @@ -1,6 +1,6 @@ -- +goose Up CREATE TABLE eth.transaction_cids ( - tx_hash VARCHAR(66) PRIMARY KEY, + tx_hash VARCHAR(66) NOT NULL, header_id VARCHAR(66) NOT NULL, index INTEGER NOT NULL, cid TEXT NOT NULL, diff --git a/db/batch_process_migrations/00007_create_eth_receipt_cids_table.sql b/db/batch_process_migrations/00007_create_eth_receipt_cids_table.sql index fed5ea1..84f1d1c 100644 --- a/db/batch_process_migrations/00007_create_eth_receipt_cids_table.sql +++ b/db/batch_process_migrations/00007_create_eth_receipt_cids_table.sql @@ -1,6 +1,6 @@ -- +goose Up CREATE TABLE eth.receipt_cids ( - tx_id VARCHAR(66) PRIMARY KEY, + tx_id VARCHAR(66) NOT NULL, leaf_cid TEXT NOT NULL, leaf_mh_key TEXT NOT NULL, contract VARCHAR(66), diff --git a/db/batch_process_migrations/00008_create_eth_state_cids_table.sql b/db/batch_process_migrations/00008_create_eth_state_cids_table.sql index 72c919c..8417bd5 100644 --- a/db/batch_process_migrations/00008_create_eth_state_cids_table.sql +++ b/db/batch_process_migrations/00008_create_eth_state_cids_table.sql @@ -6,8 +6,7 @@ CREATE TABLE eth.state_cids ( mh_key TEXT NOT NULL, state_path BYTEA NOT NULL, node_type INTEGER NOT NULL, - diff BOOLEAN NOT NULL DEFAULT FALSE, - PRIMARY KEY (header_id, state_path) + diff BOOLEAN NOT NULL DEFAULT FALSE ); -- +goose Down diff --git a/db/batch_process_migrations/00009_create_eth_storage_cids_table.sql b/db/batch_process_migrations/00009_create_eth_storage_cids_table.sql index d07cfe7..dbe60ab 100644 --- a/db/batch_process_migrations/00009_create_eth_storage_cids_table.sql +++ b/db/batch_process_migrations/00009_create_eth_storage_cids_table.sql @@ -7,8 +7,7 @@ CREATE TABLE eth.storage_cids ( mh_key TEXT NOT NULL, storage_path BYTEA NOT NULL, node_type INTEGER NOT NULL, - diff BOOLEAN NOT NULL DEFAULT FALSE, - PRIMARY KEY (header_id, state_path, storage_path) + diff BOOLEAN NOT NULL DEFAULT FALSE ); -- +goose Down diff --git a/db/batch_process_migrations/00010_create_eth_state_accouts_table.sql b/db/batch_process_migrations/00010_create_eth_state_accouts_table.sql index e103795..c508b83 100644 --- a/db/batch_process_migrations/00010_create_eth_state_accouts_table.sql +++ b/db/batch_process_migrations/00010_create_eth_state_accouts_table.sql @@ -5,8 +5,7 @@ CREATE TABLE eth.state_accounts ( balance NUMERIC NOT NULL, nonce INTEGER NOT NULL, code_hash BYTEA NOT NULL, - storage_root VARCHAR(66) NOT NULL, - PRIMARY KEY (header_id, state_path) + storage_root VARCHAR(66) NOT NULL ); -- +goose Down diff --git a/db/batch_process_migrations/00011_create_eth_access_list_elements_table.sql b/db/batch_process_migrations/00011_create_eth_access_list_elements_table.sql index da1fcf0..335bc12 100644 --- a/db/batch_process_migrations/00011_create_eth_access_list_elements_table.sql +++ b/db/batch_process_migrations/00011_create_eth_access_list_elements_table.sql @@ -1,11 +1,10 @@ -- +goose Up -CREATE TABLE eth.access_list_element ( +CREATE TABLE eth.access_list_elements ( tx_id VARCHAR(66) NOT NULL, index INTEGER NOT NULL, address VARCHAR(66), - storage_keys VARCHAR(66)[], - PRIMARY KEY (tx_id, index) + storage_keys VARCHAR(66)[] ); -- +goose Down -DROP TABLE eth.access_list_element; +DROP TABLE eth.access_list_elements; diff --git a/db/batch_process_migrations/00012_create_eth_log_cids_table.sql b/db/batch_process_migrations/00012_create_eth_log_cids_table.sql index d0911ed..bf567bd 100644 --- a/db/batch_process_migrations/00012_create_eth_log_cids_table.sql +++ b/db/batch_process_migrations/00012_create_eth_log_cids_table.sql @@ -9,8 +9,7 @@ CREATE TABLE eth.log_cids ( topic0 VARCHAR(66), topic1 VARCHAR(66), topic2 VARCHAR(66), - topic3 VARCHAR(66), - PRIMARY KEY (rct_id, index) + topic3 VARCHAR(66) ); -- +goose Down diff --git a/db/batch_process_migrations/00013_create_pk_constraints.sql b/db/batch_process_migrations/00013_create_pk_constraints.sql new file mode 100644 index 0000000..fcae148 --- /dev/null +++ b/db/batch_process_migrations/00013_create_pk_constraints.sql @@ -0,0 +1,67 @@ +-- +goose Up +ALTER TABLE public.blocks +ADD CONSTRAINT pk_public_blocks PRIMARY KEY (key); + +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); + +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); + +ALTER TABLE eth.log_cids +ADD CONSTRAINT pk_eth_log_cids PRIMARY KEY (rct_id); + +ALTER TABLE eth.state_cids +ADD CONSTRAINT pk_eth_state_cids PRIMARY KEY (header_id, state_path); + +ALTER TABLE eth.storage_cids +ADD CONSTRAINT pk_eth_storage_cids PRIMARY KEY (header_id, state_path, storage_path); + +ALTER TABLE eth.state_accounts +ADD CONSTRAINT pk_eth_state_accounts PRIMARY KEY (header_id, state_path); + +-- +goose Down +ALTER TABLE public.blocks +DROP CONSTRAINT pk_public_blocks; + +ALTER TABLE public.nodes +DROP CONSTRAINT pk_public_nodes; + +ALTER TABLE eth.header_cids +DROP CONSTRAINT pk_eth_header_cids; + +ALTER TABLE eth.uncle_cids +DROP CONSTRAINT pk_eth_uncle_cids; + +ALTER TABLE eth.transaction_cids +DROP CONSTRAINT pk_eth_transaction_cids; + +ALTER TABLE eth.receipt_cids +DROP CONSTRAINT pk_eth_receipt_cids; + +ALTER TABLE eth.access_list_elements +DROP CONSTRAINT pk_eth_access_list_elements; + +ALTER TABLE eth.log_cids +DROP CONSTRAINT pk_eth_log_cids; + +ALTER TABLE eth.state_cids +DROP CONSTRAINT pk_eth_state_cids; + +ALTER TABLE eth.storage_cids +DROP CONSTRAINT pk_eth_storage_cids; + +ALTER TABLE eth.state_accounts +DROP CONSTRAINT pk_eth_state_accounts; diff --git a/db/batch_process_migrations/00014_create_fk_relations.sql b/db/batch_process_migrations/00014_create_fk_relations.sql new file mode 100644 index 0000000..4b8e157 --- /dev/null +++ b/db/batch_process_migrations/00014_create_fk_relations.sql @@ -0,0 +1,129 @@ +-- +goose Up +ALTER TABLE eth.header_cids +ADD CONSTRAINT fk_header_mh_key + FOREIGN KEY (mh_key) REFERENCES public.blocks (key) + 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) REFERENCES public.blocks (key) + 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) REFERENCES public.blocks (key) + 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) REFERENCES public.blocks (key) + 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) REFERENCES public.blocks (key) + 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) REFERENCES public.blocks (key) + ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; + +ALTER TABLE eth.storage_cids +ADD CONSTRAINT fk_storage_header_id_state_path + FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path) + ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; + +ALTER TABLE eth.state_accounts +ADD CONSTRAINT fk_account_header_id_state_path + FOREIGN KEY (header_id, state_path) REFERENCES eth.state_cids (header_id, state_path) + 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) REFERENCES public.blocks (key) + 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/drop_indexes_for_batch_processing.sql b/db/drop_indexes_for_batch_processing.sql index 30adc82..f8e3ed9 100644 --- a/db/drop_indexes_for_batch_processing.sql +++ b/db/drop_indexes_for_batch_processing.sql @@ -79,8 +79,8 @@ CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_p CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root); -- access list indexes -CREATE INDEX access_list_element_address_index ON eth.access_list_element USING btree (address); -CREATE INDEX access_list_storage_keys_index ON eth.access_list_element USING gin (storage_keys); +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_cid_index ON eth.log_cids USING btree (leaf_cid); diff --git a/db/migrations/00011_create_eth_access_list_elements_table.sql b/db/migrations/00011_create_eth_access_list_elements_table.sql index 947c9b9..b5843fa 100644 --- a/db/migrations/00011_create_eth_access_list_elements_table.sql +++ b/db/migrations/00011_create_eth_access_list_elements_table.sql @@ -1,5 +1,5 @@ -- +goose Up -CREATE TABLE eth.access_list_element ( +CREATE TABLE eth.access_list_elements ( tx_id VARCHAR(66) NOT NULL REFERENCES eth.transaction_cids (tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, index INTEGER NOT NULL, address VARCHAR(66), @@ -8,4 +8,4 @@ CREATE TABLE eth.access_list_element ( ); -- +goose Down -DROP TABLE eth.access_list_element; +DROP TABLE eth.access_list_elements; diff --git a/db/migrations/00014_create_cid_indexes.sql b/db/migrations/00014_create_cid_indexes.sql index 454a297..3759801 100644 --- a/db/migrations/00014_create_cid_indexes.sql +++ b/db/migrations/00014_create_cid_indexes.sql @@ -42,8 +42,8 @@ CREATE INDEX account_state_path_index ON eth.state_accounts USING btree (state_p CREATE INDEX storage_root_index ON eth.state_accounts USING btree (storage_root); -- access list indexes -CREATE INDEX access_list_element_address_index ON eth.access_list_element USING btree (address); -CREATE INDEX access_list_storage_keys_index ON eth.access_list_element USING gin (storage_keys); +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_mh_index ON eth.log_cids USING btree (leaf_mh_key); diff --git a/schema.sql b/schema.sql index b740a21..8d31a5c 100644 --- a/schema.sql +++ b/schema.sql @@ -213,10 +213,10 @@ $$; -- --- Name: access_list_element; Type: TABLE; Schema: eth; Owner: - +-- Name: access_list_elements; Type: TABLE; Schema: eth; Owner: - -- -CREATE TABLE eth.access_list_element ( +CREATE TABLE eth.access_list_elements ( tx_id character varying(66) NOT NULL, index integer NOT NULL, address character varying(66), @@ -418,11 +418,11 @@ ALTER TABLE ONLY public.goose_db_version ALTER COLUMN id SET DEFAULT nextval('pu -- --- Name: access_list_element access_list_element_pkey; Type: CONSTRAINT; Schema: eth; Owner: - +-- Name: access_list_elements access_list_elements_pkey; Type: CONSTRAINT; Schema: eth; Owner: - -- -ALTER TABLE ONLY eth.access_list_element - ADD CONSTRAINT access_list_element_pkey PRIMARY KEY (tx_id, index); +ALTER TABLE ONLY eth.access_list_elements + ADD CONSTRAINT access_list_elements_pkey PRIMARY KEY (tx_id, index); -- @@ -505,14 +505,6 @@ ALTER TABLE ONLY public.goose_db_version ADD CONSTRAINT goose_db_version_pkey PRIMARY KEY (id); --- --- Name: nodes node_uc; Type: CONSTRAINT; Schema: public; Owner: - --- - -ALTER TABLE ONLY public.nodes - ADD CONSTRAINT node_uc UNIQUE (genesis_block, network_id, node_id, chain_id); - - -- -- Name: nodes nodes_pkey; Type: CONSTRAINT; Schema: public; Owner: - -- @@ -525,14 +517,14 @@ ALTER TABLE ONLY public.nodes -- Name: access_list_element_address_index; Type: INDEX; Schema: eth; Owner: - -- -CREATE INDEX access_list_element_address_index ON eth.access_list_element USING btree (address); +CREATE INDEX access_list_element_address_index ON eth.access_list_elements USING btree (address); -- -- Name: access_list_storage_keys_index; Type: INDEX; Schema: eth; Owner: - -- -CREATE INDEX access_list_storage_keys_index ON eth.access_list_element USING gin (storage_keys); +CREATE INDEX access_list_storage_keys_index ON eth.access_list_elements USING gin (storage_keys); -- @@ -781,11 +773,11 @@ CREATE INDEX uncle_header_id_index ON eth.uncle_cids USING btree (header_id); -- --- Name: access_list_element access_list_element_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: - +-- Name: access_list_elements access_list_elements_tx_id_fkey; Type: FK CONSTRAINT; Schema: eth; Owner: - -- -ALTER TABLE ONLY eth.access_list_element - ADD CONSTRAINT access_list_element_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; +ALTER TABLE ONLY eth.access_list_elements + ADD CONSTRAINT access_list_elements_tx_id_fkey FOREIGN KEY (tx_id) REFERENCES eth.transaction_cids(tx_hash) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED; --