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
|
<!--
doc/src/sgml/ref/alter_default_privileges.sgml
PostgreSQL documentation
-->
<refentry id="sql-alterdefaultprivileges">
<indexterm zone="sql-alterdefaultprivileges">
<primary>ALTER DEFAULT PRIVILEGES</primary>
</indexterm>
<refmeta>
<refentrytitle>ALTER DEFAULT PRIVILEGES</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>ALTER DEFAULT PRIVILEGES</refname>
<refpurpose>define default access privileges</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
ALTER DEFAULT PRIVILEGES
[ FOR { ROLE | USER } <replaceable>target_role</replaceable> [, ...] ]
[ IN SCHEMA <replaceable>schema_name</replaceable> [, ...] ]
<replaceable class="parameter">abbreviated_grant_or_revoke</replaceable>
<phrase>where <replaceable class="parameter">abbreviated_grant_or_revoke</replaceable> is one of:</phrase>
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { USAGE | SELECT | UPDATE }
[, ...] | ALL [ PRIVILEGES ] }
ON SEQUENCES
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { EXECUTE | ALL [ PRIVILEGES ] }
ON { FUNCTIONS | ROUTINES }
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON TYPES
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | CREATE | ALL [ PRIVILEGES ] }
ON SCHEMAS
TO { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ]
REVOKE [ GRANT OPTION FOR ]
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ { USAGE | SELECT | UPDATE }
[, ...] | ALL [ PRIVILEGES ] }
ON SEQUENCES
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ EXECUTE | ALL [ PRIVILEGES ] }
ON { FUNCTIONS | ROUTINES }
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | ALL [ PRIVILEGES ] }
ON TYPES
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | CREATE | ALL [ PRIVILEGES ] }
ON SCHEMAS
FROM { [ GROUP ] <replaceable class="parameter">role_name</replaceable> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
</synopsis>
</refsynopsisdiv>
<refsect1 id="sql-alterdefaultprivileges-description">
<title>Description</title>
<para>
<command>ALTER DEFAULT PRIVILEGES</command> allows you to set the
privileges that will be applied to objects created in the future.
(It does not affect privileges assigned to already-existing objects.)
Privileges can be set globally (i.e., for all objects created in the
current database), or just for objects created in specified schemas.
</para>
<para>
While you can change your own default privileges and the defaults of
roles that you are a member of, at object creation time, new object
permissions are only affected by the default privileges of the current
role, and are not inherited from any roles in which the current role
is a member.
</para>
<para>
As explained in <xref linkend="ddl-priv"/>,
the default privileges for any object type normally grant all grantable
permissions to the object owner, and may grant some privileges to
<literal>PUBLIC</literal> as well. However, this behavior can be changed by
altering the global default privileges with
<command>ALTER DEFAULT PRIVILEGES</command>.
</para>
<para>
Currently,
only the privileges for schemas, tables (including views and foreign
tables), sequences, functions, and types (including domains) can be
altered. For this command, functions include aggregates and procedures.
The words <literal>FUNCTIONS</literal> and <literal>ROUTINES</literal> are
equivalent in this command. (<literal>ROUTINES</literal> is preferred
going forward as the standard term for functions and procedures taken
together. In earlier PostgreSQL releases, only the
word <literal>FUNCTIONS</literal> was allowed. It is not possible to set
default privileges for functions and procedures separately.)
</para>
<para>
Default privileges that are specified per-schema are added to whatever
the global default privileges are for the particular object type.
This means you cannot revoke privileges per-schema if they are granted
globally (either by default, or according to a previous <command>ALTER
DEFAULT PRIVILEGES</command> command that did not specify a schema).
Per-schema <literal>REVOKE</literal> is only useful to reverse the
effects of a previous per-schema <literal>GRANT</literal>.
</para>
<refsect2>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable>target_role</replaceable></term>
<listitem>
<para>
Change default privileges for objects created by the
<replaceable>target_role</replaceable>, or the current
role if unspecified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>schema_name</replaceable></term>
<listitem>
<para>
The name of an existing schema. If specified, the default privileges
are altered for objects later created in that schema.
If <literal>IN SCHEMA</literal> is omitted, the global default privileges
are altered.
<literal>IN SCHEMA</literal> is not allowed when setting privileges
for schemas, since schemas can't be nested.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>role_name</replaceable></term>
<listitem>
<para>
The name of an existing role to grant or revoke privileges for.
This parameter, and all the other parameters in
<replaceable class="parameter">abbreviated_grant_or_revoke</replaceable>,
act as described under
<xref linkend="sql-grant"/> or
<xref linkend="sql-revoke"/>,
except that one is setting permissions for a whole class of objects
rather than specific named objects.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect2>
</refsect1>
<refsect1 id="sql-alterdefaultprivileges-notes">
<title>Notes</title>
<para>
Use <xref linkend="app-psql"/>'s <command>\ddp</command> command
to obtain information about existing assignments of default privileges.
The meaning of the privilege display is the same as explained for
<command>\dp</command> in <xref linkend="ddl-priv"/>.
</para>
<para>
If you wish to drop a role for which the default privileges have been
altered, it is necessary to reverse the changes in its default privileges
or use <command>DROP OWNED BY</command> to get rid of the default privileges entry
for the role.
</para>
</refsect1>
<refsect1 id="sql-alterdefaultprivileges-examples">
<title>Examples</title>
<para>
Grant SELECT privilege to everyone for all tables (and views) you
subsequently create in schema <literal>myschema</literal>, and allow
role <literal>webuser</literal> to INSERT into them too:
<programlisting>
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT SELECT ON TABLES TO PUBLIC;
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT INSERT ON TABLES TO webuser;
</programlisting>
</para>
<para>
Undo the above, so that subsequently-created tables won't have any
more permissions than normal:
<programlisting>
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE SELECT ON TABLES FROM PUBLIC;
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE INSERT ON TABLES FROM webuser;
</programlisting>
</para>
<para>
Remove the public EXECUTE permission that is normally granted on functions,
for all functions subsequently created by role <literal>admin</literal>:
<programlisting>
ALTER DEFAULT PRIVILEGES FOR ROLE admin REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
</programlisting>
Note however that you <emphasis>cannot</emphasis> accomplish that effect
with a command limited to a single schema. This command has no effect,
unless it is undoing a matching <literal>GRANT</literal>:
<programlisting>
ALTER DEFAULT PRIVILEGES IN SCHEMA public REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
</programlisting>
That's because per-schema default privileges can only add privileges to
the global setting, not remove privileges granted by it.
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
There is no <command>ALTER DEFAULT PRIVILEGES</command> statement in the SQL
standard.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-grant"/></member>
<member><xref linkend="sql-revoke"/></member>
</simplelist>
</refsect1>
</refentry>
|