pt-online-schema-change,比较请参考pt-online-schema-change使用说明、限制与比较或 ONLINE DDL VS PT-ONLINE-SCHEMA-CHANGE 。INPLACE 和 COPY 两种方式,通过在ALTER语句的ALGORITHM参数指定。ALGORITHM=INPLACE,可以避免重建表带来的IO和CPU消耗,保证ddl期间依然有良好的性能和并发。ALGORITHM=COPY,需要拷贝原始表,所以不允许并发DML写操作,可读。这种copy方式的效率还是不如 inplace ,因为前者需要记录undo和redo log,而且因为临时占用buffer pool引起短时间内性能受影响。LOCK=NONE,即DDL期间允许并发读写涉及的表,比如为了保证 ALTER TABLE 时不影响用户注册或支付,可以明确指定,好处是如果不幸该 alter语句不支持对该表的继续写入,则会提示失败,而不会直接发到库上执行。ALGORITHM=COPY默认LOCK级别LOCK=SHARED,即DDL期间表上的写操作会被阻塞,但不影响读取。LOCK=DEFAULT,让mysql自己去判断lock的模式,原则是mysql尽可能不去锁表LOCK=EXCLUSIVE,即DDL期间该表不可用,堵塞任何读写请求。如果你想alter操作在最短的时间内完成,或者表短时间内不可用能接受,可以手动指定。waiting meta data lock。同样在ddl结束之前,也要等待alter期间所有的事务完成,也会堵塞一小段时间。所以尽量在ALTER TABLE之前确保没有大事务在执行,否则一样出现连环锁表。*号的限制说明| Operation | In-Place? | Copies Table? | Allows Concurrent DML? | Allows Concurrent Query? | Notes |
|---|---|---|---|---|---|
| 添加索引 | Yes* | No* | Yes | Yes | 对全文索引的一些限制 |
| 删除索引 | Yes | No | Yes | Yes | 仅修改表的元数据 |
| OPTIMIZE TABLE | Yes | Yes | Yes | Yes | 从 5.6.17开始使用ALGORITHM=INPLACE,当然如果指定了old_alter_table=1或mysqld启动带--skip-new则将还是COPY模式。如果表上有全文索引只支持COPY |
| 对一列设置默认值 | Yes | No | Yes | Yes | 仅修改表的元数据 |
| 对一列修改auto-increment 的值 | Yes | No | Yes | Yes | 仅修改表的元数据 |
| 添加 foreign key constraint | Yes* | No* | Yes | Yes | 为了避免拷贝表,在约束创建时会禁用foreign_key_checks |
| 删除 foreign key constraint | Yes | No | Yes | Yes | foreign_key_checks 不影响 |
| 改变列名 | Yes* | No* | Yes* | Yes | 为了允许DML并发, 如果保持相同数据类型,仅改变列名 |
| 添加列 | Yes* | Yes* | Yes* | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作。当添加列是auto-increment,不允许DML并发 |
| 删除列 | Yes | Yes* | Yes | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作 |
| 修改列数据类型 | No | Yes* | No | Yes | 修改类型或添加长度,都会拷贝表,而且不允许更新操作 |
| 更改列顺序 | Yes | Yes | Yes | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作 |
| 修改ROW_FORMAT 和KEY_BLOCK_SIZE | Yes | Yes | Yes | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作 |
| 设置列属性NULL 或NOT NULL | Yes | Yes | Yes | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作 |
| 添加主键 | Yes* | Yes | Yes | Yes | 尽管允许 ALGORITHM=INPLACE ,但数据大幅重组,所以它仍然是一项昂贵的操作。 如果列定义必须转化NOT NULL,则不允许INPLACE |
| 删除并添加主键 | Yes | Yes | Yes | Yes | 在同一个 ALTER TABLE 语句删除就主键、添加新主键时,才允许inplace;数据大幅重组,所以它仍然是一项昂贵的操作。 |
| 删除主键 | No | Yes | No | Yes | 不允许并发DML,要拷贝表,而且如果没有在同一 ATLER TABLE 语句里同时添加主键则会收到限制 |
| 变更表字符集 | No | Yes | No | Yes | 如果新的字符集编码不同,重建表 |
ALGORITHM=COPY一定会发生拷贝表,只读。但ALGORITHM=INPLACEE也要可能发生拷贝表,但可以并发DML:datadir目录有足够的磁盘空间,能够放的下整张表,因为拷贝表的的操作是直接在数据目录下进行的。tmpdir目录足够存下索引一列的数据(如果是组合索引,当前临时排序文件一合并到原表上就会删除)innodb_online_alter_log_max_size变量所指定的大小,会引起DB_ONLINE_LOG_TOO_BIG 错误。默认为 128M,特别对于需要拷贝大表的alter操作,考虑临时加大该值,以此获得更大的日志缓存空间ALTER TABLE 之后,最好 ANALYZE TABLE tb1 去更新索引统计信息| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | mysql> select version(); +------------+ | version()| +------------+ | 5.6.30-log | +------------+ 1 row in set (0.00 sec) mysql> show create table sbtest1; CREATE TABLE `sbtest1` ( `id` int(10) unsigned NOT NULL AUTO_INCREMENT, `k` int(10) unsigned NOT NULL DEFAULT "0", `c` char(120) COLLATE utf8_bin NOT NULL DEFAULT "", `pad` char(60) COLLATE utf8_bin NOT NULL DEFAULT "", PRIMARY KEY (`id`), KEY `k_1` (`k`) ) ENGINE=InnoDB AUTO_INCREMENT=5000001 DEFAULT CHARSET=utf8 COLLATE=utf8_bin MAX_ROWS=1000000 mysql> show variables like "old_alter_table"; +-----------------+-------+ | Variable_name | Value | +-----------------+-------+ | old_alter_table | OFF | +-----------------+-------+ 1 row in set (0.00 sec) |
| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 | **SESSION1:** mysql> set old_alter_table=1; Query OK, 0 rows affected (0.00 sec) mysql> alter table sbtest1 drop index idx_k_1; Query OK, 5000000 rows affected (44.79 sec) Records: 5000000Duplicates: 0Warnings: 0 mysql> alter table sbtest1 add index idx_k_1(k); Query OK, 5000000 rows affected (1 min 11.29 sec) Records: 5000000Duplicates: 0Warnings: 0 **SESSION2:** mysql> select * from sbtest1 limit 1; +----+---------+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+ | id | k | c | pad | +----+---------+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+ |1 | 2481886 | 08566691963-88624...106334-50535565977 | 63188288836-9235114...351-49282961843 | +----+---------+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+ 1 row in set (0.00 sec) mysql> update sbtest1 set k=2481885 where id=1; Query OK, 1 row affected (45.16 sec) Rows matched: 1Changed: 1Warnings: 0 **SESSION3:** mysql> show processlist; +--------+-----------------+-----------+------------+---------+--------+---------------------------------+-----------------------------------------+ | Id | User| Host| db | Command | Time | State | Info| +--------+-----------------+-----------+------------+---------+--------+---------------------------------+-----------------------------------------+ | 118652 | root| localhost | confluence | Query | 19 | copy to tmp table | alter table sbtest1 add index k_1(k)| | 118666 | root| localhost | confluence | Query |3 | Waiting for table metadata lock | update sbtest1 set k=2481885 where id=1 | | 118847 | root| localhost | NULL | Query |0 | init| show processlist| +--------+-----------------+-----------+------------+---------+--------+---------------------------------+-----------------------------------------+ 4 rows in set (0.00 sec) 同时在datadir目录下可以看到 -rw-rw---- 1 mysql mysql 8.5K May 23 21:24 sbtest1.frm -rw-rw---- 1 mysql mysql 1.2G May 23 21:24 sbtest1.ibd -rw-rw---- 1 mysql mysql 8.5K May 23 20:48 #sql-1c6a_1cf7c.frm -rw-rw---- 1 mysql mysql 638M May 23 20:48 #sql-1c6a_1cf7c.ibd |
Waiting for table metadata lock。下面改成Online DDL方式| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 | **SESSION1** mysql> set old_alter_table=0; mysql> alter table sbtest1 drop index k_1; Query OK, 0 rows affected (0.01 sec) Records: 0Duplicates: 0Warnings: 0 索引秒删 mysql> alter table sbtest1 add index k_1(k); Query OK, 0 rows affected (13.99 sec) Records: 0Duplicates: 0Warnings: 0 **SESSION2** mysql> update sbtest1 set k=2481887 where id=1; Query OK, 1 row affected (0.00 sec) Rows matched: 1Changed: 1Warnings: 0 **SESSION3** mysql> show processlist; +--------+-----------------+-----------+------------+---------+--------+------------------------+--------------------------------------+ | Id | User| Host| db | Command | Time | State| Info | +--------+-----------------+-----------+------------+---------+--------+------------------------+--------------------------------------+ | 118652 | root| localhost | confluence | Query | 10 | altering table | alter table sbtest1 add index k_1(k) | | 118666 | root| localhost | confluence | Sleep |9 || NULL | | 118847 | root| localhost | NULL | Query |0 | init | show processlist | +--------+-----------------+-----------+------------+---------+--------+------------------------+--------------------------------------+ 4 rows in set (0.00 sec) |
| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | **SESSION1** mysql> select * from sbtest1 where c="long select before alter"; Empty set (4.36 sec) **SESSION2** mysql> alter table sbtest1 add index k_1(k); Query OK, 0 rows affected (16.28 sec) Records: 0Duplicates: 0Warnings: 0 **SESSION3** mysql> select * from sbtest1 where c="long select after alter execution but not complete"; Empty set (5.89 sec) **SESSION4** mysql> show processlist; +----+-----------------+-----------+------------+---------+------+---------------------------------+------------------------------------------------------------------------------------+ | Id | User| Host| db | Command | Time | State | Info | +----+-----------------+-----------+------------+---------+------+---------------------------------+------------------------------------------------------------------------------------+ |5 | root| localhost | confluence | Query |3 | Sending data| select * from sbtest1 where c="long select before alter" | |7 | root| localhost | NULL | Query |0 | init| show processlist | | 13 | root| localhost | confluence | Query |2 | Waiting for table metadata lock | alter table sbtest1 add index k_1(k) | | 14 | root| localhost | confluence | Query |1 | Waiting for table metadata lock | select * from sbtest1 where c="long select after alter execution but not complete" | +----+-----------------+-----------+------------+---------+------+---------------------------------+------------------------------------------------------------------------------------+ 5 rows in set (0.00 sec) |
| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 | **SESSION1** mysql> ALTER TABLE `sbtest2` ADD COLUMN `f_new_col1` int(11) NULL DEFAULT 0, ADD COLUMN `f_new_col2` varchar(32) NULL DEFAULT "" AFTER `f_new_col1`; Query OK, 0 rows affected (1 min 57.86 sec) Records: 0Duplicates: 0Warnings: 0 **SESSION2** mysql> update sbtest2 set c="update when add colomun ddl start" where c="33333"; Query OK, 0 rows affected (4.41 sec) Rows matched: 0Changed: 0Warnings: 0 **SESSION3** mysql> select * from sbtest2 where c="select when add colomun ddl start"; Empty set (3.44 sec) **SESSION4** mysql> show processlist; +-----+-----------------+-----------+------------+---------+------+---------------------------+------------------------------------------------------------------------------------------------------+ | Id| User| Host| db | Command | Time | State | Info | +-----+-----------------+-----------+------------+---------+------+---------------------------+------------------------------------------------------------------------------------------------------+ | 5 | root| localhost | confluence | Query |4 | altering table| ALTER TABLE `sbtest2`ADD COLUMN `f_new_col1` int(11) NULL DEFAULT 0, ADD COLUMN `f_new_col2` varch | | 7 | root| localhost | NULL | Query |0 | init| show processlist | | 161 | root| localhost | confluence | Query |2 | Searching rows for update | update sbtest2 set c="update when add colomun ddl start" where c="33333" | | 187 | root| localhost | confluence | Query |1 | Sending data| select * from sbtest2 where c="select when add colomun ddl start"| +-----+-----------------+-----------+------------+---------+------+---------------------------+------------------------------------------------------------------------------------------------------+ 5 rows in set (0.00 sec) |
| 1 2 | -rw-rw---- 1 mysql mysql 8.6K May 23 21:42 #sql-7055_5.frm -rw-rw---- 1 mysql mysql 112K May 23 21:42 #sql-ib21-16847116.ibd |
| 1 2 | ALTER TABLE `sbtest2` 4DROIP COLUMN `f_new_col1`, algorithm=copy; |
| 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | **SESSION1** mysql> ALTER TABLE sbtest2 4 CHANGE f_new_col2 f_new_col2 varchar(50) NULL DEFAULT "", algorithm=inplace ; ERROR 1846 (0A000): ALGORITHM=INPLACE is not supported. Reason: Cannot change column type INPLACE. Try ALGORITHM=COPY. 不支持INPLACE mysql> ALTER TABLE sbtest2 4 CHANGE f_new_col2 f_new_col2 varchar(50) NULL DEFAULT ""; **SESSION2** mysql> update sbtest2 set c="update when add colomun ddl start" where c="33333"; mysql> select * from sbtest2 where c="select when add colomun ddl start"; Empty set (3.79 sec) mysql> show processlist; +-----+-----------------+-----------+------------+---------+------+---------------------------------+----------------------------------------------------------------------------------+ | Id| User| Host| db | Command | Time | State | Info | +-----+-----------------+-----------+------------+---------+------+---------------------------------+----------------------------------------------------------------------------------+ | 5 | root| localhost | confluence | Query |5 | copy to tmp table | ALTER TABLE sbtest2 CHANGE f_new_col2 f_new_col2 varchar(50) NULL DEFAULT "" | | 7 | root| localhost | NULL | Query |0 | init| show processlist | | 161 | root| localhost | confluence | Query |4 | Waiting for table metadata lock | update sbtest2 set c="update when add colomun ddl start" where c="33333" | | 187 | root| localhost | confluence | Query |3 | Sending data| select * from sbtest2 where c="select when add colomun ddl start"| +-----+-----------------+-----------+------------+---------+------+---------------------------------+----------------------------------------------------------------------------------+ 5 rows in set (0.00 sec) |