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
Show file tree
Hide file tree
Changes from 2 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
47 changes: 36 additions & 11 deletions go/mysql/flavor_mysql.go
Original file line number Diff line number Diff line change
Expand Up @@ -345,17 +345,42 @@ 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.
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`
// 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
t1.table_name,
t1.table_type,
UNIX_TIMESTAMP(t1.create_time),
t1.table_comment,
i1.file_size,
i1.allocated_size
FROM information_schema.tables t1
LEFT JOIN information_schema.innodb_tablespaces i1
ON i1.name = CONCAT(t1.table_schema, '/', t1.table_name) COLLATE utf8_general_ci
WHERE
t1.table_schema = database() AND t1.create_options != 'partitioned'
UNION ALL
SELECT
t2.table_name,
t2.table_type,
UNIX_TIMESTAMP(t2.create_time),
t2.table_comment,
SUM(i2.file_size),
SUM(i2.allocated_size)
FROM information_schema.tables t2
LEFT JOIN information_schema.innodb_tablespaces i2
ON i2.name LIKE (CONCAT(t2.table_schema, '/', t2.table_name, '#p#%') COLLATE utf8_general_ci )
WHERE
t2.table_schema = database() AND t2.create_options = 'partitioned'
GROUP BY
t2.table_name, t2.table_type, t2.create_time, t2.table_comment
`

// baseShowTablesWithSizes is part of the Flavor interface.
func (mysqlFlavor56) baseShowTablesWithSizes() string {
Expand Down
2 changes: 1 addition & 1 deletion go/vt/vttablet/tabletserver/schema/engine_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -46,7 +46,7 @@ import (
querypb "vitess.io/vitess/go/vt/proto/query"
)

const baseShowTablesPattern = `SELECT t\.table_name.*`
const baseShowTablesPattern = `[\s]*SELECT[\s]+(t|t1)[.]table_name.*`

var mustMatch = utils.MustMatchFn(".Mutex")

Expand Down