This blog we describe an issue with MySQL 5.7’s super_read_only feature when used alongside with GTID in chained slave instances.
Background
In MySQL 5.7.5 and onward introduced the gtid_executed
table in the MySQL database to store every GTID. This allows slave instances to use the GTID feature regardless whether the binlog option is set or not. Here is an example of the rows in the gtid_executed
table:
mysql> SELECT * FROM mysql.gtid_executed; +--------------------------------------+----------------+--------------+ | source_uuid | interval_start | interval_end | +--------------------------------------+----------------+--------------+ | 00005730-1111-1111-1111-111111111111 | 1 | 1 | | 00005730-1111-1111-1111-111111111111 | 2 | 2 | | 00005730-1111-1111-1111-111111111111 | 3 | 3 | | 00005730-1111-1111-1111-111111111111 | 4 | 4 | | 00005730-1111-1111-1111-111111111111 | 5 | 5 | | 00005730-1111-1111-1111-111111111111 | 6 | 6 | | 00005730-1111-1111-1111-111111111111 | 7 | 7 | | 00005730-1111-1111-1111-111111111111 | 8 | 8 | | 00005730-1111-1111-1111-111111111111 | 9 | 9 | | 00005730-1111-1111-1111-111111111111 | 10 | 10 | ...
To save space, this table needs to be compressed periodically by replacing GTIDs rows with a single row that represents that interval of identifiers. For example, the above GTIDs can be represented with the following row:
mysql> SELECT * FROM mysql.gtid_executed; +--------------------------------------+----------------+--------------+ | source_uuid | interval_start | interval_end | +--------------------------------------+----------------+--------------+ | 00005730-1111-1111-1111-111111111111 | 1 | 10 | ...
On the other hand, we have the super_read_only
feature, if this option is set to ON, MySQL won’t allow any updates – even from users that have SUPER
privileges. It was first implemented on WebscaleSQL and later ported to Percona Server 5.6. MySQL mainstream code implemented a similar feature in version 5.7.8.
The Issue [1]
MySQL’s super_read_only
feature won’t allow the compression of the mysql.gtid_executed
table. If a high number of transactions run on the master instance, it causes the gtid_executed
table to grow to a considerable size. Let’s see an example.
I’m going to use the MySQL Sandbox to quickly setup a Master/Slave configuration, and sysbench to simulate a high number of transactions on master instance.
First, set up replication using GTID:
make_replication_sandbox --sandbox_base_port=5730 /opt/mysql/5.7.17 --how_many_nodes=1 --gtid
Next, set up the variables for a chained slave instance:
echo "super_read_only=ON" >> node1/my.sandbox.cnf echo "log_slave_updates=ON" >> node1/my.sandbox.cnf node1/restart
Now, generate a high number of transactions:
sysbench --test=oltp.lua --mysql-socket=/tmp/mysql_sandbox5730.sock --report-interval=1 --oltp-tables-count=100000 --oltp-table-size=100 --max-time=1800 --oltp-read-only=off --max-requests=0 --num-threads=8 --rand-type=uniform --db-driver=mysql --mysql-user=msandbox --mysql-password=msandbox --mysql-db=test prepare
After running sysbench for awhile, we check that the number of rows in the gtid_executed
table is increasing faster:
slave1 [localhost] {msandbox} ((none)) > select count(*) from mysql.gtid_executed ; +----------+ | count(*) | +----------+ | 300038 | +----------+ 1 row in set (0.00 sec)
By reviewing SHOW ENGINE INNODB STATUS
, we can find a compression thread running and trying to compress the gtid_executed
table.
---TRANSACTION 4192571, ACTIVE 0 sec fetching rows mysql tables in use 1, locked 1 9 lock struct(s), heap size 1136, 1533 row lock(s), undo log entries 1525 MySQL thread id 4, OS thread handle 139671027824384, query id 0 Compressing gtid_executed table
This thread runs and takes ages to complete (or may never complete). It has been reported as #84332.
The Issue [2]
What happens if you have to stop MySQL while the thread compressing the gtid_executed
table is running? In this special case, if you run the flush-logs
command before or at the same time as mysqladmin shutdown
, MySQL will actually stop accepting connections (all new connections hang waiting for the server) and will start to wait for the thread compressing the gtid_executed
table to complete its work. Below is an example.
First, execute the flush logs command and obtain ERROR 1290:
$ mysql -h 127.0.0.1 -P 5731 -u msandbox -pmsandbox -e "flush logs ;" ERROR 1290 (HY000): The MySQL server is running with the --super-read-only option so it cannot execute this statement
We’ve tried to shutdown the instance, but it hangs:
$ mysqladmin -h 127.0.0.1 -P 5731 -u msandbox -pmsandbox shutdown ^CWarning; Aborted waiting on pid file: 'mysql_sandbox5731.pid' after 175 seconds
This bug has been reported and verified as #84597.
The Workaround
If you already have an established connection to your database with SUPER
privileges, you can disable the super_read_only
feature dynamically. Once that is done, the pending thread compressing the gtid_executed
table completes its work and the shutdown finishes successfully. Below is an example.
We check rows in the gtid_executed
table:
$ mysql -h 127.0.0.1 -P 5731 -u msandbox -pmsandbox -e "select count(*) from mysql.gtid_executed ;" +----------+ | count(*) | +----------+ | 300038 | +----------+
We disable the super_read_only
feature on an already established connection:
$ mysql> set global super_read_only=OFF ;
We check the rows in the gtid_executed
table again, verifying that the compress thread ran successfully.
$ mysql -h 127.0.0.1 -P 5731 -u msandbox -pmsandbox -e "select count(*) from mysql.gtid_executed ;" +----------+ | count(*) | +----------+ | 1 | +----------+
Now we can shutdown the instance without issues:
$ mysqladmin -h 127.0.0.1 -P 5731 -u msandbox -pmsandbox shutdown
You can disable the super_read_only
feature before you shutdown the instance to compress the gtid_executed
table. If you ran into bug above, and don’t have any established connections to your database, the only way to shutdown the server is by issuing a kill -9
on the mysqld process.
Summary
As shown in this blog post, some of the mechanics of MySQL 5.7’s super_read_only
command are not working as expected. This can prevent some administrative operations, like shutdown
, from happening.
If you are using the super_read_only
feature on MySQL 5.7.17 or older, including Percona Server 5.7.16 or older (which ports the mainstream implementation – unlike Percona Server 5.6, which ported Webscale’s super_read_only
implementation) don’t use FLUSH LOGS
.