From 7f8247cb4f817b140e0dbcfb289d649521077628 Mon Sep 17 00:00:00 2001 From: i-norden Date: Tue, 30 Aug 2022 12:05:51 -0500 Subject: [PATCH] revert hash indexes; add eth probes tables --- .../00014_create_pending_tx_table.sql | 8 ++ ...dexes.sql => 00015_create_cid_indexes.sql} | 38 ++++---- ...=> 00016_create_postgraphile_triggers.sql} | 0 ....sql => 00017_create_db_version_table.sql} | 0 ...a.sql => 00018_create_eth_meta_schema.sql} | 0 ... 00019_create_watched_addresses_table.sql} | 0 db/migrations/00019_update_db_version.sql | 6 -- .../00022_create_probes_meta_tables.sql | 97 +++++++++++++++++++ db/migrations/00023_update_db_version.sql | 6 ++ 9 files changed, 130 insertions(+), 25 deletions(-) create mode 100644 db/migrations/00014_create_pending_tx_table.sql rename db/migrations/{00014_create_cid_indexes.sql => 00015_create_cid_indexes.sql} (80%) rename db/migrations/{00015_create_postgraphile_triggers.sql => 00016_create_postgraphile_triggers.sql} (100%) rename db/migrations/{00016_create_db_version_table.sql => 00017_create_db_version_table.sql} (100%) rename db/migrations/{00017_create_eth_meta_schema.sql => 00018_create_eth_meta_schema.sql} (100%) rename db/migrations/{00018_create_watched_addresses_table.sql => 00019_create_watched_addresses_table.sql} (100%) delete mode 100644 db/migrations/00019_update_db_version.sql create mode 100644 db/migrations/00022_create_probes_meta_tables.sql create mode 100644 db/migrations/00023_update_db_version.sql diff --git a/db/migrations/00014_create_pending_tx_table.sql b/db/migrations/00014_create_pending_tx_table.sql new file mode 100644 index 0000000..1a8c7b3 --- /dev/null +++ b/db/migrations/00014_create_pending_tx_table.sql @@ -0,0 +1,8 @@ +-- +goose Up +CREATE TABLE IF NOT EXISTS eth.pending_txs ( + tx_hash VARCHAR(66) NOT NULL PRIMARY KEY, + mh_key TEXT NOT NULL +); + +-- +goose Down +DROP TABLE eth.pending_txs; diff --git a/db/migrations/00014_create_cid_indexes.sql b/db/migrations/00015_create_cid_indexes.sql similarity index 80% rename from db/migrations/00014_create_cid_indexes.sql rename to db/migrations/00015_create_cid_indexes.sql index a360017..23d139e 100644 --- a/db/migrations/00014_create_cid_indexes.sql +++ b/db/migrations/00015_create_cid_indexes.sql @@ -3,7 +3,7 @@ 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, block_number); 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 hash (state_root); +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 @@ -13,19 +13,19 @@ 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 hash (header_id); +CREATE INDEX tx_header_id_index ON eth.transaction_cids USING btree (header_id); CREATE INDEX tx_cid_index ON eth.transaction_cids USING btree (cid, block_number); CREATE 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 hash (dst); -CREATE INDEX tx_src_index ON eth.transaction_cids USING hash (src); -CREATE INDEX tx_data_index ON eth.transaction_cids USING hash (tx_data); +CREATE INDEX tx_dst_index ON eth.transaction_cids USING btree (dst); +CREATE INDEX tx_src_index ON eth.transaction_cids USING btree (src); +CREATE INDEX tx_data_index ON eth.transaction_cids USING btree (tx_data); -- receipt indexes CREATE INDEX rct_block_number_index ON eth.receipt_cids USING brin (block_number); -CREATE INDEX rct_header_id_index ON eth.receipt_cids USING hash (header_id); +CREATE INDEX rct_header_id_index ON eth.receipt_cids USING btree (header_id); 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 hash (contract); +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 @@ -33,7 +33,7 @@ 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 hash (header_id); +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 @@ -42,30 +42,30 @@ CREATE INDEX storage_state_path_index ON eth.storage_cids USING btree (state_pat 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 hash (header_id); +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 hash (header_id); -CREATE INDEX account_storage_root_index ON eth.state_accounts USING hash (storage_root); +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 hash (address); +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_header_id_index ON eth.log_cids USING hash (header_id); +CREATE INDEX log_header_id_index ON eth.log_cids USING btree (header_id); 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 hash (address); -CREATE INDEX log_topic0_index ON eth.log_cids USING hash (topic0); -CREATE INDEX log_topic1_index ON eth.log_cids USING hash (topic1); -CREATE INDEX log_topic2_index ON eth.log_cids USING hash (topic2); -CREATE INDEX log_topic3_index ON eth.log_cids USING hash (topic3); -CREATE INDEX log_data_index ON eth.log_cids USING hash (log_data); +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); +CREATE INDEX log_data_index ON eth.log_cids USING btree (log_data); -- +goose Down -- log indexes diff --git a/db/migrations/00015_create_postgraphile_triggers.sql b/db/migrations/00016_create_postgraphile_triggers.sql similarity index 100% rename from db/migrations/00015_create_postgraphile_triggers.sql rename to db/migrations/00016_create_postgraphile_triggers.sql diff --git a/db/migrations/00016_create_db_version_table.sql b/db/migrations/00017_create_db_version_table.sql similarity index 100% rename from db/migrations/00016_create_db_version_table.sql rename to db/migrations/00017_create_db_version_table.sql diff --git a/db/migrations/00017_create_eth_meta_schema.sql b/db/migrations/00018_create_eth_meta_schema.sql similarity index 100% rename from db/migrations/00017_create_eth_meta_schema.sql rename to db/migrations/00018_create_eth_meta_schema.sql diff --git a/db/migrations/00018_create_watched_addresses_table.sql b/db/migrations/00019_create_watched_addresses_table.sql similarity index 100% rename from db/migrations/00018_create_watched_addresses_table.sql rename to db/migrations/00019_create_watched_addresses_table.sql diff --git a/db/migrations/00019_update_db_version.sql b/db/migrations/00019_update_db_version.sql deleted file mode 100644 index 7bf47f0..0000000 --- a/db/migrations/00019_update_db_version.sql +++ /dev/null @@ -1,6 +0,0 @@ --- +goose Up -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 = 'v4.0.0'; diff --git a/db/migrations/00022_create_probes_meta_tables.sql b/db/migrations/00022_create_probes_meta_tables.sql new file mode 100644 index 0000000..f35c0b3 --- /dev/null +++ b/db/migrations/00022_create_probes_meta_tables.sql @@ -0,0 +1,97 @@ +-- +goose Up +-- peer tx represents a tx that has been seen by a peer +-- the same tx (hash) can be seen by different peers +-- or received by different probes +-- so the primary key is a composite on (raw_peer_id, tx_hash, received_by_probe) +-- this table is persistent, and continues to map probe/peer meta_data to transaction hashes +-- whether they are in the canonical tx table or the pending tx table +CREATE TABLE eth_meta.peer_tx ( + raw_peer_id bytea NOT NULL, + tx_hash VARCHAR(66) NOT NULL, + received timestamp with time zone NOT NULL, + received_by_probe integer NOT NULL +); + +CREATE TABLE eth_meta.asn ( + id BIGINT NOT NULL, + asn INTEGER NOT NULL, + registry TEXT NOT NULL, + country_code TEXT NOT NULL, + name TEXT NOT NULL +); + +CREATE TABLE eth_meta.peer ( + asn_id BIGINT NOT NULL, + prefix CIDR NOT NULL, + rdns TEXT, + raw_dht_peer_id BIGINT, + city TEXT, + country TEXT, + coords JSONB +); + +CREATE TABLE eth_meta.peer_dht ( + dht_peer_id BIGINT NOT NULL, + neighbor_id BIGINT NOT NULL, + seen TIMESTAMP WITH TIME ZONE NOT NULL, + seen_by_probe INTEGER NOT NULL +); + +CREATE TABLE eth_meta.peer_seen ( + raw_peer_id BYTEA NOT NULL, + first_seen TIMESTAMP WITH TIME ZONE NOT NULL, + probe_id INTEGER NOT NULL +); + +CREATE TABLE eth_meta.probe ( + id INTEGER NOT NULL, + ip INET NOT NULL, + deployed TIMESTAMP WITH TIME ZONE NOT NULL +); + +CREATE TABLE eth_meta.raw_dht_peer ( + id BIGINT NOT NULL, + pubkey BYTEA NOT NULL, + ip INET NOT NULL, + port INTEGER NOT NULL, + client_id TEXT, + network_id BYTEA, + genesis_hash BYTEA, + forks JSONB, + created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL +); + +CREATE TABLE eth_meta.raw_peer ( + id BYTEA NOT NULL, + ip INET NOT NULL, + port INTEGER NOT NULL, + client_id TEXT NOT NULL, + created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL +); + +CREATE TABLE eth_meta.site ( + id INTEGER NOT NULL, + provider TEXT NOT NULL, + az TEXT NOT NULL, + probe_id INTEGER NOT NULL, + privkey BYTEA NOT NULL +); + +CREATE TABLE eth_meta.tx_chain ( + id BYTEA NOT NULL, + height INTEGER NOT NULL, + ts TIMESTAMP WITH TIME ZONE NOT NULL +); + +-- +goose Down +DROP TABLE eth_meta.tx_chain; +DROP TABLE eth_meta.site; +DROP TABLE eth_meta.raw_peer; +DROP TABLE eth_meta.raw_dht_peer; +DROP TABLE eth_meta.probe; +DROP TABLE eth_meta.peer_seen; +DROP TABLE eth_meta.peer_dht; +DROP TABLE eth_meta.peer; +DROP TABLE eth_meta.asn; +DROP TABLE eth_meta.peer_tx; diff --git a/db/migrations/00023_update_db_version.sql b/db/migrations/00023_update_db_version.sql new file mode 100644 index 0000000..918822e --- /dev/null +++ b/db/migrations/00023_update_db_version.sql @@ -0,0 +1,6 @@ +-- +goose Up +INSERT INTO public.db_version (singleton, version) VALUES (true, 'v5.0.0') +ON CONFLICT (singleton) DO UPDATE SET (version, tstamp) = ('v5.0.0', NOW()); + +-- +goose Down +DELETE FROM public.db_version WHERE version = 'v5.0.0';