MySQL 5.7 introduces a change in the way we query for global variables and status variables: the INFORMATION_SCHEMA.(GLOBAL|SESSION)_(VARIABLES|STATUS) tables are now deprecated and empty. Instead, we are to use the respective performance_schema.(global|session)_(variables|status) tables.
But the change goes farther than that; there is also a security change. Oracle created a pitfall of 2 changes at the same time:
- Variables/status moved to a different table
- Privileges required on said table
As an example, my non-root user gets:
mysql> show session variables like 'tx_isolation'; ERROR 1142 (42000): SELECT command denied to user 'normal_user'@'my_host' for table 'session_variables'
Who gets affected by this? Nearly everyone and everything.
- Your Nagios will not be able to read status variables
- Your ORM will not be able to determine session variables
- Your replication user will fail connecting (see this post by Giuseppe)
- And most everyone else.
The problem with the above is that involves two unrelated changes to your setup, which are not entirely simple to coordinate:
- Change your app code to choose the correct schema (information_schema vs. performance_schema)
- GRANT the permissions on your database
Perhaps at this point you still do not consider this to be a problem. You may be thinking: well, let’s first prepare by creating the GRANTs, and once that is in place, we can, at our leisure, modify the code.
Not so fast. Can you really that simply create those GRANTs?
Migration woes
How do you migrate to a new MySQL version? You do not reinstall all your servers. You want an easy migration path, and that path is: introduce one or two slaves of a newer version, see that everything works to your satisfaction, slowly upgrade all your other slaves, eventually switchover/upgrade your master.
This should not be any different for 5.7. We would like to provision a 5.7 slave in our topologies and just see that everything works. Well, we have, and things don’t just work. Our Nagios stops working for that 5.7 slave. Orchestrator started complaining (by this time I’ve already fixed it to be more tolerant for the 5.7 problems so no crashes here).
I hope you see the problem by now.
You cannot issue a GRANT SELECT ON performance_schema.global_variables TO ‘…’ on your 5.6 master.
The table simply does not exist there, which means the statement will not go to binary logs, which means it will not replicate on your 5.7 slave, which means you will not be able to SHOW GLOBAL VARIABLES on your slave, which means everything remains broken.
Yes, you can issue this directly on your 5.7 slaves. It’s doable, but undesired. It’s ugly in terms of automation (and will quite possibly break some assumptions and sanity checks your automation uses); in terms of validity testing. It’s unfriendly to GTID (make sure to SET SQL_LOG_BIN=0 before that).
WHY in the first place?
It seems like a security thing. I’m not sure whether this was intended. So you prevent a SHOW GLOBAL VARIABLES for a normal user. Makes sense. And yet:
mysql> show global variables like 'hostname'; ERROR 1142 (42000): SELECT command denied to user 'normal_user'@'my_host' for table 'global_variables' mysql> select @@global.hostname; +---------------------+ | @@global.hostname | +---------------------+ | myhost.mydomain.com | +---------------------+ mysql> select @@version; +--------------+ | @@version | +--------------+ | 5.7.8-rc-log | +--------------+
Seems like I’m allowed access to that info after all. So it’s not strictly a security design decision. For status variable, I admit, I don’t have a similar workaround.
Solutions?
The following are meant to be solutions, but do not really solve the problem:
- SHOW commands. SHOW GLOBAL|SESSION VARIABLES|STATUS will work properly, and will implicitly know whether to provide the results via information_schema or performance_schema tables.
- But, aren’t we meant to be happier with SELECT queries? So that I can really do stuff that is smarter than LIKE ‘variable_name%’?
- And of course you cannot use SHOW in server side cursors. Your stored routines are in a mess now.
- This does not solve the GRANTs problem.
- show_compatibility_56: an introduced variable in 5.7, boolean. It truly is a time-travel-paradox novel in disguise, in multiple respects.
- Documentation introduces it, and says it is deprecated.
- time-travel-paradox :O
- But it actually works in 5.7.8 (latest)
- time-travel-paradox plot thickens
- Your automation scripts do not know in advance whether your MySQL has this variable
- Hence SELECT @@global.show_compatibility_56 will produce an error on 5.6
- But the “safe” way of SHOW GLOBAL VARIABLES LIKE ‘show_compatibility_56’ will fail on a privilege error on 5.7
- time-travel-paradox :O
- Actually advised by my colleague Simon J. Mudd, show_compatibility_56 defaults to OFF. I support this line of thought. Or else it’s old_passwords=1 all over again.
- show_compatibility_56 doesn’t solve the GRANTs problem.
- This does not solve any migration path. It just postpones the moment when I will hit the same problem. When I flip the variable from “1” to “0”, I’m back at square one.
- Documentation introduces it, and says it is deprecated.
Suggestion
I claim security is not the issue, as presented above. I claim Oracle will yet again fall into the trap of no-easy-way-to-migrate-to-GTID in 5.6 if the current solution is unchanged. I claim that there have been too many changes at once. Therefore, I suggest one of the alternative two flows:
- Flow 1: keep information_schema, later migration into performance_schema
- In 5.7, information_schema tables should still produce the data.
- No security constraints on information_schema
- Generate WARNINGs on reading from information_schema (“…this will be deprecated…”)
- performance_schema also available. With security constraints, whatever.
- In 5.8 remove information_schema tables; we are left with performance_schema only.
- Flow 2: easy migration into performance_schema:
- In 5.7, performance_schema tables should not require any special privileges. Any user can read from them.
- Keep show_compatibility_56 as it is.
- SHOW commands choose between information_schema or performance_schema on their own — just as things are done now.
- In 5.8, performance_schema tables will require SELECT privileges.
As always, I love the work done by the engineers; and I love how they listen to the community.
Comments are most welcome. Have I missed the simple solution here? Are there even more complications to these features? Thoughts on my suggested two flows?
[UPDATE 2015-08-19]
Please see this followup by Morgan Tocker of Oracle.
Interestingly, the upgrade document does not mention VARIABLES, or STATUS, or performance_schema, or information_schema
https://dev.mysql.com/doc/refman/5.7/en/upgrading-from-previous-series.html
And yet there’s this special section: http://dev.mysql.com/doc/refman/5.7/en/performance-schema-variable-table-migration.html
That page is in the wrong place. People who have no issues with the performance schema will not look at it, and since the upgrade page does not mention performance_schema (it is already scary enough as it is now) they would not be encouraged to look for it.
At least a link to the performance_schema migration page should be in the main upgrade doc.
Hi Shlomi!
Thanks for the feedback! Yes, the privileges required for PERFORMANCE_SCHEMA tables that are now used underneath legacy SHOW commands were incorrect. This was noticed internally and reported, but the fix did not make the 5.7.8 RC2 cutoff. The bug report is waiting proper documentation, but the fix for the following bug report fixes several PERFORMANCE_SCHEMA table privileges, including those affecting global variables:
http://bugs.mysql.com/bug.php?id=77702
I hope that helps!