Thread: How to create a read only user account to access to all pg database?

How to create a read only user account to access to all pg database?

From
KhunSanAung
Date:
Hi All,

I have several pg database with their own login user account.
For backup purpose, I'd like to create an additional read only user account that can access all the pg database.
How can I do it?
Via PSQL command or via pgAdmin III client would be okay.

Your help is high appreciated.

Many thanks & best regards

--
Have a nice day!
--

Mr. Khun San Aung

Re: How to create a read only user account to access to all pg database?

From
Shreeyansh Dba
Date:
Hi KhunSanAung,

A simple way is Create a user with superuser privileges and read only permission.

-Login psql as postgres or other superuser.
-Create the new superuser role and set it to read only :

CREATE USER backupadmn WITH PASSWORD 'pwd' SUPERUSER ;
ALTER USER backupadmn set default_transaction_read_only = on;


Regards,
Sagar Jadhav
Database Administrator



On Wed, Nov 25, 2015 at 9:05 AM, KhunSanAung <khunsanaung.gis@gmail.com> wrote:
Hi All,

I have several pg database with their own login user account.
For backup purpose, I'd like to create an additional read only user account that can access all the pg database.
How can I do it?
Via PSQL command or via pgAdmin III client would be okay.

Your help is high appreciated.

Many thanks & best regards

--
Have a nice day!
--

Mr. Khun San Aung


Re: How to create a read only user account to access to all pg database?

From
Ville Rantamaula
Date:
Hi,

Assuming you have only the public schema in use per database (usually the case). In each database run the following SQL:
CREATE ROLE backup WITH LOGIN;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO backup;
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO backup;

After that, adjust the file PostgreSQL configuration file pg_hba.conf to allow appropriate access for newly create ROLE backup.

Yours,
Ville


2015-11-25 5:35 GMT+02:00 KhunSanAung <khunsanaung.gis@gmail.com>:
Hi All,

I have several pg database with their own login user account.
For backup purpose, I'd like to create an additional read only user account that can access all the pg database.
How can I do it?
Via PSQL command or via pgAdmin III client would be okay.

Your help is high appreciated.

Many thanks & best regards

--
Have a nice day!
--

Mr. Khun San Aung


Re: How to create a read only user account to access to all pg database?

From
Stephen Frost
Date:
* Shreeyansh Dba (shreeyansh2014@gmail.com) wrote:
> A simple way is Create a user with superuser privileges and read only
> permission.
>
> -Login psql as postgres or other superuser.
> -Create the new superuser role and set it to read only :
>
> CREATE USER backupadmn WITH PASSWORD 'pwd' SUPERUSER ;
> ALTER USER backupadmn set default_transaction_read_only = on;

Uh, that doesn't create a read-only user, it just starts that user's
session out with the transaction being read only *by default*.

Do NOT use this to try and create read-only users.

The user can trivially change that if they have SQL access using begin:

----------------------
=# begin read write;
BEGIN
=*# alter user r1 set default_transaction_read_only = 0;
ALTER ROLE
=*# commit;
COMMIT
=#
----------------------

Thanks!

Stephen

Attachment