Make LC_COLLATE and LC_CTYPE database-level settings. Collation and
[PostgreSQL.git] / doc / src / sgml / ref / grant.sgml
blob8a9fde3018fb6e890a7c24860172bbe6d54b13d1
1 <!--
2 $PostgreSQL$
3 PostgreSQL documentation
4 -->
6 <refentry id="SQL-GRANT">
7 <refmeta>
8 <refentrytitle id="sql-grant-title">GRANT</refentrytitle>
9 <refmiscinfo>SQL - Language Statements</refmiscinfo>
10 </refmeta>
12 <refnamediv>
13 <refname>GRANT</refname>
14 <refpurpose>define access privileges</refpurpose>
15 </refnamediv>
17 <indexterm zone="sql-grant">
18 <primary>GRANT</primary>
19 </indexterm>
21 <refsynopsisdiv>
22 <synopsis>
23 GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
24 [,...] | ALL [ PRIVILEGES ] }
25 ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...]
26 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
28 GRANT { { USAGE | SELECT | UPDATE }
29 [,...] | ALL [ PRIVILEGES ] }
30 ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...]
31 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
33 GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] }
34 ON DATABASE <replaceable>dbname</replaceable> [, ...]
35 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
37 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
38 ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [, ...]
39 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
41 GRANT { USAGE | ALL [ PRIVILEGES ] }
42 ON LANGUAGE <replaceable>langname</replaceable> [, ...]
43 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
45 GRANT { { CREATE | USAGE } [,...] | ALL [ PRIVILEGES ] }
46 ON SCHEMA <replaceable>schemaname</replaceable> [, ...]
47 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
49 GRANT { CREATE | ALL [ PRIVILEGES ] }
50 ON TABLESPACE <replaceable>tablespacename</> [, ...]
51 TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
53 GRANT <replaceable class="PARAMETER">role</replaceable> [, ...] TO <replaceable class="PARAMETER">rolename</replaceable> [, ...] [ WITH ADMIN OPTION ]
54 </synopsis>
55 </refsynopsisdiv>
57 <refsect1 id="sql-grant-description">
58 <title>Description</title>
60 <para>
61 The <command>GRANT</command> command has two basic variants: one
62 that grants privileges on a database object (table, view, sequence,
63 database, function, procedural language, schema, or tablespace),
64 and one that grants membership in a role. These variants are
65 similar in many ways, but they are different enough to be described
66 separately.
67 </para>
69 <para>
70 As of <productname>PostgreSQL</productname> 8.1, the concepts of users and
71 groups have been unified into a single kind of entity called a role.
72 It is therefore no longer necessary to use the keyword <literal>GROUP</>
73 to identify whether a grantee is a user or a group. <literal>GROUP</>
74 is still allowed in the command, but it is a noise word.
75 </para>
77 <refsect2 id="sql-grant-description-objects">
78 <title>GRANT on Database Objects</title>
80 <para>
81 This variant of the <command>GRANT</command> command gives specific
82 privileges on a database object to
83 one or more roles. These privileges are added
84 to those already granted, if any.
85 </para>
87 <para>
88 The key word <literal>PUBLIC</literal> indicates that the
89 privileges are to be granted to all roles, including those that might
90 be created later. <literal>PUBLIC</literal> can be thought of as an
91 implicitly defined group that always includes all roles.
92 Any particular role will have the sum
93 of privileges granted directly to it, privileges granted to any role it
94 is presently a member of, and privileges granted to
95 <literal>PUBLIC</literal>.
96 </para>
98 <para>
99 If <literal>WITH GRANT OPTION</literal> is specified, the recipient
100 of the privilege can in turn grant it to others. Without a grant
101 option, the recipient cannot do that. Grant options cannot be granted
102 to <literal>PUBLIC</literal>.
103 </para>
105 <para>
106 There is no need to grant privileges to the owner of an object
107 (usually the user that created it),
108 as the owner has all privileges by default. (The owner could,
109 however, choose to revoke some of his own privileges for safety.)
110 The right to drop an object, or to alter its definition in any way is
111 not described by a grantable privilege; it is inherent in the owner,
112 and cannot be granted or revoked. The owner implicitly has all grant
113 options for the object, too.
114 </para>
116 <para>
117 Depending on the type of object, the initial default privileges might
118 include granting some privileges to <literal>PUBLIC</literal>.
119 The default is no public access for tables, schemas, and tablespaces;
120 <literal>CONNECT</> privilege and <literal>TEMP</> table creation privilege
121 for databases;
122 <literal>EXECUTE</> privilege for functions; and
123 <literal>USAGE</> privilege for languages.
124 The object owner can of course revoke these privileges. (For maximum
125 security, issue the <command>REVOKE</> in the same transaction that
126 creates the object; then there is no window in which another user
127 can use the object.)
128 </para>
130 <para>
131 The possible privileges are:
133 <variablelist>
134 <varlistentry>
135 <term>SELECT</term>
136 <listitem>
137 <para>
138 Allows <xref linkend="sql-select" endterm="sql-select-title"> from
139 any column of the specified table, view, or sequence.
140 Also allows the use of
141 <xref linkend="sql-copy" endterm="sql-copy-title"> TO.
142 This privilege is also needed to reference existing column values in
143 <xref linkend="sql-update" endterm="sql-update-title"> or
144 <xref linkend="sql-delete" endterm="sql-delete-title">.
145 For sequences, this privilege also allows the use of the
146 <function>currval</function> function.
147 </para>
148 </listitem>
149 </varlistentry>
151 <varlistentry>
152 <term>INSERT</term>
153 <listitem>
154 <para>
155 Allows <xref linkend="sql-insert" endterm="sql-insert-title"> of a new
156 row into the specified table.
157 Also allows <xref linkend="sql-copy" endterm="sql-copy-title"> FROM.
158 </para>
159 </listitem>
160 </varlistentry>
162 <varlistentry>
163 <term>UPDATE</term>
164 <listitem>
165 <para>
166 Allows <xref linkend="sql-update" endterm="sql-update-title"> of any
167 column of the specified table.
168 (In practice, any nontrivial <command>UPDATE</> command will require
169 <literal>SELECT</> privilege as well, since it must reference table
170 columns to determine which rows to update, and/or to compute new
171 values for columns.)
172 <literal>SELECT ... FOR UPDATE</literal>
173 and <literal>SELECT ... FOR SHARE</literal>
174 also require this privilege, in addition to the
175 <literal>SELECT</literal> privilege. For sequences, this
176 privilege allows the use of the <function>nextval</function> and
177 <function>setval</function> functions.
178 </para>
179 </listitem>
180 </varlistentry>
182 <varlistentry>
183 <term>DELETE</term>
184 <listitem>
185 <para>
186 Allows <xref linkend="sql-delete" endterm="sql-delete-title"> of a row
187 from the specified table.
188 (In practice, any nontrivial <command>DELETE</> command will require
189 <literal>SELECT</> privilege as well, since it must reference table
190 columns to determine which rows to delete.)
191 </para>
192 </listitem>
193 </varlistentry>
195 <varlistentry>
196 <term>TRUNCATE</term>
197 <listitem>
198 <para>
199 Allows <xref linkend="sql-truncate" endterm="sql-truncate-title"> on
200 the specified table.
201 </para>
202 </listitem>
203 </varlistentry>
205 <varlistentry>
206 <term>REFERENCES</term>
207 <listitem>
208 <para>
209 To create a foreign key constraint, it is
210 necessary to have this privilege on both the referencing and
211 referenced tables.
212 </para>
213 </listitem>
214 </varlistentry>
216 <varlistentry>
217 <term>TRIGGER</term>
218 <listitem>
219 <para>
220 Allows the creation of a trigger on the specified table. (See the
221 <xref linkend="sql-createtrigger" endterm="sql-createtrigger-title"> statement.)
222 </para>
223 </listitem>
224 </varlistentry>
226 <varlistentry>
227 <term>CREATE</term>
228 <listitem>
229 <para>
230 For databases, allows new schemas to be created within the database.
231 </para>
232 <para>
233 For schemas, allows new objects to be created within the schema.
234 To rename an existing object, you must own the object <emphasis>and</>
235 have this privilege for the containing schema.
236 </para>
237 <para>
238 For tablespaces, allows tables, indexes, and temporary files to be
239 created within the tablespace, and allows databases to be created that
240 have the tablespace as their default tablespace. (Note that revoking
241 this privilege will not alter the placement of existing objects.)
242 </para>
243 </listitem>
244 </varlistentry>
246 <varlistentry>
247 <term>CONNECT</term>
248 <listitem>
249 <para>
250 Allows the user to connect to the specified database. This
251 privilege is checked at connection startup (in addition to checking
252 any restrictions imposed by <filename>pg_hba.conf</>).
253 </para>
254 </listitem>
255 </varlistentry>
257 <varlistentry>
258 <term>TEMPORARY</term>
259 <term>TEMP</term>
260 <listitem>
261 <para>
262 Allows temporary tables to be created while using the specified database.
263 </para>
264 </listitem>
265 </varlistentry>
267 <varlistentry>
268 <term>EXECUTE</term>
269 <listitem>
270 <para>
271 Allows the use of the specified function and the use of any
272 operators that are implemented on top of the function. This is
273 the only type of privilege that is applicable to functions.
274 (This syntax works for aggregate functions, as well.)
275 </para>
276 </listitem>
277 </varlistentry>
279 <varlistentry>
280 <term>USAGE</term>
281 <listitem>
282 <para>
283 For procedural languages, allows the use of the specified language for
284 the creation of functions in that language. This is the only type
285 of privilege that is applicable to procedural languages.
286 </para>
287 <para>
288 For schemas, allows access to objects contained in the specified
289 schema (assuming that the objects' own privilege requirements are
290 also met). Essentially this allows the grantee to <quote>look up</>
291 objects within the schema. Without this permission, it is still
292 possible to see the object names, e.g. by querying the system tables.
293 Also, after revoking this permission, existing backends might have
294 statements that have previously performed this lookup, so this is not
295 a completely secure way to prevent object access.
296 </para>
297 <para>
298 For sequences, this privilege allows the use of the
299 <function>currval</function> and <function>nextval</function> functions.
300 </para>
301 </listitem>
302 </varlistentry>
304 <varlistentry>
305 <term>ALL PRIVILEGES</term>
306 <listitem>
307 <para>
308 Grant all of the available privileges at once.
309 The <literal>PRIVILEGES</literal> key word is optional in
310 <productname>PostgreSQL</productname>, though it is required by
311 strict SQL.
312 </para>
313 </listitem>
314 </varlistentry>
315 </variablelist>
317 The privileges required by other commands are listed on the
318 reference page of the respective command.
319 </para>
320 </refsect2>
322 <refsect2 id="sql-grant-description-roles">
323 <title>GRANT on Roles</title>
325 <para>
326 This variant of the <command>GRANT</command> command grants membership
327 in a role to one or more other roles. Membership in a role is significant
328 because it conveys the privileges granted to a role to each of its
329 members.
330 </para>
332 <para>
333 If <literal>WITH ADMIN OPTION</literal> is specified, the member can
334 in turn grant membership in the role to others, and revoke membership
335 in the role as well. Without the admin option, ordinary users cannot do
336 that. However,
337 database superusers can grant or revoke membership in any role to anyone.
338 Roles having <literal>CREATEROLE</> privilege can grant or revoke
339 membership in any role that is not a superuser.
340 </para>
342 <para>
343 Unlike the case with privileges, membership in a role cannot be granted
344 to <literal>PUBLIC</>. Note also that this form of the command does not
345 allow the noise word <literal>GROUP</>.
346 </para>
347 </refsect2>
348 </refsect1>
351 <refsect1 id="SQL-GRANT-notes">
352 <title>Notes</title>
354 <para>
355 The <xref linkend="sql-revoke" endterm="sql-revoke-title"> command is used
356 to revoke access privileges.
357 </para>
359 <para>
360 When a non-owner of an object attempts to <command>GRANT</> privileges
361 on the object, the command will fail outright if the user has no
362 privileges whatsoever on the object. As long as some privilege is
363 available, the command will proceed, but it will grant only those
364 privileges for which the user has grant options. The <command>GRANT ALL
365 PRIVILEGES</> forms will issue a warning message if no grant options are
366 held, while the other forms will issue a warning if grant options for
367 any of the privileges specifically named in the command are not held.
368 (In principle these statements apply to the object owner as well, but
369 since the owner is always treated as holding all grant options, the
370 cases can never occur.)
371 </para>
373 <para>
374 It should be noted that database superusers can access
375 all objects regardless of object privilege settings. This
376 is comparable to the rights of <literal>root</> in a Unix system.
377 As with <literal>root</>, it's unwise to operate as a superuser
378 except when absolutely necessary.
379 </para>
381 <para>
382 If a superuser chooses to issue a <command>GRANT</> or <command>REVOKE</>
383 command, the command is performed as though it were issued by the
384 owner of the affected object. In particular, privileges granted via
385 such a command will appear to have been granted by the object owner.
386 (For role membership, the membership appears to have been granted
387 by the containing role itself.)
388 </para>
390 <para>
391 <command>GRANT</> and <command>REVOKE</> can also be done by a role
392 that is not the owner of the affected object, but is a member of the role
393 that owns the object, or is a member of a role that holds privileges
394 <literal>WITH GRANT OPTION</literal> on the object. In this case the
395 privileges will be recorded as having been granted by the role that
396 actually owns the object or holds the privileges
397 <literal>WITH GRANT OPTION</literal>. For example, if table
398 <literal>t1</> is owned by role <literal>g1</>, of which role
399 <literal>u1</> is a member, then <literal>u1</> can grant privileges
400 on <literal>t1</> to <literal>u2</>, but those privileges will appear
401 to have been granted directly by <literal>g1</>. Any other member
402 of role <literal>g1</> could revoke them later.
403 </para>
405 <para>
406 If the role executing <command>GRANT</> holds the required privileges
407 indirectly via more than one role membership path, it is unspecified
408 which containing role will be recorded as having done the grant. In such
409 cases it is best practice to use <command>SET ROLE</> to become the
410 specific role you want to do the <command>GRANT</> as.
411 </para>
413 <para>
414 Granting permission on a table does not automatically extend
415 permissions to any sequences used by the table, including
416 sequences tied to <type>SERIAL</> columns. Permissions on
417 sequence must be set separately.
418 </para>
420 <para>
421 Currently, <productname>PostgreSQL</productname> does not support
422 granting or revoking privileges for individual columns of a table.
423 One possible workaround is to create a view having just the desired
424 columns and then grant privileges to that view.
425 </para>
427 <para>
428 Use <xref linkend="app-psql">'s <command>\z</command> command
429 to obtain information about existing privileges, for example:
430 <programlisting>
431 =&gt; \z mytable
432 Access privileges
433 Schema | Name | Type | Access privileges
434 --------+---------+-------+-----------------------
435 public | mytable | table | miriam=arwdDxt/miriam
436 : =r/miriam
437 : admin=arw/miriam
438 (1 row)
439 </programlisting>
440 The entries shown by <command>\z</command> are interpreted thus:
441 <programlisting>
442 rolename=xxxx -- privileges granted to a role
443 =xxxx -- privileges granted to PUBLIC
445 r -- SELECT ("read")
446 w -- UPDATE ("write")
447 a -- INSERT ("append")
448 d -- DELETE
449 D -- TRUNCATE
450 x -- REFERENCES
451 t -- TRIGGER
452 X -- EXECUTE
453 U -- USAGE
454 C -- CREATE
455 c -- CONNECT
456 T -- TEMPORARY
457 arwdDxt -- ALL PRIVILEGES (for tables)
458 * -- grant option for preceding privilege
460 /yyyy -- role that granted this privilege
461 </programlisting>
463 The above example display would be seen by user <literal>miriam</> after
464 creating table <literal>mytable</> and doing:
466 <programlisting>
467 GRANT SELECT ON mytable TO PUBLIC;
468 GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
469 </programlisting>
470 </para>
472 <para>
473 If the <quote>Access privileges</> column is empty for a given object,
474 it means the object has default privileges (that is, its privileges column
475 is null). Default privileges always include all privileges for the owner,
476 and can include some privileges for <literal>PUBLIC</> depending on the
477 object type, as explained above. The first <command>GRANT</> or
478 <command>REVOKE</> on an object
479 will instantiate the default privileges (producing, for example,
480 <literal>{miriam=arwdDxt/miriam}</>) and then modify them per the
481 specified request.
482 </para>
484 <para>
485 Notice that the owner's implicit grant options are not marked in the
486 access privileges display. A <literal>*</> will appear only when
487 grant options have been explicitly granted to someone.
488 </para>
489 </refsect1>
491 <refsect1 id="sql-grant-examples">
492 <title>Examples</title>
494 <para>
495 Grant insert privilege to all users on table <literal>films</literal>:
497 <programlisting>
498 GRANT INSERT ON films TO PUBLIC;
499 </programlisting>
500 </para>
502 <para>
503 Grant all available privileges to user <literal>manuel</literal> on view
504 <literal>kinds</literal>:
506 <programlisting>
507 GRANT ALL PRIVILEGES ON kinds TO manuel;
508 </programlisting>
510 Note that while the above will indeed grant all privileges if executed by a
511 superuser or the owner of <literal>kinds</literal>, when executed by someone
512 else it will only grant those permissions for which the someone else has
513 grant options.
514 </para>
516 <para>
517 Grant membership in role <literal>admins</> to user <literal>joe</>:
519 <programlisting>
520 GRANT admins TO joe;
521 </programlisting>
522 </para>
523 </refsect1>
525 <refsect1 id="sql-grant-compatibility">
526 <title>Compatibility</title>
528 <para>
529 According to the SQL standard, the <literal>PRIVILEGES</literal>
530 key word in <literal>ALL PRIVILEGES</literal> is required. The
531 SQL standard does not support setting the privileges on more than
532 one object per command.
533 </para>
535 <para>
536 <productname>PostgreSQL</productname> allows an object owner to revoke his
537 own ordinary privileges: for example, a table owner can make the table
538 read-only to himself by revoking his own <literal>INSERT</>,
539 <literal>UPDATE</>, <literal>DELETE</>, and <literal>TRUNCATE</>
540 privileges. This is not possible according to the SQL standard. The
541 reason is that <productname>PostgreSQL</productname> treats the owner's
542 privileges as having been granted by the owner to himself; therefore he
543 can revoke them too. In the SQL standard, the owner's privileges are
544 granted by an assumed entity <quote>_SYSTEM</>. Not being
545 <quote>_SYSTEM</>, the owner cannot revoke these rights.
546 </para>
548 <para>
549 <productname>PostgreSQL</productname> does not support the SQL-standard
550 functionality of setting privileges for individual columns.
551 </para>
553 <para>
554 The SQL standard provides for a <literal>USAGE</literal> privilege
555 on other kinds of objects: character sets, collations,
556 translations, domains.
557 </para>
559 <para>
560 Privileges on databases, tablespaces, schemas, and languages are
561 <productname>PostgreSQL</productname> extensions.
562 </para>
563 </refsect1>
566 <refsect1>
567 <title>See Also</title>
569 <simpara>
570 <xref linkend="sql-revoke" endterm="sql-revoke-title">
571 </simpara>
572 </refsect1>
574 </refentry>