• Data Warehouse Service

dws
  1. Help Center
  2. Data Warehouse Service
  3. Developer Guide
  4. SQL Reference
  5. SQL Syntax
  6. ALTER DEFAULT PRIVILEGES

ALTER DEFAULT PRIVILEGES

Function

ALTER DEFAULT PRIVILEGES allows you to set the permissions that will be applied to objectANALYZE s created in the future. (It does not affect permissions assigned to already-existing objects.) Only the permissions for tables (including views), functions, and types (including domains) can be altered.

Precautions

To isolate permissions, DWS disables the WITH GRANT OPTION syntax.

Syntax

ALTER DEFAULT PRIVILEGES
    [ FOR { ROLE | USER } target_role [, ...] ]
    [ IN SCHEMA schema_name [, ...] ]
    abbreviated_grant_or_revoke;

abbreviated_grant_or_revoke grants or revokes permissions on some objects.

grant_on_tables_clause
  | grant_on_functions_clause
  | grant_on_types_clause
  | revoke_on_tables_clause
  | revoke_on_functions_clause
  | revoke_on_types_clause
  • grant_on_tables_clause grants permissions on a table.
    GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES } 
        [, ...] | ALL [ PRIVILEGES ] }
        ON TABLES 
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • grant_on_functions_clause grants permissions on functions.
    GRANT { EXECUTE | ALL [ PRIVILEGES ] }
        ON FUNCTIONS 
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • grant_on_types_clause grants permissions on types.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON TYPES 
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • revoke_on_tables_clause revokes permissions on tables.
    REVOKE [ GRANT OPTION FOR ]
        { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES } 
        [, ...] | ALL [ PRIVILEGES ] }
        ON TABLES 
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]
  • revoke_on_functions_clause revokes permissions on functions.
    REVOKE [ GRANT OPTION FOR ]
        { EXECUTE | ALL [ PRIVILEGES ] }
        ON FUNCTIONS 
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]
  • revoke_on_types_clause revokes permissions on types.
    REVOKE [ GRANT OPTION FOR ]
        { USAGE | ALL [ PRIVILEGES ] }
        ON TYPES 
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]

Parameter Description

  • target_role

    Specifies the name of a role. If FOR ROLE/USER is omitted, the current role is assumed.

    Value range: an existing table name

  • schema_name

    Indicates the name of an existing schema.

    target_role must have the CREATE permissions for schema_name.

    Value range: An existing schema name.

  • role_name

    Indicates the name of an existing role to grant or revoke permissions for.

    Value range: an existing role name

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.

Example

-- Grant the SELECT permission on all the tables (and views) in tpcds to every user:
ALTER DEFAULT PRIVILEGES IN SCHEMA tpcds GRANT SELECT ON TABLES TO PUBLIC;

-- Create a common user jack:
CREATE USER jack PASSWORD 'Bigdata123@';

-- Grant the INSERT permission on all the tables in tpcds to user jack:
ALTER DEFAULT PRIVILEGES IN SCHEMA tpcds GRANT INSERT ON TABLES TO jack;

-- Revoke the preceding permissions:
ALTER DEFAULT PRIVILEGES IN SCHEMA tpcds REVOKE SELECT ON TABLES FROM PUBLIC; 
ALTER DEFAULT PRIVILEGES IN SCHEMA tpcds REVOKE INSERT ON TABLES FROM jack;

-- Delete user jack:
DROP USER jack;

Helpful Links

GRANT, REVOKE