Database Roles and Privileges PostgreSQL manages database access permissions using the concept of roles. A role can be thought of as either a database user, or a group of database users, depending on how the role is set up. Roles can own database objects (for example, tables) and can assign privileges on those objects to other roles to control who has access to which objects. Furthermore, it is possible to grant membership in a role to another role, thus allowing the member role use of privileges assigned to the role it is a member of. The concept of roles subsumes the concepts of users and groups. In PostgreSQL versions before 8.1, users and groups were distinct kinds of entities, but now there are only roles. Any role can act as a user, a group, or both. This chapter describes how to create and manage roles and introduces the privilege system. More information about the various types of database objects and the effects of privileges can be found in . Database Roles role user CREATE ROLE DROP ROLE Database roles are conceptually completely separate from operating system users. In practice it might be convenient to maintain a correspondence, but this is not required. Database roles are global across a database cluster installation (and not per individual database). To create a role use the SQL command: CREATE ROLE name; name follows the rules for SQL identifiers: either unadorned without special characters, or double-quoted. (In practice, you will usually want to add additional options, such as LOGIN, to the command. More details appear below.) To remove an existing role, use the analogous command: DROP ROLE name; createuser dropuser For convenience, the programs and are provided as wrappers around these SQL commands that can be called from the shell command line: createuser name dropuser name To determine the set of existing roles, examine the pg_roles system catalog, for example SELECT rolname FROM pg_roles; The program's \du meta-command is also useful for listing the existing roles. In order to bootstrap the database system, a freshly initialized system always contains one predefined role. This role is always a superuser, and by default (unless altered when running initdb) it will have the same name as the operating system user that initialized the database cluster. Customarily, this role will be named postgres. In order to create more roles you first have to connect as this initial role. Every connection to the database server is made in the name of some particular role, and this role determines the initial access privileges for commands issued on that connection. The role name to use for a particular database connection is indicated by the client that is initiating the connection request in an application-specific fashion. For example, the psql program uses the command line option to indicate the role to connect as. Many applications assume the name of the current operating system user by default (including createuser and psql). Therefore it is often convenient to maintain a naming correspondence between roles and operating system users. The set of database roles a given client connection may connect as is determined by the client authentication setup, as explained in . (Thus, a client is not necessarily limited to connect as the role with the same name as its operating system user, just as a person's login name need not match her real name.) Since the role identity determines the set of privileges available to a connected client, it is important to carefully configure this when setting up a multiuser environment. Role Attributes A database role may have a number of attributes that define its privileges and interact with the client authentication system. login privilegelogin privilege Only roles that have the LOGIN attribute can be used as the initial role name for a database connection. A role with the LOGIN attribute can be considered the same thing as a database user. To create a role with login privilege, use either CREATE ROLE name LOGIN; CREATE USER name; (CREATE USER is equivalent to CREATE ROLE except that CREATE USER assumes LOGIN by default, while CREATE ROLE does not.) superuser statussuperuser A database superuser bypasses all permission checks. This is a dangerous privilege and should not be used carelessly; it is best to do most of your work as a role that is not a superuser. To create a new database superuser, use CREATE ROLE name SUPERUSER. You must do this as a role that is already a superuser. database creationdatabaseprivilege to create A role must be explicitly given permission to create databases (except for superusers, since those bypass all permission checks). To create such a role, use CREATE ROLE name CREATEDB. role creationroleprivilege to create A role must be explicitly given permission to create more roles (except for superusers, since those bypass all permission checks). To create such a role, use CREATE ROLE name CREATEROLE. A role with CREATEROLE privilege can alter and drop other roles, too, as well as grant or revoke membership in them. However, to create, alter, drop, or change membership of a superuser role, superuser status is required; CREATEROLE is not sufficient for that. passwordpassword A password is only significant if the client authentication method requires the user to supply a password when connecting to the database. The A role's attributes can be modified after creation with ALTER ROLE.ALTER ROLE See the reference pages for the and commands for details. It is good practice to create a role that has the CREATEDB and CREATEROLE privileges, but is not a superuser, and then use this role for all routine management of databases and roles. This approach avoids the dangers of operating as a superuser for tasks that do not really require it. A role can also have role-specific defaults for many of the run-time configuration settings described in . For example, if for some reason you want to disable index scans (hint: not a good idea) anytime you connect, you can use ALTER ROLE myname SET enable_indexscan TO off; This will save the setting (but not set it immediately). In subsequent connections by this role it will appear as though SET enable_indexscan TO off; had been executed just before the session started. You can still alter this setting during the session; it will only be the default. To remove a role-specific default setting, use ALTER ROLE rolename RESET varname;. Note that role-specific defaults attached to roles without LOGIN privilege are fairly useless, since they will never be invoked. Privileges privilege owner GRANT REVOKE When an object is created, it is assigned an owner. The owner is normally the role that executed the creation statement. For most kinds of objects, the initial state is that only the owner (or a superuser) can do anything with the object. To allow other roles to use it, privileges must be granted. There are several different kinds of privilege: SELECT, INSERT, UPDATE, DELETE, RULE, REFERENCES, TRIGGER, CREATE, CONNECT, TEMPORARY, EXECUTE, and USAGE. For more information on the different types of privileges supported by PostgreSQL, see the reference page. To assign privileges, the GRANT command is used. So, if joe is an existing role, and accounts is an existing table, the privilege to update the table can be granted with GRANT UPDATE ON accounts TO joe; The special name PUBLIC can be used to grant a privilege to every role on the system. Writing ALL in place of a specific privilege specifies that all privileges that apply to the object will be granted. To revoke a privilege, use the fittingly named command: REVOKE ALL ON accounts FROM PUBLIC; The special privileges of an object's owner (i.e., the right to modify or destroy the object) are always implicit in being the owner, and cannot be granted or revoked. But the owner can choose to revoke his own ordinary privileges, for example to make a table read-only for himself as well as others. An object can be assigned to a new owner with an ALTER command of the appropriate kind for the object. Superusers can always do this; ordinary roles can only do it if they are both the current owner of the object (or a member of the owning role) and a member of the new owning role. Role Membership rolemembership in It is frequently convenient to group users together to ease management of privileges: that way, privileges can be granted to, or revoked from, a group as a whole. In PostgreSQL this is done by creating a role that represents the group, and then granting membership in the group role to individual user roles. To set up a group role, first create the role: CREATE ROLE name; Typically a role being used as a group would not have the LOGIN attribute, though you can set it if you wish. Once the group role exists, you can add and remove members using the and commands: GRANT group_role TO role1, ... ; REVOKE group_role FROM role1, ... ; You can grant membership to other group roles, too (since there isn't really any distinction between group roles and non-group roles). The database will not let you set up circular membership loops. Also, it is not permitted to grant membership in a role to PUBLIC. The members of a role can use the privileges of the group role in two ways. First, every member of a group can explicitly do to temporarily become the group role. In this state, the database session has access to the privileges of the group role rather than the original login role, and any database objects created are considered owned by the group role not the login role. Second, member roles that have the INHERIT attribute automatically have use of privileges of roles they are members of. As an example, suppose we have done CREATE ROLE joe LOGIN INHERIT; CREATE ROLE admin NOINHERIT; CREATE ROLE wheel NOINHERIT; GRANT admin TO joe; GRANT wheel TO admin; Immediately after connecting as role joe, a database session will have use of privileges granted directly to joe plus any privileges granted to admin, because joe inherits admin's privileges. However, privileges granted to wheel are not available, because even though joe is indirectly a member of wheel, the membership is via admin which has the NOINHERIT attribute. After SET ROLE admin; the session would have use of only those privileges granted to admin, and not those granted to joe. After SET ROLE wheel; the session would have use of only those privileges granted to wheel, and not those granted to either joe or admin. The original privilege state can be restored with any of SET ROLE joe; SET ROLE NONE; RESET ROLE; The SET ROLE command always allows selecting any role that the original login role is directly or indirectly a member of. Thus, in the above example, it is not necessary to become admin before becoming wheel. In the SQL standard, there is a clear distinction between users and roles, and users do not automatically inherit privileges while roles do. This behavior can be obtained in PostgreSQL by giving roles being used as SQL roles the INHERIT attribute, while giving roles being used as SQL users the NOINHERIT attribute. However, PostgreSQL defaults to giving all roles the INHERIT attribute, for backwards compatibility with pre-8.1 releases in which users always had use of permissions granted to groups they were members of. The role attributes LOGIN, SUPERUSER, CREATEDB, and CREATEROLE can be thought of as special privileges, but they are never inherited as ordinary privileges on database objects are. You must actually SET ROLE to a specific role having one of these attributes in order to make use of the attribute. Continuing the above example, we might well choose to grant CREATEDB and CREATEROLE to the admin role. Then a session connecting as role joe would not have these privileges immediately, only after doing SET ROLE admin. To destroy a group role, use : DROP ROLE name; Any memberships in the group role are automatically revoked (but the member roles are not otherwise affected). Note however that any objects owned by the group role must first be dropped or reassigned to other owners; and any permissions granted to the group role must be revoked. Functions and Triggers Functions and triggers allow users to insert code into the backend server that other users may execute unintentionally. Hence, both mechanisms permit users to Trojan horse others with relative ease. The only real protection is tight control over who can define functions. Functions run inside the backend server process with the operating system permissions of the database server daemon. If the programming language used for the function allows unchecked memory accesses, it is possible to change the server's internal data structures. Hence, among many other things, such functions can circumvent any system access controls. Function languages that allow such access are considered untrusted, and PostgreSQL allows only superusers to create functions written in those languages.