
There are various things left to do: contrib dbsize and oid2name modules need work, and so does the documentation. Also someone should think about COMMENT ON TABLESPACE and maybe RENAME TABLESPACE. Also initlocation is dead, it just doesn't know it yet. Gavin Sherry and Tom Lane.
457 lines
16 KiB
Plaintext
457 lines
16 KiB
Plaintext
<!--
|
|
$PostgreSQL: pgsql/doc/src/sgml/ref/grant.sgml,v 1.41 2004/06/18 06:13:05 tgl Exp $
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-GRANT">
|
|
<refmeta>
|
|
<refentrytitle id="sql-grant-title">GRANT</refentrytitle>
|
|
<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 | RULE | REFERENCES | TRIGGER }
|
|
[,...] | ALL [ PRIVILEGES ] }
|
|
ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
|
|
GRANT { { CREATE | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] }
|
|
ON DATABASE <replaceable>dbname</replaceable> [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
|
|
GRANT { CREATE | ALL [ PRIVILEGES ] }
|
|
ON TABLESPACE <replaceable>tablespacename</> [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
|
|
GRANT { EXECUTE | ALL [ PRIVILEGES ] }
|
|
ON FUNCTION <replaceable>funcname</replaceable> ([<replaceable>type</replaceable>, ...]) [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
|
|
GRANT { USAGE | ALL [ PRIVILEGES ] }
|
|
ON LANGUAGE <replaceable>langname</replaceable> [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
|
|
GRANT { { CREATE | USAGE } [,...] | ALL [ PRIVILEGES ] }
|
|
ON SCHEMA <replaceable>schemaname</replaceable> [, ...]
|
|
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1 id="sql-grant-description">
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
The <command>GRANT</command> command gives specific privileges on
|
|
an object (table, view, sequence, database, function, procedural language,
|
|
or schema) to
|
|
one or more users or groups of users. These privileges are added
|
|
to those already granted, if any.
|
|
</para>
|
|
|
|
<para>
|
|
The key word <literal>PUBLIC</literal> indicates that the
|
|
privileges are to be granted to all users, including those that may
|
|
be created later. <literal>PUBLIC</literal> may be thought of as an
|
|
implicitly defined group that always includes all users.
|
|
Any particular user will have the sum
|
|
of privileges granted directly to him, privileges granted to any group he
|
|
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 may in turn grant it to others. Without a grant
|
|
option, the recipient cannot do that. At present, grant options can
|
|
only be granted to individual users, not to groups or
|
|
<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.)
|
|
The right to drop an object, or to alter its definition in any way is
|
|
not described by a grantable privilege; it is inherent in the owner,
|
|
and cannot be granted or revoked. The owner implicitly has all grant
|
|
options for the object, too.
|
|
</para>
|
|
|
|
<para>
|
|
Depending on the type of object, the initial default privileges may
|
|
include granting some privileges to <literal>PUBLIC</literal>.
|
|
The default is no public access for tables, schemas, and tablespaces;
|
|
<literal>TEMP</> table creation privilege for databases;
|
|
<literal>EXECUTE</> privilege for functions; and
|
|
<literal>USAGE</> privilege for languages.
|
|
The object owner may of course revoke these 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
|
|
may use the object.)
|
|
</para>
|
|
|
|
<para>
|
|
The possible privileges are:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term>SELECT</term>
|
|
<listitem>
|
|
<para>
|
|
Allows <xref linkend="sql-select" endterm="sql-select-title"> from any column of the
|
|
specified table, view, or sequence. Also allows the use of
|
|
<xref linkend="sql-copy" endterm="sql-copy-title"> TO. For sequences, this
|
|
privilege also allows the use of the <function>currval</function> function.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>INSERT</term>
|
|
<listitem>
|
|
<para>
|
|
Allows <xref linkend="sql-insert" endterm="sql-insert-title"> of a new row into the
|
|
specified table. Also allows <xref linkend="sql-copy" endterm="sql-copy-title"> FROM.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>UPDATE</term>
|
|
<listitem>
|
|
<para>
|
|
Allows <xref linkend="sql-update" endterm="sql-update-title"> of any column of the
|
|
specified table. <literal>SELECT ... FOR UPDATE</literal>
|
|
also requires this privilege (besides the
|
|
<literal>SELECT</literal> privilege). For sequences, this
|
|
privilege allows the use of the <function>nextval</function> and
|
|
<function>setval</function> functions.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>DELETE</term>
|
|
<listitem>
|
|
<para>
|
|
Allows <xref linkend="sql-delete" endterm="sql-delete-title"> of a row from the
|
|
specified table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>RULE</term>
|
|
<listitem>
|
|
<para>
|
|
Allows the creation of a rule on the table/view. (See the <xref
|
|
linkend="sql-createrule" endterm="sql-createrule-title"> statement.)
|
|
</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 tables.
|
|
</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" endterm="sql-createtrigger-title"> statement.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>CREATE</term>
|
|
<listitem>
|
|
<para>
|
|
For databases, allows new schemas to be created within the database.
|
|
</para>
|
|
<para>
|
|
For tablespaces, allows tables to be created within the tablespace,
|
|
and allows databases and schemas to be created that have the tablespace
|
|
as their default tablespace. (Note that revoking this privilege
|
|
will not alter the behavior of existing databases and schemas.)
|
|
</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>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>TEMPORARY</term>
|
|
<term>TEMP</term>
|
|
<listitem>
|
|
<para>
|
|
Allows temporary tables to be created while using the 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.
|
|
</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>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1 id="SQL-GRANT-notes">
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
The <xref linkend="sql-revoke" endterm="sql-revoke-title"> command is used
|
|
to revoke access privileges.
|
|
</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.
|
|
</para>
|
|
|
|
<para>
|
|
Currently, <productname>PostgreSQL</productname> does not support
|
|
granting or revoking privileges for individual columns of a table.
|
|
One possible workaround is to create a view having just the desired
|
|
columns and then grant privileges to that view.
|
|
</para>
|
|
|
|
<para>
|
|
Use <xref linkend="app-psql">'s <command>\z</command> command
|
|
to obtain information about existing privileges, for example:
|
|
<programlisting>
|
|
=> \z mytable
|
|
|
|
Access privileges for database "lusitania"
|
|
Schema | Name | Type | Access privileges
|
|
--------+---------+-------+------------------------------------------------------------
|
|
public | mytable | table | {miriam=arwdRxt/miriam,=r/miriam,"group todos=arw/miriam"}
|
|
(1 row)
|
|
</programlisting>
|
|
The entries shown by <command>\z</command> are interpreted thus:
|
|
<programlisting>
|
|
=xxxx -- privileges granted to PUBLIC
|
|
uname=xxxx -- privileges granted to a user
|
|
group gname=xxxx -- privileges granted to a group
|
|
|
|
r -- SELECT ("read")
|
|
w -- UPDATE ("write")
|
|
a -- INSERT ("append")
|
|
d -- DELETE
|
|
R -- RULE
|
|
x -- REFERENCES
|
|
t -- TRIGGER
|
|
X -- EXECUTE
|
|
U -- USAGE
|
|
C -- CREATE
|
|
T -- TEMPORARY
|
|
arwdRxt -- ALL PRIVILEGES (for tables)
|
|
* -- grant option for preceding privilege
|
|
|
|
/yyyy -- user who granted this privilege
|
|
</programlisting>
|
|
|
|
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 GROUP todos;
|
|
</programlisting>
|
|
</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 may 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=arwdRxt/miriam}</>) and then modify them per the
|
|
specified request.
|
|
</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>
|
|
</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>
|
|
The SQL standard allows setting privileges for individual columns
|
|
within a table:
|
|
|
|
<synopsis>
|
|
GRANT <replaceable class="PARAMETER">privileges</replaceable>
|
|
ON <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) ] [, ...]
|
|
TO { PUBLIC | <replaceable class="PARAMETER">username</replaceable> [, ...] } [ WITH GRANT OPTION ]
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
The SQL standard provides for a <literal>USAGE</literal> privilege
|
|
on other kinds of objects: character sets, collations,
|
|
translations, domains.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>RULE</literal> privilege, and privileges on
|
|
databases, tablespaces, schemas, languages, and sequences are
|
|
<productname>PostgreSQL</productname> extensions.
|
|
</para>
|
|
</refsect1>
|
|
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simpara>
|
|
<xref linkend="sql-revoke" endterm="sql-revoke-title">
|
|
</simpara>
|
|
</refsect1>
|
|
|
|
</refentry>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode: sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"../reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|