From c4d3b71ac9f672af355221466a2f6a87cb728fe0 Mon Sep 17 00:00:00 2001 From: fzzf678 Date: Mon, 5 Jan 2026 18:16:29 +0800 Subject: [PATCH 1/9] Create database-read-only.md --- database-read-only.md | 158 ++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 158 insertions(+) create mode 100644 database-read-only.md diff --git a/database-read-only.md b/database-read-only.md new file mode 100644 index 0000000000000..17b57a5587a5b --- /dev/null +++ b/database-read-only.md @@ -0,0 +1,158 @@ +# Database Read-Only + +Database-level read-only allows you to set a single database to read-only, so that write operations (DDL, DML, and some locking reads) against that database and its objects are rejected. This capability is useful in scenarios such as sharded migration, traffic failback drills, and tenant data export, where you want to reduce the blast radius. + +## Usage scenarios + +- **Batch migration / failback**: When a shard batch encounters issues and you need to fail traffic back, set the corresponding database to read-only to prevent new writes from continuing. +- **Data export**: Set a tenant database to read-only to avoid inconsistency caused by data changes during export. + +## Syntax + +```sql +ALTER {DATABASE | SCHEMA} [db_name] READ ONLY [=] {DEFAULT | 0 | 1}; +``` + +- `db_name` is optional. If omitted, TiDB uses the current default database of the session. If there is no default database, the statement fails. +- `DEFAULT` is equivalent to `0` (read-write). +- `READ ONLY` is only supported in `ALTER DATABASE/SCHEMA`, not supported in `CREATE DATABASE`. +- `READ ONLY` must be used alone. It cannot be combined in the same `ALTER DATABASE` statement with other options such as `CHARACTER SET`, `COLLATE`, `PLACEMENT POLICY`, or `SET TIFLASH REPLICA`. + +**Examples** + +Set a database to read-only: + +```sql +ALTER DATABASE test READ ONLY = 1; +``` + +Set a database back to read-write: + +```sql +ALTER DATABASE test READ ONLY = 0; +``` + +If the database is already in the requested state, the statement succeeds and returns a `Note` (you can check it via `SHOW WARNINGS`). + +## Privileges and usage constraints + +- **Required privilege**: You must have the `ALTER` privilege on the target database. +- **Interaction with cluster read-only**: When the cluster is in read-only mode (for example, `tidb_restricted_read_only=1`), you cannot change database read-only status. The statement will fail with `Running in read-only mode`. +- **System database restriction**: Database-level read-only is not supported for system databases, including `mysql`, `sys`, `INFORMATION_SCHEMA`, `PERFORMANCE_SCHEMA`, and `METRICS_SCHEMA`. + +## Database read-only observability + +### Using INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS + +The `OPTIONS` column of `INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS` shows extended schema properties. If it is `READ ONLY=1`, the database is read-only; if it is empty, the database is read-write. + +```sql +SELECT CATALOG_NAME, SCHEMA_NAME, OPTIONS FROM INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS; + ++--------------+--------------------+-------------+ +| CATALOG_NAME | SCHEMA_NAME | OPTIONS | ++--------------+--------------------+-------------+ +| def | INFORMATION_SCHEMA | | +| def | METRICS_SCHEMA | | +| def | mysql | | +| def | PERFORMANCE_SCHEMA | | +| def | sys | | +| def | test | READ ONLY=1 | ++--------------+--------------------+-------------+ +``` + +### Using SHOW CREATE DATABASE + +When a database is read-only, `SHOW CREATE DATABASE` appends a comment `/* READ ONLY = 1 */` at the end of the output. + +```sql +SHOW CREATE DATABASE test; ++----------+--------------------------------------------------------------------------------------+ +| Database | Create Database | ++----------+--------------------------------------------------------------------------------------+ +| test | CREATE DATABASE `test` /*!40100 DEFAULT CHARACTER SET utf8mb4 */ /* READ ONLY = 1 */ | ++----------+--------------------------------------------------------------------------------------+ +``` + +## Behavior of read-only DDL + +### Transaction when switching read-only state + +`ALTER DATABASE ... READ ONLY = 1` is an online DDL. It first blocks new writes to the target database and then waits for existing transactions related to that database to commit before returning. + +If a transaction has not accessed the database at the beginning, but accesses an object in that database after the read-only DDL finishes, it may fail with an error similar to: + +- `public schema read only state has changed` + +### Troubleshooting when DDL takes a long time + +If `ALTER DATABASE ... READ ONLY = 1` takes a long time to finish, it is usually blocked by uncommitted transactions, TiDB periodically outputs the following logs: + +``` +[INFO] [schema.go:xxx] ["uncommitted txn block read only ddl"] [category=ddl] ["txn ID"=] ["job ID"=] +``` + +You can query transaction information and locate the blocked session to further confirm the scope of the impact: + +```sql +SELECT INSTANCE, ID, SESSION_ID, USER, DB, STATE, START_TIME, RELATED_TABLE_IDS FROM INFORMATION_SCHEMA.CLUSTER_TIDB_TRX; +``` + +## Behavior in a read-only database + +When a database is read-only, restricted statements typically fail with: + +- `ERROR 3989 (HY000): Schema '' is in read only mode.` + +### Rejected operations + +- **DDL**: + - `DROP DATABASE` + - `ALTER DATABASE` (except changing `READ ONLY` itself) + - `CREATE TABLE` (including `TEMPORARY` / `GLOBAL TEMPORARY`) + - `ALTER TABLE` (changes to columns, indexes, partitions, foreign keys, `AUTO_INCREMENT`, etc.) + - `RENAME TABLE` + - `TRUNCATE TABLE` + - `DROP TABLE` / `DROP VIEW` + - `CREATE INDEX` / `DROP INDEX` + - `CREATE VIEW` / `CREATE OR REPLACE VIEW` +- **DML**: `INSERT`, `REPLACE`, `UPDATE`, `DELETE` +- **Locking reads**: `SELECT ... FOR UPDATE` and related variants (`NOWAIT/WAIT`, `FOR UPDATE OF ...`, `TABLE ... FOR UPDATE`, etc.) +- **FOR SHARE**: When `tidb_enable_shared_lock_promotion=1`, `SELECT ... FOR SHARE` is also rejected (because it may be promoted to `FOR UPDATE` semantics). +- **Data import**: `LOAD DATA`, `IMPORT INTO` +- **Binding**: Create binding on statements that modify data are rejected. +- **PREPARE**: TiDB performs the read-only check during `PREPARE`. Statements that are not executable in a read-only database fail at `PREPARE` time, which may differ from MySQL. +- **EXECUTE**: Executing a prepared statement that modifies data in a read-only database fails. +- **EXPLAIN / EXPLAIN ANALYZE**: Planning also triggers the read-only check. Therefore, `EXPLAIN` / `EXPLAIN ANALYZE` can fail for statements that are not executable in read-only. +- **Foreign Key Cascades**: If a `DELETE/UPDATE` on a parent table triggers cascading changes on child tables, and the child table is in a read-only database, the `DELETE/UPDATE` is rejected with `ERROR 3989`. + + +> Note: In the current implementation, temporary tables are not exempt. Creating/modifying/writing temporary tables in a read-only database is also rejected. + +### Allowed operations + +- Regular read-only queries: `SELECT` without `FOR UPDATE/SHARE`, `TABLE t;` + +### Replication / synchronization tools + +Database-level read-only only applies at the TiDB SQL layer. Paths that bypass the SQL layer are not restricted. + +**TiCDC**: Replicating this DDL is currently not supported. + +**DM**: Replicating this DDL is currently not supported. + +**Dumpling**: Exporting a read-only database is supported and requires no extra configuration. + +**TiDB Lightning**: Physical import into a read-only database can succeed, while logical import fails. + +**BR**: Restoring into a read-only database is allowed. + +## MySQL compatibility + +This feature is based on MySQL 8.0 database-level read-only. Below are the major incompatibilities between TiDB and MySQL in the current implementation: + +- **ALTER DATABASE with multiple options**: MySQL allows setting `READ ONLY` together with `CHARACTER SET`/`COLLATE` in a single `ALTER DATABASE` statement; TiDB only supports setting `READ ONLY` alone (you need to split it into multiple statements). +- **TEMPORARY tables**: MySQL typically does not restrict `TEMPORARY` tables because of database-level read-only; TiDB does not exempt them and rejects creating/modifying/writing temporary tables (including `GLOBAL TEMPORARY`) in a read-only database. +- **PREPARE**: MySQL may allow `PREPARE` to succeed and fail at execution time; TiDB checks at `PREPARE` time and rejects statements that are not executable in a read-only database (commonly `ERROR 3989`). +- **EXPLAIN/EXPLAIN ANALYZE**: MySQL may allow `EXPLAIN` for some statements; TiDB triggers the read-only check during planning, so `EXPLAIN` can also fail for statements not executable in read-only. +- **Cross-database view dependency checks**: MySQL may block structural changes to underlying tables if they are referenced by views in a read-only database; TiDB currently does not block such changes (this may be improved in the future). From 46dd8f685b8ec76faa1c5d52149ad6db32f2a4b2 Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:21:32 +0800 Subject: [PATCH 2/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index 17b57a5587a5b..8588c929c8c6e 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -44,7 +44,7 @@ If the database is already in the requested state, the statement succeeds and re ### Using INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS -The `OPTIONS` column of `INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS` shows extended schema properties. If it is `READ ONLY=1`, the database is read-only; if it is empty, the database is read-write. +The `OPTIONS` column of `INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS` shows extended schema properties. If this column's value is `READ ONLY=1`, the database is read-only; if the column is empty, the database is read-write. ```sql SELECT CATALOG_NAME, SCHEMA_NAME, OPTIONS FROM INFORMATION_SCHEMA.SCHEMATA_EXTENSIONS; From 1182aac4f87a50da356658c466ee1404b7827714 Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:21:46 +0800 Subject: [PATCH 3/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index 8588c929c8c6e..878c3674cacb5 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -120,7 +120,7 @@ When a database is read-only, restricted statements typically fail with: - **Locking reads**: `SELECT ... FOR UPDATE` and related variants (`NOWAIT/WAIT`, `FOR UPDATE OF ...`, `TABLE ... FOR UPDATE`, etc.) - **FOR SHARE**: When `tidb_enable_shared_lock_promotion=1`, `SELECT ... FOR SHARE` is also rejected (because it may be promoted to `FOR UPDATE` semantics). - **Data import**: `LOAD DATA`, `IMPORT INTO` -- **Binding**: Create binding on statements that modify data are rejected. +- **Binding**: Creating bindings for statements that modify data is rejected. - **PREPARE**: TiDB performs the read-only check during `PREPARE`. Statements that are not executable in a read-only database fail at `PREPARE` time, which may differ from MySQL. - **EXECUTE**: Executing a prepared statement that modifies data in a read-only database fails. - **EXPLAIN / EXPLAIN ANALYZE**: Planning also triggers the read-only check. Therefore, `EXPLAIN` / `EXPLAIN ANALYZE` can fail for statements that are not executable in read-only. From b83427aafc1f5deb798fdede0f4c1741b39b2cd0 Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:29:27 +0800 Subject: [PATCH 4/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index 878c3674cacb5..c7aba9c7fab3d 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -137,7 +137,7 @@ When a database is read-only, restricted statements typically fail with: Database-level read-only only applies at the TiDB SQL layer. Paths that bypass the SQL layer are not restricted. -**TiCDC**: Replicating this DDL is currently not supported. +**TiCDC**: Currently, TiCDC does not support replicating this DDL. **DM**: Replicating this DDL is currently not supported. From 013eb45caa68d2c1595306a822b57636bd2bef22 Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:29:38 +0800 Subject: [PATCH 5/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index c7aba9c7fab3d..4a12e9680d521 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -139,7 +139,7 @@ Database-level read-only only applies at the TiDB SQL layer. Paths that bypass t **TiCDC**: Currently, TiCDC does not support replicating this DDL. -**DM**: Replicating this DDL is currently not supported. +**DM**: Currently, DM does not support replicating this DDL. **Dumpling**: Exporting a read-only database is supported and requires no extra configuration. From ec8b8053dd11763ad086388614dfaa6470af6f42 Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:29:59 +0800 Subject: [PATCH 6/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index 4a12e9680d521..7468cd385b6a8 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -141,7 +141,7 @@ Database-level read-only only applies at the TiDB SQL layer. Paths that bypass t **DM**: Currently, DM does not support replicating this DDL. -**Dumpling**: Exporting a read-only database is supported and requires no extra configuration. +**Dumpling**: Dumpling supports exporting a read-only database and requires no extra configuration. **TiDB Lightning**: Physical import into a read-only database can succeed, while logical import fails. From 617ee089bd78d408bb18d41721344386ee5db51c Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 5 Jan 2026 18:30:18 +0800 Subject: [PATCH 7/9] Update database-read-only.md Co-authored-by: gemini-code-assist[bot] <176961590+gemini-code-assist[bot]@users.noreply.github.com> --- database-read-only.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database-read-only.md b/database-read-only.md index 7468cd385b6a8..b6a22ab8c04f5 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -145,7 +145,7 @@ Database-level read-only only applies at the TiDB SQL layer. Paths that bypass t **TiDB Lightning**: Physical import into a read-only database can succeed, while logical import fails. -**BR**: Restoring into a read-only database is allowed. +**BR**: BR allows restoring into a read-only database. ## MySQL compatibility From 2113042d5a66f241e0a6ce0cac2b4b71f0d0b382 Mon Sep 17 00:00:00 2001 From: fzzf678 Date: Tue, 6 Jan 2026 14:08:51 +0800 Subject: [PATCH 8/9] Update database-read-only.md --- database-read-only.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/database-read-only.md b/database-read-only.md index b6a22ab8c04f5..d0d62b5553421 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -110,14 +110,14 @@ When a database is read-only, restricted statements typically fail with: - `DROP DATABASE` - `ALTER DATABASE` (except changing `READ ONLY` itself) - `CREATE TABLE` (including `TEMPORARY` / `GLOBAL TEMPORARY`) - - `ALTER TABLE` (changes to columns, indexes, partitions, foreign keys, `AUTO_INCREMENT`, etc.) + - `ALTER TABLE` (such as changes to columns, indexes, partitions, foreign keys, `AUTO_INCREMENT`) - `RENAME TABLE` - `TRUNCATE TABLE` - `DROP TABLE` / `DROP VIEW` - `CREATE INDEX` / `DROP INDEX` - `CREATE VIEW` / `CREATE OR REPLACE VIEW` - **DML**: `INSERT`, `REPLACE`, `UPDATE`, `DELETE` -- **Locking reads**: `SELECT ... FOR UPDATE` and related variants (`NOWAIT/WAIT`, `FOR UPDATE OF ...`, `TABLE ... FOR UPDATE`, etc.) +- **Locking reads**: `SELECT ... FOR UPDATE` and related variants (such as `NOWAIT/WAIT`, `FOR UPDATE OF ...`, `TABLE ... FOR UPDATE`) - **FOR SHARE**: When `tidb_enable_shared_lock_promotion=1`, `SELECT ... FOR SHARE` is also rejected (because it may be promoted to `FOR UPDATE` semantics). - **Data import**: `LOAD DATA`, `IMPORT INTO` - **Binding**: Creating bindings for statements that modify data is rejected. From 5922c2a62f846021b8210c4a4076a836fba7fccd Mon Sep 17 00:00:00 2001 From: fzzf678 <108643977+fzzf678@users.noreply.github.com> Date: Mon, 12 Jan 2026 20:32:16 +0800 Subject: [PATCH 9/9] Apply suggestions from code review Co-authored-by: Frank945946 <108602632+Frank945946@users.noreply.github.com> --- database-read-only.md | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/database-read-only.md b/database-read-only.md index d0d62b5553421..fa1f9087d60d7 100644 --- a/database-read-only.md +++ b/database-read-only.md @@ -1,10 +1,10 @@ # Database Read-Only -Database-level read-only allows you to set a single database to read-only, so that write operations (DDL, DML, and some locking reads) against that database and its objects are rejected. This capability is useful in scenarios such as sharded migration, traffic failback drills, and tenant data export, where you want to reduce the blast radius. +Database-level read-only allows you to set a single database to read-only, so that write operations (DDL, DML, and some locking reads) against that database and its objects are rejected. ## Usage scenarios -- **Batch migration / failback**: When a shard batch encounters issues and you need to fail traffic back, set the corresponding database to read-only to prevent new writes from continuing. +- **Batch migration / failback**: When syncing multiple upstream shards to a downstream database, if the downstream encounters issues, you can set the corresponding database to read-only to prevent new writes before failing traffic back to the upstream. - **Data export**: Set a tenant database to read-only to avoid inconsistency caused by data changes during export. ## Syntax @@ -104,7 +104,7 @@ When a database is read-only, restricted statements typically fail with: - `ERROR 3989 (HY000): Schema '' is in read only mode.` -### Rejected operations +### Rejected operations when the target database is read-only - **DDL**: - `DROP DATABASE`