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

sql-statements: update docs #4247

Closed
wants to merge 10 commits into from
14 changes: 10 additions & 4 deletions TOC.md
Original file line number Diff line number Diff line change
Expand Up @@ -254,12 +254,13 @@
- [`BACKUP`](/sql-statements/sql-statement-backup.md)
- [`BEGIN`](/sql-statements/sql-statement-begin.md)
- [`CHANGE COLUMN`](/sql-statements/sql-statement-change-column.md)
- [`COMMIT`](/sql-statements/sql-statement-commit.md)
- [`CHANGE DRAINER`](/sql-statements/sql-statement-change-drainer.md)
- [`CHANGE PUMP`](/sql-statements/sql-statement-change-pump.md)
- [`COMMIT`](/sql-statements/sql-statement-commit.md)
- [`CREATE BINDING`](/sql-statements/sql-statement-create-binding.md)
- [`CREATE [GLOBAL|SESSION] BINDING`](/sql-statements/sql-statement-create-binding.md)
- [`CREATE DATABASE`](/sql-statements/sql-statement-create-database.md)
- [`CREATE INDEX`](/sql-statements/sql-statement-create-index.md)
- [`CREATE ROLE`](/sql-statements/sql-statement-create-role.md)
- [`CREATE SEQUENCE`](/sql-statements/sql-statement-create-sequence.md)
- [`CREATE TABLE LIKE`](/sql-statements/sql-statement-create-table-like.md)
- [`CREATE TABLE`](/sql-statements/sql-statement-create-table.md)
Expand All @@ -270,10 +271,11 @@
- [`DESC`](/sql-statements/sql-statement-desc.md)
- [`DESCRIBE`](/sql-statements/sql-statement-describe.md)
- [`DO`](/sql-statements/sql-statement-do.md)
- [`DROP BINDING`](/sql-statements/sql-statement-drop-binding.md)
- [`DROP [GLOBAL|SESSION] BINDING`](/sql-statements/sql-statement-drop-binding.md)
- [`DROP COLUMN`](/sql-statements/sql-statement-drop-column.md)
- [`DROP DATABASE`](/sql-statements/sql-statement-drop-database.md)
- [`DROP INDEX`](/sql-statements/sql-statement-drop-index.md)
- [`DROP ROLE`](/sql-statements/sql-statement-drop-role.md)
- [`DROP SEQUENCE`](/sql-statements/sql-statement-drop-sequence.md)
- [`DROP STATS`](/sql-statements/sql-statement-drop-stats.md)
- [`DROP TABLE`](/sql-statements/sql-statement-drop-table.md)
Expand All @@ -287,6 +289,7 @@
- [`FLUSH STATUS`](/sql-statements/sql-statement-flush-status.md)
- [`FLUSH TABLES`](/sql-statements/sql-statement-flush-tables.md)
- [`GRANT <privileges>`](/sql-statements/sql-statement-grant-privileges.md)
- [`GRANT <role>`](/sql-statements/sql-statement-grant-role.md)
- [`INSERT`](/sql-statements/sql-statement-insert.md)
- [`KILL [TIDB]`](/sql-statements/sql-statement-kill.md)
- [`LOAD DATA`](/sql-statements/sql-statement-load-data.md)
Expand All @@ -299,16 +302,18 @@
- [`REPLACE`](/sql-statements/sql-statement-replace.md)
- [`RESTORE`](/sql-statements/sql-statement-restore.md)
- [`REVOKE <privileges>`](/sql-statements/sql-statement-revoke-privileges.md)
- [`REVOKE <role>`](/sql-statements/sql-statement-revoke-role.md)
- [`ROLLBACK`](/sql-statements/sql-statement-rollback.md)
- [`SELECT`](/sql-statements/sql-statement-select.md)
- [`SET DEFAULT ROLE`](/sql-statements/sql-statement-set-default-role.md)
- [`SET [NAMES|CHARACTER SET]`](/sql-statements/sql-statement-set-names.md)
- [`SET PASSWORD`](/sql-statements/sql-statement-set-password.md)
- [`SET ROLE`](/sql-statements/sql-statement-set-role.md)
- [`SET TRANSACTION`](/sql-statements/sql-statement-set-transaction.md)
- [`SET [GLOBAL|SESSION] <variable>`](/sql-statements/sql-statement-set-variable.md)
- [`SHOW [BACKUPS|RESTORES]`](/sql-statements/sql-statement-show-backups.md)
- [`SHOW ANALYZE STATUS`](/sql-statements/sql-statement-show-analyze-status.md)
- [`SHOW BINDINGS`](/sql-statements/sql-statement-show-bindings.md)
- [`SHOW [GLOBAL|SESSION] BINDINGS`](/sql-statements/sql-statement-show-bindings.md)
- [`SHOW BUILTINS`](/sql-statements/sql-statement-show-builtins.md)
- [`SHOW CHARACTER SET`](/sql-statements/sql-statement-show-character-set.md)
- [`SHOW COLLATION`](/sql-statements/sql-statement-show-collation.md)
Expand All @@ -333,6 +338,7 @@
- [`SHOW PROFILES`](/sql-statements/sql-statement-show-profiles.md)
- [`SHOW PUMP STATUS`](/sql-statements/sql-statement-show-pump-status.md)
- [`SHOW SCHEMAS`](/sql-statements/sql-statement-show-schemas.md)
- [`SHOW STATS_HEALTHY`](/sql-statements/sql-statement-show-stats-healthy.md)
- [`SHOW STATS_HISTOGRAMS`](/sql-statements/sql-statement-show-histograms.md)
- [`SHOW STATS_META`](/sql-statements/sql-statement-show-stats-meta.md)
- [`SHOW STATUS`](/sql-statements/sql-statement-show-status.md)
Expand Down
106 changes: 97 additions & 9 deletions sql-statements/sql-statement-create-binding.md
Original file line number Diff line number Diff line change
@@ -1,12 +1,16 @@
---
title: CREATE BINDING
title: CREATE [GLOBAL|SESSION] BINDING
summary: TiDB 数据库中 CREATE BINDING 的使用概况。
aliases: ['/docs-cn/dev/sql-statements/sql-statement-create-binding/']
---

# CREATE BINDING
# CREATE [GLOBAL|SESSION] BINDING

`CREATE BINDING` 语句用于在 TiDB 上创建新 SQL BIND。
`CREATE BINDING` 语句用于在 TiDB 中创建新的绑定执行计划。绑定不需要更改底层查询,可用于将优化器 Hint 插入语句中。

`BINDING` 语句可以在 `GLOBAL` 或者 `SESSION` 作用域内绑定执行计划。在不指定作用域时,默认的隐式作用域为 `SESSION`。

被绑定的 SQL 会被参数化后存储到系统表中。在处理 SQL 查询时,只要参数化后的 SQL 和系统表中某个被绑定的 SQL 语句一致,并且系统变量 `tidb_use_plan_baselines` 的值为 `ON`(其默认值为 `ON`),即可使用相应的优化器 Hint。如果存在多个可匹配的执行计划,优化器会从中选择代价最小的一个进行绑定。

## 语法图

Expand All @@ -24,19 +28,103 @@ aliases: ['/docs-cn/dev/sql-statements/sql-statement-create-binding/']

****

## 语法说明
## 示例

{{< copyable "sql" >}}

```sql
CREATE [GLOBAL | SESSION] BINDING FOR SelectStmt USING SelectStmt;
CREATE TABLE t1 (
-> id INT NOT NULL PRIMARY KEY auto_increment,
-> b INT NOT NULL,
-> pad VARBINARY(255),
-> INDEX(b)
-> );
Query OK, 0 rows affected (0.07 sec)
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM dual;
Query OK, 1 row affected (0.01 sec)
Records: 1 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 1 row affected (0.00 sec)
Records: 1 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 8 rows affected (0.00 sec)
Records: 8 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 1000 rows affected (0.04 sec)
Records: 1000 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 100000 rows affected (1.74 sec)
Records: 100000 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 100000 rows affected (2.15 sec)
Records: 100000 Duplicates: 0 Warnings: 0
INSERT INTO t1 SELECT NULL, FLOOR(RAND()*1000), RANDOM_BYTES(255) FROM t1 a JOIN t1 b JOIN t1 c LIMIT 100000;
Query OK, 100000 rows affected (2.64 sec)
Records: 100000 Duplicates: 0 Warnings: 0
SELECT SLEEP(1);
+----------+
| SLEEP(1) |
+----------+
| 0 |
+----------+
1 row in set (1.00 sec)
ANALYZE TABLE t1;
Query OK, 0 rows affected (1.33 sec)
EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123;
+-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+
| id | estRows | actRows | task | access object | execution info | operator info | memory | disk |
+-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+
| IndexLookUp_10 | 583.00 | 297 | root | | time:10.545072ms, loops:2, rpc num: 1, rpc time:398.359µs, proc keys:297 | | 109.1484375 KB | N/A |
| ├─IndexRangeScan_8(Build) | 583.00 | 297 | cop[tikv] | table:t1, index:b(b) | time:0s, loops:4 | range:[123,123], keep order:false | N/A | N/A |
| └─TableRowIDScan_9(Probe) | 583.00 | 297 | cop[tikv] | table:t1 | time:12ms, loops:4 | keep order:false | N/A | N/A |
+-------------------------------+---------+---------+-----------+----------------------+---------------------------------------------------------------------------+-----------------------------------+----------------+------+
3 rows in set (0.02 sec)
CREATE SESSION BINDING FOR
-> SELECT * FROM t1 WHERE b = 123
-> USING
-> SELECT * FROM t1 IGNORE INDEX (b) WHERE b = 123;
Query OK, 0 rows affected (0.00 sec)
EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123;
+-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+
| id | estRows | actRows | task | access object | execution info | operator info | memory | disk |
+-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+
| TableReader_7 | 583.00 | 297 | root | | time:222.32506ms, loops:2, rpc num: 1, rpc time:222.078952ms, proc keys:301010 | data:Selection_6 | 88.6640625 KB | N/A |
| └─Selection_6 | 583.00 | 297 | cop[tikv] | | time:224ms, loops:298 | eq(test.t1.b, 123) | N/A | N/A |
| └─TableFullScan_5 | 301010.00 | 301010 | cop[tikv] | table:t1 | time:220ms, loops:298 | keep order:false | N/A | N/A |
+-------------------------+-----------+---------+-----------+---------------+--------------------------------------------------------------------------------+--------------------+---------------+------+
3 rows in set (0.22 sec)
SHOW SESSION BINDINGS\G
*************************** 1. row ***************************
Original_sql: select * from t1 where b = ?
Bind_sql: SELECT * FROM t1 IGNORE INDEX (b) WHERE b = 123
Default_db: test
Status: using
Create_time: 2020-05-22 14:38:03.456
Update_time: 2020-05-22 14:38:03.456
Charset: utf8mb4
Collation: utf8mb4_0900_ai_ci
1 row in set (0.00 sec)
DROP SESSION BINDING FOR SELECT * FROM t1 WHERE b = 123;
Query OK, 0 rows affected (0.00 sec)
EXPLAIN ANALYZE SELECT * FROM t1 WHERE b = 123;
+-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+
| id | estRows | actRows | task | access object | execution info | operator info | memory | disk |
+-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+
| IndexLookUp_10 | 583.00 | 297 | root | | time:5.31206ms, loops:2, rpc num: 1, rpc time:665.927µs, proc keys:297 | | 109.1484375 KB | N/A |
| ├─IndexRangeScan_8(Build) | 583.00 | 297 | cop[tikv] | table:t1, index:b(b) | time:0s, loops:4 | range:[123,123], keep order:false | N/A | N/A |
| └─TableRowIDScan_9(Probe) | 583.00 | 297 | cop[tikv] | table:t1 | time:0s, loops:4 | keep order:false | N/A | N/A |
+-------------------------------+---------+---------+-----------+----------------------+-------------------------------------------------------------------------+-----------------------------------+----------------+------+
3 rows in set (0.01 sec)
```

该语句可以在 GLOBAL 或者 SESSION 作用域内为 SQL 绑定执行计划。在不指定作用域时,隐式作用域为 SESSION。
## MySQL 兼容性

被绑定的 SQL 会被参数化后存储到系统表中。在处理 SQL 查询时,只要参数化后的 SQL 和系统表中某个被绑定的 SQL 语句一致,并且系统变量 `tidb_use_plan_baselines` 的值为 `on`(其默认值为 `on`),即可使用相应的优化器 Hint。如果存在多个可匹配的执行计划,优化器会从中选择代价最小的一个进行绑定
`CREATE BINDING` 语句是 TiDB 对 MySQL 语法的扩展

## 另请参阅

* [DROP BINDING](/sql-statements/sql-statement-drop-binding.md)
* [SHOW BINDINGS](/sql-statements/sql-statement-show-bindings.md)
* [DROP [GLOBAL|SESSION] BINDING](/sql-statements/sql-statement-drop-binding.md)
* [SHOW [GLOBAL|SESSION] BINDINGS](/sql-statements/sql-statement-show-bindings.md)
* [ANALYZE](/sql-statements/sql-statement-analyze-table.md)
* [Optimizer Hints](/optimizer-hints.md)
* [执行计划管理 (SPM)](/sql-plan-management.md)
145 changes: 145 additions & 0 deletions sql-statements/sql-statement-create-role.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,145 @@
---
title: CREATE ROLE
summary: TiDB 数据库中 CREATE ROLE 的使用概况。
---

# CREATE ROLE

`CREATE ROLE` 语句是基于角色的访问控制 (RBAC) 操作的一部分,用于创建新角色并将其授予给用户。

## 语法图

**CreateRoleStmt:**

![CreateRoleStmt](/media/sqlgram/CreateRoleStmt.png)

**IfNotExists:**

![IfNotExists](/media/sqlgram/IfNotExists.png)

**RoleSpec:**

![RoleSpec](/media/sqlgram/RoleSpec.png)

## 示例

创建一个新角色 `analyticsteam` 和一个新用户 `jennifer`:

```sql
$ mysql -uroot
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 37
Server version: 5.7.25-TiDB-v4.0.0-beta.2-728-ga9177fe84 TiDB Server (Apache License 2.0) Community Edition, MySQL 5.7 compatible
Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
CREATE ROLE analyticsteam;
Query OK, 0 rows affected (0.02 sec)
GRANT SELECT ON test.* TO analyticsteam;
Query OK, 0 rows affected (0.02 sec)
CREATE USER jennifer;
Query OK, 0 rows affected (0.01 sec)
GRANT analyticsteam TO jennifer;
Query OK, 0 rows affected (0.01 sec)
```

需要注意的是,默认情况下,用户 `jennifer` 需要启用 `SET ROLE analyticsteam`,才能使用与角色相关联的权限:

```sql
$ mysql -ujennifer
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 32
Server version: 5.7.25-TiDB-v4.0.0-beta.2-728-ga9177fe84 TiDB Server (Apache License 2.0) Community Edition, MySQL 5.7 compatible
Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
SHOW GRANTS;
+---------------------------------------------+
| Grants for User |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%' |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
2 rows in set (0.00 sec)
SHOW TABLES in test;
ERROR 1044 (42000): Access denied for user 'jennifer'@'%' to database 'test'
SET ROLE analyticsteam;
Query OK, 0 rows affected (0.00 sec)
SHOW GRANTS;
+---------------------------------------------+
| Grants for User |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%' |
| GRANT Select ON test.* TO 'jennifer'@'%' |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
3 rows in set (0.00 sec)
SHOW TABLES IN test;
+----------------+
| Tables_in_test |
+----------------+
| t1 |
+----------------+
1 row in set (0.00 sec)
```

`SET DEFAULT ROLE` 语句可以对用户 `jennifer` 设置默认启用的角色,用户不用执行 `SET ROLE` 语句就能具有角色拥有的权限。

```sql
$ mysql -uroot
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 34
Server version: 5.7.25-TiDB-v4.0.0-beta.2-728-ga9177fe84 TiDB Server (Apache License 2.0) Community Edition, MySQL 5.7 compatible
Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
SET DEFAULT ROLE analyticsteam TO jennifer;
Query OK, 0 rows affected (0.02 sec)
```

```sql
$ mysql -ujennifer
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 35
Server version: 5.7.25-TiDB-v4.0.0-beta.2-728-ga9177fe84 TiDB Server (Apache License 2.0) Community Edition, MySQL 5.7 compatible
Copyright (c) 2000, 2020, Oracle and/or its affiliates. All rights reserved.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
SHOW GRANTS;
+---------------------------------------------+
| Grants for User |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%' |
| GRANT Select ON test.* TO 'jennifer'@'%' |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
3 rows in set (0.00 sec)
SHOW TABLES IN test;
+----------------+
| Tables_in_test |
+----------------+
| t1 |
+----------------+
1 row in set (0.00 sec)
```

## MySQL 兼容性

`CREATE ROLE` 语句与 MySQL 8.0 的角色功能完全兼容。如有任何其他兼容性差异,请在 GitHub 上提交 [issue](/report-issue.md)。

## 另请参阅

* [DROP ROLE](/sql-statements/sql-statement-drop-role.md)
* [GRANT <role>](/sql-statements/sql-statement-grant-role.md)
* [REVOKE <role>](/sql-statements/sql-statement-revoke-role.md)
* [SET ROLE](/sql-statements/sql-statement-set-role.md)
* [SET DEFAULT ROLE](/sql-statements/sql-statement-set-default-role.md)
* [基于角色的访问控制](/role-based-access-control.md)
Loading