From f71228884cb111208aa3d3aba45e344ceb691cc2 Mon Sep 17 00:00:00 2001 From: Andrew Cravenho Date: Tue, 29 Jan 2019 11:58:48 -0500 Subject: [PATCH 1/3] Update migration script for dropped/replaced transactions --- .../scripts/update_replaced_transaction.sql | 75 ++++++++++++++++++- 1 file changed, 71 insertions(+), 4 deletions(-) diff --git a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql index 16f0765744..78c83865df 100644 --- a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql +++ b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql @@ -1,19 +1,86 @@ DO $$ DECLARE + total_count integer := 0; + completed_count integer := 0; + remaining_count integer := 0; + batch_size integer := 1000; + iterator integer := batch_size; + updated_count integer; + deleted_count integer; start_time TIMESTAMP WITHOUT TIME ZONE := clock_timestamp(); end_time TIMESTAMP WITHOUT TIME ZONE; elapsed_time INTERVAL; temp_start_time TIMESTAMP WITHOUT TIME ZONE; temp_end_time TIMESTAMP WITHOUT TIME ZONE; + temp_elapsed_time INTERVAL; + update_start_time TIMESTAMP WITHOUT TIME ZONE; + update_end_time TIMESTAMP WITHOUT TIME ZONE; + update_elapsed_time INTERVAL; + per_row INTERVAL; BEGIN RAISE NOTICE 'Started at %', start_time; temp_start_time := clock_timestamp(); - UPDATE transactions SET error = 'dropped/replaced', status = 0 FROM transactions t1 - INNER JOIN transactions t2 - ON t1.from_address_hash = t2.from_address_hash AND t1.nonce = t2.nonce - WHERE t1.block_hash IS NULL AND t2.block_hash IS NOT NULL; + DROP TABLE IF EXISTS transactions_dropped_replaced; + CREATE TEMP TABLE transactions_dropped_replaced + ( + nonce integer NOT NULL, + from_address_hash bytea NOT NULL, + row_number integer NOT NULL + ); + + INSERT INTO transactions_dropped_replaced + SELECT transactions.nonce, + transactions.from_address_hash, + ROW_NUMBER() OVER () + FROM transactions + WHERE transactions.block_hash IS NULL; + + temp_end_time := clock_timestamp(); + temp_elapsed_time := temp_end_time - temp_start_time; + total_count := (SELECT COUNT(*) FROM transactions_dropped_replaced); + + RAISE NOTICE 'transactions_dropped_replaced TEMP table filled in %', temp_elapsed_time; + + remaining_count := total_count; + + RAISE NOTICE '% transactions to be updated', remaining_count; + + update_start_time := clock_timestamp(); + + WHILE remaining_count > 0 + LOOP + UPDATE transactions + SET error = 'dropped/replaced', status = 0 + FROM transactions_dropped_replaced + WHERE transactions_dropped_replaced.row_number <= iterator AND + transactions_dropped_replaced.nonce = transactions.nonce AND + transactions_dropped_replaced.from_address_hash = transactions.from_address_hash AND + transactions.block_hash IS NOT NULL; + + GET DIAGNOSTICS updated_count = ROW_COUNT; + RAISE NOTICE '-> % transaction counts updated.', updated_count; + + DELETE + FROM transactions_dropped_replaced + WHERE transactions_dropped_replaced.row_number <= iterator; + + GET DIAGNOSTICS deleted_count = ROW_COUNT; + RAISE NOTICE '-> % transactions from it count removed from queue.', deleted_count; + + -- COMMITS THE BATCH UPDATES + CHECKPOINT; + + remaining_count := remaining_count - deleted_count; + iterator := iterator + batch_size; + RAISE NOTICE '-> % remaining', remaining_count; + RAISE NOTICE '-> % next batch', iterator; + update_elapsed_time := clock_timestamp() - update_start_time; + completed_count := total_count - remaining_count; + per_row := update_elapsed_time / completed_count; + RAISE NOTICE '-> Estimated time until completion: %s', per_row * remaining_count; + END LOOP; end_time := clock_timestamp(); elapsed_time := end_time - start_time; From c0ac367960cf337a80b1d4fcec37d6bbe71dd7e8 Mon Sep 17 00:00:00 2001 From: Andrew Cravenho Date: Tue, 29 Jan 2019 12:27:32 -0500 Subject: [PATCH 2/3] Fix block_hash is null statement --- .../repo/migrations/scripts/update_replaced_transaction.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql index 78c83865df..781764c778 100644 --- a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql +++ b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql @@ -3,7 +3,7 @@ DO $$ total_count integer := 0; completed_count integer := 0; remaining_count integer := 0; - batch_size integer := 1000; + batch_size integer := 10; iterator integer := batch_size; updated_count integer; deleted_count integer; @@ -57,7 +57,7 @@ DO $$ WHERE transactions_dropped_replaced.row_number <= iterator AND transactions_dropped_replaced.nonce = transactions.nonce AND transactions_dropped_replaced.from_address_hash = transactions.from_address_hash AND - transactions.block_hash IS NOT NULL; + transactions.block_hash IS NULL; GET DIAGNOSTICS updated_count = ROW_COUNT; RAISE NOTICE '-> % transaction counts updated.', updated_count; From 4a5bf27060f8442fb5b2cb7cb1992dc12be762d6 Mon Sep 17 00:00:00 2001 From: Andrew Cravenho Date: Tue, 29 Jan 2019 18:05:21 -0500 Subject: [PATCH 3/3] Only add confirmed dropped/replaced txs to temp table --- .../scripts/update_replaced_transaction.sql | 12 +++++++----- 1 file changed, 7 insertions(+), 5 deletions(-) diff --git a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql index 781764c778..501a550f82 100644 --- a/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql +++ b/apps/explorer/priv/repo/migrations/scripts/update_replaced_transaction.sql @@ -3,7 +3,7 @@ DO $$ total_count integer := 0; completed_count integer := 0; remaining_count integer := 0; - batch_size integer := 10; + batch_size integer := 50; iterator integer := batch_size; updated_count integer; deleted_count integer; @@ -31,11 +31,13 @@ DO $$ ); INSERT INTO transactions_dropped_replaced - SELECT transactions.nonce, - transactions.from_address_hash, + SELECT t1.nonce, + t1.from_address_hash, ROW_NUMBER() OVER () - FROM transactions - WHERE transactions.block_hash IS NULL; + FROM transactions t1 + INNER JOIN transactions t2 + ON t1.from_address_hash = t2.from_address_hash AND t1.nonce = t2.nonce AND t2.block_hash IS NOT NULL + WHERE t1.block_hash IS NULL; temp_end_time := clock_timestamp(); temp_elapsed_time := temp_end_time - temp_start_time;