1GRANT(7)                 PostgreSQL 10.7 Documentation                GRANT(7)
2
3
4

NAME

6       GRANT - define access privileges
7

SYNOPSIS

9       GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
10           [, ...] | ALL [ PRIVILEGES ] }
11           ON { [ TABLE ] table_name [, ...]
12                | ALL TABLES IN SCHEMA schema_name [, ...] }
13           TO role_specification [, ...] [ WITH GRANT OPTION ]
14
15       GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( column_name [, ...] )
16           [, ...] | ALL [ PRIVILEGES ] ( column_name [, ...] ) }
17           ON [ TABLE ] table_name [, ...]
18           TO role_specification [, ...] [ WITH GRANT OPTION ]
19
20       GRANT { { USAGE | SELECT | UPDATE }
21           [, ...] | ALL [ PRIVILEGES ] }
22           ON { SEQUENCE sequence_name [, ...]
23                | ALL SEQUENCES IN SCHEMA schema_name [, ...] }
24           TO role_specification [, ...] [ WITH GRANT OPTION ]
25
26       GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
27           ON DATABASE database_name [, ...]
28           TO role_specification [, ...] [ WITH GRANT OPTION ]
29
30       GRANT { USAGE | ALL [ PRIVILEGES ] }
31           ON DOMAIN domain_name [, ...]
32           TO role_specification [, ...] [ WITH GRANT OPTION ]
33
34       GRANT { USAGE | ALL [ PRIVILEGES ] }
35           ON FOREIGN DATA WRAPPER fdw_name [, ...]
36           TO role_specification [, ...] [ WITH GRANT OPTION ]
37
38       GRANT { USAGE | ALL [ PRIVILEGES ] }
39           ON FOREIGN SERVER server_name [, ...]
40           TO role_specification [, ...] [ WITH GRANT OPTION ]
41
42       GRANT { EXECUTE | ALL [ PRIVILEGES ] }
43           ON { FUNCTION function_name [ ( [ [ argmode ] [ arg_name ] arg_type [, ...] ] ) ] [, ...]
44                | ALL FUNCTIONS IN SCHEMA schema_name [, ...] }
45           TO role_specification [, ...] [ WITH GRANT OPTION ]
46
47       GRANT { USAGE | ALL [ PRIVILEGES ] }
48           ON LANGUAGE lang_name [, ...]
49           TO role_specification [, ...] [ WITH GRANT OPTION ]
50
51       GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
52           ON LARGE OBJECT loid [, ...]
53           TO role_specification [, ...] [ WITH GRANT OPTION ]
54
55       GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
56           ON SCHEMA schema_name [, ...]
57           TO role_specification [, ...] [ WITH GRANT OPTION ]
58
59       GRANT { CREATE | ALL [ PRIVILEGES ] }
60           ON TABLESPACE tablespace_name [, ...]
61           TO role_specification [, ...] [ WITH GRANT OPTION ]
62
63       GRANT { USAGE | ALL [ PRIVILEGES ] }
64           ON TYPE type_name [, ...]
65           TO role_specification [, ...] [ WITH GRANT OPTION ]
66
67       where role_specification can be:
68
69           [ GROUP ] role_name
70         | PUBLIC
71         | CURRENT_USER
72         | SESSION_USER
73
74       GRANT role_name [, ...] TO role_name [, ...] [ WITH ADMIN OPTION ]
75

DESCRIPTION

77       The GRANT command has two basic variants: one that grants privileges on
78       a database object (table, column, view, foreign table, sequence,
79       database, foreign-data wrapper, foreign server, function, procedural
80       language, schema, or tablespace), and one that grants membership in a
81       role. These variants are similar in many ways, but they are different
82       enough to be described separately.
83
84   GRANT on Database Objects
85       This variant of the GRANT command gives specific privileges on a
86       database object to one or more roles. These privileges are added to
87       those already granted, if any.
88
89       There is also an option to grant privileges on all objects of the same
90       type within one or more schemas. This functionality is currently
91       supported only for tables, sequences, and functions (but note that ALL
92       TABLES is considered to include views and foreign tables).
93
94       The key word PUBLIC indicates that the privileges are to be granted to
95       all roles, including those that might be created later.  PUBLIC can be
96       thought of as an implicitly defined group that always includes all
97       roles. Any particular role will have the sum of privileges granted
98       directly to it, privileges granted to any role it is presently a member
99       of, and privileges granted to PUBLIC.
100
101       If WITH GRANT OPTION is specified, the recipient of the privilege can
102       in turn grant it to others. Without a grant option, the recipient
103       cannot do that. Grant options cannot be granted to PUBLIC.
104
105       There is no need to grant privileges to the owner of an object (usually
106       the user that created it), as the owner has all privileges by default.
107       (The owner could, however, choose to revoke some of their own
108       privileges for safety.)
109
110       The right to drop an object, or to alter its definition in any way, is
111       not treated as a grantable privilege; it is inherent in the owner, and
112       cannot be granted or revoked. (However, a similar effect can be
113       obtained by granting or revoking membership in the role that owns the
114       object; see below.) The owner implicitly has all grant options for the
115       object, too.
116
117       PostgreSQL grants default privileges on some types of objects to
118       PUBLIC. No privileges are granted to PUBLIC by default on tables, table
119       columns, sequences, foreign data wrappers, foreign servers, large
120       objects, schemas, or tablespaces. For other types of objects, the
121       default privileges granted to PUBLIC are as follows: CONNECT and
122       TEMPORARY (create temporary tables) privileges for databases; EXECUTE
123       privilege for functions; and USAGE privilege for languages and data
124       types (including domains). The object owner can, of course, REVOKE both
125       default and expressly granted privileges. (For maximum security, issue
126       the REVOKE in the same transaction that creates the object; then there
127       is no window in which another user can use the object.) Also, these
128       initial default privilege settings can be changed using the ALTER
129       DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7)) command.
130
131       The possible privileges are:
132
133       SELECT
134           Allows SELECT(7) from any column, or the specific columns listed,
135           of the specified table, view, or sequence. Also allows the use of
136           COPY(7) TO. This privilege is also needed to reference existing
137           column values in UPDATE(7) or DELETE(7). For sequences, this
138           privilege also allows the use of the currval function. For large
139           objects, this privilege allows the object to be read.
140
141       INSERT
142           Allows INSERT(7) of a new row into the specified table. If specific
143           columns are listed, only those columns may be assigned to in the
144           INSERT command (other columns will therefore receive default
145           values). Also allows COPY(7) FROM.
146
147       UPDATE
148           Allows UPDATE(7) of any column, or the specific columns listed, of
149           the specified table. (In practice, any nontrivial UPDATE command
150           will require SELECT privilege as well, since it must reference
151           table columns to determine which rows to update, and/or to compute
152           new values for columns.)  SELECT ... FOR UPDATE and SELECT ... FOR
153           SHARE also require this privilege on at least one column, in
154           addition to the SELECT privilege. For sequences, this privilege
155           allows the use of the nextval and setval functions. For large
156           objects, this privilege allows writing or truncating the object.
157
158       DELETE
159           Allows DELETE(7) of a row from the specified table. (In practice,
160           any nontrivial DELETE command will require SELECT privilege as
161           well, since it must reference table columns to determine which rows
162           to delete.)
163
164       TRUNCATE
165           Allows TRUNCATE(7) on the specified table.
166
167       REFERENCES
168           Allows creation of a foreign key constraint referencing the
169           specified table, or specified column(s) of the table. (See the
170           CREATE TABLE (CREATE_TABLE(7)) statement.)
171
172       TRIGGER
173           Allows the creation of a trigger on the specified table. (See the
174           CREATE TRIGGER (CREATE_TRIGGER(7)) statement.)
175
176       CREATE
177           For databases, allows new schemas and publications to be created
178           within the database.
179
180           For schemas, allows new objects to be created within the schema. To
181           rename an existing object, you must own the object and have this
182           privilege for the containing schema.
183
184           For tablespaces, allows tables, indexes, and temporary files to be
185           created within the tablespace, and allows databases to be created
186           that have the tablespace as their default tablespace. (Note that
187           revoking this privilege will not alter the placement of existing
188           objects.)
189
190       CONNECT
191           Allows the user to connect to the specified database. This
192           privilege is checked at connection startup (in addition to checking
193           any restrictions imposed by pg_hba.conf).
194
195       TEMPORARY
196       TEMP
197           Allows temporary tables to be created while using the specified
198           database.
199
200       EXECUTE
201           Allows the use of the specified function and the use of any
202           operators that are implemented on top of the function. This is the
203           only type of privilege that is applicable to functions. (This
204           syntax works for aggregate functions, as well.)
205
206       USAGE
207           For procedural languages, allows the use of the specified language
208           for the creation of functions in that language. This is the only
209           type of privilege that is applicable to procedural languages.
210
211           For schemas, allows access to objects contained in the specified
212           schema (assuming that the objects' own privilege requirements are
213           also met). Essentially this allows the grantee to “look up” objects
214           within the schema. Without this permission, it is still possible to
215           see the object names, e.g. by querying the system tables. Also,
216           after revoking this permission, existing backends might have
217           statements that have previously performed this lookup, so this is
218           not a completely secure way to prevent object access.
219
220           For sequences, this privilege allows the use of the currval and
221           nextval functions.
222
223           For types and domains, this privilege allows the use of the type or
224           domain in the creation of tables, functions, and other schema
225           objects. (Note that it does not control general “usage” of the
226           type, such as values of the type appearing in queries. It only
227           prevents objects from being created that depend on the type. The
228           main purpose of the privilege is controlling which users create
229           dependencies on a type, which could prevent the owner from changing
230           the type later.)
231
232           For foreign-data wrappers, this privilege allows creation of new
233           servers using the foreign-data wrapper.
234
235           For servers, this privilege allows creation of foreign tables using
236           the server. Grantees may also create, alter, or drop their own user
237           mappings associated with that server.
238
239       ALL PRIVILEGES
240           Grant all of the available privileges at once. The PRIVILEGES key
241           word is optional in PostgreSQL, though it is required by strict
242           SQL.
243       The privileges required by other commands are listed on the reference
244       page of the respective command.
245
246   GRANT on Roles
247       This variant of the GRANT command grants membership in a role to one or
248       more other roles. Membership in a role is significant because it
249       conveys the privileges granted to a role to each of its members.
250
251       If WITH ADMIN OPTION is specified, the member can in turn grant
252       membership in the role to others, and revoke membership in the role as
253       well. Without the admin option, ordinary users cannot do that. A role
254       is not considered to hold WITH ADMIN OPTION on itself, but it may grant
255       or revoke membership in itself from a database session where the
256       session user matches the role. Database superusers can grant or revoke
257       membership in any role to anyone. Roles having CREATEROLE privilege can
258       grant or revoke membership in any role that is not a superuser.
259
260       Unlike the case with privileges, membership in a role cannot be granted
261       to PUBLIC. Note also that this form of the command does not allow the
262       noise word GROUP.
263

NOTES

265       The REVOKE(7) command is used to revoke access privileges.
266
267       Since PostgreSQL 8.1, the concepts of users and groups have been
268       unified into a single kind of entity called a role. It is therefore no
269       longer necessary to use the keyword GROUP to identify whether a grantee
270       is a user or a group.  GROUP is still allowed in the command, but it is
271       a noise word.
272
273       A user may perform SELECT, INSERT, etc. on a column if they hold that
274       privilege for either the specific column or its whole table. Granting
275       the privilege at the table level and then revoking it for one column
276       will not do what one might wish: the table-level grant is unaffected by
277       a column-level operation.
278
279       When a non-owner of an object attempts to GRANT privileges on the
280       object, the command will fail outright if the user has no privileges
281       whatsoever on the object. As long as some privilege is available, the
282       command will proceed, but it will grant only those privileges for which
283       the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
284       warning message if no grant options are held, while the other forms
285       will issue a warning if grant options for any of the privileges
286       specifically named in the command are not held. (In principle these
287       statements apply to the object owner as well, but since the owner is
288       always treated as holding all grant options, the cases can never
289       occur.)
290
291       It should be noted that database superusers can access all objects
292       regardless of object privilege settings. This is comparable to the
293       rights of root in a Unix system. As with root, it's unwise to operate
294       as a superuser except when absolutely necessary.
295
296       If a superuser chooses to issue a GRANT or REVOKE command, the command
297       is performed as though it were issued by the owner of the affected
298       object. In particular, privileges granted via such a command will
299       appear to have been granted by the object owner. (For role membership,
300       the membership appears to have been granted by the containing role
301       itself.)
302
303       GRANT and REVOKE can also be done by a role that is not the owner of
304       the affected object, but is a member of the role that owns the object,
305       or is a member of a role that holds privileges WITH GRANT OPTION on the
306       object. In this case the privileges will be recorded as having been
307       granted by the role that actually owns the object or holds the
308       privileges WITH GRANT OPTION. For example, if table t1 is owned by role
309       g1, of which role u1 is a member, then u1 can grant privileges on t1 to
310       u2, but those privileges will appear to have been granted directly by
311       g1. Any other member of role g1 could revoke them later.
312
313       If the role executing GRANT holds the required privileges indirectly
314       via more than one role membership path, it is unspecified which
315       containing role will be recorded as having done the grant. In such
316       cases it is best practice to use SET ROLE to become the specific role
317       you want to do the GRANT as.
318
319       Granting permission on a table does not automatically extend
320       permissions to any sequences used by the table, including sequences
321       tied to SERIAL columns. Permissions on sequences must be set
322       separately.
323
324       Use psql(1)'s \dp command to obtain information about existing
325       privileges for tables and columns. For example:
326
327           => \dp mytable
328                                         Access privileges
329            Schema |  Name   | Type  |   Access privileges   | Column access privileges
330           --------+---------+-------+-----------------------+--------------------------
331            public | mytable | table | miriam=arwdDxt/miriam | col1:
332                                     : =r/miriam             :   miriam_rw=rw/miriam
333                                     : admin=arw/miriam
334           (1 row)
335
336       The entries shown by \dp are interpreted thus:
337
338           rolename=xxxx -- privileges granted to a role
339                   =xxxx -- privileges granted to PUBLIC
340
341                       r -- SELECT ("read")
342                       w -- UPDATE ("write")
343                       a -- INSERT ("append")
344                       d -- DELETE
345                       D -- TRUNCATE
346                       x -- REFERENCES
347                       t -- TRIGGER
348                       X -- EXECUTE
349                       U -- USAGE
350                       C -- CREATE
351                       c -- CONNECT
352                       T -- TEMPORARY
353                 arwdDxt -- ALL PRIVILEGES (for tables, varies for other objects)
354                       * -- grant option for preceding privilege
355
356                   /yyyy -- role that granted this privilege
357
358       The above example display would be seen by user miriam after creating
359       table mytable and doing:
360
361           GRANT SELECT ON mytable TO PUBLIC;
362           GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
363           GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
364
365       For non-table objects there are other \d commands that can display
366       their privileges.
367
368       If the “Access privileges” column is empty for a given object, it means
369       the object has default privileges (that is, its privileges column is
370       null). Default privileges always include all privileges for the owner,
371       and can include some privileges for PUBLIC depending on the object
372       type, as explained above. The first GRANT or REVOKE on an object will
373       instantiate the default privileges (producing, for example,
374       {miriam=arwdDxt/miriam}) and then modify them per the specified
375       request. Similarly, entries are shown in “Column access privileges”
376       only for columns with nondefault privileges. (Note: for this purpose,
377       “default privileges” always means the built-in default privileges for
378       the object's type. An object whose privileges have been affected by an
379       ALTER DEFAULT PRIVILEGES command will always be shown with an explicit
380       privilege entry that includes the effects of the ALTER.)
381
382       Notice that the owner's implicit grant options are not marked in the
383       access privileges display. A * will appear only when grant options have
384       been explicitly granted to someone.
385

EXAMPLES

387       Grant insert privilege to all users on table films:
388
389           GRANT INSERT ON films TO PUBLIC;
390
391       Grant all available privileges to user manuel on view kinds:
392
393           GRANT ALL PRIVILEGES ON kinds TO manuel;
394
395       Note that while the above will indeed grant all privileges if executed
396       by a superuser or the owner of kinds, when executed by someone else it
397       will only grant those permissions for which the someone else has grant
398       options.
399
400       Grant membership in role admins to user joe:
401
402           GRANT admins TO joe;
403

COMPATIBILITY

405       According to the SQL standard, the PRIVILEGES key word in ALL
406       PRIVILEGES is required. The SQL standard does not support setting the
407       privileges on more than one object per command.
408
409       PostgreSQL allows an object owner to revoke their own ordinary
410       privileges: for example, a table owner can make the table read-only to
411       themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
412       privileges. This is not possible according to the SQL standard. The
413       reason is that PostgreSQL treats the owner's privileges as having been
414       granted by the owner to themselves; therefore they can revoke them too.
415       In the SQL standard, the owner's privileges are granted by an assumed
416       entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
417       rights.
418
419       According to the SQL standard, grant options can be granted to PUBLIC;
420       PostgreSQL only supports granting grant options to roles.
421
422       The SQL standard provides for a USAGE privilege on other kinds of
423       objects: character sets, collations, translations.
424
425       In the SQL standard, sequences only have a USAGE privilege, which
426       controls the use of the NEXT VALUE FOR expression, which is equivalent
427       to the function nextval in PostgreSQL. The sequence privileges SELECT
428       and UPDATE are PostgreSQL extensions. The application of the sequence
429       USAGE privilege to the currval function is also a PostgreSQL extension
430       (as is the function itself).
431
432       Privileges on databases, tablespaces, schemas, and languages are
433       PostgreSQL extensions.
434

SEE ALSO

436       REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
437
438
439
440PostgreSQL 10.7                      2019                             GRANT(7)
Impressum