1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/grant.sgml,v 1.31 2002/11/21 23:34:43 petere 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">tablename</replaceable> [, ...]
TO { <replaceable class="PARAMETER">username</replaceable> | GROUP <replaceable class="PARAMETER">groupname</replaceable> | PUBLIC } [, ...]
GRANT { { CREATE | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] }
ON DATABASE <replaceable>dbname</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 } [, ...]
GRANT { { CREATE | USAGE } [,...] | ALL [ PRIVILEGES ] }
ON SCHEMA <replaceable>schemaname</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, database, function, procedural language,
or schema) 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>
There is no need to grant privileges to the creator of an object,
as the creator has all privileges by default.
(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 an object, or to alter it in any way
not described by a grantable right, is likewise inherent in the
creator, and cannot be granted or revoked.
</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 and schemas;
<literal>TEMP</> table creation privilege for databases;
<literal>EXECUTE</> privilege for functions; and
<literal>USAGE</> privilege for languages.
The object creator 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 <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
<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 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 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>
The <xref linkend="sql-revoke" endterm="sql-revoke-title"> command is used
to revoke access privileges.
</para>
<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>\dp</command> command
to obtain information about existing privileges, for example:
<programlisting>
lusitania=> \dp mytable
Access privileges for database "lusitania"
Schema | Table | Access privileges
--------+---------+---------------------------------------
public | mytable | {=r,miriam=arwdRxt,"group todos=arw"}
(1 row)
</programlisting>
The entries shown by <command>\dp</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)
</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 field
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}</>) and then modify them per the specified request.
</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" 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:
-->