Defines access privileges.
GRANT { {SELECT | INSERT | UPDATE | DELETE | REFERENCES |
TRIGGER | TRUNCATE } [, ...] | ALL [PRIVILEGES] }
ON { [TABLE] [[[ONLY] <table_name> [, ...]] [, ...]]
| ALL TABLES IN SCHEMA <schema_name> [, ...] }
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <column_name> [, ...] )
[, ...] | ALL [ PRIVILEGES ] ( <column_name> [, ...] ) }
ON [TABLE] [[[ONLY] <table_name> [, ...]] [, ...]]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { {USAGE | SELECT | UPDATE} [, ...] | ALL [PRIVILEGES] }
ON { SEQUENCE <sequence_name> [, ...]
| ALL SEQUENCES IN SCHEMA <schema_name> [, ...] }
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { {CREATE | CONNECT | TEMPORARY | TEMP} [, ...] | ALL
[PRIVILEGES] }
ON DATABASE <database_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON DOMAIN <domain_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN DATA WRAPPER <fdw_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN SERVER <server_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { EXECUTE | ALL [PRIVILEGES] }
ON { { FUNCTION | PROCEDURE | ROUTINE } <routine_name> [ ( [ [ <argmode> ] [ <argname> ] <argtype> [, ...] ] ) ] [, ...]
| ALL { FUNCTIONS | PROCEDURES | ROUTINES } IN SCHEMA <schema_name> [, ...] }
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [PRIVILEGES] }
ON LANGUAGE <lang_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { { CREATE | USAGE } [, ...] | ALL [PRIVILEGES] }
ON SCHEMA <schema_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT { CREATE | ALL [PRIVILEGES] }
ON TABLESPACE <tablespace_name> [, ...]
TO <role_specification> [ WITH GRANT OPTION ]
GRANT { USAGE | ALL [ PRIVILEGES ] }
ON TYPE <type_name> [, ...]
TO <role_specification> [, ...] [ WITH GRANT OPTION ]
GRANT <role_name> [, ...] TO <role_specification> [, ...]
[ WITH ADMIN OPTION ]
[ GRANTED BY <role_specification> ]
GRANT { SELECT | INSERT | ALL [PRIVILEGES] }
ON PROTOCOL <protocolname>
TO <username>
where <role_specification> can be:
[ GROUP ] <role_name>
| PUBLIC
| CURRENT_USER
| SESSION_USER
The GRANT
command has two basic variants: one that grants privileges on a database object (table, column, view, foreign table, sequence, database, foreign-data wrapper, foreign server, function, procedural language, schema, or tablespace), and one that grants membership in a role. These variants are similar in many ways, but they are different enough to be described separately.
GRANT on Database Objects
This variant of the GRANT
command gives specific privileges on a database object to one or more roles. These privileges are added to those already granted, if any.
The keyword PUBLIC
indicates that the privileges are to be granted to all roles, including those that may be created later. PUBLIC
may be thought of as an implicitly defined group-level role that always includes all roles. 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 PUBLIC
.
If WITH GRANT OPTION
is specified, the recipient of the privilege may in turn grant it to others. Without a grant option, the recipient cannot do that. Grant options cannot be granted to PUBLIC
.
There is no need to grant privileges to the owner of an object (usually the role that created it), as the owner has all privileges by default. (The owner could, however, choose to revoke some of their own privileges for safety.) it The right to drop an object, or to alter its definition in any way is not treated as a grantable privilege; it is inherent in the owner, and cannot be granted or revoked. (However, a similar effect can be obtained by granting or revoking membership in the role that owns the object; see below.) The owner implicitly has all grant options for the object, too.
The possible privileges are:
SELECT
INSERT
UPDATE
DELETE
TRUNCATE
REFERENCES
TRIGGER
CREATE
CONNECT
TEMPORARY
, TEMP
EXECUTE
USAGE
ALL PRIVILEGES
The FUNCTION
syntax works for plain functions, aggregate functions, and window functions, but not for procedures; use PROCEDURE
for those. Alternatively, use ROUTINE
to refer to a function, aggregate function, window function, or procedure regardless of its precise type.
There is also an option to grant privileges on all objects of the same type within one or more schemas. This functionality is currently supported only for tables, sequences, functions, and procedures. ALL TABLES
also affects views and foreign tables, just like the specific-object GRANT
command. ALL FUNCTIONS
also affects aggregate and window functions, but not procedures, again just like the specific-object GRANT
command. Use ALL ROUTINES
to include procedures.
GRANT on Roles
This variant of the GRANT
command grants membership in a role to one or more other roles. Membership in a role is significant because it conveys the privileges granted to a role to each of its members.
If WITH ADMIN OPTION
is specified, the member may in turn grant membership in the role to others, and revoke membership in the role as well. Without the admin option, ordinary users cannot do that. A role is not considered to hold WITH ADMIN OPTION
on itself, but it may grant or revoke membership in itself from a database session where the session user matches the role. Database superusers can grant or revoke membership in any role to anyone. Roles having CREATEROLE
privilege can grant or revoke membership in any role that is not a superuser.
If GRANTED BY
is specified, the grant is recorded as having been done by the specified role. Only database superusers may use this option, except when it names the same role executing the command.
Unlike the case with privileges, membership in a role cannot be granted to PUBLIC
. Note also that this form of the command does not allow the noise word GROUP
in role_specification.
GRANT on Partitioned Tables
By default, when you grant privileges to a partitioned table, Greenplum Database recurses the operation to its child tables. To direct Greenplum to perform the GRANT
on the partitioned table only, specify the ONLY <table_name>
clause.
GRANT on Protocols
You can also use the GRANT
command to specify which users can access a trusted protocol. (If the protocol is not trusted, you cannot give any other user permission to use it to read or write data.)
To allow a user to create a readable external table with a trusted protocol:
GRANT SELECT ON PROTOCOL <protocolname> TO <username>
To allow a user to create a writable external table with a trusted protocol:
GRANT INSERT ON PROTOCOL <protocolname> TO <username>
To allow a user to create both readable and writable external table with a trusted protocol:
GRANT ALL ON PROTOCOL <protocolname> TO <username>
You can also use this command to grant users permissions to create and use s3
and pxf
external tables. However, external tables of type http
, https
, gpfdist
, and gpfdists
, are implemented internally in Greenplum Database instead of as custom protocols. For these types, use the CREATE ROLE
or ALTER ROLE
command to set the CREATEEXTTABLE
or NOCREATEEXTTABLE
attribute for each user. See CREATE ROLE for syntax and examples.
SELECT
from any column, or the specific columns listed, of the specified table, view, or sequence. Also allows the use of
COPY TO
. This privilege is also needed to reference existing column values in
UPDATE
or
DELETE
.
INSERT
of a new row into the specified table. If specific columns are listed, only those columns may be assigned to in the
INSERT
command (other columns will receive default values). Also allows
COPY FROM
.
UPDATE
of any column, or the specific columns listed, of the specified table.
SELECT ... FOR UPDATE
and
SELECT ... FOR SHARE
also require this privilege on at least one column, (as well as the
SELECT
privilege). For sequences, this privilege allows the use of the
nextval()
and
setval()
functions.
DELETE
of a row from the specified table.
Allows the creation of a trigger on the specified table.
NoteGreenplum Database does not support triggers.
TRUNCATE
of all rows from the specified table.
For databases, allows new schemas to be created within the database.
For schemas, allows new objects to be created within the schema. To rename an existing object, you must own the object and have this privilege for the containing schema.
pg_hba.conf
).
For procedural languages, allows the use of the specified language for the creation of functions in that language. This is the only type of privilege that is applicable to procedural languages.
For schemas, allows access to objects contained in the specified schema (assuming that the objects' own privilege requirements are also met). Essentially this allows the grantee to look up objects within the schema.
For sequences, this privilege allows the use of the currval()
and nextval()
function.
For types and domains, this privilege allows the use of the type or domain in the creation of tables, functions, and other schema objects. (Note that it does not control general "usage" of the type, such as values of the type appearing in queries. It only prevents objects from being created that depend on the type. The main purpose of the privilege is controlling which users create dependencies on a type, which could prevent the owner from changing the type later.)
For foreign-data wrappers, this privilege enables the grantee to create new servers using that foreign-data wrapper.
PRIVILEGES
key word is optional in Greenplum Database, though it is required by strict SQL.
The REVOKE command is used to revoke access privileges.
Greenplum Database unifies the concepts of users and groups into a single kind of entity called a role. It is therefore not necessary to use the keyword GROUP
to identify whether a grantee is a user or a group. GROUP
is still allowed in the command, but it is a noise word.
A user may perform SELECT
, INSERT
, and so forth, on a column if they hold that privilege for either the specific column or the whole table. Granting the privilege at the table level and then revoking it for one column does not do what you might wish: the table-level grant is unaffected by a column-level operation.
When a non-owner of an object attempts to GRANT
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 grant only those privileges for which the user has grant options. The GRANT ALL PRIVILEGES
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.)
Database superusers can access all objects regardless of object privilege settings. This is comparable to the rights of root
in a Unix system. As with root
, it's unwise to operate as a superuser except when absolutely necessary. One exception to this rule is view objects. Access to tables referenced in the view is determined by permissions of the view owner not the current user (even if the current user is a superuser).
If a superuser chooses to issue a GRANT
or REVOKE
command, the command is performed as though it were issued by the owner of the affected object. In particular, privileges granted via such a command will appear to have been granted by the object owner. (For role membership, the membership appears to have been granted by the containing role itself.)
GRANT
and REVOKE
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 WITH GRANT OPTION
on the object. In this case the privileges will be recorded as having been granted by the role that actually owns the object or holds the privileges WITH GRANT OPTION
. For example, if table t1
is owned by role g1
, of which role u1
is a member, then u1
can grant privileges on t1
to u2
, but those privileges will appear to have been granted directly by g1
. Any other member of role g1
could revoke them later.
If the role executing GRANT
holds the required privileges indirectly via more than one role membership path, it is unspecified which containing role will be recorded as having done the grant. In such cases it is best practice to use SET ROLE
to become the specific role you want to do the GRANT
as.
Granting permission on a table does not automatically extend permissions to any sequences used by the table, including sequences tied to SERIAL
columns. Permissions on a sequence must be set separately.
The GRANT
command cannot be used to set privileges for the protocols file
, gpfdist
, or gpfdists
. These protocols are implemented internally in Greenplum Database. Instead, use the CREATE ROLE or ALTER ROLE command to set the CREATEEXTTABLE
attribute for the role.
Use psql
's \dp
meta-command to obtain information about existing privileges for tables and columns. There are other \d
meta-commands that you can use to display the privileges of non-table objects.
Grant insert privilege to all roles on table mytable
:
GRANT INSERT ON mytable TO PUBLIC;
Grant all available privileges to user manuel
on view kinds
:
GRANT ALL PRIVILEGES ON kinds TO manuel;
Note that while the above will indeed grant all privileges if run by a superuser or the owner of kinds
, when run by someone else it will only grant those permissions for which the granting role has grant options.
Grant membership in role admins
to user joe
:
GRANT admins TO joe;
According to the SQL standard, the PRIVILEGES
key word in ALL PRIVILEGES
is required, but it is optional in Greenplum Database. The SQL standard does not support setting the privileges on more than one object per command.
Greenplum Database allows an object owner to revoke their own ordinary privileges: for example, a table owner can make the table read-only to theirself by revoking their own INSERT
, UPDATE
, DELETE
, and TRUNCATE
privileges. This is not possible according to the SQL standard. Greenplum Database treats the owner's privileges as having been granted by the owner to the owner; therefore they can revoke them too. In the SQL standard, the owner's privileges are granted by an assumed system entity. Not being system, the owner cannot revoke these rights.
The SQL standard allows the GRANTED BY
option to be used in all forms of GRANT
. Greenplum Database only supports it when granting role membership, and even then only superusers may use it in nontrivial ways.
The SQL standard provides for a USAGE
privilege on other kinds of objects: character sets, collations, translations.
In the SQL standard, sequences only have a USAGE
privilege, which controls the use of the NEXT VALUE FOR
expression, which is equivalent to the function nextval()
in Greenplum Database. The sequence privileges SELECT
and UPDATE
are Greenplum Database extensions. The application of the sequence USAGE
privilege to the currval()
function is also a Greenplum Database extension (as is the function itself).
Privileges on databases, tablespaces, schemas, and languages are Greenplum Database extensions.
ALTER DEFAULT PRIVILEGES, REVOKE
Parent topic: SQL Commands