Use of a data dictionary-enabled MySQL server entails some operational differences compared to a server that does not have a data dictionary:
Previously, enabling the
innodb_read_only
system variable prevented creating and dropping tables only for theInnoDB
storage engine. As of MySQL 8.4, enablinginnodb_read_only
prevents these operations for all storage engines. Table creation and drop operations for any storage engine modify data dictionary tables in themysql
system database, but those tables use theInnoDB
storage engine and cannot be modified wheninnodb_read_only
is enabled. The same principle applies to other table operations that require modifying data dictionary tables. Examples:ANALYZE TABLE
fails because it updates table statistics, which are stored in the data dictionary.ALTER TABLE
fails because it updates the storage engine designation, which is stored in the data dictionary.tbl_name
ENGINE=engine_name
NoteEnabling
innodb_read_only
also has important implications for non-data dictionary tables in themysql
system database. For details, see the description ofinnodb_read_only
in Section 17.14, “InnoDB Startup Options and System Variables”Previously, tables in the
mysql
system database were visible to DML and DDL statements. As of MySQL 8.4, data dictionary tables are invisible and cannot be modified or queried directly. However, in most cases there are correspondingINFORMATION_SCHEMA
tables that can be queried instead. This enables the underlying data dictionary tables to be changed as server development proceeds, while maintaining a stableINFORMATION_SCHEMA
interface for application use.INFORMATION_SCHEMA
tables in MySQL 8.4 are closely tied to the data dictionary, resulting in several usage differences:Previously,
INFORMATION_SCHEMA
queries for table statistics in theSTATISTICS
andTABLES
tables retrieved statistics directly from storage engines. As of MySQL 8.4, cached table statistics are used by default. Theinformation_schema_stats_expiry
system variable defines the period of time before cached table statistics expire. The default is 86400 seconds (24 hours). (To update the cached values at any time for a given table, useANALYZE TABLE
.) If there are no cached statistics or statistics have expired, statistics are retrieved from storage engines when querying table statistics columns. To always retrieve the latest statistics directly from storage engines, setinformation_schema_stats_expiry
to0
. For more information, see Section 10.2.3, “Optimizing INFORMATION_SCHEMA Queries”.Several
INFORMATION_SCHEMA
tables are views on data dictionary tables, which enables the optimizer to use indexes on those underlying tables. Consequently, depending on optimizer choices, the row order of results forINFORMATION_SCHEMA
queries might differ from previous results. If a query result must have specific row ordering characteristics, include anORDER BY
clause.Queries on
INFORMATION_SCHEMA
tables may return column names in a different lettercase than in earlier MySQL series. Applications should test result set column names in case-insensitive fashion. If that is not feasible, a workaround is to use column aliases in the select list that return column names in the required lettercase. For example:SELECT TABLE_SCHEMA AS table_schema, TABLE_NAME AS table_name FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'users';
mysqldump no longer dumps the
INFORMATION_SCHEMA
database, even if explicitly named on the command line.CREATE TABLE
requires thatdst_tbl
LIKEsrc_tbl
src_tbl
be a base table and fails if it is anINFORMATION_SCHEMA
table that is a view on data dictionary tables.Previously, result set headers of columns selected from
INFORMATION_SCHEMA
tables used the capitalization specified in the query. This query produces a result set with a header oftable_name
:SELECT table_name FROM INFORMATION_SCHEMA.TABLES;
As of MySQL 8.4, these headers are capitalized; the preceding query produces a result set with a header of
TABLE_NAME
. If necessary, a column alias can be used to achieve a different lettercase. For example:SELECT table_name AS 'table_name' FROM INFORMATION_SCHEMA.TABLES;
The data directory affects how mysqldump dumps information from the
mysql
system database:mysqldump only dumps non-data dictionary tables in that database, when previously it was possible to dump all tables in the
mysql
system database.Previously, the
--routines
and--events
options were not required to include stored routines and events when using the--all-databases
option: The dump included themysql
system database, and therefore also theproc
andevent
tables containing stored routine and event definitions. As of MySQL 8.4, theevent
andproc
tables are not used. Definitions for the corresponding objects are stored in data dictionary tables, but those tables are not dumped. To include stored routines and events in a dump made using--all-databases
, use the--routines
and--events
options explicitly.Previously, the
--routines
option required theSELECT
privilege for theproc
table. As of MySQL 8.4, that table is not used;--routines
requires the globalSELECT
privilege instead.Previously, it was possible to dump stored routine and event definitions together with their creation and modification timestamps, by dumping the
proc
andevent
tables. As of MySQL 8.4, those tables are not used, so it is not possible to dump timestamps.
Previously, creating a stored routine that contains illegal characters produced a warning. As of MySQL 8.4, this is an error.