GRANT (Schema)
Grants schema privileges to users and roles. By default, only superusers and the schema owner have the following schema privileges:
- Create objects within a schema
- Alter and drop a schema
By default, new users cannot access schema PUBLIC. You must explicitly grant all new users USAGE privileges on the PUBLIC schema.
Syntax
GRANT { privilege[,…] | ALL [ PRIVILEGES ] [ EXTEND ] } ON SCHEMA [database.]schema[,…] TO grantee[,…] [ WITH GRANT OPTION ]
Parameters
privilege |
One of the following privileges:
You can also grant the following privileges on a schema, to be inherited by tables and their projections, and by views of that schema. If inheritance is enabled for the database and schema, these privileges are automatically granted to those objects on creation:
|
ALL [PRIVILEGES][EXTEND] |
Grants USAGE AND CREATE privileges. Inherited privileges must be granted explicitly. You can qualify
|
[database.]schema |
Specifies a target schema. If you specify a database, it must be the current database. |
grantee |
Specifies who is granted privileges, one of the following: |
WITH GRANT OPTION |
Gives grantee the privilege to grant the same privileges to other users or roles, and also revoke them. For details, see Granting Privileges in the Administrator's Guide. |
Privileges
Non-superuser: USAGE on the schema and one of the following:
- Owner
- Privileges grantee given the option (
WITH GRANT OPTION
) of granting privileges to other users or roles.
Examples
Grant user Joe USAGE privilege on schema online_sales
.
=> CREATE USER Joe; CREATE USER
=> GRANT USAGE ON SCHEMA online_sales TO Joe; GRANT PRIVILEGE