Defines a new database role (user or group).
CREATE ROLE <name> [[WITH] <option> [ ... ]]
where option can be:
SUPERUSER | NOSUPERUSER
| CREATEDB | NOCREATEDB
| CREATEROLE | NOCREATEROLE
| CREATEEXTTABLE | NOCREATEEXTTABLE
[ ( <attribute>='<value>'[, ...] ) ]
where <attributes> and <value> are:
type='readable'|'writable'
protocol='gpfdist'|'http'
| INHERIT | NOINHERIT
| LOGIN | NOLOGIN
| REPLICATION | NOREPLICATION
| BYPASSRLS | NOBYPASSRLS
| CONNECTION LIMIT <connlimit>
| [ ENCRYPTED ] PASSWORD '<password>' | PASSWORD NULL
| VALID UNTIL '<timestamp>'
| IN ROLE <role_name> [, ...]
| IN GROUP <role_name> [, ...]
| ROLE <role_name> [, ...]
| ADMIN <role_name> [, ...]
| USER <role_name> [, ...]
| SYSID <uid> [, ...]
| RESOURCE QUEUE <queue_name>
| RESOURCE GROUP <group_name>
| [ DENY <deny_point> ]
| [ DENY BETWEEN <deny_point> AND <deny_point>]
CREATE ROLE
adds a new role to a Greenplum Database system. A role is an entity that can own database objects and have database privileges. A role can be considered a user, a group, or both depending on how it is used. You must have CREATEROLE
privilege or be a database superuser to use this command.
Note that roles are defined at the system-level and are valid for all databases in your Greenplum Database system.
SUPERUSER
is specified, the role being defined will be a superuser, who can override all access restrictions within the database. Superuser status is dangerous and should be used only when really needed. You must yourself be a superuser to create a new superuser.
NOSUPERUSER
is the default.
CREATEDB
is specified, the role being defined will be allowed to create new databases. Specifying
NOCREATEDB
(the default) will deny a role the ability to create databases.
CREATE ROLE
). If
CREATEROLE
is specified, the role being defined will be allowed to create new roles, alter other roles, and drop other roles.
NOCREATEROLE
(the default) will deny a role the ability to create roles or modify roles other than their own.
CREATEEXTTABLE
is specified, the role being defined is allowed to create external tables. The default
type
is
readable
and the default
protocol
is
gpfdist
, if not specified. Valid types are
gpfdist
,
gpfdists
,
http
, and
https
.
NOCREATEEXTTABLE
(the default type) denies the role the ability to create external tables. Note that external tables that use the
file
or
execute
protocols can only be created by superusers.
Use the GRANT...ON PROTOCOL
command to allow users to create and use external tables with a custom protocol type, including the s3
and pxf
protocols included with Greenplum Database.
INHERIT
(the default) allows the role to use whatever database privileges have been granted to all roles it is directly or indirectly a member of. With
NOINHERIT
, membership in another role only grants the ability to
SET ROLE
to that other role; the privileges of the other role are only available after having done so.
LOGIN
allows a role to log in to a database. A role having the
LOGIN
attribute can be thought of as a user. Roles with
NOLOGIN
are useful for managing database privileges, but are not users in the usual sense of the word. If not specified,
NOLOGIN
is the default, except when
CREATE ROLE
is invoked through its alternative spelling
CREATE USER.
REPLICATION
attribute is a very highly privileged role, and should only be used on roles actually used for replication. If not specified,
NOREPLICATION
is the default. You must be a superuser to create a new role having the
REPLICATION
attribute.
NOBYPASSRLS
is the default. You must be a superuser to create a new role having the
BYPASSRLS
attribute.
Note that pg_dump
will set row_security to OFF
by default, to ensure all contents of a table are dumped out. If the user running pg_dump
does not have appropriate permissions, an error will be returned. However, superusers and the owner of the table being dumped always bypass RLS.
-1
means there is no limit. Note that only normal connections are counted towards this limit. Neither prepared transactions nor background worker connections are counted towards this limit.
LOGIN
attribute, but you can nonetheless define one for roles without it.) If you do not plan to use password authentication you can omit this option. If no password is specified, the password will be set to null and password authentication will always fail for that user. A null password can optionally be written explicitly as
PASSWORD NULL
. <div class="note>
Note: Specifying an empty string will also set the password to null, but that was not the case before Greenplum Database version 7. In earlier versions, an empty string could be used, or not, depending on the authentication method and the exact version, and
libpq
would refuse to use it in any case. To avoid the ambiguity, specifying an empty string should be avoided.
ENCRYPTED
keyword has no effect, but is accepted for backwards compatibility. The method of encryption is determined by the configuration parameter
password_encryption
. If the presented password string is already in MD5-encrypted or SCRAM-encrypted format, then it is stored as-is regardless of
password_encryption
(since the system cannot decrypt the specified encrypted password string, to encrypt it in a different format). This allows reloading of encrypted passwords during dump/restore.
GRANT
command to do that.)
IN GROUP
is an obsolete spelling of
IN ROLE
.
ADMIN
clause is like
ROLE
, but the named roles are added to the new role
WITH ADMIN OPTION
, giving them the right to grant membership in this role to others.
USER
clause is an obsolete spelling of the
ROLE
clause.
SYSID
clause is ignored, but is accepted for backwards compatibility.
If you do not specify a resource group for a new role, the role is automatically assigned the default resource group for the role’s capability, admin_group
for SUPERUSER
roles, default_group
for non-admin roles.
You can assign the admin_group
resource group to any role having the SUPERUSER
attribute.
You can assign the default_group
resource group to any role.
You cannot assign a resource group that you create for an external component to a role.
LOGIN
privilege can be assigned to a resource queue. The special keyword
NONE
means that the role is assigned to the default resource queue. A role can only belong to one resource queue.
Roles with the SUPERUSER
attribute are exempt from resource queue limits. For a superuser role, queries always run immediately regardless of limits imposed by an assigned resource queue.
DENY
and
DENY BETWEEN
keywords set time-based constraints that are enforced at login.
DENY
sets a day or a day and time to deny access.
DENY BETWEEN
sets an interval during which access is denied. Both use the parameter deny_point that has the following format:
DAY day [ TIME 'time' ]
The two parts of the deny_point
parameter use the following formats:
For day
:
{'Sunday' | 'Monday' | 'Tuesday' |'Wednesday' | 'Thursday' | 'Friday' |
'Saturday' | 0-6 }
For time
:
{ 00-23 : 00-59 | 01-12 : 00-59 { AM | PM }}
The DENY BETWEEN
clause uses two deny_point parameters:
DENY BETWEEN <deny_point> AND <deny_point>
Use ALTER ROLE to change the attributes of a role, and DROP ROLE to remove a role. All the attributes specified by CREATE ROLE
can be modified by later ALTER ROLE
commands.
The preferred way to add and remove role members of roles is to use GRANT and REVOKE.
The VALID UNTIL
clause defines an expiration time for a password only, not for the role per se. The expiration time is not enforced when logging in using a non-password-based authentication method.
The INHERIT
attribute governs inheritance of grantable privileges (access privileges for database objects and role memberships). It does not apply to the special role attributes set by CREATE ROLE
and ALTER ROLE
. For example, being a member of a role with CREATEDB
privilege does not immediately grant the ability to create databases, even if INHERIT
is set; it would be necessary to become that role via SET ROLE before creating a database.
The INHERIT
attribute is the default for reasons of backwards compatibility. In prior releases of Greenplum Database, users always had access to all privileges of groups they were members of. However, NOINHERIT
provides a closer match to the semantics specified in the SQL standard.
Be careful with the CREATEROLE
privilege. There is no concept of inheritance for the privileges of a CREATEROLE
-role. That means that even if a role does not have a certain privilege but is allowed to create other roles, it can easily create another role with different privileges than its own (except for creating roles with superuser privileges). For example, if a role has the CREATEROLE
privilege but not the CREATEDB
privilege, it can create a new role with the CREATEDB
privilege. Therefore, regard roles that have the CREATEROLE
privilege as almost-superuser-roles.
Greenplum Database includes a program createuser that has the same functionality as CREATE ROLE
(in fact, it calls this command) but can be run from the command shell.
The CONNECTION LIMIT
option is only enforced approximately; if two new sessions start at about the same time when just one connection “slot” remains for the role, it is possible that both will fail. Also, the limit is never enforced for superusers.
You must exercise caution when specifying an unencrypted password with this command. The password will be transmitted to the server in clear-text, and it might also be logged in the client’s command history or the server log. The client program createuser, however, transmits the password encrypted. Also, psql contains a command \password
that can be used to safely change the password later.
Create a role that can log in, but don’t give it a password:
CREATE ROLE jonathan LOGIN;
Create a role with a password:
CREATE USER davide WITH PASSWORD 'jw8s0F4';
(CREATE USER
is the same as CREATE ROLE
except that it implies LOGIN
.)
Create a role with a password that is valid until the end of 2022:
CREATE USER joelle WITH LOGIN PASSWORD 'jw8s0F4' VALID UNTIL '2023-01-01';
Create a role that can create databases and manage other roles:
CREATE ROLE admin WITH CREATEDB CREATEROLE;
Create a role that does not allow login access on Sundays:
CREATE ROLE user3 DENY DAY 'Sunday';
Create a role that can create readable and writable external tables of type ‘gpfdist’:
CREATE ROLE jan WITH CREATEEXTTABLE(type='readable', protocol='gpfdist')
CREATEEXTTABLE(type='writable', protocol='gpfdist');
Create a role, assigning a resource group:
CREATE ROLE bill RESOURCE GROUP rg_light;
Create a role that belongs to a resource queue:
CREATE ROLE jonathan LOGIN RESOURCE QUEUE poweruser;
CREATE ROLE
is in the SQL standard, but the standard only requires the syntax:
CREATE ROLE <name> [WITH ADMIN <rolename>]
Allowing multiple initial administrators, and all the other options of CREATE ROLE
, are Greenplum Database extensions.
The SQL standard defines the concepts of users and roles, but it regards them as distinct concepts and leaves all commands defining users to be specified by the database implementation. In Greenplum Database users and roles are unified into a single type of object. Roles therefore have many more optional attributes than they do in the standard.
The behavior specified by the SQL standard is most closely approximated by giving users the NOINHERIT
attribute, while roles are given the INHERIT
attribute.
SET ROLE, ALTER ROLE, DROP ROLE, GRANT, REVOKE, CREATE RESOURCE QUEUE CREATE RESOURCE GROUP, createuser
Parent topic: SQL Commands