Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add description about user ATTRIBUTE #11084

Merged
merged 12 commits into from
Nov 7, 2022
1 change: 1 addition & 0 deletions TOC.md
Original file line number Diff line number Diff line change
Expand Up @@ -806,6 +806,7 @@
- [`TIKV_REGION_PEERS`](/information-schema/information-schema-tikv-region-peers.md)
- [`TIKV_REGION_STATUS`](/information-schema/information-schema-tikv-region-status.md)
- [`TIKV_STORE_STATUS`](/information-schema/information-schema-tikv-store-status.md)
- [`USER_ATTRIBUTES`](/information-schema/information-schema-user-attributes.md)
- [`USER_PRIVILEGES`](/information-schema/information-schema-user-privileges.md)
- [`VARIABLES_INFO`](/information-schema/information-schema-variables-info.md)
- [`VIEWS`](/information-schema/information-schema-views.md)
Expand Down
49 changes: 49 additions & 0 deletions information-schema/information-schema-user-attributes.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
---
title: USER_ATTRIBUTES
summary: Learn the `USER_ATTRIBUTES` INFORMATION_SCHEMA table.
---

# USER_ATTRIBUTES

The `USER_PRIVILEGES` table provides information about user comments and user attributes. This information comes from the `mysql.user` system table.

```sql
USE information_schema;
DESC user_attributes;
```

```sql
+-----------+--------------+------+------+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-----------+--------------+------+------+---------+-------+
| USER | varchar(32) | NO | | NULL | |
| HOST | varchar(255) | NO | | NULL | |
| ATTRIBUTE | longtext | YES | | NULL | |
+-----------+--------------+------+------+---------+-------+
3 rows in set (0.00 sec)
```

Fields in the `USER_ATTRIBUTES` table are described as follows:

* `USER`: The user name.
* `HOST`: The host from which the user can connect to TiDB. If the value of this field is `%`, it means that the user can connect to TiDB from any host.
* `ATTRIBUTE`: The comment and attribute of the user, which are set by the [`CREATE USER`](/sql-statements/sql-statement-create-user.md) or [`ALTER USER`](/sql-statements/sql-statement-alter-user.md) statement.

The following is an example:

```sql
CREATE USER testuser1 COMMENT 'This user is created only for test';
CREATE USER testuser2 ATTRIBUTE '{"email": "[email protected]"}';
SELECT * FROM information_schema.user_attributes;
```

```sql
+-----------+------+---------------------------------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+---------------------------------------------------+
| root | % | NULL |
| testuser1 | % | {"comment": "This user is created only for test"} |
| testuser2 | % | {"email": "[email protected]"} |
+-----------+------+---------------------------------------------------+
3 rows in set (0.00 sec)
```
1 change: 1 addition & 0 deletions information-schema/information-schema.md
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,7 @@ Many `INFORMATION_SCHEMA` tables have a corresponding `SHOW` command. The benefi
| [`TABLE_CONSTRAINTS`](/information-schema/information-schema-table-constraints.md) | Provides information on primary keys, unique indexes and foreign keys. |
| `TABLE_PRIVILEGES` | Not implemented by TiDB. Returns zero rows. |
| `TRIGGERS` | Not implemented by TiDB. Returns zero rows. |
| [`USER_ATTRIBUTES`](/information-schema/information-schema-user-attributes.md) | Summarizes information about user comments and user attributes. |
| [`USER_PRIVILEGES`](/information-schema/information-schema-user-privileges.md) | Summarizes the privileges associated with the current user. |
| [`VARIABLES_INFO`](/information-schema/information-schema-variables-info.md) | Provides information about TiDB system variables. |
| [`VIEWS`](/information-schema/information-schema-views.md) | Provides a list of views that the current user has visibility of. Similar to running `SHOW FULL TABLES WHERE table_type = 'VIEW'` |
Expand Down
56 changes: 51 additions & 5 deletions sql-statements/sql-statement-alter-user.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ This statement changes an existing user inside the TiDB privilege system. In the

```ebnf+diagram
AlterUserStmt ::=
'ALTER' 'USER' IfExists (UserSpecList RequireClauseOpt ConnectionOptions LockOption | 'USER' '(' ')' 'IDENTIFIED' 'BY' AuthString)
'ALTER' 'USER' IfExists (UserSpecList RequireClauseOpt ConnectionOptions LockOption AttributeOption | 'USER' '(' ')' 'IDENTIFIED' 'BY' AuthString)

UserSpecList ::=
UserSpec ( ',' UserSpec )*
Expand All @@ -27,6 +27,8 @@ AuthOption ::=
( 'IDENTIFIED' ( 'BY' ( AuthString | 'PASSWORD' HashString ) | 'WITH' StringName ( 'BY' AuthString | 'AS' HashString )? ) )?

LockOption ::= ( 'ACCOUNT' 'LOCK' | 'ACCOUNT' 'UNLOCK' )?

AttributeOption ::= ( 'COMMENT' CommentString | 'ATTRIBUTE' AttributeString )?
```

## Examples
Expand Down Expand Up @@ -63,14 +65,58 @@ ALTER USER 'newuser' ACCOUNT LOCK;
Query OK, 0 rows affected (0.02 sec)
```

Modify the attributes of `newuser`:

```sql
ALTER USER 'newuser' ATTRIBUTE '{"newAttr": "value", "deprecatedAttr": null}';
SELECT * FROM information_schema.user_attributes;
```

```sql
+-----------+------+--------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+--------------------------+
| newuser | % | {"newAttr": "value"} |
+-----------+------+--------------------------+
1 rows in set (0.00 sec)
```

Modify the comment of `newuser` using `ALTER USER ... COMMENT`:

```sql
ALTER USER 'newuser' COMMENT 'Here is the comment';
SELECT * FROM information_schema.user_attributes;
```

```sql
+-----------+------+--------------------------------------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+--------------------------------------------------------+
| newuser | % | {"comment": "Here is the comment", "newAttr": "value"} |
+-----------+------+--------------------------------------------------------+
1 rows in set (0.00 sec)
```

Remove the comment of `newuser` using `ALTER USER ... ATTRIBUTE`:

```sql
ALTER USER 'newuser' ATTRIBUTE '{"comment": null}';
SELECT * FROM information_schema.user_attributes;
```

```sql
+-----------+------+---------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+---------------------------+
| newuser | % | {"newAttr": "value"} |
+-----------+------+---------------------------+
1 rows in set (0.00 sec)
```

qiancai marked this conversation as resolved.
Show resolved Hide resolved
> **Note:**
>
> Do not use `ACCOUNT UNLOCK` to unlock a [role](/sql-statements/sql-statement-create-role.md). Otherwise, the unlocked role can be used to log in to TiDB without password.

## MySQL compatibility

* In MySQL this statement is used to change attributes such as to expire a password. This functionality is not yet supported by TiDB.

## See also

<CustomContent platform="tidb">
Expand Down
36 changes: 35 additions & 1 deletion sql-statements/sql-statement-create-user.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ This statement creates a new user, specified with a password. In the MySQL privi

```ebnf+diagram
CreateUserStmt ::=
'CREATE' 'USER' IfNotExists UserSpecList RequireClauseOpt ConnectionOptions LockOption
'CREATE' 'USER' IfNotExists UserSpecList RequireClauseOpt ConnectionOptions LockOption AttributeOption

IfNotExists ::=
('IF' 'NOT' 'EXISTS')?
Expand All @@ -31,6 +31,8 @@ StringName ::=
| Identifier

LockOption ::= ( 'ACCOUNT' 'LOCK' | 'ACCOUNT' 'UNLOCK' )?

AttributeOption ::= ( 'COMMENT' CommentString | 'ATTRIBUTE' AttributeString )?
```

## Examples
Expand Down Expand Up @@ -73,6 +75,38 @@ CREATE USER 'newuser5'@'%' ACCOUNT LOCK;
Query OK, 1 row affected (0.02 sec)
```

Create a user with a comment.

```sql
CREATE USER 'newuser6'@'%' COMMENT 'This user is created only for test';
SELECT * FROM information_schema.user_attributes;
```

```
+-----------+------+---------------------------------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+---------------------------------------------------+
| newuser6 | % | {"comment": "This user is created only for test"} |
+-----------+------+---------------------------------------------------+
1 rows in set (0.00 sec)
```

Create a user with an `email` attribute.

```sql
CREATE USER 'newuser7'@'%' ATTRIBUTE '{"email": "[email protected]"}';
SELECT * FROM information_schema.user_attributes;
```

```sql
+-----------+------+---------------------------------------------------+
| USER | HOST | ATTRIBUTE |
+-----------+------+---------------------------------------------------+
| newuser7 | % | {"email": "[email protected]"} |
+-----------+------+---------------------------------------------------+
1 rows in set (0.00 sec)
```

## MySQL compatibility

The following `CREATE USER` options are not yet supported by TiDB, and will be parsed but ignored:
Expand Down
81 changes: 43 additions & 38 deletions sql-statements/sql-statement-show-columns-from.md
Original file line number Diff line number Diff line change
Expand Up @@ -111,44 +111,49 @@ mysql> show full columns from v1;
1 row in set (0.00 sec)

mysql> show full columns from mysql.user;
+-----------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
| Field | Type | Collation | Null | Key | Default | Extra | Privileges | Comment |
+-----------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
| Host | char(64) | utf8mb4_bin | NO | PRI | NULL | | select,insert,update,references | |
| User | char(32) | utf8mb4_bin | NO | PRI | NULL | | select,insert,update,references | |
| authentication_string | text | utf8mb4_bin | YES | | NULL | | select,insert,update,references | |
| Select_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Insert_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Update_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Delete_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Drop_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Process_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Grant_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| References_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Alter_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Show_db_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Super_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_tmp_table_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Lock_tables_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Execute_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_view_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Show_view_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_routine_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Alter_routine_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Index_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_user_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Event_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Trigger_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_role_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Drop_role_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Account_locked | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Shutdown_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Reload_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| FILE_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Config_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
+-----------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
33 rows in set (0.01 sec)
+------------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
| Field | Type | Collation | Null | Key | Default | Extra | Privileges | Comment |
+------------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
| Host | char(255) | utf8mb4_bin | NO | PRI | NULL | | select,insert,update,references | |
| User | char(32) | utf8mb4_bin | NO | PRI | NULL | | select,insert,update,references | |
| authentication_string | text | utf8mb4_bin | YES | | NULL | | select,insert,update,references | |
| plugin | char(64) | utf8mb4_bin | YES | | NULL | | select,insert,update,references | |
| Select_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Insert_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Update_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Delete_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Drop_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Process_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Grant_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| References_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Alter_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Show_db_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Super_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_tmp_table_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Lock_tables_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Execute_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_view_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Show_view_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_routine_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Alter_routine_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Index_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_user_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Event_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Repl_slave_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Repl_client_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Trigger_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_role_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Drop_role_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Account_locked | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Shutdown_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Reload_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| FILE_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Config_priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| Create_Tablespace_Priv | enum('N','Y') | utf8mb4_bin | NO | | N | | select,insert,update,references | |
| User_attributes | json | NULL | YES | | NULL | | select,insert,update,references | |
+------------------------+---------------+-------------+------+------+---------+-------+---------------------------------+---------+
38 rows in set (0.00 sec)
```

## MySQL compatibility
Expand Down