1GRANT(7) PostgreSQL 15.4 Documentation GRANT(7)
2
3
4
6 GRANT - define access privileges
7
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 OPTION ]
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
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 conveys the privileges granted to a role to each of its members.
181
182 If WITH ADMIN OPTION is specified, the member can in turn grant
183 membership in the role to others, and revoke membership in the role as
184 well. Without the admin option, ordinary users cannot do that. A role
185 is not considered to hold WITH ADMIN OPTION on itself. Database
186 superusers can grant or revoke membership in any role to anyone. Roles
187 having CREATEROLE privilege can grant or revoke membership in any role
188 that is not a superuser.
189
190 If GRANTED BY is specified, the grant is recorded as having been done
191 by the specified role. Only database superusers may use this option,
192 except when it names the same role executing the command.
193
194 Unlike the case with privileges, membership in a role cannot be granted
195 to PUBLIC. Note also that this form of the command does not allow the
196 noise word GROUP in role_specification.
197
199 The REVOKE command is used to revoke access privileges.
200
201 Since PostgreSQL 8.1, the concepts of users and groups have been
202 unified into a single kind of entity called a role. It is therefore no
203 longer necessary to use the keyword GROUP to identify whether a grantee
204 is a user or a group. GROUP is still allowed in the command, but it is
205 a noise word.
206
207 A user may perform SELECT, INSERT, etc. on a column if they hold that
208 privilege for either the specific column or its whole table. Granting
209 the privilege at the table level and then revoking it for one column
210 will not do what one might wish: the table-level grant is unaffected by
211 a column-level operation.
212
213 When a non-owner of an object attempts to GRANT privileges on the
214 object, the command will fail outright if the user has no privileges
215 whatsoever on the object. As long as some privilege is available, the
216 command will proceed, but it will grant only those privileges for which
217 the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
218 warning message if no grant options are held, while the other forms
219 will issue a warning if grant options for any of the privileges
220 specifically named in the command are not held. (In principle these
221 statements apply to the object owner as well, but since the owner is
222 always treated as holding all grant options, the cases can never
223 occur.)
224
225 It should be noted that database superusers can access all objects
226 regardless of object privilege settings. This is comparable to the
227 rights of root in a Unix system. As with root, it's unwise to operate
228 as a superuser except when absolutely necessary.
229
230 If a superuser chooses to issue a GRANT or REVOKE command, the command
231 is performed as though it were issued by the owner of the affected
232 object. In particular, privileges granted via such a command will
233 appear to have been granted by the object owner. (For role membership,
234 the membership appears to have been granted by the containing role
235 itself.)
236
237 GRANT and REVOKE can also be done by a role that is not the owner of
238 the affected object, but is a member of the role that owns the object,
239 or is a member of a role that holds privileges WITH GRANT OPTION on the
240 object. In this case the privileges will be recorded as having been
241 granted by the role that actually owns the object or holds the
242 privileges WITH GRANT OPTION. For example, if table t1 is owned by role
243 g1, of which role u1 is a member, then u1 can grant privileges on t1 to
244 u2, but those privileges will appear to have been granted directly by
245 g1. Any other member of role g1 could revoke them later.
246
247 If the role executing GRANT holds the required privileges indirectly
248 via more than one role membership path, it is unspecified which
249 containing role will be recorded as having done the grant. In such
250 cases it is best practice to use SET ROLE to become the specific role
251 you want to do the GRANT as.
252
253 Granting permission on a table does not automatically extend
254 permissions to any sequences used by the table, including sequences
255 tied to SERIAL columns. Permissions on sequences must be set
256 separately.
257
258 See Section 5.7 for more information about specific privilege types, as
259 well as how to inspect objects' privileges.
260
262 Grant insert privilege to all users on table films:
263
264 GRANT INSERT ON films TO PUBLIC;
265
266 Grant all available privileges to user manuel on view kinds:
267
268 GRANT ALL PRIVILEGES ON kinds TO manuel;
269
270 Note that while the above will indeed grant all privileges if executed
271 by a superuser or the owner of kinds, when executed by someone else it
272 will only grant those permissions for which the someone else has grant
273 options.
274
275 Grant membership in role admins to user joe:
276
277 GRANT admins TO joe;
278
280 According to the SQL standard, the PRIVILEGES key word in ALL
281 PRIVILEGES is required. The SQL standard does not support setting the
282 privileges on more than one object per command.
283
284 PostgreSQL allows an object owner to revoke their own ordinary
285 privileges: for example, a table owner can make the table read-only to
286 themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
287 privileges. This is not possible according to the SQL standard. The
288 reason is that PostgreSQL treats the owner's privileges as having been
289 granted by the owner to themselves; therefore they can revoke them too.
290 In the SQL standard, the owner's privileges are granted by an assumed
291 entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
292 rights.
293
294 According to the SQL standard, grant options can be granted to PUBLIC;
295 PostgreSQL only supports granting grant options to roles.
296
297 The SQL standard allows the GRANTED BY option to specify only
298 CURRENT_USER or CURRENT_ROLE. The other variants are PostgreSQL
299 extensions.
300
301 The SQL standard provides for a USAGE privilege on other kinds of
302 objects: character sets, collations, translations.
303
304 In the SQL standard, sequences only have a USAGE privilege, which
305 controls the use of the NEXT VALUE FOR expression, which is equivalent
306 to the function nextval in PostgreSQL. The sequence privileges SELECT
307 and UPDATE are PostgreSQL extensions. The application of the sequence
308 USAGE privilege to the currval function is also a PostgreSQL extension
309 (as is the function itself).
310
311 Privileges on databases, tablespaces, schemas, languages, and
312 configuration parameters are PostgreSQL extensions.
313
315 REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
316
317
318
319PostgreSQL 15.4 2023 GRANT(7)