postgresql/doc/src/sgml/ref/grant.sgml

675 lines
26 KiB
Plaintext

<!--
doc/src/sgml/ref/grant.sgml
PostgreSQL documentation
-->
<refentry id="SQL-GRANT">
<refmeta>
<refentrytitle>GRANT</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>GRANT</refname>
<refpurpose>define access privileges</refpurpose>
</refnamediv>
<indexterm zone="sql-grant">
<primary>GRANT</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
[, ...] | ALL [ PRIVILEGES ] }
ON { [ TABLE ] <replaceable class="PARAMETER">table_name</replaceable> [, ...]
| ALL TABLES IN SCHEMA <replaceable class="PARAMETER">schema_name</replaceable> [, ...] }
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] )
[, ...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] ) }
ON [ TABLE ] <replaceable class="PARAMETER">table_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { USAGE | SELECT | UPDATE }
[, ...] | ALL [ PRIVILEGES ] }
ON { SEQUENCE <replaceable class="PARAMETER">sequence_name</replaceable> [, ...]
| ALL SEQUENCES IN SCHEMA <replaceable class="PARAMETER">schema_name</replaceable> [, ...] }
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
ON DATABASE <replaceable>database_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON DOMAIN <replaceable>domain_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN DATA WRAPPER <replaceable>fdw_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN SERVER <replaceable>server_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { EXECUTE | ALL [ PRIVILEGES ] }
ON { FUNCTION <replaceable>function_name</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) [, ...]
| ALL FUNCTIONS IN SCHEMA <replaceable class="PARAMETER">schema_name</replaceable> [, ...] }
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON LANGUAGE <replaceable>lang_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
ON LARGE OBJECT <replaceable class="PARAMETER">loid</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
ON SCHEMA <replaceable>schema_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { CREATE | ALL [ PRIVILEGES ] }
ON TABLESPACE <replaceable>tablespace_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON TYPE <replaceable>type_name</replaceable> [, ...]
TO { [ GROUP ] <replaceable class="PARAMETER">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT <replaceable class="PARAMETER">role_name</replaceable> [, ...] TO <replaceable class="PARAMETER">role_name</replaceable> [, ...] [ WITH ADMIN OPTION ]
</synopsis>
</refsynopsisdiv>
<refsect1 id="sql-grant-description">
<title>Description</title>
<para>
The <command>GRANT</command> command has two basic variants: one
that grants privileges on a database object (table, column, view, foreign
table, sequence, database, foreign-data wrapper, foreign server, function,
procedural language, schema, or tablespace), and one that grants
membership in a role. These variants are similar in many ways, but
they are different enough to be described separately.
</para>
<refsect2 id="sql-grant-description-objects">
<title>GRANT on Database Objects</title>
<para>
This variant of the <command>GRANT</command> command gives specific
privileges on a database object to
one or more roles. These privileges are added
to those already granted, if any.
</para>
<para>
There is also an option to grant privileges on all objects of the same
type within one or more schemas. This functionality is currently supported
only for tables, sequences, and functions (but note that <literal>ALL
TABLES</> is considered to include views and foreign tables).
</para>
<para>
The key word <literal>PUBLIC</literal> indicates that the
privileges are to be granted to all roles, including those that might
be created later. <literal>PUBLIC</literal> can be thought of as an
implicitly defined group that always includes all roles.
Any particular role will have the sum
of privileges granted directly to it, privileges granted to any role it
is presently a member of, and privileges granted to
<literal>PUBLIC</literal>.
</para>
<para>
If <literal>WITH GRANT OPTION</literal> is specified, the recipient
of the privilege can in turn grant it to others. Without a grant
option, the recipient cannot do that. Grant options cannot be granted
to <literal>PUBLIC</literal>.
</para>
<para>
There is no need to grant privileges to the owner of an object
(usually the user that created it),
as the owner has all privileges by default. (The owner could,
however, choose to revoke some of his own privileges for safety.)
</para>
<para>
The right to drop an object, or to alter its definition in any way, is
not treated as a grantable privilege; it is inherent in the owner,
and cannot be granted or revoked. (However, a similar effect can be
obtained by granting or revoking membership in the role that owns
the object; see below.) The owner implicitly has all grant
options for the object, too.
</para>
<para>
PostgreSQL grants default privileges on some types of objects to
<literal>PUBLIC</literal>. No privileges are granted to
<literal>PUBLIC</literal> by default on tables,
columns, schemas or tablespaces. For other types, the default privileges
granted to <literal>PUBLIC</literal> are as follows:
<literal>CONNECT</literal> and <literal>CREATE TEMP TABLE</literal> for
databases; <literal>EXECUTE</literal> privilege for functions; and
<literal>USAGE</literal> privilege for languages.
The object owner can, of course, <command>REVOKE</command>
both default and expressly granted privileges. (For maximum
security, issue the <command>REVOKE</> in the same transaction that
creates the object; then there is no window in which another user
can use the object.)
Also, these initial default privilege settings can be changed using the
<xref linkend="sql-alterdefaultprivileges">
command.
</para>
<para>
The possible privileges are:
<variablelist>
<varlistentry>
<term>SELECT</term>
<listitem>
<para>
Allows <xref linkend="sql-select"> from
any column, or the specific columns listed, of the specified table,
view, or sequence.
Also allows the use of
<xref linkend="sql-copy"> TO.
This privilege is also needed to reference existing column values in
<xref linkend="sql-update"> or
<xref linkend="sql-delete">.
For sequences, this privilege also allows the use of the
<function>currval</function> function.
For large objects, this privilege allows the object to be read.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>INSERT</term>
<listitem>
<para>
Allows <xref linkend="sql-insert"> of a new
row into the specified table. If specific columns are listed,
only those columns may be assigned to in the <command>INSERT</>
command (other columns will therefore receive default values).
Also allows <xref linkend="sql-copy"> FROM.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>UPDATE</term>
<listitem>
<para>
Allows <xref linkend="sql-update"> of any
column, or the specific columns listed, of the specified table.
(In practice, any nontrivial <command>UPDATE</> command will require
<literal>SELECT</> privilege as well, since it must reference table
columns to determine which rows to update, and/or to compute new
values for columns.)
<literal>SELECT ... FOR UPDATE</literal>
and <literal>SELECT ... FOR SHARE</literal>
also require this privilege on at least one column, in addition to the
<literal>SELECT</literal> privilege. For sequences, this
privilege allows the use of the <function>nextval</function> and
<function>setval</function> functions.
For large objects, this privilege allows writing or truncating the
object.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>DELETE</term>
<listitem>
<para>
Allows <xref linkend="sql-delete"> of a row
from the specified table.
(In practice, any nontrivial <command>DELETE</> command will require
<literal>SELECT</> privilege as well, since it must reference table
columns to determine which rows to delete.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRUNCATE</term>
<listitem>
<para>
Allows <xref linkend="sql-truncate"> on
the specified table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>REFERENCES</term>
<listitem>
<para>
To create a foreign key constraint, it is
necessary to have this privilege on both the referencing and
referenced columns. The privilege may be granted for all columns
of a table, or just specific columns.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TRIGGER</term>
<listitem>
<para>
Allows the creation of a trigger on the specified table. (See the
<xref linkend="sql-createtrigger"> statement.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>CREATE</term>
<listitem>
<para>
For databases, allows new schemas to be created within the database.
</para>
<para>
For schemas, allows new objects to be created within the schema.
To rename an existing object, you must own the object <emphasis>and</>
have this privilege for the containing schema.
</para>
<para>
For tablespaces, allows tables, indexes, and temporary files to be
created within the tablespace, and allows databases to be created that
have the tablespace as their default tablespace. (Note that revoking
this privilege will not alter the placement of existing objects.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>CONNECT</term>
<listitem>
<para>
Allows the user to connect to the specified database. This
privilege is checked at connection startup (in addition to checking
any restrictions imposed by <filename>pg_hba.conf</>).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>TEMPORARY</term>
<term>TEMP</term>
<listitem>
<para>
Allows temporary tables to be created while using the specified database.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>EXECUTE</term>
<listitem>
<para>
Allows the use of the specified function and the use of any
operators that are implemented on top of the function. This is
the only type of privilege that is applicable to functions.
(This syntax works for aggregate functions, as well.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>USAGE</term>
<listitem>
<para>
For procedural languages, allows the use of the specified language for
the creation of functions in that language. This is the only type
of privilege that is applicable to procedural languages.
</para>
<para>
For schemas, allows access to objects contained in the specified
schema (assuming that the objects' own privilege requirements are
also met). Essentially this allows the grantee to <quote>look up</>
objects within the schema. Without this permission, it is still
possible to see the object names, e.g. by querying the system tables.
Also, after revoking this permission, existing backends might have
statements that have previously performed this lookup, so this is not
a completely secure way to prevent object access.
</para>
<para>
For sequences, this privilege allows the use of the
<function>currval</function> and <function>nextval</function> functions.
</para>
<para>
For types and domains, this privilege allow the use of the type or
domain in the creation of tables, functions, and other schema objects.
(Note that it does not control general <quote>usage</quote> of the type,
such as values of the type appearing in queries. It only prevents
objects from being created that depend on the type. The main purpose of
the privilege is controlling which users create dependencies on a type,
which could prevent the owner from changing the type later.)
</para>
<para>
For foreign-data wrappers, this privilege enables the grantee
to create new servers using that foreign-data wrapper.
</para>
<para>
For servers, this privilege enables the grantee to create foreign
tables using the server, and also to create, alter, or drop his own
user's user mappings associated with that server.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ALL PRIVILEGES</term>
<listitem>
<para>
Grant all of the available privileges at once.
The <literal>PRIVILEGES</literal> key word is optional in
<productname>PostgreSQL</productname>, though it is required by
strict SQL.
</para>
</listitem>
</varlistentry>
</variablelist>
The privileges required by other commands are listed on the
reference page of the respective command.
</para>
</refsect2>
<refsect2 id="sql-grant-description-roles">
<title>GRANT on Roles</title>
<para>
This variant of the <command>GRANT</command> command grants membership
in a role to one or more other roles. Membership in a role is significant
because it conveys the privileges granted to a role to each of its
members.
</para>
<para>
If <literal>WITH ADMIN OPTION</literal> is specified, the member can
in turn grant membership in the role to others, and revoke membership
in the role as well. Without the admin option, ordinary users cannot
do that. A role is not considered to hold <literal>WITH ADMIN
OPTION</literal> on itself, but it may grant or revoke membership in
itself from a database session where the session user matches the
role. Database superusers can grant or revoke membership in any role
to anyone. Roles having <literal>CREATEROLE</> privilege can grant
or revoke membership in any role that is not a superuser.
</para>
<para>
Unlike the case with privileges, membership in a role cannot be granted
to <literal>PUBLIC</>. Note also that this form of the command does not
allow the noise word <literal>GROUP</>.
</para>
</refsect2>
</refsect1>
<refsect1 id="SQL-GRANT-notes">
<title>Notes</title>
<para>
The <xref linkend="sql-revoke"> command is used
to revoke access privileges.
</para>
<para>
Since <productname>PostgreSQL</productname> 8.1, the concepts of users and
groups have been unified into a single kind of entity called a role.
It is therefore no longer necessary to use the keyword <literal>GROUP</>
to identify whether a grantee is a user or a group. <literal>GROUP</>
is still allowed in the command, but it is a noise word.
</para>
<para>
A user may perform <command>SELECT</>, <command>INSERT</>, etc. on a
column if he holds that privilege for either the specific column or
its whole table. Granting the privilege at the table level and then
revoking it for one column will not do what you might wish: the
table-level grant is unaffected by a column-level operation.
</para>
<para>
When a non-owner of an object attempts to <command>GRANT</> privileges
on the object, the command will fail outright if the user has no
privileges whatsoever on the object. As long as some privilege is
available, the command will proceed, but it will grant only those
privileges for which the user has grant options. The <command>GRANT ALL
PRIVILEGES</> forms will issue a warning message if no grant options are
held, while the other forms will issue a warning if grant options for
any of the privileges specifically named in the command are not held.
(In principle these statements apply to the object owner as well, but
since the owner is always treated as holding all grant options, the
cases can never occur.)
</para>
<para>
It should be noted that database superusers can access
all objects regardless of object privilege settings. This
is comparable to the rights of <literal>root</> in a Unix system.
As with <literal>root</>, it's unwise to operate as a superuser
except when absolutely necessary.
</para>
<para>
If a superuser chooses to issue a <command>GRANT</> or <command>REVOKE</>
command, the command is performed as though it were issued by the
owner of the affected object. In particular, privileges granted via
such a command will appear to have been granted by the object owner.
(For role membership, the membership appears to have been granted
by the containing role itself.)
</para>
<para>
<command>GRANT</> and <command>REVOKE</> can also be done by a role
that is not the owner of the affected object, but is a member of the role
that owns the object, or is a member of a role that holds privileges
<literal>WITH GRANT OPTION</literal> on the object. In this case the
privileges will be recorded as having been granted by the role that
actually owns the object or holds the privileges
<literal>WITH GRANT OPTION</literal>. For example, if table
<literal>t1</> is owned by role <literal>g1</>, of which role
<literal>u1</> is a member, then <literal>u1</> can grant privileges
on <literal>t1</> to <literal>u2</>, but those privileges will appear
to have been granted directly by <literal>g1</>. Any other member
of role <literal>g1</> could revoke them later.
</para>
<para>
If the role executing <command>GRANT</> holds the required privileges
indirectly via more than one role membership path, it is unspecified
which containing role will be recorded as having done the grant. In such
cases it is best practice to use <command>SET ROLE</> to become the
specific role you want to do the <command>GRANT</> as.
</para>
<para>
Granting permission on a table does not automatically extend
permissions to any sequences used by the table, including
sequences tied to <type>SERIAL</> columns. Permissions on
sequences must be set separately.
</para>
<para>
Use <xref linkend="app-psql">'s <command>\dp</command> command
to obtain information about existing privileges for tables and
columns. For example:
<programlisting>
=&gt; \dp mytable
Access privileges
Schema | Name | Type | Access privileges | Column access privileges
--------+---------+-------+-----------------------+--------------------------
public | mytable | table | miriam=arwdDxt/miriam | col1:
: =r/miriam : miriam_rw=rw/miriam
: admin=arw/miriam
(1 row)
</programlisting>
The entries shown by <command>\dp</command> are interpreted thus:
<literallayout class="monospaced">
rolename=xxxx -- privileges granted to a role
=xxxx -- privileges granted to PUBLIC
r -- SELECT ("read")
w -- UPDATE ("write")
a -- INSERT ("append")
d -- DELETE
D -- TRUNCATE
x -- REFERENCES
t -- TRIGGER
X -- EXECUTE
U -- USAGE
C -- CREATE
c -- CONNECT
T -- TEMPORARY
arwdDxt -- ALL PRIVILEGES (for tables, varies for other objects)
* -- grant option for preceding privilege
/yyyy -- role that granted this privilege
</literallayout>
The above example display would be seen by user <literal>miriam</> after
creating table <literal>mytable</> and doing:
<programlisting>
GRANT SELECT ON mytable TO PUBLIC;
GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
</programlisting>
</para>
<para>
For non-table objects there are other <command>\d</> commands
that can display their privileges.
</para>
<para>
If the <quote>Access privileges</> column is empty for a given object,
it means the object has default privileges (that is, its privileges column
is null). Default privileges always include all privileges for the owner,
and can include some privileges for <literal>PUBLIC</> depending on the
object type, as explained above. The first <command>GRANT</> or
<command>REVOKE</> on an object
will instantiate the default privileges (producing, for example,
<literal>{miriam=arwdDxt/miriam}</>) and then modify them per the
specified request. Similarly, entries are shown in <quote>Column access
privileges</> only for columns with nondefault privileges.
(Note: for this purpose, <quote>default privileges</> always means the
built-in default privileges for the object's type. An object whose
privileges have been affected by an <command>ALTER DEFAULT PRIVILEGES</>
command will always be shown with an explicit privilege entry that
includes the effects of the <command>ALTER</>.)
</para>
<para>
Notice that the owner's implicit grant options are not marked in the
access privileges display. A <literal>*</> will appear only when
grant options have been explicitly granted to someone.
</para>
</refsect1>
<refsect1 id="sql-grant-examples">
<title>Examples</title>
<para>
Grant insert privilege to all users on table <literal>films</literal>:
<programlisting>
GRANT INSERT ON films TO PUBLIC;
</programlisting>
</para>
<para>
Grant all available privileges to user <literal>manuel</literal> on view
<literal>kinds</literal>:
<programlisting>
GRANT ALL PRIVILEGES ON kinds TO manuel;
</programlisting>
Note that while the above will indeed grant all privileges if executed by a
superuser or the owner of <literal>kinds</literal>, when executed by someone
else it will only grant those permissions for which the someone else has
grant options.
</para>
<para>
Grant membership in role <literal>admins</> to user <literal>joe</>:
<programlisting>
GRANT admins TO joe;
</programlisting></para>
</refsect1>
<refsect1 id="sql-grant-compatibility">
<title>Compatibility</title>
<para>
According to the SQL standard, the <literal>PRIVILEGES</literal>
key word in <literal>ALL PRIVILEGES</literal> is required. The
SQL standard does not support setting the privileges on more than
one object per command.
</para>
<para>
<productname>PostgreSQL</productname> allows an object owner to revoke his
own ordinary privileges: for example, a table owner can make the table
read-only to himself by revoking his own <literal>INSERT</>,
<literal>UPDATE</>, <literal>DELETE</>, and <literal>TRUNCATE</>
privileges. This is not possible according to the SQL standard. The
reason is that <productname>PostgreSQL</productname> treats the owner's
privileges as having been granted by the owner to himself; therefore he
can revoke them too. In the SQL standard, the owner's privileges are
granted by an assumed entity <quote>_SYSTEM</>. Not being
<quote>_SYSTEM</>, the owner cannot revoke these rights.
</para>
<para>
According to the SQL standard, grant options can be granted to
<literal>PUBLIC</literal>; PostgreSQL only supports granting grant options
to roles.
</para>
<para>
The SQL standard provides for a <literal>USAGE</literal> privilege
on other kinds of objects: character sets, collations,
translations.
</para>
<para>
In the SQL standard, sequences only have a <literal>USAGE</literal>
privilege, which controls the use of the <literal>NEXT VALUE FOR</literal>
expression, which is equivalent to the
function <function>nextval</function> in PostgreSQL. The sequence
privileges <literal>SELECT</literal> and <literal>UPDATE</literal> are
PostgreSQL extensions. The application of the
sequence <literal>USAGE</literal> privilege to
the <literal>currval</literal> function is also a PostgreSQL extension (as
is the function itself).
</para>
<para>
Privileges on databases, tablespaces, schemas, and languages are
<productname>PostgreSQL</productname> extensions.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-revoke"></member>
<member><xref linkend="sql-alterdefaultprivileges"></member>
</simplelist>
</refsect1>
</refentry>