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