Authorization

On this page Carat arrow pointing down
Warning:
CockroachDB v20.2 is no longer supported as of May 10, 2022. For more details, refer to the Release Support Policy.

You can map SQL roles to SQL privileges and use role membership to group users that share privileges.

Users and roles

There is no technical distinction between a SQL role or user in CockroachDB. Depending on its configuration, a role can:

  • log in via the SQL shell.
  • be used by applications to connect to the database.
  • be granted privileges to specific actions and database objects.
  • be a member of other roles, inheriting their privileges.
  • have other roles as members that inherit its privileges.

We often refer to these as "roles" when they are created for managing the privileges of their member "users". We often refer to roles that are enabled to log in to a database as "users".

The SQL statements CREATE USER and CREATE ROLE will create the same entity with one exception: CREATE ROLE will add the NOLOGIN option by default, preventing the role from being used to log in. Otherwise, for enhanced PostgreSQL compatibility, the keywords ROLE and USER can be used interchangeably in SQL statements.

Throughout the documentation, however, we refer to a "user" or "role" based on the intended purpose of the entity, and we default to using the term "role" when we want to include both possibilities for how the role may be used.

Users

A SQL user (a role with LOGIN privileges) can interact with a CockroachDB database using the built-in SQL shell or through an application.

Create and manage users

You can use the CREATE USER and DROP USER statements to create and remove users, the ALTER USER statement to add or change a user's password and role options, and the SHOW USERS statement to list users.

The statements CREATE ROLE, DROP ROLE, ALTER ROLE, and SHOW ROLES are equivalent to these, respectively, with the exception of the default NOLOGIN setting added with CREATE ROLE.

Use the GRANT <privileges> and REVOKE <privileges> statements to manage the user’s privileges.

For each database and table that the user needs to access, a user must be granted the required privileges or granted membership to roles that confer these privileges.

By default, a new user belongs to the public role and has no privileges other than those assigned to the public role. For more information, see Public role.

root user

The root user is created by default for each cluster. The root user is assigned to the admin role and has all privileges across the cluster.

For secure clusters, in addition to generating the client certificate for the root user, you can assign or change the password for the root user using the ALTER USER statement.

Roles

A role is a group of users and/or other roles for which you can grant or revoke privileges as a whole. To simplify access management, create a role and grant privileges to the role, then create SQL users and grant them membership to the role.

Users and roles and technically the same type of entity. See Users and roles.

Create and manage roles

To create and manage your cluster's roles, use the following statements:

Statement Description
CREATE ROLE Create SQL roles.
DROP ROLE Remove one or more SQL roles.
GRANT <roles> Add a role or user as a member to a role.
REVOKE <roles> Revoke a role or user's membership to a role.
GRANT <privileges> Manage each role or user's SQL privileges for interacting with specific databases and tables.
REVOKE <privileges> Revoke privileges from users and/or roles.
SHOW ROLES List the roles for all databases.
SHOW GRANTS List the privileges granted to users.

Default roles

The admin and public roles exist by default.

admin role

The admin role is created by default and cannot be dropped. Users belonging to the admin role have all privileges for all database objects across the cluster. The root user belongs to the admin role by default.

An admin user is a member of the admin role. Only admin users can use CREATE ROLE and DROP ROLE.

To assign a user to the admin role:

icon/buttons/copy
> GRANT admin TO <username>;

public role

All new users and roles belong to the public role by default. You can grant and revoke privileges on the public role.

Terminology

Role admin

A role admin is a member of the role that's allowed to grant or revoke role membership to other users for that specific role. To create a role admin, use WITH ADMIN OPTION.

Tip:

The terms “admin role” and “role admin” can be confusing. A user who is a member of the admin role has all privileges on all database objects across the entire cluster, whereas a role admin has privileges limited to the role they are a member of. Assign the admin role to a SQL user if you want the user to have privileges across the cluster. Make a SQL user the role admin if you want to limit the user’s privileges to its current role, but with an option to grant or revoke role membership to other users. This applies to the admin role as well - only admin users with the WITH ADMIN OPTION can add or remove other users from the admin role.

Direct member

A user or role that is an immediate member of the role.

Example: A is a member of B.

Indirect member

A user or role that is a member of the role by association.

Example: A is a member of C ... is a member of B where "..." is an arbitrary number of memberships.

Object ownership

New in v20.2 All CockroachDB objects (such as databases, tables, schemas, and types) must have owners. The user that created the object is the default owner of the object and has ALL privileges on the object. Similarly, any roles that are members of the owner role also have all privileges on the object.

All objects that do not have owners (for example, objects created before upgrading to v20.2) have admin set as the default owner, with the exception of system objects. System objects without owners have node as their owner.

To allow another user to use the object, the owner can assign privileges to the other user. Members of the admin role have ALL privileges on all objects.

Users that own objects cannot be dropped until the ownership is transferred to another user.

Privileges

When a user connects to a database, either via the built-in SQL client or a client driver, CockroachDB checks the user and role's privileges for each statement executed. If the user does not have sufficient privileges for a statement, CockroachDB gives an error.

Supported privileges

Roles and users can be granted the following privileges:

Privilege Levels
ALL Database, Schema, Table, Type
CREATE Database, Schema, Table
DROP Database, Table
GRANT Database, Schema, Table, Type
SELECT Table, Database
INSERT Table
DELETE Table
UPDATE Table
USAGE Schema, Type
ZONECONFIG Database, Table

Assign privileges

Use the GRANT <privileges> and REVOKE <privileges> statements to manage privileges for users and roles.

Take the following points into consideration while granting privileges to roles and users:

  • When a role or user is granted privileges for a database, new tables created in the database will inherit the privileges, but the privileges can then be changed. To grant privileges to a user on all existing tables in a database, see Grant privileges on all tables in a database

    Note:

    The user does not get privileges to existing tables in the database.

  • When a role or user is granted privileges for a table, the privileges are limited to the table.

  • In CockroachDB, privileges are granted to users and roles at the database and table levels. They are not yet supported for other granularities such as columns or rows.

  • The root user automatically belongs to the admin role and has the ALL privilege for new databases.

  • For privileges required by specific statements, see the documentation for the respective SQL statement.

Authorization best practices

We recommend the following best practices to set up access control for your clusters:

  • Use the root user only for database administration tasks such as creating and managing other users, creating and managing roles, and creating and managing databases. Do not use the root user for applications; instead, create users or roles with specific privileges based on your application’s access requirements.
  • Use the "least privilege model" to grant privileges to users and roles.

Example

The following example uses MovR, a fictional vehicle-sharing application, to demonstrate CockroachDB SQL statements. For more information about the MovR example application and dataset, see MovR: A Global Vehicle-sharing App.

Let's say we want to create the following access control setup for the movr database:

  • One database admin (named db_admin) who can perform all database operations for existing tables as well as for tables added in the future.
  • One app user (named app_user) who can add, read update, and delete vehicles from the vehicles table.
  • One user (named report_user) who can only read the vehicles table.
  1. Use the cockroach demo command to load the movr database and dataset into a CockroachDB cluster:

    icon/buttons/copy
    $ cockroach demo
    
  2. Create the database admin (named db_admin) who can perform all database operations for existing tables as well as for tables added in the future:

    icon/buttons/copy
    > CREATE USER db_admin;
    
  3. Grant all privileges on database movr to user db_admin:

    icon/buttons/copy
    > GRANT ALL ON DATABASE movr TO db_admin;
    
  4. Grant all privileges on all tables in database movr to user db_admin:

    icon/buttons/copy
    > GRANT ALL ON TABLE * TO db_admin;
    
  5. Verify that db_admin has all privileges:

    icon/buttons/copy
    > SHOW GRANTS FOR db_admin;
    
      database_name |    schema_name     |         table_name         | grantee  | privilege_type  
    +---------------+--------------------+----------------------------+----------+----------------+
      movr          | crdb_internal      | NULL                       | db_admin | ALL             
      movr          | information_schema | NULL                       | db_admin | ALL             
      movr          | pg_catalog         | NULL                       | db_admin | ALL             
      movr          | public             | NULL                       | db_admin | ALL             
      movr          | public             | promo_codes                | db_admin | ALL             
      movr          | public             | rides                      | db_admin | ALL             
      movr          | public             | user_promo_codes           | db_admin | ALL             
      movr          | public             | users                      | db_admin | ALL             
      movr          | public             | vehicle_location_histories | db_admin | ALL             
      movr          | public             | vehicles                   | db_admin | ALL             
    (10 rows)
    
  6. As the root user, create a SQL user named app_user with permissions to add, read, update, and delete vehicles in the vehicles table:

    icon/buttons/copy
    > CREATE USER app_user;
    
    icon/buttons/copy
    > GRANT INSERT, DELETE, UPDATE, SELECT ON vehicles TO app_user;
    
    icon/buttons/copy
    > SHOW GRANTS FOR app_user;
    
      database_name | schema_name | table_name | grantee  | privilege_type  
    +---------------+-------------+------------+----------+----------------+
      movr          | public      | vehicles   | app_user | DELETE          
      movr          | public      | vehicles   | app_user | INSERT          
      movr          | public      | vehicles   | app_user | SELECT          
      movr          | public      | vehicles   | app_user | UPDATE          
    (4 rows)
    
  7. As the root user, create a SQL user named report_user with permissions to only read from the vehicles table:

    icon/buttons/copy
    > CREATE USER report_user;
    
    icon/buttons/copy
    > GRANT SELECT ON vehicles TO report_user;
    
    icon/buttons/copy
    > SHOW GRANTS FOR report_user;
    
      database_name | schema_name | table_name |   grantee   | privilege_type  
    +---------------+-------------+------------+-------------+----------------+
      movr          | public      | vehicles   | report_user | SELECT          
    (1 row)
    

The following example uses MovR, a fictional vehicle-sharing application, to demonstrate CockroachDB SQL statements. For more information about the MovR example application and dataset, see MovR: A Global Vehicle-sharing App.

Let's say we want to create the following access control setup for the movr database:

  • Two database admins (named db_admin_1 and db_admin_2) who can perform all database operations for existing tables as well as for tables added in the future.
  • Three app users (named app_user_1, app_user_2, and app_user_3) who can add, read update, and delete vehicles from the vehicles table.
  • Five users (named report_user_1, report_user_2, report_user_3, report_user_4, report_user_5) who can only read the vehicles table.
  1. Use the cockroach demo command to load the movr database and dataset into a CockroachDB cluster.:

    icon/buttons/copy
    $ cockroach demo
    
  2. Create the database admin role (named db_admin_role) whose members can perform all database operations for existing tables as well as for tables added in the future:

    icon/buttons/copy
    > CREATE ROLE db_admin_role;
    
    icon/buttons/copy
    > SHOW ROLES;
    
        username    |  options   | member_of
    ----------------+------------+------------
      admin         | CREATEROLE | {}
      db_admin_role | NOLOGIN    | {}
      root          | CREATEROLE | {admin}
    (3 rows)
    
    icon/buttons/copy
    > GRANT ALL ON DATABASE movr TO db_admin_role;
    
    icon/buttons/copy
    > GRANT ALL ON TABLE * TO db_admin_role;
    
    icon/buttons/copy
    > SHOW GRANTS ON DATABASE movr;
    
      database_name |    schema_name     |    grantee    | privilege_type
    ----------------+--------------------+---------------+-----------------
      movr          | crdb_internal      | admin         | ALL
      movr          | crdb_internal      | db_admin_role | ALL
      movr          | crdb_internal      | root          | ALL
      movr          | information_schema | admin         | ALL
      movr          | information_schema | db_admin_role | ALL
      movr          | information_schema | root          | ALL
      movr          | pg_catalog         | admin         | ALL
      movr          | pg_catalog         | db_admin_role | ALL
      movr          | pg_catalog         | root          | ALL
      movr          | public             | admin         | ALL
      movr          | public             | db_admin_role | ALL
      movr          | public             | root          | ALL
    (12 rows)
    
  3. Create two database admin users (named db_admin_1 and db_admin_2) and grant them membership to the db_admin_role role:

    icon/buttons/copy
    > CREATE USER db_admin_1;
    
    icon/buttons/copy
    > CREATE USER db_admin_2;
    
    icon/buttons/copy
    > GRANT db_admin_role TO db_admin_1, db_admin_2;
    
  4. Create a role named app_user_role whose members can add, read update, and delete vehicles to the vehicles table.

    icon/buttons/copy
    > CREATE ROLE app_user_role;
    
    icon/buttons/copy
    > SHOW ROLES;
    
        username    |  options   |    member_of
    ----------------+------------+------------------
      admin         | CREATEROLE | {}
      app_user_role | NOLOGIN    | {}
      db_admin_1    |            | {db_admin_role}
      db_admin_2    |            | {db_admin_role}
      db_admin_role | NOLOGIN    | {}
      root          | CREATEROLE | {admin}
    (6 rows)
    
    icon/buttons/copy
    > GRANT INSERT, UPDATE, DELETE, SELECT ON TABLE vehicles TO app_user_role;
    
    icon/buttons/copy
    > SHOW GRANTS ON vehicles;
    
      database_name | schema_name | table_name |    grantee    | privilege_type
    ----------------+-------------+------------+---------------+-----------------
      movr          | public      | vehicles   | admin         | ALL
      movr          | public      | vehicles   | app_user_role | DELETE
      movr          | public      | vehicles   | app_user_role | INSERT
      movr          | public      | vehicles   | app_user_role | SELECT
      movr          | public      | vehicles   | app_user_role | UPDATE
      movr          | public      | vehicles   | db_admin_role | ALL
      movr          | public      | vehicles   | root          | ALL
    (7 rows)
    
  5. Create three app users (named app_user_1, app_user_2, and app_user_3) and grant them membership to the app_user_role role:

    icon/buttons/copy
    > CREATE USER app_user_1;
    
    icon/buttons/copy
    > CREATE USER app_user_2;
    
    icon/buttons/copy
    > CREATE USER app_user_3;
    
    icon/buttons/copy
    > GRANT app_user_role TO app_user_1, app_user_2, app_user_3;
    
  6. Create a role named report_user_role whose members can only read the vehicles table.

    icon/buttons/copy
    > CREATE ROLE report_user_role;
    
    icon/buttons/copy
    > SHOW ROLES;
    
          username     |  options   |    member_of
    -------------------+------------+------------------
      admin            | CREATEROLE | {}
      app_user_1       |            | {app_user_role}
      app_user_2       |            | {app_user_role}
      app_user_3       |            | {app_user_role}
      app_user_role    | NOLOGIN    | {}
      db_admin_1       |            | {db_admin_role}
      db_admin_2       |            | {db_admin_role}
      db_admin_role    | NOLOGIN    | {}
      report_user_role | NOLOGIN    | {}
      root             | CREATEROLE | {admin}
    (10 rows)
    
    icon/buttons/copy
    > GRANT SELECT ON vehicles TO report_user_role;
    
    icon/buttons/copy
    > SHOW GRANTS ON vehicles;
    
      database_name | schema_name | table_name |     grantee      | privilege_type
    ----------------+-------------+------------+------------------+-----------------
      movr          | public      | vehicles   | admin            | ALL
      movr          | public      | vehicles   | app_user_role    | DELETE
      movr          | public      | vehicles   | app_user_role    | INSERT
      movr          | public      | vehicles   | app_user_role    | SELECT
      movr          | public      | vehicles   | app_user_role    | UPDATE
      movr          | public      | vehicles   | db_admin_role    | ALL
      movr          | public      | vehicles   | report_user_role | SELECT
      movr          | public      | vehicles   | root             | ALL
    (8 rows)
    
  7. Create five report users (named report_user_1, report_user_2, report_user_3, report_user_4, and report_user_5) and grant them membership to the report_user_role role:

    icon/buttons/copy
    > CREATE USER report_user_1;
    
    icon/buttons/copy
    > CREATE USER report_user_2;
    
    icon/buttons/copy
    > CREATE USER report_user_3;
    
    icon/buttons/copy
    > CREATE USER report_user_4;
    
    icon/buttons/copy
    > CREATE USER report_user_5;
    
    icon/buttons/copy
    > GRANT report_user_role TO report_user_1, report_user_2, report_user_3, report_user_4, report_user_5;
    

See also


Yes No
On this page

Yes No