1GRANT(7) SQL Commands GRANT(7)
2
3
4
6 GRANT - define access privileges
7
8
10 GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
11 [,...] | ALL [ PRIVILEGES ] }
12 ON [ TABLE ] tablename [, ...]
13 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
14
15 GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( column [, ...] )
16 [,...] | ALL [ PRIVILEGES ] ( column [, ...] ) }
17 ON [ TABLE ] tablename [, ...]
18 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
19
20 GRANT { { USAGE | SELECT | UPDATE }
21 [,...] | ALL [ PRIVILEGES ] }
22 ON SEQUENCE sequencename [, ...]
23 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
24
25 GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] }
26 ON DATABASE dbname [, ...]
27 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
28
29 GRANT { USAGE | ALL [ PRIVILEGES ] }
30 ON FOREIGN DATA WRAPPER fdwname [, ...]
31 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
32
33 GRANT { USAGE | ALL [ PRIVILEGES ] }
34 ON FOREIGN SERVER servername [, ...]
35 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
36
37 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
38 ON FUNCTION funcname ( [ [ argmode ] [ argname ] argtype [, ...] ] ) [, ...]
39 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
40
41 GRANT { USAGE | ALL [ PRIVILEGES ] }
42 ON LANGUAGE langname [, ...]
43 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
44
45 GRANT { { CREATE | USAGE } [,...] | ALL [ PRIVILEGES ] }
46 ON SCHEMA schemaname [, ...]
47 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
48
49 GRANT { CREATE | ALL [ PRIVILEGES ] }
50 ON TABLESPACE tablespacename [, ...]
51 TO { [ GROUP ] rolename | PUBLIC } [, ...] [ WITH GRANT OPTION ]
52
53 GRANT role [, ...] TO rolename [, ...] [ WITH ADMIN OPTION ]
54
55
57 The GRANT command has two basic variants: one that grants privileges on
58 a database object (table, column, view, sequence, database, foreign-
59 data wrapper, foreign server, function, procedural language, schema, or
60 tablespace), and one that grants membership in a role. These variants
61 are similar in many ways, but they are different enough to be described
62 separately.
63
64 As of PostgreSQL 8.1, the concepts of users and groups have been uni‐
65 fied into a single kind of entity called a role. It is therefore no
66 longer necessary to use the keyword GROUP to identify whether a grantee
67 is a user or a group. GROUP is still allowed in the command, but it is
68 a noise word.
69
70 GRANT ON DATABASE OBJECTS
71 This variant of the GRANT command gives specific privileges on a data‐
72 base object to one or more roles. These privileges are added to those
73 already granted, if any.
74
75 The key word PUBLIC indicates that the privileges are to be granted to
76 all roles, including those that might be created later. PUBLIC can be
77 thought of as an implicitly defined group that always includes all
78 roles. Any particular role will have the sum of privileges granted
79 directly to it, privileges granted to any role it is presently a member
80 of, and privileges granted to PUBLIC.
81
82 If WITH GRANT OPTION is specified, the recipient of the privilege can
83 in turn grant it to others. Without a grant option, the recipient can‐
84 not do that. Grant options cannot be granted to PUBLIC.
85
86 There is no need to grant privileges to the owner of an object (usually
87 the user that created it), as the owner has all privileges by default.
88 (The owner could, however, choose to revoke some of his own privileges
89 for safety.) The right to drop an object, or to alter its definition
90 in any way is not described by a grantable privilege; it is inherent in
91 the owner, and cannot be granted or revoked. The owner implicitly has
92 all grant options for the object, too.
93
94 Depending on the type of object, the initial default privileges might
95 include granting some privileges to PUBLIC. The default is no public
96 access for tables, columns, schemas, and tablespaces; CONNECT privilege
97 and TEMP table creation privilege for databases; EXECUTE privilege for
98 functions; and USAGE privilege for languages. The object owner can of
99 course revoke these privileges. (For maximum security, issue the REVOKE
100 in the same transaction that creates the object; then there is no win‐
101 dow in which another user can use the object.)
102
103 The possible privileges are:
104
105 SELECT Allows SELECT [select(7)] from any column, or the specific col‐
106 umns listed, of the specified table, view, or sequence. Also
107 allows the use of COPY [copy(7)] TO. This privilege is also
108 needed to reference existing column values in UPDATE [update(7)]
109 or DELETE [delete(7)]. For sequences, this privilege also
110 allows the use of the currval function.
111
112 INSERT Allows INSERT [insert(7)] of a new row into the specified table.
113 If specific columns are listed, only those columns may be
114 assigned to in the INSERT command (other columns will therefore
115 receive default values). Also allows COPY [copy(7)] FROM.
116
117 UPDATE Allows UPDATE [update(7)] of any column, or the specific columns
118 listed, of the specified table. (In practice, any nontrivial
119 UPDATE command will require SELECT privilege as well, since it
120 must reference table columns to determine which rows to update,
121 and/or to compute new values for columns.) SELECT ... FOR
122 UPDATE and SELECT ... FOR SHARE also require this privilege on
123 at least one column, in addition to the SELECT privilege. For
124 sequences, this privilege allows the use of the nextval and set‐
125 val functions.
126
127 DELETE Allows DELETE [delete(7)] of a row from the specified table.
128 (In practice, any nontrivial DELETE command will require SELECT
129 privilege as well, since it must reference table columns to
130 determine which rows to delete.)
131
132 TRUNCATE
133 Allows TRUNCATE [truncate(7)] on the specified table.
134
135 REFERENCES
136 To create a foreign key constraint, it is necessary to have this
137 privilege on both the referencing and referenced columns. The
138 privilege may be granted for all columns of a table, or just
139 specific columns.
140
141 TRIGGER
142 Allows the creation of a trigger on the specified table. (See
143 the CREATE TRIGGER [create_trigger(7)] statement.)
144
145 CREATE For databases, allows new schemas to be created within the data‐
146 base.
147
148 For schemas, allows new objects to be created within the schema.
149 To rename an existing object, you must own the object and have
150 this privilege for the containing schema.
151
152 For tablespaces, allows tables, indexes, and temporary files to
153 be created within the tablespace, and allows databases to be
154 created that have the tablespace as their default tablespace.
155 (Note that revoking this privilege will not alter the placement
156 of existing objects.)
157
158 CONNECT
159 Allows the user to connect to the specified database. This priv‐
160 ilege is checked at connection startup (in addition to checking
161 any restrictions imposed by pg_hba.conf).
162
163 TEMPORARY
164
165 TEMP Allows temporary tables to be created while using the specified
166 database.
167
168 EXECUTE
169 Allows the use of the specified function and the use of any
170 operators that are implemented on top of the function. This is
171 the only type of privilege that is applicable to functions.
172 (This syntax works for aggregate functions, as well.)
173
174 USAGE For procedural languages, allows the use of the specified lan‐
175 guage for the creation of functions in that language. This is
176 the only type of privilege that is applicable to procedural lan‐
177 guages.
178
179 For schemas, allows access to objects contained in the specified
180 schema (assuming that the objects' own privilege requirements
181 are also met). Essentially this allows the grantee to ``look
182 up'' objects within the schema. Without this permission, it is
183 still possible to see the object names, e.g. by querying the
184 system tables. Also, after revoking this permission, existing
185 backends might have statements that have previously performed
186 this lookup, so this is not a completely secure way to prevent
187 object access.
188
189 For sequences, this privilege allows the use of the currval and
190 nextval functions.
191
192 For foreign-data wrappers, this privilege enables the grantee to
193 create new servers using that foreign-data wrapper.
194
195 For servers, this privilege enables the grantee to create,
196 alter, and drop his own user's user mappings associated with
197 that server. Also, it enables the grantee to query the options
198 of the server and associated user mappings.
199
200 ALL PRIVILEGES
201 Grant all of the available privileges at once. The PRIVILEGES
202 key word is optional in PostgreSQL, though it is required by
203 strict SQL.
204
205 The privileges required by other commands are listed on the reference
206 page of the respective command.
207
208 GRANT ON ROLES
209 This variant of the GRANT command grants membership in a role to one or
210 more other roles. Membership in a role is significant because it con‐
211 veys the privileges granted to a role to each of its members.
212
213 If WITH ADMIN OPTION is specified, the member can in turn grant member‐
214 ship in the role to others, and revoke membership in the role as well.
215 Without the admin option, ordinary users cannot do that. A role is not
216 considered to hold WITH ADMIN OPTION on itself, but it may grant or
217 revoke membership in itself from a database session where the session
218 user matches the role. Database superusers can grant or revoke member‐
219 ship in any role to anyone. Roles having CREATEROLE privilege can grant
220 or revoke membership in any role that is not a superuser.
221
222 Unlike the case with privileges, membership in a role cannot be granted
223 to PUBLIC. Note also that this form of the command does not allow the
224 noise word GROUP.
225
227 The REVOKE [revoke(7)] command is used to revoke access privileges.
228
229 A user may perform SELECT, INSERT, etc. on a column if he holds that
230 privilege for either the specific column or its whole table. Granting
231 the privilege at the table level and then revoking it for one column
232 will not do what you might wish: the table-level grant is unaffected by
233 a column-level operation.
234
235 When a non-owner of an object attempts to GRANT privileges on the
236 object, the command will fail outright if the user has no privileges
237 whatsoever on the object. As long as some privilege is available, the
238 command will proceed, but it will grant only those privileges for which
239 the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
240 warning message if no grant options are held, while the other forms
241 will issue a warning if grant options for any of the privileges specif‐
242 ically named in the command are not held. (In principle these state‐
243 ments apply to the object owner as well, but since the owner is always
244 treated as holding all grant options, the cases can never occur.)
245
246 It should be noted that database superusers can access all objects
247 regardless of object privilege settings. This is comparable to the
248 rights of root in a Unix system. As with root, it's unwise to operate
249 as a superuser except when absolutely necessary.
250
251 If a superuser chooses to issue a GRANT or REVOKE command, the command
252 is performed as though it were issued by the owner of the affected
253 object. In particular, privileges granted via such a command will
254 appear to have been granted by the object owner. (For role membership,
255 the membership appears to have been granted by the containing role
256 itself.)
257
258 GRANT and REVOKE can also be done by a role that is not the owner of
259 the affected object, but is a member of the role that owns the object,
260 or is a member of a role that holds privileges WITH GRANT OPTION on the
261 object. In this case the privileges will be recorded as having been
262 granted by the role that actually owns the object or holds the privi‐
263 leges WITH GRANT OPTION. For example, if table t1 is owned by role g1,
264 of which role u1 is a member, then u1 can grant privileges on t1 to u2,
265 but those privileges will appear to have been granted directly by g1.
266 Any other member of role g1 could revoke them later.
267
268 If the role executing GRANT holds the required privileges indirectly
269 via more than one role membership path, it is unspecified which con‐
270 taining role will be recorded as having done the grant. In such cases
271 it is best practice to use SET ROLE to become the specific role you
272 want to do the GRANT as.
273
274 Granting permission on a table does not automatically extend permis‐
275 sions to any sequences used by the table, including sequences tied to
276 SERIAL columns. Permissions on sequences must be set separately.
277
278 Use psql(1)'s \dp command to obtain information about existing privi‐
279 leges for tables and columns. For example:
280
281 => \dp mytable
282 Access privileges
283 Schema | Name | Type | Access privileges | Column access privileges
284 --------+---------+-------+-----------------------+--------------------------
285 public | mytable | table | miriam=arwdDxt/miriam | col1:
286 : =r/miriam : miriam_rw=rw/miriam
287 : admin=arw/miriam
288 (1 row)
289
290 The entries shown by \dp are interpreted thus:
291
292 rolename=xxxx -- privileges granted to a role
293 =xxxx -- privileges granted to PUBLIC
294
295 r -- SELECT ("read")
296 w -- UPDATE ("write")
297 a -- INSERT ("append")
298 d -- DELETE
299 D -- TRUNCATE
300 x -- REFERENCES
301 t -- TRIGGER
302 X -- EXECUTE
303 U -- USAGE
304 C -- CREATE
305 c -- CONNECT
306 T -- TEMPORARY
307 arwdDxt -- ALL PRIVILEGES (for tables, varies for other objects)
308 * -- grant option for preceding privilege
309
310 /yyyy -- role that granted this privilege
311
312 The above example display would be seen by user miriam after creating
313 table mytable and doing:
314
315 GRANT SELECT ON mytable TO PUBLIC;
316 GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
317 GRANT SELECT (col1), UPDATE (col1) ON mytable TO miriam_rw;
318
319
320 For non-table objects there are other \d commands that can display
321 their privileges.
322
323 If the ``Access privileges'' column is empty for a given object, it
324 means the object has default privileges (that is, its privileges column
325 is null). Default privileges always include all privileges for the
326 owner, and can include some privileges for PUBLIC depending on the
327 object type, as explained above. The first GRANT or REVOKE on an object
328 will instantiate the default privileges (producing, for example,
329 {miriam=arwdDxt/miriam}) and then modify them per the specified
330 request. Entries are shown in ``Column access privileges'' only for
331 columns with nondefault privileges.
332
333 Notice that the owner's implicit grant options are not marked in the
334 access privileges display. A * will appear only when grant options have
335 been explicitly granted to someone.
336
338 Grant insert privilege to all users on table films:
339
340 GRANT INSERT ON films TO PUBLIC;
341
342
343 Grant all available privileges to user manuel on view kinds:
344
345 GRANT ALL PRIVILEGES ON kinds TO manuel;
346
347 Note that while the above will indeed grant all privileges if executed
348 by a superuser or the owner of kinds, when executed by someone else it
349 will only grant those permissions for which the someone else has grant
350 options.
351
352 Grant membership in role admins to user joe:
353
354 GRANT admins TO joe;
355
356
358 According to the SQL standard, the PRIVILEGES key word in ALL PRIVI‐
359 LEGES is required. The SQL standard does not support setting the privi‐
360 leges on more than one object per command.
361
362 PostgreSQL allows an object owner to revoke his own ordinary privi‐
363 leges: for example, a table owner can make the table read-only to him‐
364 self by revoking his own INSERT, UPDATE, DELETE, and TRUNCATE privi‐
365 leges. This is not possible according to the SQL standard. The reason
366 is that PostgreSQL treats the owner's privileges as having been granted
367 by the owner to himself; therefore he can revoke them too. In the SQL
368 standard, the owner's privileges are granted by an assumed entity
369 ``_SYSTEM''. Not being ``_SYSTEM'', the owner cannot revoke these
370 rights.
371
372 The SQL standard provides for a USAGE privilege on other kinds of
373 objects: character sets, collations, translations, domains.
374
375 Privileges on databases, tablespaces, schemas, and languages are Post‐
376 greSQL extensions.
377
379 REVOKE [revoke(7)]
380
381
382
383SQL - Language Statements 2014-02-17 GRANT(7)