-
Notifications
You must be signed in to change notification settings - Fork 101
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat: migrations post stateless version (#515)
* feat: migrate old data * fix: dependencies * chore: some fix * fix: slow migrations * chore: reorder migrations and clean next-minor todos * feat: adapt for v2.2 merge
- Loading branch information
Showing
43 changed files
with
449 additions
and
133 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/16-moves-fill-transaction-id/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Fill transaction ids of table moves |
44 changes: 44 additions & 0 deletions
44
internal/storage/bucket/migrations/16-moves-fill-transaction-id/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,44 @@ | ||
do $$ | ||
declare | ||
_batch_size integer := 100; | ||
_max integer; | ||
begin | ||
set search_path = '{{.Schema}}'; | ||
|
||
create index moves_transactions_id on moves(transactions_id); | ||
|
||
select count(seq) | ||
from moves | ||
where transactions_id is null | ||
into _max; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _max); | ||
loop | ||
|
||
with _outdated_moves as ( | ||
select * | ||
from moves | ||
where transactions_id is null | ||
limit _batch_size | ||
) | ||
update moves | ||
set transactions_id = ( | ||
select id | ||
from transactions | ||
where seq = moves.transactions_seq | ||
) | ||
from _outdated_moves | ||
where moves.seq in (_outdated_moves.seq); | ||
|
||
exit when not found; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); | ||
|
||
commit ; | ||
end loop; | ||
|
||
alter table moves | ||
alter column transactions_id set not null; | ||
end | ||
$$ | ||
language plpgsql; |
Empty file.
Empty file.
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/17-transactions-fill-inserted-at/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Fill inserted_at column of transactions table |
59 changes: 59 additions & 0 deletions
59
internal/storage/bucket/migrations/17-transactions-fill-inserted-at/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,59 @@ | ||
do $$ | ||
declare | ||
_batch_size integer := 100; | ||
_date timestamp without time zone; | ||
_count integer := 0; | ||
begin | ||
--todo: take explicit advisory lock to avoid concurrent migrations when the service is killed | ||
set search_path = '{{.Schema}}'; | ||
|
||
-- select the date where the "11-make-stateless" migration has been applied | ||
select tstamp into _date | ||
from _system.goose_db_version | ||
where version_id = 12; | ||
|
||
create temporary table logs_transactions as | ||
select id, ledger, date, (data->'transaction'->>'id')::bigint as transaction_id | ||
from logs | ||
where date <= _date; | ||
|
||
create index on logs_transactions (ledger, transaction_id) include (id, date); | ||
|
||
select count(*) into _count | ||
from logs_transactions; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _count); | ||
|
||
for i in 0.._count by _batch_size loop | ||
-- disable triggers | ||
set session_replication_role = replica; | ||
|
||
with _rows as ( | ||
select * | ||
from logs_transactions | ||
order by ledger, transaction_id | ||
offset i | ||
limit _batch_size | ||
) | ||
update transactions | ||
set inserted_at = _rows.date | ||
from _rows | ||
where transactions.ledger = _rows.ledger and transactions.id = _rows.transaction_id; | ||
|
||
-- enable triggers | ||
set session_replication_role = default; | ||
|
||
commit; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); | ||
end loop; | ||
|
||
drop table logs_transactions; | ||
|
||
alter table transactions | ||
alter column inserted_at set default transaction_date(); | ||
|
||
drop trigger set_transaction_inserted_at on transactions; | ||
drop function set_transaction_inserted_at; | ||
end | ||
$$; |
Empty file.
Empty file.
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/18-transactions-fill-pcv/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Fill post_commit_volumes column of transactions table |
62 changes: 62 additions & 0 deletions
62
internal/storage/bucket/migrations/18-transactions-fill-pcv/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,62 @@ | ||
do $$ | ||
declare | ||
_batch_size integer := 100; | ||
_count integer; | ||
begin | ||
set search_path = '{{.Schema}}'; | ||
|
||
select count(id) | ||
from transactions | ||
where post_commit_volumes is null | ||
into _count; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _count); | ||
|
||
loop | ||
-- disable triggers | ||
set session_replication_role = replica; | ||
|
||
with _outdated_transactions as ( | ||
select id | ||
from transactions | ||
where post_commit_volumes is null | ||
limit _batch_size | ||
) | ||
update transactions | ||
set post_commit_volumes = ( | ||
select public.aggregate_objects(post_commit_volumes::jsonb) as post_commit_volumes | ||
from ( | ||
select accounts_address, json_build_object(accounts_address, post_commit_volumes) post_commit_volumes | ||
from ( | ||
select accounts_address, json_build_object(asset, post_commit_volumes) as post_commit_volumes | ||
from ( | ||
select distinct on (accounts_address, asset) | ||
accounts_address, | ||
asset, | ||
first_value(post_commit_volumes) over ( | ||
partition by accounts_address, asset | ||
order by seq desc | ||
) as post_commit_volumes | ||
from moves | ||
where transactions_id = transactions.id and ledger = transactions.ledger | ||
) moves | ||
) values | ||
) values | ||
) | ||
from _outdated_transactions | ||
where transactions.id in (_outdated_transactions.id); | ||
|
||
-- enable triggers | ||
set session_replication_role = default; | ||
|
||
exit when not found; | ||
|
||
commit; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); | ||
end loop; | ||
|
||
alter table transactions | ||
alter column post_commit_volumes set not null; | ||
end | ||
$$; |
Empty file.
Empty file.
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/19-accounts-volumes-fill-history/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Populate accounts_volumes table with historic data |
54 changes: 54 additions & 0 deletions
54
internal/storage/bucket/migrations/19-accounts-volumes-fill-history/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,54 @@ | ||
do $$ | ||
declare | ||
_count integer; | ||
_batch_size integer := 100; | ||
begin | ||
set search_path = '{{.Schema}}'; | ||
|
||
create temporary table tmp_volumes as | ||
select distinct on (ledger, accounts_address, asset) | ||
ledger, | ||
accounts_address, | ||
asset, | ||
first_value(post_commit_volumes) over ( | ||
partition by ledger, accounts_address, asset | ||
order by seq desc | ||
) as post_commit_volumes | ||
from moves | ||
where not exists( | ||
select | ||
from accounts_volumes | ||
where ledger = moves.ledger | ||
and asset = moves.asset | ||
and accounts_address = moves.accounts_address | ||
); | ||
|
||
select count(*) | ||
from tmp_volumes | ||
into _count; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _count); | ||
|
||
raise info '_count: %', _count; | ||
|
||
for i in 0.._count by _batch_size loop | ||
with _rows as ( | ||
select * | ||
from tmp_volumes | ||
offset i | ||
limit _batch_size | ||
) | ||
insert into accounts_volumes (ledger, accounts_address, asset, input, output) | ||
select ledger, accounts_address, asset, (post_commit_volumes).inputs, (post_commit_volumes).outputs | ||
from _rows | ||
on conflict do nothing; -- can be inserted by a concurrent transaction | ||
|
||
commit; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); | ||
|
||
end loop; | ||
|
||
drop table tmp_volumes; | ||
end | ||
$$; |
Empty file.
Empty file.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/20-transactions-metadata-fill-transaction-id/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Fill transactions_id column of transactions_metadata table |
44 changes: 44 additions & 0 deletions
44
internal/storage/bucket/migrations/20-transactions-metadata-fill-transaction-id/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,44 @@ | ||
|
||
do $$ | ||
declare | ||
_batch_size integer := 100; | ||
_count integer; | ||
begin | ||
set search_path = '{{.Schema}}'; | ||
|
||
select count(seq) | ||
from transactions_metadata | ||
where transactions_id is null | ||
into _count; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'init: ' || _count); | ||
|
||
loop | ||
with _outdated_transactions_metadata as ( | ||
select seq | ||
from transactions_metadata | ||
where transactions_id is null | ||
limit _batch_size | ||
) | ||
update transactions_metadata | ||
set transactions_id = ( | ||
select id | ||
from transactions | ||
where transactions_metadata.transactions_seq = seq | ||
) | ||
from _outdated_transactions_metadata | ||
where transactions_metadata.seq in (_outdated_transactions_metadata.seq); | ||
|
||
exit when not found; | ||
|
||
commit; | ||
|
||
perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size); | ||
|
||
end loop; | ||
|
||
alter table transactions_metadata | ||
alter column transactions_id set not null ; | ||
end | ||
$$; | ||
|
Empty file.
Empty file.
1 change: 1 addition & 0 deletions
1
internal/storage/bucket/migrations/21-accounts-metadata-fill-address/notes.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
name: Fill accounts_address column of accounts_metadata table |
Oops, something went wrong.