From fe705a0562dbccf57ff07bd4a611f8c8640521b8 Mon Sep 17 00:00:00 2001 From: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> Date: Sun, 25 Jun 2023 13:34:42 +0300 Subject: [PATCH 1/5] BaseShowTablesWithSizes: optimize MySQL 8.0 query Signed-off-by: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> --- go/mysql/flavor_mysql.go | 47 ++++++++++++++++++++++++++++++---------- 1 file changed, 36 insertions(+), 11 deletions(-) diff --git a/go/mysql/flavor_mysql.go b/go/mysql/flavor_mysql.go index 66bb0c46fab..3eec3ed7d78 100644 --- a/go/mysql/flavor_mysql.go +++ b/go/mysql/flavor_mysql.go @@ -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 { From 66c2dec3a82699ee99b9c471bd447d9ac372a878 Mon Sep 17 00:00:00 2001 From: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> Date: Mon, 26 Jun 2023 10:47:15 +0300 Subject: [PATCH 2/5] adapt regular expression Signed-off-by: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> --- go/vt/vttablet/tabletserver/schema/engine_test.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/go/vt/vttablet/tabletserver/schema/engine_test.go b/go/vt/vttablet/tabletserver/schema/engine_test.go index 591cae00705..25a32a3e97c 100644 --- a/go/vt/vttablet/tabletserver/schema/engine_test.go +++ b/go/vt/vttablet/tabletserver/schema/engine_test.go @@ -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") From 2a19b8aea4f38c25875a8e1e0fcd3b2edb598f1f Mon Sep 17 00:00:00 2001 From: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> Date: Mon, 26 Jun 2023 11:26:10 +0300 Subject: [PATCH 3/5] adapt regular expression, 2 Signed-off-by: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> --- go/vt/vttablet/tabletserver/query_executor_test.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/go/vt/vttablet/tabletserver/query_executor_test.go b/go/vt/vttablet/tabletserver/query_executor_test.go index 3ab653bf50c..520a29ed95f 100644 --- a/go/vt/vttablet/tabletserver/query_executor_test.go +++ b/go/vt/vttablet/tabletserver/query_executor_test.go @@ -1545,7 +1545,7 @@ func setUpQueryExecutorTest(t *testing.T) *fakesqldb.DB { return db } -const baseShowTablesPattern = `SELECT t\.table_name.*` +const baseShowTablesPattern = `[\s]*SELECT[\s]+(t|t1)[.]table_name.*` func initQueryExecutorTestDB(db *fakesqldb.DB) { addQueryExecutorSupportedQueries(db) From 7f8de65b406ecf09e31f4485583f446e4564afc9 Mon Sep 17 00:00:00 2001 From: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> Date: Mon, 26 Jun 2023 12:28:55 +0300 Subject: [PATCH 4/5] refactored query again to combat the many unit test query format assumptions Signed-off-by: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> --- go/mysql/flavor_mysql.go | 46 +++++++++---------- .../tabletserver/query_executor_test.go | 2 +- .../tabletserver/schema/engine_test.go | 2 +- 3 files changed, 24 insertions(+), 26 deletions(-) diff --git a/go/mysql/flavor_mysql.go b/go/mysql/flavor_mysql.go index 3eec3ed7d78..2683e3899ec 100644 --- a/go/mysql/flavor_mysql.go +++ b/go/mysql/flavor_mysql.go @@ -352,34 +352,32 @@ GROUP BY t.table_name, t.table_type, t.create_time, t.table_comment` // - 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 +const TablesWithSize80 = `SELECT t.table_name, + 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 - t1.table_schema = database() AND t1.create_options != 'partitioned' + t.table_schema = database() AND t.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 ) + 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 - t2.table_schema = database() AND t2.create_options = 'partitioned' + t.table_schema = database() AND t.create_options = 'partitioned' GROUP BY - t2.table_name, t2.table_type, t2.create_time, t2.table_comment + t.table_name, t.table_type, t.create_time, t.table_comment ` // baseShowTablesWithSizes is part of the Flavor interface. diff --git a/go/vt/vttablet/tabletserver/query_executor_test.go b/go/vt/vttablet/tabletserver/query_executor_test.go index 520a29ed95f..3ab653bf50c 100644 --- a/go/vt/vttablet/tabletserver/query_executor_test.go +++ b/go/vt/vttablet/tabletserver/query_executor_test.go @@ -1545,7 +1545,7 @@ func setUpQueryExecutorTest(t *testing.T) *fakesqldb.DB { return db } -const baseShowTablesPattern = `[\s]*SELECT[\s]+(t|t1)[.]table_name.*` +const baseShowTablesPattern = `SELECT t\.table_name.*` func initQueryExecutorTestDB(db *fakesqldb.DB) { addQueryExecutorSupportedQueries(db) diff --git a/go/vt/vttablet/tabletserver/schema/engine_test.go b/go/vt/vttablet/tabletserver/schema/engine_test.go index 25a32a3e97c..591cae00705 100644 --- a/go/vt/vttablet/tabletserver/schema/engine_test.go +++ b/go/vt/vttablet/tabletserver/schema/engine_test.go @@ -46,7 +46,7 @@ import ( querypb "vitess.io/vitess/go/vt/proto/query" ) -const baseShowTablesPattern = `[\s]*SELECT[\s]+(t|t1)[.]table_name.*` +const baseShowTablesPattern = `SELECT t\.table_name.*` var mustMatch = utils.MustMatchFn(".Mutex") From 3501ec9b335a32ac8d3cb160a9a32427003dc2d6 Mon Sep 17 00:00:00 2001 From: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> Date: Mon, 26 Jun 2023 12:30:45 +0300 Subject: [PATCH 5/5] use t.table_schema in GROUP BY. Although not strictly necessary this may be faster Signed-off-by: Shlomi Noach <2607934+shlomi-noach@users.noreply.github.com> --- go/mysql/flavor_mysql.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/go/mysql/flavor_mysql.go b/go/mysql/flavor_mysql.go index 2683e3899ec..789f7e30515 100644 --- a/go/mysql/flavor_mysql.go +++ b/go/mysql/flavor_mysql.go @@ -377,7 +377,7 @@ UNION ALL WHERE t.table_schema = database() AND t.create_options = 'partitioned' GROUP BY - t.table_name, t.table_type, t.create_time, t.table_comment + t.table_schema, t.table_name, t.table_type, t.create_time, t.table_comment ` // baseShowTablesWithSizes is part of the Flavor interface.