Skip to content

Commit 09b8b6c

Browse files
authored
feat: improve migration performances (#1175)
* feat: improve migration performances * fix: from reviews * fix: some offsets
1 parent 0840b9f commit 09b8b6c

File tree

10 files changed

+42
-120
lines changed
  • internal/storage/bucket/migrations
    • 17-moves-fill-transaction-id
    • 18-transactions-fill-inserted-at
    • 19-transactions-fill-pcv
    • 27-fix-invalid-pcv
    • 28-fix-pcv-missing-asset
    • 29-fix-invalid-metadata-on-reverts
    • 31-fix-transaction-updated-at
    • 32-fix-log-data-for-reverted-transactions
    • 33-fix-invalid-date-format
    • 34-fix-memento-format

10 files changed

+42
-120
lines changed

internal/storage/bucket/migrations/17-moves-fill-transaction-id/up.sql

Lines changed: 20 additions & 22 deletions
Original file line numberDiff line numberDiff line change
@@ -5,40 +5,38 @@ do $$
55
begin
66
set search_path = '{{.Schema}}';
77

8-
select count(seq)
8+
create temporary table transactions_ids as
9+
select row_number() over (order by transactions.seq) as row_number,
10+
moves.seq as moves_seq, transactions.id, transactions.seq as transactions_seq
911
from moves
10-
where transactions_id is null
12+
join transactions on transactions.seq = moves.transactions_seq
13+
where transactions_id is null;
14+
15+
create index transactions_ids_rows on transactions_ids(row_number) include (moves_seq, transactions_seq, id);
16+
17+
analyze transactions_ids;
18+
19+
select count(*)
20+
from transactions_ids
1121
into _max;
1222

1323
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _max);
14-
loop
1524

16-
with _outdated_moves as (
25+
for i in 1.._max by _batch_size loop
26+
with _rows as (
1727
select *
18-
from moves
19-
where transactions_id is null
20-
limit _batch_size
28+
from transactions_ids
29+
where row_number >= i and row_number < i + _batch_size
2130
)
2231
update moves
23-
set transactions_id = (
24-
select id
25-
from transactions
26-
where seq = moves.transactions_seq
27-
)
28-
from _outdated_moves
29-
where moves.seq in (_outdated_moves.seq);
32+
set transactions_id = _rows.id
33+
from _rows
34+
where seq = _rows.moves_seq;
3035

31-
exit when not found;
36+
commit;
3237

3338
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size);
34-
35-
commit ;
3639
end loop;
37-
38-
alter table moves
39-
add constraint transactions_id_not_null
40-
check (transactions_id is not null)
41-
not valid;
4240
end
4341
$$
4442
language plpgsql;

internal/storage/bucket/migrations/18-transactions-fill-inserted-at/up.sql

Lines changed: 5 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -3,7 +3,6 @@ do $$
33
_ledger record;
44
_vsql text;
55
_batch_size integer := 1000;
6-
_date timestamp without time zone;
76
_count integer := 0;
87
begin
98
set search_path = '{{.Schema}}';
@@ -19,17 +18,12 @@ do $$
1918
execute _vsql;
2019
end loop;
2120

22-
-- select the date where the "11-make-stateless" migration has been applied
23-
select tstamp into _date
24-
from goose_db_version
25-
where version_id = 12;
26-
2721
create temporary table logs_transactions as
28-
select id, ledger, date, (data->'transaction'->>'id')::bigint as transaction_id
22+
select row_number() over (order by ledger, id) as row_number, ledger, date, (data->'transaction'->>'id')::bigint as transaction_id
2923
from logs
30-
where date <= _date;
24+
where type = 'NEW_TRANSACTION' or type = 'REVERTED_TRANSACTION';
3125

32-
create index on logs_transactions (ledger, transaction_id) include (id, date);
26+
create index on logs_transactions (row_number) include (ledger, date, transaction_id);
3327

3428
select count(*) into _count
3529
from logs_transactions;
@@ -40,14 +34,12 @@ do $$
4034
with _rows as (
4135
select *
4236
from logs_transactions
43-
order by ledger, transaction_id
44-
offset i
45-
limit _batch_size
37+
where row_number > i and row_number <= i + _batch_size
4638
)
4739
update transactions
4840
set inserted_at = _rows.date
4941
from _rows
50-
where transactions.ledger = _rows.ledger and transactions.id = _rows.transaction_id;
42+
where transactions.ledger = _rows.ledger and transactions.id = _rows.transaction_id and inserted_at is null;
5143

5244
commit;
5345

internal/storage/bucket/migrations/19-transactions-fill-pcv/up.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -42,7 +42,7 @@ do $$
4242
select transactions_seq, volumes
4343
from moves_view
4444
-- play better than offset/limit
45-
where transactions_seq >= _offset and transactions_seq < _offset + _batch_size
45+
where transactions_seq > _offset and transactions_seq <= _offset + _batch_size
4646
)
4747
update transactions
4848
set post_commit_volumes = data.volumes
Lines changed: 1 addition & 62 deletions
Original file line numberDiff line numberDiff line change
@@ -1,67 +1,6 @@
11
do $$
2-
declare
3-
_offset integer := 0;
4-
_batch_size integer := 1000;
52
begin
6-
set search_path = '{{ .Schema }}';
7-
8-
drop table if exists moves_view;
9-
10-
create table moves_view as
11-
select transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
12-
from (
13-
select transactions_seq, accounts_address, public.aggregate_objects(json_build_object(asset, json_build_object('input', (post_commit_volumes).inputs, 'output', (post_commit_volumes).outputs))::jsonb) as volumes
14-
from (
15-
SELECT DISTINCT ON (moves.transactions_seq, accounts_address, asset) moves.transactions_seq, accounts_address, asset,
16-
first_value(post_commit_volumes) OVER (
17-
PARTITION BY moves.transactions_seq, accounts_address, asset
18-
ORDER BY seq DESC
19-
) AS post_commit_volumes
20-
FROM moves
21-
where insertion_date < (
22-
select tstamp from goose_db_version where version_id = 12
23-
)
24-
) moves
25-
group by transactions_seq, accounts_address
26-
) data
27-
group by transactions_seq;
28-
29-
create index moves_view_idx on moves_view(transactions_seq);
30-
-- speed up hash join when updating rows later
31-
alter table moves_view add foreign key(transactions_seq) references transactions(seq);
32-
33-
if (select count(*) from moves_view) = 0 then
34-
drop table moves_view;
35-
return;
36-
end if;
37-
38-
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || (select count(*) from moves_view));
39-
40-
loop
41-
with data as (
42-
select transactions_seq, volumes
43-
from moves_view
44-
-- play better than offset/limit
45-
where transactions_seq >= _offset and transactions_seq < _offset + _batch_size
46-
)
47-
update transactions
48-
set post_commit_volumes = data.volumes
49-
from data
50-
where transactions.seq = data.transactions_seq;
51-
52-
if not found then
53-
drop table moves_view;
54-
exit;
55-
end if;
56-
57-
_offset = _offset + _batch_size;
58-
59-
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size);
60-
61-
commit;
62-
end loop;
63-
64-
drop table if exists moves_view;
3+
raise notice 'Migration superseded by next migration';
654
end
665
$$;
676

internal/storage/bucket/migrations/28-fix-pcv-missing-asset/up.sql

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -8,7 +8,8 @@ do $$
88
drop table if exists moves_view;
99

1010
create table moves_view as
11-
select transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
11+
select row_number() over (order by transactions_seq) as row_number,
12+
transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
1213
from (
1314
select transactions_seq, accounts_address, public.aggregate_objects(json_build_object(asset, json_build_object('input', (post_commit_volumes).inputs, 'output', (post_commit_volumes).outputs))::jsonb) as volumes
1415
from (
@@ -26,7 +27,7 @@ do $$
2627
) data
2728
group by transactions_seq;
2829

29-
create index moves_view_idx on moves_view(transactions_seq);
30+
create index moves_view_idx on moves_view(row_number) include (transactions_seq, volumes);
3031
-- speed up hash join when updating rows later
3132
alter table moves_view add foreign key(transactions_seq) references transactions(seq);
3233

@@ -41,8 +42,7 @@ do $$
4142
with data as (
4243
select transactions_seq, volumes
4344
from moves_view
44-
offset _offset
45-
limit _batch_size
45+
where row_number > _offset and row_number <= _offset + _batch_size
4646
)
4747
update transactions
4848
set post_commit_volumes = data.volumes

internal/storage/bucket/migrations/29-fix-invalid-metadata-on-reverts/up.sql

Lines changed: 2 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,7 @@ do $$
1717
from logs
1818
where type = 'REVERTED_TRANSACTION'
1919
)
20-
select reversed.ledger, reversed.reversedTransactionID, reversed.revertedTransactionID, reversed.revertedAt
20+
select row_number() over (order by transactions.seq) as row_number, reversed.ledger, reversed.reversedTransactionID, reversed.revertedTransactionID, reversed.revertedAt
2121
from transactions
2222
join reversed on
2323
reversed.reversedTransactionID = transactions.id and
@@ -37,9 +37,7 @@ do $$
3737
with data as (
3838
select ledger, reversedTransactionID, revertedTransactionID, revertedAt
3939
from txs_view
40-
order by ledger, reversedTransactionID, revertedTransactionID
41-
offset _offset
42-
limit _batch_size
40+
where row_number > _offset and row_number <= _offset + _batch_size
4341
)
4442
update transactions
4543
set

internal/storage/bucket/migrations/31-fix-transaction-updated-at/up.sql

Lines changed: 2 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -8,7 +8,7 @@ do $$
88
drop table if exists txs_view;
99

1010
create table txs_view as
11-
select *
11+
select row_number() over (order by transactions.seq) as row_number, *
1212
from transactions
1313
where updated_at is null;
1414

@@ -26,9 +26,7 @@ do $$
2626
with data as (
2727
select *
2828
from txs_view
29-
order by seq
30-
offset _offset
31-
limit _batch_size
29+
where row_number > _offset and row_number <= _offset+_batch_size
3230
)
3331
update transactions
3432
set updated_at = transactions.inserted_at

internal/storage/bucket/migrations/32-fix-log-data-for-reverted-transactions/up.sql

Lines changed: 4 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -16,13 +16,14 @@ do $$
1616
from logs
1717
where type = 'REVERTED_TRANSACTION' and data->>'revertedTransactionID' is not null
1818
)
19-
select reversed.id as log_id, transactions.*
19+
select row_number() over (order by transactions.seq) as row_number,
20+
reversed.id as log_id, transactions.*
2021
from transactions
2122
join reversed on
2223
reversed.revertedTransactionID = transactions.id and
2324
reversed.ledger = transactions.ledger;
2425

25-
create index txs_view_idx on txs_view(log_id, id);
26+
create index txs_view_idx on txs_view(row_number);
2627

2728
if (select count(*) from txs_view) = 0 then
2829
return;
@@ -34,9 +35,7 @@ do $$
3435
with data as (
3536
select *
3637
from txs_view
37-
order by ledger, log_id, id
38-
offset _offset
39-
limit _batch_size
38+
where row_number > _offset and row_number <= _offset + _batch_size
4039
)
4140
update logs
4241
set data = data || jsonb_build_object('revertedTransaction', jsonb_build_object(

internal/storage/bucket/migrations/33-fix-invalid-date-format/up.sql

Lines changed: 2 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -16,7 +16,7 @@ do $$
1616
from logs
1717
where type = 'REVERTED_TRANSACTION' and data->>'revertedTransactionID' is not null
1818
)
19-
select reversed.id as log_id, transactions.*
19+
select row_number() over (order by transactions.seq) as row_number, reversed.id as log_id, transactions.*
2020
from transactions
2121
join reversed on
2222
reversed.revertedTransactionID = transactions.id and
@@ -34,9 +34,7 @@ do $$
3434
with data as (
3535
select *
3636
from txs_view
37-
order by ledger, log_id, id
38-
offset _offset
39-
limit _batch_size
37+
where row_number > _offset and row_number <= _offset + _batch_size
4038
)
4139
update logs
4240
set data = data || jsonb_build_object('revertedTransaction', jsonb_build_object(

internal/storage/bucket/migrations/34-fix-memento-format/up.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -15,7 +15,7 @@ do $$
1515
with data as (
1616
select *
1717
from logs
18-
where seq >= _offset and seq < _offset + _batch_size
18+
where seq > _offset and seq <= _offset + _batch_size
1919
order by seq
2020
)
2121
update logs

0 commit comments

Comments
 (0)