1GRANT(7)                 PostgreSQL 12.2 Documentation                GRANT(7)
2
3
4

NAME

6       GRANT - define access privileges
7

SYNOPSIS

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
15       GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( column_name [, ...] )
16           [, ...] | ALL [ PRIVILEGES ] ( column_name [, ...] ) }
17           ON [ TABLE ] table_name [, ...]
18           TO role_specification [, ...] [ WITH GRANT OPTION ]
19
20       GRANT { { USAGE | SELECT | UPDATE }
21           [, ...] | ALL [ PRIVILEGES ] }
22           ON { SEQUENCE sequence_name [, ...]
23                | ALL SEQUENCES IN SCHEMA schema_name [, ...] }
24           TO role_specification [, ...] [ WITH GRANT OPTION ]
25
26       GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
27           ON DATABASE database_name [, ...]
28           TO role_specification [, ...] [ WITH GRANT OPTION ]
29
30       GRANT { USAGE | ALL [ PRIVILEGES ] }
31           ON DOMAIN domain_name [, ...]
32           TO role_specification [, ...] [ WITH GRANT OPTION ]
33
34       GRANT { USAGE | ALL [ PRIVILEGES ] }
35           ON FOREIGN DATA WRAPPER fdw_name [, ...]
36           TO role_specification [, ...] [ WITH GRANT OPTION ]
37
38       GRANT { USAGE | ALL [ PRIVILEGES ] }
39           ON FOREIGN SERVER server_name [, ...]
40           TO role_specification [, ...] [ WITH GRANT OPTION ]
41
42       GRANT { EXECUTE | ALL [ PRIVILEGES ] }
43           ON { { FUNCTION | PROCEDURE | ROUTINE } routine_name [ ( [ [ argmode ] [ arg_name ] arg_type [, ...] ] ) ] [, ...]
44                | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA schema_name [, ...] }
45           TO role_specification [, ...] [ WITH GRANT OPTION ]
46
47       GRANT { USAGE | ALL [ PRIVILEGES ] }
48           ON LANGUAGE lang_name [, ...]
49           TO role_specification [, ...] [ WITH GRANT OPTION ]
50
51       GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
52           ON LARGE OBJECT loid [, ...]
53           TO role_specification [, ...] [ WITH GRANT OPTION ]
54
55       GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
56           ON SCHEMA schema_name [, ...]
57           TO role_specification [, ...] [ WITH GRANT OPTION ]
58
59       GRANT { CREATE | ALL [ PRIVILEGES ] }
60           ON TABLESPACE tablespace_name [, ...]
61           TO role_specification [, ...] [ WITH GRANT OPTION ]
62
63       GRANT { USAGE | ALL [ PRIVILEGES ] }
64           ON TYPE type_name [, ...]
65           TO role_specification [, ...] [ WITH GRANT OPTION ]
66
67       where role_specification can be:
68
69           [ GROUP ] role_name
70         | PUBLIC
71         | CURRENT_USER
72         | SESSION_USER
73
74       GRANT role_name [, ...] TO role_name [, ...] [ WITH ADMIN OPTION ]
75

DESCRIPTION

77       The GRANT command has two basic variants: one that grants privileges on
78       a database object (table, column, view, foreign table, sequence,
79       database, foreign-data wrapper, foreign server, function, procedure,
80       procedural language, schema, or tablespace), and one that grants
81       membership in a role. These variants are similar in many ways, but they
82       are different enough to be described separately.
83
84   GRANT on Database Objects
85       This variant of the GRANT command gives specific privileges on a
86       database object to one or more roles. These privileges are added to
87       those already granted, if any.
88
89       The key word PUBLIC indicates that the privileges are to be granted to
90       all roles, including those that might be created later.  PUBLIC can be
91       thought of as an implicitly defined group that always includes all
92       roles. Any particular role will have the sum of privileges granted
93       directly to it, privileges granted to any role it is presently a member
94       of, and privileges granted to PUBLIC.
95
96       If WITH GRANT OPTION is specified, the recipient of the privilege can
97       in turn grant it to others. Without a grant option, the recipient
98       cannot do that. Grant options cannot be granted to PUBLIC.
99
100       There is no need to grant privileges to the owner of an object (usually
101       the user that created it), as the owner has all privileges by default.
102       (The owner could, however, choose to revoke some of their own
103       privileges for safety.)
104
105       The right to drop an object, or to alter its definition in any way, is
106       not treated as a grantable privilege; it is inherent in the owner, and
107       cannot be granted or revoked. (However, a similar effect can be
108       obtained by granting or revoking membership in the role that owns the
109       object; see below.) The owner implicitly has all grant options for the
110       object, too.
111
112       The possible privileges are:
113
114       SELECT
115       INSERT
116       UPDATE
117       DELETE
118       TRUNCATE
119       REFERENCES
120       TRIGGER
121       CREATE
122       CONNECT
123       TEMPORARY
124       EXECUTE
125       USAGE
126           Specific types of privileges, as defined in Section 5.7.
127
128       TEMP
129           Alternative spelling for TEMPORARY.
130
131       ALL PRIVILEGES
132           Grant all of the privileges available for the object's type. The
133           PRIVILEGES key word is optional in PostgreSQL, though it is
134           required by strict SQL.
135
136       The FUNCTION syntax works for plain functions, aggregate functions, and
137       window functions, but not for procedures; use PROCEDURE for those.
138       Alternatively, use ROUTINE to refer to a function, aggregate function,
139       window function, or procedure regardless of its precise type.
140
141       There is also an option to grant privileges on all objects of the same
142       type within one or more schemas. This functionality is currently
143       supported only for tables, sequences, functions, and procedures.  ALL
144       TABLES also affects views and foreign tables, just like the
145       specific-object GRANT command.  ALL FUNCTIONS also affects aggregate
146       and window functions, but not procedures, again just like the
147       specific-object GRANT command. Use ALL ROUTINES to include procedures.
148
149   GRANT on Roles
150       This variant of the GRANT command grants membership in a role to one or
151       more other roles. Membership in a role is significant because it
152       conveys the privileges granted to a role to each of its members.
153
154       If WITH ADMIN OPTION is specified, the member can in turn grant
155       membership in the role to others, and revoke membership in the role as
156       well. Without the admin option, ordinary users cannot do that. A role
157       is not considered to hold WITH ADMIN OPTION on itself, but it may grant
158       or revoke membership in itself from a database session where the
159       session user matches the role. Database superusers can grant or revoke
160       membership in any role to anyone. Roles having CREATEROLE privilege can
161       grant or revoke membership in any role that is not a superuser.
162
163       Unlike the case with privileges, membership in a role cannot be granted
164       to PUBLIC. Note also that this form of the command does not allow the
165       noise word GROUP.
166

NOTES

168       The REVOKE(7) command is used to revoke access privileges.
169
170       Since PostgreSQL 8.1, the concepts of users and groups have been
171       unified into a single kind of entity called a role. It is therefore no
172       longer necessary to use the keyword GROUP to identify whether a grantee
173       is a user or a group.  GROUP is still allowed in the command, but it is
174       a noise word.
175
176       A user may perform SELECT, INSERT, etc. on a column if they hold that
177       privilege for either the specific column or its whole table. Granting
178       the privilege at the table level and then revoking it for one column
179       will not do what one might wish: the table-level grant is unaffected by
180       a column-level operation.
181
182       When a non-owner of an object attempts to GRANT privileges on the
183       object, the command will fail outright if the user has no privileges
184       whatsoever on the object. As long as some privilege is available, the
185       command will proceed, but it will grant only those privileges for which
186       the user has grant options. The GRANT ALL PRIVILEGES forms will issue a
187       warning message if no grant options are held, while the other forms
188       will issue a warning if grant options for any of the privileges
189       specifically named in the command are not held. (In principle these
190       statements apply to the object owner as well, but since the owner is
191       always treated as holding all grant options, the cases can never
192       occur.)
193
194       It should be noted that database superusers can access all objects
195       regardless of object privilege settings. This is comparable to the
196       rights of root in a Unix system. As with root, it's unwise to operate
197       as a superuser except when absolutely necessary.
198
199       If a superuser chooses to issue a GRANT or REVOKE command, the command
200       is performed as though it were issued by the owner of the affected
201       object. In particular, privileges granted via such a command will
202       appear to have been granted by the object owner. (For role membership,
203       the membership appears to have been granted by the containing role
204       itself.)
205
206       GRANT and REVOKE can also be done by a role that is not the owner of
207       the affected object, but is a member of the role that owns the object,
208       or is a member of a role that holds privileges WITH GRANT OPTION on the
209       object. In this case the privileges will be recorded as having been
210       granted by the role that actually owns the object or holds the
211       privileges WITH GRANT OPTION. For example, if table t1 is owned by role
212       g1, of which role u1 is a member, then u1 can grant privileges on t1 to
213       u2, but those privileges will appear to have been granted directly by
214       g1. Any other member of role g1 could revoke them later.
215
216       If the role executing GRANT holds the required privileges indirectly
217       via more than one role membership path, it is unspecified which
218       containing role will be recorded as having done the grant. In such
219       cases it is best practice to use SET ROLE to become the specific role
220       you want to do the GRANT as.
221
222       Granting permission on a table does not automatically extend
223       permissions to any sequences used by the table, including sequences
224       tied to SERIAL columns. Permissions on sequences must be set
225       separately.
226
227       See Section 5.7 for more information about specific privilege types, as
228       well as how to inspect objects' privileges.
229

EXAMPLES

231       Grant insert privilege to all users on table films:
232
233           GRANT INSERT ON films TO PUBLIC;
234
235       Grant all available privileges to user manuel on view kinds:
236
237           GRANT ALL PRIVILEGES ON kinds TO manuel;
238
239       Note that while the above will indeed grant all privileges if executed
240       by a superuser or the owner of kinds, when executed by someone else it
241       will only grant those permissions for which the someone else has grant
242       options.
243
244       Grant membership in role admins to user joe:
245
246           GRANT admins TO joe;
247

COMPATIBILITY

249       According to the SQL standard, the PRIVILEGES key word in ALL
250       PRIVILEGES is required. The SQL standard does not support setting the
251       privileges on more than one object per command.
252
253       PostgreSQL allows an object owner to revoke their own ordinary
254       privileges: for example, a table owner can make the table read-only to
255       themselves by revoking their own INSERT, UPDATE, DELETE, and TRUNCATE
256       privileges. This is not possible according to the SQL standard. The
257       reason is that PostgreSQL treats the owner's privileges as having been
258       granted by the owner to themselves; therefore they can revoke them too.
259       In the SQL standard, the owner's privileges are granted by an assumed
260       entity “_SYSTEM”. Not being “_SYSTEM”, the owner cannot revoke these
261       rights.
262
263       According to the SQL standard, grant options can be granted to PUBLIC;
264       PostgreSQL only supports granting grant options to roles.
265
266       The SQL standard provides for a USAGE privilege on other kinds of
267       objects: character sets, collations, translations.
268
269       In the SQL standard, sequences only have a USAGE privilege, which
270       controls the use of the NEXT VALUE FOR expression, which is equivalent
271       to the function nextval in PostgreSQL. The sequence privileges SELECT
272       and UPDATE are PostgreSQL extensions. The application of the sequence
273       USAGE privilege to the currval function is also a PostgreSQL extension
274       (as is the function itself).
275
276       Privileges on databases, tablespaces, schemas, and languages are
277       PostgreSQL extensions.
278

SEE ALSO

280       REVOKE(7), ALTER DEFAULT PRIVILEGES (ALTER_DEFAULT_PRIVILEGES(7))
281
282
283
284PostgreSQL 12.2                      2020                             GRANT(7)
Impressum