Add script to validate internal_transactions constraint for large DBs

Problem: executing the existing sql script to validate internal_transactions constraint is too slow (or even gets stuck) for large DBs and its progress cannot be checked.

Solution: add an alternative implementation of the same script that can be monitored from outside and has better performance.
pull/2373/head
pasqu4le 5 years ago
parent 1cee89e768
commit 1f5bf98a06
No known key found for this signature in database
GPG Key ID: 8F3EE01F1DC90687
  1. 1
      CHANGELOG.md
  2. 3
      apps/explorer/priv/repo/migrations/20181108205650_additional_internal_transaction_constraints.exs
  3. 75
      apps/explorer/priv/repo/migrations/scripts/20181108205650_large_additional_internal_transaction_constraints.sql

@ -1,6 +1,7 @@
## Current
### Features
- [#2373](https://github.com/poanetwork/blockscout/pull/2373) - Add script to validate internal_transactions constraint for large DBs
### Fixes
- [#2425](https://github.com/poanetwork/blockscout/pull/2425) - Force to show address view for checksummed address even if it is not in DB

@ -7,6 +7,9 @@ defmodule Explorer.Repo.Migrations.AdditionalInternalTransactionConstraints do
mix ecto.migrate
psql -d $DATABASE -a -f priv/repo/migrations/scripts/20181108205650_additional_internal_transaction_constraints.sql
```
NOTE: you may want to consider using `apps/explorer/priv/repo/migrations/scripts/20181108205650_large_additional_internal_transaction_constraints.sql`
instead if you are dealing with a very large number of transactions/internal_transactions.
"""
use Ecto.Migration

@ -0,0 +1,75 @@
-- This script is a reimplementation of `20181108205650_additional_internal_transaction_constraints.sql`
-- that is meant to be executed on DBs where the number of transactions and/or
-- internal_transactions is very large.
-- To check the progress it is advised to run this in a `tmux` session or save
-- the output to a file.
-- IMPORTANT NOTE: after making all the corrections needed the script will NOT
-- run the constraint validations because this may be a very long and taxing
-- operation. To validate the constraint one can run, after the script fininshed:
-- ALTER TABLE internal_transactions VALIDATE CONSTRAINT call_has_call_type;
-- ALTER TABLE internal_transactions VALIDATE CONSTRAINT call_has_input;
-- ALTER TABLE internal_transactions VALIDATE CONSTRAINT create_has_init;
DO $$
DECLARE
batch_size integer := 10000; -- HOW MANY ITEMS WILL BE UPDATED AT A TIME
last_transaction_hash bytea; -- WILL CHECK ONLY TRANSACTIONS FOLLOWING THIS HASH (DESC)
last_fetched_batch_size integer;
BEGIN
RAISE NOTICE 'STARTING SCRIPT';
CREATE TEMP TABLE transactions_with_deprecated_internal_transactions(hash bytea NOT NULL);
LOOP
RAISE NOTICE 'Fetching new batch of % transactions to correct', batch_size;
INSERT INTO transactions_with_deprecated_internal_transactions
SELECT DISTINCT transaction_hash
FROM internal_transactions
WHERE
(last_transaction_hash IS NULL OR transaction_hash < last_transaction_hash) AND
-- call_has_call_type CONSTRAINT
((type = 'call' AND call_type IS NULL) OR
-- call_has_input CONSTRAINT
(type = 'call' AND input IS NULL) OR
-- create_has_init CONSTRAINT
(type = 'create' AND init is NULL))
ORDER BY transaction_hash DESC LIMIT batch_size;
SELECT INTO last_fetched_batch_size count(*) FROM transactions_with_deprecated_internal_transactions;
RAISE NOTICE 'Batch of % transactions was fetched, starting their deprecation', last_fetched_batch_size;
-- UPDATE TRANSACTIONS
UPDATE transactions
SET internal_transactions_indexed_at = NULL,
error = NULL
FROM transactions_with_deprecated_internal_transactions
WHERE transactions.hash = transactions_with_deprecated_internal_transactions.hash;
-- REMOVE THE DEPRECATED internal_transactions
DELETE FROM internal_transactions
USING transactions_with_deprecated_internal_transactions
WHERE internal_transactions.transaction_hash = transactions_with_deprecated_internal_transactions.hash;
-- COMMIT THE BATCH UPDATES
CHECKPOINT;
-- UPDATE last_transaction_hash TO KEEP TRACK OF ROWS ALREADY CHECKED
SELECT INTO last_transaction_hash hash
FROM transactions_with_deprecated_internal_transactions
ORDER BY hash ASC LIMIT 1;
RAISE NOTICE 'Last batch completed, last transaction hash: %', last_transaction_hash;
-- CLEAR THE TEMP TABLE
DELETE FROM transactions_with_deprecated_internal_transactions;
-- EXIT IF ALL internal_transactions HAVE BEEN CHECKED ALREADY
EXIT WHEN last_fetched_batch_size != batch_size;
END LOOP;
RAISE NOTICE 'SCRIPT FINISHED, all affected transactions have been deprecated';
DROP TABLE transactions_with_deprecated_internal_transactions;
END $$;
Loading…
Cancel
Save