summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/revoke.sgml
blob: 2db66bbf378e22c4fa4f1989ead18468d1fd24e0 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
<!--
doc/src/sgml/ref/revoke.sgml
PostgreSQL documentation
-->

<refentry id="sql-revoke">
 <indexterm zone="sql-revoke">
  <primary>REVOKE</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>REVOKE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>REVOKE</refname>
  <refpurpose>remove access privileges</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
REVOKE [ GRANT OPTION FOR ]
    { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
    [, ...] | ALL [ PRIVILEGES ] }
    ON { [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
         | ALL TABLES IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="parameter">column_name</replaceable> [, ...] )
    [, ...] | ALL [ PRIVILEGES ] ( <replaceable class="parameter">column_name</replaceable> [, ...] ) }
    ON [ TABLE ] <replaceable class="parameter">table_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { USAGE | SELECT | UPDATE }
    [, ...] | ALL [ PRIVILEGES ] }
    ON { SEQUENCE <replaceable class="parameter">sequence_name</replaceable> [, ...]
         | ALL SEQUENCES IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] }
    ON DATABASE <replaceable>database_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { USAGE | ALL [ PRIVILEGES ] }
    ON DOMAIN <replaceable>domain_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { USAGE | ALL [ PRIVILEGES ] }
    ON FOREIGN DATA WRAPPER <replaceable>fdw_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { USAGE | ALL [ PRIVILEGES ] }
    ON FOREIGN SERVER <replaceable>server_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { EXECUTE | ALL [ PRIVILEGES ] }
    ON { { FUNCTION | PROCEDURE | ROUTINE } <replaceable>function_name</replaceable> [ ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceable class="parameter">arg_name</replaceable> ] <replaceable class="parameter">arg_type</replaceable> [, ...] ] ) ] [, ...]
         | ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <replaceable>schema_name</replaceable> [, ...] }
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { USAGE | ALL [ PRIVILEGES ] }
    ON LANGUAGE <replaceable>lang_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
    ON LARGE OBJECT <replaceable class="parameter">loid</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { SET | ALTER SYSTEM } [, ...] | ALL [ PRIVILEGES ] }
    ON PARAMETER <replaceable class="parameter">configuration_parameter</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
    ON SCHEMA <replaceable>schema_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { CREATE | ALL [ PRIVILEGES ] }
    ON TABLESPACE <replaceable>tablespace_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ GRANT OPTION FOR ]
    { USAGE | ALL [ PRIVILEGES ] }
    ON TYPE <replaceable>type_name</replaceable> [, ...]
    FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

REVOKE [ { ADMIN | INHERIT | SET } OPTION FOR ]
    <replaceable class="parameter">role_name</replaceable> [, ...] FROM <replaceable class="parameter">role_specification</replaceable> [, ...]
    [ GRANTED BY <replaceable class="parameter">role_specification</replaceable> ]
    [ CASCADE | RESTRICT ]

<phrase>where <replaceable class="parameter">role_specification</replaceable> can be:</phrase>

    [ GROUP ] <replaceable class="parameter">role_name</replaceable>
  | PUBLIC
  | CURRENT_ROLE
  | CURRENT_USER
  | SESSION_USER
</synopsis>
 </refsynopsisdiv>

 <refsect1 id="sql-revoke-description">
  <title>Description</title>

  <para>
   The <command>REVOKE</command> command revokes previously granted
   privileges from one or more roles.  The key word
   <literal>PUBLIC</literal> refers to the implicitly defined group of
   all roles.
  </para>

  <para>
   See the description of the <link linkend="sql-grant"><command>GRANT</command></link> command for
   the meaning of the privilege types.
  </para>

  <para>
   Note that any particular role will have the sum
   of privileges granted directly to it, privileges granted to any role it
   is presently a member of, and privileges granted to
   <literal>PUBLIC</literal>.  Thus, for example, revoking <literal>SELECT</literal> privilege
   from <literal>PUBLIC</literal> does not necessarily mean that all roles
   have lost <literal>SELECT</literal> privilege on the object: those who have it granted
   directly or via another role will still have it.  Similarly, revoking
   <literal>SELECT</literal> from a user might not prevent that user from using
   <literal>SELECT</literal> if <literal>PUBLIC</literal> or another membership
   role still has <literal>SELECT</literal> rights.
  </para>

  <para>
   If <literal>GRANT OPTION FOR</literal> is specified, only the grant
   option for the privilege is revoked, not the privilege itself.
   Otherwise, both the privilege and the grant option are revoked.
  </para>

  <para>
   If a user holds a privilege with grant option and has granted it to
   other users then the privileges held by those other users are
   called dependent privileges. If the privilege or the grant option
   held by the first user is being revoked and dependent privileges
   exist, those dependent privileges are also revoked if
   <literal>CASCADE</literal> is specified; if it is not, the revoke action
   will fail.  This recursive revocation only affects privileges that
   were granted through a chain of users that is traceable to the user
   that is the subject of this <literal>REVOKE</literal> command.
   Thus, the affected users might effectively keep the privilege if it
   was also granted through other users.
  </para>

  <para>
   When revoking privileges on a table, the corresponding column privileges
   (if any) are automatically revoked on each column of the table, as well.
   On the other hand, if a role has been granted privileges on a table, then
   revoking the same privileges from individual columns will have no effect.
  </para>

  <para>
   When revoking membership in a role, <literal>GRANT OPTION</literal> is instead
   called <literal>ADMIN OPTION</literal>, but the behavior is similar.
   Note that, in releases prior to <productname>PostgreSQL</productname> 16,
   dependent privileges were not tracked for grants of role membership,
   and thus <literal>CASCADE</literal> had no effect for role membership.
   This is no longer the case.
   Note also that this form of the command does not
   allow the noise word <literal>GROUP</literal>
   in <replaceable class="parameter">role_specification</replaceable>.
  </para>

  <para>
   Just as <literal>ADMIN OPTION</literal> can be removed from an existing
   role grant, it is also possible to revoke <literal>INHERIT OPTION</literal>
   or <literal>SET OPTION</literal>.  This is equivalent to setting the value
   of the corresponding option to <literal>FALSE</literal>.
  </para>
 </refsect1>

 <refsect1 id="sql-revoke-notes">
  <title>Notes</title>

  <para>
   A user can only revoke privileges that were granted directly by
   that user.  If, for example, user A has granted a privilege with
   grant option to user B, and user B has in turn granted it to user
   C, then user A cannot revoke the privilege directly from C.
   Instead, user A could revoke the grant option from user B and use
   the <literal>CASCADE</literal> option so that the privilege is
   in turn revoked from user C.  For another example, if both A and B
   have granted the same privilege to C, A can revoke their own grant
   but not B's grant, so C will still effectively have the privilege.
  </para>

   <para>
    When a non-owner of an object attempts to <command>REVOKE</command> privileges
    on the object, the command will fail outright if the user has no
    privileges whatsoever on the object.  As long as some privilege is
    available, the command will proceed, but it will revoke only those
    privileges for which the user has grant options.  The <command>REVOKE ALL
    PRIVILEGES</command> forms will issue a warning message if no grant options are
    held, while the other forms will issue a warning if grant options for
    any of the privileges specifically named in the command are not held.
    (In principle these statements apply to the object owner as well, but
    since the owner is always treated as holding all grant options, the
    cases can never occur.)
   </para>

   <para>
    If a superuser chooses to issue a <command>GRANT</command> or <command>REVOKE</command>
    command, the command is performed as though it were issued by the
    owner of the affected object.  (Since roles do not have owners, in the
    case of a <command>GRANT</command> of role membership, the command is
    performed as though it were issued by the bootstrap superuser.)
    Since all privileges ultimately come
    from the object owner (possibly indirectly via chains of grant options),
    it is possible for a superuser to revoke all privileges, but this might
    require use of <literal>CASCADE</literal> as stated above.
   </para>

   <para>
    <command>REVOKE</command> can also be done by a role
    that is not the owner of the affected object, but is a member of the role
    that owns the object, or is a member of a role that holds privileges
    <literal>WITH GRANT OPTION</literal> on the object.  In this case the
    command is performed as though it were issued by the containing role that
    actually owns the object or holds the privileges
    <literal>WITH GRANT OPTION</literal>.  For example, if table
    <literal>t1</literal> is owned by role <literal>g1</literal>, of which role
    <literal>u1</literal> is a member, then <literal>u1</literal> can revoke privileges
    on <literal>t1</literal> that are recorded as being granted by <literal>g1</literal>.
    This would include grants made by <literal>u1</literal> as well as by other
    members of role <literal>g1</literal>.
   </para>

   <para>
    If the role executing <command>REVOKE</command> holds privileges
    indirectly via more than one role membership path, it is unspecified
    which containing role will be used to perform the command.  In such cases
    it is best practice to use <command>SET ROLE</command> to become the specific
    role you want to do the <command>REVOKE</command> as.  Failure to do so might
    lead to revoking privileges other than the ones you intended, or not
    revoking anything at all.
   </para>

   <para>
    See <xref linkend="ddl-priv"/> for more information about specific
    privilege types, as well as how to inspect objects' privileges.
   </para>
 </refsect1>

 <refsect1 id="sql-revoke-examples">
  <title>Examples</title>

  <para>
   Revoke insert privilege for the public on table
   <literal>films</literal>:

<programlisting>
REVOKE INSERT ON films FROM PUBLIC;
</programlisting>
  </para>

  <para>
   Revoke all privileges from user <literal>manuel</literal> on view
   <literal>kinds</literal>:

<programlisting>
REVOKE ALL PRIVILEGES ON kinds FROM manuel;
</programlisting>

   Note that this actually means <quote>revoke all privileges that I
   granted</quote>.
  </para>

  <para>
   Revoke membership in role <literal>admins</literal> from user <literal>joe</literal>:

<programlisting>
REVOKE admins FROM joe;
</programlisting></para>
 </refsect1>

 <refsect1 id="sql-revoke-compatibility">
  <title>Compatibility</title>

   <para>
    The compatibility notes of the <link linkend="sql-grant"><command>GRANT</command></link> command
    apply analogously to <command>REVOKE</command>.
    The keyword <literal>RESTRICT</literal> or <literal>CASCADE</literal>
    is required according to the standard, but <productname>PostgreSQL</productname>
    assumes <literal>RESTRICT</literal> by default.
   </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-grant"/></member>
   <member><xref linkend="sql-alterdefaultprivileges"/></member>
  </simplelist>
 </refsect1>

</refentry>