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)"