Thread: Grant read-only access to exactly one database amongst many

Grant read-only access to exactly one database amongst many

From
Graham Leggett
Date:
Hi all,

I have a postgresql 15 instance with two databases in it, and I have a need to grant read-only access to one of those
databasesto a given user. 

To do this I created a dedicated role for readonly access to the database db1:

CREATE ROLE "dv_read_db1"
GRANT CONNECT ON DATABASE db1 TO dv_read_db1
GRANT USAGE ON SCHEMA public TO “dv_read_db1"
GRANT SELECT ON ALL TABLES IN SCHEMA public TO “dv_read_db1"
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO “dv_read_db1"

CREATE USER minfrin LOGIN;
GRANT dv_read_db1 TO minfrin;

On the surface this works, I get readonly access to db1.

Trouble is, I can create tables in db1 which is write access. I can also connect to db2 (bad), and I can enumerate the
tablesin db2 (bad), although the queries of the contents say access is denied. 

I appears the mechanism I am using above has insecure side effects.

What is the way to grant read only access to a single database, without exposing other databases, and being futureproof
againstfuture features offering potential write access to a read only user? 

Regards,
Graham
—




Re: Grant read-only access to exactly one database amongst many

From
Tom Lane
Date:
Graham Leggett <minfrin@sharp.fm> writes:
> Trouble is, I can create tables in db1 which is write access. I can also connect to db2 (bad), and I can enumerate
thetables in db2 (bad), although the queries of the contents say access is denied. 

You need to read the docs about default privileges: see about
halfway down

https://www.postgresql.org/docs/15/ddl-priv.html

where it says "PostgreSQL grants privileges on some types of objects
to PUBLIC by default ...".  In this case I think you likely need to
revoke the default public CREATE privilege on schema public in db1,
and revoke the default public CONNECT privilege on database db2.

            regards, tom lane



Re: Grant read-only access to exactly one database amongst many

From
"David G. Johnston"
Date:
On Sun, Feb 4, 2024 at 5:04 PM Graham Leggett <minfrin@sharp.fm> wrote:
Hi all,

I have a postgresql 15 instance with two databases in it, and I have a need to grant read-only access to one of those databases to a given user.

To do this I created a dedicated role for readonly access to the database db1:

CREATE ROLE "dv_read_db1"
GRANT CONNECT ON DATABASE db1 TO dv_read_db1

This grant is basically pointless since by default all roles can connect everywhere via the PUBLIC pseudo-role.  You need to revoke that grant, or even alter it being given out by default.

 
Trouble is, I can create tables in db1 which is write access.

Since in v15 PUBLIC also gets CREATE on the public schema.

I can also connect to db2 (bad),

See my comment regarding the pointless grant in a default setup.

and I can enumerate the tables in db2 (bad),

Connect privilege grants reading all catalog data by design.


I appears the mechanism I am using above has insecure side effects.

It has, from your expectation, insecure defaults which you never changed.  We changed public schema in v16 but the ease-of-use database connecting remains.

David J.

Re: Grant read-only access to exactly one database amongst many

From
Graham Leggett
Date:
On 05 Feb 2024, at 00:54, David G. Johnston <david.g.johnston@gmail.com> wrote:

I have a postgresql 15 instance with two databases in it, and I have a need to grant read-only access to one of those databases to a given user.

To do this I created a dedicated role for readonly access to the database db1:

CREATE ROLE "dv_read_db1"
GRANT CONNECT ON DATABASE db1 TO dv_read_db1

This grant is basically pointless since by default all roles can connect everywhere via the PUBLIC pseudo-role.  You need to revoke that grant, or even alter it being given out by default.

More on this point at the end…

Trouble is, I can create tables in db1 which is write access.

Since in v15 PUBLIC also gets CREATE on the public schema.

…ouch…

I can also connect to db2 (bad),

See my comment regarding the pointless grant in a default setup.

and I can enumerate the tables in db2 (bad),

Connect privilege grants reading all catalog data by design.


I appears the mechanism I am using above has insecure side effects.

It has, from your expectation, insecure defaults which you never changed.  We changed public schema in v16 but the ease-of-use database connecting remains.

It looks like changing these defaults is likely to be difficult, which is why I posted here.

I want to optionally allow user minfrin to access both databases by doing this:

CREATE USER minfrin LOGIN;
GRANT dv_read_db1 TO minfrin;
GRANT dv_read_db2 TO minfrin;

If I am understanding you correctly to prevent dv_read_db1 from connecting to db2, I need to actively revoke access to db2. Also, to prevent dv_read_db2 from connecting to db1, I need to actively revoke access to db1.

Would the two grants above dv_read_db1 and dv_read_db2 not cause the unintended side effect of revoking access to each other, resulting in no access being allowed at all?

Also, how do you handle the race condition between the time a database db3 is created, and the the time all readonly users have their access revoked to db3?

Regards,
Graham

Re: Grant read-only access to exactly one database amongst many

From
"David G. Johnston"
Date:
On Monday, February 5, 2024, Graham Leggett <minfrin@sharp.fm> wrote:

Also, how do you handle the race condition between the time a database db3 is created, and the the time all readonly users have their access revoked to db3?


You alter the default privileges for the system so PUBLIC does not get connect privileges on newly created databases.

David J.

p.s. this mailing list is for discussing patches, discussions Lon how to use the system belong on the -general list.