From f6c688b130313141fca2f4e727e192d7c825fd3e Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Wed, 16 Dec 2020 01:19:30 -0600 Subject: [PATCH 01/22] Add psql to timescaledb migration scripts Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../createHyperTables.sql | 279 ++++++++++++++++++ .../time-scale-migration/csvBackupTables.sql | 49 +++ .../time-scale-migration/csvRestoreTables.sql | 49 +++ .../time-scale-migration/migration.config | 10 + .../time-scale-migration/timeScaleDbInit.sql | 45 +++ .../timeScaleDbMigration.sh | 83 ++++++ 6 files changed, 515 insertions(+) create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql create mode 100755 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql new file mode 100644 index 00000000000..1ead4ee3e2a --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql @@ -0,0 +1,279 @@ +------------------- +-- alter tables by removing domains +-- update to custom schema +-- Create hyper tables from v1 schema, inserts from old table, add indexes +-- Use default of 604800000000000 ns (7 days) as chunk time interval +------------------- + +\set chunkIdInterval 10000 +\set chunkTimeInterval 604800000000000 +\set newSchema mirrornode + +-- alter schemas by replacing domains +alter table account_balance + alter column account_id type bigint, + alter column balance type bigint, + alter column consensus_timestamp type bigint; + +-- account_balance_file +alter table account_balance_file + alter column node_account_id type bigint; + +-- account_balance_sets +alter table account_balance_sets + alter column consensus_timestamp type bigint; + +-- address_book +alter table address_book + alter column start_consensus_timestamp type bigint, + alter column end_consensus_timestamp type bigint, + alter column file_id type bigint; + +-- address_book_entry +alter table address_book_entry + alter column consensus_timestamp type bigint, + alter column consensus_timestamp set not null, + alter column node_account_id type bigint; + +-- contract_result +alter table contract_result + alter column consensus_timestamp type bigint; + +-- crypto_transfer +alter table crypto_transfer + alter column entity_id type bigint, + alter column consensus_timestamp type bigint, + alter column amount type bigint; + +-- file_data +alter table file_data + alter column consensus_timestamp type bigint, + alter column entity_id type bigint; + +-- live_hash +alter table live_hash + alter column consensus_timestamp type bigint; + +-- non_fee_transfer +alter table non_fee_transfer + alter column entity_id type bigint, + alter column consensus_timestamp type bigint, + alter column amount type bigint; + +-- record_file +alter table record_file + alter column node_account_id type bigint; + +-- t_entities +alter table t_entities + alter column id type bigint, + alter column proxy_account_id type bigint; + +-- token +alter table token + alter column token_id type bigint, + alter column treasury_account_id type bigint; + +-- token_account +alter table token_account + alter column account_id type bigint, + alter column token_id type bigint; + +-- token_balance +alter table token_balance + alter column account_id type bigint, + alter column token_id type bigint; + +-- token_transfer +alter table token_transfer + alter column token_id type bigint, + alter column account_id type bigint, + alter column amount type bigint; + +-- topic_message +alter table topic_message + alter column consensus_timestamp type bigint; + +-- transaction +alter table transaction + alter column payer_account_id type bigint, + alter column node_account_id type bigint, + alter column entity_id type bigint, + alter column max_fee type bigint; + + +-- Update schema from public to mirror_node +-- account_balance +alter table account_balance + set schema :newSchema; + +-- account_balance_file +alter table account_balance_file + set schema :newSchema; + +-- account_balance_sets +alter table account_balance_sets + set schema :newSchema; + +-- address_book +alter sequence address_book_entry_id_seq + set schema :newSchema; +alter table address_book + set schema :newSchema; + +-- address_book_entry +alter table address_book_entry + set schema :newSchema; + +-- contract_result +alter table contract_result + set schema :newSchema; + +-- crypto_transfer +alter table crypto_transfer + set schema :newSchema; + +-- file_data +alter table file_data + set schema :newSchema; + +-- live_hash +alter table live_hash + set schema :newSchema; + +-- non_fee_transfer +alter table non_fee_transfer + set schema :newSchema; + +-- record_file +alter sequence s_record_files_seq + set schema :newSchema; +alter table record_file + set schema :newSchema; + +-- t_application_status +alter table t_application_status + set schema :newSchema; + +-- t_entities +alter table t_entities + set schema :newSchema; + +-- t_entity_types +alter table t_entity_types + set schema :newSchema; + +-- t_transaction_results +alter table t_transaction_results + set schema :newSchema; + +-- t_transaction_types +alter table t_transaction_types + set schema :newSchema; + +-- token +alter table token + set schema :newSchema; + +-- token_account +alter table token_account + set schema :newSchema; + +-- token_balance +alter table token_balance + set schema :newSchema; + +-- token_transfer +alter table token_transfer + set schema :newSchema; + +-- topic_message +alter table topic_message + set schema :newSchema; + +-- transaction +alter table transaction + set schema :newSchema; + + +-- create hyper tables +-- account_balance +select create_hypertable('account_balance', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- account_balance_file +select create_hypertable('account_balance_file', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- account_balance_sets +select create_hypertable('account_balance_sets', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- address_book +select create_hypertable('address_book', 'start_consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- address_book_entry +select create_hypertable('address_book_entry', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- contract_result +select create_hypertable('contract_result', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- crypto_transfer +select create_hypertable('crypto_transfer', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- file_data +select create_hypertable('file_data', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- live_hash +select create_hypertable('live_hash', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- non_fee_transfer +select create_hypertable('non_fee_transfer', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- record_file +select create_hypertable('record_file', 'consensus_start', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- t_application_status hyper table creation skipped as it serves only as a reference table + +-- t_entities +select create_hypertable('t_entities', 'id', + chunk_time_interval => :chunkIdInterval, if_not_exists => true); + +-- t_entity_types hyper table creation skipped as it serves only as a reference table and rarely gets updated + +-- t_transaction_results hyper table creation skipped as it serves only as a reference table and rarely gets updated + +-- t_transaction_types hyper table creation skipped as it serves only as a reference table and rarely gets updated + +-- token +select create_hypertable('token', 'created_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- token_account +select create_hypertable('token_account', 'created_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- token_balance +select create_hypertable('token_balance', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- token_transfer +select create_hypertable('token_transfer', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- topic_message +select create_hypertable('topic_message', 'consensus_timestamp', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + +-- transaction +select create_hypertable('transaction', 'consensus_ns', + chunk_time_interval => :chunkTimeInterval, if_not_exists => true); + diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql new file mode 100644 index 00000000000..b4df9eb63d0 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql @@ -0,0 +1,49 @@ +------------------- +-- Backup tables use efficient COPY process to CSV's +------------------- + +\copy (select * from account_balance) to account_balance.csv delimiter ',' csv; + +\copy (select * from account_balance_file) to account_balance_file.csv delimiter ',' csv; + +\copy (select * from account_balance_sets) to account_balance_sets.csv delimiter ',' csv; + +\copy (select * from address_book) to address_book.csv delimiter ',' csv; + +\copy (select * from address_book_entry) to address_book_entry.csv delimiter ',' csv; + +\copy (select * from contract_result) to contract_result.csv delimiter ',' csv; + +\copy (select * from crypto_transfer) to crypto_transfer.csv delimiter ',' csv; + +\copy (select * from file_data) to file_data.csv delimiter ',' csv; + +\copy (select * from flyway_schema_history) to flyway_schema_history.csv delimiter ',' csv; + +\copy (select * from live_hash) to live_hash.csv delimiter ',' csv; + +\copy (select * from non_fee_transfer) to non_fee_transfer.csv delimiter ',' csv; + +\copy (select * from record_file) to record_file.csv delimiter ',' csv; + +\copy (select * from t_application_status) to t_application_status.csv delimiter ',' csv; + +\copy (select * from t_entities) to t_entities.csv delimiter ',' csv; + +\copy (select * from t_entity_types) to t_entity_types.csv delimiter ',' csv; + +\copy (select * from t_transaction_results) to t_transaction_results.csv delimiter ',' csv; + +\copy (select * from t_transaction_types) to t_transaction_types.csv delimiter ',' csv; + +\copy (select * from token) to token.csv delimiter ',' csv; + +\copy (select * from token_account) to token_account.csv delimiter ',' csv; + +\copy (select * from token_balance) to token_balance.csv delimiter ',' csv; + +\copy (select * from token_message) to token_message.csv delimiter ',' csv; + +\copy (select * from topic_message) to topic_message.csv delimiter ',' csv; + +\copy (select * from transaction) to transaction.csv delimiter ',' csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql new file mode 100644 index 00000000000..b56f123ae14 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql @@ -0,0 +1,49 @@ +------------------- +-- Restore Backup tables use efficient COPY process to CSV's +------------------- + +\copy account_balance from account_balance.csv csv; + +\copy account_balance_file from account_balance_file.csv csv; + +\copy account_balance_sets from account_balance_sets.csv csv; + +\copy address_book from address_book.csv csv; + +\copy address_book_entry from address_book_entry.csv csv; + +\copy contract_result from contract_result.csv csv; + +\copy crypto_transfer from crypto_transfer.csv csv; + +\copy file_data from file_data.csv csv; + +\copy flyway_schema_history from flyway_schema_history.csv csv; + +\copy live_hash from live_hash.csv csv; + +\copy non_fee_transfer from non_fee_transfer.csv csv; + +\copy record_file from record_file.csv csv; + +\copy t_application_status from t_application_status.csv csv; + +\copy t_entities from t_entities.csv csv; + +\copy t_entity_types from t_entity_types.csv csv; + +\copy t_transaction_results from t_transaction_results.csv csv; + +\copy t_transaction_types from t_transaction_types.csv csv; + +\copy token from token.csv csv; + +\copy token_account from token_account.csv csv; + +\copy token_balance from token_balance.csv csv; + +\copy token_transfer from token_transfer.csv csv; + +\copy topic_message from topic_message.csv csv; + +\copy transaction from transaction.csv csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config new file mode 100644 index 00000000000..63e3bea5b51 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config @@ -0,0 +1,10 @@ +OLD_DB_HOST=localhost +OLD_DB_NAME=localhost +OLD_DB_PORT=5432 +OLD_DB_USER=mirror_node +OLD_PASSWORD=mirror_node_pass +NEW_DB_HOST=localhost +NEW_DB_NAME=localhost +NEW_DB_PORT=6432 +NEW_DB_USER=mirror_node +NEW_PASSWORD=mirror_node_pass diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql new file mode 100644 index 00000000000..a25f438fa49 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql @@ -0,0 +1,45 @@ +-- init the timescale db mirror node db +-- Change the values below if you are not installing via Docker + +\set db_name 'mirror_node' +\set db_user 'mirror_node' +\set db_password 'mirror_node_pass' +\set db_owner 'mirror_node' +\set grpc_user 'mirror_grpc' +\set grpc_password 'mirror_grpc_pass' +\set rest_user 'mirror_api' +\set rest_password 'mirror_api_pass' +\set schema_name 'mirror_node' + +-- create primary user and db +create user :db_user with login createrole password :'db_password'; +create database :db_name with owner :db_owner; + +-- create api users +create user :grpc_user with login password :'grpc_password'; +create user :rest_user with login password :'rest_password'; + +-- is it necessary to explicitly grant the following? +grant all privileges on database :db_name to :db_user; + +-- grant connect access to api users +grant connect on database :db_name to :grpc_user; +grant connect on database :db_name to :rest_user; + +\c :db_name + +-- schema +create schema if not exists :schema_name; +grant usage on schema :schema_name to public; +grant all privileges on all tables in schema :schema_name to :db_user; + +-- alter search path for given schema +alter user :db_user set search_path = :schema_name, public; +alter user :grpc_user set search_path = :schema_name, public; +alter user :rest_user set search_path = :schema_name, public; + +-- grant select privileges on past and future tables to api users +alter default privileges in schema :schema_name grant select on tables to :grpc_user; +alter default privileges in schema :schema_name grant select on tables to :rest_user; +grant select on all tables in schema :schema_name to :grpc_user; +grant select on all tables in schema :schema_name to :rest_user; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh new file mode 100755 index 00000000000..68e2b6b2157 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh @@ -0,0 +1,83 @@ +#!/usr/bin/env bash +echo "BASH_VERSION: $BASH_VERSION" +set -e + +. migration.config +echo "$OLD_DB_HOST" "$OLD_DB_NAME" "$OLD_DB_PORT" "$OLD_DB_USER" "$NEW_DB_HOST" "$NEW_DB_NAME" "$NEW_DB_PORT" "$NEW_DB_USER" + +if [[ -z $OLD_DB_HOST ]]; then + echo "Current host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $OLD_DB_NAME ]]; then + echo "Current db name is not set. Please configure OLD_DB_NAME in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $OLD_DB_PORT ]]; then + echo "Current port is not set. Please configure OLD_DB_PORT in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $OLD_DB_USER ]]; then + echo "Current db primary user name is not set. Please configure OLD_DB_USER in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $OLD_PASSWORD ]]; then + echo "Old db primary user password is not set. Please configure OLD_PASSWORD in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $NEW_DB_HOST ]]; then + echo "New host name is not set. Please configure NEW_DB_HOST in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $NEW_DB_NAME ]]; then + echo "New db name is not set. Please configure NEW_DB_NAME in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $NEW_DB_PORT ]]; then + echo "New db port is not set. Please configure NEW_DB_PORT in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $NEW_DB_USER ]]; then + echo "New db primary user name is not set. Please configure NEW_DB_USER in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +if [[ -z $NEW_PASSWORD ]]; then + echo "New db primary user password is not set. Please configure NEW_PASSWORD in migration.config file and rerun './timeScaleDbMigration.sh'" + exit 1 +fi + +start_time="$(date -u +%s)" +# assumes 1. Valid populated current mirror node postgres db with appropriate user 2. New empty TimeScaleDb db host with appropriate user +echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)" + +echo "1. Migrate schema to TimeScaleDb. Postgres($OLD_DB_HOST:$OLD_DB_PORT) will prompt for password..." +PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --section=pre-data -f mirror_node_${start_time}.bak mirror_node +# +echo "2. Restore table schemas to new host. TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT) will prompt for password..." +psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER "password=${NEW_PASSWORD}" timeScaleDBInit.sql +echo "3. Create new hyper tables" +psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f createHyperTables.sql "password=${NEW_PASSWORD}" + +echo "4. Copy tables into separate CSV's" +psql -h $OLD_DB_HOST -d $OLD_DB_NAME -p $OLD_DB_PORT -U $OLD_DB_USER -f csvBackupTables.sql "password=${OLD_PASSWORD}" + +## Optionally use https://github.com/timescale/timescaledb-parallel-copy as it's mulithreaded +echo "5. Pg_restore to separate host" +psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f csvRestoreTables.sql "password=${NEW_PASSWORD}" + +# leave index creation and policy sets to migration 2.0 +end_time="$(date -u +%s)" + +elapsed="$(($end_time - $start_time))" +echo "Migration from postgres to timescale took a total of $elapsed seconds" From 2a52fc729ef5b57ef02d2b3b8abd3cc49e453e4d Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Wed, 16 Dec 2020 17:57:01 -0600 Subject: [PATCH 02/22] Improved comments on script Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../time-scale-migration/timeScaleDbMigration.sh | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh index 68e2b6b2157..4abf5b09095 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh @@ -57,23 +57,23 @@ fi start_time="$(date -u +%s)" # assumes 1. Valid populated current mirror node postgres db with appropriate user 2. New empty TimeScaleDb db host with appropriate user -echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)" +echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." -echo "1. Migrate schema to TimeScaleDb. Postgres($OLD_DB_HOST:$OLD_DB_PORT) will prompt for password..." +echo "1. Backing up table schema from Postgres($OLD_DB_HOST:$OLD_DB_PORT)..." PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --section=pre-data -f mirror_node_${start_time}.bak mirror_node # -echo "2. Restore table schemas to new host. TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT) will prompt for password..." +echo "2. Restoring table schemas to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER "password=${NEW_PASSWORD}" timeScaleDBInit.sql -echo "3. Create new hyper tables" +echo "3. Creating new hyper tables on TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f createHyperTables.sql "password=${NEW_PASSWORD}" -echo "4. Copy tables into separate CSV's" +echo "4. Backing up tables from from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to separate CSV's..." psql -h $OLD_DB_HOST -d $OLD_DB_NAME -p $OLD_DB_PORT -U $OLD_DB_USER -f csvBackupTables.sql "password=${OLD_PASSWORD}" ## Optionally use https://github.com/timescale/timescaledb-parallel-copy as it's mulithreaded -echo "5. Pg_restore to separate host" +echo "5. Restoring CSV backups to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f csvRestoreTables.sql "password=${NEW_PASSWORD}" # leave index creation and policy sets to migration 2.0 From 1cdddc072c8e19ea4444b445903fa832a8135d39 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Mon, 21 Dec 2020 18:48:59 -0600 Subject: [PATCH 03/22] Simplify logic and reuse flyway migration script Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../migration/v2/V2.0.0__time_scale_init.sql | 5 +- .../time-scale-migration/alterSchema.sql | 14 ++ .../createHyperTables.sql | 192 +----------------- .../time-scale-migration/csvBackupTables.sql | 2 +- .../time-scale-migration/migration.config | 6 +- .../timeScaleDbMigration.sh | 32 +-- 6 files changed, 40 insertions(+), 211 deletions(-) create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql index 9d94f8ce822..46fbc49ed44 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql @@ -14,7 +14,7 @@ comment on table account_balance is 'Account balances (historical) in tinybars a create table if not exists account_balance_file ( - consensus_timestamp bigint, + consensus_timestamp bigint not null, count bigint not null, load_start bigint, load_end bigint, @@ -37,7 +37,7 @@ comment on table account_balance_sets is 'Processing state of snapshots of the e -- address_book create table if not exists address_book ( - start_consensus_timestamp bigint, + start_consensus_timestamp bigint not null, end_consensus_timestamp bigint null, file_id bigint not null, node_count int null, @@ -415,6 +415,7 @@ comment on table token is 'Token entities'; --- token_account create table if not exists token_account ( + id serial, account_id bigint not null, associated boolean not null default false, created_timestamp bigint not null, diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql new file mode 100644 index 00000000000..b88ebf3bf07 --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql @@ -0,0 +1,14 @@ +------------------- +-- alter tables by removing domains +-- update to custom schema +------------------- + +\set newSchema mirrornode +-- Update schema from public to custom schema e.g mirrornode +alter table flyway_schema_history + set schema :newSchema; + +-- update sequence start values +select setval('address_book_entry_id_seq', (select max(id) from address_book_entry)); +select setval('record_file_id_seq', (select max(id) from record_file)); +select setval('token_account_id_seq', (select max(id) from token_account)); diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql index 1ead4ee3e2a..c5b4536a793 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql @@ -1,202 +1,12 @@ ------------------- --- alter tables by removing domains --- update to custom schema -- Create hyper tables from v1 schema, inserts from old table, add indexes -- Use default of 604800000000000 ns (7 days) as chunk time interval ------------------- +-- refer to spring.flyway.placeholders for latest values of chunkIdInterval and chunkTimeInterval \set chunkIdInterval 10000 \set chunkTimeInterval 604800000000000 -\set newSchema mirrornode --- alter schemas by replacing domains -alter table account_balance - alter column account_id type bigint, - alter column balance type bigint, - alter column consensus_timestamp type bigint; - --- account_balance_file -alter table account_balance_file - alter column node_account_id type bigint; - --- account_balance_sets -alter table account_balance_sets - alter column consensus_timestamp type bigint; - --- address_book -alter table address_book - alter column start_consensus_timestamp type bigint, - alter column end_consensus_timestamp type bigint, - alter column file_id type bigint; - --- address_book_entry -alter table address_book_entry - alter column consensus_timestamp type bigint, - alter column consensus_timestamp set not null, - alter column node_account_id type bigint; - --- contract_result -alter table contract_result - alter column consensus_timestamp type bigint; - --- crypto_transfer -alter table crypto_transfer - alter column entity_id type bigint, - alter column consensus_timestamp type bigint, - alter column amount type bigint; - --- file_data -alter table file_data - alter column consensus_timestamp type bigint, - alter column entity_id type bigint; - --- live_hash -alter table live_hash - alter column consensus_timestamp type bigint; - --- non_fee_transfer -alter table non_fee_transfer - alter column entity_id type bigint, - alter column consensus_timestamp type bigint, - alter column amount type bigint; - --- record_file -alter table record_file - alter column node_account_id type bigint; - --- t_entities -alter table t_entities - alter column id type bigint, - alter column proxy_account_id type bigint; - --- token -alter table token - alter column token_id type bigint, - alter column treasury_account_id type bigint; - --- token_account -alter table token_account - alter column account_id type bigint, - alter column token_id type bigint; - --- token_balance -alter table token_balance - alter column account_id type bigint, - alter column token_id type bigint; - --- token_transfer -alter table token_transfer - alter column token_id type bigint, - alter column account_id type bigint, - alter column amount type bigint; - --- topic_message -alter table topic_message - alter column consensus_timestamp type bigint; - --- transaction -alter table transaction - alter column payer_account_id type bigint, - alter column node_account_id type bigint, - alter column entity_id type bigint, - alter column max_fee type bigint; - - --- Update schema from public to mirror_node --- account_balance -alter table account_balance - set schema :newSchema; - --- account_balance_file -alter table account_balance_file - set schema :newSchema; - --- account_balance_sets -alter table account_balance_sets - set schema :newSchema; - --- address_book -alter sequence address_book_entry_id_seq - set schema :newSchema; -alter table address_book - set schema :newSchema; - --- address_book_entry -alter table address_book_entry - set schema :newSchema; - --- contract_result -alter table contract_result - set schema :newSchema; - --- crypto_transfer -alter table crypto_transfer - set schema :newSchema; - --- file_data -alter table file_data - set schema :newSchema; - --- live_hash -alter table live_hash - set schema :newSchema; - --- non_fee_transfer -alter table non_fee_transfer - set schema :newSchema; - --- record_file -alter sequence s_record_files_seq - set schema :newSchema; -alter table record_file - set schema :newSchema; - --- t_application_status -alter table t_application_status - set schema :newSchema; - --- t_entities -alter table t_entities - set schema :newSchema; - --- t_entity_types -alter table t_entity_types - set schema :newSchema; - --- t_transaction_results -alter table t_transaction_results - set schema :newSchema; - --- t_transaction_types -alter table t_transaction_types - set schema :newSchema; - --- token -alter table token - set schema :newSchema; - --- token_account -alter table token_account - set schema :newSchema; - --- token_balance -alter table token_balance - set schema :newSchema; - --- token_transfer -alter table token_transfer - set schema :newSchema; - --- topic_message -alter table topic_message - set schema :newSchema; - --- transaction -alter table transaction - set schema :newSchema; - - --- create hyper tables -- account_balance select create_hypertable('account_balance', 'consensus_timestamp', chunk_time_interval => :chunkTimeInterval, if_not_exists => true); diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql index b4df9eb63d0..82eddd8d0f6 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql @@ -42,7 +42,7 @@ \copy (select * from token_balance) to token_balance.csv delimiter ',' csv; -\copy (select * from token_message) to token_message.csv delimiter ',' csv; +\copy (select * from token_transfer) to token_transfer.csv delimiter ',' csv; \copy (select * from topic_message) to topic_message.csv delimiter ',' csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config index 63e3bea5b51..406907cadfc 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config @@ -1,10 +1,10 @@ OLD_DB_HOST=localhost -OLD_DB_NAME=localhost -OLD_DB_PORT=5432 +OLD_DB_NAME=mirror_node +OLD_DB_PORT=7432 OLD_DB_USER=mirror_node OLD_PASSWORD=mirror_node_pass NEW_DB_HOST=localhost -NEW_DB_NAME=localhost +NEW_DB_NAME=mirror_node NEW_DB_PORT=6432 NEW_DB_USER=mirror_node NEW_PASSWORD=mirror_node_pass diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh index 4abf5b09095..77bb2580663 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh @@ -2,8 +2,7 @@ echo "BASH_VERSION: $BASH_VERSION" set -e -. migration.config -echo "$OLD_DB_HOST" "$OLD_DB_NAME" "$OLD_DB_PORT" "$OLD_DB_USER" "$NEW_DB_HOST" "$NEW_DB_NAME" "$NEW_DB_PORT" "$NEW_DB_USER" +. scripts/time-scale-migration/migration.config if [[ -z $OLD_DB_HOST ]]; then echo "Current host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './timeScaleDbMigration.sh'" @@ -59,22 +58,27 @@ start_time="$(date -u +%s)" # assumes 1. Valid populated current mirror node postgres db with appropriate user 2. New empty TimeScaleDb db host with appropriate user echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." -echo "1. Backing up table schema from Postgres($OLD_DB_HOST:$OLD_DB_PORT)..." -PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --section=pre-data -f mirror_node_${start_time}.bak mirror_node -# -echo "2. Restoring table schemas to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." -psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER "password=${NEW_PASSWORD}" timeScaleDBInit.sql -echo "3. Creating new hyper tables on TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." -psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f createHyperTables.sql "password=${NEW_PASSWORD}" +echo "2. Restoring flyway_schema_history to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." +PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER Date: Mon, 21 Dec 2020 19:17:59 -0600 Subject: [PATCH 04/22] Add documentation Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docs/operations.md | 30 +++++++++++- .../src/main/resources/db/scripts/init_v2.sql | 46 +++++++++++++++++++ 2 files changed, 75 insertions(+), 1 deletion(-) create mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql diff --git a/docs/operations.md b/docs/operations.md index e6c5c114506..a61cab08fa9 100644 --- a/docs/operations.md +++ b/docs/operations.md @@ -93,6 +93,35 @@ systemctl status hedera-mirror-importer.service sudo journalctl -fu hedera-mirror-importer.service ``` +### v1 to v2 Data Migration + +To support time series logic the Mirror Node db schema shifted from PostgeSQL (v1) to TimeScaleDB (v2) +For mirror node operators running v1 db schema looking to upgrade to v2 the following steps can be taken + +1. Setup a new database using TimeScale +Docker installation recommended - https://docs.timescale.com/latest/getting-started/installation/docker/installation-docker + + +2. Create DB & Init Schema +The init script for v2 at `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create teh db, users, schema, extensions and ensure all permissions are set. +This may be run manually against the db node or in teh docker case mounted under `/docker-entrypoint-initdb.d/` on the docker container + +> **_NOTE:_** The following steps assume the database, users and schema have been created + +3. Configure migration properties +A properties file contains variable for easy running. These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. + +Updated the values at `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` appropriately + +4. Run migration script + +From the `hedera-mirror-importer/src/main/resources/db` directory run + ```shell script + $ ./scripts/time-scale-migration/timeScaleDbMigration.sh + ``` + +Adopting the recommended steps [Migrating from a Different PostgreSQL Database](https://docs.timescale.com/latest/getting-started/migrating-data#different-db) we + ## Monitor The monitor is a Java-based application and should be able to run on any platform that Java supports. That said, we @@ -224,5 +253,4 @@ available - `/swagger/ui` - Metrics dashboard - `/swagger/stats` - Aggregated statistics - `/swagger/metrics` - Prometheus formatted metrics - Where `swagger` is the default metrics path as controlled by `hedera.mirror.rest.metrics.config.uriPath`. diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql new file mode 100644 index 00000000000..68c29decb3e --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql @@ -0,0 +1,46 @@ +-- init the timescale db mirror node db +-- Change the values below if you are not installing via Docker + +\set db_name 'mirror_node' +\set importer_user 'mirror_node' +\set importer_password 'mirror_node_pass' +\set importer_user 'mirror_node' +\set grpc_user 'mirror_grpc' +\set grpc_password 'mirror_grpc_pass' +\set rest_user 'mirror_api' +\set rest_password 'mirror_api_pass' +\set schema_name 'mirror_node' + +-- create primary user and db +create database :db_name; +\c :db_name +create extension if not exists timescaledb cascade; + +-- create users +create user :importer_user with login createrole password :'importer_password'; +create role viewer; +create user :grpc_user with login password :'grpc_password' in role viewer; +create user :rest_user with login password :'rest_password' in role viewer; + +-- grant connect access to api users +grant connect on database :db_name to :grpc_user; +grant connect on database :db_name to :rest_user; + +-- schema +create schema if not exists :schema_name; +grant usage on schema :schema_name to public; +grant all privileges on all tables in schema :schema_name to :importer_user; + +-- alter search path for given schema +alter user :importer_user set search_path = :schema_name, public; +alter user :grpc_user set search_path = :schema_name, public; +alter user :rest_user set search_path = :schema_name, public; + +-- grant select privileges on past and future tables to api users +grant select on all tables in schema :schema_name to :importer_user; +grant select on all tables in schema :schema_name to viewer; +alter default privileges for role :importer_user in schema :schema_name grant select on tables to viewer; + +-- add extensions +create extension if not exists timescaledb cascade; +create extension pg_stat_statements; From 06e6003123ed11f338e1d28afb44a08e68cf48d7 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Tue, 22 Dec 2020 17:28:44 -0600 Subject: [PATCH 05/22] Updated for super and owner users Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docker-compose.override.yml | 4 ++ docker-compose.yml | 14 +++++ docs/operations.md | 48 +++++++++++++---- .../src/main/resources/db/scripts/init_v2.sql | 53 ++++++++++++------- .../time-scale-migration/csvBackupTables.sql | 2 - .../time-scale-migration/csvRestoreTables.sql | 2 - .../time-scale-migration/migration.config | 2 +- .../time-scale-migration/timeScaleDbInit.sql | 45 ---------------- .../timeScaleDbMigration.sh | 2 +- 9 files changed, 93 insertions(+), 79 deletions(-) create mode 100644 docker-compose.override.yml delete mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql diff --git a/docker-compose.override.yml b/docker-compose.override.yml new file mode 100644 index 00000000000..f263f9124f1 --- /dev/null +++ b/docker-compose.override.yml @@ -0,0 +1,4 @@ +version: "3.3" +services: + tsdb: + entrypoint: ["echo", "TimeScaleDB service is disabled"] diff --git a/docker-compose.yml b/docker-compose.yml index e7eddbd1679..cbd989a4c7b 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -67,3 +67,17 @@ services: tty: true ports: - 5551:5551 + + tsdb: + image: timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 + restart: unless-stopped + stop_grace_period: 2m + stop_signal: SIGTERM + tty: true + environment: + POSTGRES_PASSWORD: mirror_node_pass + volumes: + - ./tsdb:/var/lib/postgresql/data + - ./hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql/:/docker-entrypoint-initdb.d/init_v2.sql + ports: + - 6432:5432 diff --git a/docs/operations.md b/docs/operations.md index a61cab08fa9..47b6bdd42ad 100644 --- a/docs/operations.md +++ b/docs/operations.md @@ -95,33 +95,61 @@ sudo journalctl -fu hedera-mirror-importer.service ### v1 to v2 Data Migration -To support time series logic the Mirror Node db schema shifted from PostgeSQL (v1) to TimeScaleDB (v2) +To support time series logic the Mirror Node DB schema shifted from PostgeSQL (v1) to TimeScaleDB (v2). +Adopting the recommended steps [Migrating from a Different PostgreSQL Database](https://docs.timescale.com/latest/getting-started/migrating-data#different-db) we + + For mirror node operators running v1 db schema looking to upgrade to v2 the following steps can be taken 1. Setup a new database using TimeScale -Docker installation recommended - https://docs.timescale.com/latest/getting-started/installation/docker/installation-docker + Docker installation steps are recommended - https://docs.timescale.com/latest/getting-started/installation/docker/installation-docker + + To install using docker-compose: + Update the `docker-compose.override.yml` file to disable postgres instead of TimeScaleDB + ```yaml + version: "3.3" + services: + db: + entrypoint: ["echo", "PostgreSQL db is disabled"] + ``` + + Start up a TimescaleDB service: + ```shell script + $ docker-compose up tsdb + ``` + + Note: If the new db is running on the same server node as the original db, then the port must be updated to something other than 5432. + The `tsdb` port can be updated to a different port e.g. 6432 as follows: + ```yaml + ... + services: + ... + tsdb: + ports: + - 6432:5432 + ``` 2. Create DB & Init Schema -The init script for v2 at `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create teh db, users, schema, extensions and ensure all permissions are set. -This may be run manually against the db node or in teh docker case mounted under `/docker-entrypoint-initdb.d/` on the docker container -> **_NOTE:_** The following steps assume the database, users and schema have been created + The init script for v2 at `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create the db, users, schema, extensions and ensure all permissions are set. + This may be run manually against the db node. In the docker-compose case this file is already mounted under `/docker-entrypoint-initdb.d/` on the docker container and run on startup. + + > **_NOTE:_** The following steps assume the database, users and schema have been created 3. Configure migration properties -A properties file contains variable for easy running. These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. -Updated the values at `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` appropriately + A properties file contains db variable for easy running. These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. + + Update the values at `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` appropriately for your db setup. 4. Run migration script -From the `hedera-mirror-importer/src/main/resources/db` directory run + From the `hedera-mirror-importer/src/main/resources/db` directory run ```shell script $ ./scripts/time-scale-migration/timeScaleDbMigration.sh ``` -Adopting the recommended steps [Migrating from a Different PostgreSQL Database](https://docs.timescale.com/latest/getting-started/migrating-data#different-db) we - ## Monitor The monitor is a Java-based application and should be able to run on any platform that Java supports. That said, we diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql index 68c29decb3e..373a0288f42 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql @@ -1,46 +1,63 @@ -- init the timescale db mirror node db -- Change the values below if you are not installing via Docker +\set db_host 'localhost' +\set db_port 6432 \set db_name 'mirror_node' -\set importer_user 'mirror_node' -\set importer_password 'mirror_node_pass' -\set importer_user 'mirror_node' +\set db_super_user 'postgres' +\set db_owner 'mirror_node' +\set owner_password 'mirror_node_pass' +\set importer_user 'mirror_importer' +\set importer_password 'mirror_importer_pass' \set grpc_user 'mirror_grpc' \set grpc_password 'mirror_grpc_pass' \set rest_user 'mirror_api' \set rest_password 'mirror_api_pass' -\set schema_name 'mirror_node' +\set schema_name 'mirrornode' + +-- create owner user +create user :db_owner with login createrole password :'owner_password'; -- create primary user and db -create database :db_name; -\c :db_name -create extension if not exists timescaledb cascade; +create database :db_name with owner :db_owner; +\c :db_name :db_owner -- create users -create user :importer_user with login createrole password :'importer_password'; +create user :importer_user with login password :'importer_password'; create role viewer; create user :grpc_user with login password :'grpc_password' in role viewer; create user :rest_user with login password :'rest_password' in role viewer; -- grant connect access to api users -grant connect on database :db_name to :grpc_user; -grant connect on database :db_name to :rest_user; +grant connect on database :db_name to viewer; -- schema -create schema if not exists :schema_name; +create schema if not exists :schema_name authorization :db_owner; grant usage on schema :schema_name to public; -grant all privileges on all tables in schema :schema_name to :importer_user; -- alter search path for given schema +alter user :db_owner set search_path = :schema_name, public; alter user :importer_user set search_path = :schema_name, public; alter user :grpc_user set search_path = :schema_name, public; alter user :rest_user set search_path = :schema_name, public; --- grant select privileges on past and future tables to api users +-- grant select privileges on past and future tables and sequences to users +grant all privileges on all tables in schema :schema_name to :db_owner; +grant all privileges on all sequences in schema :schema_name to :db_owner; grant select on all tables in schema :schema_name to :importer_user; grant select on all tables in schema :schema_name to viewer; -alter default privileges for role :importer_user in schema :schema_name grant select on tables to viewer; - --- add extensions -create extension if not exists timescaledb cascade; -create extension pg_stat_statements; +grant select on all sequences in schema :schema_name to :importer_user; +grant select on all sequences in schema :schema_name to viewer; +alter default privileges in schema :schema_name grant select on tables to :importer_user; +alter default privileges in schema :schema_name grant select on tables to viewer; +alter default privileges in schema :schema_name grant select on sequences to :importer_user; +alter default privileges in schema :schema_name grant select on sequences to viewer; + +-- add extensions, ensuring they're available to new schema +-- drop extension if exists timescaledb; +\c :db_name :db_super_user +drop extension if exists timescaledb; +-- must reconnect otherwise fails with "Start a new session and execute CREATE EXTENSION as the first command. Make sure to pass the "-X" flag to psql." +\c :db_name :db_super_user +create extension if not exists timescaledb schema :schema_name cascade; +create extension if not exists pg_stat_statements schema :schema_name; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql index 82eddd8d0f6..deab20c3f1f 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql @@ -18,8 +18,6 @@ \copy (select * from file_data) to file_data.csv delimiter ',' csv; -\copy (select * from flyway_schema_history) to flyway_schema_history.csv delimiter ',' csv; - \copy (select * from live_hash) to live_hash.csv delimiter ',' csv; \copy (select * from non_fee_transfer) to non_fee_transfer.csv delimiter ',' csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql index b56f123ae14..dc77e28c6c9 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql @@ -18,8 +18,6 @@ \copy file_data from file_data.csv csv; -\copy flyway_schema_history from flyway_schema_history.csv csv; - \copy live_hash from live_hash.csv csv; \copy non_fee_transfer from non_fee_transfer.csv csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config index 406907cadfc..61e459c6228 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config @@ -1,6 +1,6 @@ OLD_DB_HOST=localhost OLD_DB_NAME=mirror_node -OLD_DB_PORT=7432 +OLD_DB_PORT=5432 OLD_DB_USER=mirror_node OLD_PASSWORD=mirror_node_pass NEW_DB_HOST=localhost diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql deleted file mode 100644 index a25f438fa49..00000000000 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbInit.sql +++ /dev/null @@ -1,45 +0,0 @@ --- init the timescale db mirror node db --- Change the values below if you are not installing via Docker - -\set db_name 'mirror_node' -\set db_user 'mirror_node' -\set db_password 'mirror_node_pass' -\set db_owner 'mirror_node' -\set grpc_user 'mirror_grpc' -\set grpc_password 'mirror_grpc_pass' -\set rest_user 'mirror_api' -\set rest_password 'mirror_api_pass' -\set schema_name 'mirror_node' - --- create primary user and db -create user :db_user with login createrole password :'db_password'; -create database :db_name with owner :db_owner; - --- create api users -create user :grpc_user with login password :'grpc_password'; -create user :rest_user with login password :'rest_password'; - --- is it necessary to explicitly grant the following? -grant all privileges on database :db_name to :db_user; - --- grant connect access to api users -grant connect on database :db_name to :grpc_user; -grant connect on database :db_name to :rest_user; - -\c :db_name - --- schema -create schema if not exists :schema_name; -grant usage on schema :schema_name to public; -grant all privileges on all tables in schema :schema_name to :db_user; - --- alter search path for given schema -alter user :db_user set search_path = :schema_name, public; -alter user :grpc_user set search_path = :schema_name, public; -alter user :rest_user set search_path = :schema_name, public; - --- grant select privileges on past and future tables to api users -alter default privileges in schema :schema_name grant select on tables to :grpc_user; -alter default privileges in schema :schema_name grant select on tables to :rest_user; -grant select on all tables in schema :schema_name to :grpc_user; -grant select on all tables in schema :schema_name to :rest_user; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh index 77bb2580663..c97d1c33509 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh @@ -59,7 +59,7 @@ start_time="$(date -u +%s)" echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." echo "1. Backing up flyway table schema from Postgres($OLD_DB_HOST:$OLD_DB_PORT)..." -PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --section=pre-data --table public.flyway_schema_history -f mirror_node_${start_time}.bak mirror_node +PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --table public.flyway_schema_history -f mirror_node_${start_time}.bak mirror_node echo "2. Restoring flyway_schema_history to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER Date: Tue, 22 Dec 2020 22:36:04 -0600 Subject: [PATCH 06/22] CLeaned up docs Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docs/operations.md | 41 +++++++++++++++++++++++++---------------- 1 file changed, 25 insertions(+), 16 deletions(-) diff --git a/docs/operations.md b/docs/operations.md index 47b6bdd42ad..118605f1a3c 100644 --- a/docs/operations.md +++ b/docs/operations.md @@ -95,17 +95,14 @@ sudo journalctl -fu hedera-mirror-importer.service ### v1 to v2 Data Migration -To support time series logic the Mirror Node DB schema shifted from PostgeSQL (v1) to TimeScaleDB (v2). -Adopting the recommended steps [Migrating from a Different PostgreSQL Database](https://docs.timescale.com/latest/getting-started/migrating-data#different-db) we +To support time series logic the Mirror Node DB schema shifted from PostgeSQL (v1) to TimescaleDB (v2). +[Migrating from a Different PostgreSQL Database](https://docs.timescale.com/latest/getting-started/migrating-data#different-db) highlights the general recommended data migration steps when moving to TimescaleDB. +For mirror node operators running v1 db schema, the following steps can be taken to upgrade to v2. -For mirror node operators running v1 db schema looking to upgrade to v2 the following steps can be taken +1. Setup a new database container using TimeScale -1. Setup a new database using TimeScale - Docker installation steps are recommended - https://docs.timescale.com/latest/getting-started/installation/docker/installation-docker - - To install using docker-compose: - Update the `docker-compose.override.yml` file to disable postgres instead of TimeScaleDB + To install using docker-compose, update the `docker-compose.override.yml` file to disable postgres instead of TimeScaleDB ```yaml version: "3.3" @@ -114,12 +111,12 @@ For mirror node operators running v1 db schema looking to upgrade to v2 the foll entrypoint: ["echo", "PostgreSQL db is disabled"] ``` - Start up a TimescaleDB service: + Start up the TimescaleDB service: ```shell script $ docker-compose up tsdb ``` - Note: If the new db is running on the same server node as the original db, then the port must be updated to something other than 5432. + Note: If the new db is running on the same server node as the original PostgeSQL db, then the port must be updated to something other than 5432. The `tsdb` port can be updated to a different port e.g. 6432 as follows: ```yaml ... @@ -132,24 +129,36 @@ For mirror node operators running v1 db schema looking to upgrade to v2 the foll 2. Create DB & Init Schema - The init script for v2 at `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create the db, users, schema, extensions and ensure all permissions are set. - This may be run manually against the db node. In the docker-compose case this file is already mounted under `/docker-entrypoint-initdb.d/` on the docker container and run on startup. + The init script for v2 `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create the database, users, schema, extensions and ensure all permissions are set. + In the docker-compose case this file is already mounted under `/docker-entrypoint-initdb.d/` on the docker container and run on startup. - > **_NOTE:_** The following steps assume the database, users and schema have been created + This may be run manually against the db node if not using docker-compose: + ```shell script + $ psql "dbname=mirror_node host=localhost user=mirror_importer password=mirror_importer_pass port=6432" -f hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql + ``` + + > **_NOTE:_** The following steps assume the database, users and schema have been created as detailed above 3. Configure migration properties - A properties file contains db variable for easy running. These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. + The configuration file `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` contains db variables for easy running. + These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. - Update the values at `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` appropriately for your db setup. + Update these values appropriately for your db setup. 4. Run migration script - From the `hedera-mirror-importer/src/main/resources/db` directory run + From the `hedera-mirror-importer/src/main/resources/db` directory run the `timeScaleDbMigration.sh` script ```shell script $ ./scripts/time-scale-migration/timeScaleDbMigration.sh ``` + The script uses successive `psql` connections to backup, configure and restore data on the new database nodes. + First it copies over the `flyway_schema_history` table, to maintain migration history. + It then utilizes the migration sql script used by normal flyway operations to create the new tables and then creates the Timescale hyper tables based on these. + Following this the tables from the old database are backed up as csv files using `\COPY` and then the data inserted into the new database also using `\COPY`. + Finally the schema of the `flyway_schema_history` is updated and the sequence values are updated to ensure continuation. + ## Monitor The monitor is a Java-based application and should be able to run on any platform that Java supports. That said, we From b04b0d27963f58d03ad0cf44b3a59b7e5c1a3152 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Mon, 4 Jan 2021 12:03:56 -0600 Subject: [PATCH 07/22] Cleaned up docs Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../templates/job-timescaledb-init.yaml | 2 +- .../templates/secret-postgresql.yaml | 2 +- .../templates/secret-timescaledb.yaml | 2 +- docker-compose.override.yml | 4 -- docker-compose.yml | 6 ++- docs/installation.md | 54 +++++++++++++++---- docs/operations.md | 48 +++++------------ .../src/main/resources/db/scripts/drop.sql | 2 +- .../db/scripts/{init.sql => init_v1.sql} | 0 .../alterSchema.sql | 0 .../createHyperTables.sql | 0 .../csvBackupTables.sql | 0 .../csvRestoreTables.sql | 0 .../migration.config | 0 .../migration.sh} | 44 +++++++-------- 15 files changed, 86 insertions(+), 78 deletions(-) delete mode 100644 docker-compose.override.yml rename hedera-mirror-importer/src/main/resources/db/scripts/{init.sql => init_v1.sql} (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration => timescaledb}/alterSchema.sql (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration => timescaledb}/createHyperTables.sql (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration => timescaledb}/csvBackupTables.sql (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration => timescaledb}/csvRestoreTables.sql (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration => timescaledb}/migration.config (100%) rename hedera-mirror-importer/src/main/resources/db/scripts/{time-scale-migration/timeScaleDbMigration.sh => timescaledb/migration.sh} (55%) diff --git a/charts/hedera-mirror/templates/job-timescaledb-init.yaml b/charts/hedera-mirror/templates/job-timescaledb-init.yaml index 5ab5b38c750..a71f647852a 100644 --- a/charts/hedera-mirror/templates/job-timescaledb-init.yaml +++ b/charts/hedera-mirror/templates/job-timescaledb-init.yaml @@ -28,7 +28,7 @@ spec: - name: ACCESS_SVC_CONNSTR_POSTGRES value: host={{ include "hedera-mirror.dbHost" . }} user=postgres connect_timeout=3 sslmode=disable password={{ .Values.timescaledb.credentials.accessNode.superuser }} - name: DB_INIT_FILE - value: /usr/etc/db-init/init.sql + value: /usr/etc/db-init/init_v2.sql volumeMounts: - name: timescale-db-init-volume mountPath: /usr/etc/db-init diff --git a/charts/hedera-mirror/templates/secret-postgresql.yaml b/charts/hedera-mirror/templates/secret-postgresql.yaml index 603bbead508..4297b39e05d 100644 --- a/charts/hedera-mirror/templates/secret-postgresql.yaml +++ b/charts/hedera-mirror/templates/secret-postgresql.yaml @@ -8,7 +8,7 @@ metadata: namespace: {{ include "hedera-mirror.namespace" . }} type: Opaque stringData: - init.sql: |- + init_v1.sql: |- {{- $dbname := .Values.importer.config.hedera.mirror.importer.db.name }} {{- $password := .Values.importer.config.hedera.mirror.importer.db.password }} {{- $username := .Values.importer.config.hedera.mirror.importer.db.username }} diff --git a/charts/hedera-mirror/templates/secret-timescaledb.yaml b/charts/hedera-mirror/templates/secret-timescaledb.yaml index e63a1815aef..e0facfb8475 100644 --- a/charts/hedera-mirror/templates/secret-timescaledb.yaml +++ b/charts/hedera-mirror/templates/secret-timescaledb.yaml @@ -8,7 +8,7 @@ metadata: namespace: {{ include "hedera-mirror.namespace" . }} type: Opaque stringData: - init.sql: |- + init_v2.sql: |- {{- $dbName := .Values.importer.config.hedera.mirror.importer.db.name }} {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} {{- $importerPassword := .Values.importer.config.hedera.mirror.importer.db.password }} diff --git a/docker-compose.override.yml b/docker-compose.override.yml deleted file mode 100644 index f263f9124f1..00000000000 --- a/docker-compose.override.yml +++ /dev/null @@ -1,4 +0,0 @@ -version: "3.3" -services: - tsdb: - entrypoint: ["echo", "TimeScaleDB service is disabled"] diff --git a/docker-compose.yml b/docker-compose.yml index cbd989a4c7b..7883b98e4e9 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -68,7 +68,9 @@ services: ports: - 5551:5551 - tsdb: + timescaledb: + deploy: + replicas: 0 image: timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 restart: unless-stopped stop_grace_period: 2m @@ -80,4 +82,4 @@ services: - ./tsdb:/var/lib/postgresql/data - ./hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql/:/docker-entrypoint-initdb.d/init_v2.sql ports: - - 6432:5432 + - 5432:5432 diff --git a/docs/installation.md b/docs/installation.md index 8b1363cbf55..632ce2c4df1 100644 --- a/docs/installation.md +++ b/docs/installation.md @@ -19,16 +19,29 @@ runnable Mirror Node JAR file in the `target` directory. ## Running Locally ### Database Setup +In addition to OpenJDK 11, you will need to install a database and initialize it. +The Mirror Node utilizes [PostgreSQL](https://postgresql.org) v9.6 or [TimescaleDB](https://docs.timescale.com/latest/main) v2 depending on the version of its database schema. -In addition to OpenJDK 11, you will need to install [PostgreSQL](https://postgresql.org) 9.6 and initialize it. The only -setup required is to create the initial database and owner since [Flyway](https://flywaydb.org) manages the database -schema. The SQL script located at `hedera-mirror-importer/src/main/resources/db/scripts/init.sql` can be used to -accomplish this. Edit the file and change the `db_name`, `db_user`, `db_password` `db_owner`, `grpc_user`, or -`grpc_password` as appropriate. Make sure the application [configuration](configuration.md) matches the values in the -script. Run the script as a DB admin user and check the output carefully to ensure no errors occurred. +In both cases the only setup required is to create the initial database, users, schema, extensions and ensure all +permissions are set since [Flyway](https://flywaydb.org) manages the database schema. +Scripts for v1 and v2 are provided to accomplish this. +Make sure the application [configuration](configuration.md) matches the values in the script. +Run the script as a super user and check the output carefully to ensure no errors occurred. + +#### PostgreSQL (V1) +Run the SQL script located at `hedera-mirror-importer/src/main/resources/db/scripts/init_v1.sql`. +Edit the file and change the `db_name`, `db_user`, `db_password` `db_owner`, `grpc_user`, or `grpc_password` as appropriate. ```console -psql postgres -f hedera-mirror-importer/src/main/resources/db/scripts/init.sql +psql postgres -f hedera-mirror-importer/src/main/resources/db/scripts/init_v1.sql +``` + +#### TimescaleDB (V2) +Run the SQL script located at `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql`. +Edit the file and change the db user names, passwords and schema as appropriate. + +```console +psql postgres -f hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql ``` ### Importer @@ -86,7 +99,7 @@ npm test Docker Compose scripts are provided and run all the mirror node components: -- PostgreSQL database +- PostgreSQL/TimescaleDB database - GRPC API - Importer - Monitor @@ -95,14 +108,33 @@ Docker Compose scripts are provided and run all the mirror node components: Containers use the following persisted volumes: - `./db` on your local machine maps to `/var/lib/postgresql/data` in the containers. This contains the files for the - PostgreSQL database. If the database container fails to initialise properly and the database fails to run, you will - have to delete this folder prior to attempting a restart otherwise the database initialisation scripts will not be - run. + PostgreSQL/TimescaleDB database. If the database container fails to initialise properly and the database fails to run, + you will have to delete this folder prior to attempting a restart otherwise the database initialisation scripts will + not be run. - `./data` on your local machine maps to `/var/lib/hedera-mirror-importer` in the container. This contains files downloaded from S3 or GCP. These are necessary not only for the database data to be persisted, but also so that the parsing containers can access file obtained via the downloading containers +### Configuration + +#### TimescaleDB vs PostgreSQL +To utilize the TimescaleDB database over the default PostgreSQL database, disable the PostgreSQL container and enable the TimescaleDB container. + +To achieve this the `docker-compose.yml` can be updated as follows: +```yaml + ... + services: + db: + deploy: + replicas: 0 + ... + timescaledb: + # deploy: + # replicas: 0 + ... +``` + ### Starting Before starting, [configure](configuration.md) the application by updating the [application.yml](../application.yml) diff --git a/docs/operations.md b/docs/operations.md index 118605f1a3c..4f595889088 100644 --- a/docs/operations.md +++ b/docs/operations.md @@ -100,57 +100,34 @@ To support time series logic the Mirror Node DB schema shifted from PostgeSQL (v For mirror node operators running v1 db schema, the following steps can be taken to upgrade to v2. -1. Setup a new database container using TimeScale +1. Setup a new TimescaleDB database - To install using docker-compose, update the `docker-compose.override.yml` file to disable postgres instead of TimeScaleDB + A new TimescaleDB server must be spun up. - ```yaml - version: "3.3" - services: - db: - entrypoint: ["echo", "PostgreSQL db is disabled"] - ``` - - Start up the TimescaleDB service: - ```shell script - $ docker-compose up tsdb - ``` + Refer to Mirror Node [DB Installation](installation.md#database-setup) for manual instructions. - Note: If the new db is running on the same server node as the original PostgeSQL db, then the port must be updated to something other than 5432. - The `tsdb` port can be updated to a different port e.g. 6432 as follows: - ```yaml - ... - services: - ... - tsdb: - ports: - - 6432:5432 - ``` - -2. Create DB & Init Schema - - The init script for v2 `hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql` may be used to create the database, users, schema, extensions and ensure all permissions are set. - In the docker-compose case this file is already mounted under `/docker-entrypoint-initdb.d/` on the docker container and run on startup. + To use the Mirror Node configured docker container, simply run: - This may be run manually against the db node if not using docker-compose: ```shell script - $ psql "dbname=mirror_node host=localhost user=mirror_importer password=mirror_importer_pass port=6432" -f hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql + $ docker-compose up timescaledb ``` + Refer to [TimescaleDB Installation Instructions](https://docs.timescale.com/latest/getting-started/installation) for other installation options. + > **_NOTE:_** The following steps assume the database, users and schema have been created as detailed above -3. Configure migration properties +2. Configure migration properties - The configuration file `hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config` contains db variables for easy running. + The configuration file `hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config` contains db variables for easy running. These options include variables such as db names, passwords, users, hosts for both the existing db and the new db. Update these values appropriately for your db setup. -4. Run migration script +3. Run migration script - From the `hedera-mirror-importer/src/main/resources/db` directory run the `timeScaleDbMigration.sh` script + From the `hedera-mirror-importer/src/main/resources/db` directory run the `migration.sh` script ```shell script - $ ./scripts/time-scale-migration/timeScaleDbMigration.sh + $ ./scripts/timescaledb/migration.sh ``` The script uses successive `psql` connections to backup, configure and restore data on the new database nodes. @@ -290,4 +267,5 @@ available - `/swagger/ui` - Metrics dashboard - `/swagger/stats` - Aggregated statistics - `/swagger/metrics` - Prometheus formatted metrics + Where `swagger` is the default metrics path as controlled by `hedera.mirror.rest.metrics.config.uriPath`. diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/drop.sql b/hedera-mirror-importer/src/main/resources/db/scripts/drop.sql index c7334f65413..e6f07e3907c 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/drop.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/drop.sql @@ -4,7 +4,7 @@ -- drop tables, views, indexes, data types, functions, stored procedures and operators associated with db drop schema if exists public cascade; --- recreate schema used by init.sql +-- recreate schema used by init_v1.sql create schema public; grant usage on schema public to public; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v1.sql similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/init.sql rename to hedera-mirror-importer/src/main/resources/db/scripts/init_v1.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/alterSchema.sql rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/createHyperTables.sql rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvBackupTables.sql rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvRestoreTables.sql similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/csvRestoreTables.sql rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvRestoreTables.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config similarity index 100% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/migration.config rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh similarity index 55% rename from hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh rename to hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh index c97d1c33509..c4b5ba31488 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/time-scale-migration/timeScaleDbMigration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh @@ -2,83 +2,83 @@ echo "BASH_VERSION: $BASH_VERSION" set -e -. scripts/time-scale-migration/migration.config +. scripts/timescaledb-migration/migration.config if [[ -z $OLD_DB_HOST ]]; then - echo "Current host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "Old host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $OLD_DB_NAME ]]; then - echo "Current db name is not set. Please configure OLD_DB_NAME in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "Old db name is not set. Please configure OLD_DB_NAME in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $OLD_DB_PORT ]]; then - echo "Current port is not set. Please configure OLD_DB_PORT in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "Old port is not set. Please configure OLD_DB_PORT in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $OLD_DB_USER ]]; then - echo "Current db primary user name is not set. Please configure OLD_DB_USER in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "Old db primary user name is not set. Please configure OLD_DB_USER in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $OLD_PASSWORD ]]; then - echo "Old db primary user password is not set. Please configure OLD_PASSWORD in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "Old db primary user password is not set. Please configure OLD_PASSWORD in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $NEW_DB_HOST ]]; then - echo "New host name is not set. Please configure NEW_DB_HOST in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "New host name is not set. Please configure NEW_DB_HOST in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $NEW_DB_NAME ]]; then - echo "New db name is not set. Please configure NEW_DB_NAME in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "New db name is not set. Please configure NEW_DB_NAME in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $NEW_DB_PORT ]]; then - echo "New db port is not set. Please configure NEW_DB_PORT in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "New db port is not set. Please configure NEW_DB_PORT in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $NEW_DB_USER ]]; then - echo "New db primary user name is not set. Please configure NEW_DB_USER in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "New db primary user name is not set. Please configure NEW_DB_USER in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi if [[ -z $NEW_PASSWORD ]]; then - echo "New db primary user password is not set. Please configure NEW_PASSWORD in migration.config file and rerun './timeScaleDbMigration.sh'" + echo "New db primary user password is not set. Please configure NEW_PASSWORD in migration.config file and rerun './timescaleDBMigration.sh'" exit 1 fi start_time="$(date -u +%s)" -# assumes 1. Valid populated current mirror node postgres db with appropriate user 2. New empty TimeScaleDb db host with appropriate user -echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." +# assumes 1. Valid populated old mirror node postgres db with appropriate user 2. New empty TimescaleDB db host with appropriate user +echo "Migrating Mirror Node Data from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." echo "1. Backing up flyway table schema from Postgres($OLD_DB_HOST:$OLD_DB_PORT)..." PGPASSWORD=${OLD_PASSWORD} pg_dump -h $OLD_DB_HOST -p $OLD_DB_PORT -U $OLD_DB_USER --table public.flyway_schema_history -f mirror_node_${start_time}.bak mirror_node -echo "2. Restoring flyway_schema_history to TimeScaleDb($NEW_DB_HOST:$NEW_DB_PORT)..." +echo "2. Restoring flyway_schema_history to TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER Date: Mon, 4 Jan 2021 16:32:34 -0600 Subject: [PATCH 08/22] Add logic to reuse V2.0.1__hyper_tables.sql Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../src/main/resources/db/scripts/init_v2.sql | 61 +++++++------ .../scripts/timescaledb/createHyperTables.sql | 89 ------------------- .../scripts/timescaledb/csvBackupTables.sql | 44 ++++----- .../db/scripts/timescaledb/migration.sh | 44 +++++---- 4 files changed, 84 insertions(+), 154 deletions(-) delete mode 100644 hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql index 373a0288f42..4250b6ec9e0 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql @@ -16,48 +16,53 @@ \set schema_name 'mirrornode' -- create owner user -create user :db_owner with login createrole password :'owner_password'; +create user :db_owner with login password :'owner_password'; -- create primary user and db create database :db_name with owner :db_owner; -\c :db_name :db_owner --- create users -create user :importer_user with login password :'importer_password'; -create role viewer; -create user :grpc_user with login password :'grpc_password' in role viewer; -create user :rest_user with login password :'rest_password' in role viewer; +-- create roles +create role readonly; +create role readwrite in role readonly; --- grant connect access to api users -grant connect on database :db_name to viewer; +-- create users +create user :grpc_user with login password :'grpc_password' in role readonly; +create user :rest_user with login password :'rest_password' in role readonly; +create user :importer_user with login password :'importer_password' in role readwrite; --- schema +-- connect with db owner to create schema and set schema user permissions +\c :db_name :db_owner create schema if not exists :schema_name authorization :db_owner; grant usage on schema :schema_name to public; --- alter search path for given schema +-- revoke default public permissions on schema +revoke create on schema :schema_name from public; + +-- grant connect and schema access to readonly role +grant connect on database :db_name to readonly; +grant usage on schema :schema_name to readonly; + +-- grant select privileges on tables to readonly +-- grant all privileges on all tables in schema :schema_name to :db_owner; +grant select on all tables in schema :schema_name to readonly; +alter default privileges in schema :schema_name grant select on tables to readonly; + +-- grant select privileges on sequences to readonly +-- grant all privileges on all sequences in schema :schema_name to :db_owner; +grant select on all sequences in schema :schema_name to readonly; +alter default privileges in schema :schema_name grant select on sequences to readonly; + +-- grant write privileges on sequences to readwrite +grant insert, update, delete on all tables in schema :schema_name to readwrite; +alter default privileges in schema :schema_name grant insert, update, delete on tables to readwrite; + +-- alter search path for given schema as super user +\c :db_name :db_super_user alter user :db_owner set search_path = :schema_name, public; alter user :importer_user set search_path = :schema_name, public; alter user :grpc_user set search_path = :schema_name, public; alter user :rest_user set search_path = :schema_name, public; --- grant select privileges on past and future tables and sequences to users -grant all privileges on all tables in schema :schema_name to :db_owner; -grant all privileges on all sequences in schema :schema_name to :db_owner; -grant select on all tables in schema :schema_name to :importer_user; -grant select on all tables in schema :schema_name to viewer; -grant select on all sequences in schema :schema_name to :importer_user; -grant select on all sequences in schema :schema_name to viewer; -alter default privileges in schema :schema_name grant select on tables to :importer_user; -alter default privileges in schema :schema_name grant select on tables to viewer; -alter default privileges in schema :schema_name grant select on sequences to :importer_user; -alter default privileges in schema :schema_name grant select on sequences to viewer; - -- add extensions, ensuring they're available to new schema --- drop extension if exists timescaledb; -\c :db_name :db_super_user -drop extension if exists timescaledb; --- must reconnect otherwise fails with "Start a new session and execute CREATE EXTENSION as the first command. Make sure to pass the "-X" flag to psql." -\c :db_name :db_super_user create extension if not exists timescaledb schema :schema_name cascade; create extension if not exists pg_stat_statements schema :schema_name; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql deleted file mode 100644 index c5b4536a793..00000000000 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/createHyperTables.sql +++ /dev/null @@ -1,89 +0,0 @@ -------------------- --- Create hyper tables from v1 schema, inserts from old table, add indexes --- Use default of 604800000000000 ns (7 days) as chunk time interval -------------------- - --- refer to spring.flyway.placeholders for latest values of chunkIdInterval and chunkTimeInterval -\set chunkIdInterval 10000 -\set chunkTimeInterval 604800000000000 - --- account_balance -select create_hypertable('account_balance', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- account_balance_file -select create_hypertable('account_balance_file', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- account_balance_sets -select create_hypertable('account_balance_sets', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- address_book -select create_hypertable('address_book', 'start_consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- address_book_entry -select create_hypertable('address_book_entry', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- contract_result -select create_hypertable('contract_result', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- crypto_transfer -select create_hypertable('crypto_transfer', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- file_data -select create_hypertable('file_data', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- live_hash -select create_hypertable('live_hash', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- non_fee_transfer -select create_hypertable('non_fee_transfer', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- record_file -select create_hypertable('record_file', 'consensus_start', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- t_application_status hyper table creation skipped as it serves only as a reference table - --- t_entities -select create_hypertable('t_entities', 'id', - chunk_time_interval => :chunkIdInterval, if_not_exists => true); - --- t_entity_types hyper table creation skipped as it serves only as a reference table and rarely gets updated - --- t_transaction_results hyper table creation skipped as it serves only as a reference table and rarely gets updated - --- t_transaction_types hyper table creation skipped as it serves only as a reference table and rarely gets updated - --- token -select create_hypertable('token', 'created_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- token_account -select create_hypertable('token_account', 'created_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- token_balance -select create_hypertable('token_balance', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- token_transfer -select create_hypertable('token_transfer', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- topic_message -select create_hypertable('topic_message', 'consensus_timestamp', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - --- transaction -select create_hypertable('transaction', 'consensus_ns', - chunk_time_interval => :chunkTimeInterval, if_not_exists => true); - diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql index deab20c3f1f..9e344d3dd0f 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/csvBackupTables.sql @@ -2,46 +2,46 @@ -- Backup tables use efficient COPY process to CSV's ------------------- -\copy (select * from account_balance) to account_balance.csv delimiter ',' csv; +\copy account_balance to account_balance.csv delimiter ',' csv; -\copy (select * from account_balance_file) to account_balance_file.csv delimiter ',' csv; +\copy account_balance_file to account_balance_file.csv delimiter ',' csv; -\copy (select * from account_balance_sets) to account_balance_sets.csv delimiter ',' csv; +\copy account_balance_sets to account_balance_sets.csv delimiter ',' csv; -\copy (select * from address_book) to address_book.csv delimiter ',' csv; +\copy address_book to address_book.csv delimiter ',' csv; -\copy (select * from address_book_entry) to address_book_entry.csv delimiter ',' csv; +\copy address_book_entry to address_book_entry.csv delimiter ',' csv; -\copy (select * from contract_result) to contract_result.csv delimiter ',' csv; +\copy contract_result to contract_result.csv delimiter ',' csv; -\copy (select * from crypto_transfer) to crypto_transfer.csv delimiter ',' csv; +\copy crypto_transfer to crypto_transfer.csv delimiter ',' csv; -\copy (select * from file_data) to file_data.csv delimiter ',' csv; +\copy file_data to file_data.csv delimiter ',' csv; -\copy (select * from live_hash) to live_hash.csv delimiter ',' csv; +\copy live_hash to live_hash.csv delimiter ',' csv; -\copy (select * from non_fee_transfer) to non_fee_transfer.csv delimiter ',' csv; +\copy non_fee_transfer to non_fee_transfer.csv delimiter ',' csv; -\copy (select * from record_file) to record_file.csv delimiter ',' csv; +\copy record_file to record_file.csv delimiter ',' csv; -\copy (select * from t_application_status) to t_application_status.csv delimiter ',' csv; +\copy t_application_status to t_application_status.csv delimiter ',' csv; -\copy (select * from t_entities) to t_entities.csv delimiter ',' csv; +\copy t_entities to t_entities.csv delimiter ',' csv; -\copy (select * from t_entity_types) to t_entity_types.csv delimiter ',' csv; +\copy t_entity_types to t_entity_types.csv delimiter ',' csv; -\copy (select * from t_transaction_results) to t_transaction_results.csv delimiter ',' csv; +\copy t_transaction_results to t_transaction_results.csv delimiter ',' csv; -\copy (select * from t_transaction_types) to t_transaction_types.csv delimiter ',' csv; +\copy t_transaction_types to t_transaction_types.csv delimiter ',' csv; -\copy (select * from token) to token.csv delimiter ',' csv; +\copy token to token.csv delimiter ',' csv; -\copy (select * from token_account) to token_account.csv delimiter ',' csv; +\copy token_account to token_account.csv delimiter ',' csv; -\copy (select * from token_balance) to token_balance.csv delimiter ',' csv; +\copy token_balance to token_balance.csv delimiter ',' csv; -\copy (select * from token_transfer) to token_transfer.csv delimiter ',' csv; +\copy token_transfer to token_transfer.csv delimiter ',' csv; -\copy (select * from topic_message) to topic_message.csv delimiter ',' csv; +\copy topic_message to topic_message.csv delimiter ',' csv; -\copy (select * from transaction) to transaction.csv delimiter ',' csv; +\copy transaction to transaction.csv delimiter ',' csv; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh index c4b5ba31488..f46ab6eac78 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh @@ -2,55 +2,65 @@ echo "BASH_VERSION: $BASH_VERSION" set -e -. scripts/timescaledb-migration/migration.config +. scripts/timescaledb/migration.config if [[ -z $OLD_DB_HOST ]]; then - echo "Old host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './timescaleDBMigration.sh'" + echo "Old host name is not set. Please configure OLD_DB_HOST in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $OLD_DB_NAME ]]; then - echo "Old db name is not set. Please configure OLD_DB_NAME in migration.config file and rerun './timescaleDBMigration.sh'" + echo "Old db name is not set. Please configure OLD_DB_NAME in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $OLD_DB_PORT ]]; then - echo "Old port is not set. Please configure OLD_DB_PORT in migration.config file and rerun './timescaleDBMigration.sh'" + echo "Old port is not set. Please configure OLD_DB_PORT in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $OLD_DB_USER ]]; then - echo "Old db primary user name is not set. Please configure OLD_DB_USER in migration.config file and rerun './timescaleDBMigration.sh'" + echo "Old db primary user name is not set. Please configure OLD_DB_USER in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $OLD_PASSWORD ]]; then - echo "Old db primary user password is not set. Please configure OLD_PASSWORD in migration.config file and rerun './timescaleDBMigration.sh'" + echo "Old db primary user password is not set. Please configure OLD_PASSWORD in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $NEW_DB_HOST ]]; then - echo "New host name is not set. Please configure NEW_DB_HOST in migration.config file and rerun './timescaleDBMigration.sh'" + echo "New host name is not set. Please configure NEW_DB_HOST in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $NEW_DB_NAME ]]; then - echo "New db name is not set. Please configure NEW_DB_NAME in migration.config file and rerun './timescaleDBMigration.sh'" + echo "New db name is not set. Please configure NEW_DB_NAME in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $NEW_DB_PORT ]]; then - echo "New db port is not set. Please configure NEW_DB_PORT in migration.config file and rerun './timescaleDBMigration.sh'" + echo "New db port is not set. Please configure NEW_DB_PORT in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $NEW_DB_USER ]]; then - echo "New db primary user name is not set. Please configure NEW_DB_USER in migration.config file and rerun './timescaleDBMigration.sh'" + echo "New db primary user name is not set. Please configure NEW_DB_USER in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi if [[ -z $NEW_PASSWORD ]]; then - echo "New db primary user password is not set. Please configure NEW_PASSWORD in migration.config file and rerun './timescaleDBMigration.sh'" + echo "New db primary user password is not set. Please configure NEW_PASSWORD in migration.config file and rerun './scripts/timescaledb/migration.sh'" + exit 1 +fi + +if [[ -z $CHUNK_INTERVAL_TIME ]]; then + echo "New db chunk interval time is not set. Please configure CHUNK_INTERVAL_TIME in migration.config file and rerun './scripts/timescaledb/migration.sh'" + exit 1 +fi + +if [[ -z $CHUNK_INTERVAL_ID ]]; then + echo "New db chunk interval id is not set. Please configure CHUNK_INTERVAL_ID in migration.config file and rerun './scripts/timescaledb/migration.sh'" exit 1 fi @@ -68,17 +78,21 @@ echo "3. Create v2 table schemas in TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER scripts/timescaledb/createHyperTables_0.sql +sed 's/${chunkIdInterval}/'$CHUNK_INTERVAL_ID'/g' scripts/timescaledb/createHyperTables_0.sql >scripts/timescaledb/createHyperTables.sql +PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb/createHyperTables.sql +rm scripts/timescaledb/createHyperTables_0.sql +rm scripts/timescaledb/createHyperTables.sql echo "5. Backing up tables from from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to separate CSV's..." -PGPASSWORD=${OLD_PASSWORD} psql -h $OLD_DB_HOST -d $OLD_DB_NAME -p $OLD_DB_PORT -U $OLD_DB_USER -f scripts/timescaledb-migration/csvBackupTables.sql +PGPASSWORD=${OLD_PASSWORD} psql -h $OLD_DB_HOST -d $OLD_DB_NAME -p $OLD_DB_PORT -U $OLD_DB_USER -f scripts/timescaledb/csvBackupTables.sql ## Optionally use https://github.com/timescale/timescaledb-parallel-copy as it's mulithreaded echo "6. Restoring CSV backups to TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." -PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb-migration/csvRestoreTables.sql +PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb/csvRestoreTables.sql echo "7. Alter schema on TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT) to support improved format..." -PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb-migration/alterSchema.sql +PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb/alterSchema.sql # leave index creation and policy sets to migration 2.0 end_time="$(date -u +%s)" From bb0185b21f744fa3788043127024bc618ed04185 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Mon, 4 Jan 2021 16:44:50 -0600 Subject: [PATCH 09/22] Improved sed process Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docker-compose.yml | 2 +- .../main/resources/db/scripts/timescaledb/migration.config | 2 ++ .../src/main/resources/db/scripts/timescaledb/migration.sh | 5 +---- 3 files changed, 4 insertions(+), 5 deletions(-) diff --git a/docker-compose.yml b/docker-compose.yml index 7883b98e4e9..d730b78db2d 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -79,7 +79,7 @@ services: environment: POSTGRES_PASSWORD: mirror_node_pass volumes: - - ./tsdb:/var/lib/postgresql/data + - ./timescaledb:/var/lib/postgresql/data - ./hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql/:/docker-entrypoint-initdb.d/init_v2.sql ports: - 5432:5432 diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config index 61e459c6228..70f0d71dbf8 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.config @@ -8,3 +8,5 @@ NEW_DB_NAME=mirror_node NEW_DB_PORT=6432 NEW_DB_USER=mirror_node NEW_PASSWORD=mirror_node_pass +CHUNK_INTERVAL_TIME=604800000000000 +CHUNK_INTERVAL_ID=10000 diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh index f46ab6eac78..80606144d36 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh @@ -78,11 +78,8 @@ echo "3. Create v2 table schemas in TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER scripts/timescaledb/createHyperTables_0.sql -sed 's/${chunkIdInterval}/'$CHUNK_INTERVAL_ID'/g' scripts/timescaledb/createHyperTables_0.sql >scripts/timescaledb/createHyperTables.sql +sed -e 's/${chunkTimeInterval}/'$CHUNK_INTERVAL_TIME'/g' -e 's/${chunkIdInterval}/'$CHUNK_INTERVAL_ID'/g' migration/v2/V2.0.1__hyper_tables.sql >scripts/timescaledb/createHyperTables.sql PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb/createHyperTables.sql -rm scripts/timescaledb/createHyperTables_0.sql -rm scripts/timescaledb/createHyperTables.sql echo "5. Backing up tables from from Postgres($OLD_DB_HOST:$OLD_DB_PORT) to separate CSV's..." PGPASSWORD=${OLD_PASSWORD} psql -h $OLD_DB_HOST -d $OLD_DB_NAME -p $OLD_DB_PORT -U $OLD_DB_USER -f scripts/timescaledb/csvBackupTables.sql From b48698a5dc69158b3fa7bc50882808dfad2644ad Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Mon, 4 Jan 2021 17:30:43 -0600 Subject: [PATCH 10/22] Removed duplicate indexes and updated chart dependencies Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- charts/hedera-mirror/requirements.lock | 8 +++--- .../v2/V2.0.2__time_scale_index_init.sql | 28 ++++++------------- 2 files changed, 12 insertions(+), 24 deletions(-) diff --git a/charts/hedera-mirror/requirements.lock b/charts/hedera-mirror/requirements.lock index b0637cb04e0..49ac6e5c402 100644 --- a/charts/hedera-mirror/requirements.lock +++ b/charts/hedera-mirror/requirements.lock @@ -10,15 +10,15 @@ dependencies: version: 0.12.0-rc1 - name: postgresql-ha repository: https://charts.bitnami.com/bitnami - version: 6.3.2 + version: 6.3.4 - name: redis repository: https://charts.bitnami.com/bitnami - version: 12.2.3 + version: 12.2.4 - name: hedera-mirror-rest repository: file://../hedera-mirror-rest version: 0.12.0-rc1 - name: timescaledb-multinode repository: https://raw.githubusercontent.com/timescale/timescaledb-kubernetes/master/charts/repo/ version: 0.7.0 -digest: sha256:b261bda6d871b9ddc44e06ad21b51429a14028ca8db2ff330d54a11e5109e630 -generated: "2020-12-21T15:48:49.454221-06:00" +digest: sha256:5b4f3a8e19c559e3507fce9339b86f91a82da8cbe57eee076c5d67f085c5b3f8 +generated: "2021-01-04T17:28:47.546372-06:00" diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index aae173d72b6..7b1d305dc9e 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -20,13 +20,9 @@ create unique index if not exists account_balance_file__name alter table account_balance_file add constraint account_balance_file_timestamp primary key (consensus_timestamp); --- address_book -alter table address_book - add constraint address_book_start_timestamp primary key (start_consensus_timestamp); +-- address_book, desc index on start_consensus_timestamp already created by hypertable --- address_book_entry -create index if not exists address_book_entry__timestamp - on address_book_entry (consensus_timestamp); +-- address_book_entry, desc index on consensus_timestamp already created by hypertable -- contract_result create index if not exists contract_result__consensus @@ -40,13 +36,9 @@ create index if not exists crypto_transfer__entity_id_consensus_timestamp where entity_id != 98; -- id corresponding to treasury address 0.0.98 --- file_data -create index if not exists file_data__consensus - on file_data (consensus_timestamp desc); +-- file_data, desc index on consensus_timestamp already created by hypertable --- live_hash -create index if not exists livehashes__consensus - on live_hash (consensus_timestamp desc); +-- live_hash, desc index on consensus_timestamp already created by hypertable -- non_fee_transfer create index if not exists non_fee_transfer__consensus_timestamp @@ -57,8 +49,6 @@ create unique index if not exists record_file_name on record_file (name, consensus_start); -- have to add consensus_start due to partitioning create unique index if not exists record_file_hash on record_file (file_hash, consensus_start); -- have to add consensus_start due to partitioning -create index if not exists record_file__consensus_start - on record_file (consensus_start); create index if not exists record_file__consensus_end on record_file (consensus_end); create index if not exists record_file__prev_hash @@ -76,14 +66,10 @@ create unique index if not exists entities_unq -- have to add id due to partitioning -- token -alter table if exists token - add constraint token_timestamp primary key (created_timestamp); create index if not exists token_id on token (token_id); -- token_account -alter table if exists token_account - add constraint token_account_timestamp primary key (created_timestamp); create unique index if not exists token_account__token_account on token_account (token_id, account_id, created_timestamp); @@ -105,7 +91,9 @@ create unique index if not exists topic_message__topic_num_realm_num_seqnum -- have to add consensus_timestamp due to partitioning -- transaction -create index transaction__transaction_id +create index if not exists transaction__transaction_id on transaction (valid_start_ns, payer_account_id); -create index transaction__payer_account_id +create index if not exists transaction__payer_account_id on transaction (payer_account_id); +create index if not exists transaction_consensus_ns + on transaction (consensus_ns); From aacfb30059c4a46aa40c9c01a590c76f4708e11b Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Tue, 5 Jan 2021 11:08:42 -0600 Subject: [PATCH 11/22] Utilize GA v2.0.0 of timescaledb Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- charts/hedera-mirror/templates/job-timescaledb-init.yaml | 2 +- charts/hedera-mirror/values.yaml | 3 +++ docker-compose.yml | 2 +- hedera-mirror-grpc/src/test/resources/config/bootstrap.yml | 2 +- hedera-mirror-importer/src/test/resources/config/bootstrap.yml | 2 +- hedera-mirror-rest/__tests__/integrationDbOps.js | 2 +- 6 files changed, 8 insertions(+), 5 deletions(-) diff --git a/charts/hedera-mirror/templates/job-timescaledb-init.yaml b/charts/hedera-mirror/templates/job-timescaledb-init.yaml index a71f647852a..a0d87ae8de8 100644 --- a/charts/hedera-mirror/templates/job-timescaledb-init.yaml +++ b/charts/hedera-mirror/templates/job-timescaledb-init.yaml @@ -15,7 +15,7 @@ spec: spec: containers: - name: init-mirrornode-db - image: timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 + image: timescale/timescaledb:2.0.0-pg12 command: - sh - -c diff --git a/charts/hedera-mirror/values.yaml b/charts/hedera-mirror/values.yaml index f75d4ac81c4..801acff67d0 100644 --- a/charts/hedera-mirror/values.yaml +++ b/charts/hedera-mirror/values.yaml @@ -185,6 +185,9 @@ timescaledb: dataNode: superuser: mirror_node_pass enabled: false + image: + repository: timescaledev/timescaledb-ha + tag: pg12.5-ts2.0.0-p0 persistentVolume: size: 500Gi resources: diff --git a/docker-compose.yml b/docker-compose.yml index d730b78db2d..1d554222387 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -71,7 +71,7 @@ services: timescaledb: deploy: replicas: 0 - image: timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 + image: timescaledev/timescaledb-ha:pg12.5-ts2.0.0-p0 restart: unless-stopped stop_grace_period: 2m stop_signal: SIGTERM diff --git a/hedera-mirror-grpc/src/test/resources/config/bootstrap.yml b/hedera-mirror-grpc/src/test/resources/config/bootstrap.yml index fa1542274ec..2379c9fdfb2 100644 --- a/hedera-mirror-grpc/src/test/resources/config/bootstrap.yml +++ b/hedera-mirror-grpc/src/test/resources/config/bootstrap.yml @@ -1,7 +1,7 @@ embedded: postgresql: enabled: true - # set to timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 (same as chart) for v2 db schema. + # set to timescaledev/timescaledb-ha:pg12.5-ts2.0.0-p0 (same as chart) for v2 db schema. docker-image: postgres:9.6-alpine # postgres:12-alpine is current default redis: docker-image: redis:5.0.9-alpine diff --git a/hedera-mirror-importer/src/test/resources/config/bootstrap.yml b/hedera-mirror-importer/src/test/resources/config/bootstrap.yml index f842a712d4b..5bbfc4a187d 100644 --- a/hedera-mirror-importer/src/test/resources/config/bootstrap.yml +++ b/hedera-mirror-importer/src/test/resources/config/bootstrap.yml @@ -5,7 +5,7 @@ embedded: # so it is enabled only for those tests. enabled: false postgresql: - # set to timescaledev/timescaledb-ha:pg12-ts2.0.0-rc3 (same as chart) for v2 db schema. + # set to timescaledev/timescaledb-ha:pg12.5-ts2.0.0-p0 (same as chart) for v2 db schema. docker-image: postgres:9.6-alpine redis: docker-image: redis:5.0.9-alpine diff --git a/hedera-mirror-rest/__tests__/integrationDbOps.js b/hedera-mirror-rest/__tests__/integrationDbOps.js index 3b68ae12b1c..f0af0e90e79 100644 --- a/hedera-mirror-rest/__tests__/integrationDbOps.js +++ b/hedera-mirror-rest/__tests__/integrationDbOps.js @@ -50,7 +50,7 @@ const v1SchemaConfigs = { const v2SchemaConfigs = { docker: { imageName: 'timescaledev/timescaledb-ha', - tagName: 'pg12-ts2.0.0-rc3', + tagName: 'pg12.5-ts2.0.0-p0', }, flyway: { baselineVersion: '1.999.999', From a5d272367365f76eb3cf9b08f1c64cfd4bdb0d09 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Tue, 5 Jan 2021 11:20:08 -0600 Subject: [PATCH 12/22] Addressed feedback on indexes Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docker-compose.yml | 2 +- .../migration/v2/V2.0.2__time_scale_index_init.sql | 14 ++++++++------ 2 files changed, 9 insertions(+), 7 deletions(-) diff --git a/docker-compose.yml b/docker-compose.yml index 1d554222387..fe54f4f3bf4 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -80,6 +80,6 @@ services: POSTGRES_PASSWORD: mirror_node_pass volumes: - ./timescaledb:/var/lib/postgresql/data - - ./hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql/:/docker-entrypoint-initdb.d/init_v2.sql + - ./hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql:/docker-entrypoint-initdb.d/init_v2.sql ports: - 5432:5432 diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index 7b1d305dc9e..b69f8433ebc 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -15,10 +15,10 @@ create index if not exists balance_sets__completed on account_balance_sets (is_complete, consensus_timestamp desc); -- account_balance_file -create unique index if not exists account_balance_file__name - on account_balance_file (name, consensus_timestamp desc); alter table account_balance_file add constraint account_balance_file_timestamp primary key (consensus_timestamp); +create unique index if not exists account_balance_file__name + on account_balance_file (name, consensus_timestamp desc); -- address_book, desc index on start_consensus_timestamp already created by hypertable @@ -66,11 +66,13 @@ create unique index if not exists entities_unq -- have to add id due to partitioning -- token -create index if not exists token_id +create unique index if not exists token_id on token (token_id); +create unique index if not exists token__id_timestamp + on token (token_id, created_timestamp); -- token_account -create unique index if not exists token_account__token_account +create unique index if not exists token_account__token_account_timestamp on token_account (token_id, account_id, created_timestamp); -- token_balance @@ -93,7 +95,7 @@ create unique index if not exists topic_message__topic_num_realm_num_seqnum -- transaction create index if not exists transaction__transaction_id on transaction (valid_start_ns, payer_account_id); -create index if not exists transaction__payer_account_id - on transaction (payer_account_id); +create index if not exists transaction__payer_account_id_consensus_ns + on transaction (payer_account_id, consensus_ns); create index if not exists transaction_consensus_ns on transaction (consensus_ns); From f1afacfc31d7a4a0405d021f049b1e8c78372b5a Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Tue, 5 Jan 2021 12:16:31 -0600 Subject: [PATCH 13/22] Fix helm repo and add templated reference for image tag Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .github/ct-install.yaml | 1 + .github/ct-lint.yaml | 1 + charts/hedera-mirror/templates/job-timescaledb-init.yaml | 2 +- 3 files changed, 3 insertions(+), 1 deletion(-) diff --git a/.github/ct-install.yaml b/.github/ct-install.yaml index c3d6bf62b77..f50b3487b64 100644 --- a/.github/ct-install.yaml +++ b/.github/ct-install.yaml @@ -3,6 +3,7 @@ chart-repos: - fluxcd=https://charts.fluxcd.io - loki=https://grafana.github.io/helm-charts - prometheus=https://prometheus-community.github.io/helm-charts + - timescaledb=https://raw.githubusercontent.com/timescale/timescaledb-kubernetes/master/charts/repo/ - traefik=https://helm.traefik.io/traefik check-version-increment: false charts: diff --git a/.github/ct-lint.yaml b/.github/ct-lint.yaml index c1f51a37e32..5034ae2b4a5 100644 --- a/.github/ct-lint.yaml +++ b/.github/ct-lint.yaml @@ -3,5 +3,6 @@ chart-repos: - fluxcd=https://charts.fluxcd.io - loki=https://grafana.github.io/helm-charts - prometheus=https://prometheus-community.github.io/helm-charts + - timescaledb=https://raw.githubusercontent.com/timescale/timescaledb-kubernetes/master/charts/repo/ - traefik=https://helm.traefik.io/traefik check-version-increment: false diff --git a/charts/hedera-mirror/templates/job-timescaledb-init.yaml b/charts/hedera-mirror/templates/job-timescaledb-init.yaml index a0d87ae8de8..3e0f8ef24b6 100644 --- a/charts/hedera-mirror/templates/job-timescaledb-init.yaml +++ b/charts/hedera-mirror/templates/job-timescaledb-init.yaml @@ -15,7 +15,7 @@ spec: spec: containers: - name: init-mirrornode-db - image: timescale/timescaledb:2.0.0-pg12 + image: "{{ .Values.timescaledb.image.repository }}:{{ .Values.timescaledb.image.tag }}" command: - sh - -c From c243aab7998f5cf1b77d33a4c0c160525f968f6c Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Tue, 5 Jan 2021 22:20:21 -0600 Subject: [PATCH 14/22] Remove id column and add dbOwner support in v1 Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../src/main/resources/application.yml | 5 +++++ .../v1/V1.33.0__drop_token_account_id.sql | 19 +++++++++++++++++++ .../migration/v2/V2.0.0__time_scale_init.sql | 1 - .../v2/V2.0.2__time_scale_index_init.sql | 2 -- .../src/main/resources/db/scripts/init_v2.sql | 10 ++++++---- .../src/test/resources/config/application.yml | 3 +++ 6 files changed, 33 insertions(+), 7 deletions(-) create mode 100644 hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql diff --git a/hedera-mirror-importer/src/main/resources/application.yml b/hedera-mirror-importer/src/main/resources/application.yml index 88d3866b88d..f09b4d8b4d6 100644 --- a/hedera-mirror-importer/src/main/resources/application.yml +++ b/hedera-mirror-importer/src/main/resources/application.yml @@ -5,10 +5,13 @@ hedera: host: 127.0.0.1 loadBalance: true name: mirror_node + owner: mirror_node + ownerPassword: mirror_node_pass password: mirror_node_pass port: 5432 restPassword: mirror_api_pass restUsername: mirror_api + schema: public username: mirror_node logging: level: @@ -73,6 +76,7 @@ spring: baselineOnMigrate: true connectRetries: 20 ignoreMissingMigrations: true + password: ${hedera.mirror.importer.db.ownerPassword} placeholders: api-password: ${hedera.mirror.importer.db.restPassword} api-user: ${hedera.mirror.importer.db.restUsername} @@ -81,6 +85,7 @@ spring: compressionAge: 604800000000000 db-name: ${hedera.mirror.importer.db.name} db-user: ${hedera.mirror.importer.db.username} + user: ${hedera.mirror.importer.db.owner} jpa: properties: hibernate: diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql new file mode 100644 index 00000000000..eef973c796c --- /dev/null +++ b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql @@ -0,0 +1,19 @@ +------------------- +-- Drop token_account id, replacing id primary key with unique index on (created_timestamp) +------------------- +alter table token_account + drop constraint token_account_pkey; +create unique index if not exists token_account__created_timestamp + on token_account (created_timestamp); + +alter table if exists token_account + drop column if exists id; + +drop sequence if exists token_account_id_seq; + +-- drop unused functions +drop function if exists + f_entity_create(bigint, bigint, bigint, integer, bigint, bigint, bigint, bigint, character varying, bytea, bigint, bytea, nanos_timestamp, text); + +drop function if exists + encodeentityid(bigint, bigint, bigint); diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql index 46fbc49ed44..2b97f07f252 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.0__time_scale_init.sql @@ -415,7 +415,6 @@ comment on table token is 'Token entities'; --- token_account create table if not exists token_account ( - id serial, account_id bigint not null, associated boolean not null default false, created_timestamp bigint not null, diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index b69f8433ebc..8ecb52586b5 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -66,8 +66,6 @@ create unique index if not exists entities_unq -- have to add id due to partitioning -- token -create unique index if not exists token_id - on token (token_id); create unique index if not exists token__id_timestamp on token (token_id, created_timestamp); diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql index 4250b6ec9e0..9ee9eec3b17 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql @@ -2,7 +2,7 @@ -- Change the values below if you are not installing via Docker \set db_host 'localhost' -\set db_port 6432 +\set db_port 5432 \set db_name 'mirror_node' \set db_super_user 'postgres' \set db_owner 'mirror_node' @@ -53,8 +53,10 @@ grant select on all sequences in schema :schema_name to readonly; alter default privileges in schema :schema_name grant select on sequences to readonly; -- grant write privileges on sequences to readwrite -grant insert, update, delete on all tables in schema :schema_name to readwrite; -alter default privileges in schema :schema_name grant insert, update, delete on tables to readwrite; +grant insert, update on all tables in schema :schema_name to readwrite; +alter default privileges in schema :schema_name grant insert, update on tables to readwrite; +grant usage on all sequences in schema :schema_name to readwrite; +alter default privileges in schema :schema_name grant usage on sequences to readwrite; -- alter search path for given schema as super user \c :db_name :db_super_user @@ -64,5 +66,5 @@ alter user :grpc_user set search_path = :schema_name, public; alter user :rest_user set search_path = :schema_name, public; -- add extensions, ensuring they're available to new schema -create extension if not exists timescaledb schema :schema_name cascade; +create extension if not exists timescaledb schema :schema_name; create extension if not exists pg_stat_statements schema :schema_name; diff --git a/hedera-mirror-importer/src/test/resources/config/application.yml b/hedera-mirror-importer/src/test/resources/config/application.yml index f3c154f0398..ffc88771945 100644 --- a/hedera-mirror-importer/src/test/resources/config/application.yml +++ b/hedera-mirror-importer/src/test/resources/config/application.yml @@ -22,6 +22,9 @@ hedera: startDate: 1970-01-01T00:00:00Z spring: + flyway: + password: ${hedera.mirror.importer.db.password} + user: ${hedera.mirror.importer.db.username} redis: url: redis://${embedded.redis.user}:${embedded.redis.password}@${embedded.redis.host}:${embedded.redis.port} task: From 5c3383dd5f4749b4650d3593b5e4a098fd8c2ce8 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Wed, 6 Jan 2021 16:36:19 -0600 Subject: [PATCH 15/22] Updated timescale db init job with new schema Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../templates/job-timescaledb-init.yaml | 57 ++++++++---- .../templates/secret-timescaledb.yaml | 86 ++++++++++++++++--- charts/hedera-mirror/values.yaml | 4 +- 3 files changed, 116 insertions(+), 31 deletions(-) diff --git a/charts/hedera-mirror/templates/job-timescaledb-init.yaml b/charts/hedera-mirror/templates/job-timescaledb-init.yaml index 3e0f8ef24b6..fd400f5869c 100644 --- a/charts/hedera-mirror/templates/job-timescaledb-init.yaml +++ b/charts/hedera-mirror/templates/job-timescaledb-init.yaml @@ -2,15 +2,13 @@ apiVersion: batch/v1 kind: Job metadata: - labels: - {{- include "hedera-mirror.labels" . | nindent 4 }} + labels: {{- include "hedera-mirror.labels" . | nindent 4 }} name: {{ include "hedera-mirror.dbHost" . }}-init-job namespace: {{ include "hedera-mirror.namespace" . }} annotations: "helm.sh/hook": post-install - "helm.sh/hook-delete-policy": hook-succeeded spec: - backoffLimit: 4 + backoffLimit: 1 template: spec: containers: @@ -23,20 +21,49 @@ spec: set -e while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; - psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_INIT_FILE} + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_USERS_FILE} + echo 'Completed db initialization and user creation for mirror node' + sleep 5s + + while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_MIRRORNODE}" --set ON_ERROR_STOP=1 -f ${DB_SCHEMA_FILE} + echo 'Completed db schema initialization' + sleep 5s + + while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_PATH_FILE} + echo 'Completed db search path setting' + + echo 'Completed db initialization for mirror node' env: - name: ACCESS_SVC_CONNSTR_POSTGRES value: host={{ include "hedera-mirror.dbHost" . }} user=postgres connect_timeout=3 sslmode=disable password={{ .Values.timescaledb.credentials.accessNode.superuser }} - - name: DB_INIT_FILE - value: /usr/etc/db-init/init_v2.sql + - name: ACCESS_SVC_CONNSTR_MIRRORNODE + value: host={{ include "hedera-mirror.dbHost" . }} dbname={{ .Values.importer.config.hedera.mirror.importer.db.name }} user={{ .Values.importer.config.hedera.mirror.importer.db.owner }} connect_timeout=3 sslmode=disable password={{ .Values.importer.config.hedera.mirror.importer.db.ownerPassword }} + - name: DB_USERS_FILE + value: /usr/etc/db-init/users_v2.sql + - name: DB_SCHEMA_FILE + value: /usr/etc/db-init/schema_v2.sql + - name: DB_PATH_FILE + value: /usr/etc/db-init/path_v2.sql volumeMounts: - - name: timescale-db-init-volume + - name: timescaledb-init-volume mountPath: /usr/etc/db-init volumes: - - name: timescale-db-init-volume - secret: - defaultMode: 420 - secretName: {{ include "hedera-mirror.dbHost" . }}-init - restartPolicy: OnFailure - ttlSecondsAfterFinished: 600 - {{- end -}} + - name: timescaledb-init-volume + projected: + sources: + - secret: + name: {{ include "hedera-mirror.dbHost" . }}-init + items: + - key: users_v2.sql + path: users_v2.sql + mode: 420 + - key: schema_v2.sql + path: schema_v2.sql + mode: 420 + - key: path_v2.sql + path: path_v2.sql + mode: 420 + restartPolicy: Never +{{- end -}} diff --git a/charts/hedera-mirror/templates/secret-timescaledb.yaml b/charts/hedera-mirror/templates/secret-timescaledb.yaml index e0facfb8475..3e4a9c382fb 100644 --- a/charts/hedera-mirror/templates/secret-timescaledb.yaml +++ b/charts/hedera-mirror/templates/secret-timescaledb.yaml @@ -4,27 +4,87 @@ kind: Secret metadata: labels: {{- include "hedera-mirror.labels" . | nindent 4 }} - name: {{ printf "%s-timescaledb-init" .Release.Name }} + name: {{ include "hedera-mirror.dbHost" . }}-init namespace: {{ include "hedera-mirror.namespace" . }} type: Opaque stringData: - init_v2.sql: |- + users_v2.sql: |- {{- $dbName := .Values.importer.config.hedera.mirror.importer.db.name }} + {{- $dbOwner := .Values.importer.config.hedera.mirror.importer.db.owner }} + {{- $dbOwnerPassword := .Values.importer.config.hedera.mirror.importer.db.ownerPassword }} {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} {{- $importerPassword := .Values.importer.config.hedera.mirror.importer.db.password }} {{- $grpcUsername := .Values.grpc.config.hedera.mirror.grpc.db.username }} {{- $grpcPassword := .Values.grpc.config.hedera.mirror.grpc.db.password }} {{- $restUser := .Values.global.rest.username }} {{- $restPassword := .Values.global.rest.password }} - create database {{ $dbName }}; + + -- create owner user + create user {{ $dbOwner }} with login password '{{ $dbOwnerPassword }}'; + + -- create primary user and db + create database {{ $dbName }} with owner {{ $dbOwner }}; + + -- create roles + create role readonly; + create role readwrite in role readonly; + + -- create users + create user {{ $grpcUsername }} with login password '{{ $grpcPassword }}' in role readonly; + create user {{ $restUser }} with login password '{{ $restPassword }}' in role readonly; + create user {{ $importerUser }} with login password '{{ $importerPassword }}' in role readwrite; + + -- drop timescaledb extension for future install to ensure availability in custom schema + drop extension if exists timescaledb cascade; + schema_v2.sql: |- + {{- $dbName := .Values.importer.config.hedera.mirror.importer.db.name }} + {{- $dbOwner := .Values.importer.config.hedera.mirror.importer.db.owner }} + {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} + {{- $grpcUsername := .Values.grpc.config.hedera.mirror.grpc.db.username }} + {{- $restUser := .Values.global.rest.username }} + {{- $dbSchema := .Values.importer.config.hedera.mirror.importer.db.schema }} + + -- create schema and set schema user permissions + create schema if not exists {{ $dbSchema }} authorization {{ $dbOwner }}; + grant usage on schema {{ $dbSchema }} to public; + + -- revoke default public permissions on schema + revoke create on schema {{ $dbSchema }} from public; + + -- grant connect and schema access to readonly role + grant connect on database {{ $dbName }} to readonly; + grant usage on schema {{ $dbSchema }} to readonly; + + -- grant select privileges on tables to readonly + -- grant all privileges on all tables in schema {{ $dbSchema }} to {{ $dbOwner }}; + grant select on all tables in schema {{ $dbSchema }} to readonly; + alter default privileges in schema {{ $dbSchema }} grant select on tables to readonly; + + -- grant select privileges on sequences to readonly + -- grant all privileges on all sequences in schema {{ $dbSchema }} to {{ $dbOwner }}; + grant select on all sequences in schema {{ $dbSchema }} to readonly; + alter default privileges in schema {{ $dbSchema }} grant select on sequences to readonly; + + -- grant write privileges on sequences to readwrite + grant insert, update, delete on all tables in schema {{ $dbSchema }} to readwrite; + alter default privileges in schema {{ $dbSchema }} grant insert, update on tables to readwrite; + grant usage on all sequences in schema {{ $dbSchema }} to readwrite; + alter default privileges in schema {{ $dbSchema }} grant usage on sequences to readwrite; + path_v2.sql: |- + {{- $dbOwner := .Values.importer.config.hedera.mirror.importer.db.owner }} + {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} + {{- $grpcUsername := .Values.grpc.config.hedera.mirror.grpc.db.username }} + {{- $restUser := .Values.global.rest.username }} + {{- $dbSchema := .Values.importer.config.hedera.mirror.importer.db.schema }} + \c {{ $dbName }}; - create extension if not exists timescaledb cascade; - create user {{ $importerUser }} with login password '{{ $importerPassword }}'; - create role viewer; - create user {{ $grpcUsername }} with login password '{{ $grpcPassword }}' in role viewer; - create user {{ $restUser }} with login password '{{ $restPassword }}' in role viewer; - grant select on all tables in schema public to {{ $importerUser }}; - grant select on all tables in schema public to viewer; - alter default privileges for role {{ $importerUser }} in schema public grant select on tables to viewer; - create extension pg_stat_statements; - {{- end -}} + -- alter search path for given schema + alter user {{ $dbOwner }} set search_path = {{ $dbSchema }}, public; + alter user {{ $importerUser }} set search_path = {{ $dbSchema }}, public; + alter user {{ $grpcUsername }} set search_path = {{ $dbSchema }}, public; + alter user {{ $restUser }} set search_path = {{ $dbSchema }}, public; + + -- add extensions, ensuring they're available to new schema + create extension if not exists timescaledb cascade schema {{ $dbSchema }}; + create extension if not exists pg_stat_statements cascade schema {{ $dbSchema }}; +{{- end -}} \ No newline at end of file diff --git a/charts/hedera-mirror/values.yaml b/charts/hedera-mirror/values.yaml index 801acff67d0..1a03dde9306 100644 --- a/charts/hedera-mirror/values.yaml +++ b/charts/hedera-mirror/values.yaml @@ -203,7 +203,5 @@ timescaledb: parameters: max_wal_size: 8GB # recommended to be 80% of the Volume Size min_wal_size: 2GB # 80% of the WAL Volume Size - shared_buffers: 1GB # recommended to be 25% of available instance memory + shared_buffers: 1GB # recommended to be 25% of available instance memory work_mem: 50MB - - From 6ecd5311d4e7ca8623be4506fffe6873082f408b Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Wed, 6 Jan 2021 17:28:48 -0600 Subject: [PATCH 16/22] Addressed documentation feedback Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- docs/installation.md | 8 +++++--- docs/operations.md | 6 +++--- .../src/main/resources/db/scripts/init_v2.sql | 9 +++++---- .../main/resources/db/scripts/timescaledb/migration.sh | 2 +- 4 files changed, 14 insertions(+), 11 deletions(-) diff --git a/docs/installation.md b/docs/installation.md index 632ce2c4df1..fa20eb2c4f5 100644 --- a/docs/installation.md +++ b/docs/installation.md @@ -22,8 +22,10 @@ runnable Mirror Node JAR file in the `target` directory. In addition to OpenJDK 11, you will need to install a database and initialize it. The Mirror Node utilizes [PostgreSQL](https://postgresql.org) v9.6 or [TimescaleDB](https://docs.timescale.com/latest/main) v2 depending on the version of its database schema. -In both cases the only setup required is to create the initial database, users, schema, extensions and ensure all -permissions are set since [Flyway](https://flywaydb.org) manages the database schema. +For both databases, since [Flyway](https://flywaydb.org) will manage the database schema, the only required setup steps include: +* creating the database, users, schema, and extensions. +* ensuring all permissions are set. + Scripts for v1 and v2 are provided to accomplish this. Make sure the application [configuration](configuration.md) matches the values in the script. Run the script as a super user and check the output carefully to ensure no errors occurred. @@ -121,7 +123,7 @@ Containers use the following persisted volumes: #### TimescaleDB vs PostgreSQL To utilize the TimescaleDB database over the default PostgreSQL database, disable the PostgreSQL container and enable the TimescaleDB container. -To achieve this the `docker-compose.yml` can be updated as follows: +To achieve this the `docker-compose.yml` can be updated to set the postgres `db` service replicas to 0 whiles removing this same setting from the `timescaledb` service as follows: ```yaml ... services: diff --git a/docs/operations.md b/docs/operations.md index 4f595889088..66f105a1bd1 100644 --- a/docs/operations.md +++ b/docs/operations.md @@ -100,7 +100,7 @@ To support time series logic the Mirror Node DB schema shifted from PostgeSQL (v For mirror node operators running v1 db schema, the following steps can be taken to upgrade to v2. -1. Setup a new TimescaleDB database +1. Set up a new TimescaleDB database A new TimescaleDB server must be spun up. @@ -130,9 +130,9 @@ For mirror node operators running v1 db schema, the following steps can be taken $ ./scripts/timescaledb/migration.sh ``` - The script uses successive `psql` connections to backup, configure and restore data on the new database nodes. + The script uses successive `psql` connections to back up, configure and restore data on the new database nodes. First it copies over the `flyway_schema_history` table, to maintain migration history. - It then utilizes the migration sql script used by normal flyway operations to create the new tables and then creates the Timescale hyper tables based on these. + It then utilizes the migration sql script used by normal flyway operations to create the new tables and then creates the Timescale hypertables based on these. Following this the tables from the old database are backed up as csv files using `\COPY` and then the data inserted into the new database also using `\COPY`. Finally the schema of the `flyway_schema_history` is updated and the sequence values are updated to ensure continuation. diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql index 9ee9eec3b17..e6dbb18e26b 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/init_v2.sql @@ -30,6 +30,9 @@ create user :grpc_user with login password :'grpc_password' in role readonly; create user :rest_user with login password :'rest_password' in role readonly; create user :importer_user with login password :'importer_password' in role readwrite; +-- drop timescaledb extension for future install to ensure availability in custom schema +drop extension if exists timescaledb cascade; + -- connect with db owner to create schema and set schema user permissions \c :db_name :db_owner create schema if not exists :schema_name authorization :db_owner; @@ -43,12 +46,10 @@ grant connect on database :db_name to readonly; grant usage on schema :schema_name to readonly; -- grant select privileges on tables to readonly --- grant all privileges on all tables in schema :schema_name to :db_owner; grant select on all tables in schema :schema_name to readonly; alter default privileges in schema :schema_name grant select on tables to readonly; -- grant select privileges on sequences to readonly --- grant all privileges on all sequences in schema :schema_name to :db_owner; grant select on all sequences in schema :schema_name to readonly; alter default privileges in schema :schema_name grant select on sequences to readonly; @@ -66,5 +67,5 @@ alter user :grpc_user set search_path = :schema_name, public; alter user :rest_user set search_path = :schema_name, public; -- add extensions, ensuring they're available to new schema -create extension if not exists timescaledb schema :schema_name; -create extension if not exists pg_stat_statements schema :schema_name; +create extension if not exists timescaledb cascade schema :schema_name; +create extension if not exists pg_stat_statements cascade schema :schema_name; diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh index 80606144d36..755f680b77f 100755 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/migration.sh @@ -77,7 +77,7 @@ PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT echo "3. Create v2 table schemas in TimescaleDB($NEW_DB_HOST:$NEW_DB_PORT)..." PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER scripts/timescaledb/createHyperTables.sql PGPASSWORD=${NEW_PASSWORD} psql -h $NEW_DB_HOST -d $NEW_DB_NAME -p $NEW_DB_PORT -U $NEW_DB_USER -f scripts/timescaledb/createHyperTables.sql From f47e5a9ccb5ae76688ee85aa9960d2a6ed7382de Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Wed, 6 Jan 2021 18:53:09 -0600 Subject: [PATCH 17/22] Remove sequence update of token_account from alterSchema.sql Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../src/main/resources/db/scripts/timescaledb/alterSchema.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql index b88ebf3bf07..81b061b1fbc 100644 --- a/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql +++ b/hedera-mirror-importer/src/main/resources/db/scripts/timescaledb/alterSchema.sql @@ -11,4 +11,3 @@ alter table flyway_schema_history -- update sequence start values select setval('address_book_entry_id_seq', (select max(id) from address_book_entry)); select setval('record_file_id_seq', (select max(id) from record_file)); -select setval('token_account_id_seq', (select max(id) from token_account)); From 3ed4fe340136021236dce1181758b15107a66165 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Thu, 7 Jan 2021 15:36:30 -0600 Subject: [PATCH 18/22] Addressed index feedback and update config docs Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../templates/job-timescaledb-init.yaml | 36 +++------ docs/configuration.md | 7 +- .../v1/V1.33.0__drop_token_account_id.sql | 7 +- .../db/migration/v2/V2.0.1__hyper_tables.sql | 77 ++++++++++--------- .../v2/V2.0.2__time_scale_index_init.sql | 56 ++++++++++---- .../AbstractEntityRecordItemListenerTest.java | 5 +- .../entity/sql/SqlEntityListenerTest.java | 9 ++- .../AddressBookEntryRepositoryTest.java | 29 +++---- 8 files changed, 123 insertions(+), 103 deletions(-) diff --git a/charts/hedera-mirror/templates/job-timescaledb-init.yaml b/charts/hedera-mirror/templates/job-timescaledb-init.yaml index fd400f5869c..278b23fd87c 100644 --- a/charts/hedera-mirror/templates/job-timescaledb-init.yaml +++ b/charts/hedera-mirror/templates/job-timescaledb-init.yaml @@ -7,6 +7,7 @@ metadata: namespace: {{ include "hedera-mirror.namespace" . }} annotations: "helm.sh/hook": post-install + "helm.sh/hook-delete-policy": hook-succeeded spec: backoffLimit: 1 template: @@ -21,17 +22,13 @@ spec: set -e while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; - psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_USERS_FILE} + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_INIT_DIR}/users_v2.sql echo 'Completed db initialization and user creation for mirror node' - sleep 5s - while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; - psql --echo-queries -d "${ACCESS_SVC_CONNSTR_MIRRORNODE}" --set ON_ERROR_STOP=1 -f ${DB_SCHEMA_FILE} + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_MIRRORNODE}" --set ON_ERROR_STOP=1 -f ${DB_INIT_DIR}/schema_v2.sql echo 'Completed db schema initialization' - sleep 5s - while ! pg_isready -U postgres -h {{ include "hedera-mirror.dbHost" . }}-data; do sleep 1; done; - psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_PATH_FILE} + psql --echo-queries -d "${ACCESS_SVC_CONNSTR_POSTGRES}" --set ON_ERROR_STOP=1 -f ${DB_INIT_DIR}/path_v2.sql echo 'Completed db search path setting' echo 'Completed db initialization for mirror node' @@ -40,30 +37,15 @@ spec: value: host={{ include "hedera-mirror.dbHost" . }} user=postgres connect_timeout=3 sslmode=disable password={{ .Values.timescaledb.credentials.accessNode.superuser }} - name: ACCESS_SVC_CONNSTR_MIRRORNODE value: host={{ include "hedera-mirror.dbHost" . }} dbname={{ .Values.importer.config.hedera.mirror.importer.db.name }} user={{ .Values.importer.config.hedera.mirror.importer.db.owner }} connect_timeout=3 sslmode=disable password={{ .Values.importer.config.hedera.mirror.importer.db.ownerPassword }} - - name: DB_USERS_FILE - value: /usr/etc/db-init/users_v2.sql - - name: DB_SCHEMA_FILE - value: /usr/etc/db-init/schema_v2.sql - - name: DB_PATH_FILE - value: /usr/etc/db-init/path_v2.sql + - name: DB_INIT_DIR + value: /usr/etc/db-init volumeMounts: - name: timescaledb-init-volume mountPath: /usr/etc/db-init volumes: - name: timescaledb-init-volume - projected: - sources: - - secret: - name: {{ include "hedera-mirror.dbHost" . }}-init - items: - - key: users_v2.sql - path: users_v2.sql - mode: 420 - - key: schema_v2.sql - path: schema_v2.sql - mode: 420 - - key: path_v2.sql - path: path_v2.sql - mode: 420 + secret: + defaultMode: 420 + secretName: {{ include "hedera-mirror.dbHost" . }}-init restartPolicy: Never {{- end -}} diff --git a/docs/configuration.md b/docs/configuration.md index 09b287bfba6..81fa5def45f 100644 --- a/docs/configuration.md +++ b/docs/configuration.md @@ -26,9 +26,12 @@ value, it is recommended to only populate overridden properties in the custom `a | `hedera.mirror.importer.db.host` | 127.0.0.1 | The IP or hostname used to connect to the database | | `hedera.mirror.importer.db.loadBalance` | true | Whether to enable pgpool load balancing. If false, it sends all reads to the primary db backend instead of load balancing them across the primary and replicas. | | `hedera.mirror.importer.db.name` | mirror_node | The name of the database | -| `hedera.mirror.importer.db.password` | mirror_node_pass | The database password the processor uses to connect. | +| `hedera.mirror.importer.db.owner` | mirror_node | The username of the db user with owner permissions to create and modify the schema | +| `hedera.mirror.importer.db.ownerPassword` | mirror_node_pass | The password for the owner user the processor uses to connect. | +| `hedera.mirror.importer.db.password` | mirror_node_pass | The database password for the Importer user the processor uses to connect. | | `hedera.mirror.importer.db.port` | 5432 | The port used to connect to the database | -| `hedera.mirror.importer.db.username` | mirror_node | The username the processor uses to connect to the database | +| `hedera.mirror.importer.db.schema` | public | The name of the custom schema database objects will be created in. This is applicable from v2 of the data schema | +| `hedera.mirror.importer.db.username` | mirror_node | The Importer username the processor uses to connect to the database | | `hedera.mirror.importer.downloader.accessKey` | "" | The cloud storage access key | | `hedera.mirror.importer.downloader.allowAnonymousAccess` | | Whether the cloud storage bucket allows for anonymous access. | | `hedera.mirror.importer.downloader.balance.batchSize` | 15 | The number of signature files to download per node before downloading the signed files | diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql index eef973c796c..db29cd32100 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql @@ -1,11 +1,10 @@ ------------------- -- Drop token_account id, replacing id primary key with unique index on (created_timestamp) ------------------- -alter table token_account +alter table if exists token_account drop constraint token_account_pkey; -create unique index if not exists token_account__created_timestamp - on token_account (created_timestamp); - +alter table if exists token_account + add primary key (created_timestamp); alter table if exists token_account drop column if exists id; diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql index 2eb3288b0b9..267a06ae73a 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql @@ -1,58 +1,59 @@ ------------------- -- Create hyper tables for tables that have mostly insert logic --- Use default of 604800000000000 ns (7 days) as chunk time interval --- add TIMESTAMPTZ data type column to tables where no monotonically increasing id exists +-- Set chunk_time_interval using parameterized value, usually default of 604800000000000 ns (7 days) +-- Set create_default_indexes to false for tables where a primary key is needed or an index in ASC order is needed. +-- By default TimescaleDB adds an index in DESC order for partitioning column ------------------- -- account_balance -select create_hypertable('account_balance', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('account_balance', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- account_balance_file -select create_hypertable('account_balance_file', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('account_balance_file', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- account_balance_sets -select create_hypertable('account_balance_sets', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('account_balance_sets', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- address_book -select create_hypertable('address_book', 'start_consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('address_book', 'start_consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- address_book_entry -select create_hypertable('address_book_entry', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('address_book_entry', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- contract_result -select create_hypertable('contract_result', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('contract_result', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- crypto_transfer -select create_hypertable('crypto_transfer', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('crypto_transfer', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- file_data -select create_hypertable('file_data', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('file_data', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + if_not_exists => true); -- live_hash -select create_hypertable('live_hash', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('live_hash', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + if_not_exists => true); -- non_fee_transfer -select create_hypertable('non_fee_transfer', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('non_fee_transfer', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- record_file -select create_hypertable('record_file', 'consensus_start', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('record_file', 'consensus_start', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- t_application_status hyper table creation skipped as it serves only as a reference table -- t_entities -select create_hypertable('t_entities', 'id', - chunk_time_interval => ${chunkIdInterval}, if_not_exists => true); +select create_hypertable('t_entities', 'id', chunk_time_interval => ${chunkIdInterval}, + create_default_indexes => false, if_not_exists => true); -- t_entity_types hyper table creation skipped as it serves only as a reference table and rarely gets updated @@ -61,25 +62,25 @@ select create_hypertable('t_entities', 'id', -- t_transaction_types hyper table creation skipped as it serves only as a reference table and rarely gets updated -- token -select create_hypertable('token', 'created_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('token', 'created_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- token_account -select create_hypertable('token_account', 'created_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('token_account', 'created_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- token_balance -select create_hypertable('token_balance', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('token_balance', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- token_transfer -select create_hypertable('token_transfer', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('token_transfer', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- topic_message -select create_hypertable('topic_message', 'consensus_timestamp', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('topic_message', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); -- transaction -select create_hypertable('transaction', 'consensus_ns', - chunk_time_interval => ${chunkTimeInterval}, if_not_exists => true); +select create_hypertable('transaction', 'consensus_ns', chunk_time_interval => ${chunkTimeInterval}, + create_default_indexes => false, if_not_exists => true); diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index 8ecb52586b5..388c8f69337 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -4,25 +4,31 @@ -- account_balance alter table account_balance - add constraint account_balance_timestamp_id primary key (consensus_timestamp, account_id); + add primary key (consensus_timestamp, account_id); create index if not exists account_balance__account_timestamp on account_balance (account_id desc, consensus_timestamp desc); -- account_balance_sets alter table account_balance_sets - add constraint account_balance_sets_timestamp primary key (consensus_timestamp); + add primary key (consensus_timestamp); create index if not exists balance_sets__completed on account_balance_sets (is_complete, consensus_timestamp desc); -- account_balance_file alter table account_balance_file - add constraint account_balance_file_timestamp primary key (consensus_timestamp); + add primary key (consensus_timestamp); create unique index if not exists account_balance_file__name on account_balance_file (name, consensus_timestamp desc); --- address_book, desc index on start_consensus_timestamp already created by hypertable +-- address_book +alter table address_book + add primary key (start_consensus_timestamp); --- address_book_entry, desc index on consensus_timestamp already created by hypertable +-- address_book_entry +alter table address_book_entry + add primary key (consensus_timestamp, memo); +create index if not exists address_book_entry__timestamp + on address_book_entry (consensus_timestamp); -- contract_result create index if not exists contract_result__consensus @@ -45,6 +51,8 @@ create index if not exists non_fee_transfer__consensus_timestamp on non_fee_transfer (consensus_timestamp); -- record_file +alter table record_file + add primary key (consensus_start); create unique index if not exists record_file_name on record_file (name, consensus_start); -- have to add consensus_start due to partitioning create unique index if not exists record_file_hash @@ -55,6 +63,8 @@ create index if not exists record_file__prev_hash on record_file (prev_hash); -- t_entities +alter table t_entities + add primary key (id); -- Enforce lowercase hex representation by constraint rather than making indexes on lower(ed25519). alter table t_entities add constraint c__t_entities__lower_ed25519 @@ -63,19 +73,39 @@ create index if not exists entities__ed25519_public_key_hex_natural_id on t_entities (ed25519_public_key_hex, fk_entity_type_id, entity_shard, entity_realm, entity_num); create unique index if not exists entities_unq on t_entities (entity_shard, entity_realm, entity_num, id); --- have to add id due to partitioning +-- have to add id when creating unique indexes due to partitioning + +-- t_entity_types +alter table t_entity_types + add primary key (id); + +-- t_transaction_results +alter table t_transaction_results + add primary key (proto_id); +create unique index if not exists t_transaction_results_name + on t_transaction_results (result); + +-- t_transaction_types +alter table t_transaction_types + add primary key (proto_id); +create unique index if not exists t_transaction_types_name + on t_transaction_types (name); -- token +alter table token + add primary key (created_timestamp); create unique index if not exists token__id_timestamp on token (token_id, created_timestamp); -- token_account +alter table token_account + add primary key (created_timestamp); create unique index if not exists token_account__token_account_timestamp on token_account (token_id, account_id, created_timestamp); -- token_balance -alter table if exists token_balance - add constraint token_balance_timestamp_ids primary key (consensus_timestamp, account_id, token_id); +alter table token_balance + add primary key (consensus_timestamp, account_id, token_id); -- token_transfer create index if not exists token_transfer__token_account_timestamp @@ -83,17 +113,17 @@ create index if not exists token_transfer__token_account_timestamp -- topic_message alter table if exists topic_message - add constraint topic_message_timestamp primary key (consensus_timestamp); + add primary key (consensus_timestamp); create index if not exists topic_message__realm_num_timestamp on topic_message (realm_num, topic_num, consensus_timestamp); create unique index if not exists topic_message__topic_num_realm_num_seqnum on topic_message (realm_num, topic_num, sequence_number, consensus_timestamp); --- have to add consensus_timestamp due to partitioning +-- have to add consensus_timestamp when creating unique indexes due to partitioning -- transaction +alter table if exists transaction + add primary key (consensus_ns); create index if not exists transaction__transaction_id on transaction (valid_start_ns, payer_account_id); create index if not exists transaction__payer_account_id_consensus_ns - on transaction (payer_account_id, consensus_ns); -create index if not exists transaction_consensus_ns - on transaction (consensus_ns); + on transaction (payer_account_id); diff --git a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/AbstractEntityRecordItemListenerTest.java b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/AbstractEntityRecordItemListenerTest.java index 574a41e1012..bf9ea955118 100644 --- a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/AbstractEntityRecordItemListenerTest.java +++ b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/AbstractEntityRecordItemListenerTest.java @@ -180,8 +180,9 @@ protected final void assertContract(ContractID contractId, Entities dbEntity) { protected void parseRecordItemAndCommit(RecordItem recordItem) { String fileName = UUID.randomUUID().toString(); EntityId nodeAccountId = EntityId.of(TestUtils.toAccountId("0.0.3")); - RecordFile recordFile = new RecordFile(0L, 0L, null, fileName, 0L, 0L, UUID.randomUUID() - .toString(), "", nodeAccountId, 0L, 0); + RecordFile recordFile = new RecordFile(recordItem.getConsensusTimestamp(), + recordItem.getConsensusTimestamp() + 1, null, fileName, 0L, 0L, + UUID.randomUUID().toString(), "", nodeAccountId, 0L, 0); recordFileRepository.save(recordFile); recordStreamFileListener.onStart(new StreamFileData(fileName, null)); // open connection entityRecordItemListener.onItem(recordItem); diff --git a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/sql/SqlEntityListenerTest.java b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/sql/SqlEntityListenerTest.java index f10527acb22..ba5f36d2d13 100644 --- a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/sql/SqlEntityListenerTest.java +++ b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/parser/record/entity/sql/SqlEntityListenerTest.java @@ -94,7 +94,7 @@ public class SqlEntityListenerTest extends IntegrationTest { @BeforeEach final void beforeEach() { String newFileHash = UUID.randomUUID().toString(); - recordFile = insertRecordFileRecord(fileName, newFileHash, "fileHash0"); + recordFile = insertRecordFileRecord(fileName, newFileHash, "fileHash0", 1L); sqlEntityListener.onStart(new StreamFileData(fileName, null)); } @@ -240,7 +240,7 @@ void onEntityIdDuplicates() throws Exception { sqlEntityListener.onEntityId(entityId); // duplicate within file completeFileAndCommit(); - recordFile = insertRecordFileRecord(UUID.randomUUID().toString(), null, null); + recordFile = insertRecordFileRecord(UUID.randomUUID().toString(), null, null, 1L); sqlEntityListener.onStart(new StreamFileData(fileName, null)); sqlEntityListener.onEntityId(entityId); // duplicate across files completeFileAndCommit(); @@ -341,7 +341,7 @@ private String completeFileAndCommit() { return recordFile.getFileHash(); } - private RecordFile insertRecordFileRecord(String filename, String fileHash, String prevHash) { + private RecordFile insertRecordFileRecord(String filename, String fileHash, String prevHash, long consensusStart) { if (fileHash == null) { fileHash = UUID.randomUUID().toString(); } @@ -350,7 +350,8 @@ private RecordFile insertRecordFileRecord(String filename, String fileHash, Stri } EntityId nodeAccountId = EntityId.of(TestUtils.toAccountId("0.0.3")); - RecordFile rf = new RecordFile(1L, 2L, null, filename, 0L, 0L, fileHash, prevHash, nodeAccountId, 0L, 0); + RecordFile rf = new RecordFile(consensusStart, consensusStart + 1, null, filename, 0L, 0L, fileHash, prevHash + , nodeAccountId, 0L, 0); recordFileRepository.save(rf); return rf; } diff --git a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/repository/AddressBookEntryRepositoryTest.java b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/repository/AddressBookEntryRepositoryTest.java index 2d790ca3456..21bda0151c6 100644 --- a/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/repository/AddressBookEntryRepositoryTest.java +++ b/hedera-mirror-importer/src/test/java/com/hedera/mirror/importer/repository/AddressBookEntryRepositoryTest.java @@ -23,8 +23,8 @@ public class AddressBookEntryRepositoryTest extends AbstractRepositoryTest { @Test void save() { - addressBookRepository.save(addressBook(null)); - AddressBookEntry addressBookEntry = addressBookEntryRepository.save(addressBookEntry(null)); + addressBookRepository.save(addressBook(null, 1L)); + AddressBookEntry addressBookEntry = addressBookEntryRepository.save(addressBookEntry(null, 1L, 3)); assertThat(addressBookEntryRepository.findById(addressBookEntry.getId())) .get() .isEqualTo(addressBookEntry); @@ -32,24 +32,26 @@ void save() { @Test void verifySequence() { - addressBookRepository.save(addressBook(null)); - addressBookEntryRepository.save(addressBookEntry(null)); - addressBookEntryRepository.save(addressBookEntry(null)); - addressBookEntryRepository.save(addressBookEntry(null)); + long consensusTimestamp = 1L; + addressBookRepository.save(addressBook(null, consensusTimestamp)); + addressBookEntryRepository.save(addressBookEntry(null, consensusTimestamp, 3)); + addressBookEntryRepository.save(addressBookEntry(null, consensusTimestamp, 4)); + addressBookEntryRepository.save(addressBookEntry(null, consensusTimestamp, 5)); assertThat(addressBookEntryRepository.findAll()) .isNotNull() .extracting(AddressBookEntry::getId) .containsSequence(1L, 2L, 3L); } - private AddressBookEntry addressBookEntry(Consumer nodeAddressCustomizer) { + private AddressBookEntry addressBookEntry(Consumer nodeAddressCustomizer, long consensusTimestamp, long nodeAccountId) { + String nodeAccountIdString = String.format("0.0.%s", nodeAccountId); AddressBookEntry.AddressBookEntryBuilder builder = AddressBookEntry.builder() - .consensusTimestamp(0L) + .consensusTimestamp(consensusTimestamp) .ip("127.0.0.1") .publicKey("rsa+public/key") - .memo("0.0.3") - .nodeAccountId(EntityId.of("0.0.5", EntityTypeEnum.ACCOUNT)) - .nodeId(5L) + .memo(nodeAccountIdString) + .nodeAccountId(EntityId.of(nodeAccountIdString, EntityTypeEnum.ACCOUNT)) + .nodeId(nodeAccountId) .nodeCertHash("nodeCertHash".getBytes()); if (nodeAddressCustomizer != null) { @@ -59,10 +61,11 @@ private AddressBookEntry addressBookEntry(Consumer addressBookCustomizer) { + private AddressBook addressBook(Consumer addressBookCustomizer, + long consensusTimestamp) { AddressBook.AddressBookBuilder builder = AddressBook.builder() - .startConsensusTimestamp(0L) + .startConsensusTimestamp(consensusTimestamp) .fileData("address book memo".getBytes()) .fileId(addressBookEntityId102); From 48df1413edda3696b8b4934f3d58dee85827e1f3 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Thu, 7 Jan 2021 15:45:16 -0600 Subject: [PATCH 19/22] Updated index name Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../resources/db/migration/v2/V2.0.2__time_scale_index_init.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index 388c8f69337..b910f84f2b8 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -125,5 +125,5 @@ alter table if exists transaction add primary key (consensus_ns); create index if not exists transaction__transaction_id on transaction (valid_start_ns, payer_account_id); -create index if not exists transaction__payer_account_id_consensus_ns +create index if not exists transaction__payer_account_id on transaction (payer_account_id); From 714fb97637f3a3a82f7cd4019f4662f31a453789 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Thu, 7 Jan 2021 18:44:06 -0600 Subject: [PATCH 20/22] Streamlined variables in secret and added live_hash and file_data primary keys Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../templates/secret-timescaledb.yaml | 16 ++-------------- .../db/migration/v2/V2.0.1__hyper_tables.sql | 4 ++-- .../v2/V2.0.2__time_scale_index_init.sql | 8 ++++++-- 3 files changed, 10 insertions(+), 18 deletions(-) diff --git a/charts/hedera-mirror/templates/secret-timescaledb.yaml b/charts/hedera-mirror/templates/secret-timescaledb.yaml index 3e4a9c382fb..719627b0dca 100644 --- a/charts/hedera-mirror/templates/secret-timescaledb.yaml +++ b/charts/hedera-mirror/templates/secret-timescaledb.yaml @@ -18,6 +18,7 @@ stringData: {{- $grpcPassword := .Values.grpc.config.hedera.mirror.grpc.db.password }} {{- $restUser := .Values.global.rest.username }} {{- $restPassword := .Values.global.rest.password }} + {{- $dbSchema := .Values.importer.config.hedera.mirror.importer.db.schema }} -- create owner user create user {{ $dbOwner }} with login password '{{ $dbOwnerPassword }}'; @@ -37,13 +38,6 @@ stringData: -- drop timescaledb extension for future install to ensure availability in custom schema drop extension if exists timescaledb cascade; schema_v2.sql: |- - {{- $dbName := .Values.importer.config.hedera.mirror.importer.db.name }} - {{- $dbOwner := .Values.importer.config.hedera.mirror.importer.db.owner }} - {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} - {{- $grpcUsername := .Values.grpc.config.hedera.mirror.grpc.db.username }} - {{- $restUser := .Values.global.rest.username }} - {{- $dbSchema := .Values.importer.config.hedera.mirror.importer.db.schema }} - -- create schema and set schema user permissions create schema if not exists {{ $dbSchema }} authorization {{ $dbOwner }}; grant usage on schema {{ $dbSchema }} to public; @@ -71,12 +65,6 @@ stringData: grant usage on all sequences in schema {{ $dbSchema }} to readwrite; alter default privileges in schema {{ $dbSchema }} grant usage on sequences to readwrite; path_v2.sql: |- - {{- $dbOwner := .Values.importer.config.hedera.mirror.importer.db.owner }} - {{- $importerUser := .Values.importer.config.hedera.mirror.importer.db.username }} - {{- $grpcUsername := .Values.grpc.config.hedera.mirror.grpc.db.username }} - {{- $restUser := .Values.global.rest.username }} - {{- $dbSchema := .Values.importer.config.hedera.mirror.importer.db.schema }} - \c {{ $dbName }}; -- alter search path for given schema alter user {{ $dbOwner }} set search_path = {{ $dbSchema }}, public; @@ -87,4 +75,4 @@ stringData: -- add extensions, ensuring they're available to new schema create extension if not exists timescaledb cascade schema {{ $dbSchema }}; create extension if not exists pg_stat_statements cascade schema {{ $dbSchema }}; -{{- end -}} \ No newline at end of file +{{- end -}} diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql index 267a06ae73a..d0a2ea249da 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.1__hyper_tables.sql @@ -35,11 +35,11 @@ select create_hypertable('crypto_transfer', 'consensus_timestamp', chunk_time_in -- file_data select create_hypertable('file_data', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, - if_not_exists => true); + create_default_indexes => false, if_not_exists => true); -- live_hash select create_hypertable('live_hash', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, - if_not_exists => true); + create_default_indexes => false, if_not_exists => true); -- non_fee_transfer select create_hypertable('non_fee_transfer', 'consensus_timestamp', chunk_time_interval => ${chunkTimeInterval}, diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql index b910f84f2b8..6f5285f827d 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v2/V2.0.2__time_scale_index_init.sql @@ -42,9 +42,13 @@ create index if not exists crypto_transfer__entity_id_consensus_timestamp where entity_id != 98; -- id corresponding to treasury address 0.0.98 --- file_data, desc index on consensus_timestamp already created by hypertable +-- file_data +alter table file_data + add primary key (consensus_timestamp); --- live_hash, desc index on consensus_timestamp already created by hypertable +-- live_hash +alter table live_hash + add primary key (consensus_timestamp); -- non_fee_transfer create index if not exists non_fee_transfer__consensus_timestamp From c0b32de90be8cf4f724abcb250ac386bf21cb534 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Fri, 8 Jan 2021 09:37:29 -0600 Subject: [PATCH 21/22] Add missing primary keys on live_hash and file_data in v1 schema Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../db/migration/v1/V1.33.0__drop_token_account_id.sql | 9 +++++++++ 1 file changed, 9 insertions(+) diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql index db29cd32100..3c0c7e3111e 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql @@ -1,5 +1,7 @@ ------------------- -- Drop token_account id, replacing id primary key with unique index on (created_timestamp) +-- Drop unused functions f_entity_create and encodeentityid +-- Add missing primary keys on file_data and live_hash ------------------- alter table if exists token_account drop constraint token_account_pkey; @@ -16,3 +18,10 @@ drop function if exists drop function if exists encodeentityid(bigint, bigint, bigint); + +-- add missing primary keys +alter table file_data + add primary key (consensus_timestamp); + +alter table live_hash + add primary key (consensus_timestamp); From 2af65594d6539bcd3b37f09a7284fa2acee8aa55 Mon Sep 17 00:00:00 2001 From: Nana-EC <56320167+Nana-EC@users.noreply.github.com> Date: Fri, 8 Jan 2021 09:59:12 -0600 Subject: [PATCH 22/22] Drop non-unique duplicate indexes Signed-off-by: Nana-EC <56320167+Nana-EC@users.noreply.github.com> --- .../db/migration/v1/V1.33.0__drop_token_account_id.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql index 3c0c7e3111e..4d02ef3614c 100644 --- a/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql +++ b/hedera-mirror-importer/src/main/resources/db/migration/v1/V1.33.0__drop_token_account_id.sql @@ -20,8 +20,10 @@ drop function if exists encodeentityid(bigint, bigint, bigint); -- add missing primary keys +drop index if exists idx__t_file_data__consensus; alter table file_data add primary key (consensus_timestamp); +drop index if exists idx__t_livehashes__consensus; alter table live_hash add primary key (consensus_timestamp);