REVOKE statements let you revoke privileges on database objects from users and roles.
This is the multi-page printable view of this section. Click here to print.
REVOKE statements
- 1: REVOKE (authentication)
- 2: REVOKE (database)
- 3: REVOKE (library)
- 4: REVOKE (model)
- 5: REVOKE (procedure)
- 6: REVOKE (Resource pool)
- 7: REVOKE (Role)
- 8: REVOKE (schema)
- 9: REVOKE (sequence)
- 10: REVOKE (storage location)
- 11: REVOKE (table)
- 12: REVOKE (TLS configuration)
- 13: REVOKE (user defined extension)
- 14: REVOKE (view)
1 - REVOKE (authentication)
Revokes privileges on an authentication method from users and roles.
Syntax
REVOKE AUTHENTICATION auth-method-name FROM grantee[,...]
Parameters
auth-method-name
- Name of the target authentication method.
grantee
Specifies whose privileges are revoked, one of the following:
Privileges
Superuser
Examples
-
Revoke
v_ldap
authentication from userjsmith
:=> REVOKE AUTHENTICATION v_ldap FROM jsmith;
-
Revoke
v_gss
authentication from the roleDBprogrammer
:=> REVOKE AUTHENTICATION v_gss FROM DBprogrammer;
-
Revoke
localpwd
as the default client authentication method:=> REVOKE AUTHENTICATION localpwd FROM PUBLIC;
See also
2 - REVOKE (database)
Revokes database privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON DATABASE db-spec
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- The database privilege to revoke, one of the following:
-
CREATE
: Create schemas. -
TEMP
: Create temporary tables.
-
ALL [PRIVILEGES]
- Revokes all database privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
is supported to comply with the SQL standard. ON DATABASE
db-spec
Specifies the current database, set to the database name or
DEFAULT
.grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Fred
's privilege to create schemas in the current database:
=> REVOKE CREATE ON DATABASE DEFAULT FROM Fred;
Revoke user Fred
's privilege to create temporary tables in the current database:
=> REVOKE TEMP ON DATABASE DEFAULT FROM Fred;
See also
3 - REVOKE (library)
Revokes library privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { USAGE | ALL [ PRIVILEGES ] }
ON LIBRARY [[database.]schema.]library[,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
USAGE
- Revokes access to the specified libraries.
Important
Privileges on functions in these libraries must be separately revoked. ALL [PRIVILEGES]
- Revokes all library privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack. The optional keyword
PRIVILEGES
conforms with the SQL standard. [
database
.]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.library
- The target library.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Examples
These commands show how to create a new library, and then grant and revoke user Fred
's USAGE privilege on that library.
=> CREATE LIBRARY MyFunctions AS 'home/dbadmin/my_functions.so';
=> GRANT USAGE ON LIBRARY MyFunctions TO Fred;
=> REVOKE USAGE ON LIBRARY MyFunctions FROM Fred;
See also
4 - REVOKE (model)
Revokes model privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON MODEL [[database.]schema.]model-name [,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
USAGE
- One of the following privileges:
ALL [PRIVILEGES]
- Revokes all model privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard. [
database
.]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.model-name
- Name of the target model.
*
grantee*
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Fred
's USAGE privilege on model mySvmClassModel
:
=> REVOKE USAGE ON mySvmClassModel FROM Fred;
See also
5 - REVOKE (procedure)
Revokes procedure privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL PRIVILEGES }
ON PROCEDURE [[database.]schema.]procedure( [argument-list] )[,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
EXECUTE
- Revokes grantees ability to run the specified procedures.
ALL [PRIVILEGES]
- Revokes all procedure privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard. [
database
.]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.*
procedure*
- The target procedure.
argument-list
- A comma-delimited list of procedure arguments, where each argument is specified as follows:
[argname] argtype
If the procedure is defined with no arguments, supply an empty argument list.
*
grantee*
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
This example revokes user Bob
's execute privilege on the tokenize
procedure.
=> REVOKE EXECUTE ON PROCEDURE tokenize(varchar) FROM Bob;
See also
6 - REVOKE (Resource pool)
Revokes resource pool access privileges from users and roles.
Vertica checks resource pool privileges at runtime. Revoking a user's privileges for a resource pool can have an immediate effect on the user's current session. For example, a user query might require USAGE privileges on a resource pool. If you revoke those privileges from that user, subsequent attempts by the user to execute that query fail and return with an error message.
Syntax
REVOKE [ GRANT OPTION FOR ] { USAGE | ALL PRIVILEGES }
ON RESOURCE POOL resource-pool[,...]
[FOR SUBCLUSTER subcluster | FOR CURRENT SUBCLUSTER]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
USAGE
- Revokes grantee's access to the specified resource pool.
ALL PRIVILEGES
- Revokes all resource pool privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard. resource-pool
- The target resource pool.
subcluster
- The subcluster for the resource pool.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Joe
's USAGE privileges on resource pool Joe_pool
.
=> REVOKE USAGE ON RESOURCE POOL Joe_pool FROM Joe;
REVOKE PRIVILEGE
Revoke user Joe
's USAGE privileges on resource pool Joe_pool
for subcluster sub1
.
=> REVOKE USAGE ON RESOURCE POOL Joe_pool FOR SUBCLUSTER sub1 FROM Joe;
REVOKE PRIVILEGE
See also
7 - REVOKE (Role)
Revokes a role from users and roles.
Syntax
REVOKE [ ADMIN OPTION FOR ] role[,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
ADMIN OPTION FOR
- Revokes from the grantees the authority to assign the specified roles to other users or roles. Current roles for grantees remain unaffected. If you omit this clause, Vertica revokes role assignment privileges and the current roles .
role
- Role to revoke.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
One of the following:
-
Superuser
-
Privileges grantee who was given the option (
WITH ADMIN OPTION
) of extending these privileges to other users
Examples
This example shows the revocation of the pseudosuperuser role from the dbadmin user:
=> REVOKE pseudosuperuser from dbadmin;
This example shows the revocation of administration access from the dbadmin user for the pseudosuperuser role. The ADMIN OPTION command does not remove the pseudosuperuser role.
=> REVOKE ADMIN OPTION FOR pseudosuperuser FROM dbadmin;
Notes
If the role you are trying to revoke was not already granted to the user, Vertica returns a NOTICE:
=> REVOKE commentor FROM Sue;
NOTICE 2022: Role "commentor" was not already granted to user "Sue"
REVOKE ROLE
See also
8 - REVOKE (schema)
Revokes schema privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON SCHEMA [database.]schema[,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- The schema privilege to revoke, one of the following:
-
USAGE: Access objects in the specified schemas.
-
CREATE: Create objects in the specified schemas.
You can also revoke privileges from tables and views that they inherited on creation from this schema. When you revoke inherited privileges at the schema level, Vertica automatically applies the revocation to all tables and views that inherited these privileges.
-
SELECT: Query tables and views. SELECT privileges are granted by default to the PUBLIC role.
-
INSERT: Insert rows, or and load data into tables with
COPY
.Note
COPY FROM STDIN
is allowed for users with INSERT privileges, whileCOPY FROM
file
requires admin privileges. -
UPDATE: Update table rows.
-
DELETE: Delete table rows.
-
REFERENCES: Create foreign key constraints on this table. This privilege must be set on both referencing and referenced tables.
-
TRUNCATE: Truncate table contents. Non-owners of tables can also execute the following partition operations on them:
-
ALTER: Modify the DDL of tables and views with
ALTER TABLE
andALTER VIEW
, respectively. -
DROP: Drop tables and views.
-
ALL [PRIVILEGES]
- Revokes USAGE AND CREATE privileges. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard.Important
Inherited privileges must be explicitly revoked. [
database
.]
schema
- The schema on which to revoke privileges. If you specify a database, it must be the current database.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Joe
's USAGE privilege on schema online_sales
.
=> REVOKE USAGE ON SCHEMA online_sales FROM Joe;
REVOKE PRIVILEGE
See also
9 - REVOKE (sequence)
Revokes sequence privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON {
SEQUENCE [[database.]schema.]sequence[,...]
| ALL SEQUENCES IN SCHEMA [database.]schema[,...] }
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- One of the following privileges:
-
SELECT: Execute functions
CURRVAL
andNEXTVAL
on the specified sequences. -
ALTER: Modify a sequence's DDL with
ALTER SEQUENCE
-
DROP: Drop this sequence with
DROP SEQUENCE
.
-
ALL [PRIVILEGES]
- Revokes all sequence privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
is supported to comply with the SQL standard. [
database
.]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.SEQUENCE
sequence
- Specifies the sequence on which to revoke privileges.
ALL SEQUENCES IN SCHEMA
schema
- Revokes the specified privileges on all sequences in schema
schema
. grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Joe
's privileges on sequence my_seq
.
=> REVOKE ALL PRIVILEGES ON SEQUENCE my_seq FROM Joe;
REVOKE PRIVILEGE
See also
10 - REVOKE (storage location)
Revokes privileges on a USER-defined storage location from users and roles. For more information, see Creating storage locations.
Note
If the storage location is dropped, Vertica automatically revokes all privileges on it.Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON LOCATION 'path' [ ON node ]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- One of the following privileges:
-
READ
: Copy data from files in the storage location into a table. -
WRITE
: Export data from the database to the storage location. WithWRITE
privileges, grantees can also saveCOPY
statement rejected data and exceptions files to the storage location.
-
ALL [PRIVILEGES]
- Revokes all storage location privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
is supported to comply with the SQL standard. ON LOCATION '
path
' [ ON
node
]
- Specifies the path name mount point of the storage location. If qualified by
ON NODE
, Vertica revokes access to the storage location residing onnode
.If no node is specified, the revoke operation applies to all nodes on the specified path. All nodes must be on the specified path; otherwise, the entire revoke operation rolls back.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
See also
Granting and revoking privileges11 - REVOKE (table)
Revokes table privileges from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON {
[ TABLE ] [[database.]schema.]table[,...]
| ALL TABLES IN SCHEMA [database.]schema[,...] }
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- One of the following privileges:
-
SELECT: Query tables. SELECT privileges are granted by default to the PUBLIC role.
-
INSERT: Insert table rows with INSERT, and load data with
COPY
.Note
COPY FROM STDIN
is allowed for users with INSERT privileges, whileCOPY FROM
file
requires admin privileges. -
UPDATE: Update table rows.
-
DELETE: Delete table rows.
-
REFERENCES: Create foreign key constraints on this table. This privilege must be set on both referencing and referenced tables.
-
TRUNCATE: Truncate table contents. Non-owners of tables can also execute the following partition operations on them:
-
ALTER: Modify a table's DDL with
ALTER TABLE
. -
DROP: Drop a table.
-
ALL [PRIVILEGES]
- Revokes all table privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
is supported to comply with the SQL standard. [
database.
]
schema
- Specifies a schema, by default
public
. Ifschema
is any schema other thanpublic
, you must supply the schema name. For example:myschema.thisDbObject
One exception applies: you can specify system tables without their schema name.
If you specify a database, it must be the current database.
TABLE
table
- Specifies the table on which to revoke privileges.
ON ALL TABLES IN SCHEMA
schema
- Revokes the specified privileges on all tables and views in schema
schema
. grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Ownership
-
GRANT OPTION on the object
Examples
Revoke user Joe
's privileges on table customer_dimension
.
=> REVOKE ALL PRIVILEGES ON TABLE customer_dimension FROM Joe;
REVOKE PRIVILEGE
See also
12 - REVOKE (TLS configuration)
Revokes privileges granted on one or more TLS CONFIGURATIONs from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ]
{ ALL | [ privilege[,...] ]}
ON TLS CONFIGURATION tls_configuration[,...]
FROM grantee [,...]
Parameters
WITH GRANT OPTION
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- The privilege to revoke, one of the following:
tls_configuration
- The TLS CONFIGURATION on which to revoke privileges.
grantee
Specifies who is granted privileges, one of the following:
Privileges
Non-superusers require 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
To revoke ALTER privileges on the TLS CONFIGURATION server
from the role client_server_tls_manager
:
=> REVOKE ALTER ON TLS CONFIGURATION server FROM client_server_tls_manager;
13 - REVOKE (user defined extension)
Revokes privileges on one or more user-defined extensions from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL PRIVILEGES }
ON {
UDx-type [[database.]schema.]function-name( [argument-list] )[,...]
| ALL FUNCTIONS IN SCHEMA schema[,...] }
FROM grantee[,...]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
EXECUTE
- Revokes grantees ability to run the specified functions.
ALL [PRIVILEGES]
- Revokes all function privileges that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard. ON
UDx-type
- Specifies the function's user-defined extension (UDx) type, where
UDx-type
is one of the following:-
FUNCTION
-
AGGREGATE FUNCTION
-
ANALYTIC FUNCTION
-
TRANSFORM FUNCTION
-
FILTER
-
PARSER
-
SOURCE
-
[
database
.]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.function-name
- The name of the user-defined function on which to revoke privileges.
ON ALL FUNCTIONS IN SCHEMA
schema
- Revokes privileges on all functions in the specified schema.
argument-list
- Required for all polymorphic functions, a comma-delimited list of function arguments, where each argument is specified as follows:
[argname] argtype
If the procedure is defined with no arguments, supply an empty argument list.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Privileges
Non-superuser, one of the following:
-
Owner of the target function
-
Privileges grantee who was given the option (
WITH GRANT OPTION
) of extending these privileges to other users
Examples
Revoke EXECUTE
privileges from user Bob
on function myzeroifnull
:
=> REVOKE EXECUTE ON FUNCTION myzeroifnull (x INT) FROM Bob;
Revoke all privileges from user Doug
on function Pagerank
:
=> REVOKE ALL ON TRANSFORM FUNCTION Pagerank (t float) FROM Doug;
Revoke EXECUTE
privileges on all functions in the zero-schema
schema from user Bob:
=> REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA zero-schema FROM Bob;
Revoke EXECUTE
privileges from user Bob on the tokenize
function:
=> REVOKE EXECUTE ON TRANSFORM FUNCTION tokenize(VARCHAR) FROM Bob;
Revoke all privileges on the ExampleSource()
source from user Alice:
=> REVOKE ALL ON SOURCE ExampleSource() FROM Alice;
See also
14 - REVOKE (view)
Revokes privileges on a view from users and roles.
Syntax
REVOKE [ GRANT OPTION FOR ] { privilege[,...] | ALL [ PRIVILEGES ] }
ON [[database.]schema.]view[,...]
FROM grantee[,...]
[ CASCADE ]
Parameters
GRANT OPTION FOR
Revokes the grant option for the specified privileges. Current privileges for grantees remain unaffected. If you omit this clause, Vertica revokes both the grant option and current privileges.
privilege
- One of the following:
-
SELECT: Query the specified views.
-
ALTER: Modify a view's DDL with
ALTER VIEW
-
DROP: Drop this view with
DROP VIEW
.
-
ALL PRIVILEGES
- Revokes all privileges that pertain to views that also belong to the revoker. Users cannot revoke privileges that they themselves lack.
The optional keyword
PRIVILEGES
conforms with the SQL standard. [
database.
]
schema
Database and schema. The default schema is
public
. If you specify a database, it must be the current database.view
- The view on which to revoke privileges.
grantee
Specifies whose privileges are revoked, one of the following:
CASCADE
I
f the target grantees have a grant option to extend the specified privileges to other users,CASCADE
specifies to search for these users and revoke the privileges from them also.
Examples
Revoke SELECT privileges from user Joe
on view test_view
.
=> REVOKE SELECT ON test_view FROM Joe;
REVOKE PRIVILEGE