fix company creation for admin and inviting of new employees

This commit is contained in:
Danel Kungla
2025-07-31 12:27:30 +03:00
parent 87363051cd
commit a39c21e4e7
18 changed files with 496 additions and 57 deletions

View File

@@ -0,0 +1,280 @@
drop function if exists medreport.add_invitations_to_account(text, medreport.invitation[]);
drop type if exists medreport.invitation;
create type medreport.invitation as (
email text,
role text,
personal_code char(11)
);
create or replace function medreport.add_invitations_to_account (
account_slug text,
invitations medreport.invitation[]
) returns medreport.invitations[]
set search_path = ''
as $$
declare
new_invitation medreport.invitations;
all_invitations medreport.invitations[] := array[]::medreport.invitations[];
invite_token text;
invite medreport.invitation;
begin
foreach invite in array invitations loop
invite_token := extensions.uuid_generate_v4();
insert into medreport.invitations (
email,
account_id,
invited_by,
role,
invite_token,
personal_code
)
values (
invite.email,
(select id from medreport.accounts where slug = account_slug),
auth.uid(),
invite.role,
invite_token,
invite.personal_code
)
returning * into new_invitation;
all_invitations := array_append(all_invitations, new_invitation);
end loop;
return all_invitations;
end;
$$ language plpgsql;
grant execute on function medreport.add_invitations_to_account(text, medreport.invitation[]) to authenticated;
grant
execute on function medreport.has_permission (uuid, uuid, medreport.app_permissions) to authenticated,
service_role;
grant
execute on function medreport.has_more_elevated_role (uuid, uuid, varchar) to authenticated,
service_role;
grant
execute on function medreport.has_same_role_hierarchy_level (uuid, uuid, varchar) to authenticated,
service_role;
ALTER TABLE medreport.invitations ALTER COLUMN id DROP DEFAULT;
ALTER TABLE medreport.invitations DROP COLUMN id;
ALTER TABLE medreport.invitations ADD COLUMN id UUID NOT NULL DEFAULT gen_random_uuid();
ALTER TABLE medreport.invitations ADD PRIMARY KEY (id);
ALTER TABLE medreport.invitations DROP CONSTRAINT invitations_pkey;
ALTER TABLE medreport.invitations DROP COLUMN id;
ALTER TABLE medreport.invitations ADD COLUMN id SERIAL PRIMARY KEY;
DROP FUNCTION IF EXISTS medreport.get_account_invitations(account_slug text);
create function medreport.get_account_invitations (account_slug text)
returns table (
id integer,
email varchar(255),
account_id uuid,
invited_by uuid,
role varchar(50),
created_at timestamptz,
updated_at timestamptz,
expires_at timestamptz,
personal_code text,
inviter_name varchar,
inviter_email varchar
)
set search_path = ''
as $$
begin
return query
select
invitation.id,
invitation.email,
invitation.account_id,
invitation.invited_by,
invitation.role,
invitation.created_at,
invitation.updated_at,
invitation.expires_at,
invitation.personal_code,
account.name,
account.email
from
medreport.invitations as invitation
join medreport.accounts as account on invitation.account_id = account.id
where
account.slug = account_slug;
end;
$$ language plpgsql;
grant execute on function medreport.get_account_invitations(text) to authenticated, service_role;
drop policy if exists invitations_read_self on medreport.invitations;
drop policy if exists invitations_create_self on medreport.invitations;
drop policy if exists invitations_update on medreport.invitations;
drop policy if exists invitations_delete on medreport.invitations;
drop policy if exists super_admins_access_invitations on medreport.invitations;
create policy invitations_read_self on medreport.invitations for
select
to authenticated using (medreport.has_role_on_account (account_id));
create policy invitations_create_self on medreport.invitations for insert to authenticated
with
check (
medreport.is_set ('enable_team_accounts')
and medreport.has_permission (
(
select
auth.uid ()
),
account_id,
'invites.manage'::medreport.app_permissions
)
and (medreport.has_more_elevated_role (
(
select
auth.uid ()
),
account_id,
role
) or medreport.has_same_role_hierarchy_level(
(
select
auth.uid ()
),
account_id,
role
))
);
create policy invitations_update on medreport.invitations
for update
to authenticated using (
medreport.has_permission (
(
select
auth.uid ()
),
account_id,
'invites.manage'::medreport.app_permissions
)
and medreport.has_more_elevated_role (
(
select
auth.uid ()
),
account_id,
role
)
)
with
check (
medreport.has_permission (
(
select
auth.uid ()
),
account_id,
'invites.manage'::medreport.app_permissions
)
and medreport.has_more_elevated_role (
(
select
auth.uid ()
),
account_id,
role
)
);
create policy invitations_delete on medreport.invitations for delete to authenticated using (
medreport.has_role_on_account (account_id)
and medreport.has_permission (
(
select
auth.uid ()
),
account_id,
'invites.manage'::medreport.app_permissions
)
);
create policy super_admins_access_invitations
on medreport.invitations
as permissive
for select
to authenticated
using (medreport.is_super_admin());
INSERT INTO medreport.config DEFAULT VALUES;
DROP FUNCTION public.get_invitations_with_account_ids(
company_id uuid,
personal_codes text[]
);
ALTER TABLE "medreport"."invitations" ADD COLUMN IF NOT EXISTS personal_code text;
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1
FROM pg_constraint
WHERE conname = 'accounts_personal_code_unique'
) THEN
ALTER TABLE medreport.accounts
ADD CONSTRAINT accounts_personal_code_unique UNIQUE (personal_code);
END IF;
END$$;
ALTER TABLE medreport.invitations
ALTER COLUMN personal_code TYPE text;
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1
FROM pg_constraint
WHERE conname = 'invitations_personal_code_unique'
) THEN
ALTER TABLE medreport.invitations
ADD CONSTRAINT invitations_personal_code_unique UNIQUE (personal_code);
END IF;
END$$;
create or replace function medreport.get_invitations_with_account_ids(
company_id uuid,
personal_codes text[]
)
returns table (
invite_token text,
personal_code text,
account_id uuid
)
language sql
as $$
select
i.invite_token,
i.personal_code,
a.id as account_id
from medreport.invitations i
join medreport.accounts a on a.personal_code = i.personal_code
where i.account_id = company_id
and i.personal_code = any(personal_codes);
$$;
grant
execute on function medreport.get_invitations_with_account_ids (uuid, text[]) to authenticated,
service_role;
GRANT USAGE, SELECT ON SEQUENCE medreport.invitations_id_seq TO authenticated;
DROP FUNCTION IF EXISTS public.has_permission(uuid, uuid, medreport.app_permissions);

View File

@@ -0,0 +1,67 @@
DROP TRIGGER IF EXISTS add_current_user_to_new_account ON medreport.accounts;
create or replace function medreport.create_team_account (
account_name text,
new_personal_code text
) returns medreport.accounts
security definer
set search_path = ''
as $$
declare
existing_account medreport.accounts;
current_user uuid := (select auth.uid())::uuid;
new_account medreport.accounts;
begin
if not medreport.is_set('enable_team_accounts') then
raise exception 'Team accounts are not enabled';
end if;
insert into medreport.accounts(
name,
is_personal_account)
values (
account_name,
false)
returning
* into new_account;
-- Try to find existing account
select *
into existing_account
from medreport.accounts
where personal_code = new_personal_code
limit 1;
-- If not found, fail
if not found then
raise exception 'No account found with personal_code = %', new_personal_code;
end if;
-- Insert membership
insert into medreport.accounts_memberships (
user_id,
account_id,
account_role,
created_by,
updated_by,
created_at,
updated_at,
has_seen_confirmation
)
values (
existing_account.id,
new_account.id,
'owner',
null,
null,
now(),
now(),
false
)
on conflict do nothing;
return new_account;
end;
$$ language plpgsql;
grant execute on function medreport.create_team_account (text, text) to authenticated, service_role;

View File

@@ -0,0 +1,9 @@
create trigger "trigger_invitation_email" after insert
on "medreport"."invitations" for each row
execute function "supabase_functions"."http_request"(
'http://host.docker.internal:3000/api/db/webhook',
'POST',
'{"Content-Type":"application/json", "X-Supabase-Event-Signature":"WEBHOOKSECRET"}',
'{}',
'1000'
);