Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

BaseShowTablesWithSizes: optimize MySQL 8.0 query #13375

Merged
merged 5 commits into from
Jun 27, 2023
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
43 changes: 33 additions & 10 deletions go/mysql/flavor_mysql.go
Original file line number Diff line number Diff line change
Expand Up @@ -345,17 +345,40 @@ GROUP BY t.table_name, t.table_type, t.create_time, t.table_comment`
// We join with a subquery that materializes the data from `information_schema.innodb_sys_tablespaces`
// early for performance reasons. This effectively causes only a single read of `information_schema.innodb_tablespaces`
// per query.
// Note the following:
// - We use UNION ALL to deal differently with partitioned tables vs. non-partitioned tables.
// Originally, the query handled both, but that introduced "WHERE ... OR" conditions that led to poor query
// optimization. By separating to UNION ALL we remove all "OR" conditions.
// - We utilize `INFORMATION_SCHEMA`.`TABLES`.`CREATE_OPTIONS` column to do early pruning before the JOIN.
// - `TABLES`.`TABLE_NAME` has `utf8mb4_0900_ai_ci` collation. `INNODB_TABLESPACES`.`NAME` has `utf8mb3_general_ci`.
// We normalize the collation to get better query performance (we force the casting at the time of our choosing)
const TablesWithSize80 = `SELECT t.table_name,
t.table_type,
UNIX_TIMESTAMP(t.create_time),
t.table_comment,
SUM(i.file_size),
SUM(i.allocated_size)
FROM information_schema.tables t
LEFT JOIN information_schema.innodb_tablespaces i
ON i.name LIKE CONCAT(database(), '/%') AND (i.name = CONCAT(t.table_schema, '/', t.table_name) OR i.name LIKE CONCAT(t.table_schema, '/', t.table_name, '#p#%'))
WHERE t.table_schema = database()
GROUP BY t.table_name, t.table_type, t.create_time, t.table_comment`
t.table_type,
UNIX_TIMESTAMP(t.create_time),
t.table_comment,
i.file_size,
i.allocated_size
FROM information_schema.tables t
LEFT JOIN information_schema.innodb_tablespaces i
ON i.name = CONCAT(t.table_schema, '/', t.table_name) COLLATE utf8_general_ci
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Hm. Shouldn't we collate to at least a utf8mb4 collation, because that's a strict superset of utf8mb3, and thus all values valid in TABLES.TABLE_NAME can be handled?

Copy link
Contributor Author

@shlomi-noach shlomi-noach Jun 27, 2023

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The table name has a utf8mb3 character set, and so there is no point in converting to a utf8mb4-collation:

> select * from information_schema.columns where table_name='TABLES' and column_name='TABLE_NAME'\G
*************************** 1. row ***************************
           TABLE_CATALOG: def
            TABLE_SCHEMA: information_schema
              TABLE_NAME: TABLES
             COLUMN_NAME: TABLE_NAME
        ORDINAL_POSITION: 3
          COLUMN_DEFAULT: NULL
             IS_NULLABLE: YES
               DATA_TYPE: varchar
CHARACTER_MAXIMUM_LENGTH: 64
  CHARACTER_OCTET_LENGTH: 192
       NUMERIC_PRECISION: NULL
           NUMERIC_SCALE: NULL
      DATETIME_PRECISION: NULL
      CHARACTER_SET_NAME: utf8mb3
          COLLATION_NAME: utf8mb3_tolower_ci
             COLUMN_TYPE: varchar(64)

WHERE
t.table_schema = database() AND t.create_options != 'partitioned'
UNION ALL
SELECT
t.table_name,
t.table_type,
UNIX_TIMESTAMP(t.create_time),
t.table_comment,
SUM(i.file_size),
SUM(i.allocated_size)
FROM information_schema.tables t
LEFT JOIN information_schema.innodb_tablespaces i
ON i.name LIKE (CONCAT(t.table_schema, '/', t.table_name, '#p#%') COLLATE utf8_general_ci )
WHERE
t.table_schema = database() AND t.create_options = 'partitioned'
GROUP BY
t.table_schema, t.table_name, t.table_type, t.create_time, t.table_comment
`

// baseShowTablesWithSizes is part of the Flavor interface.
func (mysqlFlavor56) baseShowTablesWithSizes() string {
Expand Down