From 372faa76d0397cb0fb72d58405c4d374ee9deb14 Mon Sep 17 00:00:00 2001 From: Geoffrey Ragot Date: Thu, 24 Apr 2025 10:35:41 +0200 Subject: [PATCH] fix: missing denormalized data in logs --- .../0-init-schema/up_tests_after.sql | 4 +- .../18-transactions-fill-inserted-at/up.sql | 2 +- .../up_tests_after.sql | 6 ++ .../notes.yaml | 1 + .../up.sql | 69 +++++++++++++++++++ .../up_tests_after.sql | 18 +++++ 6 files changed, 97 insertions(+), 3 deletions(-) create mode 100644 internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/notes.yaml create mode 100644 internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up.sql create mode 100644 internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up_tests_after.sql diff --git a/internal/storage/bucket/migrations/0-init-schema/up_tests_after.sql b/internal/storage/bucket/migrations/0-init-schema/up_tests_after.sql index f8d4401789..150a5e90f6 100644 --- a/internal/storage/bucket/migrations/0-init-schema/up_tests_after.sql +++ b/internal/storage/bucket/migrations/0-init-schema/up_tests_after.sql @@ -12,7 +12,7 @@ select ('{' '"transaction": {' '"id": ' || (seq/5) + (seq % 5) || ',' - '"timestamp": "' || now() || '",' + '"timestamp": ' || to_json(now()::timestamp without time zone) || ',' '"postings": [' '{' '"destination": "sellers:' || (seq % 5) || '",' @@ -58,7 +58,7 @@ select ('{' '"transaction": {' '"id": ' || (seq/5) + (seq % 5) || ',' - '"timestamp": "' || now() || '",' + '"timestamp": ' || to_json(now()::timestamp without time zone) || ',' '"postings": [' '{' '"source": "sellers:' || (seq % 5) || '",' diff --git a/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up.sql b/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up.sql index 3874a27ae9..0435642743 100644 --- a/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up.sql +++ b/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up.sql @@ -21,7 +21,7 @@ do $$ -- select the date where the "11-make-stateless" migration has been applied select tstamp into _date - from _system.goose_db_version + from goose_db_version where version_id = 12; create temporary table logs_transactions as diff --git a/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up_tests_after.sql b/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up_tests_after.sql index e69de29bb2..1ecf472e14 100644 --- a/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up_tests_after.sql +++ b/internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up_tests_after.sql @@ -0,0 +1,6 @@ +do $$ + begin + set search_path = '{{.Schema}}'; + assert (select count(*) from transactions where inserted_at is null) = 0, 'inserted_at should not be null'; + end; +$$ \ No newline at end of file diff --git a/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/notes.yaml b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/notes.yaml new file mode 100644 index 0000000000..17b23b5a51 --- /dev/null +++ b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/notes.yaml @@ -0,0 +1 @@ +name: Fill log data for reverted transactions diff --git a/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up.sql b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up.sql new file mode 100644 index 0000000000..c39dd1bb46 --- /dev/null +++ b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up.sql @@ -0,0 +1,69 @@ +do $$ + declare + _offset integer := 0; + _batch_size integer := 1000; + begin + set search_path = '{{ .Schema }}'; + + drop table if exists txs_view; + + create temp table txs_view as + with reversed as ( + select + ledger, + id, + (convert_from(memento, 'UTF-8')::jsonb ->> 'revertedTransactionID')::numeric as revertedTransactionID + from logs + where type = 'REVERTED_TRANSACTION' and data->>'revertedTransactionID' is not null + ) + select reversed.id as log_id, transactions.* + from transactions + join reversed on + reversed.revertedTransactionID = transactions.id and + reversed.ledger = transactions.ledger; + + create index txs_view_idx on txs_view(log_id, id); + + if (select count(*) from txs_view) = 0 then + return; + end if; + + perform pg_notify('migrations-{{ .Schema }}', 'init: ' || (select count(*) from txs_view)); + + loop + with data as ( + select * + from txs_view + order by ledger, log_id, id + offset _offset + limit _batch_size + ) + update logs + set data = data || jsonb_build_object('revertedTransaction', jsonb_build_object( + 'id', data.id, + 'postings', data.postings::jsonb, + 'metadata', data.metadata, + 'reverted', true, + 'revertedAt', data.reverted_at, + 'insertedAt', data.inserted_at, + 'timestamp', data.timestamp, + 'reference', case when data.reference is not null and data.reference <> '' then data.reference end, + 'postCommitVolumes', data.post_commit_volumes + )) + from data + where logs.id = data.log_id and + logs.ledger = data.ledger; + + exit when not found; + + _offset = _offset + _batch_size; + + perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); + + commit; + end loop; + + drop table if exists txs_view; + end +$$; + diff --git a/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up_tests_after.sql b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up_tests_after.sql new file mode 100644 index 0000000000..1cbe797fa8 --- /dev/null +++ b/internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up_tests_after.sql @@ -0,0 +1,18 @@ +do $$ + declare + expected varchar = '{"transaction": {"id": 22, "metadata": {"tax": "1%"}, "postings": [{"asset": "USD", "amount": 99, "source": "sellers:0", "destination": "orders:10"}, {"asset": "USD", "amount": 1, "source": "fees", "destination": "orders:10"}, {"asset": "USD", "amount": 100, "source": "orders:10", "destination": "world"}, {"asset": "SELL", "amount": 1, "source": "sellers:0", "destination": "world"}], ' || + '"timestamp": ' || + (select to_json(timestamp) from "{{.Schema}}".transactions where id = 22 and ledger = 'ledger0') + || '}, "revertedTransaction": {"id": 2, "metadata": {"tax": "1%"}, "postings": [{"asset": "SELL", "amount": 1, "source": "world", "destination": "sellers:0"}, {"asset": "USD", "amount": 100, "source": "world", "destination": "orders:10"}, {"asset": "USD", "amount": 1, "source": "orders:10", "destination": "fees"}, {"asset": "USD", "amount": 99, "source": "orders:10", "destination": "sellers:0"}], "reverted": true, "reference": null, "timestamp": ' || + (select to_json(timestamp) from "{{.Schema}}".transactions where id = 2 and ledger = 'ledger0') || + ', "insertedAt": ' || + (select to_json(inserted_at) from "{{.Schema}}".transactions where id = 2 and ledger = 'ledger0') || + ', "revertedAt": ' || + (select to_json(reverted_at) from "{{.Schema}}".transactions where id = 2 and ledger = 'ledger0') || + ', "postCommitVolumes": {"fees": {"USD": {"input": 3, "output": 0}}, "world": {"USD": {"input": 0, "output": 300}, "SELL": {"input": 0, "output": 3}}, "orders:10": {"USD": {"input": 100, "output": 100}}, "sellers:0": {"USD": {"input": 297, "output": 0}, "SELL": {"input": 3, "output": 0}}}}, "revertedTransactionID": "2"}'; + begin + set search_path = '{{.Schema}}'; + assert (select data::varchar from logs where id = 22 and ledger = 'ledger0') = expected, + 'data should be equals to ' || expected || ' but was ' || (select data::varchar from logs where id = 22 and ledger = 'ledger0'); + end; +$$ \ No newline at end of file