Securing PostgreSQL using object permissions

Displaying object permissions

Every table, sequence, view, or other object in a PostgreSQL database 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 object permissions assigned to roles and users as shown in the example below. For the purposes of illustration we are using a fictitious database taken from our DNS server using PowerDNS how-to guide.

dbadmin@lisa psql -d dns
Example database object listing showing permissions
template1=# \dp 
                                      Access privileges 
 Schema |      Name      |   Type   |    Access privileges    | Column access privileges 
--------+----------------+----------+-------------------------+-------------------------- 
 public | domains        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=arwd/dbadmin  |  
 public | domains_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin   |  
 public | records        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=arwd/dbadmin  |  
 public | records_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin   |  
 public | supermasters   | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=arwd/dbadmin  |  

You can see in the above example that for each database object a set of access privileges is displayed 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. As you can see the dbadmin user has full control of all objects, the dns_admin user has the permissions required to administer the DNS system and all members of the dns role have sufficient read permissions to serve DNS records from the database.

<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.

INSERT - a
Allows the specified role to INSERT a new row into the specified table.
SELECT - r
Allows the specified role to SELECT from any column in the specified table or view. This privilege is also required to reference existing column values in UPDATE or DELETE queries, such as in a WHERE reference. When applied to a sequence this privilege allows the use of the currval function to retrieve the current sequence value.
UPDATE - w
Allows the specified role to UPDATE any column in the specified table. The SELECT privilege is also required to reference existing column values which is a practical requirement of any nontrivial UPDATE command as it is required in a WHERE reference at the very least. When applied to a sequence this privilege allows the use of both the nextval and setval functions to retrieve and set the next value in the sequence respectively.
DELETE - d
Allows the specified role to DELETE a row from the specified table. As with the UPDATE command above the SELECT privilege is also required to reference existing column values which is a practical requirement of any nontrivial DELETE command as it is usually required in a WHERE reference at the very least.
TRUNCATE - D
Allows the specified role to TRUNCATE the entire contents of the specified table.
REFERENCES - x
Allows the specified role to create a foreign key constraint utilising the specified table. It should be noted that this permission is required on both the referencing and referenced tables in the relationship. No special permissions are required to use a foreign key constraint.
TRIGGER - t
Allows the specified role to create a TRIGGER on the specified table. No special permissions are required for normal execution of triggers once created.
EXECUTE - X
Allows the specified role to execute the specified function.
USAGE - U
Allows the specified role to use the specified SEQUENCE with the currval and nextval functions to retrieve the current and next value from the sequence.

Revoking object permissions

We showed, in the section of this guide, that permissions can be removed using the REVOKE command. As we have no need to allow the dns_admin user SELECT access to any tables, they inherit this from their membership of the dns role we can remove this permission as shown below.

Revoking all public permissions
dns=# REVOKE SELECT ON domains FROM dns_admin; 
REVOKE 
dns=# REVOKE SELECT ON records FROM dns_admin; 
REVOKE 
dns=# REVOKE SELECT ON supermasters FROM dns_admin; 
REVOKE 

You can verify that the commands had the desired effect by displaying a list of objects as shown in the following example. As you can see SELECT privileges are no longer directly granted to the dns_admin user.

Example database object listing showing reduced permissions
dns=# \dp 
                                    Access privileges 
 Schema |      Name      |   Type   |    Access privileges    | Column access privileges 
--------+----------------+----------+-------------------------+-------------------------- 
 public | domains        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
 public | domains_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin   |  
 public | records        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
 public | records_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin   |  
 public | supermasters   | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
(5 rows) 

Granting object permissions

Of course, permissions can be granted using the GRANT command in exactly the same way. Assuming we wanted to give the dns role, and therefore by implication all of its members, SELECT permissions on the two sequences we could do so with the following commands.

Granting SELECT permissions on a sequence to a user
template1=# GRANT SELECT ON domains_id_seq TO dns; 
GRANT 
template1=# GRANT SELECT ON records_id_seq TO dns; 
GRANT 

As before you can verify that the commands had the desired effect by displaying a listing of database objects from within the psql application.

Example database listing showing reduced permissions
template1=# \dp 
                                    Access privileges 
 Schema |      Name      |   Type   |    Access privileges    | Column access privileges 
--------+----------------+----------+-------------------------+-------------------------- 
 public | domains        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
 public | domains_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin  +|  
        |                |          | dns=r/dbadmin           |  
 public | records        | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
 public | records_id_seq | sequence | dbadmin=rwU/dbadmin    +|  
        |                |          | dns_admin=rwU/dbadmin  +|  
        |                |          | dns=r/dbadmin           |  
 public | supermasters   | table    | dbadmin=arwdDxt/dbadmin+|  
        |                |          | dns=r/dbadmin          +|  
        |                |          | dns_admin=awd/dbadmin   |  
(5 rows)