1CREATE ROLE(7)           PostgreSQL 16.1 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' | PASSWORD NULL
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 22 and Chapter 21 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. Only superuser roles or roles with CREATEDB can specify
60           CREATEDB.
61
62       CREATEROLE
63       NOCREATEROLE
64           These clauses determine whether a role will be permitted to create,
65           alter, drop, comment on, and change the security label for other
66           roles. See role creation for more details about what capabilities
67           are conferred by this privilege. If not specified, NOCREATEROLE is
68           the default.
69
70       INHERIT
71       NOINHERIT
72           When the GRANT statement is used to confer membership in one role
73           to another role, the GRANT may use the WITH INHERIT clause to
74           specify whether the privileges of the granted role should be
75           “inherited” by the new member. If the GRANT statement does not
76           specify either inheritance behavior, the new GRANT will be created
77           WITH INHERIT TRUE if the member role is set to INHERIT and to WITH
78           INHERIT FALSE if it is set to NOINHERIT.
79
80           In PostgreSQL versions before 16, the GRANT statement did not
81           support WITH INHERIT. Therefore, changing this role-level property
82           would also change the behavior of already-existing grants. This is
83           no longer the case.
84
85       LOGIN
86       NOLOGIN
87           These clauses determine whether a role is allowed to log in; that
88           is, whether the role can be given as the initial session
89           authorization name during client connection. A role having the
90           LOGIN attribute can be thought of as a user. Roles without this
91           attribute are useful for managing database privileges, but are not
92           users in the usual sense of the word. If not specified, NOLOGIN is
93           the default, except when CREATE ROLE is invoked through its
94           alternative spelling CREATE USER.
95
96       REPLICATION
97       NOREPLICATION
98           These clauses determine whether a role is a replication role. A
99           role must have this attribute (or be a superuser) in order to be
100           able to connect to the server in replication mode (physical or
101           logical replication) and in order to be able to create or drop
102           replication slots. A role having the REPLICATION attribute is a
103           very highly privileged role, and should only be used on roles
104           actually used for replication. If not specified, NOREPLICATION is
105           the default. Only superuser roles or roles with REPLICATION can
106           specify REPLICATION.
107
108       BYPASSRLS
109       NOBYPASSRLS
110           These clauses determine whether a role bypasses every row-level
111           security (RLS) policy.  NOBYPASSRLS is the default. Only superuser
112           roles or roles with BYPASSRLS can specify BYPASSRLS.
113
114           Note that pg_dump will set row_security to OFF by default, to
115           ensure all contents of a table are dumped out. If the user running
116           pg_dump does not have appropriate permissions, an error will be
117           returned. However, superusers and the owner of the table being
118           dumped always bypass RLS.
119
120       CONNECTION LIMIT connlimit
121           If role can log in, this specifies how many concurrent connections
122           the role can make. -1 (the default) means no limit. Note that only
123           normal connections are counted towards this limit. Neither prepared
124           transactions nor background worker connections are counted towards
125           this limit.
126
127       [ ENCRYPTED ] PASSWORD 'password'
128       PASSWORD NULL
129           Sets the role's password. (A password is only of use for roles
130           having the LOGIN attribute, but you can nonetheless define one for
131           roles without it.) If you do not plan to use password
132           authentication you can omit this option. If no password is
133           specified, the password will be set to null and password
134           authentication will always fail for that user. A null password can
135           optionally be written explicitly as PASSWORD NULL.
136
137               Note
138               Specifying an empty string will also set the password to null,
139               but that was not the case before PostgreSQL version 10. In
140               earlier versions, an empty string could be used, or not,
141               depending on the authentication method and the exact version,
142               and libpq would refuse to use it in any case. To avoid the
143               ambiguity, specifying an empty string should be avoided.
144           The password is always stored encrypted in the system catalogs. The
145           ENCRYPTED keyword has no effect, but is accepted for backwards
146           compatibility. The method of encryption is determined by the
147           configuration parameter password_encryption. If the presented
148           password string is already in MD5-encrypted or SCRAM-encrypted
149           format, then it is stored as-is regardless of password_encryption
150           (since the system cannot decrypt the specified encrypted password
151           string, to encrypt it in a different format). This allows reloading
152           of encrypted passwords during dump/restore.
153
154       VALID UNTIL 'timestamp'
155           The VALID UNTIL clause sets a date and time after which the role's
156           password is no longer valid. If this clause is omitted the password
157           will be valid for all time.
158
159       IN ROLE role_name
160           The IN ROLE clause causes the new role to be automatically added as
161           a member of the specified existing roles. (Note that there is no
162           option to add the new role as an administrator; use a separate
163           GRANT command to do that.)
164
165       IN GROUP role_name
166           IN GROUP is an obsolete spelling of IN ROLE.
167
168       ROLE role_name
169           The ROLE clause causes one or more specified existing roles to be
170           automatically added as members of the new role. This in effect
171           makes the new role a “group”.
172
173       ADMIN role_name
174           The ADMIN clause is like ROLE, but the named roles are added to the
175           new role WITH ADMIN OPTION, giving them the right to grant
176           membership in this role to others.
177
178       USER role_name
179           The USER clause is an obsolete spelling of the ROLE clause.
180
181       SYSID uid
182           The SYSID clause is ignored, but is accepted for backwards
183           compatibility.
184

NOTES

186       Use ALTER ROLE to change the attributes of a role, and DROP ROLE to
187       remove a role. All the attributes specified by CREATE ROLE can be
188       modified by later ALTER ROLE commands.
189
190       The preferred way to add and remove members of roles that are being
191       used as groups is to use GRANT and REVOKE.
192
193       The VALID UNTIL clause defines an expiration time for a password only,
194       not for the role per se. In particular, the expiration time is not
195       enforced when logging in using a non-password-based authentication
196       method.
197
198       The INHERIT attribute governs inheritance of grantable privileges (that
199       is, access privileges for database objects and role memberships). It
200       does not apply to the special role attributes set by CREATE ROLE and
201       ALTER ROLE. For example, being a member of a role with CREATEDB
202       privilege does not immediately grant the ability to create databases,
203       even if INHERIT is set; it would be necessary to become that role via
204       SET ROLE before creating a database.
205
206       The INHERIT attribute is the default for reasons of backwards
207       compatibility: in prior releases of PostgreSQL, users always had access
208       to all privileges of groups they were members of. However, NOINHERIT
209       provides a closer match to the semantics specified in the SQL standard.
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       createrole_self_grant
271
272
273
274PostgreSQL 16.1                      2023                       CREATE ROLE(7)
Impressum