postgresql/doc/src/sgml/ref/create_role.sgml

517 lines
20 KiB
Plaintext

<!--
doc/src/sgml/ref/create_role.sgml
PostgreSQL documentation
-->
<refentry id="sql-createrole">
<indexterm zone="sql-createrole">
<primary>CREATE ROLE</primary>
</indexterm>
<refmeta>
<refentrytitle>CREATE ROLE</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE ROLE</refname>
<refpurpose>define a new database role</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
CREATE ROLE <replaceable class="parameter">name</replaceable> [ [ WITH ] <replaceable class="parameter">option</replaceable> [ ... ] ]
<phrase>where <replaceable class="parameter">option</replaceable> can be:</phrase>
SUPERUSER | NOSUPERUSER
| CREATEDB | NOCREATEDB
| CREATEROLE | NOCREATEROLE
| INHERIT | NOINHERIT
| LOGIN | NOLOGIN
| REPLICATION | NOREPLICATION
| BYPASSRLS | NOBYPASSRLS
| CONNECTION LIMIT <replaceable class="parameter">connlimit</replaceable>
| [ ENCRYPTED ] PASSWORD '<replaceable class="parameter">password</replaceable>' | PASSWORD NULL
| VALID UNTIL '<replaceable class="parameter">timestamp</replaceable>'
| IN ROLE <replaceable class="parameter">role_name</replaceable> [, ...]
| ROLE <replaceable class="parameter">role_name</replaceable> [, ...]
| ADMIN <replaceable class="parameter">role_name</replaceable> [, ...]
| SYSID <replaceable class="parameter">uid</replaceable>
</synopsis>
</refsynopsisdiv>
<!--
CAUTION: remember to keep create_user.sgml and create_group.sgml
in sync when changing the above synopsis!
-->
<refsect1>
<title>Description</title>
<para>
<command>CREATE ROLE</command> adds a new role to a
<productname>PostgreSQL</productname> database cluster. A role is
an entity that can own database objects and have database privileges;
a role can be considered a <quote>user</quote>, a <quote>group</quote>, or both
depending on how it is used. Refer to
<xref linkend="user-manag"/> and <xref
linkend="client-authentication"/> for information about managing
users and authentication. You must have <literal>CREATEROLE</literal>
privilege or be a database superuser to use this command.
</para>
<para>
Note that roles are defined at the database cluster
level, and so are valid in all databases in the cluster.
</para>
<para>
During role creation it is possible to immediately assign the newly created
role to be a member of an existing role, and also assign existing roles
to be members of the newly created role. The rules for which initial
role membership options are enabled described below in the
<literal>IN ROLE</literal>, <literal>ROLE</literal>, and
<literal>ADMIN</literal> clauses. The <xref linkend="sql-grant"/>
command has fine-grained option control during membership creation,
and the ability to modify these options after the new role is created.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name of the new role.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SUPERUSER</literal></term>
<term><literal>NOSUPERUSER</literal></term>
<listitem>
<para>
These clauses determine whether the new role is a <quote>superuser</quote>,
who can override all access restrictions within the database.
Superuser status is dangerous and should be used only when really
needed. You must yourself be a superuser to create a new superuser.
If not specified,
<literal>NOSUPERUSER</literal> is the default.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CREATEDB</literal></term>
<term><literal>NOCREATEDB</literal></term>
<listitem>
<para>
These clauses define a role's ability to create databases. If
<literal>CREATEDB</literal> is specified, the role being
defined will be allowed to create new databases. Specifying
<literal>NOCREATEDB</literal> will deny a role the ability to
create databases. If not specified,
<literal>NOCREATEDB</literal> is the default.
Only superuser roles or roles with <literal>CREATEDB</literal>
can specify <literal>CREATEDB</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CREATEROLE</literal></term>
<term><literal>NOCREATEROLE</literal></term>
<listitem>
<para>
These clauses determine whether a role will be permitted to
create, alter, drop, comment on, and change the security label for
other roles.
See <xref linkend="role-creation"/> for more details about what
capabilities are conferred by this privilege.
If not specified, <literal>NOCREATEROLE</literal> is the default.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>INHERIT</literal></term>
<term><literal>NOINHERIT</literal></term>
<listitem>
<para>
This affects the membership inheritance status when this
role is added as a member of another role, both in this and
future commands. Specifically, it controls the inheritance
status of memberships added with this command using the
<literal>IN ROLE</literal> clause, and in later commands using
the <literal>ROLE</literal> clause. It is also used as the
default inheritance status when adding this role as a member
using the <literal>GRANT</literal> command. If not specified,
<literal>INHERIT</literal> is the default.
</para>
<para>
In <productname>PostgreSQL</productname> versions before 16,
inheritance was a role-level attribute that controlled all runtime
membership checks for that role.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>LOGIN</literal></term>
<term><literal>NOLOGIN</literal></term>
<listitem>
<para>
These clauses determine whether a role is allowed to log in;
that is, whether the role can be given as the initial session
authorization name during client connection. A role having
the <literal>LOGIN</literal> attribute can be thought of as a user.
Roles without this attribute are useful for managing database
privileges, but are not users in the usual sense of the word.
If not specified,
<literal>NOLOGIN</literal> is the default, except when
<command>CREATE ROLE</command> is invoked through its alternative spelling
<link linkend="sql-createuser"><command>CREATE USER</command></link>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>REPLICATION</literal></term>
<term><literal>NOREPLICATION</literal></term>
<listitem>
<para>
These clauses determine whether a role is a replication role. A role
must have this attribute (or be a superuser) in order to be able to
connect to the server in replication mode (physical or logical
replication) and in order to be able to create or drop replication
slots.
A role having the <literal>REPLICATION</literal> attribute is a very
highly privileged role, and should only be used on roles actually
used for replication. If not specified,
<literal>NOREPLICATION</literal> is the default.
Only superuser roles or roles with <literal>REPLICATION</literal>
can specify <literal>REPLICATION</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>BYPASSRLS</literal></term>
<term><literal>NOBYPASSRLS</literal></term>
<listitem>
<para>
These clauses determine whether a role bypasses every row-level
security (RLS) policy. <literal>NOBYPASSRLS</literal> is the default.
Only superuser roles or roles with <literal>BYPASSRLS</literal>
can specify <literal>BYPASSRLS</literal>.
</para>
<para>
Note that pg_dump will set <literal>row_security</literal> to
<literal>OFF</literal> by default, to ensure all contents of a table are
dumped out. If the user running pg_dump does not have appropriate
permissions, an error will be returned. However, superusers and the
owner of the table being dumped always bypass RLS.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CONNECTION LIMIT</literal> <replaceable class="parameter">connlimit</replaceable></term>
<listitem>
<para>
If role can log in, this specifies how many concurrent connections
the role can make. -1 (the default) means no limit. Note that only
normal connections are counted towards this limit. Neither prepared
transactions nor background worker connections are counted towards
this limit.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>[ <literal>ENCRYPTED</literal> ] <literal>PASSWORD</literal> '<replaceable class="parameter">password</replaceable>'</term>
<term><literal>PASSWORD NULL</literal></term>
<listitem>
<para>
Sets the role's password. (A password is only of use for
roles having the <literal>LOGIN</literal> attribute, but you
can nonetheless define one for roles without it.) If you do
not plan to use password authentication you can omit this
option. If no password is specified, the password will be set
to null and password authentication will always fail for that
user. A null password can optionally be written explicitly as
<literal>PASSWORD NULL</literal>.
</para>
<note>
<para>
Specifying an empty string will also set the password to null,
but that was not the case before <productname>PostgreSQL</productname>
version 10. In earlier versions, an empty string could be used,
or not, depending on the authentication method and the exact
version, and libpq would refuse to use it in any case.
To avoid the ambiguity, specifying an empty string should be
avoided.
</para>
</note>
<para>
The password is always stored encrypted in the system catalogs. The
<literal>ENCRYPTED</literal> keyword has no effect, but is accepted for
backwards compatibility. The method of encryption is determined
by the configuration parameter <xref linkend="guc-password-encryption"/>.
If the presented password string is already in MD5-encrypted or
SCRAM-encrypted format, then it is stored as-is regardless of
<varname>password_encryption</varname> (since the system cannot decrypt
the specified encrypted password string, to encrypt it in a
different format). This allows reloading of encrypted passwords
during dump/restore.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>VALID UNTIL</literal> '<replaceable class="parameter">timestamp</replaceable>'</term>
<listitem>
<para>
The <literal>VALID UNTIL</literal> clause sets a date and
time after which the role's password is no longer valid. If
this clause is omitted the password will be valid for all time.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IN ROLE</literal> <replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
The <literal>IN ROLE</literal> clause causes the new role to
be automatically added as a member of the specified existing
roles. The new membership will have the <literal>SET</literal>
option enabled and the <literal>ADMIN</literal> option disabled.
The <literal>INHERIT</literal> option will be enabled unless the
<literal>NOINHERIT</literal> option is specified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ROLE</literal> <replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
The <literal>ROLE</literal> clause causes one or more specified
existing roles to be automatically added as members, with the
<literal>SET</literal> option enabled. This in effect makes the
new role a <quote>group</quote>. Roles named in this clause
with the role-level <literal>INHERIT</literal> attribute will have
the <literal>INHERIT</literal> option enabled in the new membership.
New memberships will have the <literal>ADMIN</literal> option disabled.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>ADMIN</literal> <replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
The <literal>ADMIN</literal> clause has the same effect as
<literal>ROLE</literal>, but the named roles are added as members
of the new role with <literal>ADMIN</literal> enabled, giving
them the right to grant membership in the new role to others.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SYSID</literal> <replaceable class="parameter">uid</replaceable></term>
<listitem>
<para>
The <literal>SYSID</literal> clause is ignored, but is accepted
for backwards compatibility.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Use <link linkend="sql-alterrole"><command>ALTER ROLE</command></link> to
change the attributes of a role, and <link linkend="sql-droprole"><command>DROP ROLE</command></link>
to remove a role. All the attributes
specified by <command>CREATE ROLE</command> can be modified by later
<command>ALTER ROLE</command> commands.
</para>
<para>
The preferred way to add and remove members of roles that are being
used as groups is to use
<link linkend="sql-grant"><command>GRANT</command></link> and
<link linkend="sql-revoke"><command>REVOKE</command></link>.
</para>
<para>
The <literal>VALID UNTIL</literal> clause defines an expiration time for a
password only, not for the role per se. In
particular, the expiration time is not enforced when logging in using
a non-password-based authentication method.
</para>
<para>
The role attributes defined here are non-inheritable, i.e., being a
member of a role with, e.g., <literal>CREATEDB</literal> will not
allow the member to create new databases even if the membership grant
has the <literal>INHERIT</literal> option. Of course, if the membership
grant has the <literal>SET</literal> option the member role would be able to
<link linkend="sql-set-role"><command>SET ROLE</command></link> to the
createdb role and then create a new database.
</para>
<para>
The membership grants created by the
<literal>IN ROLE</literal>, <literal>ROLE</literal>, and <literal>ADMIN</literal>
clauses have the role executing this command as the grantee.
</para>
<para>
The <literal>INHERIT</literal> attribute is the default for reasons of backwards
compatibility: in prior releases of <productname>PostgreSQL</productname>,
users always had access to all privileges of groups they were members of.
However, <literal>NOINHERIT</literal> provides a closer match to the semantics
specified in the SQL standard.
</para>
<para>
<productname>PostgreSQL</productname> includes a program <xref
linkend="app-createuser"/> that has
the same functionality as <command>CREATE ROLE</command> (in fact,
it calls this command) but can be run from the command shell.
</para>
<para>
The <literal>CONNECTION LIMIT</literal> option is only enforced approximately;
if two new sessions start at about the same time when just one
connection <quote>slot</quote> remains for the role, it is possible that
both will fail. Also, the limit is never enforced for superusers.
</para>
<para>
Caution must be exercised when specifying an unencrypted password
with this command. The password will be transmitted to the server
in cleartext, and it might also be logged in the client's command
history or the server log. The command <xref
linkend="app-createuser"/>, however, transmits
the password encrypted. Also, <xref linkend="app-psql"/>
contains a command
<command>\password</command> that can be used to safely change the
password later.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Create a role that can log in, but don't give it a password:
<programlisting>
CREATE ROLE jonathan LOGIN;
</programlisting>
</para>
<para>
Create a role with a password:
<programlisting>
CREATE USER davide WITH PASSWORD 'jw8s0F4';
</programlisting>
(<command>CREATE USER</command> is the same as <command>CREATE ROLE</command> except
that it implies <literal>LOGIN</literal>.)
</para>
<para>
Create a role with a password that is valid until the end of 2004.
After one second has ticked in 2005, the password is no longer
valid.
<programlisting>
CREATE ROLE miriam WITH LOGIN PASSWORD 'jw8s0F4' VALID UNTIL '2005-01-01';
</programlisting>
</para>
<para>
Create a role that can create databases and manage roles:
<programlisting>
CREATE ROLE admin WITH CREATEDB CREATEROLE;
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
The <command>CREATE ROLE</command> statement is in the SQL standard,
but the standard only requires the syntax
<synopsis>
CREATE ROLE <replaceable class="parameter">name</replaceable> [ WITH ADMIN <replaceable class="parameter">role_name</replaceable> ]
</synopsis>
Multiple initial administrators, and all the other options of
<command>CREATE ROLE</command>, are
<productname>PostgreSQL</productname> extensions.
</para>
<para>
The SQL standard defines the concepts of users and roles, but it
regards them as distinct concepts and leaves all commands defining
users to be specified by each database implementation. In
<productname>PostgreSQL</productname> we have chosen to unify
users and roles into a single kind of entity. Roles therefore
have many more optional attributes than they do in the standard.
</para>
<para>
The behavior specified by the SQL standard is most closely approximated
creating SQL-standard users as <productname>PostgreSQL</productname>
roles with the <literal>NOINHERIT</literal> option, and SQL-standard
roles as <productname>PostgreSQL</productname> roles with the
<literal>INHERIT</literal> option.
</para>
<para>
The <literal>USER</literal> clause has the same behavior as
<literal>ROLE</literal> but has been deprecated:
<synopsis>
USER <replaceable class="parameter">role_name</replaceable> [, ...]
</synopsis>
</para>
<para>
The <literal>IN GROUP</literal> clause has the same behavior as <literal>IN
ROLE</literal> but has been deprecated:
<synopsis>
IN GROUP <replaceable class="parameter">role_name</replaceable> [, ...]
</synopsis>
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-set-role"/></member>
<member><xref linkend="sql-alterrole"/></member>
<member><xref linkend="sql-droprole"/></member>
<member><xref linkend="sql-grant"/></member>
<member><xref linkend="sql-revoke"/></member>
<member><xref linkend="app-createuser"/></member>
<member><xref linkend="guc-createrole-self-grant"/></member>
</simplelist>
</refsect1>
</refentry>