Skip to content

Commit 061391a

Browse files
authored
feat: use DO blocks around SQL statements in migrations (#1335)
Migrations that contain `SELECT`, `INSERT`, `UPDATE`, `DELETE` that are not already wrapped in a `DO` block, are wrapped. This is because anything that executes in a `DO` block _does not get counted as activity_ on the database.
1 parent 55febd2 commit 061391a

4 files changed

+27
-14
lines changed
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,11 @@
11
-- backfill the auth.identities column by adding an email identity
22
-- for all auth.users with an email and password
33

4-
insert into {{ index .Options "Namespace" }}.identities (id, user_id, identity_data, provider, last_sign_in_at, created_at, updated_at)
5-
select id, id as user_id, jsonb_build_object('sub', id, 'email', email) as identity_data, 'email' as provider, null as last_sign_in_at, '2022-11-25' as created_at, '2022-11-25' as updated_at
6-
from {{ index .Options "Namespace" }}.users as users
7-
where encrypted_password != '' and email is not null and not exists(select user_id from {{ index .Options "Namespace" }}.identities where user_id = users.id);
4+
do $$
5+
begin
6+
insert into {{ index .Options "Namespace" }}.identities (id, user_id, identity_data, provider, last_sign_in_at, created_at, updated_at)
7+
select id, id as user_id, jsonb_build_object('sub', id, 'email', email) as identity_data, 'email' as provider, null as last_sign_in_at, '2022-11-25' as created_at, '2022-11-25' as updated_at
8+
from {{ index .Options "Namespace" }}.users as users
9+
where encrypted_password != '' and email is not null and not exists(select user_id from {{ index .Options "Namespace" }}.identities where user_id = users.id);
10+
end;
11+
$$;

migrations/20221208132122_backfill_email_last_sign_in_at.up.sql

+3
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,7 @@
11
-- previous backfill migration left last_sign_in_at to be null, which broke some projects
22

3+
do $$
4+
begin
35
update {{ index .Options "Namespace" }}.identities
46
set last_sign_in_at = '2022-11-25'
57
where
@@ -8,3 +10,4 @@ update {{ index .Options "Namespace" }}.identities
810
updated_at = '2022-11-25' and
911
provider = 'email' and
1012
id = user_id::text;
13+
end $$;

migrations/20221215195800_add_identities_email_column.up.sql

+9-6
Original file line numberDiff line numberDiff line change
@@ -1,9 +1,12 @@
1-
update
2-
{{ index .Options "Namespace" }}.identities as identities
3-
set
4-
identity_data = identity_data || jsonb_build_object('email', (select email from {{ index .Options "Namespace" }}.users where id = identities.user_id)),
5-
updated_at = '2022-11-25'
6-
where identities.provider = 'email' and identity_data->>'email' is null;
1+
do $$
2+
begin
3+
update
4+
{{ index .Options "Namespace" }}.identities as identities
5+
set
6+
identity_data = identity_data || jsonb_build_object('email', (select email from {{ index .Options "Namespace" }}.users where id = identities.user_id)),
7+
updated_at = '2022-11-25'
8+
where identities.provider = 'email' and identity_data->>'email' is null;
9+
end $$;
710

811
alter table only {{ index .Options "Namespace" }}.identities
912
add column if not exists email text generated always as (lower(identity_data->>'email')) stored;
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,9 @@
11
-- backfills the missing email identity for invited users
22

3-
insert into {{ index .Options "Namespace" }}.identities (id, user_id, identity_data, provider, last_sign_in_at, created_at, updated_at)
4-
select id, id as user_id, jsonb_build_object('sub', id, 'email', email) as identity_data, 'email' as provider, null as last_sign_in_at, '2023-01-25' as created_at, '2023-01-25' as updated_at
5-
from {{ index .Options "Namespace" }}.users as users
6-
where invited_at is not null and not exists (select user_id from {{ index .Options "Namespace" }}.identities where user_id = users.id and provider = 'email');
3+
do $$
4+
begin
5+
insert into {{ index .Options "Namespace" }}.identities (id, user_id, identity_data, provider, last_sign_in_at, created_at, updated_at)
6+
select id, id as user_id, jsonb_build_object('sub', id, 'email', email) as identity_data, 'email' as provider, null as last_sign_in_at, '2023-01-25' as created_at, '2023-01-25' as updated_at
7+
from {{ index .Options "Namespace" }}.users as users
8+
where invited_at is not null and not exists (select user_id from {{ index .Options "Namespace" }}.identities where user_id = users.id and provider = 'email');
9+
end $$;

0 commit comments

Comments
 (0)