ALTER DEFAULT PRIVILEGES
7
SQL - Language Statements
ALTER DEFAULT PRIVILEGES
define default access privileges
ALTER DEFAULT PRIVILEGES
ALTER DEFAULT PRIVILEGES
[ FOR { ROLE | USER } target_role [, ...] ]
[ IN SCHEMA schema_name [, ...] ]
abbreviated_grant_or_revoke
where abbreviated_grant_or_revoke is one of:
GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { { USAGE | SELECT | UPDATE }
[, ...] | ALL [ PRIVILEGES ] }
ON SEQUENCES
TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
GRANT { EXECUTE | ALL [ PRIVILEGES ] }
ON FUNCTIONS
TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]
REVOKE [ GRANT OPTION FOR ]
{ { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER }
[, ...] | ALL [ PRIVILEGES ] }
ON TABLES
FROM { [ GROUP ] role_name | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ { USAGE | SELECT | UPDATE }
[, ...] | ALL [ PRIVILEGES ] }
ON SEQUENCES
FROM { [ GROUP ] role_name | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ EXECUTE | ALL [ PRIVILEGES ] }
ON FUNCTIONS
FROM { [ GROUP ] role_name | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
Description
ALTER DEFAULT PRIVILEGES> 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.) Currently,
only the privileges for tables (including views and foreign tables),
sequences, and functions can be altered.
You can change default privileges only for objects that will be created by
yourself or by roles that you are a member of. The privileges can be set
globally (i.e., for all objects created in the current database),
or just for objects created in specified schemas. Default privileges
that are specified per-schema are added to whatever the global default
privileges are for the particular object type.
As explained under ,
the default privileges for any object type normally grant all grantable
permissions to the object owner, and may grant some privileges to
PUBLIC> as well. However, this behavior can be changed by
altering the global default privileges with
ALTER DEFAULT PRIVILEGES>.
Parameters
target_role
The name of an existing role of which the current role is a member.
If FOR ROLE> is omitted, the current role is assumed.
schema_name
The name of an existing schema. Each target_role>
must have CREATE> privileges for each specified schema.
If IN SCHEMA> is omitted, the global default privileges
are altered.
role_name
The name of an existing role to grant or revoke privileges for.
This parameter, and all the other parameters in
abbreviated_grant_or_revoke>,
act as described under
or
,
except that one is setting permissions for a whole class of objects
rather than specific named objects.
Notes
Use 's \ddp command
to obtain information about existing assignments of default privileges.
The meaning of the privilege values is the same as explained for
\dp under
.
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 DROP OWNED BY> to get rid of the default privileges entry
for the role.
Examples
Grant SELECT privilege to everyone for all tables (and views) you
subsequently create in schema myschema, and allow
role webuser> to INSERT into them too:
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT SELECT ON TABLES TO PUBLIC;
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema GRANT INSERT ON TABLES TO webuser;
Undo the above, so that subsequently-created tables won't have any
more permissions than normal:
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE SELECT ON TABLES FROM PUBLIC;
ALTER DEFAULT PRIVILEGES IN SCHEMA myschema REVOKE INSERT ON TABLES FROM webuser;
Remove the public EXECUTE permission that is normally granted on functions,
for all functions subsequently created by role admin>:
ALTER DEFAULT PRIVILEGES FOR ROLE admin REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
Compatibility
There is no ALTER DEFAULT PRIVILEGES statement in the SQL
standard.
See Also