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

[release-17.0] BaseShowTablesWithSizes: optimize MySQL 8.0 query (#13375) #13390

Merged
merged 6 commits into from
Jun 28, 2023
Merged
Show file tree
Hide file tree
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
44 changes: 34 additions & 10 deletions go/mysql/flavor_mysql.go
Original file line number Diff line number Diff line change
Expand Up @@ -345,17 +345,41 @@ 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)
// - `create_options` is NULL for views, and therefore we need an additional UNION ALL to include views
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
WHERE
t.table_schema = database() AND not 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
50 changes: 50 additions & 0 deletions go/vt/vttablet/endtoend/misc_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,7 @@ import (
"context"
"fmt"
"io"
"math"
"net/http"
"reflect"
"strings"
Expand Down Expand Up @@ -944,3 +945,52 @@ func TestHexAndBitBindVar(t *testing.T) {
require.NoError(t, err)
assert.Equal(t, `[[INT64(10) UINT64(10) INT64(2480) UINT64(2480)]]`, fmt.Sprintf("%v", qr.Rows))
}

// Test will validate drop view ddls.
func TestShowTablesWithSizes(t *testing.T) {
ctx := context.Background()
conn, err := mysql.Connect(ctx, &connParams)
require.NoError(t, err)
defer conn.Close()

setupQueries := []string{
`drop view if exists show_tables_with_sizes_v1`,
`drop table if exists show_tables_with_sizes_t1`,
`drop table if exists show_tables_with_sizes_employees`,
`create table show_tables_with_sizes_t1 (id int primary key)`,
`create view show_tables_with_sizes_v1 as select * from show_tables_with_sizes_t1`,
`CREATE TABLE show_tables_with_sizes_employees (id INT NOT NULL, store_id INT) PARTITION BY HASH(store_id) PARTITIONS 4`,
}

defer func() {
_, _ = conn.ExecuteFetch(`drop view if exists show_tables_with_sizes_v1`, 1, false)
_, _ = conn.ExecuteFetch(`drop table if exists show_tables_with_sizes_t1`, 1, false)
_, _ = conn.ExecuteFetch(`drop table if exists show_tables_with_sizes_employees`, 1, false)
}()
for _, query := range setupQueries {
_, err := conn.ExecuteFetch(query, 1, false)
require.NoError(t, err)
}
expectTables := map[string]([]string){ // TABLE_TYPE, TABLE_COMMENT
"show_tables_with_sizes_t1": {"BASE TABLE", ""},
"show_tables_with_sizes_v1": {"VIEW", "VIEW"},
"show_tables_with_sizes_employees": {"BASE TABLE", ""},
}

rs, err := conn.ExecuteFetch(conn.BaseShowTablesWithSizes(), math.MaxInt, false)
require.NoError(t, err)
require.NotEmpty(t, rs.Rows)

assert.GreaterOrEqual(t, len(rs.Rows), len(expectTables))
matchedTables := map[string]bool{}
for _, row := range rs.Rows {
tableName := row[0].ToString()
vals, ok := expectTables[tableName]
if ok {
assert.Equal(t, vals[0], row[1].ToString()) // TABLE_TYPE
assert.Equal(t, vals[1], row[3].ToString()) // TABLE_COMMENT
matchedTables[tableName] = true
}
}
assert.Equalf(t, len(expectTables), len(matchedTables), "%v", matchedTables)
}