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