4 GRANT — define access privileges
8 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 ]
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 ]
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 ]
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 ]
34 GRANT { USAGE | ALL [ PRIVILEGES ] }
35 ON DOMAIN domain_name [, ...]
36 TO role_specification [, ...] [ WITH GRANT OPTION ]
37 [ GRANTED BY role_specification ]
39 GRANT { USAGE | ALL [ PRIVILEGES ] }
40 ON FOREIGN DATA WRAPPER fdw_name [, ...]
41 TO role_specification [, ...] [ WITH GRANT OPTION ]
42 [ GRANTED BY role_specification ]
44 GRANT { USAGE | ALL [ PRIVILEGES ] }
45 ON FOREIGN SERVER server_name [, ...]
46 TO role_specification [, ...] [ WITH GRANT OPTION ]
47 [ GRANTED BY role_specification ]
49 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
50 ON { { FUNCTION | PROCEDURE | ROUTINE } routine_name [ ( [ [ argmode ] [ arg
51 _name ] arg_type [, ...] ] ) ] [, ...]
52 | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA schema_name [, ..
54 TO role_specification [, ...] [ WITH GRANT OPTION ]
55 [ GRANTED BY role_specification ]
57 GRANT { USAGE | ALL [ PRIVILEGES ] }
58 ON LANGUAGE lang_name [, ...]
59 TO role_specification [, ...] [ WITH GRANT OPTION ]
60 [ GRANTED BY role_specification ]
62 GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
63 ON LARGE OBJECT loid [, ...]
64 TO role_specification [, ...] [ WITH GRANT OPTION ]
65 [ GRANTED BY role_specification ]
67 GRANT { { SET | ALTER SYSTEM } [, ... ] | ALL [ PRIVILEGES ] }
68 ON PARAMETER configuration_parameter [, ...]
69 TO role_specification [, ...] [ WITH GRANT OPTION ]
70 [ GRANTED BY role_specification ]
72 GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
73 ON SCHEMA schema_name [, ...]
74 TO role_specification [, ...] [ WITH GRANT OPTION ]
75 [ GRANTED BY role_specification ]
77 GRANT { CREATE | ALL [ PRIVILEGES ] }
78 ON TABLESPACE tablespace_name [, ...]
79 TO role_specification [, ...] [ WITH GRANT OPTION ]
80 [ GRANTED BY role_specification ]
82 GRANT { USAGE | ALL [ PRIVILEGES ] }
83 ON TYPE type_name [, ...]
84 TO role_specification [, ...] [ WITH GRANT OPTION ]
85 [ GRANTED BY role_specification ]
87 GRANT role_name [, ...] TO role_specification [, ...]
88 [ WITH { ADMIN | INHERIT | SET } { OPTION | TRUE | FALSE } ]
89 [ GRANTED BY role_specification ]
91 where role_specification can be:
101 The GRANT command has two basic variants: one that grants privileges on
102 a database object (table, column, view, foreign table, sequence,
103 database, foreign-data wrapper, foreign server, function, procedure,
104 procedural language, large object, configuration parameter, schema,
105 tablespace, or type), and one that grants membership in a role. These
106 variants are similar in many ways, but they are different enough to be
107 described separately.
109 GRANT on Database Objects
111 This variant of the GRANT command gives specific privileges on a
112 database object to one or more roles. These privileges are added to
113 those already granted, if any.
115 The key word PUBLIC indicates that the privileges are to be granted to
116 all roles, including those that might be created later. PUBLIC can be
117 thought of as an implicitly defined group that always includes all
118 roles. Any particular role will have the sum of privileges granted
119 directly to it, privileges granted to any role it is presently a member
120 of, and privileges granted to PUBLIC.
122 If WITH GRANT OPTION is specified, the recipient of the privilege can
123 in turn grant it to others. Without a grant option, the recipient
124 cannot do that. Grant options cannot be granted to PUBLIC.
126 If GRANTED BY is specified, the specified grantor must be the current
127 user. This clause is currently present in this form only for SQL
130 There is no need to grant privileges to the owner of an object (usually
131 the user that created it), as the owner has all privileges by default.
132 (The owner could, however, choose to revoke some of their own
133 privileges for safety.)
135 The right to drop an object, or to alter its definition in any way, is
136 not treated as a grantable privilege; it is inherent in the owner, and
137 cannot be granted or revoked. (However, a similar effect can be
138 obtained by granting or revoking membership in the role that owns the
139 object; see below.) The owner implicitly has all grant options for the
142 The possible privileges are:
159 Specific types of privileges, as defined in Section 5.8.
162 Alternative spelling for TEMPORARY.
165 Grant all of the privileges available for the object's type. The
166 PRIVILEGES key word is optional in PostgreSQL, though it is
167 required by strict SQL.
169 The FUNCTION syntax works for plain functions, aggregate functions, and
170 window functions, but not for procedures; use PROCEDURE for those.
171 Alternatively, use ROUTINE to refer to a function, aggregate function,
172 window function, or procedure regardless of its precise type.
174 There is also an option to grant privileges on all objects of the same
175 type within one or more schemas. This functionality is currently
176 supported only for tables, sequences, functions, and procedures. ALL
177 TABLES also affects views and foreign tables, just like the
178 specific-object GRANT command. ALL FUNCTIONS also affects aggregate and
179 window functions, but not procedures, again just like the
180 specific-object GRANT command. Use ALL ROUTINES to include procedures.
184 This variant of the GRANT command grants membership in a role to one or
185 more other roles, and the modification of membership options SET,
186 INHERIT, and ADMIN; see Section 21.3 for details. Membership in a role
187 is significant because it potentially allows access to the privileges
188 granted to a role to each of its members, and potentially also the
189 ability to make changes to the role itself. However, the actual
190 permissions conferred depend on the options associated with the grant.
191 To modify that options of an existing membership, simply specify the
192 membership with updated option values.
194 Each of the options described below can be set to either TRUE or FALSE.
195 The keyword OPTION is accepted as a synonym for TRUE, so that WITH
196 ADMIN OPTION is a synonym for WITH ADMIN TRUE. When altering an
197 existing membership the omission of an option results in the current
198 value being retained.
200 The ADMIN option allows the member to in turn grant membership in the
201 role to others, and revoke membership in the role as well. Without the
202 admin option, ordinary users cannot do that. A role is not considered
203 to hold WITH ADMIN OPTION on itself. Database superusers can grant or
204 revoke membership in any role to anyone. This option defaults to FALSE.
206 The INHERIT option controls the inheritance status of the new
207 membership; see Section 21.3 for details on inheritance. If it is set
208 to TRUE, it causes the new member to inherit from the granted role. If
209 set to FALSE, the new member does not inherit. If unspecified when
210 creating a new role membership, this defaults to the inheritance
211 attribute of the new member.
213 The SET option, if it is set to TRUE, allows the member to change to
214 the granted role using the SET ROLE command. If a role is an indirect
215 member of another role, it can use SET ROLE to change to that role only
216 if there is a chain of grants each of which has SET TRUE. This option
219 To create an object owned by another role or give ownership of an
220 existing object to another role, you must have the ability to SET ROLE
221 to that role; otherwise, commands such as ALTER ... OWNER TO or CREATE
222 DATABASE ... OWNER will fail. However, a user who inherits the
223 privileges of a role but does not have the ability to SET ROLE to that
224 role may be able to obtain full access to the role by manipulating
225 existing objects owned by that role (e.g. they could redefine an
226 existing function to act as a Trojan horse). Therefore, if a role's
227 privileges are to be inherited but should not be accessible via SET
228 ROLE, it should not own any SQL objects.
230 If GRANTED BY is specified, the grant is recorded as having been done
231 by the specified role. A user can only attribute a grant to another
232 role if they possess the privileges of that role. The role recorded as
233 the grantor must have ADMIN OPTION on the target role, unless it is the
234 bootstrap superuser. When a grant is recorded as having a grantor other
235 than the bootstrap superuser, it depends on the grantor continuing to
236 possess ADMIN OPTION on the role; so, if ADMIN OPTION is revoked,
237 dependent grants must be revoked as well.
239 Unlike the case with privileges, membership in a role cannot be granted
240 to PUBLIC. Note also that this form of the command does not allow the
241 noise word GROUP in role_specification.
245 The REVOKE command is used to revoke access privileges.
247 Since PostgreSQL 8.1, the concepts of users and groups have been
248 unified into a single kind of entity called a role. It is therefore no
249 longer necessary to use the keyword GROUP to identify whether a grantee
250 is a user or a group. GROUP is still allowed in the command, but it is
253 A user may perform SELECT, INSERT, etc. on a column if they hold that
254 privilege for either the specific column or its whole table. Granting
255 the privilege at the table level and then revoking it for one column
256 will not do what one might wish: the table-level grant is unaffected by
257 a column-level operation.
259 When a non-owner of an object attempts to GRANT privileges on the
260 object, the command will fail outright if the user has no privileges
261 whatsoever on the object. As long as some privilege is available, the
262 command will proceed, but it will grant only those privileges for which
263 the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
264 warning message if no grant options are held, while the other forms
265 will issue a warning if grant options for any of the privileges
266 specifically named in the command are not held. (In principle these
267 statements apply to the object owner as well, but since the owner is
268 always treated as holding all grant options, the cases can never
271 It should be noted that database superusers can access all objects
272 regardless of object privilege settings. This is comparable to the
273 rights of root in a Unix system. As with root, it's unwise to operate
274 as a superuser except when absolutely necessary.
276 If a superuser chooses to issue a GRANT or REVOKE command, the command
277 is performed as though it were issued by the owner of the affected
278 object. In particular, privileges granted via such a command will
279 appear to have been granted by the object owner. (For role membership,
280 the membership appears to have been granted by the bootstrap
283 GRANT and REVOKE can also be done by a role that is not the owner of
284 the affected object, but is a member of the role that owns the object,
285 or is a member of a role that holds privileges WITH GRANT OPTION on the
286 object. In this case the privileges will be recorded as having been
287 granted by the role that actually owns the object or holds the
288 privileges WITH GRANT OPTION. For example, if table t1 is owned by role
289 g1, of which role u1 is a member, then u1 can grant privileges on t1 to
290 u2, but those privileges will appear to have been granted directly by
291 g1. Any other member of role g1 could revoke them later.
293 If the role executing GRANT holds the required privileges indirectly
294 via more than one role membership path, it is unspecified which
295 containing role will be recorded as having done the grant. In such
296 cases it is best practice to use SET ROLE to become the specific role
297 you want to do the GRANT as.
299 Granting permission on a table does not automatically extend
300 permissions to any sequences used by the table, including sequences
301 tied to SERIAL columns. Permissions on sequences must be set
304 See Section 5.8 for more information about specific privilege types, as
305 well as how to inspect objects' privileges.
309 Grant insert privilege to all users on table films:
310 GRANT INSERT ON films TO PUBLIC;
312 Grant all available privileges to user manuel on view kinds:
313 GRANT ALL PRIVILEGES ON kinds TO manuel;
315 Note that while the above will indeed grant all privileges if executed
316 by a superuser or the owner of kinds, when executed by someone else it
317 will only grant those permissions for which the someone else has grant
320 Grant membership in role admins to user joe:
325 According to the SQL standard, the PRIVILEGES key word in ALL
326 PRIVILEGES is required. The SQL standard does not support setting the
327 privileges on more than one object per command.
329 PostgreSQL allows an object owner to revoke their own ordinary
330 privileges: for example, a table owner can make the table read-only to
331 themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
332 privileges. This is not possible according to the SQL standard. The
333 reason is that PostgreSQL treats the owner's privileges as having been
334 granted by the owner to themselves; therefore they can revoke them too.
335 In the SQL standard, the owner's privileges are granted by an assumed
336 entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
339 According to the SQL standard, grant options can be granted to PUBLIC;
340 PostgreSQL only supports granting grant options to roles.
342 The SQL standard allows the GRANTED BY option to specify only
343 CURRENT_USER or CURRENT_ROLE. The other variants are PostgreSQL
346 The SQL standard provides for a USAGE privilege on other kinds of
347 objects: character sets, collations, translations.
349 In the SQL standard, sequences only have a USAGE privilege, which
350 controls the use of the NEXT VALUE FOR expression, which is equivalent
351 to the function nextval in PostgreSQL. The sequence privileges SELECT
352 and UPDATE are PostgreSQL extensions. The application of the sequence
353 USAGE privilege to the currval function is also a PostgreSQL extension
354 (as is the function itself).
356 Privileges on databases, tablespaces, schemas, languages, and
357 configuration parameters are PostgreSQL extensions.
361 REVOKE, ALTER DEFAULT PRIVILEGES