Thread: How to allow users to create and modify tables only in their ownschemas, but with generic table owner
How to allow users to create and modify tables only in their ownschemas, but with generic table owner
From
Schmid Andreas
Date:
Hi List I'd like to setup my database in a way that only a superuser may create schemas, then grants permission to a specific userto create tables inside this schema. This should work so far with GRANT CREATE ON SCHEMA ... TO user_a. However I wantthe table owner not to be the user that creates the tables. Instead the owner should rather be a generic role (e.g. table_owner),and the owner should be the same over all tables of the whole database. This would work, too, if I grant membershipin role table_owner to all users that may create tables. (The users must issue a SET ROLE table_owner before creatingtables.) What I didn't achieve so far is making sure that user_a who created tables in schema_a cannot crete/modify tables of schema_bthat were created by user_b. Do you see any way to achieve this, while still sticking to that generic owner role? Thanks a lot for your thoughts. Andy
Re: How to allow users to create and modify tables only in theirown schemas, but with generic table owner
From
Laurenz Albe
Date:
On Fri, 2020-03-06 at 11:04 +0000, Schmid Andreas wrote: > I'd like to setup my database in a way that only a superuser may create schemas, > then grants permission to a specific user to create tables inside this schema. > This should work so far with GRANT CREATE ON SCHEMA ... TO user_a. > However I want the table owner not to be the user that creates the tables. > Instead the owner should rather be a generic role (e.g. table_owner), and the > owner should be the same over all tables of the whole database. This would work, > too, if I grant membership in role table_owner to all users that may create tables. > (The users must issue a SET ROLE table_owner before creating tables.) Yes, that will work, but you have to SET ROLE before creating the table. > What I didn't achieve so far is making sure that user_a who created tables in schema_a > cannot crete/modify tables of schema_b that were created by user_b. Do you see any way > to achieve this, while still sticking to that generic owner role? No, that is impossible. But I don't understand the motivation: If you want that, why would you want a "table_owner" role? If you don't want user B to be able to drop user A's table, why don't you have each user be the owner of his tables? Yours, Laurenz Albe