From 2ad1042de208182bcc83e8f780966b019530b19c Mon Sep 17 00:00:00 2001 From: Felipe Renan Date: Wed, 21 Nov 2018 17:17:48 -0200 Subject: [PATCH] Add script to migrate block_number to token transfers This script copy block_number from the transactions' table to token transfers' table in batches. --- ...16_add_block_number_to_token_transfers.exs | 9 +++++ ...ansfers_update_block_number_in_batches.sql | 39 +++++++++++++++++++ 2 files changed, 48 insertions(+) create mode 100644 apps/explorer/priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql diff --git a/apps/explorer/priv/repo/migrations/20181121170616_add_block_number_to_token_transfers.exs b/apps/explorer/priv/repo/migrations/20181121170616_add_block_number_to_token_transfers.exs index ff3a73bb6a..60c426e304 100644 --- a/apps/explorer/priv/repo/migrations/20181121170616_add_block_number_to_token_transfers.exs +++ b/apps/explorer/priv/repo/migrations/20181121170616_add_block_number_to_token_transfers.exs @@ -1,4 +1,13 @@ defmodule Explorer.Repo.Migrations.AddBlockNumberToTokenTransfers do + @moduledoc """ + Use `priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql` to migrate data. + + ```sh + mix ecto.migrate + psql -d $DATABASE -a -f priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql + ``` + """ + use Ecto.Migration def change do diff --git a/apps/explorer/priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql b/apps/explorer/priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql new file mode 100644 index 0000000000..1fc30be9a9 --- /dev/null +++ b/apps/explorer/priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql @@ -0,0 +1,39 @@ +DO $$ +DECLARE + row_count integer; + batch_size integer := 100000; -- HOW MANY ITEMS WILL BE UPDATED AT TIME + affected integer; +BEGIN + RAISE NOTICE 'Counting items to be updated'; + + row_count := (SELECT COUNT(*) FROM token_transfers WHERE block_number IS NULL); + + RAISE NOTICE '% items', row_count; + + WHILE row_count > 0 LOOP + WITH cte AS ( + SELECT + t.hash, + t.block_number + FROM token_transfers AS tt + INNER JOIN transactions AS t ON t.hash = tt.transaction_hash + WHERE tt.block_number IS NULL + LIMIT batch_size + ) + UPDATE token_transfers + SET + block_number = cte.block_number + FROM cte + WHERE token_transfers.transaction_hash = cte.hash; + + GET DIAGNOSTICS affected = ROW_COUNT; + RAISE NOTICE '-> % token transfers updated!', affected; + + -- UPDATES THE COUNTER SO IT DOESN'T TURN INTO AN INFINITE LOOP + row_count := row_count - batch_size; + + RAISE NOTICE '-> % items missing to update', row_count; + + CHECKPOINT; -- COMMITS THE BATCH UPDATES + END LOOP; +END $$;