Securing PostgreSQL using database permissions

Displaying database permissions

Every database in a PostgreSQL cluster has an associated set of permissions. These permissions allow fine grained control over the actions allowed for a particular role or user. The psql application can be used to show the permissions assigned to roles and users as shown in the example below.

pgadmin@lisa psql -d template1
Example database listing showing default permissions
template1=# \l 
                               List of databases 
   Name    |  Owner  | Encoding |  Collation  |    Ctype    |  Access privileges 
-----------+---------+----------+-------------+-------------+--------------------- 
 postgres  | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 |  
 template0 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | =c/pgadmin         + 
                                                            | pgadmin=CTc/pgadmin 
 template1 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | pgadmin=CTc/pgadmin+ 
                                                            | =c/pgadmin 
(3 rows) 

You can see in the above example that for each database either an empty set of access privileges is displayed, indicating that no permissions have been granted, or a string describing the current set of permissions, in the format shown below. If the <user> portion of the string is empty then the privileges which follow are assigned to the special PUBLIC role.

<user> = <permissions> / <granted by>

The access privileges displayed in the above example output are summed up in the following table. More information on available access privileges is available in the GRANT section of the PostgreSQL documentation.

CONNECT - c
Whenever a client attempts to establish a database connection the connection parameters are first checked against the rules specified in pg_hba.conf and, assuming the connection is allowed, a further check is performed to verify that the connecting user is allowed access to the specified database. If the connecting user has no CONNECT privileges on any database then the connection will be refused. In the above example both template0 and template1 provide CONNECT rights to all users as well as also providing them to the pgadmin user specifically.
CREATE - C
The CREATE permission indicates that the specified role is allowed to create new schemas within the specified database. In the above example the CREATE privilege is granted to the pgadmin user for both the template0 and template1 databases.
TEMPORARY - T
The TEMPORARY (or TEMP) permission allows the specified role to create temporary tables while using the specified database. In the above example the TEMPORARY permission is granted to the pgadmin user on both the template0 and template1 databases.

Revoking database permissions

We showed, in the previous example, that the set of default permissions on a fresh PostgreSQL cluster included CONNECT privileges for the special PUBLIC role. As we have no need for connections to be allowed for the entire membership of the PUBLIC role we can improve security by revoking those permissions. The example commands shown below can be used to REVOKE all permissions granted to the PUBLIC role on both the template0 and template1 databases.

Revoking all public permissions
template1=# REVOKE ALL ON DATABASE template0 FROM PUBLIC; 
REVOKE 
template1=# REVOKE ALL ON DATABASE template1 FROM PUBLIC; 
REVOKE 

You can verify that the commands had the desired effect by displaying a list of databases as shown below. As you can see the only privileges granted on the template0 and template1 databases are now granted specifically to the pgadmin role.

Example database listing showing reduced permissions
template1=# \l 
                               List of databases 
   Name    |  Owner  | Encoding |  Collation  |    Ctype    |  Access privileges 
-----------+---------+----------+-------------+-------------+--------------------- 
 postgres  | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 |  
 template0 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | pgadmin=CTc/pgadmin 
 template1 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | pgadmin=CTc/pgadmin 
(3 rows) 

Granting database permissions

Of course, now that we have revoked CONNECT permissions from the PUBLIC role, only users which have been granted CONNECT privileges, or are members of roles which have been granted CONNECT privileges, may connect to the database cluster. The example below demonstrates how to GRANT the CONNECT and TEMPORARY privileges to a specific role on a specific database.

Granting CONNECT permissions on a database to a user
template1=# GRANT CONNECT ON DATABASE dns TO dns; 
GRANT 
template1=# GRANT TEMPORARY ON DATABASE dns TO dns; 
GRANT 

As before you can verify that the commands had the desired effect by displaying a listing of databases using the pgsql application. The example below shows an additional database, mail (taken from our E-mail virtual-hosting system using Postfix and CourierIMAP how-to guide), which is owned by the dbadmin user and also allows connections from any users who are members of the mail role.

Example database listing showing reduced permissions
template1=# \l 
                               List of databases 
   Name    |  Owner  | Encoding |  Collation  |    Ctype    |  Access privileges 
-----------+---------+----------+-------------+-------------+--------------------- 
 mail      | dbadmin | UTF8     | en_GB.utf8  | en_GB.utf8  | dbadmin=CTc/dbadmin+ 
           |         |          |             |             | mail=Tc/dbadmin 
 postgres  | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 |  
 template0 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | pgadmin=CTc/pgadmin 
 template1 | pgadmin | UTF8     | en_GB.UTF-8 | en_GB.UTF-8 | pgadmin=CTc/pgadmin 
(4 rows)