Re: Making a schema "read-only" (was Unexpected message in grant/revoke script)

From: "Webb Sprague" <webb(dot)sprague(at)gmail(dot)com>
To: "Erik Jones" <erik(at)myemma(dot)com>, "Carl Mason" <carlm(at)demog(dot)berkeley(dot)edu>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Making a schema "read-only" (was Unexpected message in grant/revoke script)
Date: 2008-03-14 22:36:03
Message-ID: b11ea23c0803141536r93cb677s256f0330d5e2d015@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Thanks to Eric and Tom, I think I have got it. Here is the function
for adding a new student, who can select anything in public and can do
anything at all in their own schema.

revoke all on schema public from public; -- done only once
create or replace function new_student (text) returns void as $$
declare
t_name text;
begin
-- personal schema
execute 'create role ' || $1 || ' LOGIN';
execute 'create schema authorization ' || $1 ;

-- public schema
execute 'revoke all on schema public from ' || $1;
execute 'grant usage on schema public to ' || $1;
for t_name in select table_name from information_schema.tables
where table_schema = 'public' order by table_name loop
raise notice 'granting select to %s on %s', $1, t_name;
execute 'grant select on ' || t_name || ' to ' || $1;
end loop;
end;
$$ language plpgsql ;
select new_student ('fobar'); --etc

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Tom Lane 2008-03-14 22:57:51 Re: How to silence psql notices, warnings, etc.?
Previous Message Kynn Jones 2008-03-14 21:38:04 shared memory/max_locks_per_transaction error