1CREATE ROLE(7)           PostgreSQL 10.7 Documentation          CREATE ROLE(7)
2
3
4

NAME

6       CREATE_ROLE - define a new database role
7

SYNOPSIS

9       CREATE ROLE name [ [ WITH ] option [ ... ] ]
10
11       where option can be:
12
13             SUPERUSER | NOSUPERUSER
14           | CREATEDB | NOCREATEDB
15           | CREATEROLE | NOCREATEROLE
16           | INHERIT | NOINHERIT
17           | LOGIN | NOLOGIN
18           | REPLICATION | NOREPLICATION
19           | BYPASSRLS | NOBYPASSRLS
20           | CONNECTION LIMIT connlimit
21           | [ ENCRYPTED ] PASSWORD 'password'
22           | VALID UNTIL 'timestamp'
23           | IN ROLE role_name [, ...]
24           | IN GROUP role_name [, ...]
25           | ROLE role_name [, ...]
26           | ADMIN role_name [, ...]
27           | USER role_name [, ...]
28           | SYSID uid
29

DESCRIPTION

31       CREATE ROLE adds a new role to a PostgreSQL database cluster. A role is
32       an entity that can own database objects and have database privileges; a
33       role can be considered a “user”, a “group”, or both depending on how it
34       is used. Refer to Chapter 21 and Chapter 20 for information about
35       managing users and authentication. You must have CREATEROLE privilege
36       or be a database superuser to use this command.
37
38       Note that roles are defined at the database cluster level, and so are
39       valid in all databases in the cluster.
40

PARAMETERS

42       name
43           The name of the new role.
44
45       SUPERUSER
46       NOSUPERUSER
47           These clauses determine whether the new role is a “superuser”, who
48           can override all access restrictions within the database. Superuser
49           status is dangerous and should be used only when really needed. You
50           must yourself be a superuser to create a new superuser. If not
51           specified, NOSUPERUSER is the default.
52
53       CREATEDB
54       NOCREATEDB
55           These clauses define a role's ability to create databases. If
56           CREATEDB is specified, the role being defined will be allowed to
57           create new databases. Specifying NOCREATEDB will deny a role the
58           ability to create databases. If not specified, NOCREATEDB is the
59           default.
60
61       CREATEROLE
62       NOCREATEROLE
63           These clauses determine whether a role will be permitted to create
64           new roles (that is, execute CREATE ROLE). A role with CREATEROLE
65           privilege can also alter and drop other roles. If not specified,
66           NOCREATEROLE is the default.
67
68       INHERIT
69       NOINHERIT
70           These clauses determine whether a role “inherits” the privileges of
71           roles it is a member of. A role with the INHERIT attribute can
72           automatically use whatever database privileges have been granted to
73           all roles it is directly or indirectly a member of. Without
74           INHERIT, membership in another role only grants the ability to SET
75           ROLE to that other role; the privileges of the other role are only
76           available after having done so. If not specified, INHERIT is the
77           default.
78
79       LOGIN
80       NOLOGIN
81           These clauses determine whether a role is allowed to log in; that
82           is, whether the role can be given as the initial session
83           authorization name during client connection. A role having the
84           LOGIN attribute can be thought of as a user. Roles without this
85           attribute are useful for managing database privileges, but are not
86           users in the usual sense of the word. If not specified, NOLOGIN is
87           the default, except when CREATE ROLE is invoked through its
88           alternative spelling CREATE USER (CREATE_USER(7)).
89
90       REPLICATION
91       NOREPLICATION
92           These clauses determine whether a role is a replication role. A
93           role must have this attribute (or be a superuser) in order to be
94           able to connect to the server in replication mode (physical or
95           logical replication) and in order to be able to create or drop
96           replication slots. A role having the REPLICATION attribute is a
97           very highly privileged role, and should only be used on roles
98           actually used for replication. If not specified, NOREPLICATION is
99           the default.
100
101       BYPASSRLS
102       NOBYPASSRLS
103           These clauses determine whether a role bypasses every row-level
104           security (RLS) policy.  NOBYPASSRLS is the default. Note that
105           pg_dump will set row_security to OFF by default, to ensure all
106           contents of a table are dumped out. If the user running pg_dump
107           does not have appropriate permissions, an error will be returned.
108           The superuser and owner of the table being dumped always bypass
109           RLS.
110
111       CONNECTION LIMIT connlimit
112           If role can log in, this specifies how many concurrent connections
113           the role can make. -1 (the default) means no limit. Note that only
114           normal connections are counted towards this limit. Neither prepared
115           transactions nor background worker connections are counted towards
116           this limit.
117
118       [ ENCRYPTED ] PASSWORD password
119           Sets the role's password. (A password is only of use for roles
120           having the LOGIN attribute, but you can nonetheless define one for
121           roles without it.) If you do not plan to use password
122           authentication you can omit this option. If no password is
123           specified, the password will be set to null and password
124           authentication will always fail for that user. A null password can
125           optionally be written explicitly as PASSWORD NULL.
126
127               Note
128               Specifying an empty string will also set the password to null,
129               but that was not the case before PostgreSQL version 10. In
130               earlier versions, an empty string could be used, or not,
131               depending on the authentication method and the exact version,
132               and libpq would refuse to use it in any case. To avoid the
133               ambiguity, specifying an empty string should be avoided.
134           The password is always stored encrypted in the system catalogs. The
135           ENCRYPTED keyword has no effect, but is accepted for backwards
136           compatibility. The method of encryption is determined by the
137           configuration parameter password_encryption. If the presented
138           password string is already in MD5-encrypted or SCRAM-encrypted
139           format, then it is stored as-is regardless of password_encryption
140           (since the system cannot decrypt the specified encrypted password
141           string, to encrypt it in a different format). This allows reloading
142           of encrypted passwords during dump/restore.
143
144       VALID UNTIL 'timestamp'
145           The VALID UNTIL clause sets a date and time after which the role's
146           password is no longer valid. If this clause is omitted the password
147           will be valid for all time.
148
149       IN ROLE role_name
150           The IN ROLE clause lists one or more existing roles to which the
151           new role will be immediately added as a new member. (Note that
152           there is no option to add the new role as an administrator; use a
153           separate GRANT command to do that.)
154
155       IN GROUP role_name
156           IN GROUP is an obsolete spelling of IN ROLE.
157
158       ROLE role_name
159           The ROLE clause lists one or more existing roles which are
160           automatically added as members of the new role. (This in effect
161           makes the new role a “group”.)
162
163       ADMIN role_name
164           The ADMIN clause is like ROLE, but the named roles are added to the
165           new role WITH ADMIN OPTION, giving them the right to grant
166           membership in this role to others.
167
168       USER role_name
169           The USER clause is an obsolete spelling of the ROLE clause.
170
171       SYSID uid
172           The SYSID clause is ignored, but is accepted for backwards
173           compatibility.
174

NOTES

176       Use ALTER ROLE (ALTER_ROLE(7)) to change the attributes of a role, and
177       DROP ROLE (DROP_ROLE(7)) to remove a role. All the attributes specified
178       by CREATE ROLE can be modified by later ALTER ROLE commands.
179
180       The preferred way to add and remove members of roles that are being
181       used as groups is to use GRANT(7) and REVOKE(7).
182
183       The VALID UNTIL clause defines an expiration time for a password only,
184       not for the role per se. In particular, the expiration time is not
185       enforced when logging in using a non-password-based authentication
186       method.
187
188       The INHERIT attribute governs inheritance of grantable privileges (that
189       is, access privileges for database objects and role memberships). It
190       does not apply to the special role attributes set by CREATE ROLE and
191       ALTER ROLE. For example, being a member of a role with CREATEDB
192       privilege does not immediately grant the ability to create databases,
193       even if INHERIT is set; it would be necessary to become that role via
194       SET ROLE (SET_ROLE(7)) before creating a database.
195
196       The INHERIT attribute is the default for reasons of backwards
197       compatibility: in prior releases of PostgreSQL, users always had access
198       to all privileges of groups they were members of. However, NOINHERIT
199       provides a closer match to the semantics specified in the SQL standard.
200
201       Be careful with the CREATEROLE privilege. There is no concept of
202       inheritance for the privileges of a CREATEROLE-role. That means that
203       even if a role does not have a certain privilege but is allowed to
204       create other roles, it can easily create another role with different
205       privileges than its own (except for creating roles with superuser
206       privileges). For example, if the role “user” has the CREATEROLE
207       privilege but not the CREATEDB privilege, nonetheless it can create a
208       new role with the CREATEDB privilege. Therefore, regard roles that have
209       the CREATEROLE privilege as almost-superuser-roles.
210
211       PostgreSQL includes a program createuser(1) that has the same
212       functionality as CREATE ROLE (in fact, it calls this command) but can
213       be run from the command shell.
214
215       The CONNECTION LIMIT option is only enforced approximately; if two new
216       sessions start at about the same time when just one connection “slot”
217       remains for the role, it is possible that both will fail. Also, the
218       limit is never enforced for superusers.
219
220       Caution must be exercised when specifying an unencrypted password with
221       this command. The password will be transmitted to the server in
222       cleartext, and it might also be logged in the client's command history
223       or the server log. The command createuser(1), however, transmits the
224       password encrypted. Also, psql(1) contains a command \password that can
225       be used to safely change the password later.
226

EXAMPLES

228       Create a role that can log in, but don't give it a password:
229
230           CREATE ROLE jonathan LOGIN;
231
232       Create a role with a password:
233
234           CREATE USER davide WITH PASSWORD 'jw8s0F4';
235
236       (CREATE USER is the same as CREATE ROLE except that it implies LOGIN.)
237
238       Create a role with a password that is valid until the end of 2004.
239       After one second has ticked in 2005, the password is no longer valid.
240
241           CREATE ROLE miriam WITH LOGIN PASSWORD 'jw8s0F4' VALID UNTIL '2005-01-01';
242
243       Create a role that can create databases and manage roles:
244
245           CREATE ROLE admin WITH CREATEDB CREATEROLE;
246

COMPATIBILITY

248       The CREATE ROLE statement is in the SQL standard, but the standard only
249       requires the syntax
250
251           CREATE ROLE name [ WITH ADMIN role_name ]
252
253       Multiple initial administrators, and all the other options of CREATE
254       ROLE, are PostgreSQL extensions.
255
256       The SQL standard defines the concepts of users and roles, but it
257       regards them as distinct concepts and leaves all commands defining
258       users to be specified by each database implementation. In PostgreSQL we
259       have chosen to unify users and roles into a single kind of entity.
260       Roles therefore have many more optional attributes than they do in the
261       standard.
262
263       The behavior specified by the SQL standard is most closely approximated
264       by giving users the NOINHERIT attribute, while roles are given the
265       INHERIT attribute.
266

SEE ALSO

268       SET ROLE (SET_ROLE(7)), ALTER ROLE (ALTER_ROLE(7)), DROP ROLE
269       (DROP_ROLE(7)), GRANT(7), REVOKE(7), createuser(1)
270
271
272
273PostgreSQL 10.7                      2019                       CREATE ROLE(7)
Impressum