1<!--
2doc/src/sgml/ref/create_role.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-createrole">
7 <indexterm zone="sql-createrole">
8  <primary>CREATE ROLE</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>CREATE ROLE</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>CREATE ROLE</refname>
19  <refpurpose>define a new database role</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24CREATE ROLE <replaceable class="parameter">name</replaceable> [ [ WITH ] <replaceable class="parameter">option</replaceable> [ ... ] ]
25
26<phrase>where <replaceable class="parameter">option</replaceable> can be:</phrase>
27
28      SUPERUSER | NOSUPERUSER
29    | CREATEDB | NOCREATEDB
30    | CREATEROLE | NOCREATEROLE
31    | INHERIT | NOINHERIT
32    | LOGIN | NOLOGIN
33    | REPLICATION | NOREPLICATION
34    | BYPASSRLS | NOBYPASSRLS
35    | CONNECTION LIMIT <replaceable class="parameter">connlimit</replaceable>
36    | [ ENCRYPTED ] PASSWORD '<replaceable class="parameter">password</replaceable>' | PASSWORD NULL
37    | VALID UNTIL '<replaceable class="parameter">timestamp</replaceable>'
38    | IN ROLE <replaceable class="parameter">role_name</replaceable> [, ...]
39    | IN GROUP <replaceable class="parameter">role_name</replaceable> [, ...]
40    | ROLE <replaceable class="parameter">role_name</replaceable> [, ...]
41    | ADMIN <replaceable class="parameter">role_name</replaceable> [, ...]
42    | USER <replaceable class="parameter">role_name</replaceable> [, ...]
43    | SYSID <replaceable class="parameter">uid</replaceable>
44</synopsis>
45 </refsynopsisdiv>
46
47<!--
48CAUTION: remember to keep create_user.sgml and create_group.sgml
49in sync when changing the above synopsis!
50-->
51
52 <refsect1>
53  <title>Description</title>
54
55  <para>
56   <command>CREATE ROLE</command> adds a new role to a
57   <productname>PostgreSQL</productname> database cluster.  A role is
58   an entity that can own database objects and have database privileges;
59   a role can be considered a <quote>user</quote>, a <quote>group</quote>, or both
60   depending on how it is used.  Refer to
61   <xref linkend="user-manag"/> and <xref
62   linkend="client-authentication"/> for information about managing
63   users and authentication.  You must have <literal>CREATEROLE</literal>
64   privilege or be a database superuser to use this command.
65  </para>
66
67  <para>
68   Note that roles are defined at the database cluster
69   level, and so are valid in all databases in the cluster.
70  </para>
71 </refsect1>
72
73 <refsect1>
74  <title>Parameters</title>
75
76    <variablelist>
77     <varlistentry>
78      <term><replaceable class="parameter">name</replaceable></term>
79      <listitem>
80       <para>
81        The name of the new role.
82       </para>
83      </listitem>
84     </varlistentry>
85
86     <varlistentry>
87      <term><literal>SUPERUSER</literal></term>
88      <term><literal>NOSUPERUSER</literal></term>
89      <listitem>
90       <para>
91        These clauses determine whether the new role is a <quote>superuser</quote>,
92        who can override all access restrictions within the database.
93        Superuser status is dangerous and should be used only when really
94        needed.  You must yourself be a superuser to create a new superuser.
95        If not specified,
96        <literal>NOSUPERUSER</literal> is the default.
97       </para>
98      </listitem>
99     </varlistentry>
100
101     <varlistentry>
102      <term><literal>CREATEDB</literal></term>
103      <term><literal>NOCREATEDB</literal></term>
104      <listitem>
105       <para>
106        These clauses define a role's ability to create databases.  If
107        <literal>CREATEDB</literal> is specified, the role being
108        defined will be allowed to create new databases. Specifying
109        <literal>NOCREATEDB</literal> will deny a role the ability to
110        create databases. If not specified,
111        <literal>NOCREATEDB</literal> is the default.
112       </para>
113      </listitem>
114     </varlistentry>
115
116     <varlistentry>
117      <term><literal>CREATEROLE</literal></term>
118      <term><literal>NOCREATEROLE</literal></term>
119      <listitem>
120       <para>
121        These clauses determine whether a role will be permitted to
122        create new roles (that is, execute <command>CREATE ROLE</command>).
123        A role with <literal>CREATEROLE</literal> privilege can also alter
124        and drop other roles.
125        If not specified,
126        <literal>NOCREATEROLE</literal> is the default.
127       </para>
128      </listitem>
129     </varlistentry>
130
131     <varlistentry>
132      <term><literal>INHERIT</literal></term>
133      <term><literal>NOINHERIT</literal></term>
134      <listitem>
135       <para>
136        These clauses determine whether a role <quote>inherits</quote> the
137        privileges of roles it is a member of.
138        A role with the <literal>INHERIT</literal> attribute can automatically
139        use whatever database privileges have been granted to all roles
140        it is directly or indirectly a member of.
141        Without <literal>INHERIT</literal>, membership in another role
142        only grants the ability to <command>SET ROLE</command> to that other role;
143        the privileges of the other role are only available after having
144        done so.
145        If not specified,
146        <literal>INHERIT</literal> is the default.
147       </para>
148      </listitem>
149     </varlistentry>
150
151     <varlistentry>
152      <term><literal>LOGIN</literal></term>
153      <term><literal>NOLOGIN</literal></term>
154      <listitem>
155       <para>
156        These clauses determine whether a role is allowed to log in;
157        that is, whether the role can be given as the initial session
158        authorization name during client connection.  A role having
159        the <literal>LOGIN</literal> attribute can be thought of as a user.
160        Roles without this attribute are useful for managing database
161        privileges, but are not users in the usual sense of the word.
162        If not specified,
163        <literal>NOLOGIN</literal> is the default, except when
164        <command>CREATE ROLE</command> is invoked through its alternative spelling
165        <xref linkend="sql-createuser"/>.
166       </para>
167      </listitem>
168     </varlistentry>
169
170     <varlistentry>
171      <term><literal>REPLICATION</literal></term>
172      <term><literal>NOREPLICATION</literal></term>
173      <listitem>
174       <para>
175        These clauses determine whether a role is a replication role.  A role
176        must have this attribute (or be a superuser) in order to be able to
177        connect to the server in replication mode (physical or logical
178        replication) and in order to be able to create or drop replication
179        slots.
180        A role having the <literal>REPLICATION</literal> attribute is a very
181        highly privileged role, and should only be used on roles actually
182        used for replication. If not specified,
183        <literal>NOREPLICATION</literal> is the default.
184        You must be a superuser to create a new role having the
185        <literal>REPLICATION</literal> attribute.
186       </para>
187      </listitem>
188     </varlistentry>
189
190     <varlistentry>
191      <term><literal>BYPASSRLS</literal></term>
192      <term><literal>NOBYPASSRLS</literal></term>
193      <listitem>
194       <para>
195        These clauses determine whether a role bypasses every row-level
196        security (RLS) policy.  <literal>NOBYPASSRLS</literal> is the default.
197        You must be a superuser to create a new role having
198        the <literal>BYPASSRLS</literal> attribute.
199       </para>
200
201       <para>
202        Note that pg_dump will set <literal>row_security</literal> to
203        <literal>OFF</literal> by default, to ensure all contents of a table are
204        dumped out.  If the user running pg_dump does not have appropriate
205        permissions, an error will be returned.  However, superusers and the
206        owner of the table being dumped always bypass RLS.
207       </para>
208      </listitem>
209     </varlistentry>
210
211     <varlistentry>
212      <term><literal>CONNECTION LIMIT</literal> <replaceable class="parameter">connlimit</replaceable></term>
213      <listitem>
214       <para>
215        If role can log in, this specifies how many concurrent connections
216        the role can make.  -1 (the default) means no limit. Note that only
217        normal connections are counted towards this limit. Neither prepared
218        transactions nor background worker connections are counted towards
219        this limit.
220       </para>
221      </listitem>
222     </varlistentry>
223
224     <varlistentry>
225      <term>[ <literal>ENCRYPTED</literal> ] <literal>PASSWORD</literal> '<replaceable class="parameter">password</replaceable>'</term>
226      <term><literal>PASSWORD NULL</literal></term>
227      <listitem>
228       <para>
229        Sets the role's password.  (A password is only of use for
230        roles having the <literal>LOGIN</literal> attribute, but you
231        can nonetheless define one for roles without it.)  If you do
232        not plan to use password authentication you can omit this
233        option.  If no password is specified, the password will be set
234        to null and password authentication will always fail for that
235        user.  A null password can optionally be written explicitly as
236        <literal>PASSWORD NULL</literal>.
237       </para>
238       <note>
239         <para>
240           Specifying an empty string will also set the password to null,
241           but that was not the case before <productname>PostgreSQL</productname>
242           version 10. In earlier versions, an empty string could be used,
243           or not, depending on the authentication method and the exact
244           version, and libpq would refuse to use it in any case.
245           To avoid the ambiguity, specifying an empty string should be
246           avoided.
247         </para>
248       </note>
249       <para>
250        The password is always stored encrypted in the system catalogs. The
251        <literal>ENCRYPTED</literal> keyword has no effect, but is accepted for
252        backwards compatibility. The method of encryption is determined
253        by the configuration parameter <xref linkend="guc-password-encryption"/>.
254        If the presented password string is already in MD5-encrypted or
255        SCRAM-encrypted format, then it is stored as-is regardless of
256        <varname>password_encryption</varname> (since the system cannot decrypt
257        the specified encrypted password string, to encrypt it in a
258        different format).  This allows reloading of encrypted passwords
259        during dump/restore.
260       </para>
261      </listitem>
262     </varlistentry>
263
264     <varlistentry>
265      <term><literal>VALID UNTIL</literal> '<replaceable class="parameter">timestamp</replaceable>'</term>
266      <listitem>
267       <para>
268        The <literal>VALID UNTIL</literal> clause sets a date and
269        time after which the role's password is no longer valid.  If
270        this clause is omitted the password will be valid for all time.
271       </para>
272      </listitem>
273     </varlistentry>
274
275     <varlistentry>
276      <term><literal>IN ROLE</literal> <replaceable class="parameter">role_name</replaceable></term>
277      <listitem>
278       <para>
279        The <literal>IN ROLE</literal> clause lists one or more existing
280        roles to which the new role will be immediately added as a new
281        member.  (Note that there is no option to add the new role as an
282        administrator; use a separate <command>GRANT</command> command to do that.)
283       </para>
284      </listitem>
285     </varlistentry>
286
287     <varlistentry>
288      <term><literal>IN GROUP</literal> <replaceable class="parameter">role_name</replaceable></term>
289      <listitem>
290       <para><literal>IN GROUP</literal> is an obsolete spelling of
291        <literal>IN ROLE</literal>.
292       </para>
293      </listitem>
294     </varlistentry>
295
296     <varlistentry>
297      <term><literal>ROLE</literal> <replaceable class="parameter">role_name</replaceable></term>
298      <listitem>
299       <para>
300        The <literal>ROLE</literal> clause lists one or more existing
301        roles which are automatically added as members of the new role.
302        (This in effect makes the new role a <quote>group</quote>.)
303       </para>
304      </listitem>
305     </varlistentry>
306
307     <varlistentry>
308      <term><literal>ADMIN</literal> <replaceable class="parameter">role_name</replaceable></term>
309      <listitem>
310       <para>
311        The <literal>ADMIN</literal> clause is like <literal>ROLE</literal>,
312        but the named roles are added to the new role <literal>WITH ADMIN
313        OPTION</literal>, giving them the right to grant membership in this role
314        to others.
315       </para>
316      </listitem>
317     </varlistentry>
318
319     <varlistentry>
320      <term><literal>USER</literal> <replaceable class="parameter">role_name</replaceable></term>
321      <listitem>
322       <para>
323        The <literal>USER</literal> clause is an obsolete spelling of
324        the <literal>ROLE</literal> clause.
325       </para>
326      </listitem>
327     </varlistentry>
328
329     <varlistentry>
330      <term><literal>SYSID</literal> <replaceable class="parameter">uid</replaceable></term>
331      <listitem>
332       <para>
333        The <literal>SYSID</literal> clause is ignored, but is accepted
334        for backwards compatibility.
335       </para>
336      </listitem>
337     </varlistentry>
338    </variablelist>
339 </refsect1>
340
341 <refsect1>
342  <title>Notes</title>
343
344  <para>
345   Use <xref linkend="sql-alterrole"/> to
346   change the attributes of a role, and <xref linkend="sql-droprole"/>
347   to remove a role.  All the attributes
348   specified by <command>CREATE ROLE</command> can be modified by later
349   <command>ALTER ROLE</command> commands.
350  </para>
351
352  <para>
353   The preferred way to add and remove members of roles that are being
354   used as groups is to use
355   <xref linkend="sql-grant"/> and
356   <xref linkend="sql-revoke"/>.
357  </para>
358
359  <para>
360   The <literal>VALID UNTIL</literal> clause defines an expiration time for a
361   password only, not for the role <foreignphrase>per se</foreignphrase>.  In
362   particular, the expiration time is not enforced when logging in using
363   a non-password-based authentication method.
364  </para>
365
366  <para>
367   The <literal>INHERIT</literal> attribute governs inheritance of grantable
368   privileges (that is, access privileges for database objects and role
369   memberships).  It does not apply to the special role attributes set by
370   <command>CREATE ROLE</command> and <command>ALTER ROLE</command>.  For example, being
371   a member of a role with <literal>CREATEDB</literal> privilege does not immediately
372   grant the ability to create databases, even if <literal>INHERIT</literal> is set;
373   it would be necessary to become that role via
374   <xref linkend="sql-set-role"/> before
375   creating a database.
376  </para>
377
378  <para>
379   The <literal>INHERIT</literal> attribute is the default for reasons of backwards
380   compatibility: in prior releases of <productname>PostgreSQL</productname>,
381   users always had access to all privileges of groups they were members of.
382   However, <literal>NOINHERIT</literal> provides a closer match to the semantics
383   specified in the SQL standard.
384  </para>
385
386  <para>
387   Be careful with the <literal>CREATEROLE</literal> privilege. There is no concept of
388   inheritance for the privileges of a <literal>CREATEROLE</literal>-role. That
389   means that even if a role does not have a certain privilege but is allowed
390   to create other roles, it can easily create another role with different
391   privileges than its own (except for creating roles with superuser
392   privileges). For example, if the role <quote>user</quote> has the
393   <literal>CREATEROLE</literal> privilege but not the <literal>CREATEDB</literal> privilege,
394   nonetheless it can create a new role with the <literal>CREATEDB</literal>
395   privilege. Therefore, regard roles that have the <literal>CREATEROLE</literal>
396   privilege as almost-superuser-roles.
397  </para>
398
399  <para>
400   <productname>PostgreSQL</productname> includes a program <xref
401   linkend="app-createuser"/> that has
402   the same functionality as <command>CREATE ROLE</command> (in fact,
403   it calls this command) but can be run from the command shell.
404  </para>
405
406  <para>
407   The <literal>CONNECTION LIMIT</literal> option is only enforced approximately;
408   if two new sessions start at about the same time when just one
409   connection <quote>slot</quote> remains for the role, it is possible that
410   both will fail.  Also, the limit is never enforced for superusers.
411  </para>
412
413  <para>
414   Caution must be exercised when specifying an unencrypted password
415   with this command.  The password will be transmitted to the server
416   in cleartext, and it might also be logged in the client's command
417   history or the server log.  The command <xref
418   linkend="app-createuser"/>, however, transmits
419   the password encrypted.  Also, <xref linkend="app-psql"/>
420   contains a command
421   <command>\password</command> that can be used to safely change the
422   password later.
423  </para>
424 </refsect1>
425
426 <refsect1>
427  <title>Examples</title>
428
429  <para>
430   Create a role that can log in, but don't give it a password:
431<programlisting>
432CREATE ROLE jonathan LOGIN;
433</programlisting>
434  </para>
435
436  <para>
437   Create a role with a password:
438<programlisting>
439CREATE USER davide WITH PASSWORD 'jw8s0F4';
440</programlisting>
441   (<command>CREATE USER</command> is the same as <command>CREATE ROLE</command> except
442   that it implies <literal>LOGIN</literal>.)
443  </para>
444
445  <para>
446   Create a role with a password that is valid until the end of 2004.
447   After one second has ticked in 2005, the password is no longer
448   valid.
449
450<programlisting>
451CREATE ROLE miriam WITH LOGIN PASSWORD 'jw8s0F4' VALID UNTIL '2005-01-01';
452</programlisting>
453  </para>
454
455  <para>
456   Create a role that can create databases and manage roles:
457<programlisting>
458CREATE ROLE admin WITH CREATEDB CREATEROLE;
459</programlisting></para>
460 </refsect1>
461
462 <refsect1>
463  <title>Compatibility</title>
464
465  <para>
466   The <command>CREATE ROLE</command> statement is in the SQL standard,
467   but the standard only requires the syntax
468<synopsis>
469CREATE ROLE <replaceable class="parameter">name</replaceable> [ WITH ADMIN <replaceable class="parameter">role_name</replaceable> ]
470</synopsis>
471   Multiple initial administrators, and all the other options of
472   <command>CREATE ROLE</command>, are
473   <productname>PostgreSQL</productname> extensions.
474  </para>
475
476  <para>
477   The SQL standard defines the concepts of users and roles, but it
478   regards them as distinct concepts and leaves all commands defining
479   users to be specified by each database implementation.  In
480   <productname>PostgreSQL</productname> we have chosen to unify
481   users and roles into a single kind of entity.  Roles therefore
482   have many more optional attributes than they do in the standard.
483  </para>
484
485  <para>
486   The behavior specified by the SQL standard is most closely approximated
487   by giving users the <literal>NOINHERIT</literal> attribute, while roles are
488   given the <literal>INHERIT</literal> attribute.
489  </para>
490 </refsect1>
491
492 <refsect1>
493  <title>See Also</title>
494
495  <simplelist type="inline">
496   <member><xref linkend="sql-set-role"/></member>
497   <member><xref linkend="sql-alterrole"/></member>
498   <member><xref linkend="sql-droprole"/></member>
499   <member><xref linkend="sql-grant"/></member>
500   <member><xref linkend="sql-revoke"/></member>
501   <member><xref linkend="app-createuser"/></member>
502  </simplelist>
503 </refsect1>
504</refentry>
505