1CREATE ROLE(7) PostgreSQL 13.3 Documentation CREATE ROLE(7)
2
3
4
6 CREATE_ROLE - define a new database role
7
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
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
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. You must be a superuser to create a new role having
100 the REPLICATION attribute.
101
102 BYPASSRLS
103 NOBYPASSRLS
104 These clauses determine whether a role bypasses every row-level
105 security (RLS) policy. NOBYPASSRLS is the default. You must be a
106 superuser to create a new role having the BYPASSRLS attribute.
107
108 Note that pg_dump will set row_security to OFF by default, to
109 ensure all contents of a table are dumped out. If the user running
110 pg_dump does not have appropriate permissions, an error will be
111 returned. However, superusers and the owner of the table being
112 dumped always bypass RLS.
113
114 CONNECTION LIMIT connlimit
115 If role can log in, this specifies how many concurrent connections
116 the role can make. -1 (the default) means no limit. Note that only
117 normal connections are counted towards this limit. Neither prepared
118 transactions nor background worker connections are counted towards
119 this limit.
120
121 [ ENCRYPTED ] PASSWORD 'password'
122 PASSWORD NULL
123 Sets the role's password. (A password is only of use for roles
124 having the LOGIN attribute, but you can nonetheless define one for
125 roles without it.) If you do not plan to use password
126 authentication you can omit this option. If no password is
127 specified, the password will be set to null and password
128 authentication will always fail for that user. A null password can
129 optionally be written explicitly as PASSWORD NULL.
130
131 Note
132 Specifying an empty string will also set the password to null,
133 but that was not the case before PostgreSQL version 10. In
134 earlier versions, an empty string could be used, or not,
135 depending on the authentication method and the exact version,
136 and libpq would refuse to use it in any case. To avoid the
137 ambiguity, specifying an empty string should be avoided.
138 The password is always stored encrypted in the system catalogs. The
139 ENCRYPTED keyword has no effect, but is accepted for backwards
140 compatibility. The method of encryption is determined by the
141 configuration parameter password_encryption. If the presented
142 password string is already in MD5-encrypted or SCRAM-encrypted
143 format, then it is stored as-is regardless of password_encryption
144 (since the system cannot decrypt the specified encrypted password
145 string, to encrypt it in a different format). This allows reloading
146 of encrypted passwords during dump/restore.
147
148 VALID UNTIL 'timestamp'
149 The VALID UNTIL clause sets a date and time after which the role's
150 password is no longer valid. If this clause is omitted the password
151 will be valid for all time.
152
153 IN ROLE role_name
154 The IN ROLE clause lists one or more existing roles to which the
155 new role will be immediately added as a new member. (Note that
156 there is no option to add the new role as an administrator; use a
157 separate GRANT command to do that.)
158
159 IN GROUP role_name
160 IN GROUP is an obsolete spelling of IN ROLE.
161
162 ROLE role_name
163 The ROLE clause lists one or more existing roles which are
164 automatically added as members of the new role. (This in effect
165 makes the new role a “group”.)
166
167 ADMIN role_name
168 The ADMIN clause is like ROLE, but the named roles are added to the
169 new role WITH ADMIN OPTION, giving them the right to grant
170 membership in this role to others.
171
172 USER role_name
173 The USER clause is an obsolete spelling of the ROLE clause.
174
175 SYSID uid
176 The SYSID clause is ignored, but is accepted for backwards
177 compatibility.
178
180 Use ALTER ROLE (ALTER_ROLE(7)) to change the attributes of a role, and
181 DROP ROLE (DROP_ROLE(7)) to remove a role. All the attributes specified
182 by CREATE ROLE can be modified by later ALTER ROLE commands.
183
184 The preferred way to add and remove members of roles that are being
185 used as groups is to use GRANT(7) and REVOKE(7).
186
187 The VALID UNTIL clause defines an expiration time for a password only,
188 not for the role per se. In particular, the expiration time is not
189 enforced when logging in using a non-password-based authentication
190 method.
191
192 The INHERIT attribute governs inheritance of grantable privileges (that
193 is, access privileges for database objects and role memberships). It
194 does not apply to the special role attributes set by CREATE ROLE and
195 ALTER ROLE. For example, being a member of a role with CREATEDB
196 privilege does not immediately grant the ability to create databases,
197 even if INHERIT is set; it would be necessary to become that role via
198 SET ROLE (SET_ROLE(7)) before creating a database.
199
200 The INHERIT attribute is the default for reasons of backwards
201 compatibility: in prior releases of PostgreSQL, users always had access
202 to all privileges of groups they were members of. However, NOINHERIT
203 provides a closer match to the semantics specified in the SQL standard.
204
205 Be careful with the CREATEROLE privilege. There is no concept of
206 inheritance for the privileges of a CREATEROLE-role. That means that
207 even if a role does not have a certain privilege but is allowed to
208 create other roles, it can easily create another role with different
209 privileges than its own (except for creating roles with superuser
210 privileges). For example, if the role “user” has the CREATEROLE
211 privilege but not the CREATEDB privilege, nonetheless it can create a
212 new role with the CREATEDB privilege. Therefore, regard roles that have
213 the CREATEROLE privilege as almost-superuser-roles.
214
215 PostgreSQL includes a program createuser(1) that has the same
216 functionality as CREATE ROLE (in fact, it calls this command) but can
217 be run from the command shell.
218
219 The CONNECTION LIMIT option is only enforced approximately; if two new
220 sessions start at about the same time when just one connection “slot”
221 remains for the role, it is possible that both will fail. Also, the
222 limit is never enforced for superusers.
223
224 Caution must be exercised when specifying an unencrypted password with
225 this command. The password will be transmitted to the server in
226 cleartext, and it might also be logged in the client's command history
227 or the server log. The command createuser(1), however, transmits the
228 password encrypted. Also, psql(1) contains a command \password that can
229 be used to safely change the password later.
230
232 Create a role that can log in, but don't give it a password:
233
234 CREATE ROLE jonathan LOGIN;
235
236 Create a role with a password:
237
238 CREATE USER davide WITH PASSWORD 'jw8s0F4';
239
240 (CREATE USER is the same as CREATE ROLE except that it implies LOGIN.)
241
242 Create a role with a password that is valid until the end of 2004.
243 After one second has ticked in 2005, the password is no longer valid.
244
245 CREATE ROLE miriam WITH LOGIN PASSWORD 'jw8s0F4' VALID UNTIL '2005-01-01';
246
247 Create a role that can create databases and manage roles:
248
249 CREATE ROLE admin WITH CREATEDB CREATEROLE;
250
252 The CREATE ROLE statement is in the SQL standard, but the standard only
253 requires the syntax
254
255 CREATE ROLE name [ WITH ADMIN role_name ]
256
257 Multiple initial administrators, and all the other options of CREATE
258 ROLE, are PostgreSQL extensions.
259
260 The SQL standard defines the concepts of users and roles, but it
261 regards them as distinct concepts and leaves all commands defining
262 users to be specified by each database implementation. In PostgreSQL we
263 have chosen to unify users and roles into a single kind of entity.
264 Roles therefore have many more optional attributes than they do in the
265 standard.
266
267 The behavior specified by the SQL standard is most closely approximated
268 by giving users the NOINHERIT attribute, while roles are given the
269 INHERIT attribute.
270
272 SET ROLE (SET_ROLE(7)), ALTER ROLE (ALTER_ROLE(7)), DROP ROLE
273 (DROP_ROLE(7)), GRANT(7), REVOKE(7), createuser(1)
274
275
276
277PostgreSQL 13.3 2021 CREATE ROLE(7)