1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
-- Deploy 0814-tenants-and-users:credentials/credentials to pg
-- requires: users/users
BEGIN;
\ir ../../defaults.sql
create table :"id_schema".user_credentials (
id uuid primary key,
tenant_id uuid not null default '00000000-0000-0000-0000-000000000000',
encrypted_password varchar,
external_auth_id varchar,
constraint "user"
foreign key (id, tenant_id)
references :"id_schema".users (id, tenant_id)
on update cascade on delete cascade
deferrable initially immediate,
constraint provide_password_or_external_auth_id
check (num_nonnulls(encrypted_password, external_auth_id) > 0)
);
create index user_credentials_on_external_auth_id on :"id_schema".user_credentials using hash (external_auth_id);
create index user_credentials_on_tenant_id on :"id_schema".user_credentials using hash (tenant_id);
create index user_credentials_on_id on :"id_schema".user_credentials (id);
comment on constraint "user" on :"id_schema".user_credentials is E'@omit';
alter table :"id_schema".users
add column credentials_id uuid,
add constraint separate_credentials_for_each_user
unique (credentials_id)
deferrable initially immediate,
add constraint credentials
foreign key (credentials_id)
references :"id_schema".user_credentials (id)
on update cascade on delete set null
deferrable initially immediate
;
comment on constraint credentials on :"id_schema".users is E'@foreignFieldName user';
with added_credentials as (
insert into :"id_schema".user_credentials (id, tenant_id, encrypted_password, external_auth_id)
(
select id, tenant_id, encrypted_password, external_auth_id
from :"id_schema".users
where num_nonnulls(encrypted_password, external_auth_id) > 0
)
returning *
)
update :"id_schema".users
set credentials_id = added_credentials.id
from added_credentials
where added_credentials.id = users.id;
create trigger t080_auto_encrypt_user_passwords
before insert or update of encrypted_password
on :"id_schema".user_credentials
for each row
execute function :"id_schema".auto_encrypt_user_passwords();
COMMIT;