1GRANT(7)                 PostgreSQL 16.1 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           [ GRANTED BY role_specification ]
15
16       GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( column_name [, ...] )
17           [, ...] | ALL [ PRIVILEGES ] ( column_name [, ...] ) }
18           ON [ TABLE ] table_name [, ...]
19           TO role_specification [, ...] [ WITH GRANT OPTION ]
20           [ GRANTED BY role_specification ]
21
22       GRANT { { USAGE | SELECT | UPDATE }
23           [, ...] | ALL [ PRIVILEGES ] }
24           ON { SEQUENCE sequence_name [, ...]
25                | ALL SEQUENCES IN SCHEMA schema_name [, ...] }
26           TO role_specification [, ...] [ WITH GRANT OPTION ]
27           [ GRANTED BY role_specification ]
28
29       GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
30           ON DATABASE database_name [, ...]
31           TO role_specification [, ...] [ WITH GRANT OPTION ]
32           [ GRANTED BY role_specification ]
33
34       GRANT { USAGE | ALL [ PRIVILEGES ] }
35           ON DOMAIN domain_name [, ...]
36           TO role_specification [, ...] [ WITH GRANT OPTION ]
37           [ GRANTED BY role_specification ]
38
39       GRANT { USAGE | ALL [ PRIVILEGES ] }
40           ON FOREIGN DATA WRAPPER fdw_name [, ...]
41           TO role_specification [, ...] [ WITH GRANT OPTION ]
42           [ GRANTED BY role_specification ]
43
44       GRANT { USAGE | ALL [ PRIVILEGES ] }
45           ON FOREIGN SERVER server_name [, ...]
46           TO role_specification [, ...] [ WITH GRANT OPTION ]
47           [ GRANTED BY role_specification ]
48
49       GRANT { EXECUTE | ALL [ PRIVILEGES ] }
50           ON { { FUNCTION | PROCEDURE | ROUTINE } routine_name [ ( [ [ argmode ] [ arg_name ] arg_type [, ...] ] ) ] [, ...]
51                | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA schema_name [, ...] }
52           TO role_specification [, ...] [ WITH GRANT OPTION ]
53           [ GRANTED BY role_specification ]
54
55       GRANT { USAGE | ALL [ PRIVILEGES ] }
56           ON LANGUAGE lang_name [, ...]
57           TO role_specification [, ...] [ WITH GRANT OPTION ]
58           [ GRANTED BY role_specification ]
59
60       GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
61           ON LARGE OBJECT loid [, ...]
62           TO role_specification [, ...] [ WITH GRANT OPTION ]
63           [ GRANTED BY role_specification ]
64
65       GRANT { { SET | ALTER SYSTEM } [, ... ] | ALL [ PRIVILEGES ] }
66           ON PARAMETER configuration_parameter [, ...]
67           TO role_specification [, ...] [ WITH GRANT OPTION ]
68           [ GRANTED BY role_specification ]
69
70       GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
71           ON SCHEMA schema_name [, ...]
72           TO role_specification [, ...] [ WITH GRANT OPTION ]
73           [ GRANTED BY role_specification ]
74
75       GRANT { CREATE | ALL [ PRIVILEGES ] }
76           ON TABLESPACE tablespace_name [, ...]
77           TO role_specification [, ...] [ WITH GRANT OPTION ]
78           [ GRANTED BY role_specification ]
79
80       GRANT { USAGE | ALL [ PRIVILEGES ] }
81           ON TYPE type_name [, ...]
82           TO role_specification [, ...] [ WITH GRANT OPTION ]
83           [ GRANTED BY role_specification ]
84
85       GRANT role_name [, ...] TO role_specification [, ...]
86           [ WITH { ADMIN | INHERIT | SET } { OPTION | TRUE | FALSE } ]
87           [ GRANTED BY role_specification ]
88
89       where role_specification can be:
90
91           [ GROUP ] role_name
92         | PUBLIC
93         | CURRENT_ROLE
94         | CURRENT_USER
95         | SESSION_USER
96

DESCRIPTION

98       The GRANT command has two basic variants: one that grants privileges on
99       a database object (table, column, view, foreign table, sequence,
100       database, foreign-data wrapper, foreign server, function, procedure,
101       procedural language, large object, configuration parameter, schema,
102       tablespace, or type), and one that grants membership in a role. These
103       variants are similar in many ways, but they are different enough to be
104       described separately.
105
106   GRANT on Database Objects
107       This variant of the GRANT command gives specific privileges on a
108       database object to one or more roles. These privileges are added to
109       those already granted, if any.
110
111       The key word PUBLIC indicates that the privileges are to be granted to
112       all roles, including those that might be created later.  PUBLIC can be
113       thought of as an implicitly defined group that always includes all
114       roles. Any particular role will have the sum of privileges granted
115       directly to it, privileges granted to any role it is presently a member
116       of, and privileges granted to PUBLIC.
117
118       If WITH GRANT OPTION is specified, the recipient of the privilege can
119       in turn grant it to others. Without a grant option, the recipient
120       cannot do that. Grant options cannot be granted to PUBLIC.
121
122       If GRANTED BY is specified, the specified grantor must be the current
123       user. This clause is currently present in this form only for SQL
124       compatibility.
125
126       There is no need to grant privileges to the owner of an object (usually
127       the user that created it), as the owner has all privileges by default.
128       (The owner could, however, choose to revoke some of their own
129       privileges for safety.)
130
131       The right to drop an object, or to alter its definition in any way, is
132       not treated as a grantable privilege; it is inherent in the owner, and
133       cannot be granted or revoked. (However, a similar effect can be
134       obtained by granting or revoking membership in the role that owns the
135       object; see below.) The owner implicitly has all grant options for the
136       object, too.
137
138       The possible privileges are:
139
140       SELECT
141       INSERT
142       UPDATE
143       DELETE
144       TRUNCATE
145       REFERENCES
146       TRIGGER
147       CREATE
148       CONNECT
149       TEMPORARY
150       EXECUTE
151       USAGE
152       SET
153       ALTER SYSTEM
154           Specific types of privileges, as defined in Section 5.7.
155
156       TEMP
157           Alternative spelling for TEMPORARY.
158
159       ALL PRIVILEGES
160           Grant all of the privileges available for the object's type. The
161           PRIVILEGES key word is optional in PostgreSQL, though it is
162           required by strict SQL.
163
164       The FUNCTION syntax works for plain functions, aggregate functions, and
165       window functions, but not for procedures; use PROCEDURE for those.
166       Alternatively, use ROUTINE to refer to a function, aggregate function,
167       window function, or procedure regardless of its precise type.
168
169       There is also an option to grant privileges on all objects of the same
170       type within one or more schemas. This functionality is currently
171       supported only for tables, sequences, functions, and procedures.  ALL
172       TABLES also affects views and foreign tables, just like the
173       specific-object GRANT command.  ALL FUNCTIONS also affects aggregate
174       and window functions, but not procedures, again just like the
175       specific-object GRANT command. Use ALL ROUTINES to include procedures.
176
177   GRANT on Roles
178       This variant of the GRANT command grants membership in a role to one or
179       more other roles. Membership in a role is significant because it
180       potentially allows access to the privileges granted to a role to each
181       of its members, and potentially also the ability to make changes to the
182       role itself. However, the actual permissions conferred depend on the
183       options associated with the grant.
184
185       Each of the options described below can be set to either TRUE or FALSE.
186       The keyword OPTION is accepted as a synonym for TRUE, so that WITH
187       ADMIN OPTION is a synonym for WITH ADMIN TRUE.
188
189       The ADMIN option allows the member to in turn grant membership in the
190       role to others, and revoke membership in the role as well. Without the
191       admin option, ordinary users cannot do that. A role is not considered
192       to hold WITH ADMIN OPTION on itself. Database superusers can grant or
193       revoke membership in any role to anyone. This option defaults to FALSE.
194
195       The INHERIT option, if it is set to TRUE, causes the member to inherit
196       the privileges of the granted role. That is, it can automatically use
197       whatever database privileges have been granted to that role. If set to
198       FALSE, the member does not inherit the privileges of the granted role.
199       If this clause is not specified, it defaults to true if the member role
200       is set to INHERIT and to false if the member role is set to NOINHERIT.
201       See CREATE ROLE.
202
203       The SET option, if it is set to TRUE, allows the member to change to
204       the granted role using the SET ROLE command. If a role is an indirect
205       member of another role, it can use SET ROLE to change to that role only
206       if there is a chain of grants each of which has SET TRUE. This option
207       defaults to TRUE.
208
209       To create an object owned by another role or give ownership of an
210       existing object to another role, you must have the ability to SET ROLE
211       to that role; otherwise, commands such as ALTER ... OWNER TO or CREATE
212       DATABASE ... OWNER will fail. However, a user who inherits the
213       privileges of a role but does not have the ability to SET ROLE to that
214       role may be able to obtain full access to the role by manipulating
215       existing objects owned by that role (e.g. they could redefine an
216       existing function to act as a Trojan horse). Therefore, if a role's
217       privileges are to be inherited but should not be accessible via SET
218       ROLE, it should not own any SQL objects.
219
220       If GRANTED BY is specified, the grant is recorded as having been done
221       by the specified role. A user can only attribute a grant to another
222       role if they possess the privileges of that role. The role recorded as
223       the grantor must have ADMIN OPTION on the target role, unless it is the
224       bootstrap superuser. When a grant is recorded as having a grantor other
225       than the bootstrap superuser, it depends on the grantor continuing to
226       possess ADMIN OPTION on the role; so, if ADMIN OPTION is revoked,
227       dependent grants must be revoked as well.
228
229       Unlike the case with privileges, membership in a role cannot be granted
230       to PUBLIC. Note also that this form of the command does not allow the
231       noise word GROUP in role_specification.
232

NOTES

234       The REVOKE command is used to revoke access privileges.
235
236       Since PostgreSQL 8.1, the concepts of users and groups have been
237       unified into a single kind of entity called a role. It is therefore no
238       longer necessary to use the keyword GROUP to identify whether a grantee
239       is a user or a group.  GROUP is still allowed in the command, but it is
240       a noise word.
241
242       A user may perform SELECT, INSERT, etc. on a column if they hold that
243       privilege for either the specific column or its whole table. Granting
244       the privilege at the table level and then revoking it for one column
245       will not do what one might wish: the table-level grant is unaffected by
246       a column-level operation.
247
248       When a non-owner of an object attempts to GRANT privileges on the
249       object, the command will fail outright if the user has no privileges
250       whatsoever on the object. As long as some privilege is available, the
251       command will proceed, but it will grant only those privileges for which
252       the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
253       warning message if no grant options are held, while the other forms
254       will issue a warning if grant options for any of the privileges
255       specifically named in the command are not held. (In principle these
256       statements apply to the object owner as well, but since the owner is
257       always treated as holding all grant options, the cases can never
258       occur.)
259
260       It should be noted that database superusers can access all objects
261       regardless of object privilege settings. This is comparable to the
262       rights of root in a Unix system. As with root, it's unwise to operate
263       as a superuser except when absolutely necessary.
264
265       If a superuser chooses to issue a GRANT or REVOKE command, the command
266       is performed as though it were issued by the owner of the affected
267       object. In particular, privileges granted via such a command will
268       appear to have been granted by the object owner. (For role membership,
269       the membership appears to have been granted by the bootstrap
270       superuser.)
271
272       GRANT and REVOKE can also be done by a role that is not the owner of
273       the affected object, but is a member of the role that owns the object,
274       or is a member of a role that holds privileges WITH GRANT OPTION on the
275       object. In this case the privileges will be recorded as having been
276       granted by the role that actually owns the object or holds the
277       privileges WITH GRANT OPTION. For example, if table t1 is owned by role
278       g1, of which role u1 is a member, then u1 can grant privileges on t1 to
279       u2, but those privileges will appear to have been granted directly by
280       g1. Any other member of role g1 could revoke them later.
281
282       If the role executing GRANT holds the required privileges indirectly
283       via more than one role membership path, it is unspecified which
284       containing role will be recorded as having done the grant. In such
285       cases it is best practice to use SET ROLE to become the specific role
286       you want to do the GRANT as.
287
288       Granting permission on a table does not automatically extend
289       permissions to any sequences used by the table, including sequences
290       tied to SERIAL columns. Permissions on sequences must be set
291       separately.
292
293       See Section 5.7 for more information about specific privilege types, as
294       well as how to inspect objects' privileges.
295

EXAMPLES

297       Grant insert privilege to all users on table films:
298
299           GRANT INSERT ON films TO PUBLIC;
300
301       Grant all available privileges to user manuel on view kinds:
302
303           GRANT ALL PRIVILEGES ON kinds TO manuel;
304
305       Note that while the above will indeed grant all privileges if executed
306       by a superuser or the owner of kinds, when executed by someone else it
307       will only grant those permissions for which the someone else has grant
308       options.
309
310       Grant membership in role admins to user joe:
311
312           GRANT admins TO joe;
313

COMPATIBILITY

315       According to the SQL standard, the PRIVILEGES key word in ALL
316       PRIVILEGES is required. The SQL standard does not support setting the
317       privileges on more than one object per command.
318
319       PostgreSQL allows an object owner to revoke their own ordinary
320       privileges: for example, a table owner can make the table read-only to
321       themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
322       privileges. This is not possible according to the SQL standard. The
323       reason is that PostgreSQL treats the owner's privileges as having been
324       granted by the owner to themselves; therefore they can revoke them too.
325       In the SQL standard, the owner's privileges are granted by an assumed
326       entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
327       rights.
328
329       According to the SQL standard, grant options can be granted to PUBLIC;
330       PostgreSQL only supports granting grant options to roles.
331
332       The SQL standard allows the GRANTED BY option to specify only
333       CURRENT_USER or CURRENT_ROLE. The other variants are PostgreSQL
334       extensions.
335
336       The SQL standard provides for a USAGE privilege on other kinds of
337       objects: character sets, collations, translations.
338
339       In the SQL standard, sequences only have a USAGE privilege, which
340       controls the use of the NEXT VALUE FOR expression, which is equivalent
341       to the function nextval in PostgreSQL. The sequence privileges SELECT
342       and UPDATE are PostgreSQL extensions. The application of the sequence
343       USAGE privilege to the currval function is also a PostgreSQL extension
344       (as is the function itself).
345
346       Privileges on databases, tablespaces, schemas, languages, and
347       configuration parameters are PostgreSQL extensions.
348

SEE ALSO

350       REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
351
352
353
354PostgreSQL 16.1                      2023                             GRANT(7)
Impressum