1ALTER DEFAULT PRIVILEGES(7P)ostgreSQL 13.4 DocumentatiAoLnTER DEFAULT PRIVILEGES(7)
2
3
4
6 ALTER_DEFAULT_PRIVILEGES - define default access privileges
7
9 ALTER DEFAULT PRIVILEGES
10 [ FOR { ROLE | USER } target_role [, ...] ]
11 [ IN SCHEMA schema_name [, ...] ]
12 abbreviated_grant_or_revoke
13
14 where abbreviated_grant_or_revoke is one of:
15
16 GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
17 [, ...] | ALL [ PRIVILEGES ] }
18 ON TABLES
19 TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
20
21 GRANT { { USAGE | SELECT | UPDATE }
22 [, ...] | ALL [ PRIVILEGES ] }
23 ON SEQUENCES
24 TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
25
26 GRANT { EXECUTE | ALL [ PRIVILEGES ] }
27 ON { FUNCTIONS | ROUTINES }
28 TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
29
30 GRANT { USAGE | ALL [ PRIVILEGES ] }
31 ON TYPES
32 TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
33
34 GRANT { USAGE | CREATE | ALL [ PRIVILEGES ] }
35 ON SCHEMAS
36 TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
37
38 REVOKE [ GRANT OPTION FOR ]
39 { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
40 [, ...] | ALL [ PRIVILEGES ] }
41 ON TABLES
42 FROM { [ GROUP ] role_name | PUBLIC } [, ...]
43 [ CASCADE | RESTRICT ]
44
45 REVOKE [ GRANT OPTION FOR ]
46 { { USAGE | SELECT | UPDATE }
47 [, ...] | ALL [ PRIVILEGES ] }
48 ON SEQUENCES
49 FROM { [ GROUP ] role_name | PUBLIC } [, ...]
50 [ CASCADE | RESTRICT ]
51
52 REVOKE [ GRANT OPTION FOR ]
53 { EXECUTE | ALL [ PRIVILEGES ] }
54 ON { FUNCTIONS | ROUTINES }
55 FROM { [ GROUP ] role_name | PUBLIC } [, ...]
56 [ CASCADE | RESTRICT ]
57
58 REVOKE [ GRANT OPTION FOR ]
59 { USAGE | ALL [ PRIVILEGES ] }
60 ON TYPES
61 FROM { [ GROUP ] role_name | PUBLIC } [, ...]
62 [ CASCADE | RESTRICT ]
63
64 REVOKE [ GRANT OPTION FOR ]
65 { USAGE | CREATE | ALL [ PRIVILEGES ] }
66 ON SCHEMAS
67 FROM { [ GROUP ] role_name | PUBLIC } [, ...]
68 [ CASCADE | RESTRICT ]
69
71 ALTER DEFAULT PRIVILEGES allows you to set the privileges that will be
72 applied to objects created in the future. (It does not affect
73 privileges assigned to already-existing objects.) Currently, only the
74 privileges for schemas, tables (including views and foreign tables),
75 sequences, functions, and types (including domains) can be altered. For
76 this command, functions include aggregates and procedures. The words
77 FUNCTIONS and ROUTINES are equivalent in this command. (ROUTINES is
78 preferred going forward as the standard term for functions and
79 procedures taken together. In earlier PostgreSQL releases, only the
80 word FUNCTIONS was allowed. It is not possible to set default
81 privileges for functions and procedures separately.)
82
83 You can change default privileges only for objects that will be created
84 by yourself or by roles that you are a member of. The privileges can be
85 set globally (i.e., for all objects created in the current database),
86 or just for objects created in specified schemas.
87
88 As explained in Section 5.7, the default privileges for any object type
89 normally grant all grantable permissions to the object owner, and may
90 grant some privileges to PUBLIC as well. However, this behavior can be
91 changed by altering the global default privileges with ALTER DEFAULT
92 PRIVILEGES.
93
94 Default privileges that are specified per-schema are added to whatever
95 the global default privileges are for the particular object type. This
96 means you cannot revoke privileges per-schema if they are granted
97 globally (either by default, or according to a previous ALTER DEFAULT
98 PRIVILEGES command that did not specify a schema). Per-schema REVOKE is
99 only useful to reverse the effects of a previous per-schema GRANT.
100
101 Parameters
102 target_role
103 The name of an existing role of which the current role is a member.
104 If FOR ROLE is omitted, the current role is assumed.
105
106 schema_name
107 The name of an existing schema. If specified, the default
108 privileges are altered for objects later created in that schema. If
109 IN SCHEMA is omitted, the global default privileges are altered.
110 IN SCHEMA is not allowed when setting privileges for schemas, since
111 schemas can't be nested.
112
113 role_name
114 The name of an existing role to grant or revoke privileges for.
115 This parameter, and all the other parameters in
116 abbreviated_grant_or_revoke, act as described under GRANT(7) or
117 REVOKE(7), except that one is setting permissions for a whole class
118 of objects rather than specific named objects.
119
121 Use psql(1)'s \ddp command to obtain information about existing
122 assignments of default privileges. The meaning of the privilege display
123 is the same as explained for \dp in Section 5.7.
124
125 If you wish to drop a role for which the default privileges have been
126 altered, it is necessary to reverse the changes in its default
127 privileges or use DROP OWNED BY to get rid of the default privileges
128 entry for the role.
129
131 Grant SELECT privilege to everyone for all tables (and views) you
132 subsequently create in schema myschema, and allow role webuser to
133 INSERT into them too:
134
135 ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT SELECT ON TABLES TO PUBLIC;
136 ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT INSERT ON TABLES TO webuser;
137
138 Undo the above, so that subsequently-created tables won't have any more
139 permissions than normal:
140
141 ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE SELECT ON TABLES FROM PUBLIC;
142 ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE INSERT ON TABLES FROM webuser;
143
144 Remove the public EXECUTE permission that is normally granted on
145 functions, for all functions subsequently created by role admin:
146
147 ALTER DEFAULT PRIVILEGES FOR ROLE admin REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
148
149 Note however that you cannot accomplish that effect with a command
150 limited to a single schema. This command has no effect, unless it is
151 undoing a matching GRANT:
152
153 ALTER DEFAULT PRIVILEGES IN SCHEMA public REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
154
155 That's because per-schema default privileges can only add privileges to
156 the global setting, not remove privileges granted by it.
157
159 There is no ALTER DEFAULT PRIVILEGES statement in the SQL standard.
160
162 GRANT(7), REVOKE(7)
163
164
165
166PostgreSQL 13.4 2021 ALTER DEFAULT PRIVILEGES(7)