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