GRANT grants permissions to roles and users.
GRANT is used in the following scenarios:
System permissions are also called user attributes, including SYSADMIN, CREATEDB, CREATEROLE, AUDITADMIN, and LOGIN.
They can be specified only by the CREATE ROLE or ALTER ROLE syntax. The SYSADMIN permission can be granted and revoked using GRANT ALL PRIVILEGE and REVOKE ALL PRIVILEGE, respectively. System permissions cannot be inherited by a user from a role, and cannot be granted using PUBLIC.
Grant permissions related to database objects (tables, views, specified columns, databases, functions, and schemas) to specified roles or users.
GRANT grants specified database object permissions to one or more roles. These permissions are appended to those already granted, if any.
The key word PUBLIC indicates that the permissions are to be granted to all roles, including those that might be created later. PUBLIC can be regarded as an implicitly defined group including all roles. Any particular role will have the sum of permissions granted directly to it using GRANT, permissions granted to any role it is presently a member of, and permissions granted to PUBLIC.
If WITH GRANT OPTION is specified, the recipient of a permission can in turn grant it to others. This option cannot be granted to PUBLIC. Only GaussDB(DWS) supports this operation.
GaussDB(DWS) grants the permissions for objects of certain types to PUBLIC. By default, permissions for tables, table columns, sequences, external data sources, external servers, schemas, and tablespace are not granted to PUBLIC. However, permissions for the following objects are granted to PUBLIC: CONNECT and CREATE TEMP TABLE permissions for databases, EXECUTE permission for functions, and USAGE permission for languages and data types (including domains). An object owner can revoke the default permissions granted to PUBLIC and grant permissions to other users as needed. For security purposes, you are advised to create an object and set permissions for it in the same transaction so that other users do not have time windows to use the object. In addition, you can run the ALTER DEFAULT PRIVILEGES statement to modify the initial default permissions.
Grant a role's or user's permissions to one or more roles or users. In this case, every role or user can be regarded as a set of one or more database permissions.
If WITH ADMIN OPTION is specified, the member can in turn grant permissions in the role to others, and revoke permissions in the role as well. If a role or user granted with certain permissions is changed or revoked, the permissions inherited from the role or user also change.
A database administrator can grant permissions to and revoke them from any role or user. Roles having CREATEROLE permission can grant or revoke membership in any role that is not an administrator.
None
1 2 3 4 5 6 | GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER | ANALYZE | ANALYSE | VACUUM | ALTER | DROP } [, ...] | ALL [ PRIVILEGES ] } ON { [ TABLE ] table_name [, ...] | ALL TABLES IN SCHEMA schema_name [, ...] } TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 5 | GRANT { {{ SELECT | INSERT | UPDATE | REFERENCES } ( column_name [, ...] )} [, ...] | ALL [ PRIVILEGES ] ( column_name [, ...] ) } ON [ TABLE ] table_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 5 | GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...] | ALL [ PRIVILEGES ] } ON DATABASE database_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 | GRANT { USAGE | ALL [ PRIVILEGES ] } ON DOMAIN domain_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
The current version does not support granting the domain access permission.
1 2 3 4 | GRANT { USAGE | ALL [ PRIVILEGES ] } ON FOREIGN DATA WRAPPER fdw_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 | GRANT { USAGE | ALL [ PRIVILEGES ] } ON FOREIGN SERVER server_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 5 | GRANT { EXECUTE | ALL [ PRIVILEGES ] } ON { FUNCTION {function_name ( [ {[ argmode ] [ arg_name ] arg_type} [, ...] ] )} [, ...] | ALL FUNCTIONS IN SCHEMA schema_name [, ...] } TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 | GRANT { USAGE | ALL [ PRIVILEGES ] } ON LANGUAGE lang_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
The current version does not support granting the procedural language access permission.
1 2 3 4 | GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] } ON LARGE OBJECT loid [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
The current version does not support granting the large object access permission.
1 2 3 4 5 | GRANT { { SELECT | UPDATE | USAGE } [, ...] | ALL [ PRIVILEGES ] } ON { SEQUENCE sequence_name [, ...] | ALL SEQUENCES IN SCHEMA schema_name [, ...] } TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 | GRANT { CREATE | USAGE | COMPUTE | ALL [ PRIVILEGES ] } ON NODE GROUP group_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
1 2 3 4 | GRANT { { CREATE | USAGE | ALTER | DROP } [, ...] | ALL [ PRIVILEGES ] } ON SCHEMA schema_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
When you grant table or view rights to other users, you also need to grant the USAGE permission for the schema that the tables and views belong to. Without this permission, the users granted with the table or view rights can only see the object names, but cannot access them.
1 2 3 4 | GRANT { USAGE | ALL [ PRIVILEGES ] } ON TYPE type_name [, ...] TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ]; |
The current version does not support granting the type access permission.
1 2 3 | GRANT role_name [, ...] TO role_name [, ...] [ WITH ADMIN OPTION ]; |
1 2 | GRANT ALL { PRIVILEGES | PRIVILEGE } TO role_name; |
GRANT grants the following permissions:
Allows SELECT from any column, or the specific columns listed, of the specified table, view, or sequence.
Allows INSERT of a new row into the specified table.
Allows UPDATE of any column, or the specific columns listed, of the specified table. SELECT ... FOR UPDATE and SELECT ... FOR SHARE also require this permission on at least one column, in addition to the SELECT permission.
Allows DELETE of a row from the specified table.
Allows TRUNCATE on the specified table.
To create a foreign key constraint, it is necessary to have this permission on both the referencing and referenced columns.
To create a trigger, you must have the TRIGGER permission on the table or view.
To perform the ANALYZE | ANALYSE operation on a table to collect statistics data, you must have the ANALYZE | ANALYSE permission on the table.
Allows the user to connect to the specified database.
Allows temporary tables to be created when the specified database is used.
Allows the use of the specified function and the use of any operators that are implemented on top of the function.
Allows users to perform elastic computing in a computing sub-cluster that they have the compute permission on.
Grants all of the available permissions at once. Only system administrators have permission to run GRANT ALL PRIVILEGES.
Specifies whether permission transfer is allowed. If WITH GRANT OPTION is specified, the recipient of a permission can in turn grant it to others. This option cannot be granted to PUBLIC.
Specifies whether permission transfer is allowed. If WITH ADMIN OPTION is specified, members of a role can grant membership of the role to others.
GRANT parameters are as follows:
Specifies an existing user name.
Specifies an existing table name.
Specifies an existing column name.
Specifies an existing schema name.
Specifies an existing database name.
Specifies an existing function name.
Specifies an existing sequence name.
Specifies an existing domain type.
Specifies an existing foreign data wrapper name.
Specifies an existing language name.
Specifies an existing type name.
Specifies an existing sub-cluster name.
Specifies the parameter mode.
Value range: a string. It must comply with the naming convention.
Indicates the parameter name.
Value range: a string. It must comply with the naming convention.
Specifies the parameter type.
Value range: a string. It must comply with the naming convention.
Identifier of the large object that includes this page
Value range: a string. It must comply with the naming convention.
Create two users:
1 2 | CREATE USER joe PASSWORD '{Password}'; CREATE USER kim PASSWORD '{Password}'; |
Create a schema:
1 | CREATE SCHEMA tpcds; |
Create a table:
1 | CREATE TABLE IF NOT EXISTS tpcds.reason(r_reason_sk int,r_reason_id int,r_reason_desc int); |
1 | GRANT ALL PRIVILEGES TO joe; |
Afterward, user joe has the sysadmin permissions.
1 | GRANT SELECT ON TABLE tpcds.reason TO joe; |
1 | GRANT ALL PRIVILEGES ON tpcds.reason TO kim; |
After the granting succeeds, user kim has all the permissions of the tpcds.reason table, including the add, delete, modify, and query permissions.
1 | GRANT USAGE ON SCHEMA tpcds TO joe; |
After the authorization is successful, user joe has the USAGE permission of the schema and can access the objects contained in the schema.
1 | GRANT select (r_reason_sk,r_reason_id,r_reason_desc),update (r_reason_desc) ON tpcds.reason TO joe; |
After the granting succeeds, user joe immediately has the query permission of the r_reason_sk and r_reason_id columns in the tpcds.reason table.
1 | GRANT select (r_reason_sk, r_reason_id) ON tpcds.reason TO joe ; |
1 2 3 4 5 6 | CREATE FUNCTION func_add_sql(integer, integer) RETURNS integer AS 'select $1 + $2;' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT; GRANT EXECUTE ON FUNCTION func_add_sql(integer, integer) TO joe; |
1 2 | CREATE SEQUENCE serial START 101 CACHE 20; GRANT UPDATE ON SEQUENCE serial TO joe; |
1 | GRANT create,connect on database gaussdb TO joe ; |
1 | GRANT USAGE,CREATE ON SCHEMA tpcds TO joe; |
1 | GRANT joe TO kim WITH ADMIN OPTION; |
1 | GRANT joe TO kim; |