当前位置:   article > 正文

MySQL 8.0.30新特性GIPK_mysql8.0.30

mysql8.0.30

从MySQL8.0.30开始,开始支持generated invisible primary keys(GIPK) ,局限于innodb引擎的表,即当开启GIPK特性后,创建无主键innodb表时,默认会在表中创建一个主键`my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT,PRIMARY KEY (`my_row_id`)字段。通过sql_generate_invisible_primary_key 控制是否开启GIPK特性,默认关闭。生成的主键不能更改,可以在 visible 和 invisible 之间进行转换,如果要使自动创建的显示主键invisible,可以执行:alter table  table_name alter column my_row_id set invisible,此期间会加MDL写锁(dml语句会加MDL读锁,alter会加MDL写锁,读写,写写排斥,隔离DML语句与DDL语句之间的操作的影响)

ps:开启新特性后,创建无主键的innodb表时,不支持创建或添加列、索引的命名为my_row_id

新特性测试:

  1. mysql> show global variables like 'sql_generate_invisible_primary_key'; 默认GIPK特性关闭状态
  2. +------------------------------------+-------+
  3. | Variable_name | Value |
  4. +------------------------------------+-------+
  5. | sql_generate_invisible_primary_key | OFF |
  6. +------------------------------------+-------+
  7. 1 row in set (0.00 sec)
  8. mysql> set global sql_generate_invisible_primary_key=ON;
  9. Query OK, 0 rows affected (0.00 sec)
  10. 重新连接
  11. mysql> create database rbac;
  12. Query OK, 1 row affected (0.01 sec)
  13. mysql> use rbac
  14. Database changed
  15. mysql> create table bj(id int);
  16. Query OK, 0 rows affected (0.04 sec)
  17. mysql> show create table bj;
  18. +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  19. | Table | Create Table |
  20. +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  21. | bj | CREATE TABLE `bj` (
  22. `my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT /*!80023 INVISIBLE */,
  23. `id` int DEFAULT NULL,
  24. PRIMARY KEY (`my_row_id`)
  25. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 |
  26. +-------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
  27. ###解析binlog同样有my_row_id字段信息###
  28. /usr/local/mysql/bin/mysqlbinlog -v mysql-binlog.000004|less
  29. CREATE TABLE `bj` (
  30. `my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT /*!80023 INVISIBLE */,
  31. `id` int DEFAULT NULL,
  32. PRIMARY KEY (`my_row_id`)
  33. )
  34. /*!*/;
  35. SET @@SESSION.GTID_NEXT= 'AUTOMATIC' /* added by mysqlbinlog */ /*!*/;
  36. DELIMITER ;
  37. ###插入测试数据
  38. mysql> insert into bj values(1);
  39. Query OK, 1 row affected (0.01 sec)
  40. mysql> select * from bj;
  41. +------+
  42. | id |
  43. +------+
  44. | 1 |
  45. +------+
  46. 1 row in set (0.00 sec)

结论:8.0.30版本及更新版本,开启GIPK特性后,创建无主键的innodb表,会自动创建一列pki:`my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT,PRIMARY KEY (`my_row_id`),默认不可见。

部署mysql测试环境

  1. [root@vm10-0-0-99 ~]# rz -re mysql-8.0.32-linux-glibc2.12-x86_64.tar.xz
  2. [root@vm10-0-0-99 ~]# tar xf mysql-8.0.32-linux-glibc2.12-x86_64.tar.xz
  3. [root@vm10-0-0-99 ~]# mv mysql-8.0.32-linux-glibc2.12-x86_64 mysql
  4. [root@vm10-0-0-99 ~]# mv mysql /usr/local/
  5. [root@vm10-0-0-99 ~]# mkdir -p /data/3306/data
  6. [root@vm10-0-0-99 ~]# useradd mysql
  7. [root@vm10-0-0-99 ~]# chown -R mysql.mysql /data/
  8. [root@vm10-0-0-99 ~]# /usr/local/mysql/bin/mysqld --initialize-insecure --user=mysql --basedir=/usr/local/mysql --datadir=/data/3306/data/
  9. /usr/local/mysql/bin/mysqld: error while loading shared libraries: libaio.so.1: cannot open shared object file: No such file or directory
  10. [root@vm10-0-0-99 ~]# yum install -y libaio
  11. [root@vm10-0-0-99 ~]# cat /data/3306/my.cnf
  12. [mysqld]
  13. user=mysql
  14. server_id=33061
  15. basedir=/usr/local/mysql
  16. datadir=/data/3306/data
  17. port=3306
  18. socket=/data/3306/mysql.sock
  19. log_error=/data/3306/data/mysql-error.log
  20. log-bin=/data/3306/data/mysql-binlog
  21. [root@vm10-0-0-99 ~]#/usr/local/mysql/bin/mysqld --defaults-file=/data/3306/my.cnf
  22. [root@vm10-0-0-99 ~]#/usr/local/mysql/bin/mysql -S /data/3306/mysql.sock
  23. [root@vm10-0-0-99 ~]# ss -lntup
  24. Netid State Recv-Q Send-Q Local Address:Port Peer Address:Port
  25. udp UNCONN 0 0 *:68 *:* users:(("dhclient",pid=4764,fd=6))
  26. udp UNCONN 0 0 *:111 *:* users:(("systemd",pid=1,fd=37))
  27. tcp LISTEN 0 128 *:22 *:* users:(("sshd",pid=4837,fd=3))
  28. tcp LISTEN 0 128 *:111 *:* users:(("systemd",pid=1,fd=36))
  29. tcp LISTEN 0 128 :::22 :::* users:(("sshd",pid=4837,fd=4))
  30. tcp LISTEN 0 70 :::33060 :::* users:(("mysqld",pid=16852,fd=20))
  31. tcp LISTEN 0 128 :::3306 :::* users:(("mysqld",pid=16852,fd=23))

###同版本搭建主从###

  1. #创建主从复制用户
  2. create user repl@'10.0.0.%' identified with mysql_native_password by '123'; --低版本mysql报错把密码插件去掉执行
  3. grant replication slave on *.* to repl@'10.0.0.%';
  4. #主库查看binlog pos点信息
  5. mysql> show master status;
  6. +---------------------+----------+--------------+------------------+-------------------+
  7. | File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
  8. +---------------------+----------+--------------+------------------+-------------------+
  9. | mysql-binlog.000001 | 674 | | | |
  10. +---------------------+----------+--------------+------------------+-------------------+
  11. 1 row in set (0.00 sec)
  12. #从库执行连接主库命令
  13. change master to master_host='10.0.0.99',master_user='repl',master_password='123',master_port=3306,master_log_file='mysql-binlog.000001',master_log_pos=674,master_connect_retry=10;
  14. start slave;
  15. show slave status\G;

###8.0.32从库### port 3306

###8.0.30从库### port 3307

###8.0.20从库### port 3308

###5.7.30从库### port 3309

架构图:

  1. 8.0.328.0.30开启此特性,8.0.205.7.30无此特性
  2. mysql> show global variables like 'sql_generate_invisible_primary_key';
  3. +------------------------------------+-------+
  4. | Variable_name | Value |
  5. +------------------------------------+-------+
  6. | sql_generate_invisible_primary_key | ON |
  7. +------------------------------------+-------+
  8. 1 row in set (0.00 sec)
  9. 主库创建无主键表
  10. mysql> create database rbac;
  11. Query OK, 1 row affected (0.01 sec)
  12. mysql> use rbac
  13. Database changed
  14. mysql> create table test(a int);
  15. Query OK, 0 rows affected (0.03 sec)
  16. mysql> create table dig_a(id int);
  17. Query OK, 0 rows affected (0.05 sec)
  18. #各版本从库正常回放
  19. mysql> show create table dig_a;
  20. +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  21. | Table | Create Table |
  22. +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  23. | dig_a | CREATE TABLE `dig_a` (
  24. `my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT /*!80023 INVISIBLE */,
  25. `id` int DEFAULT NULL,
  26. PRIMARY KEY (`my_row_id`)
  27. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci |
  28. +-------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  29. 1 row in set (0.00 sec)

结论1:高版本-->低版本复制,需要注意版本兼容性问题,字符集、排序规则、插件。

  1. 8.0.32 --> 5.7.30
  2. master binlog :
  3. SET @@session.character_set_client=255,@@session.collation_connection=255,@@session.collation_server=255 255为utf8mb4
  4. 从库不支持SET @@session.character_set_client=255,所以每个event前执行环境变量时会报错,导致主从中断,通过set global character_set_client无法持久化参数
  5. master my.cnf配置文件修改utf8mb3,重启生效。
  6. [mysqld]
  7. character-set-client-handshake = FALSE
  8. character-set-server = utf8
  9. collation-server = utf8_unicode_ci
  10. init_connect='SET NAMES utf8'
  11. [mysql]
  12. default-character-set=utf8mb3
  13. [client]
  14. default-character-set=utf8mb3
  15. 255对应的utf8mb4,33对应的是mb3,5.7支持设置为utf8mb4,但是不支持将此变量设置为255
  • 复制功能测试
  1. Master插入测试数据: my_row_id为不可见状态
  2. mysql> insert into dig_a values(1);
  3. Query OK, 1 row affected (0.01 sec)
  4. mysql> insert into dig_a values(2);
  5. Query OK, 1 row affected (0.01 sec)
  6. mysql> insert into dig_a values(3);
  7. Query OK, 1 row affected (0.01 sec)
  8. mysql> select * from dig_a;
  9. +------+
  10. | id |
  11. +------+
  12. | 1 |
  13. | 2 |
  14. | 3 |
  15. +------+
  16. mysql> delete from dig_a where my_row_id=1;
  17. Query OK, 1 row affected (0.00 sec)
  18. mysql> select * from dig_a;
  19. +------+
  20. | id |
  21. +------+
  22. | 2 |
  23. | 3 |
  24. +------+
  25. 2 rows in set (0.00 sec)
  26. mysql> update dig_a set id=22 where my_row_id=2;
  27. Query OK, 1 row affected (0.00 sec)
  28. Rows matched: 1 Changed: 1 Warnings: 0
  29. mysql> select * from dig_a;
  30. +------+
  31. | id |
  32. +------+
  33. | 22 |
  34. | 3 |
  35. +------+
  36. 2 rows in set (0.00 sec)
  37. mysql> insert into dig_a values(4);
  38. Query OK, 1 row affected (0.01 sec)
  39. mysql> insert into dig_a(my_row_id,id) values(5,5);
  40. Query OK, 1 row affected (0.01 sec)
  41. mysql> update dig_a set id=44 where my_row_id=4;
  42. Query OK, 1 row affected (0.01 sec)
  43. Rows matched: 1 Changed: 1 Warnings: 0
  44. mysql> delete from dig_a where my_row_id=3;
  45. Query OK, 1 row affected (0.01 sec)
  46. mysql> select * from dig_a;
  47. +-----------+------+
  48. | my_row_id | id |
  49. +-----------+------+
  50. | 1 | 1 |
  51. | 2 | 2 |
  52. | 4 | 44 |
  53. +-----------+------+
  54. 3 rows in set (0.00 sec)
  55. my_row_id visible可见状态:
  56. 清空表数据
  57. mysql> truncate dig_a;
  58. Query OK, 0 rows affected (0.05 sec)
  59. mysql> alter table dig_a alter column my_row_id set visible;
  60. Query OK, 0 rows affected (0.01 sec)
  61. Records: 0 Duplicates: 0 Warnings: 0
  62. mysql> insert into dig_a values(1);
  63. ERROR 1136 (21S01): Column count doesn't match value count at row 1 ---visible可见状态下不指定列插入报错
  64. mysql> insert into dig_a(id) values(1);
  65. Query OK, 1 row affected (0.01 sec)
  66. mysql> insert into dig_a(id) values(2);
  67. Query OK, 1 row affected (0.01 sec)
  68. mysql> insert into dig_a(id) values(3);
  69. Query OK, 1 row affected (0.01 sec)
  70. mysql> insert into dig_a(my_row_id,id) values(4,4);
  71. Query OK, 1 row affected (0.01 sec)
  72. mysql> update dig_a set id=44 where my_row_id=4;
  73. Query OK, 1 row affected (0.01 sec)
  74. Rows matched: 1 Changed: 1 Warnings: 0
  75. mysql> delete from dig_a where my_row_id=3;
  76. Query OK, 1 row affected (0.01 sec)
  77. mysql> select * from dig_a;
  78. +-----------+------+
  79. | my_row_id | id |
  80. +-----------+------+
  81. | 1 | 1 |
  82. | 2 | 2 |
  83. | 4 | 44 |
  84. +-----------+------+
  85. 3 rows in set (0.00 sec)

结论2:执行alter  ......  visible使my_row_id隐藏/显示的命令无gipk特性版本会报错

my_row_id 为visible可见状态下:insert 语句必须指定列插入,否则报错 ;update delete可以通过my_row_id进行查询、更新、删除操作   

my_row_id为invisible不可见状态下,DML语句正常  ,且可以通过my_row_id进行查询、更新和删除操作

  1. 使用自定义列代替my_row_id:
  2. mysql> alter table dig_a drop column my_row_id;
  3. ERROR 1235 (42000): This version of MySQL doesn't yet support 'existing primary key drop without adding a new primary key. In @@sql_generate_invisible_primary_key=ON mode table should have a primary key. Please add a new primary key to be able to drop existing primary key.'
  4. 在设置sql_generate_invisible_primary_key=ON的情况下,必须要有一个主键(存量表除外)
  5. mysql> set session sql_generate_invisible_primary_key=OFF;
  6. Query OK, 0 rows affected (0.00 sec)
  7. mysql> show variables like 'sql_generate_invisible_primary_key';
  8. +------------------------------------+-------+
  9. | Variable_name | Value |
  10. +------------------------------------+-------+
  11. | sql_generate_invisible_primary_key | OFF |
  12. +------------------------------------+-------+
  13. 1 row in set (0.00 sec)
  14. mysql> alter table dig_a drop column my_row_id;
  15. Query OK, 3 rows affected (0.06 sec)
  16. Records: 3 Duplicates: 0 Warnings: 0
  17. mysql> alter table dig_a add a int primary key auto_increment;
  18. Query OK, 0 rows affected (0.12 sec)
  19. Records: 0 Duplicates: 0 Warnings: 0
  20. mysql> select * from dig_a;
  21. +------+---+
  22. | id | a |
  23. +------+---+
  24. | 1 | 1 |
  25. | 2 | 2 |
  26. | 44 | 3 |
  27. +------+---+
  28. 3 rows in set (0.00 sec)
  29. mysql> desc dig_a;
  30. +-------+------+------+-----+---------+----------------+
  31. | Field | Type | Null | Key | Default | Extra |
  32. +-------+------+------+-----+---------+----------------+
  33. | id | int | YES | | NULL | |
  34. | a | int | NO | PRI | NULL | auto_increment |
  35. +-------+------+------+-----+---------+----------------+
  36. 2 rows in set (0.00 sec)

结论2:对于已经自动添加my_row_id的表,如需要使用自定义列代替my_row_id作为主键,可以先将set session sql_generate_invisible_primary_key=OFF;然后进行表结构变更

  1. DDL加列测试
  2. mysql> set session sql_generate_invisible_primary_key=ON;
  3. Query OK, 0 rows affected (0.00 sec)
  4. mysql> create table dig_b(id int not null default 0);
  5. Query OK, 0 rows affected (0.03 sec)
  6. mysql> show create table dig_b;
  7. +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  8. | Table | Create Table |
  9. +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  10. | dig_b | CREATE TABLE `dig_b` (
  11. `my_row_id` bigint unsigned NOT NULL AUTO_INCREMENT /*!80023 INVISIBLE */,
  12. `id` int NOT NULL DEFAULT '0',
  13. PRIMARY KEY (`my_row_id`)
  14. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci |
  15. +-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
  16. 1 row in set (0.00 sec)
  17. mysql> alter table dig_b add a int default 0 not null;
  18. Query OK, 0 rows affected (0.02 sec)
  19. Records: 0 Duplicates: 0 Warnings: 0
  20. mysql> select * from dig_b;
  21. +----+---+
  22. | id | a |
  23. +----+---+
  24. | 1 | 0 |
  25. | 2 | 0 |
  26. | 3 | 0 |
  27. +----+---+
  28. 3 rows in set (0.00 sec)
  29. mysql> alter table dig_b add index i_a(a);
  30. Query OK, 0 rows affected (0.09 sec)
  31. Records: 0 Duplicates: 0 Warnings: 0

结论3:其他非对列my_row_id的DDL语句,从库可以正常回放

集群2:测试mysql5.7.30 -→mysql8.0.32版本同步

架构图:

  1. ###从库开启GIPK特性###
  2. mysql> set global sql_generate_invisible_primary_key=ON;
  3. Query OK, 0 rows affected (0.31 sec)
  4. ###主库创建表###
  5. mysql> select version();
  6. +------------+
  7. | version() |
  8. +------------+
  9. | 5.7.30-log |
  10. +------------+
  11. 1 row in set (0.00 sec)
  12. mysql> create database rbac_2;
  13. Query OK, 1 row affected (0.01 sec)
  14. mysql> use rbac_2;
  15. Database changed
  16. mysql> create table dic(id int);
  17. Query OK, 0 rows affected (0.03 sec)
  18. ###从库查看表结构###
  19. mysql> show create table dic;
  20. +-------+-------------------------------------------------------------------------------------+
  21. | Table | Create Table |
  22. +-------+-------------------------------------------------------------------------------------+
  23. | dic | CREATE TABLE `dic` (
  24. `id` int DEFAULT NULL
  25. ) ENGINE=InnoDB DEFAULT CHARSET=latin1 |
  26. +-------+-------------------------------------------------------------------------------------+
  27. 从库开启gipk,主库(5.7.30)创建的表无主键的情况下,下游gipk特性失效,完全按照主库的表结构同步
  28. ###主库创建带有my_row_id字段的无主键innodb表###
  29. mysql> create table dic_2(my_row_id int,id int);
  30. Query OK, 0 rows affected (0.02 sec)
  31. 从库查询
  32. mysql> show create table dic_2;
  33. +-------+-----------------------------------------------------------------------------------------------------------------------+
  34. | Table | Create Table |
  35. +-------+-----------------------------------------------------------------------------------------------------------------------+
  36. | dic_2 | CREATE TABLE `dic_2` (
  37. `my_row_id` int DEFAULT NULL,
  38. `id` int DEFAULT NULL
  39. ) ENGINE=InnoDB DEFAULT CHARSET=latin1 |
  40. +-------+-----------------------------------------------------------------------------------------------------------------------+
  41. 从库不影响创建带有my_row_id敏感列名的表

结论4:在主库是没有此特性的情况下,从库(8.0.32)通过回放主库的binlog进行同步,gipk特性失效,且主库创建带有my_row_id关键字的列,从库回放不会报错

       测试:

用户由当前8.0.27升级至8.0.32版本后,之前无主键表是否可以进行ddl变更      MySQL8.0.32 GIPK开启无主键表DDL变更

测试:

由mysql 8.0.27 升级到mysql 8.0.32,测试功能是否正常

  1. #主从环境
  2. Master 8.0.27 10.0.0.99:3311
  3. Slave 8.0.27 10.0.0.115:3311
  4. ###升级Slave版本 8.0.27-->8.0.32###
  5. #安装新版本mysql 8.0.32
  6. rz -re mysql-8.0.32-linux-glibc2.12-x86_64.tar.xz
  7. #解压安装包
  8. tar -xf mysql-8.0.32-linux-glibc2.12-x86_64.tar.xz
  9. #mv到/usr/local/
  10. mv mysql-8.0.32-linux-glibc2.12-x86_64 mysql8032
  11. mv mysql8032/ /usr/local/
  12. #修改用户
  13. chown -R mysql.mysql /usr/local/mysql8032
  14. #关闭从库
  15. ps -ef|grep 3311
  16. kill pid
  17. #使用新版本mysqld_safe 指定 旧版本 配置文件(数据目录) 启动
  18. /usr/local/mysql8032/bin/mysqld_safe --defaults-file=/data/3311/my.cnf &
  19. [root@vm10-0-0-115 ~]# ps -ef|grep 3311
  20. root 35481 31967 0 11:12 pts/1 00:00:00 grep --color=auto 3311
  21. root 81003 1 0 Jul27 ? 00:00:00 /bin/sh /usr/local/mysql8032/bin/mysqld_safe --defaults-file=/data/3311/my.cnf
  22. mysql 81167 81003 0 Jul27 ? 00:02:02 /usr/local/mysql8032/bin/mysqld --defaults-file=/data/3311/my.cnf --basedir=/usr/local/mysql8027 --datadir=/data/3311/data --plugin-dir=/usr/local/mysql8027/lib/plugin --user=mysql --log-error=/data/3311/data/mysql-error.log --pid-file=vm10-0-0-115.pid --socket=/data/3311/mysql.sock --port=3311
  23. #启动mysql,验证是否升级成功
  24. /usr/local/mysql8032/bin/mysql -S /data/3311/mysql.sock
  25. Server version: 8.0.32 MySQL Community Server - GPL
  26. mysql> show global variables like 'sql_generate_invisible_primary_key';
  27. +------------------------------------+-------+
  28. | Variable_name | Value |
  29. +------------------------------------+-------+
  30. | sql_generate_invisible_primary_key | OFF |
  31. +------------------------------------+-------+
  32. 1 row in set (0.00 sec)
  33. #升级成功#

声明:本文内容由网友自发贡献,不代表【wpsshop博客】立场,版权归原作者所有,本站不承担相应法律责任。如您发现有侵权的内容,请联系我们。转载请注明出处:https://www.wpsshop.cn/w/不正经/article/detail/542101
推荐阅读
相关标签
  

闽ICP备14008679号