Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ do $$

drop table if exists moves_view;

create temp table moves_view as
create table moves_view as
select transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
from (
select transactions_seq::numeric, 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
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
from (
SELECT DISTINCT ON (moves.transactions_seq, accounts_address, asset) moves.transactions_seq, accounts_address, asset,
first_value(post_commit_volumes) OVER (
Expand All @@ -27,8 +27,11 @@ do $$
group by transactions_seq;

create index moves_view_idx on moves_view(transactions_seq);
-- speed up hash join when updating rows later
alter table moves_view add foreign key(transactions_seq) references transactions(seq);

if (select count(*) from moves_view) = 0 then
drop table moves_view;
return;
end if;

Expand All @@ -46,7 +49,10 @@ do $$
from data
where transactions.seq = data.transactions_seq;

exit when not found;
if not found then
drop table moves_view;
exit;
end if;

_offset = _offset + _batch_size;

Expand Down
12 changes: 9 additions & 3 deletions internal/storage/bucket/migrations/27-fix-invalid-pcv/up.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ do $$

drop table if exists moves_view;

create temp table moves_view as
create table moves_view as
select transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
from (
select transactions_seq::numeric, 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
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
from (
SELECT DISTINCT ON (moves.transactions_seq, accounts_address, asset) moves.transactions_seq, accounts_address, asset,
first_value(post_commit_volumes) OVER (
Expand All @@ -27,8 +27,11 @@ do $$
group by transactions_seq;

create index moves_view_idx on moves_view(transactions_seq);
-- speed up hash join when updating rows later
alter table moves_view add foreign key(transactions_seq) references transactions(seq);

if (select count(*) from moves_view) = 0 then
drop table moves_view;
return;
end if;

Expand All @@ -46,7 +49,10 @@ do $$
from data
where transactions.seq = data.transactions_seq;

exit when not found;
if not found then
drop table moves_view;
exit;
end if;

_offset = _offset + _batch_size;

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,10 +7,10 @@ do $$

drop table if exists moves_view;

create temp table moves_view as
create table moves_view as
select transactions_seq, public.aggregate_objects(jsonb_build_object(accounts_address, volumes)) as volumes
from (
select transactions_seq::numeric, 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
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
from (
SELECT DISTINCT ON (moves.transactions_seq, accounts_address, asset) moves.transactions_seq, accounts_address, asset,
first_value(post_commit_volumes) OVER (
Expand All @@ -27,8 +27,11 @@ do $$
group by transactions_seq;

create index moves_view_idx on moves_view(transactions_seq);
-- speed up hash join when updating rows later
alter table moves_view add foreign key(transactions_seq) references transactions(seq);

if (select count(*) from moves_view) = 0 then
drop table moves_view;
return;
end if;

Expand All @@ -46,7 +49,10 @@ do $$
from data
where transactions.seq = data.transactions_seq;

exit when not found;
if not found then
drop table moves_view;
exit;
end if;

_offset = _offset + _batch_size;

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,14 +7,18 @@ do $$

drop table if exists txs_view;

create temp table txs_view as
create table txs_view as
select *
from transactions
where updated_at is null;

Comment on lines +10 to 14
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

🛠️ Refactor suggestion

Selecting * inflates the staging table – project only needed columns

create table txs_view as select * from transactions where updated_at is null;

txs_view is used solely to obtain seq and inserted_at. Copying every column (including large JSONB blobs) can blow up disk / temp-file usage and I/O for large ledgers.

-create table txs_view as
-select *
-from transactions
-where updated_at is null;
+create table txs_view as
+select seq, inserted_at
+from transactions
+where updated_at is null;

Smaller table ⇒ less I/O, faster scan & hash join.

📝 Committable suggestion

‼️ IMPORTANT
Carefully review the code before committing. Ensure that it accurately replaces the highlighted code, contains no missing lines, and has no issues with indentation. Thoroughly test & benchmark the code to ensure it meets the requirements.

Suggested change
create table txs_view as
select *
from transactions
where updated_at is null;
create table txs_view as
select seq, inserted_at
from transactions
where updated_at is null;
🤖 Prompt for AI Agents
In internal/storage/bucket/migrations/31-fix-transaction-updated-at/up.sql
around lines 10 to 14, the create table statement uses select * which copies all
columns including large JSONB blobs, causing unnecessary disk and I/O usage.
Modify the select statement to include only the needed columns seq and
inserted_at to reduce table size and improve performance.

if (select count(*) from txs_view) = 0 then
drop table txs_view;
return;
end if;
-- speed up hash join when updating rows later
create index txs_view_seq_idx on txs_view(seq);
alter table txs_view add foreign key(seq) references transactions(seq);

perform pg_notify('migrations-{{ .Schema }}', 'init: ' || (select count(*) from txs_view));

Expand All @@ -29,10 +33,12 @@ do $$
update transactions
set updated_at = transactions.inserted_at
from data
where transactions.seq = data.seq and
transactions.ledger = data.ledger;
where transactions.seq = data.seq;

exit when not found;
if not found then
drop table txs_view;
exit;
end if;

_offset = _offset + _batch_size;

Expand Down
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
do $$
declare
_offset integer := 0;
_batch_size integer := 1000;
_batch_size integer := 10000;
begin
set search_path = '{{ .Schema }}';

Expand All @@ -15,9 +15,8 @@ do $$
with data as (
select *
from logs
where seq >= _offset and seq < _offset + _batch_size
order by seq
offset _offset
limit _batch_size
)
update logs
set memento = convert_to(
Expand Down Expand Up @@ -82,15 +81,15 @@ do $$
from data
where logs.seq = data.seq;

exit when not found;
if _offset >= (select max(seq) from logs) then
exit;
end if;

_offset = _offset + _batch_size;

perform pg_notify('migrations-{{ .Schema }}', 'continue: ' || _batch_size);

commit;
end loop;

drop table if exists txs_view;
end
$$;
Loading