<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/grant.sgml,v 1.21 2002/02/21 22:39:36 momjian 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> <refsynopsisdiv> <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | RULE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ON [ TABLE ] <replaceable class="PARAMETER">objectname</replaceable> [, ...] TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] 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 } [, ...] GRANT { USAGE | ALL [ PRIVILEGES ] } ON LANGUAGE <replaceable>langname</replaceable> [, ...] TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...] </synopsis> </refsynopsisdiv> <refsect1 id="sql-grant-description"> <title>Description</title> <para> The <command>GRANT</command> command gives specific permissions on an object (table, view, sequence, function, procedural language) to one or more users or groups of users. These permissions 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. Note that 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> Users other than the creator of an object do not have any access privileges to the object unless the creator grants permissions. There is no need to grant privileges to the creator of an object, as the creator automatically holds all privileges. (The creator could, however, choose to revoke some of his own privileges for safety. Note that the ability to grant and revoke privileges is inherent in the creator and cannot be lost. The right to drop the object is likewise inherent in the creator, and cannot be granted or revoked.) </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"> FROM. </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"> TO. </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 <function>nextval</function>, <function>currval</function> and <function>setval</function>. </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 <xref linkend="sql-createrule" endterm="sql-createrule-title"> statement.) </para> </listitem> </varlistentry> <varlistentry> <term>REFERENCES</term> <listitem> <para> To create a table with a foreign key constraint, it is necessary to have this privilege on the table with the referenced key. </para> </listitem> </varlistentry> <varlistentry> <term>TRIGGER</term> <listitem> <para> Allows the creation of a trigger on the specified table. (See <xref linkend="sql-createtrigger" endterm="sql-createtrigger-title"> statement.) </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. </para> </listitem> </varlistentry> <varlistentry> <term>USAGE</term> <listitem> <para> Allows the use of the specified procedural language for the creation of functions in that language. This is the only type of privilege that is applicable to procedural languages. </para> </listitem> </varlistentry> <varlistentry> <term>ALL PRIVILEGES</term> <listitem> <para> Grant all of the privileges applicable to the object 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> It should be noted that database <firstterm>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> Currently, to grant privileges in <productname>PostgreSQL</productname> to only a few columns, you must create a view having 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 privileges on existing objects: <programlisting> Database = lusitania +------------------+---------------------------------------------+ | Relation | Grant/Revoke Permissions | +------------------+---------------------------------------------+ | mytable | {"=rw","miriam=arwdRxt","group todos=rw"} | +------------------+---------------------------------------------+ Legend: uname=arwR -- privileges granted to a user group gname=arwR -- privileges granted to a group =arwR -- privileges granted to PUBLIC r -- SELECT ("read") w -- UPDATE ("write") a -- INSERT ("append") d -- DELETE R -- RULE x -- REFERENCES t -- TRIGGER arwdRxt -- ALL PRIVILEGES </programlisting> </para> <para> The <xref linkend="sql-revoke" endterm="sql-revoke-title"> command is used to revoke access privileges. </para> </refsect1> <refsect1 id="sql-grant-examples"> <title>Examples</title> <para> Grant insert privilege to all users on table films: <programlisting> GRANT INSERT ON films TO PUBLIC; </programlisting> </para> <para> Grant all privileges to user <literal>manuel</literal> on view <literal>kinds</literal>: <programlisting> GRANT ALL PRIVILEGES ON kinds TO manuel; </programlisting> </para> </refsect1> <refsect1 id="sql-grant-compatibility"> <title>Compatibility</title> <refsect2> <title>SQL92</title> <para> The <literal>PRIVILEGES</literal> key word in <literal>ALL PRIVILEGES</literal> is required. <acronym>SQL</acronym> does not support setting the privileges on more than one table per command. </para> <para> The <acronym>SQL92</acronym> syntax for GRANT allows setting privileges for individual columns within a table, and allows setting a privilege to grant the same privileges to others: <synopsis> GRANT <replaceable class="PARAMETER">privilege</replaceable> [, ...] ON <replaceable class="PARAMETER">object</replaceable> [ ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) ] [, ...] TO { PUBLIC | <replaceable class="PARAMETER">username</replaceable> [, ...] } [ WITH GRANT OPTION ] </synopsis> </para> <para> <acronym>SQL</acronym> allows to grant the USAGE privilege on other kinds of objects: CHARACTER SET, COLLATION, TRANSLATION, DOMAIN. </para> <para> The TRIGGER privilege was introduced in SQL99. The RULE privilege is a PostgreSQL extension. </para> </refsect2> </refsect1> <refsect1> <title>See Also</title> <simpara> <xref linkend="sql-revoke"> </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: -->