Skip to content

Commit

Permalink
en: add doc for online-ddl-scheme (#58)
Browse files Browse the repository at this point in the history
  • Loading branch information
ran-huang committed May 15, 2020
1 parent 6edb64b commit 02fc17a
Show file tree
Hide file tree
Showing 4 changed files with 271 additions and 0 deletions.
1 change: 1 addition & 0 deletions en/TOC.md
Expand Up @@ -15,6 +15,7 @@
- [Black and White Lists](feature-overview.md#black-and-white-table-lists)
- [Binlog Event Filter](feature-overview.md#binlog-event-filter)
- [Replication Delay Monitoring](feature-overview.md#replication-delay-monitoring)
- [Online-ddl-scheme](online-ddl-scheme.md)
+ Sharding Support
- [Introduction](feature-shard-merge.md)
- [Restrictions](feature-shard-merge.md#restrictions)
Expand Down
27 changes: 27 additions & 0 deletions en/faq.md
Expand Up @@ -47,3 +47,30 @@ Generally, at this time, the relay unit exits with an error and cannot be automa
4. Clean up downstream replicated data.
5. Use DM-Ansible to [start the entire DM cluster](deploy-a-dm-cluster-using-ansible.md#step-9-deploy-the-dm-cluster).
6. Restart data replication with the new task name, or set `remove-meta` to `true` and `task-mode` to `all`.

## How to handle the error returned by the DDL operation related to the gh-ost table, after `online-ddl-scheme: "gh-ost"` is set?

```
[unit=Sync] ["error information"="{\"msg\":\"[code=36046:class=sync-unit:scope=internal:level=high] online ddls on ghost table `xxx`.`_xxxx_gho`\\ngithub.com/pingcap/dm/pkg/terror.(*Error).Generate ......
```

The above error can be caused by the following reason:

In the last `rename ghost_table to origin table` step, DM reads the DDL information in memory, and restores it to the DDL of the origin table.

However, the DDL information in memory is obtained in either of the two ways:

- DM [processes the gh-ost table during the `alter ghost_table` operation](online-ddl-scheme.md#online-schema-change-gh-ost) and records the DDL information of `ghost_table`;
- When DM-worker is restarted to start the task, DM reads the DDL from `dm_meta.{task_name}_onlineddl`.

Therefore, in the process of incremental replication, if the specified Pos has skipped the `alter ghost_table` DDL but the Pos is still in the online-ddl process of gh-ost, the ghost_table is not written into memory or `dm_meta.{task_name}_onlineddl` correctly. In such cases, the above error is returned.

You can avoid this error by the following steps:

1. Remove the `online-ddl-scheme` configuration of the task.

2. Configure `_{table_name}_gho`, `_{table_name}_ghc`, and `_{table_name}_del` in `black-white-list.ignore-tables`.

3. Execute the upstream DDL in the downstream TiDB manually.

4. After the Pos is replicated to the position after the gh-ost process, re-enable the `online-ddl-scheme` and comment out `black-white-list.ignore-tables`.
241 changes: 241 additions & 0 deletions en/online-ddl-scheme.md
@@ -0,0 +1,241 @@
---
title: DM online-ddl-scheme
summary: This document introduces the online-ddl-scheme feature of DM.
category: reference
---

# DM online-ddl-scheme

This document introduces the online-ddl-scheme feature of DM.

## Overview

DDL statements are always used in the database applications. MySQL 5.6 and later versions support online-ddl, but there are limitations for usage. For example, to acquire the MDL lock, some DDLs still need to be copied. In production scenario, the table lock during DDL execution can block the reads or writes to and from the database to a certain extent.

By using gh-ost and pt-osc, DDLs can be executed on the MySQL database more gracefully, and the impact on reads and writes is reduced as much as possible.

TiDB is implemented based on the online asynchronous schema change algorithm of Google F1. It does not block reads and writes during the DDL execution. Therefore, the large amount of intermediate table data and binlog events generated by gh-ost and pt-osc in the process of online-schema-change is not needed during the replication from MySQL to TiDB.

For Data Migration (DM), which supports the data replication from MySQL to TiDB, the online-ddl-scheme feature is to perform special processing on the above two online-schema-change tools (gh-ost and pt-osc). This way, the required DDL replication can be completed more rapidly.

## Configuration

In the task configuration file, `online-ddl-scheme` is at the same level of `name`. For example:

```yml
# ----------- Global configuration -----------
## ********* Basic configuration *********
name: test # The name of the task. Should be globally unique.
task-mode: all # The task mode. Can be set to `full`/`incremental`/`all`.
is-sharding: true # Whether it is a task to merge shards.
meta-schema: "dm_meta" # The downstream database that stores the `meta` information.
remove-meta: false # Whether to remove the `meta` information (`checkpoint` and `onlineddl`) corresponding to the task name before starting the replication task.
enable-heartbeat: false # Whether to enable the heartbeat feature.
online-ddl-scheme: "gh-ost" # Only "gh-ost" and "pt" are currently supported.
target-database: # Configuration of the downstream database instance.
host: "192.168.0.1"
port: 4000
user: "root"
password: "" # The password must be encrypted using dmctl if it is not empty.
```

For the advanced configuration and the description of each configuration parameter, refer to [DM advanced task configuration file template](task-configuration-file-full.md#task-configuration-file-template-advanced).

## online-schema-change: gh-ost

When gh-ost implements online-schema-change, 3 types of tables are created:

- gho: used to apply DDLs. When the data is fully replicated and the gho table is consistent with the origin table, the origin table is replaced by renaming.
- ghc: used to store information that is related to online-schema-change.
- del: created by renaming the origin table.

In the process of replication, DM divides the above tables into 3 categories:

- ghostTable: `\_\*\_gho`
- trashTable: `\_\*\_ghc`, `\_\*\_del`
- realTable: the origin table that executes online-ddl.

The SQL statements mostly used by gh-ost and the corresponding operation of DM are as follows:

1. Create the `_ghc` table:

```sql
Create /* gh-ost */ table `test`.`_test4_ghc` (
id bigint auto_increment,
last_update timestamp not null DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
hint varchar(64) charset ascii not null,
value varchar(4096) charset ascii not null,
primary key(id),
unique key hint_uidx(hint)
) auto_increment=256 ;
```

DM does not create the `_test4_ghc` table.

2. Create the `_gho` table:

```sql
Create /* gh-ost */ table `test`.`_test4_gho` like `test`.`test4` ;
```

DM does not create the `_test4_gho` table. DM deletes the `dm_meta.{task_name}\_onlineddl` record in the downstream according to `ghost_schema`, `ghost_table`, and the `server_id` of `dm_worker`, and clears the related information in memory.

```
DELETE FROM dm_meta.{task_name}_onlineddl WHERE id = {server_id} and ghost_schema = {ghost_schema} and ghost_table = {ghost_table};
```

3. Apply the DDL that needs to be executed in the `_gho` table:

```sql
Alter /* gh-ost */ table `test`.`_test4_gho` add column cl1 varchar(20) not null ;
```

DM does not perform the DDL operation of `_test4_gho`. It records this DDL in `dm_meta.{task_name}\_onlineddl` and memory.

```sql
REPLACE INTO dm_meta.{task_name}_onlineddl (id, ghost_schema , ghost_table , ddls) VALUES (......);
```

4. Write data to the `_ghc` table, and replicate the origin table data to the `_gho` table:

```sql
Insert /* gh-ost */ into `test`.`_test4_ghc` values (......);
Insert /* gh-ost `test`.`test4` */ ignore into `test`.`_test4_gho` (`id`, `date`, `account_id`, `conversion_price`, `ocpc_matched_conversions`, `ad_cost`, `cl2`)
(select `id`, `date`, `account_id`, `conversion_price`, `ocpc_matched_conversions`, `ad_cost`, `cl2` from `test`.`test4` force index (`PRIMARY`)
where (((`id` > _binary'1') or ((`id` = _binary'1'))) and ((`id` < _binary'2') or ((`id` = _binary'2')))) lock in share mode
) ;
```

DM does not execute DML statements that are not for **realtable**.

5. After the replication is completed, both the origin table and `_gho` table are renamed, and the online DDL operation is completed:

```sql
Rename /* gh-ost */ table `test`.`test4` to `test`.`_test4_del`, `test`.`_test4_gho` to `test`.`test4`;
```

DM performs the following two operations:

* DM splits the above `rename` operation into two SQL statements.

```sql
rename test.test4 to test._test4_del;
rename test._test4_gho to test.test4;
```

* DM does not execute `rename to _test4_del`. When executing `rename ghost_table to origin table`, DM takes the following steps:

- Read the DDL recorded in memory in Step 3
- Replace `ghost_table` and `ghost_schema` with `origin_table` and its corresponding schema
- Execute the DDL that has been replaced

```sql
alter table test._test4_gho add column cl1 varchar(20) not null;
-- Replaced with:
alter table test.test4 add column cl1 varchar(20) not null;
```

> **Note:**
>
> The specific SQL statements of gh-ost vary with the parameters used in the execution. This document only lists the major SQL statements. For more details, refer to the [gh-ost documentation](https://github.com/github/gh-ost#gh-ost).
## online-schema-change: pt

When pt-osc implements online-schema-change, 2 types of tables are created:

- `new`: used to apply DDL. When the data is fully replicated and the `new` table is consistent with the origin table, the origin table is replaced by renaming.
- `old`: created by renaming the origin table.
- 3 kinds of Trigger: `pt_osc\_\*\_ins`, `pt_osc\_\*\_upd`, `pt_osc\_\*\_del`. In the process of pt_osc, the new data generated by the origin table is replicated to `new` by the Trigger.

In the process of replication, DM divides the above tables into 3 categories:

- ghostTable: `\_\*\_new`
- trashTable: `\_\*\_old`
- realTable: the origin table that executes online-ddl.

The SQL statements mostly used by pt-osc and the corresponding operation of DM are as follows:

1. Create the `_new` table:

```sql
CREATE TABLE `test`.`_test4_new` ( id int(11) NOT NULL AUTO_INCREMENT,
date date DEFAULT NULL, account_id bigint(20) DEFAULT NULL, conversion_price decimal(20,3) DEFAULT NULL, ocpc_matched_conversions bigint(20) DEFAULT NULL, ad_cost decimal(20,3) DEFAULT NULL,cl2 varchar(20) COLLATE utf8mb4_bin NOT NULL,cl1 varchar(20) COLLATE utf8mb4_bin NOT NULL,PRIMARY KEY (id) ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin ;
```

DM does not create the `_test4_new` table. DM deletes the `dm_meta.{task_name}\_onlineddl` record in the downstream according to `ghost_schema`, `ghost_table`, and the `server_id` of `dm_worker`, and clears the related information in memory.

```sql
DELETE FROM dm_meta.{task_name}_onlineddl WHERE id = {server_id} and ghost_schema = {ghost_schema} and ghost_table = {ghost_table};
```

2. Execute DDL in the `_new` table:

```sql
ALTER TABLE `test`.`_test4_new` add column c3 int;
```

DM does not perform the DDL operation of `_test4_new`. Instead, it records this DDL in `dm_meta.{task_name}\_onlineddl` and memory.

```sql
REPLACE INTO dm_meta.{task_name}_onlineddl (id, ghost_schema , ghost_table , ddls) VALUES (......);
```

3. Create 3 Triggers used for data replication:

```sql
CREATE TRIGGER `pt_osc_test_test4_del` AFTER DELETE ON `test`.`test4` ...... ;
CREATE TRIGGER `pt_osc_test_test4_upd` AFTER UPDATE ON `test`.`test4` ...... ;
CREATE TRIGGER `pt_osc_test_test4_ins` AFTER INSERT ON `test`.`test4` ...... ;
```

DM does not execute Trigger operations that are not supported in TiDB.

4. Replicate the origin table data to the `_new` table:

```sql
INSERT LOW_PRIORITY IGNORE INTO `test`.`_test4_new` (`id`, `date`, `account_id`, `conversion_price`, `ocpc_matched_conversions`, `ad_cost`, `cl2`, `cl1`) SELECT `id`, `date`, `account_id`, `conversion_price`, `ocpc_matched_conversions`, `ad_cost`, `cl2`, `cl1` FROM `test`.`test4` LOCK IN SHARE MODE /*pt-online-schema-change 3227 copy table*/
```

DM does not execute the DML statements that are not for **realtable**.

5. After the data replication is completed, the origin table and `_new` table are renamed, and the online DDL operation is completed:

```sql
RENAME TABLE `test`.`test4` TO `test`.`_test4_old`, `test`.`_test4_new` TO `test`.`test4`
```

DM performs the following two operations:

* DM splits the above `rename` operation into two SQL statements:

```sql
rename test.test4 to test._test4_old;
rename test._test4_new to test.test4;
```

* DM does not execute `rename to _test4_old`. When executing `rename ghost_table to origin table`, DM takes the following steps:

- Read the DDL recorded in memory in Step 2
- Replace `ghost_table` and `ghost_schema` with `origin_table` and its corresponding schema
- Execute the DDL that has been replaced

```sql
ALTER TABLE `test`.`_test4_new` add column c3 int;
-- Replaced with:
ALTER TABLE `test`.`test4` add column c3 int;
```

6. Delete the `_old` table and 3 Triggers of the online DDL operation:

```sql
DROP TABLE IF EXISTS `test`.`_test4_old`;
DROP TRIGGER IF EXISTS `pt_osc_test_test4_del` AFTER DELETE ON `test`.`test4` ...... ;
DROP TRIGGER IF EXISTS `pt_osc_test_test4_upd` AFTER UPDATE ON `test`.`test4` ...... ;
DROP TRIGGER IF EXISTS `pt_osc_test_test4_ins` AFTER INSERT ON `test`.`test4` ...... ;
```

DM does not delete `_test4_old` and Triggers.

> **Note:**
>
> The specific SQL statements of pt-osc vary with the parameters used in the execution. This document only lists the major SQL statements. For more details, refer to the [pt-osc documentation](https://www.percona.com/doc/percona-toolkit/2.2/pt-online-schema-change.html).
2 changes: 2 additions & 0 deletions en/task-configuration-file-full.md
Expand Up @@ -34,6 +34,8 @@ heartbeat-update-interval: 1 # The interval at which DM updates the MySQL hea
heartbeat-report-interval: 10 # The interval at which DM estimates the lag (the delay time).
timezone: "Asia/Shanghai" # The timezone.
case-sensitive: false # Determines whether the schema/table is case-sensitive.
online-ddl-scheme: "gh-ost" # Only "gh-ost" and "pt" are currently supported.

target-database: # Configuration of the downstream database instance.
host: "192.168.0.1"
port: 4000
Expand Down

0 comments on commit 02fc17a

Please sign in to comment.