1GRANT(7) PostgreSQL 14.3 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 { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
66 ON SCHEMA schema_name [, ...]
67 TO role_specification [, ...] [ WITH GRANT OPTION ]
68 [ GRANTED BY role_specification ]
69
70 GRANT { CREATE | ALL [ PRIVILEGES ] }
71 ON TABLESPACE tablespace_name [, ...]
72 TO role_specification [, ...] [ WITH GRANT OPTION ]
73 [ GRANTED BY role_specification ]
74
75 GRANT { USAGE | ALL [ PRIVILEGES ] }
76 ON TYPE type_name [, ...]
77 TO role_specification [, ...] [ WITH GRANT OPTION ]
78 [ GRANTED BY role_specification ]
79
80 GRANT role_name [, ...] TO role_specification [, ...]
81 [ WITH ADMIN OPTION ]
82 [ GRANTED BY role_specification ]
83
84 where role_specification can be:
85
86 [ GROUP ] role_name
87 | PUBLIC
88 | CURRENT_ROLE
89 | CURRENT_USER
90 | SESSION_USER
91
93 The GRANT command has two basic variants: one that grants privileges on
94 a database object (table, column, view, foreign table, sequence,
95 database, foreign-data wrapper, foreign server, function, procedure,
96 procedural language, schema, or tablespace), and one that grants
97 membership in a role. These variants are similar in many ways, but they
98 are different enough to be described separately.
99
100 GRANT on Database Objects
101 This variant of the GRANT command gives specific privileges on a
102 database object to one or more roles. These privileges are added to
103 those already granted, if any.
104
105 The key word PUBLIC indicates that the privileges are to be granted to
106 all roles, including those that might be created later. PUBLIC can be
107 thought of as an implicitly defined group that always includes all
108 roles. Any particular role will have the sum of privileges granted
109 directly to it, privileges granted to any role it is presently a member
110 of, and privileges granted to PUBLIC.
111
112 If WITH GRANT OPTION is specified, the recipient of the privilege can
113 in turn grant it to others. Without a grant option, the recipient
114 cannot do that. Grant options cannot be granted to PUBLIC.
115
116 If GRANTED BY is specified, the specified grantor must be the current
117 user. This clause is currently present in this form only for SQL
118 compatibility.
119
120 There is no need to grant privileges to the owner of an object (usually
121 the user that created it), as the owner has all privileges by default.
122 (The owner could, however, choose to revoke some of their own
123 privileges for safety.)
124
125 The right to drop an object, or to alter its definition in any way, is
126 not treated as a grantable privilege; it is inherent in the owner, and
127 cannot be granted or revoked. (However, a similar effect can be
128 obtained by granting or revoking membership in the role that owns the
129 object; see below.) The owner implicitly has all grant options for the
130 object, too.
131
132 The possible privileges are:
133
134 SELECT
135 INSERT
136 UPDATE
137 DELETE
138 TRUNCATE
139 REFERENCES
140 TRIGGER
141 CREATE
142 CONNECT
143 TEMPORARY
144 EXECUTE
145 USAGE
146 Specific types of privileges, as defined in Section 5.7.
147
148 TEMP
149 Alternative spelling for TEMPORARY.
150
151 ALL PRIVILEGES
152 Grant all of the privileges available for the object's type. The
153 PRIVILEGES key word is optional in PostgreSQL, though it is
154 required by strict SQL.
155
156 The FUNCTION syntax works for plain functions, aggregate functions, and
157 window functions, but not for procedures; use PROCEDURE for those.
158 Alternatively, use ROUTINE to refer to a function, aggregate function,
159 window function, or procedure regardless of its precise type.
160
161 There is also an option to grant privileges on all objects of the same
162 type within one or more schemas. This functionality is currently
163 supported only for tables, sequences, functions, and procedures. ALL
164 TABLES also affects views and foreign tables, just like the
165 specific-object GRANT command. ALL FUNCTIONS also affects aggregate
166 and window functions, but not procedures, again just like the
167 specific-object GRANT command. Use ALL ROUTINES to include procedures.
168
169 GRANT on Roles
170 This variant of the GRANT command grants membership in a role to one or
171 more other roles. Membership in a role is significant because it
172 conveys the privileges granted to a role to each of its members.
173
174 If WITH ADMIN OPTION is specified, the member can in turn grant
175 membership in the role to others, and revoke membership in the role as
176 well. Without the admin option, ordinary users cannot do that. A role
177 is not considered to hold WITH ADMIN OPTION on itself, but it may grant
178 or revoke membership in itself from a database session where the
179 session user matches the role. Database superusers can grant or revoke
180 membership in any role to anyone. Roles having CREATEROLE privilege can
181 grant or revoke membership in any role that is not a superuser.
182
183 If GRANTED BY is specified, the grant is recorded as having been done
184 by the specified role. Only database superusers may use this option,
185 except when it names the same role executing the command.
186
187 Unlike the case with privileges, membership in a role cannot be granted
188 to PUBLIC. Note also that this form of the command does not allow the
189 noise word GROUP in role_specification.
190
192 The REVOKE command is used to revoke access privileges.
193
194 Since PostgreSQL 8.1, the concepts of users and groups have been
195 unified into a single kind of entity called a role. It is therefore no
196 longer necessary to use the keyword GROUP to identify whether a grantee
197 is a user or a group. GROUP is still allowed in the command, but it is
198 a noise word.
199
200 A user may perform SELECT, INSERT, etc. on a column if they hold that
201 privilege for either the specific column or its whole table. Granting
202 the privilege at the table level and then revoking it for one column
203 will not do what one might wish: the table-level grant is unaffected by
204 a column-level operation.
205
206 When a non-owner of an object attempts to GRANT privileges on the
207 object, the command will fail outright if the user has no privileges
208 whatsoever on the object. As long as some privilege is available, the
209 command will proceed, but it will grant only those privileges for which
210 the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
211 warning message if no grant options are held, while the other forms
212 will issue a warning if grant options for any of the privileges
213 specifically named in the command are not held. (In principle these
214 statements apply to the object owner as well, but since the owner is
215 always treated as holding all grant options, the cases can never
216 occur.)
217
218 It should be noted that database superusers can access all objects
219 regardless of object privilege settings. This is comparable to the
220 rights of root in a Unix system. As with root, it's unwise to operate
221 as a superuser except when absolutely necessary.
222
223 If a superuser chooses to issue a GRANT or REVOKE command, the command
224 is performed as though it were issued by the owner of the affected
225 object. In particular, privileges granted via such a command will
226 appear to have been granted by the object owner. (For role membership,
227 the membership appears to have been granted by the containing role
228 itself.)
229
230 GRANT and REVOKE can also be done by a role that is not the owner of
231 the affected object, but is a member of the role that owns the object,
232 or is a member of a role that holds privileges WITH GRANT OPTION on the
233 object. In this case the privileges will be recorded as having been
234 granted by the role that actually owns the object or holds the
235 privileges WITH GRANT OPTION. For example, if table t1 is owned by role
236 g1, of which role u1 is a member, then u1 can grant privileges on t1 to
237 u2, but those privileges will appear to have been granted directly by
238 g1. Any other member of role g1 could revoke them later.
239
240 If the role executing GRANT holds the required privileges indirectly
241 via more than one role membership path, it is unspecified which
242 containing role will be recorded as having done the grant. In such
243 cases it is best practice to use SET ROLE to become the specific role
244 you want to do the GRANT as.
245
246 Granting permission on a table does not automatically extend
247 permissions to any sequences used by the table, including sequences
248 tied to SERIAL columns. Permissions on sequences must be set
249 separately.
250
251 See Section 5.7 for more information about specific privilege types, as
252 well as how to inspect objects' privileges.
253
255 Grant insert privilege to all users on table films:
256
257 GRANT INSERT ON films TO PUBLIC;
258
259 Grant all available privileges to user manuel on view kinds:
260
261 GRANT ALL PRIVILEGES ON kinds TO manuel;
262
263 Note that while the above will indeed grant all privileges if executed
264 by a superuser or the owner of kinds, when executed by someone else it
265 will only grant those permissions for which the someone else has grant
266 options.
267
268 Grant membership in role admins to user joe:
269
270 GRANT admins TO joe;
271
273 According to the SQL standard, the PRIVILEGES key word in ALL
274 PRIVILEGES is required. The SQL standard does not support setting the
275 privileges on more than one object per command.
276
277 PostgreSQL allows an object owner to revoke their own ordinary
278 privileges: for example, a table owner can make the table read-only to
279 themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
280 privileges. This is not possible according to the SQL standard. The
281 reason is that PostgreSQL treats the owner's privileges as having been
282 granted by the owner to themselves; therefore they can revoke them too.
283 In the SQL standard, the owner's privileges are granted by an assumed
284 entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
285 rights.
286
287 According to the SQL standard, grant options can be granted to PUBLIC;
288 PostgreSQL only supports granting grant options to roles.
289
290 The SQL standard allows the GRANTED BY option to specify only
291 CURRENT_USER or CURRENT_ROLE. The other variants are PostgreSQL
292 extensions.
293
294 The SQL standard provides for a USAGE privilege on other kinds of
295 objects: character sets, collations, translations.
296
297 In the SQL standard, sequences only have a USAGE privilege, which
298 controls the use of the NEXT VALUE FOR expression, which is equivalent
299 to the function nextval in PostgreSQL. The sequence privileges SELECT
300 and UPDATE are PostgreSQL extensions. The application of the sequence
301 USAGE privilege to the currval function is also a PostgreSQL extension
302 (as is the function itself).
303
304 Privileges on databases, tablespaces, schemas, and languages are
305 PostgreSQL extensions.
306
308 REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
309
310
311
312PostgreSQL 14.3 2022 GRANT(7)