Skip to content

Commit

Permalink
Merge pull request #8629 from cockroachdb/new_role_options
Browse files Browse the repository at this point in the history
Updated SQL statements for new role options
  • Loading branch information
Amruta-Ranade authored Oct 20, 2020
2 parents a42af39 + 171e06c commit 60fae0c
Show file tree
Hide file tree
Showing 19 changed files with 535 additions and 317 deletions.
13 changes: 13 additions & 0 deletions _includes/v20.2/sql/privileges.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
You can manage the following privileges for databases and tables:

Privilege | Levels
----------|------------
`ALL` | Database, Table
`CREATE` | Database, Table
`DROP` | Database, Table
`GRANT` | Database, Table
`SELECT` | Table
`INSERT` | Table
`DELETE` | Table
`UPDATE` | Table
`ZONECONFIG` | Database, Table
134 changes: 40 additions & 94 deletions v20.2/alter-role.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@ summary: The ALTER ROLE statement can be used to add or change a role's password
toc: true
---

The `ALTER ROLE` [statement](sql-statements.html) can be used to add, change, or remove a [role's](create-role.html) password and to change the login privileges for a role.
The `ALTER ROLE` [statement](sql-statements.html) can be used to add, change, or remove a [role's](create-role.html) password and to change the privileges for a role.

{{site.data.alerts.callout_info}}
Since the keywords `ROLE` and `USER` can now be used interchangeably in SQL statements for enhanced Postgres compatibility, `ALTER ROLE` is now an alias for [`ALTER USER`](alter-user.html).
Expand All @@ -16,7 +16,7 @@ Since the keywords `ROLE` and `USER` can now be used interchangeably in SQL stat

## Required privileges

To alter other roles, the role must have the [`CREATEROLE`](create-role.html#allow-the-role-to-create-other-roles) parameter set.
To alter other roles, the role must be a member of the `admin` role or have the [`CREATEROLE`](create-role.html#create-a-role-that-can-create-other-roles-and-manage-authentication-methods-for-the-new-roles) parameter set.

## Synopsis

Expand All @@ -32,143 +32,89 @@ table td:first-child {

Parameter | Description
----------|-------------
`name` | The name of the role whose password you want to create or add.
`password` | Let the role [authenticate their access to a secure cluster](authentication.html#client-authentication) using this new password. Passwords should be entered as a [string literal](sql-constants.html#string-literals). For compatibility with PostgreSQL, a password can also be entered as an [identifier](#change-password-using-an-identifier). <br><br>To prevent a role from using [password authentication](authentication.html#client-authentication) and to mandate [certificate-based client authentication](authentication.html#client-authentication), [set the password as `NULL`](#prevent-a-role-from-using-password-authentication).
`name` | The name of the role whose role options you want to alter.
`CREATELOGIN`/`NOCREATELOGIN` | Allow or disallow the role to manage authentication using the `WITH PASSWORD`, `VALID UNTIL`, and `LOGIN/NOLOGIN` parameters. <br><br>By default, the parameter is set to `NOCREATELOGIN` for all non-admin roles.
`LOGIN`/`NOLOGIN` | The `LOGIN` parameter allows a role to login with one of the [client authentication methods](authentication.html#client-authentication). Setting the parameter to `NOLOGIN` prevents the role from logging in using any authentication method.
`password` | Let the role [authenticate their access to a secure cluster](authentication.html#client-authentication) using this new password. Passwords should be entered as a [string literal](sql-constants.html#string-literals). For compatibility with PostgreSQL, a password can also be entered as an identifier. <br><br>To prevent a role from using [password authentication](authentication.html#client-authentication) and to mandate [certificate-based client authentication](authentication.html#client-authentication), [set the password as `NULL`](#prevent-a-role-from-using-password-authentication).
`VALID UNTIL` | The date and time (in the [`timestamp`](timestamp.html) format) after which the password is not valid.
`LOGIN`/`NOLOGIN` | The `LOGIN` parameter allows a role to login with one of the [client authentication methods](authentication.html#client-authentication). [Setting the parameter to `NOLOGIN`](#change-login-privileges-for-a-role) prevents the role from logging in using any authentication method.
`CREATEROLE`/`NOCREATEROLE` | Allow or disallow the role to create, alter, and drop other roles. <br><br>By default, the parameter is set to `NOCREATEROLE` for all non-admin and non-root roles.
`CREATEROLE`/`NOCREATEROLE` | Allow or disallow the role to [create](create-role.html), alter, and [drop](drop-role.html) other non-admin roles. <br><br>By default, the parameter is set to `NOCREATEROLE` for all non-admin roles.
`CREATEDB`/`NOCREATEDB` | Allow or disallow the role to [create](create-database.html) or [rename](rename-database.html) a database. The role is assigned as the owner of the database. <br><br>By default, the parameter is set to `NOCREATEDB` for all non-admin roles.
`CONTROLJOB`/`NOCONTROLJOB` | Allow or disallow the role to [pause](pause-job.html), [resume](resume-job.html), and [cancel](cancel-job.html) jobs. Non-admin roles cannot control jobs created by admins. <br><br>By default, the parameter is set to `NOCONTROLJOB` for all non-admin roles.
`CANCELQUERY`/`NOCANCELQUERY` | Allow or disallow the role to cancel [queries](cancel-query.html) and [sessions](cancel-session.html) of other roles. Without this privilege, roles can only cancel their own queries and sessions. Even with this privilege, non-admins cannot cancel admin queries or sessions. This option should usually be combined with `VIEWACTIVITY` so that the role can view other roles' query and session information. <br><br>By default, the parameter is set to `NOCANCELQUERY` for all non-admin roles.
`VIEWACTIVITY`/`NOVIEWACTIVITY` | Allow or disallow a role to see other roles' [queries](show-queries.html) and [sessions](show-sessions.html) using `SHOW QUERIES`, `SHOW SESSIONS`, and the [**Statements**](admin-ui-statements-page.html) and **Transactions** pages in the Admin UI. Without this privilege, the `SHOW` commands only show the role's own data and the Admin UI pages are unavailable. <br><br>By default, the parameter is set to `NOVIEWACTIVITY` for all non-admin roles.
`CONTROLCHANGEFEED`/`NOCONTROLCHANGEFEED` | Allow or disallow the role to run [`CREATE CHANGEFEED`](create-changefeed.html) on tables they have `SELECT` privileges on. <br><br>By default, the parameter is set to `NOCONTROLCHANGEFEED` for all non-admin roles.
`MODIFYCLUSTERSETTING`/`NOMODIFYCLUSTERSETTING` | Allow or disallow the role to to modify the [cluster settings](cluster-settings.html) with the `sql.defaults` prefix. <br><br>By default, the parameter is set to `NOMODIFYCLUSTERSETTING` for all non-admin roles.

## Examples

### Change password using a string literal

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl WITH PASSWORD 'ilov3beefjerky';
~~~
{{site.data.alerts.callout_info}}
The following statements are run by the `root` user that is a member of the `admin` role and has `ALL` privileges.
{{site.data.alerts.end}}

### Change password using an identifier
### Allow a role to log in to the database using a password

The following statement changes the password to `ilov3beefjerky`, as above:
The following example allows a role to log in to the database with a [password](authentication.html#client-authentication):

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl WITH PASSWORD ilov3beefjerky;
root@:26257/defaultdb> ALTER ROLE carl WITH LOGIN PASSWORD 'An0ther$tr0nGpassW0rD' VALID UNTIL '2021-10-10';
~~~

This is equivalent to the example in the previous section because the password contains only lowercase characters.

In contrast, the following statement changes the password to `thereisnotomorrow`, even though the password in the syntax contains capitals, because identifiers are normalized automatically:

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl WITH PASSWORD ThereIsNoTomorrow;
~~~
### Prevent a role from using password authentication

To preserve case in a password specified using identifier syntax, use double quotes:
The following statement prevents the user from using password authentication and mandates certificate-based [client authentication](authentication.html#client-authentication):

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl WITH PASSWORD "ThereIsNoTomorrow";
root@:26257/defaultdb> ALTER ROLE carl WITH PASSWORD NULL;
~~~

### Set password validity
### Allow a role to create other roles and manage authentication methods for the new roles

The following statement sets the date and time after which the password is not valid:
The following example allows the role to [create other roles](create-role.html) and [manage authentication methods](authentication.html#client-authentication) for them:

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl VALID UNTIL '2021-01-01';
root@:26257/defaultdb> ALTER ROLE carl WITH CREATEROLE CREATELOGIN;
~~~

### Prevent a role from using password authentication
### Allow a role to create and rename databases

The following statement prevents the role from using password authentication and mandates certificate-based client authentication:
The following example allows the role to [create](create-database.html) or [rename](rename-database.html) databases:

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl WITH PASSWORD NULL;
root@:26257/defaultdb> ALTER ROLE carl WITH CREATEDB;
~~~

### Change login privileges for a role
### Allow a role to pause, resume, and cancel non-admin jobs

The following statement prevents the role from logging in with any [client authentication method](authentication.html#client-authentication):
The following example allows the role to [pause](pause-job.html), [resume](resume-job.html), and [cancel](cancel-job.html) jobs:

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl NOLOGIN;
root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLJOB;
~~~

{% include copy-clipboard.html %}
~~~ sql
> SHOW ROLES;
~~~
### Allow a role to see and cancel non-admin queries and sessions

~~~
username | options | member_of
-----------+------------+------------
admin | CREATEROLE | {}
carl | NOLOGIN | {}
root | CREATEROLE | {admin}
(3 rows)
~~~

The following statement allows the role to log in with one of the client authentication methods:

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl LOGIN;
~~~
The following example allows the role to cancel [queries](cancel-query.html) and [sessions](cancel-session.html) for other non-admin roles:

{% include copy-clipboard.html %}
~~~ sql
> SHOW ROLES;
root@:26257/defaultdb> ALTER ROLE carl WITH CANCELQUERY VIEWACTIVITY;
~~~

~~~
username | options | member_of
-----------+------------+------------
admin | CREATEROLE | {}
carl | | {}
root | CREATEROLE | {admin}
(3 rows)
~~~
### Allow a role to control changefeeds

### Allow the role to create other roles
The following example allows the role to run [`CREATE CHANGEFEED`](create-changefeed.html):

{% include copy-clipboard.html %}
~~~ sql
> SHOW ROLES;
root@:26257/defaultdb> ALTER ROLE carl WITH CONTROLCHANGEFEED;
~~~

~~~
username | options | member_of
-----------+------------+------------
admin | CREATEROLE | {}
carl | | {}
root | CREATEROLE | {admin}
(3 rows)
~~~
### Allow a role to modify cluster settings

{% include copy-clipboard.html %}
~~~ sql
> ALTER ROLE carl with CREATEROLE;
~~~
The following example allows the role to modify [cluster settings](cluster-settings.html):

{% include copy-clipboard.html %}
~~~ sql
> SHOW ROLES;
~~~

root@:26257/defaultdb> ALTER ROLE carl WITH MODIFYCLUSTERSETTING;
~~~
username | options | member_of
-----------+------------+------------
admin | CREATEROLE | {}
carl | CREATEROLE | {}
root | CREATEROLE | {admin}
(3 rows)
~~~


## See also

Expand Down
Loading

0 comments on commit 60fae0c

Please sign in to comment.