Skip to content

Commit

Permalink
[release-15.0] BaseShowTablesWithSizes: optimize MySQL 8.0 query (#13375
Browse files Browse the repository at this point in the history
) (#13388)

* BaseShowTablesWithSizes: optimize MySQL 8.0 query

Signed-off-by: Shlomi Noach <[email protected]>

* adapt regular expression

Signed-off-by: Shlomi Noach <[email protected]>

* adapt regular expression, 2

Signed-off-by: Shlomi Noach <[email protected]>

* refactored query again to combat the many unit test query format assumptions

Signed-off-by: Shlomi Noach <[email protected]>

* use t.table_schema in GROUP BY. Although not strictly necessary this may be faster

Signed-off-by: Shlomi Noach <[email protected]>

* Support views in BaseShowTablesWithSizes for MySQL 8.0 (#13394)

* Support views in BaseShowTablesWithSizes for MySQL 8.0

Signed-off-by: Shlomi Noach <[email protected]>

* added test

Signed-off-by: Shlomi Noach <[email protected]>

* fixed test

Signed-off-by: Shlomi Noach <[email protected]>

* schema tracker: use null safe comparison

Signed-off-by: Andres Taylor <[email protected]>

---------

Signed-off-by: Shlomi Noach <[email protected]>
Signed-off-by: Andres Taylor <[email protected]>
Co-authored-by: Andres Taylor <[email protected]>

* BaseShowTables

Signed-off-by: Shlomi Noach <[email protected]>

---------

Signed-off-by: Shlomi Noach <[email protected]>
Signed-off-by: Andres Taylor <[email protected]>
Co-authored-by: Shlomi Noach <[email protected]>
Co-authored-by: Andres Taylor <[email protected]>
  • Loading branch information
3 people authored Jun 29, 2023
1 parent 053e0e7 commit af8b1ed
Show file tree
Hide file tree
Showing 2 changed files with 84 additions and 10 deletions.
44 changes: 34 additions & 10 deletions go/mysql/flavor_mysql.go
Original file line number Diff line number Diff line change
Expand Up @@ -341,17 +341,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 @@ -947,3 +948,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.BaseShowTables(), 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)
}

0 comments on commit af8b1ed

Please sign in to comment.