1<!--
2doc/src/sgml/ref/grant.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-grant">
7 <indexterm zone="sql-grant">
8  <primary>GRANT</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>GRANT</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>GRANT</refname>
19  <refpurpose>define access privileges</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
25    [, ...] | ALL [ PRIVILEGES ] }
26    ON { [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
27         | ALL TABLES IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
28    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
29
30GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="parameter">column_name</replaceable> [, ...] )
31    [, ...] | ALL [ PRIVILEGES ] ( <replaceable class="parameter">column_name</replaceable> [, ...] ) }
32    ON [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
33    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
34
35GRANT { { USAGE | SELECT | UPDATE }
36    [, ...] | ALL [ PRIVILEGES ] }
37    ON { SEQUENCE <replaceable class="parameter">sequence_name</replaceable> [, ...]
38         | ALL SEQUENCES IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
39    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
40
41GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
42    ON DATABASE <replaceable>database_name</replaceable> [, ...]
43    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
44
45GRANT { USAGE | ALL [ PRIVILEGES ] }
46    ON DOMAIN <replaceable>domain_name</replaceable> [, ...]
47    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
48
49GRANT { USAGE | ALL [ PRIVILEGES ] }
50    ON FOREIGN DATA WRAPPER <replaceable>fdw_name</replaceable> [, ...]
51    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
52
53GRANT { USAGE | ALL [ PRIVILEGES ] }
54    ON FOREIGN SERVER <replaceable>server_name</replaceable> [, ...]
55    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
56
57GRANT { EXECUTE | ALL [ PRIVILEGES ] }
58    ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>routine_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
59         | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable class="parameter">schema_name</replaceable> [, ...] }
60    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
61
62GRANT { USAGE | ALL [ PRIVILEGES ] }
63    ON LANGUAGE <replaceable>lang_name</replaceable> [, ...]
64    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
65
66GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
67    ON LARGE OBJECT <replaceable class="parameter">loid</replaceable> [, ...]
68    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
69
70GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
71    ON SCHEMA <replaceable>schema_name</replaceable> [, ...]
72    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
73
74GRANT { CREATE | ALL [ PRIVILEGES ] }
75    ON TABLESPACE <replaceable>tablespace_name</replaceable> [, ...]
76    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
77
78GRANT { USAGE | ALL [ PRIVILEGES ] }
79    ON TYPE <replaceable>type_name</replaceable> [, ...]
80    TO <replaceable class="parameter">role_specification</replaceable> [, ...] [ WITH GRANT OPTION ]
81
82GRANT <replaceable class="parameter">role_name</replaceable> [, ...] TO <replaceable class="parameter">role_specification</replaceable> [, ...]
83    [ WITH ADMIN OPTION ]
84    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
85
86<phrase>where <replaceable class="parameter">role_specification</replaceable> can be:</phrase>
87
88    [ GROUP ] <replaceable class="parameter">role_name</replaceable>
89  | PUBLIC
90  | CURRENT_USER
91  | SESSION_USER
92</synopsis>
93 </refsynopsisdiv>
94
95 <refsect1 id="sql-grant-description">
96  <title>Description</title>
97
98  <para>
99   The <command>GRANT</command> command has two basic variants: one
100   that grants privileges on a database object (table, column, view, foreign
101   table, sequence, database, foreign-data wrapper, foreign server, function, procedure,
102   procedural language, schema, or tablespace), and one that grants
103   membership in a role.  These variants are similar in many ways, but
104   they are different enough to be described separately.
105  </para>
106
107 <refsect2 id="sql-grant-description-objects">
108  <title>GRANT on Database Objects</title>
109
110  <para>
111   This variant of the <command>GRANT</command> command gives specific
112   privileges on a database object to
113   one or more roles.  These privileges are added
114   to those already granted, if any.
115  </para>
116
117  <para>
118   The key word <literal>PUBLIC</literal> indicates that the
119   privileges are to be granted to all roles, including those that might
120   be created later.  <literal>PUBLIC</literal> can be thought of as an
121   implicitly defined group that always includes all roles.
122   Any particular role will have the sum
123   of privileges granted directly to it, privileges granted to any role it
124   is presently a member of, and privileges granted to
125   <literal>PUBLIC</literal>.
126  </para>
127
128  <para>
129   If <literal>WITH GRANT OPTION</literal> is specified, the recipient
130   of the privilege can in turn grant it to others.  Without a grant
131   option, the recipient cannot do that.  Grant options cannot be granted
132   to <literal>PUBLIC</literal>.
133  </para>
134
135  <para>
136   There is no need to grant privileges to the owner of an object
137   (usually the user that created it),
138   as the owner has all privileges by default.  (The owner could,
139   however, choose to revoke some of their own privileges for safety.)
140  </para>
141
142  <para>
143   The right to drop an object, or to alter its definition in any way, is
144   not treated as a grantable privilege; it is inherent in the owner,
145   and cannot be granted or revoked.  (However, a similar effect can be
146   obtained by granting or revoking membership in the role that owns
147   the object; see below.)  The owner implicitly has all grant
148   options for the object, too.
149  </para>
150
151  <para>
152   The possible privileges are:
153
154   <variablelist>
155    <varlistentry>
156     <term><literal>SELECT</literal></term>
157     <term><literal>INSERT</literal></term>
158     <term><literal>UPDATE</literal></term>
159     <term><literal>DELETE</literal></term>
160     <term><literal>TRUNCATE</literal></term>
161     <term><literal>REFERENCES</literal></term>
162     <term><literal>TRIGGER</literal></term>
163     <term><literal>CREATE</literal></term>
164     <term><literal>CONNECT</literal></term>
165     <term><literal>TEMPORARY</literal></term>
166     <term><literal>EXECUTE</literal></term>
167     <term><literal>USAGE</literal></term>
168     <listitem>
169      <para>
170       Specific types of privileges, as defined in <xref linkend="ddl-priv"/>.
171      </para>
172     </listitem>
173    </varlistentry>
174
175    <varlistentry>
176     <term><literal>TEMP</literal></term>
177     <listitem>
178      <para>
179       Alternative spelling for <literal>TEMPORARY</literal>.
180      </para>
181     </listitem>
182    </varlistentry>
183
184    <varlistentry>
185     <term><literal>ALL PRIVILEGES</literal></term>
186     <listitem>
187      <para>
188       Grant all of the privileges available for the object's type.
189       The <literal>PRIVILEGES</literal> key word is optional in
190       <productname>PostgreSQL</productname>, though it is required by
191       strict SQL.
192      </para>
193     </listitem>
194    </varlistentry>
195   </variablelist>
196  </para>
197
198  <para>
199   The <literal>FUNCTION</literal> syntax works for plain functions,
200   aggregate functions, and window functions, but not for procedures;
201   use <literal>PROCEDURE</literal> for those.
202   Alternatively, use <literal>ROUTINE</literal> to refer to a function,
203   aggregate function, window function, or procedure regardless of its
204   precise type.
205  </para>
206
207  <para>
208   There is also an option to grant privileges on all objects of the same
209   type within one or more schemas.  This functionality is currently supported
210   only for tables, sequences, functions, and procedures.  <literal>ALL
211   TABLES</literal> also affects views and foreign tables, just like the
212   specific-object <command>GRANT</command> command.  <literal>ALL
213   FUNCTIONS</literal> also affects aggregate and window functions, but not
214   procedures, again just like the specific-object <command>GRANT</command>
215   command.  Use <literal>ALL ROUTINES</literal> to include procedures.
216  </para>
217 </refsect2>
218
219 <refsect2 id="sql-grant-description-roles">
220  <title>GRANT on Roles</title>
221
222  <para>
223   This variant of the <command>GRANT</command> command grants membership
224   in a role to one or more other roles.  Membership in a role is significant
225   because it conveys the privileges granted to a role to each of its
226   members.
227  </para>
228
229  <para>
230   If <literal>WITH ADMIN OPTION</literal> is specified, the member can
231   in turn grant membership in the role to others, and revoke membership
232   in the role as well.  Without the admin option, ordinary users cannot
233   do that.  A role is not considered to hold <literal>WITH ADMIN
234   OPTION</literal> on itself, but it may grant or revoke membership in
235   itself from a database session where the session user matches the
236   role.  Database superusers can grant or revoke membership in any role
237   to anyone.  Roles having <literal>CREATEROLE</literal> privilege can grant
238   or revoke membership in any role that is not a superuser.
239  </para>
240
241  <para>
242   If <literal>GRANTED BY</literal> is specified, the grant is recorded as
243   having been done by the specified role.  Only database superusers may
244   use this option, except when it names the same role executing the command.
245  </para>
246
247  <para>
248   Unlike the case with privileges, membership in a role cannot be granted
249   to <literal>PUBLIC</literal>.  Note also that this form of the command
250   does not allow the noise word <literal>GROUP</literal>
251   in <replaceable class="parameter">role_specification</replaceable>.
252  </para>
253 </refsect2>
254 </refsect1>
255
256
257 <refsect1 id="sql-grant-notes">
258  <title>Notes</title>
259
260   <para>
261    The <xref linkend="sql-revoke"/> command is used
262    to revoke access privileges.
263   </para>
264
265   <para>
266    Since <productname>PostgreSQL</productname> 8.1, the concepts of users and
267    groups have been unified into a single kind of entity called a role.
268    It is therefore no longer necessary to use the keyword <literal>GROUP</literal>
269    to identify whether a grantee is a user or a group.  <literal>GROUP</literal>
270    is still allowed in the command, but it is a noise word.
271   </para>
272
273   <para>
274    A user may perform <command>SELECT</command>, <command>INSERT</command>, etc. on a
275    column if they hold that privilege for either the specific column or
276    its whole table.  Granting the privilege at the table level and then
277    revoking it for one column will not do what one might wish: the
278    table-level grant is unaffected by a column-level operation.
279   </para>
280
281   <para>
282    When a non-owner of an object attempts to <command>GRANT</command> privileges
283    on the object, the command will fail outright if the user has no
284    privileges whatsoever on the object.  As long as some privilege is
285    available, the command will proceed, but it will grant only those
286    privileges for which the user has grant options.  The <command>GRANT ALL
287    PRIVILEGES</command> forms will issue a warning message if no grant options are
288    held, while the other forms will issue a warning if grant options for
289    any of the privileges specifically named in the command are not held.
290    (In principle these statements apply to the object owner as well, but
291    since the owner is always treated as holding all grant options, the
292    cases can never occur.)
293   </para>
294
295   <para>
296    It should be noted that database superusers can access
297    all objects regardless of object privilege settings.  This
298    is comparable to the rights of <literal>root</literal> in a Unix system.
299    As with <literal>root</literal>, it's unwise to operate as a superuser
300    except when absolutely necessary.
301   </para>
302
303   <para>
304    If a superuser chooses to issue a <command>GRANT</command> or <command>REVOKE</command>
305    command, the command is performed as though it were issued by the
306    owner of the affected object.  In particular, privileges granted via
307    such a command will appear to have been granted by the object owner.
308    (For role membership, the membership appears to have been granted
309    by the containing role itself.)
310   </para>
311
312   <para>
313    <command>GRANT</command> and <command>REVOKE</command> can also be done by a role
314    that is not the owner of the affected object, but is a member of the role
315    that owns the object, or is a member of a role that holds privileges
316    <literal>WITH GRANT OPTION</literal> on the object.  In this case the
317    privileges will be recorded as having been granted by the role that
318    actually owns the object or holds the privileges
319    <literal>WITH GRANT OPTION</literal>.  For example, if table
320    <literal>t1</literal> is owned by role <literal>g1</literal>, of which role
321    <literal>u1</literal> is a member, then <literal>u1</literal> can grant privileges
322    on <literal>t1</literal> to <literal>u2</literal>, but those privileges will appear
323    to have been granted directly by <literal>g1</literal>.  Any other member
324    of role <literal>g1</literal> could revoke them later.
325   </para>
326
327   <para>
328    If the role executing <command>GRANT</command> holds the required privileges
329    indirectly via more than one role membership path, it is unspecified
330    which containing role will be recorded as having done the grant.  In such
331    cases it is best practice to use <command>SET ROLE</command> to become the
332    specific role you want to do the <command>GRANT</command> as.
333   </para>
334
335   <para>
336    Granting permission on a table does not automatically extend
337    permissions to any sequences used by the table, including
338    sequences tied to <type>SERIAL</type> columns.  Permissions on
339    sequences must be set separately.
340   </para>
341
342   <para>
343    See <xref linkend="ddl-priv"/> for more information about specific
344    privilege types, as well as how to inspect objects' privileges.
345   </para>
346 </refsect1>
347
348 <refsect1 id="sql-grant-examples">
349  <title>Examples</title>
350
351  <para>
352   Grant insert privilege to all users on table <literal>films</literal>:
353
354<programlisting>
355GRANT INSERT ON films TO PUBLIC;
356</programlisting>
357  </para>
358
359  <para>
360   Grant all available privileges to user <literal>manuel</literal> on view
361   <literal>kinds</literal>:
362
363<programlisting>
364GRANT ALL PRIVILEGES ON kinds TO manuel;
365</programlisting>
366
367   Note that while the above will indeed grant all privileges if executed by a
368   superuser or the owner of <literal>kinds</literal>, when executed by someone
369   else it will only grant those permissions for which the someone else has
370   grant options.
371  </para>
372
373  <para>
374   Grant membership in role <literal>admins</literal> to user <literal>joe</literal>:
375
376<programlisting>
377GRANT admins TO joe;
378</programlisting></para>
379 </refsect1>
380
381 <refsect1 id="sql-grant-compatibility">
382  <title>Compatibility</title>
383
384   <para>
385    According to the SQL standard, the <literal>PRIVILEGES</literal>
386    key word in <literal>ALL PRIVILEGES</literal> is required.  The
387    SQL standard does not support setting the privileges on more than
388    one object per command.
389   </para>
390
391   <para>
392    <productname>PostgreSQL</productname> allows an object owner to revoke their
393    own ordinary privileges: for example, a table owner can make the table
394    read-only to themselves by revoking their own <literal>INSERT</literal>,
395    <literal>UPDATE</literal>, <literal>DELETE</literal>, and <literal>TRUNCATE</literal>
396    privileges.  This is not possible according to the SQL standard.  The
397    reason is that <productname>PostgreSQL</productname> treats the owner's
398    privileges as having been granted by the owner to themselves; therefore they
399    can revoke them too.  In the SQL standard, the owner's privileges are
400    granted by an assumed entity <quote>_SYSTEM</quote>.  Not being
401    <quote>_SYSTEM</quote>, the owner cannot revoke these rights.
402   </para>
403
404   <para>
405    According to the SQL standard, grant options can be granted to
406    <literal>PUBLIC</literal>; PostgreSQL only supports granting grant options
407    to roles.
408   </para>
409
410   <para>
411    The SQL standard allows the <literal>GRANTED BY</literal> option to
412    be used in all forms of <command>GRANT</command>.  PostgreSQL only
413    supports it when granting role membership, and even then only superusers
414    may use it in nontrivial ways.
415   </para>
416
417   <para>
418    The SQL standard provides for a <literal>USAGE</literal> privilege
419    on other kinds of objects: character sets, collations,
420    translations.
421   </para>
422
423   <para>
424    In the SQL standard, sequences only have a <literal>USAGE</literal>
425    privilege, which controls the use of the <literal>NEXT VALUE FOR</literal>
426    expression, which is equivalent to the
427    function <function>nextval</function> in PostgreSQL.  The sequence
428    privileges <literal>SELECT</literal> and <literal>UPDATE</literal> are
429    PostgreSQL extensions.  The application of the
430    sequence <literal>USAGE</literal> privilege to
431    the <literal>currval</literal> function is also a PostgreSQL extension (as
432    is the function itself).
433   </para>
434
435   <para>
436    Privileges on databases, tablespaces, schemas, and languages are
437    <productname>PostgreSQL</productname> extensions.
438   </para>
439 </refsect1>
440
441
442 <refsect1>
443  <title>See Also</title>
444
445  <simplelist type="inline">
446   <member><xref linkend="sql-revoke"/></member>
447   <member><xref linkend="sql-alterdefaultprivileges"/></member>
448  </simplelist>
449 </refsect1>
450
451</refentry>
452