- Docs Home
- About TiDB
- Quick Start
- Develop
- Overview
- Quick Start
- Build a TiDB Cluster in TiDB Cloud (Developer Tier)
- CRUD SQL in TiDB
- Build a Simple CRUD App with TiDB
- Example Applications
- Connect to TiDB
- Design Database Schema
- Write Data
- Read Data
- Transaction
- Optimize
- Troubleshoot
- Reference
- Cloud Native Development Environment
- Third-party Support
- Deploy
- Software and Hardware Requirements
- Environment Configuration Checklist
- Plan Cluster Topology
- Install and Start
- Verify Cluster Status
- Test Cluster Performance
- Migrate
- Overview
- Migration Tools
- Migration Scenarios
- Migrate from Aurora
- Migrate MySQL of Small Datasets
- Migrate MySQL of Large Datasets
- Migrate and Merge MySQL Shards of Small Datasets
- Migrate and Merge MySQL Shards of Large Datasets
- Migrate from CSV Files
- Migrate from SQL Files
- Migrate from One TiDB Cluster to Another TiDB Cluster
- Migrate from TiDB to MySQL-compatible Databases
- Advanced Migration
- Integrate
- Maintain
- Monitor and Alert
- Troubleshoot
- TiDB Troubleshooting Map
- Identify Slow Queries
- Analyze Slow Queries
- SQL Diagnostics
- Identify Expensive Queries Using Top SQL
- Identify Expensive Queries Using Logs
- Statement Summary Tables
- Troubleshoot Hotspot Issues
- Troubleshoot Increased Read and Write Latency
- Save and Restore the On-Site Information of a Cluster
- Troubleshoot Cluster Setup
- Troubleshoot High Disk I/O Usage
- Troubleshoot Lock Conflicts
- Troubleshoot TiFlash
- Troubleshoot Write Conflicts in Optimistic Transactions
- Troubleshoot Inconsistency Between Data and Indexes
- Performance Tuning
- Tuning Guide
- Configuration Tuning
- System Tuning
- Software Tuning
- SQL Tuning
- Overview
- Understanding the Query Execution Plan
- SQL Optimization Process
- Overview
- Logic Optimization
- Physical Optimization
- Prepare Execution Plan Cache
- Control Execution Plans
- Tutorials
- TiDB Tools
- Overview
- Use Cases
- Download
- TiUP
- Documentation Map
- Overview
- Terminology and Concepts
- Manage TiUP Components
- FAQ
- Troubleshooting Guide
- Command Reference
- Overview
- TiUP Commands
- TiUP Cluster Commands
- Overview
- tiup cluster audit
- tiup cluster check
- tiup cluster clean
- tiup cluster deploy
- tiup cluster destroy
- tiup cluster disable
- tiup cluster display
- tiup cluster edit-config
- tiup cluster enable
- tiup cluster help
- tiup cluster import
- tiup cluster list
- tiup cluster patch
- tiup cluster prune
- tiup cluster reload
- tiup cluster rename
- tiup cluster replay
- tiup cluster restart
- tiup cluster scale-in
- tiup cluster scale-out
- tiup cluster start
- tiup cluster stop
- tiup cluster template
- tiup cluster upgrade
- TiUP DM Commands
- Overview
- tiup dm audit
- tiup dm deploy
- tiup dm destroy
- tiup dm disable
- tiup dm display
- tiup dm edit-config
- tiup dm enable
- tiup dm help
- tiup dm import
- tiup dm list
- tiup dm patch
- tiup dm prune
- tiup dm reload
- tiup dm replay
- tiup dm restart
- tiup dm scale-in
- tiup dm scale-out
- tiup dm start
- tiup dm stop
- tiup dm template
- tiup dm upgrade
- TiDB Cluster Topology Reference
- DM Cluster Topology Reference
- Mirror Reference Guide
- TiUP Components
- PingCAP Clinic Diagnostic Service
- TiDB Operator
- Dumpling
- TiDB Lightning
- TiDB Data Migration
- About TiDB Data Migration
- Architecture
- Quick Start
- Deploy a DM cluster
- Tutorials
- Advanced Tutorials
- Maintain
- Cluster Upgrade
- Tools
- Performance Tuning
- Manage Data Sources
- Manage Tasks
- Export and Import Data Sources and Task Configurations of Clusters
- Handle Alerts
- Daily Check
- Reference
- Architecture
- Command Line
- Configuration Files
- OpenAPI
- Compatibility Catalog
- Secure
- Monitoring and Alerts
- Error Codes
- Glossary
- Example
- Troubleshoot
- Release Notes
- Backup & Restore (BR)
- TiDB Binlog
- TiCDC
- Dumpling
- sync-diff-inspector
- TiSpark
- Reference
- Cluster Architecture
- Key Monitoring Metrics
- Secure
- Privileges
- SQL
- SQL Language Structure and Syntax
- SQL Statements
ADD COLUMN
ADD INDEX
ADMIN
ADMIN CANCEL DDL
ADMIN CHECKSUM TABLE
ADMIN CHECK [TABLE|INDEX]
ADMIN SHOW DDL [JOBS|QUERIES]
ADMIN SHOW TELEMETRY
ALTER DATABASE
ALTER INDEX
ALTER INSTANCE
ALTER PLACEMENT POLICY
ALTER TABLE
ALTER TABLE COMPACT
ALTER USER
ANALYZE TABLE
BACKUP
BATCH
BEGIN
CHANGE COLUMN
COMMIT
CHANGE DRAINER
CHANGE PUMP
CREATE [GLOBAL|SESSION] BINDING
CREATE DATABASE
CREATE INDEX
CREATE PLACEMENT POLICY
CREATE ROLE
CREATE SEQUENCE
CREATE TABLE LIKE
CREATE TABLE
CREATE USER
CREATE VIEW
DEALLOCATE
DELETE
DESC
DESCRIBE
DO
DROP [GLOBAL|SESSION] BINDING
DROP COLUMN
DROP DATABASE
DROP INDEX
DROP PLACEMENT POLICY
DROP ROLE
DROP SEQUENCE
DROP STATS
DROP TABLE
DROP USER
DROP VIEW
EXECUTE
EXPLAIN ANALYZE
EXPLAIN
FLASHBACK TABLE
FLUSH PRIVILEGES
FLUSH STATUS
FLUSH TABLES
GRANT <privileges>
GRANT <role>
INSERT
KILL [TIDB]
LOAD DATA
LOAD STATS
MODIFY COLUMN
PREPARE
RECOVER TABLE
RENAME INDEX
RENAME TABLE
REPLACE
RESTORE
REVOKE <privileges>
REVOKE <role>
ROLLBACK
SELECT
SET DEFAULT ROLE
SET [NAMES|CHARACTER SET]
SET PASSWORD
SET ROLE
SET TRANSACTION
SET [GLOBAL|SESSION] <variable>
SHOW ANALYZE STATUS
SHOW [BACKUPS|RESTORES]
SHOW [GLOBAL|SESSION] BINDINGS
SHOW BUILTINS
SHOW CHARACTER SET
SHOW COLLATION
SHOW [FULL] COLUMNS FROM
SHOW CONFIG
SHOW CREATE PLACEMENT POLICY
SHOW CREATE SEQUENCE
SHOW CREATE TABLE
SHOW CREATE USER
SHOW DATABASES
SHOW DRAINER STATUS
SHOW ENGINES
SHOW ERRORS
SHOW [FULL] FIELDS FROM
SHOW GRANTS
SHOW INDEX [FROM|IN]
SHOW INDEXES [FROM|IN]
SHOW KEYS [FROM|IN]
SHOW MASTER STATUS
SHOW PLACEMENT
SHOW PLACEMENT FOR
SHOW PLACEMENT LABELS
SHOW PLUGINS
SHOW PRIVILEGES
SHOW [FULL] PROCESSSLIST
SHOW PROFILES
SHOW PUMP STATUS
SHOW SCHEMAS
SHOW STATS_HEALTHY
SHOW STATS_HISTOGRAMS
SHOW STATS_META
SHOW STATUS
SHOW TABLE NEXT_ROW_ID
SHOW TABLE REGIONS
SHOW TABLE STATUS
SHOW [FULL] TABLES
SHOW [GLOBAL|SESSION] VARIABLES
SHOW WARNINGS
SHUTDOWN
SPLIT REGION
START TRANSACTION
TABLE
TRACE
TRUNCATE
UPDATE
USE
WITH
- Data Types
- Functions and Operators
- Overview
- Type Conversion in Expression Evaluation
- Operators
- Control Flow Functions
- String Functions
- Numeric Functions and Operators
- Date and Time Functions
- Bit Functions and Operators
- Cast Functions and Operators
- Encryption and Compression Functions
- Locking Functions
- Information Functions
- JSON Functions
- Aggregate (GROUP BY) Functions
- Window Functions
- Miscellaneous Functions
- Precision Math
- Set Operations
- List of Expressions for Pushdown
- TiDB Specific Functions
- Clustered Indexes
- Constraints
- Generated Columns
- SQL Mode
- Table Attributes
- Transactions
- Garbage Collection (GC)
- Views
- Partitioning
- Temporary Tables
- Cached Tables
- Character Set and Collation
- Placement Rules in SQL
- System Tables
mysql
- INFORMATION_SCHEMA
- Overview
ANALYZE_STATUS
CLIENT_ERRORS_SUMMARY_BY_HOST
CLIENT_ERRORS_SUMMARY_BY_USER
CLIENT_ERRORS_SUMMARY_GLOBAL
CHARACTER_SETS
CLUSTER_CONFIG
CLUSTER_HARDWARE
CLUSTER_INFO
CLUSTER_LOAD
CLUSTER_LOG
CLUSTER_SYSTEMINFO
COLLATIONS
COLLATION_CHARACTER_SET_APPLICABILITY
COLUMNS
DATA_LOCK_WAITS
DDL_JOBS
DEADLOCKS
ENGINES
INSPECTION_RESULT
INSPECTION_RULES
INSPECTION_SUMMARY
KEY_COLUMN_USAGE
METRICS_SUMMARY
METRICS_TABLES
PARTITIONS
PLACEMENT_POLICIES
PROCESSLIST
REFERENTIAL_CONSTRAINTS
SCHEMATA
SEQUENCES
SESSION_VARIABLES
SLOW_QUERY
STATISTICS
TABLES
TABLE_CONSTRAINTS
TABLE_STORAGE_STATS
TIDB_HOT_REGIONS
TIDB_HOT_REGIONS_HISTORY
TIDB_INDEXES
TIDB_SERVERS_INFO
TIDB_TRX
TIFLASH_REPLICA
TIKV_REGION_PEERS
TIKV_REGION_STATUS
TIKV_STORE_STATUS
USER_PRIVILEGES
VIEWS
METRICS_SCHEMA
- UI
- TiDB Dashboard
- Overview
- Maintain
- Access
- Overview Page
- Cluster Info Page
- Top SQL Page
- Key Visualizer Page
- Metrics Relation Graph
- SQL Statements Analysis
- Slow Queries Page
- Cluster Diagnostics
- Search Logs Page
- Instance Profiling
- Session Management and Configuration
- FAQ
- CLI
- Command Line Flags
- Configuration File Parameters
- System Variables
- Storage Engines
- Telemetry
- Errors Codes
- Table Filter
- Schedule Replicas by Topology Labels
- FAQs
- Release Notes
- All Releases
- Release Timeline
- TiDB Versioning
- v6.1
- v6.0
- v5.4
- v5.3
- v5.2
- v5.1
- v5.0
- v4.0
- v3.1
- v3.0
- v2.1
- v2.0
- v1.0
- Glossary
Role-Based Access Control
The implementation of TiDB's role-based access control (RBAC) system is similar to that of MySQL 8.0. TiDB is compatible with most RBAC syntax of MySQL.
This document introduces TiDB RBAC-related operations and implementation.
RBAC operations
A role is a collection of a series of privileges. You can do the following operations:
- Create a role.
- Delete a role.
- Grant a privilege to a role.
- Grant a role to another user. That user can obtain the privileges involved in the role, after enabling the role.
Create a role
For example, you can use the following statement to create the roles app_developer
, app_read
, and app_write
:
CREATE ROLE 'app_developer', 'app_read', 'app_write';
For the role naming format and rule, see TiDB User Account Management.
Roles are stored in the mysql.user
table and the host name part of the role name (if omitted) defaults to '%'
. The name of the role you are trying to create must be unique; otherwise, an error is reported.
To create a role, you need the CREATE ROLE
or CREATE USER
privilege.
Grant a privilege to a role
The operation of granting a privilege to a role is the same with that of granting a privilege to a user. For details, see TiDB Privilege Management.
For example, you can use the following statement to grant the app_read
role the privilege to read the app_db
database:
GRANT SELECT ON app_db.* TO 'app_read'@'%';
You can use the following statement to grant the app_write
role the privilege to write data to the app_db
database:
GRANT INSERT, UPDATE, DELETE ON app_db.* TO 'app_write'@'%';;
You can use the following statement to grant the app_developer
role all privileges on the app_db
database:
GRANT ALL ON app_db.* TO 'app_developer';
Grant a role to a user
Assume that a user dev1
has the developer role with all the privileges on app_db
; two users read_user1
and read_user2
have the read-only privilege on app_db
; and a user rw_user1
has read and write privileges on app_db
.
Use CREATE USER
to create the users:
CREATE USER 'dev1'@'localhost' IDENTIFIED BY 'dev1pass';
CREATE USER 'read_user1'@'localhost' IDENTIFIED BY 'read_user1pass';
CREATE USER 'read_user2'@'localhost' IDENTIFIED BY 'read_user2pass';
CREATE USER 'rw_user1'@'localhost' IDENTIFIED BY 'rw_user1pass';
Then use GRANT
to grant roles to users
GRANT 'app_developer' TO 'dev1'@'localhost';
GRANT 'app_read' TO 'read_user1'@'localhost', 'read_user2'@'localhost';
GRANT 'app_read', 'app_write' TO 'rw_user1'@'localhost';
To grant a role to another user or revoke a role, you need the SUPER
privilege.
Granting a role to a user does not mean enabling the role immediately. Enabling a role is another operation.
The following operations might form a "relation loop:"
CREATE USER 'u1', 'u2';
CREATE ROLE 'r1', 'r2';
GRANT 'u1' TO 'u1';
GRANT 'r1' TO 'r1';
GRANT 'r2' TO 'u2';
GRANT 'u2' TO 'r2';
TiDB supports this multi-level authorization relationship. You can use it to implement privilege inheritance.
Check a role's privileges
You can use the SHOW GRANTS
statement to check what privileges have been granted to the user.
To check privilege-related information of another user, you need the SELECT
privilege on the mysql
database.
SHOW GRANTS FOR 'dev1'@'localhost';
+-------------------------------------------------+
| Grants for dev1@localhost |
+-------------------------------------------------+
| GRANT USAGE ON *.* TO `dev1`@`localhost` |
| GRANT `app_developer`@`%` TO `dev1`@`localhost` |
+-------------------------------------------------+
You can use the USING
option in SHOW GRANTS
to check a role's privileges:
SHOW GRANTS FOR 'dev1'@'localhost' USING 'app_developer';
+----------------------------------------------------------+
| Grants for dev1@localhost |
+----------------------------------------------------------+
| GRANT USAGE ON *.* TO `dev1`@`localhost` |
| GRANT ALL PRIVILEGES ON `app_db`.* TO `dev1`@`localhost` |
| GRANT `app_developer`@`%` TO `dev1`@`localhost` |
+----------------------------------------------------------+
SHOW GRANTS FOR 'rw_user1'@'localhost' USING 'app_read', 'app_write';
+------------------------------------------------------------------------------+
| Grants for rw_user1@localhost |
+------------------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `rw_user1`@`localhost` |
| GRANT SELECT, INSERT, UPDATE, DELETE ON `app_db`.* TO `rw_user1`@`localhost` |
| GRANT `app_read`@`%`,`app_write`@`%` TO `rw_user1`@`localhost` |
+------------------------------------------------------------------------------+
SHOW GRANTS FOR 'read_user1'@'localhost' USING 'app_read';
+--------------------------------------------------------+
| Grants for read_user1@localhost |
+--------------------------------------------------------+
| GRANT USAGE ON *.* TO `read_user1`@`localhost` |
| GRANT SELECT ON `app_db`.* TO `read_user1`@`localhost` |
| GRANT `app_read`@`%` TO `read_user1`@`localhost` |
+--------------------------------------------------------+
You can use SHOW GRANTS
or SHOW GRANTS FOR CURRENT_USER()
to check the current user's privileges. SHOW GRANTS
and SHOW GRANTS FOR CURRENT_USER()
are different in the following aspects:
SHOW GRANTS
shows the privilege of the enabled role for the current user.SHOW GRANTS FOR CURRENT_USER()
does not show the enabled role's privilege.
Set the default role
After a role is granted to a user, it does not take effect immediately. Only after the user enables this role, he can use the privilege the role owns.
You can set default roles for a user. When the user logs in, the default roles are automatically enabled.
SET DEFAULT ROLE
{NONE | ALL | role [, role ] ...}
TO user [, user ]
For example, you can use the following statement to set default roles of rw_user1@localhost
to app_read
and app_write
:
SET DEFAULT ROLE app_read, app_write TO 'rw_user1'@'localhost';
You can use the following statement to set default roles of dev1@localhost
to all roles:
SET DEFAULT ROLE ALL TO 'dev1'@'localhost';
You can use the following statement to disable all default roles of dev1@localhost
:
SET DEFAULT ROLE NONE TO 'dev1'@'localhost';
You need to grant the role to the user before you set the default role to this role.
Enable a role in the current session
You can enable some role(s) in the current session.
SET ROLE {
DEFAULT
| NONE
| ALL
| ALL EXCEPT role [, role ] ...
| role [, role ] ...
}
For example, after rw_user1
logs in, you can use the following statement to enable roles app_read
and app_write
that are valid only in the current session:
SET ROLE 'app_read', 'app_write';
You can use the following statement to enable the default role of the current user:
SET ROLE DEFAULT
You can use the following statement to enable all roles granted to the current user:
SET ROLE ALL
You can use the following statement to disable all roles:
SET ROLE NONE
You can use the following statement to enable roles except app_read
:
SET ROLE ALL EXCEPT 'app_read'
If you use SET ROLE
to enable a role, this role is valid only in the current session.
Check the current enabled role
The current user can use the CURRENT_ROLE()
function to check which role has been enabled by the current user.
For example, you can grant default roles to rw_user1'@'localhost
:
SET DEFAULT ROLE ALL TO 'rw_user1'@'localhost';
After rw_user1@localhost
logs in, you can execute the following statement:
SELECT CURRENT_ROLE();
+--------------------------------+
| CURRENT_ROLE() |
+--------------------------------+
| `app_read`@`%`,`app_write`@`%` |
+--------------------------------+
SET ROLE 'app_read'; SELECT CURRENT_ROLE();
+----------------+
| CURRENT_ROLE() |
+----------------+
| `app_read`@`%` |
+----------------+
Revoke a role
You can use the following statement to revoke the app_read
role granted to the users read_user1@localhost
and read_user2@localhost
:
REVOKE 'app_read' FROM 'read_user1'@'localhost', 'read_user2'@'localhost';
You can use the following statement to revoke the roles app_read
and app_write
granted to the rw_user1@localhost
user:
REVOKE 'app_read', 'app_write' FROM 'rw_user1'@'localhost';
The operation of revoking a role from a user is atomic. If you fail to revoke a role, this operation rolls back.
Revoke a privilege
The REVOKE
statement is reverse to GRANT
. You can use REVOKE
to revoke the privileges of app_write
.
REVOKE INSERT, UPDATE, DELETE ON app_db.* FROM 'app_write';
For details, see TiDB Privilege Management.
Delete a role
You can use the following statement to delete roles app_read
and app_write
:
DROP ROLE 'app_read', 'app_write';
This operation deletes the role records of app_read
and app_write
in the mysql.user
table and related records in the authorization table, and terminates the authorization related to the two roles.
To delete a role, you need the DROP ROLE
or DROP USER
privilege.
Authorization table
In addition to four system privilege tables, the RBAC system introduces two new system privilege tables:
mysql.role_edges
: records the authorization relationship of the role and user.mysql.default_roles
: records default roles of each user.
mysql.role_edges
mysql.role_edges
contains the following data:
SELECT * FROM mysql.role_edges;
+-----------+-----------+---------+---------+-------------------+
| FROM_HOST | FROM_USER | TO_HOST | TO_USER | WITH_ADMIN_OPTION |
+-----------+-----------+---------+---------+-------------------+
| % | r_1 | % | u_1 | N |
+-----------+-----------+---------+---------+-------------------+
1 row in set (0.00 sec)
FROM_HOST
andFROM_USER
indicate the role's host name and user name respectively.TO_HOST
andTO_USER
indicate the host name and user name of the user to which a role is granted.
mysql.default_roles
mysql.default_roles
shows which roles have been enabled by default for each user.
SELECT * FROM mysql.default_roles;
+------+------+-------------------+-------------------+
| HOST | USER | DEFAULT_ROLE_HOST | DEFAULT_ROLE_USER |
+------+------+-------------------+-------------------+
| % | u_1 | % | r_1 |
| % | u_1 | % | r_2 |
+------+------+-------------------+-------------------+
2 rows in set (0.00 sec)
HOST
andUSER
indicate the user's host name and user name respectively.DEFAULT_ROLE_HOST
andDEFAULT_ROLE_USER
indicate the host name and user name of the default role respectively.
References
Because RBAC, user management, and privilege management are closely related, you can refer to operation details in the following resources: