Add script to migrate block_number to token transfers

This script copy block_number from the transactions' table to token
transfers' table in batches.
pull/1124/head
Felipe Renan 6 years ago
parent 31e1090138
commit 2ad1042de2
  1. 9
      apps/explorer/priv/repo/migrations/20181121170616_add_block_number_to_token_transfers.exs
  2. 39
      apps/explorer/priv/repo/migrations/scripts/20181121170616_token_transfers_update_block_number_in_batches.sql

@ -1,4 +1,13 @@
defmodule Explorer.Repo.Migrations.AddBlockNumberToTokenTransfers do 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 use Ecto.Migration
def change do def change do

@ -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 $$;
Loading…
Cancel
Save