Merge pull request #1104 from poanetwork/ams-add-migration-scripts
Add migration scripts that we've been using to migrate datapull/1123/head
commit
4432ba4222
@ -0,0 +1,20 @@ |
||||
# Upgrading Guide |
||||
|
||||
### Migration scripts |
||||
|
||||
There is in the project a `scripts` folder that contains `SQL` files responsible to migrate data from the database. |
||||
|
||||
This script should be used if you already have an indexed database with a large amount of data. |
||||
|
||||
#### `address_current_token_balances_in_batches.sql` |
||||
|
||||
Is responsible to populate a new table using the `token_balances` table information. |
||||
|
||||
#### `internal_transaction_update_in_batches.sql` |
||||
|
||||
Is responsible to migrate data from the `transactions` table to the `internal_transactions` one in order to improve the application listing performance; |
||||
|
||||
#### `transaction_update_in_baches.sql` |
||||
|
||||
Parity call traces contain the input, but it was not put in the internal_transactions_params. |
||||
Enforce input and call_type being non-NULL for calls in new constraints on internal_transactions. |
@ -1,32 +0,0 @@ |
||||
defmodule Mix.Tasks.Migrate.Transaction.Info do |
||||
use Mix.Task |
||||
|
||||
alias Ecto.Adapters.SQL |
||||
alias Explorer.Repo |
||||
|
||||
@shortdoc "Migrates transaction info to internal transaction" |
||||
|
||||
@moduledoc """ |
||||
This task is reponsible to populate the `transaction_index` and |
||||
`block_number` at the `internal_transactions` table, using the |
||||
`transactions` info. |
||||
""" |
||||
|
||||
def run(_args) do |
||||
{:ok, _} = Application.ensure_all_started(:explorer) |
||||
|
||||
SQL.query( |
||||
Repo, |
||||
""" |
||||
UPDATE internal_transactions |
||||
SET |
||||
block_number = transactions.block_number, |
||||
transaction_index = transactions.index |
||||
FROM transactions |
||||
WHERE internal_transactions.transaction_hash = transactions.hash; |
||||
""", |
||||
[], |
||||
timeout: :infinity |
||||
) |
||||
end |
||||
end |
@ -0,0 +1,69 @@ |
||||
DO $$ |
||||
DECLARE |
||||
row_count integer := 1; |
||||
batch_size integer := 50000; -- HOW MANY ITEMS WILL BE UPDATED AT TIME |
||||
iterator integer := batch_size; |
||||
affected integer; |
||||
BEGIN |
||||
DROP TABLE IF EXISTS current_token_balance_temp; |
||||
-- CREATES TEMP TABLE TO STORE TOKEN BALANCES TO BE UPDATED |
||||
CREATE TEMP TABLE current_token_balance_temp( |
||||
address_hash bytea NOT NULL, |
||||
block_number bigint NOT NULL, |
||||
token_contract_address_hash bytea NOT NULL, |
||||
value numeric, |
||||
value_fetched_at timestamp without time zone, |
||||
inserted_at timestamp without time zone NOT NULL, |
||||
updated_at timestamp without time zone NOT NULL, |
||||
row_number integer |
||||
); |
||||
INSERT INTO current_token_balance_temp |
||||
SELECT DISTINCT ON (address_hash, token_contract_address_hash) |
||||
address_hash, |
||||
block_number, |
||||
token_contract_address_hash, |
||||
value, |
||||
value_fetched_at, |
||||
inserted_at, |
||||
updated_at, |
||||
ROW_NUMBER () OVER () |
||||
FROM address_token_balances |
||||
WHERE value IS NOT NULL |
||||
ORDER BY address_hash, token_contract_address_hash, block_number DESC; |
||||
|
||||
row_count := (SELECT count(*) FROM current_token_balance_temp); |
||||
RAISE NOTICE '% items to be updated', row_count; |
||||
|
||||
-- ITERATES THROUGH THE ITEMS UNTIL THE TEMP TABLE IS EMPTY |
||||
WHILE row_count > 0 LOOP |
||||
-- INSERT THE TOKEN BALANCES AND RETURNS THE ADDRESS HASH AND TOKEN HASH TO BE DELETED |
||||
WITH updated_address_current_token_balances AS ( |
||||
INSERT INTO address_current_token_balances (address_hash, block_number, token_contract_address_hash, value, value_fetched_at, inserted_at, updated_at) |
||||
SELECT |
||||
address_hash, |
||||
block_number, |
||||
token_contract_address_hash, |
||||
value, |
||||
value_fetched_at, |
||||
inserted_at, |
||||
updated_at |
||||
FROM current_token_balance_temp |
||||
WHERE current_token_balance_temp.row_number <= iterator |
||||
RETURNING address_hash, token_contract_address_hash |
||||
) |
||||
DELETE FROM current_token_balance_temp |
||||
WHERE (address_hash, token_contract_address_hash) IN (select address_hash, token_contract_address_hash from updated_address_current_token_balances); |
||||
|
||||
GET DIAGNOSTICS affected = ROW_COUNT; |
||||
RAISE NOTICE '-> % address current token balances updated!', affected; |
||||
|
||||
-- COMMITS THE BATCH UPDATES |
||||
CHECKPOINT; |
||||
|
||||
-- UPDATES THE COUNTER SO IT DOESN'T TURN INTO AN INFINITE LOOP |
||||
row_count := (SELECT count(*) FROM current_token_balance_temp); |
||||
iterator := iterator + batch_size; |
||||
RAISE NOTICE '-> % counter', row_count; |
||||
RAISE NOTICE '-> % next batch', iterator; |
||||
END LOOP; |
||||
END $$; |
@ -0,0 +1,59 @@ |
||||
DO $$ |
||||
DECLARE |
||||
row_count integer := 1; |
||||
batch_size integer := 50000; -- HOW MANY ITEMS WILL BE UPDATED AT TIME |
||||
iterator integer := batch_size; |
||||
affected integer; |
||||
BEGIN |
||||
DROP TABLE IF EXISTS transactions_temp; |
||||
|
||||
-- CREATES TEMP TABLE TO STORE TRANSACTIONS TO BE UPDATED |
||||
CREATE TEMP TABLE transactions_temp(hash bytea, block_number integer, index integer, row_number integer); |
||||
INSERT INTO transactions_temp |
||||
SELECT |
||||
t.hash, |
||||
t.block_number, |
||||
t.index, |
||||
ROW_NUMBER () OVER () |
||||
FROM transactions t |
||||
INNER JOIN internal_transactions it ON t.hash = it.transaction_hash AND it.block_number IS NULL |
||||
WHERE |
||||
t.hash = it.transaction_hash |
||||
AND it.block_number IS NULL |
||||
; |
||||
|
||||
row_count := (SELECT count(*) FROM transactions_temp); |
||||
|
||||
RAISE NOTICE '% items to be updated', row_count; |
||||
|
||||
-- ITERATES THROUGH THE ITEMS UNTIL THE TEMP TABLE IS EMPTY |
||||
WHILE row_count > 0 LOOP |
||||
-- UPDATES INTERNAL TRANSACTION AND RETURNS THE HASH TO BE DELETED |
||||
WITH updated_internal_transactions AS ( |
||||
UPDATE internal_transactions |
||||
SET |
||||
block_number = transactions_temp.block_number, |
||||
transaction_index = transactions_temp.index |
||||
FROM transactions_temp |
||||
WHERE internal_transactions.transaction_hash = transactions_temp.hash |
||||
AND transactions_temp.row_number <= iterator |
||||
RETURNING transactions_temp.hash |
||||
) |
||||
-- DELETES THE ITENS UPDATED FROM THE TEMP TABLE |
||||
DELETE FROM transactions_temp tt |
||||
USING updated_internal_transactions uit |
||||
WHERE tt.hash = uit.hash; |
||||
|
||||
GET DIAGNOSTICS affected = ROW_COUNT; |
||||
RAISE NOTICE '-> % internal transactions updated!', affected; |
||||
|
||||
CHECKPOINT; -- COMMITS THE BATCH UPDATES |
||||
|
||||
-- UPDATES THE COUNTER SO IT DOESN'T TURN INTO AN INFINITE LOOP |
||||
row_count := (SELECT count(*) FROM transactions_temp); |
||||
iterator := iterator + batch_size; |
||||
|
||||
RAISE NOTICE '-> % counter', row_count; |
||||
RAISE NOTICE '-> % next batch', iterator; |
||||
END LOOP; |
||||
END $$; |
@ -0,0 +1,55 @@ |
||||
DO $$ |
||||
DECLARE |
||||
row_count integer := 1; |
||||
batch_size integer := 50000; -- HOW MANY ITEMS WILL BE UPDATED AT TIME |
||||
iterator integer := batch_size; |
||||
affected integer; |
||||
BEGIN |
||||
DROP TABLE IF EXISTS transactions_error_itx_indexed_at_temp; |
||||
|
||||
-- CREATES TEMP TABLE TO STORE TRANSACTIONS TO BE UPDATED |
||||
CREATE TEMP TABLE transactions_error_itx_indexed_at_temp(hash bytea, row_number integer); |
||||
|
||||
INSERT INTO transactions_error_itx_indexed_at_temp |
||||
SELECT |
||||
DISTINCT it.transaction_hash, |
||||
ROW_NUMBER () OVER () |
||||
FROM internal_transactions it |
||||
WHERE it.type = 'call' |
||||
AND it.input IS NULL; |
||||
|
||||
row_count := (SELECT count(*) FROM transactions_error_itx_indexed_at_temp); |
||||
|
||||
RAISE NOTICE '% items to be updated', row_count; |
||||
|
||||
-- ITERATES THROUGH THE ITEMS UNTIL THE TEMP TABLE IS EMPTY |
||||
WHILE row_count > 0 LOOP |
||||
-- UPDATES TRANSACTION AND RETURNS THE HASH TO BE DELETED |
||||
WITH updated_transactions AS ( |
||||
UPDATE transactions |
||||
SET |
||||
internal_transactions_indexed_at = null, |
||||
error = null |
||||
FROM transactions_error_itx_indexed_at_temp |
||||
WHERE transactions.hash = transactions_error_itx_indexed_at_temp.hash |
||||
AND transactions_error_itx_indexed_at_temp.row_number <= iterator |
||||
RETURNING transactions_error_itx_indexed_at_temp.hash |
||||
) |
||||
-- DELETES THE ITENS UPDATED FROM THE TEMP TABLE |
||||
DELETE FROM transactions_error_itx_indexed_at_temp tt |
||||
USING updated_transactions uit |
||||
WHERE tt.hash = uit.hash; |
||||
|
||||
GET DIAGNOSTICS affected = ROW_COUNT; |
||||
RAISE NOTICE '-> % transactions updated!', affected; |
||||
|
||||
CHECKPOINT; -- COMMITS THE BATCH UPDATES |
||||
|
||||
-- UPDATES THE COUNTER SO IT DOESN'T TURN INTO AN INFINITE LOOP |
||||
row_count := (SELECT count(*) FROM transactions_error_itx_indexed_at_temp); |
||||
iterator := iterator + batch_size; |
||||
|
||||
RAISE NOTICE '-> % counter', row_count; |
||||
RAISE NOTICE '-> % next batch', iterator; |
||||
END LOOP; |
||||
END $$; |
Loading…
Reference in new issue