From bae5eabf8e4e417e427846fa8e50a69e04d908fb Mon Sep 17 00:00:00 2001 From: Spine Date: Wed, 23 Apr 2025 04:49:43 +0000 Subject: [PATCH] report redundant and unused mysql indexes --- app/DB.php | 48 ++++++++++++ app/SiteInfo.php | 11 ++- docker-compose.yml | 4 +- docs/01-MysqlRoles.txt | 8 +- .../docker/{mysql-home => mysql/home}/.my.cnf | 0 misc/docker/mysql/init/100-sys-select.sql | 4 + misc/docker/web/bootstrap-base.sh | 9 ++- ...0241210000000_remove_redundant_indexes.php | 67 ++++++++++++++++ sections/tools/data/site_info.php | 4 + templates/admin/mysql-table.twig | 6 +- templates/admin/site-info.twig | 76 +++++++++++++++++-- tests/phpunit/DbTest.php | 36 +++++++++ tests/phpunit/SiteInfoTest.php | 2 +- 13 files changed, 258 insertions(+), 17 deletions(-) rename misc/docker/{mysql-home => mysql/home}/.my.cnf (100%) create mode 100644 misc/docker/mysql/init/100-sys-select.sql create mode 100644 misc/my-migrations/20241210000000_remove_redundant_indexes.php diff --git a/app/DB.php b/app/DB.php index 21f9e82d2..09b0181bd 100644 --- a/app/DB.php +++ b/app/DB.php @@ -198,4 +198,52 @@ class DB extends Base { Direction::descending->value => Direction::descending, }; } + + public function redundantIndexList(): array { + self::$db->prepared_query(" + SELECT sri.table_name, + concat(sri.dominant_index_name, ' (', sri.dominant_index_columns, ')') AS covering_index, + concat(sri.redundant_index_name, ' (', sri.redundant_index_columns, ')') AS redundant_index, + coalesce(c.rows_read, 0) AS covering_read, + coalesce(r.rows_read, 0) AS redundant_read + FROM sys.schema_redundant_indexes sri + LEFT JOIN information_schema.index_statistics c + ON (c.table_name = sri.table_name and c.index_name = sri.dominant_index_name) + LEFT JOIN information_schema.index_statistics r + ON (r.table_name = sri.table_name and r.index_name = sri.redundant_index_name) + WHERE sri.table_schema = ? + ORDER BY table_name, covering_index, redundant_index + ", MYSQL_DB + ); + $list = []; + foreach (self::$db->to_array(false, MYSQLI_ASSOC, false) as $r) { + $r['covering_read'] = (int)$r['covering_read']; + $r['redundant_read'] = (int)$r['redundant_read']; + $list[] = $r; + } + return $list; + } + + public function unusedIndexList(): array { + self::$db->prepared_query(" + SELECT sui.object_name AS table_name, + sui.index_name, + group_concat( + concat(s.column_name, ' {', s.cardinality, '}') + ORDER BY s.seq_in_index + SEPARATOR ', ' + ) AS column_list + FROM sys.schema_unused_indexes sui + INNER JOIN information_schema.statistics s on ( + s.table_schema = sui.object_schema + AND s.table_name = sui.object_name + AND s.index_name = sui.index_name + ) + WHERE sui.object_schema = ? + GROUP BY table_name, index_name + ORDER BY table_name, index_name + ", MYSQL_DB + ); + return self::$db->to_array(false, MYSQLI_ASSOC, false); + } } diff --git a/app/SiteInfo.php b/app/SiteInfo.php index b6c204687..c2b0b1276 100644 --- a/app/SiteInfo.php +++ b/app/SiteInfo.php @@ -174,12 +174,19 @@ class SiteInfo extends Base { public function indexRowsRead(string $tableName): array { self::$db->prepared_query(" - SELECT DISTINCT s.INDEX_NAME, - coalesce(si.ROWS_READ, 0) as ROWS_READ + SELECT s.INDEX_NAME AS index_name, + coalesce(si.ROWS_READ, 0) AS rows_read, + group_concat( + concat(s.column_name, ' {', s.cardinality, '}') + ORDER BY s.seq_in_index + SEPARATOR ', ' + ) AS column_list FROM information_schema.statistics s LEFT JOIN information_schema.index_statistics si USING (TABLE_SCHEMA, TABLE_NAME, INDEX_NAME) WHERE s.TABLE_SCHEMA = ? AND s.TABLE_NAME = ? + GROUP BY index_name, + rows_read ORDER BY s.TABLE_NAME, s.INDEX_NAME = 'PRIMARY' DESC, coalesce(si.ROWS_READ, 0) DESC, diff --git a/docker-compose.yml b/docker-compose.yml index 1020daafc..441b2ce57 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -38,11 +38,13 @@ services: mysql: # remember to update misc/gitlab-ci.yml - image: percona:ps-8.0.40-31 + image: percona:ps-8.0.41-32 ports: - 127.0.0.1:36000:3306 volumes: - mysql-data:/var/lib/mysql + - ./misc/docker/mysql/home:/home/mysql + - ./misc/docker/mysql/init:/docker-entrypoint-initdb.d environment: - MYSQL_DATABASE=gazelle - MYSQL_USER=gazelle diff --git a/docs/01-MysqlRoles.txt b/docs/01-MysqlRoles.txt index 0617370c2..9a4252ec7 100644 --- a/docs/01-MysqlRoles.txt +++ b/docs/01-MysqlRoles.txt @@ -1,8 +1,8 @@ From: Spine To: Developers -Date: 2020-03-21 +Date: 2024-12-07 Subject: Orpheus Development Papers #1 - Mysql Roles -Version: 1 +Version: 2 The default Gazelle installation defines a single Mysql role (with full privileges) and used for everything: the website, Ocelot and Sphinx. If any @@ -68,3 +68,7 @@ GRANT CREATE TEMPORARY TABLES, DELETE, INSERT, SELECT, UPDATE ON `gazelle`.* TO GRANT DROP ON `gazelle`.`drives` TO 'www'@'localhost'; GRANT EXECUTE ON FUNCTION `gazelle`.`binomial_ci` TO 'www'@'localhost'; GRANT EXECUTE ON FUNCTION `gazelle`.`bonus_accrual` TO 'www'@'localhost'; +GRANT SELECT ON `sys`.`schema_unused_indexes` TO 'www'@'localhost'; +GRANT SELECT ON `performance_schema`.`table_io_waits_summary_by_index_usage` TO 'www'@'localhost'; +GRANT SELECT ON `sys`.`schema_redundant_indexes` TO 'www'@'localhost'; +GRANT SELECT ON `sys`.`x$schema_flattened_keys` TO 'www'@'localhost'; diff --git a/misc/docker/mysql-home/.my.cnf b/misc/docker/mysql/home/.my.cnf similarity index 100% rename from misc/docker/mysql-home/.my.cnf rename to misc/docker/mysql/home/.my.cnf diff --git a/misc/docker/mysql/init/100-sys-select.sql b/misc/docker/mysql/init/100-sys-select.sql new file mode 100644 index 000000000..cb5c164cc --- /dev/null +++ b/misc/docker/mysql/init/100-sys-select.sql @@ -0,0 +1,4 @@ +GRANT SELECT ON performance_schema.table_io_waits_summary_by_index_usage TO 'gazelle'@'%'; +GRANT SELECT ON sys.schema_redundant_indexes TO 'gazelle'@'%'; +GRANT SELECT ON sys.schema_unused_indexes TO 'gazelle'@'%'; +GRANT SELECT ON sys.x$schema_flattened_keys TO 'gazelle'@'%'; diff --git a/misc/docker/web/bootstrap-base.sh b/misc/docker/web/bootstrap-base.sh index 54ec14485..9882d82b9 100755 --- a/misc/docker/web/bootstrap-base.sh +++ b/misc/docker/web/bootstrap-base.sh @@ -58,7 +58,14 @@ if [ -z "${MYSQL_INIT_DB-}" ]; then cat /opt/gazelle/mysql_schema.sql /opt/gazelle/mysql_data.sql cat <table('api_tokens') + ->removeIndex('user_id') + ->save(); + $this->table('bookmarks_artists') + ->removeIndex('ArtistID') + ->save(); + $this->table('bookmarks_torrents') + ->addIndex('GroupID') + ->removeIndex(['UserID']) + ->removeIndexByName('groups_users') + ->save(); + $this->table('donations') + ->removeIndex('Time') + ->removeIndex('UserID') + ->save(); + $this->table('pm_conversations_users') + ->removeIndex('UserID') + ->save(); + $this->table('site_options') + ->removeIndex('Name') + ->save(); + $this->table('site_options') + ->addIndex(['Name'], ['unique' => true, 'name' => 'so_name_uidx']) + ->removeIndex('Name') + ->save(); + $this->table('users_history_ips') + ->removeIndex('UserID') + ->save(); + } + + public function down(): void { + $this->table('api_tokens') + ->addIndex(['user_id']) + ->save(); + $this->table('bookmarks_artists') + ->addIndex(['ArtistID']) + ->save(); + $this->table('bookmarks_torrents') + ->addIndex(['GroupID', 'UserID'], ['unique' => true, 'name' => 'groups_users']) + ->addIndex(['UserID']) + ->removeIndex(['GroupID']) + ->save(); + $this->table('donations') + ->addIndex(['Time']) + ->addIndex(['UserID']) + ->save(); + $this->table('pm_conversations_users') + ->addIndex(['UserID']) + ->save(); + $this->table('site_options') + ->removeIndex('Name') + ->addIndex(['Name']) + ->addIndex(['Name'], ['unique' => 'true', 'name' => 'name_index']) + ->save(); + $this->table('users_history_ips') + ->addIndex(['UserID']) + ->save(); + } +} diff --git a/sections/tools/data/site_info.php b/sections/tools/data/site_info.php index 11e47465f..de7c4e78f 100644 --- a/sections/tools/data/site_info.php +++ b/sections/tools/data/site_info.php @@ -47,6 +47,10 @@ if (isset($_GET['mode']) && $_GET['mode'] === 'userrank') { 'egid' => gid(posix_getegid()), 'openssl_strong' => $strong, 'mysql_version' => $db->version(), + 'index' => [ + 'redundant' => $db->redundantIndexList(), + 'unused' => $db->unusedIndexList(), + ], 'pg_checkpoint' => $pg->checkpointInfo(), 'pg_version' => $pg->version(), 'php_version' => phpversion(), diff --git a/templates/admin/mysql-table.twig b/templates/admin/mysql-table.twig index e28d89621..2c40db4b6 100644 --- a/templates/admin/mysql-table.twig +++ b/templates/admin/mysql-table.twig @@ -47,11 +47,13 @@ Index name Rows read + Column list and cardinalities {% for r in index_read %} - {{ r.INDEX_NAME }} - {{ r.ROWS_READ|number_format }} + {{ r.index_name }} + {{ r.rows_read|number_format }} + {{ r.column_list }} {% endfor %} diff --git a/templates/admin/site-info.twig b/templates/admin/site-info.twig index 357b53855..c1b78d167 100644 --- a/templates/admin/site-info.twig +++ b/templates/admin/site-info.twig @@ -96,22 +96,82 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;}

Tables lacking a primary key

{% for table in site_info.tablesWithoutPK %} - {% if loop.first %} +{% if loop.first %}
    - {% endif %} +{% endif %}
  • {{ table }}
  • - {% if loop.last %} +{% if loop.last %}
- {% endif %} +{% endif %} {% else %}

All tables have a primary key defined

{% endfor %}
+

Tables with redundant indexes

+
+{% for t in index.redundant %} +{% if loop.first %} +
The following tables have redundant indexes (an index that + is covered by another wider index). If there are no reads from the redundant + index it is probably safe to drop it. It may also be worth determing whether + an index (a, b) should be rebuilt as (b, a). It is assumed that you know + what you are doing in either case.
+ + + + + + + + +{% endif %} + + + + + + + +{% if loop.last %} +
TableCovering indexRedundant indexCovering readRedundant read
{{ t.table_name }}{{ t.covering_index }}{{ t.redundant_index }}{{ t.covering_read|number_format }}{{ t.redundant_read|number_format }}
+{% endif %} +{% else %} +

There are no redundant indexes on any of the tables

+{% endfor %} +
+ +

Tables with unused indexes

+
+{% for t in index.unused %} +{% if loop.first %} +
The following indexes are unused. When removing an + unused column, verify that it is not used to maintain a foreign key + association.
+ + + + + + +{% endif %} + + + + + +{% if loop.last %} +
TableIndexColumns and cardinality
{{ t.table_name }}{{ t.index_name }}{{ t.column_list }}
+{% endif %} +{% else %} +

There are no unused indexes on any of the tables

+{% endfor %} +
+

Tables with duplicate foreign keys

{% for table in site_info.tablesWithDuplicateForeignKeys %} - {% if loop.first %} +{% if loop.first %}
The following tables have redundant foreign key definitions. All but one of the definitions per table/column may safely be removed.

@@ -122,7 +182,7 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;} - {% endif %} +{% endif %} @@ -133,9 +193,9 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;} - {% if loop.last %} +{% if loop.last %}
Referenced column Constraint name
{{ table.TABLE_NAME }} {{ table.COLUMN_NAME }}
To correct: ALTER TABLE {{ table.TABLE_NAME }} DROP CONSTRAINT {{ table.CONSTRAINT_NAME }};
- {% endif %} +{% endif %} {% else %}

All tables have a correct foreign keys

{% endfor %} diff --git a/tests/phpunit/DbTest.php b/tests/phpunit/DbTest.php index f35608907..d5face3b3 100644 --- a/tests/phpunit/DbTest.php +++ b/tests/phpunit/DbTest.php @@ -3,6 +3,7 @@ namespace Gazelle; use PHPUnit\Framework\TestCase; +use PHPUnit\Framework\Attributes\Group; use GazelleUnitTest\Helper; use Gazelle\Enum\Direction; @@ -152,6 +153,40 @@ class DbTest extends TestCase { $this->assertEquals(0, (new DB())->longRunning(), 'db-long-running'); } + public function testIndexLists(): void { + $tableName = 'phpunit_' . randomString(10); + $dbh = DB::DB(); + $dbh->prepared_query(" + CREATE TABLE $tableName ( + phpunit_id int PRIMARY KEY, + t1 int, + t2 int, + key (t1, t2), + key (t1) + ) + "); + $db = new DB(); + + $list = array_filter($db->redundantIndexList(), fn ($t) => $t['table_name'] === $tableName); + $this->assertCount(1, $list, 'db-index-redundant'); + $redundant = current($list); + $this->assertEquals($tableName, $redundant['table_name'], 'redundant-table-name'); + $this->assertEquals('t1 (t1,t2)', $redundant['covering_index'], 'covering-index-name'); + $this->assertEquals('t1_2 (t1)', $redundant['redundant_index'], 'redundant-index-name'); + $this->assertEquals(0, $redundant['redundant_read'], 'redundant-redundant-read'); + $this->assertEquals(0, $redundant['covering_read'], 'redundant-covering-read'); + + $list = array_filter($db->unusedIndexList(), fn ($t) => $t['table_name'] === $tableName); + $this->assertCount(2, $list, 'db-index-unused'); + $unused = current($list); + $this->assertEquals($tableName, $unused['table_name'], 'unused-table-name'); + $this->assertEquals('t1', $unused['index_name'], 'unused-index-name'); + $this->assertEquals('t1 {0}, t2 {0}', $unused['column_list'], 'unused-column-list'); + $dbh->prepared_query(" + DROP TABLE $tableName + "); + } + public function testPgBasic(): void { $this->assertInstanceOf(\PDO::class, $this->pg()->pdo(), 'db-pg-pdo'); $num = random_int(100, 999); @@ -322,6 +357,7 @@ class DbTest extends TestCase { "); } + #[Group('no-ci')] public function testMysqlWrite(): void { $db = DB::DB(readWrite: false); $this->expectException(\mysqli_sql_exception::class); diff --git a/tests/phpunit/SiteInfoTest.php b/tests/phpunit/SiteInfoTest.php index 1b16de9f5..4001ceecb 100644 --- a/tests/phpunit/SiteInfoTest.php +++ b/tests/phpunit/SiteInfoTest.php @@ -31,7 +31,7 @@ class SiteInfoTest extends TestCase { 'siteinfo-table-read' ); $this->assertEquals( - ['INDEX_NAME', 'ROWS_READ'], + ['index_name', 'rows_read', 'column_list'], array_keys($info->indexRowsRead('users_main')[0]), 'siteinfo-index-read', );