campingmontagut/deploy/user_profile.sql
jordi fita mas 866af09b50 Move the user role down to company_user relation
I was starting to add the public page for campsite types, creating more
granular row-level security policies for select, insert, update, and
delete, because now the guest users needed to SELECT them and they have
no related company to filter the rows with.  Suddenly, i realized that
the role was wrong in the user relation: a user can be an admin to one
company, and employee to another, and guess to yet another company;
the role should be in the company_user relation instead.

That means that to know the role to set to, the user alone is not enough
and have to know the company as well.  Had to change all the
cookie-related function to accept also the company’s host name, as this
is the information that the Go application has.
2023-08-08 02:22:16 +02:00

78 lines
1.8 KiB
PL/PgSQL

-- Deploy camper:user_profile to pg
-- requires: roles
-- requires: schema_camper
-- requires: user
-- requires: company_user
-- requires: current_user_email
-- requires: current_user_cookie
-- requires: current_company_id
begin;
set search_path to camper, public;
create or replace view user_profile with (security_barrier) as
select user_id
, company_id
, email
, name
, role
, lang_tag
, left(cookie, 10) as csrf_token
from auth."user"
join company_user using (user_id)
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30
and company_id = current_company_id()
union all
select 0
, 0
, null::email
, ''
, 'guest'::name
, 'und'
, ''
where not exists (select 1
from auth."user"
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30)
;
grant select on table user_profile to guest;
grant select, update (email, name, lang_tag) on table user_profile to employee;
grant select, update (email, name, lang_tag) on table user_profile to admin;
create or replace function update_user_profile() returns trigger as
$$
begin
update auth."user"
set email = new.email
, name = new.name
, lang_tag = new.lang_tag
where email = current_user_email()
and cookie = current_user_cookie()
and cookie_expires_at > current_timestamp
and length(cookie) > 30
;
perform set_config('request.user.email', new.email, false);
return new;
end;
$$
language plpgsql
security definer
set search_path to auth, camper, pg_temp;
create trigger update_user_profile
instead of update
on user_profile
for each row
execute procedure update_user_profile();
commit;