From afc50f5d9063f1e8ad8812d4f926b4218d99dcdb Mon Sep 17 00:00:00 2001 From: Luca Palla Date: Mon, 19 May 2025 17:44:35 +0200 Subject: [PATCH 1/2] Downgrade Go from 1.24 to 1.23 Create sql scripts for migration. Update migration go scripts --- cmd/migrate/cmd.go | 4 +- database/migrate/v5/migrate.go | 29 +++- database/migrate/v5/migrationv5.sql | 248 ++++++++++++++++++++++++++++ go.mod | 2 +- 4 files changed, 278 insertions(+), 5 deletions(-) create mode 100644 database/migrate/v5/migrationv5.sql diff --git a/cmd/migrate/cmd.go b/cmd/migrate/cmd.go index bff9e8055..25e6d9e14 100644 --- a/cmd/migrate/cmd.go +++ b/cmd/migrate/cmd.go @@ -8,7 +8,7 @@ import ( "github.com/spf13/cobra" v3 "github.com/forbole/callisto/v4/cmd/migrate/v3" - v6 "github.com/forbole/callisto/v4/cmd/migrate/v5" + v5 "github.com/forbole/callisto/v4/cmd/migrate/v5" ) type Migrator func(parseCfg *parsecmdtypes.Config) error @@ -16,7 +16,7 @@ type Migrator func(parseCfg *parsecmdtypes.Config) error var ( migrations = map[string]Migrator{ "v3": v3.RunMigration, - "v6": v6.RunMigration, + "v5": v5.RunMigration, } ) diff --git a/database/migrate/v5/migrate.go b/database/migrate/v5/migrate.go index 0fd00b242..6da90c29d 100644 --- a/database/migrate/v5/migrate.go +++ b/database/migrate/v5/migrate.go @@ -2,6 +2,8 @@ package v5 import ( "fmt" + "log" + "os" utils "github.com/forbole/callisto/v4/modules/utils" "github.com/forbole/callisto/v4/types" @@ -26,6 +28,15 @@ func (db *Migrator) Migrate() error { return err } } + sqlBytes, err := os.ReadFile("migrations/your_file.sql") + if err != nil { + log.Fatalf("Failed to read SQL file: %v", err) + } + + err = db.migrateDbSchema(string(sqlBytes)) + if err != nil { + log.Fatalf("Migration failed: %v", err) + } return nil } @@ -37,17 +48,31 @@ func (db *Migrator) getMsgTypesFromMessageTable() ([]MessageRow, error) { if err != nil { return nil, err } - return rows, nil } // migrateMsgTypes stores the given message type inside the database func (db *Migrator) migrateMsgTypes(msg *types.MessageType) error { stmt := ` +CREATE TABLE message_type +( + type TEXT NOT NULL UNIQUE, + module TEXT NOT NULL, + label TEXT NOT NULL, + height BIGINT NOT NULL +); +CREATE INDEX message_type_module_index ON message_type (module); +CREATE INDEX message_type_type_index ON message_type (type); + INSERT INTO message_type(type, module, label, height) VALUES ($1, $2, $3, $4) -ON CONFLICT (type) DO NOTHING` +ON CONFLICT (type) DO NOTHING;` _, err := db.SQL.Exec(stmt, msg.Type, msg.Module, msg.Label, msg.Height) return err } + +func (db *Migrator) migrateDbSchema(migrateSQL string) error { + _, err := db.SQL.Exec(migrateSQL) + return err +} diff --git a/database/migrate/v5/migrationv5.sql b/database/migrate/v5/migrationv5.sql new file mode 100644 index 000000000..50aab3f7b --- /dev/null +++ b/database/migrate/v5/migrationv5.sql @@ -0,0 +1,248 @@ +/*######################### cosmos00.sql ##########################*/ + +/* change vacuum rules */ +ALTER TABLE block +SET ( +autovacuum_vacuum_scale_factor = 0, +autovacuum_analyze_scale_factor = 0, +autovacuum_vacuum_threshold = 10000, +autovacuum_analyze_threshold = 10000 +); + +/* transaction -> transaction partitioned */ +ALTER TABLE transaction RENAME TO transaction_before_050; + +CREATE TABLE transaction ( + hash TEXT NOT NULL, + height BIGINT NOT NULL REFERENCES block (height), + success BOOLEAN NOT NULL, + messages JSON NOT NULL DEFAULT '[]'::JSON, + memo TEXT, + signatures TEXT[] NOT NULL, + signer_infos JSONB NOT NULL DEFAULT '[]'::JSONB, + fee JSONB NOT NULL DEFAULT '{}'::JSONB, + gas_wanted BIGINT DEFAULT 0, + gas_used BIGINT DEFAULT 0, + raw_log TEXT, + logs JSONB, + events JSONB NOT NULL DEFAULT '[]'::JSONB, + partition_id BIGINT NOT NULL DEFAULT 0, + + CONSTRAINT unique_tx UNIQUE (hash, partition_id) +) PARTITION BY LIST(partition_id); + +CREATE INDEX transaction_hash_index ON transaction (hash); +CREATE INDEX transaction_height_index ON transaction (height); +CREATE INDEX transaction_partition_id_index ON transaction (partition_id); + +CREATE TABLE transaction_0 PARTITION OF transaction +FOR VALUES IN (0); + +INSERT INTO transaction ( + hash, height, success, messages, memo, signatures, + signer_infos, fee, gas_wanted, gas_used, raw_log, logs, + events, partition_id +) +SELECT + hash, + height, + success, + messages::JSON, + memo, + signatures, + signer_infos, + fee, + gas_wanted, + gas_used, + raw_log, + logs, + '[]'::JSONB, -- Check if it is a new column + 0 -- defualt value +FROM transaction_old; + +/* Create message_type table MOVED IN migrateMsgTypes function +CREATE TABLE message_type +( + type TEXT NOT NULL UNIQUE, + module TEXT NOT NULL, + label TEXT NOT NULL, + height BIGINT NOT NULL +); +CREATE INDEX message_type_module_index ON message_type (module); +CREATE INDEX message_type_type_index ON message_type (type); */ + +/* message -> message partitioned */ +ALTER TABLE message RENAME TO message_old; + +CREATE TABLE message ( + transaction_hash TEXT NOT NULL, + index BIGINT NOT NULL, + type TEXT NOT NULL REFERENCES message_type(type), + value JSON NOT NULL, + involved_accounts_addresses TEXT[] NOT NULL, + partition_id BIGINT NOT NULL DEFAULT 0, + height BIGINT NOT NULL, + FOREIGN KEY (transaction_hash, partition_id) REFERENCES transaction (hash, partition_id), + CONSTRAINT unique_message_per_tx UNIQUE (transaction_hash, index, partition_id) +) PARTITION BY LIST(partition_id); + +CREATE TABLE message_0 PARTITION OF message +FOR VALUES IN (0); + +CREATE INDEX message_transaction_hash_index ON message (transaction_hash); +CREATE INDEX message_type_index ON message (type); +CREATE INDEX message_involved_accounts_index ON message USING GIN(involved_accounts_addresses); + +INSERT INTO message ( + transaction_hash, index, type, value, + involved_accounts_addresses, partition_id, height +) +SELECT + m.transaction_hash, + m.index, + m.type, + m.value::JSON, + COALESCE(m.involved_accounts_addresses, ARRAY[]::TEXT[]), + t.partition_id, + t.height +FROM message_old m; + +/* new message_by_address function */ +DROP FUNCTION IF EXISTS messages_by_address( + TEXT[], + TEXT[], + BIGINT, + BIGINT +); + +CREATE FUNCTION messages_by_address( + addresses TEXT[], + types TEXT[], + "limit" BIGINT = 100, + "offset" BIGINT = 0) + RETURNS SETOF message AS +$$ +SELECT * FROM message +WHERE (cardinality(types) = 0 OR type = ANY (types)) + AND addresses && involved_accounts_addresses +ORDER BY height DESC LIMIT "limit" OFFSET "offset" +$$ LANGUAGE sql STABLE; + +/* Create message_by_address function */ +CREATE FUNCTION messages_by_type( + types text [], + "limit" bigint DEFAULT 100, + "offset" bigint DEFAULT 0) + RETURNS SETOF message AS +$$ +SELECT * FROM message +WHERE (cardinality(types) = 0 OR type = ANY (types)) +ORDER BY height DESC LIMIT "limit" OFFSET "offset" +$$ LANGUAGE sql STABLE; + + +/*######################### auth.sql ##########################*/ +/* Create table vesting_account */ +CREATE TABLE vesting_account +( + id SERIAL PRIMARY KEY NOT NULL, + type TEXT NOT NULL, + address TEXT NOT NULL REFERENCES account (address), + original_vesting COIN[] NOT NULL DEFAULT '{}', + end_time TIMESTAMP WITHOUT TIME ZONE NOT NULL, + start_time TIMESTAMP WITHOUT TIME ZONE +); + +CREATE UNIQUE INDEX vesting_account_address_idx ON vesting_account (address); + +/* Create table vesting_period */ + +CREATE TABLE vesting_period +( + vesting_account_id BIGINT NOT NULL REFERENCES vesting_account (id), + period_order BIGINT NOT NULL, + length BIGINT NOT NULL, + amount COIN[] NOT NULL DEFAULT '{}' +); + +-- Can table ACCOUNT_BALANCE be eliminated? + +/*######################### staking.sql ##########################*/ +/* Add column to table vesting_account */ +ALTER TABLE staking_pool +ADD COLUMN unbonding_tokens TEXT NOT NULL DEFAULT '', +ADD COLUMN staked_not_bonded_tokens TEXT NOT NULL DEFAULT ''; + +/* Drop column from table validator_status */ +ALTER TABLE validator_status +DROP COLUMN tombstoned; + +/*######################### gov.sql ##########################*/ +/* Add column to table gov_params */ +ALTER TABLE gov_params +ADD COLUMN params JSONB NOT NULL DEFAULT '[]'::JSONB; + +/* Drop columns from table gov_params */ +ALTER TABLE gov_params +DROP COLUMN deposit_params, +DROP COLUMN voting_params, +DROP COLUMN tally_params; + +/* Drop columns from table proposal */ +ALTER TABLE proposal +DROP COLUMN proposal_route, +DROP COLUMN proposal_type; + +/* Add column to table proposal */ +ALTER TABLE proposal +ADD COLUMN metadata TEXT NOT NULL DEFAULT ''; + +/* Set default for content column */ +ALTER TABLE proposal +ALTER COLUMN content SET DEFAULT '[]'::JSONB; + +/* Drop constraint unique_deposit from table proposal_deposit */ +ALTER TABLE proposal_deposit +DROP CONSTRAINT unique_deposit; + +/* Drop constraint proposal_deposit_height_fkey from table proposal_deposit */ +ALTER TABLE proposal_deposit +DROP CONSTRAINT IF EXISTS proposal_deposit_height_fkey; + +/* Add columns to table proposal_deposit */ +ALTER TABLE proposal_deposit +ADD COLUMN timestamp TIMESTAMP, +ADD COLUMN transaction_hash TEXT NOT NULL DEFAULT ''; + +/* Add constraint to table proposal_deposit */ +ALTER TABLE proposal_deposit +ADD CONSTRAINT unique_deposit UNIQUE (proposal_id, depositor_address, transaction_hash); + +/* Drop constraint unique_deposit from table proposal_vote */ +ALTER TABLE proposal_vote +DROP CONSTRAINT unique_vote; + +/* Drop constraint proposal_deposit_height_fkey from table proposal_deposit */ +ALTER TABLE proposal_vote +DROP CONSTRAINT IF EXISTS proposal_vote_height_fkey; + +/* Add columns to table proposal_deposit */ +ALTER TABLE proposal_vote +ADD COLUMN weight TEXT NOT NULL DEFAULT '', +ADD COLUMN timestamp TIMESTAMP; + +/* Add constraint to table proposal_deposit */ +ALTER TABLE proposal_vote +ADD CONSTRAINT unique_vote UNIQUE (proposal_id, voter_address, option); + +/*######################### upgrade.sql ##########################*/ +CREATE TABLE software_upgrade_plan +( + proposal_id INTEGER REFERENCES proposal (id) UNIQUE, + plan_name TEXT NOT NULL, + upgrade_height BIGINT NOT NULL, + info TEXT NOT NULL, + height BIGINT NOT NULL +); +CREATE INDEX software_upgrade_plan_proposal_id_index ON software_upgrade_plan (proposal_id); +CREATE INDEX software_upgrade_plan_height_index ON software_upgrade_plan (height); diff --git a/go.mod b/go.mod index e10d0c452..7fbed836c 100644 --- a/go.mod +++ b/go.mod @@ -1,6 +1,6 @@ module github.com/forbole/callisto/v4 -go 1.24 +go 1.23.4 require ( cosmossdk.io/log v1.5.0 From 5d8c7aad80f1c1f89d8afba7692b1806289973b6 Mon Sep 17 00:00:00 2001 From: Luca Palla Date: Fri, 23 May 2025 17:33:12 +0200 Subject: [PATCH 2/2] Update migration.go Update migrationV5.sql --- database/migrate/v5/migrate.go | 41 +++--- database/migrate/v5/migrationv5.sql | 186 ++++++++++------------------ 2 files changed, 91 insertions(+), 136 deletions(-) diff --git a/database/migrate/v5/migrate.go b/database/migrate/v5/migrate.go index 6da90c29d..629d0b5ae 100644 --- a/database/migrate/v5/migrate.go +++ b/database/migrate/v5/migrate.go @@ -28,11 +28,13 @@ func (db *Migrator) Migrate() error { return err } } - sqlBytes, err := os.ReadFile("migrations/your_file.sql") + // read the sql migration file + sqlBytes, err := os.ReadFile("database/migrate/v5/migrationv5.sql") if err != nil { log.Fatalf("Failed to read SQL file: %v", err) } + // execute scripts err = db.migrateDbSchema(string(sqlBytes)) if err != nil { log.Fatalf("Migration failed: %v", err) @@ -53,22 +55,31 @@ func (db *Migrator) getMsgTypesFromMessageTable() ([]MessageRow, error) { // migrateMsgTypes stores the given message type inside the database func (db *Migrator) migrateMsgTypes(msg *types.MessageType) error { - stmt := ` -CREATE TABLE message_type -( - type TEXT NOT NULL UNIQUE, - module TEXT NOT NULL, - label TEXT NOT NULL, - height BIGINT NOT NULL -); -CREATE INDEX message_type_module_index ON message_type (module); -CREATE INDEX message_type_type_index ON message_type (type); + // Step 1: Create the table and indexes (no parameters, can be run as plain exec) + schemaStmt := ` + CREATE TABLE IF NOT EXISTS message_type + ( + type TEXT NOT NULL UNIQUE, + module TEXT NOT NULL, + label TEXT NOT NULL, + height BIGINT NOT NULL + ); + CREATE INDEX IF NOT EXISTS message_type_module_index ON message_type (module); + CREATE INDEX IF NOT EXISTS message_type_type_index ON message_type (type); + ` -INSERT INTO message_type(type, module, label, height) -VALUES ($1, $2, $3, $4) -ON CONFLICT (type) DO NOTHING;` + _, err := db.SQL.Exec(schemaStmt) + if err != nil { + return err + } + + // Step 2: Insert the message type (with parameters) + insertStmt := ` + INSERT INTO message_type(type, module, label, height) + VALUES ($1, $2, $3, $4) + ON CONFLICT (type) DO NOTHING;` - _, err := db.SQL.Exec(stmt, msg.Type, msg.Module, msg.Label, msg.Height) + _, err = db.SQL.Exec(insertStmt, msg.Type, msg.Module, msg.Label, msg.Height) return err } diff --git a/database/migrate/v5/migrationv5.sql b/database/migrate/v5/migrationv5.sql index 50aab3f7b..271e8bfa3 100644 --- a/database/migrate/v5/migrationv5.sql +++ b/database/migrate/v5/migrationv5.sql @@ -9,103 +9,73 @@ autovacuum_vacuum_threshold = 10000, autovacuum_analyze_threshold = 10000 ); -/* transaction -> transaction partitioned */ -ALTER TABLE transaction RENAME TO transaction_before_050; - -CREATE TABLE transaction ( - hash TEXT NOT NULL, - height BIGINT NOT NULL REFERENCES block (height), - success BOOLEAN NOT NULL, - messages JSON NOT NULL DEFAULT '[]'::JSON, - memo TEXT, - signatures TEXT[] NOT NULL, - signer_infos JSONB NOT NULL DEFAULT '[]'::JSONB, - fee JSONB NOT NULL DEFAULT '{}'::JSONB, - gas_wanted BIGINT DEFAULT 0, - gas_used BIGINT DEFAULT 0, - raw_log TEXT, - logs JSONB, - events JSONB NOT NULL DEFAULT '[]'::JSONB, - partition_id BIGINT NOT NULL DEFAULT 0, - - CONSTRAINT unique_tx UNIQUE (hash, partition_id) -) PARTITION BY LIST(partition_id); - -CREATE INDEX transaction_hash_index ON transaction (hash); -CREATE INDEX transaction_height_index ON transaction (height); -CREATE INDEX transaction_partition_id_index ON transaction (partition_id); - -CREATE TABLE transaction_0 PARTITION OF transaction -FOR VALUES IN (0); - -INSERT INTO transaction ( - hash, height, success, messages, memo, signatures, - signer_infos, fee, gas_wanted, gas_used, raw_log, logs, - events, partition_id +/* transaction */ +-- Add new column to the parent transaction table +ALTER TABLE transaction +ADD COLUMN events JSONB NOT NULL DEFAULT '[]'::JSONB; + +-- Change messages column type to JSON in the parent transaction table +ALTER TABLE transaction +ALTER COLUMN messages DROP DEFAULT, +ALTER COLUMN messages TYPE JSON USING messages::JSON, +ALTER COLUMN messages SET DEFAULT '[]'::JSON; + +-- Add new column to the child transaction tables +SELECT format( + 'ALTER TABLE %I ADD COLUMN events JSONB NOT NULL DEFAULT ''[]''::JSONB;', + relname ) -SELECT - hash, - height, - success, - messages::JSON, - memo, - signatures, - signer_infos, - fee, - gas_wanted, - gas_used, - raw_log, - logs, - '[]'::JSONB, -- Check if it is a new column - 0 -- defualt value -FROM transaction_old; - -/* Create message_type table MOVED IN migrateMsgTypes function -CREATE TABLE message_type -( - type TEXT NOT NULL UNIQUE, - module TEXT NOT NULL, - label TEXT NOT NULL, - height BIGINT NOT NULL -); -CREATE INDEX message_type_module_index ON message_type (module); -CREATE INDEX message_type_type_index ON message_type (type); */ - -/* message -> message partitioned */ -ALTER TABLE message RENAME TO message_old; - -CREATE TABLE message ( - transaction_hash TEXT NOT NULL, - index BIGINT NOT NULL, - type TEXT NOT NULL REFERENCES message_type(type), - value JSON NOT NULL, - involved_accounts_addresses TEXT[] NOT NULL, - partition_id BIGINT NOT NULL DEFAULT 0, - height BIGINT NOT NULL, - FOREIGN KEY (transaction_hash, partition_id) REFERENCES transaction (hash, partition_id), - CONSTRAINT unique_message_per_tx UNIQUE (transaction_hash, index, partition_id) -) PARTITION BY LIST(partition_id); - -CREATE TABLE message_0 PARTITION OF message -FOR VALUES IN (0); - -CREATE INDEX message_transaction_hash_index ON message (transaction_hash); -CREATE INDEX message_type_index ON message (type); -CREATE INDEX message_involved_accounts_index ON message USING GIN(involved_accounts_addresses); - -INSERT INTO message ( - transaction_hash, index, type, value, - involved_accounts_addresses, partition_id, height +FROM pg_class +WHERE relname LIKE 'transaction_%' AND relkind = 'r'; + +-- Change messages column type to JSON in the child transaction tables +SELECT format( + $$ + ALTER TABLE %I + ALTER COLUMN messages DROP DEFAULT, + ALTER COLUMN messages TYPE JSON USING messages::JSON, + ALTER COLUMN messages SET DEFAULT '[]'::JSON; + $$, + relname ) -SELECT - m.transaction_hash, - m.index, - m.type, - m.value::JSON, - COALESCE(m.involved_accounts_addresses, ARRAY[]::TEXT[]), - t.partition_id, - t.height -FROM message_old m; +FROM pg_class +WHERE relname LIKE 'transaction_%' AND relkind = 'r'; + +/* message */ +-- Change value column from JSONB to JSON +ALTER TABLE message +ALTER COLUMN value DROP DEFAULT, +ALTER COLUMN value TYPE JSON USING value::JSON; + +-- Add foreign key to message_type(type) +ALTER TABLE message +ADD CONSTRAINT message_type_fk +FOREIGN KEY (type) REFERENCES message_type(type); + +-- Alter child message tables +DO $$ +DECLARE + r RECORD; +BEGIN + FOR r IN + SELECT inhrelid::regclass AS partition_name + FROM pg_inherits + WHERE inhparent = 'message'::regclass + LOOP + RAISE NOTICE 'Altering partition: %', r.partition_name; + + -- Add FK constraint on type column + EXECUTE format( + 'ALTER TABLE %I + ADD CONSTRAINT %I + FOREIGN KEY (type) REFERENCES message_type(type);', + r.partition_name, + r.partition_name || '_type_fk' + ); + END LOOP; +END +$$; + /* new message_by_address function */ DROP FUNCTION IF EXISTS messages_by_address( @@ -141,32 +111,6 @@ ORDER BY height DESC LIMIT "limit" OFFSET "offset" $$ LANGUAGE sql STABLE; -/*######################### auth.sql ##########################*/ -/* Create table vesting_account */ -CREATE TABLE vesting_account -( - id SERIAL PRIMARY KEY NOT NULL, - type TEXT NOT NULL, - address TEXT NOT NULL REFERENCES account (address), - original_vesting COIN[] NOT NULL DEFAULT '{}', - end_time TIMESTAMP WITHOUT TIME ZONE NOT NULL, - start_time TIMESTAMP WITHOUT TIME ZONE -); - -CREATE UNIQUE INDEX vesting_account_address_idx ON vesting_account (address); - -/* Create table vesting_period */ - -CREATE TABLE vesting_period -( - vesting_account_id BIGINT NOT NULL REFERENCES vesting_account (id), - period_order BIGINT NOT NULL, - length BIGINT NOT NULL, - amount COIN[] NOT NULL DEFAULT '{}' -); - --- Can table ACCOUNT_BALANCE be eliminated? - /*######################### staking.sql ##########################*/ /* Add column to table vesting_account */ ALTER TABLE staking_pool