1GRANT(7)                 PostgreSQL 13.3 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 | PROCEDURE | ROUTINE } routine_name [ ( [ [ argmode ] [ arg_name ] arg_type [, ...] ] ) ] [, ...]
44                | ALL { FUNCTIONS | PROCEDURES | ROUTINES } 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       GRANT role_name [, ...] TO role_specification [, ...]
68           [ WITH ADMIN OPTION ]
69           [ GRANTED BY role_specification ]
70
71       where role_specification can be:
72
73           [ GROUP ] role_name
74         | PUBLIC
75         | CURRENT_USER
76         | SESSION_USER
77

DESCRIPTION

79       The GRANT command has two basic variants: one that grants privileges on
80       a database object (table, column, view, foreign table, sequence,
81       database, foreign-data wrapper, foreign server, function, procedure,
82       procedural language, schema, or tablespace), and one that grants
83       membership in a role. These variants are similar in many ways, but they
84       are different enough to be described separately.
85
86   GRANT on Database Objects
87       This variant of the GRANT command gives specific privileges on a
88       database object to one or more roles. These privileges are added to
89       those already granted, if any.
90
91       The key word PUBLIC indicates that the privileges are to be granted to
92       all roles, including those that might be created later.  PUBLIC can be
93       thought of as an implicitly defined group that always includes all
94       roles. Any particular role will have the sum of privileges granted
95       directly to it, privileges granted to any role it is presently a member
96       of, and privileges granted to PUBLIC.
97
98       If WITH GRANT OPTION is specified, the recipient of the privilege can
99       in turn grant it to others. Without a grant option, the recipient
100       cannot do that. Grant options cannot be granted to PUBLIC.
101
102       There is no need to grant privileges to the owner of an object (usually
103       the user that created it), as the owner has all privileges by default.
104       (The owner could, however, choose to revoke some of their own
105       privileges for safety.)
106
107       The right to drop an object, or to alter its definition in any way, is
108       not treated as a grantable privilege; it is inherent in the owner, and
109       cannot be granted or revoked. (However, a similar effect can be
110       obtained by granting or revoking membership in the role that owns the
111       object; see below.) The owner implicitly has all grant options for the
112       object, too.
113
114       The possible privileges are:
115
116       SELECT
117       INSERT
118       UPDATE
119       DELETE
120       TRUNCATE
121       REFERENCES
122       TRIGGER
123       CREATE
124       CONNECT
125       TEMPORARY
126       EXECUTE
127       USAGE
128           Specific types of privileges, as defined in Section 5.7.
129
130       TEMP
131           Alternative spelling for TEMPORARY.
132
133       ALL PRIVILEGES
134           Grant all of the privileges available for the object's type. The
135           PRIVILEGES key word is optional in PostgreSQL, though it is
136           required by strict SQL.
137
138       The FUNCTION syntax works for plain functions, aggregate functions, and
139       window functions, but not for procedures; use PROCEDURE for those.
140       Alternatively, use ROUTINE to refer to a function, aggregate function,
141       window function, or procedure regardless of its precise type.
142
143       There is also an option to grant privileges on all objects of the same
144       type within one or more schemas. This functionality is currently
145       supported only for tables, sequences, functions, and procedures.  ALL
146       TABLES also affects views and foreign tables, just like the
147       specific-object GRANT command.  ALL FUNCTIONS also affects aggregate
148       and window functions, but not procedures, again just like the
149       specific-object GRANT command. Use ALL ROUTINES to include procedures.
150
151   GRANT on Roles
152       This variant of the GRANT command grants membership in a role to one or
153       more other roles. Membership in a role is significant because it
154       conveys the privileges granted to a role to each of its members.
155
156       If WITH ADMIN OPTION is specified, the member can in turn grant
157       membership in the role to others, and revoke membership in the role as
158       well. Without the admin option, ordinary users cannot do that. A role
159       is not considered to hold WITH ADMIN OPTION on itself, but it may grant
160       or revoke membership in itself from a database session where the
161       session user matches the role. Database superusers can grant or revoke
162       membership in any role to anyone. Roles having CREATEROLE privilege can
163       grant or revoke membership in any role that is not a superuser.
164
165       If GRANTED BY is specified, the grant is recorded as having been done
166       by the specified role. Only database superusers may use this option,
167       except when it names the same role executing the command.
168
169       Unlike the case with privileges, membership in a role cannot be granted
170       to PUBLIC. Note also that this form of the command does not allow the
171       noise word GROUP in role_specification.
172

NOTES

174       The REVOKE(7) command is used to revoke access privileges.
175
176       Since PostgreSQL 8.1, the concepts of users and groups have been
177       unified into a single kind of entity called a role. It is therefore no
178       longer necessary to use the keyword GROUP to identify whether a grantee
179       is a user or a group.  GROUP is still allowed in the command, but it is
180       a noise word.
181
182       A user may perform SELECT, INSERT, etc. on a column if they hold that
183       privilege for either the specific column or its whole table. Granting
184       the privilege at the table level and then revoking it for one column
185       will not do what one might wish: the table-level grant is unaffected by
186       a column-level operation.
187
188       When a non-owner of an object attempts to GRANT privileges on the
189       object, the command will fail outright if the user has no privileges
190       whatsoever on the object. As long as some privilege is available, the
191       command will proceed, but it will grant only those privileges for which
192       the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
193       warning message if no grant options are held, while the other forms
194       will issue a warning if grant options for any of the privileges
195       specifically named in the command are not held. (In principle these
196       statements apply to the object owner as well, but since the owner is
197       always treated as holding all grant options, the cases can never
198       occur.)
199
200       It should be noted that database superusers can access all objects
201       regardless of object privilege settings. This is comparable to the
202       rights of root in a Unix system. As with root, it's unwise to operate
203       as a superuser except when absolutely necessary.
204
205       If a superuser chooses to issue a GRANT or REVOKE command, the command
206       is performed as though it were issued by the owner of the affected
207       object. In particular, privileges granted via such a command will
208       appear to have been granted by the object owner. (For role membership,
209       the membership appears to have been granted by the containing role
210       itself.)
211
212       GRANT and REVOKE can also be done by a role that is not the owner of
213       the affected object, but is a member of the role that owns the object,
214       or is a member of a role that holds privileges WITH GRANT OPTION on the
215       object. In this case the privileges will be recorded as having been
216       granted by the role that actually owns the object or holds the
217       privileges WITH GRANT OPTION. For example, if table t1 is owned by role
218       g1, of which role u1 is a member, then u1 can grant privileges on t1 to
219       u2, but those privileges will appear to have been granted directly by
220       g1. Any other member of role g1 could revoke them later.
221
222       If the role executing GRANT holds the required privileges indirectly
223       via more than one role membership path, it is unspecified which
224       containing role will be recorded as having done the grant. In such
225       cases it is best practice to use SET ROLE to become the specific role
226       you want to do the GRANT as.
227
228       Granting permission on a table does not automatically extend
229       permissions to any sequences used by the table, including sequences
230       tied to SERIAL columns. Permissions on sequences must be set
231       separately.
232
233       See Section 5.7 for more information about specific privilege types, as
234       well as how to inspect objects' privileges.
235

EXAMPLES

237       Grant insert privilege to all users on table films:
238
239           GRANT INSERT ON films TO PUBLIC;
240
241       Grant all available privileges to user manuel on view kinds:
242
243           GRANT ALL PRIVILEGES ON kinds TO manuel;
244
245       Note that while the above will indeed grant all privileges if executed
246       by a superuser or the owner of kinds, when executed by someone else it
247       will only grant those permissions for which the someone else has grant
248       options.
249
250       Grant membership in role admins to user joe:
251
252           GRANT admins TO joe;
253

COMPATIBILITY

255       According to the SQL standard, the PRIVILEGES key word in ALL
256       PRIVILEGES is required. The SQL standard does not support setting the
257       privileges on more than one object per command.
258
259       PostgreSQL allows an object owner to revoke their own ordinary
260       privileges: for example, a table owner can make the table read-only to
261       themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
262       privileges. This is not possible according to the SQL standard. The
263       reason is that PostgreSQL treats the owner's privileges as having been
264       granted by the owner to themselves; therefore they can revoke them too.
265       In the SQL standard, the owner's privileges are granted by an assumed
266       entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
267       rights.
268
269       According to the SQL standard, grant options can be granted to PUBLIC;
270       PostgreSQL only supports granting grant options to roles.
271
272       The SQL standard allows the GRANTED BY option to be used in all forms
273       of GRANT. PostgreSQL only supports it when granting role membership,
274       and even then only superusers may use it in nontrivial ways.
275
276       The SQL standard provides for a USAGE privilege on other kinds of
277       objects: character sets, collations, translations.
278
279       In the SQL standard, sequences only have a USAGE privilege, which
280       controls the use of the NEXT VALUE FOR expression, which is equivalent
281       to the function nextval in PostgreSQL. The sequence privileges SELECT
282       and UPDATE are PostgreSQL extensions. The application of the sequence
283       USAGE privilege to the currval function is also a PostgreSQL extension
284       (as is the function itself).
285
286       Privileges on databases, tablespaces, schemas, and languages are
287       PostgreSQL extensions.
288

SEE ALSO

290       REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
291
292
293
294PostgreSQL 13.3                      2021                             GRANT(7)
Impressum