From 6bddcd15d0388a746b578bfcf1ffd8da9b79bdb0 Mon Sep 17 00:00:00 2001 From: Geoffrey Ragot Date: Wed, 30 Oct 2024 15:07:54 +0100 Subject: [PATCH] feat: move long migrations after the minimal migration --- .../migrations/11-make-stateless/up.sql | 24 ------------- .../12-transaction-reference-index/notes.yaml | 1 + .../12-transaction-reference-index/up.sql | 1 + .../13-create-ledger-indexes/notes.yaml | 1 + .../13-create-ledger-indexes/up.sql | 36 +++++++++++++++++++ 5 files changed, 39 insertions(+), 24 deletions(-) create mode 100644 internal/storage/bucket/migrations/12-transaction-reference-index/notes.yaml create mode 100644 internal/storage/bucket/migrations/12-transaction-reference-index/up.sql create mode 100644 internal/storage/bucket/migrations/13-create-ledger-indexes/notes.yaml create mode 100644 internal/storage/bucket/migrations/13-create-ledger-indexes/up.sql diff --git a/internal/storage/bucket/migrations/11-make-stateless/up.sql b/internal/storage/bucket/migrations/11-make-stateless/up.sql index 1a2462f12..9b92f4282 100644 --- a/internal/storage/bucket/migrations/11-make-stateless/up.sql +++ b/internal/storage/bucket/migrations/11-make-stateless/up.sql @@ -205,8 +205,6 @@ add column inserted_at timestamp without time zone default (transaction_date() a alter column timestamp set default (transaction_date() at time zone 'utc'), alter column id type bigint; -drop index transactions_reference; -create unique index transactions_reference on transactions (ledger, reference); create index transactions_sequences on transactions (id, seq); alter table logs @@ -482,10 +480,6 @@ $do$ vsql = 'select setval(''"log_id_' || ledger.id || '"'', coalesce((select max(id) + 1 from logs where ledger = ''' || ledger.name || '''), 1)::bigint, false)'; execute vsql; - -- enable post commit effective volumes synchronously - vsql = 'create index "pcev_' || ledger.id || '" on moves (accounts_address, asset, effective_date desc) where ledger = ''' || ledger.name || ''''; - execute vsql; - vsql = 'create trigger "set_effective_volumes_' || ledger.id || '" before insert on moves for each row when (new.ledger = ''' || ledger.name || ''') execute procedure set_effective_volumes()'; execute vsql; @@ -508,30 +502,12 @@ $do$ vsql = 'create trigger "insert_transaction_metadata_history_' || ledger.id || '" after insert on "transactions" for each row when (new.ledger = ''' || ledger.name || ''') execute procedure insert_transaction_metadata_history()'; execute vsql; - vsql = 'create index "transactions_sources_' || ledger.id || '" on transactions using gin (sources jsonb_path_ops) where ledger = ''' || ledger.name || ''''; - execute vsql; - - vsql = 'create index "transactions_destinations_' || ledger.id || '" on transactions using gin (destinations jsonb_path_ops) where ledger = ''' || ledger.name || ''''; - execute vsql; - vsql = 'create trigger "transaction_set_addresses_' || ledger.id || '" before insert on transactions for each row when (new.ledger = ''' || ledger.name || ''') execute procedure set_transaction_addresses()'; execute vsql; - vsql = 'create index "accounts_address_array_' || ledger.id || '" on accounts using gin (address_array jsonb_ops) where ledger = ''' || ledger.name || ''''; - execute vsql; - - vsql = 'create index "accounts_address_array_length_' || ledger.id || '" on accounts (jsonb_array_length(address_array)) where ledger = ''' || ledger.name || ''''; - execute vsql; - vsql = 'create trigger "accounts_set_address_array_' || ledger.id || '" before insert on accounts for each row when (new.ledger = ''' || ledger.name || ''') execute procedure set_address_array_for_account()'; execute vsql; - vsql = 'create index "transactions_sources_arrays_' || ledger.id || '" on transactions using gin (sources_arrays jsonb_path_ops) where ledger = ''' || ledger.name || ''''; - execute vsql; - - vsql = 'create index "transactions_destinations_arrays_' || ledger.id || '" on transactions using gin (destinations_arrays jsonb_path_ops) where ledger = ''' || ledger.name || ''''; - execute vsql; - vsql = 'create trigger "transaction_set_addresses_segments_' || ledger.id || '" before insert on "transactions" for each row when (new.ledger = ''' || ledger.name || ''') execute procedure set_transaction_addresses_segments()'; execute vsql; end loop; diff --git a/internal/storage/bucket/migrations/12-transaction-reference-index/notes.yaml b/internal/storage/bucket/migrations/12-transaction-reference-index/notes.yaml new file mode 100644 index 000000000..a76875651 --- /dev/null +++ b/internal/storage/bucket/migrations/12-transaction-reference-index/notes.yaml @@ -0,0 +1 @@ +name: Create transaction reference index concurrently diff --git a/internal/storage/bucket/migrations/12-transaction-reference-index/up.sql b/internal/storage/bucket/migrations/12-transaction-reference-index/up.sql new file mode 100644 index 000000000..98fa61296 --- /dev/null +++ b/internal/storage/bucket/migrations/12-transaction-reference-index/up.sql @@ -0,0 +1 @@ +create unique index concurrently transactions_reference2 on "{{.Schema}}".transactions (ledger, reference); \ No newline at end of file diff --git a/internal/storage/bucket/migrations/13-create-ledger-indexes/notes.yaml b/internal/storage/bucket/migrations/13-create-ledger-indexes/notes.yaml new file mode 100644 index 000000000..652f242b6 --- /dev/null +++ b/internal/storage/bucket/migrations/13-create-ledger-indexes/notes.yaml @@ -0,0 +1 @@ +name: Create ledger indexes diff --git a/internal/storage/bucket/migrations/13-create-ledger-indexes/up.sql b/internal/storage/bucket/migrations/13-create-ledger-indexes/up.sql new file mode 100644 index 000000000..1efb24192 --- /dev/null +++ b/internal/storage/bucket/migrations/13-create-ledger-indexes/up.sql @@ -0,0 +1,36 @@ +set search_path = '{{.Schema}}'; + +drop index transactions_reference; +alter index transactions_reference2 rename to transactions_reference; + +DO +$do$ + declare + ledger record; + vsql text; + BEGIN + for ledger in select * from _system.ledgers where bucket = current_schema loop + -- enable post commit effective volumes synchronously + vsql = 'create index "pcev_' || ledger.id || '" on moves (accounts_address, asset, effective_date desc) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "transactions_sources_' || ledger.id || '" on transactions using gin (sources jsonb_path_ops) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "transactions_destinations_' || ledger.id || '" on transactions using gin (destinations jsonb_path_ops) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "accounts_address_array_' || ledger.id || '" on accounts using gin (address_array jsonb_ops) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "accounts_address_array_length_' || ledger.id || '" on accounts (jsonb_array_length(address_array)) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "transactions_sources_arrays_' || ledger.id || '" on transactions using gin (sources_arrays jsonb_path_ops) where ledger = ''' || ledger.name || ''''; + execute vsql; + + vsql = 'create index "transactions_destinations_arrays_' || ledger.id || '" on transactions using gin (destinations_arrays jsonb_path_ops) where ledger = ''' || ledger.name || ''''; + execute vsql; + end loop; + END +$do$;