HomeMogDBMogDB StackUqbar
v2.1

Documentation:v2.1

Supported Versions:

ALTER DEFAULT PRIVILEGES

Function

ALTER DEFAULT PRIVILEGES allows you to set the permissions that will be applied to objects created in the future. (It does not affect permissions granted to existing objects.)

Precautions

Currently, you can change only the permissions for tables (including views), sequences, functions, types, CMKs of encrypted databases, and CEKs.

Syntax

AlterDafaultPrivileges ::= 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.

    abbreviated_grant_or_revoke ::= grant_on_tables_clause
          | grant_on_sequences_clause
          | grant_on_functions_clause
          | grant_on_types_clause
          | grant_on_client_master_keys_clause
          | grant_on_column_encryption_keys_clause
          | revoke_on_tables_clause
          | revoke_on_sequences_clause
          | revoke_on_functions_clause
          | revoke_on_types_clause
          | revoke_on_client_master_keys_clause
          | revoke_on_column_encryption_keys_clause
  • grant_on_tables_clause grants permissions on tables.

    grant_on_tables_clause ::= GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | ALTER | DROP | COMMENT | INDEX | VACUUM }
        [, ...] | ALL [ PRIVILEGES ] }
        ON TABLES
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • grant_on_sequences_clause grants permissions on sequences.

    grant_on_sequences_clause ::= GRANT { { SELECT | UPDATE | USAGE | ALTER | DROP | COMMENT }
        [, ...] | ALL [ PRIVILEGES ] }
        ON SEQUENCES
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • grant_on_functions_clause grants permissions on functions.

    grant_on_functions_clause ::= GRANT { { EXECUTE | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] }
        ON FUNCTIONS
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • grant_on_types_clause grants permissions on types.

    grant_on_types_clause ::= GRANT { { USAGE | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] }
        ON TYPES
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ]
  • revoke_on_tables_clause revokes permissions on tables.

    revoke_on_tables_clause ::= REVOKE [ GRANT OPTION FOR ]
        { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | ALTER | DROP | COMMENT | INDEX | VACUUM }
        [, ...] | ALL [ PRIVILEGES ] }
        ON TABLES
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]
  • revoke_on_sequences_clause revokes permissions on sequences.

    revoke_on_sequences_clause ::= REVOKE [ GRANT OPTION FOR ]
        { { SELECT | UPDATE | USAGE | ALTER | DROP | COMMENT }
        [, ...] | ALL [ PRIVILEGES ] }
        ON SEQUENCES
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]
  • revoke_on_functions_clause revokes permissions on functions.

    revoke_on_functions_clause ::= REVOKE [ GRANT OPTION FOR ]
        { {EXECUTE | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] }
        ON FUNCTIONS
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]
  • revoke_on_types_clause revokes permissions on types.

    revoke_on_types_clause ::= REVOKE [ GRANT OPTION FOR ]
        { { USAGE | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] }
        ON TYPES
        FROM { [ GROUP ] role_name | PUBLIC } [, ...]
        [ CASCADE | RESTRICT | CASCADE CONSTRAINTS ]

Parameter Description

  • target_role

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

    Value range: an existing role name

  • schema_name

    Specifies the name of an existing schema.

    target_role must have the CREATE permission for schema_name.

    Value range: an existing schema name

  • role_name

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

    Value range: an existing role name

img NOTICE: To drop a role for which the default permissions have been granted, reverse the changes in its default permissions or use DROP OWNED BY to get rid of the default permission entry for the role.

Example

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

-- Create a common user jack.
mogdb=# CREATE USER jack PASSWORD 'xxxxxxx';

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

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

-- Delete user jack.
mogdb=# DROP USER jack;

GRANTREVOKE

Copyright © 2011-2024 www.enmotech.com All rights reserved.