mirror of
https://github.com/OPSnet/Gazelle.git
synced 2026-01-16 18:04:34 -05:00
report redundant and unused mysql indexes
This commit is contained in:
48
app/DB.php
48
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);
|
||||
}
|
||||
}
|
||||
|
||||
@@ -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,
|
||||
|
||||
@@ -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
|
||||
|
||||
@@ -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';
|
||||
|
||||
4
misc/docker/mysql/init/100-sys-select.sql
Normal file
4
misc/docker/mysql/init/100-sys-select.sql
Normal file
@@ -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'@'%';
|
||||
@@ -58,7 +58,14 @@ if [ -z "${MYSQL_INIT_DB-}" ]; then
|
||||
cat /opt/gazelle/mysql_schema.sql /opt/gazelle/mysql_data.sql
|
||||
cat <<EOF
|
||||
CREATE USER IF NOT EXISTS 'ro_$MYSQL_USER'@'%' IDENTIFIED BY 'ro_$MYSQL_PASSWORD';
|
||||
GRANT SELECT ON *.* TO 'ro_$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON performance_schema.table_io_waits_summary_by_index_usage TO '$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.schema_redundant_indexes TO '$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.schema_unused_indexes TO '$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.x\$schema_flattened_keys TO '$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON performance_schema.table_io_waits_summary_by_index_usage TO 'ro_$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.schema_redundant_indexes TO 'ro_$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.schema_unused_indexes TO 'ro_$MYSQL_USER'@'%';
|
||||
GRANT SELECT ON sys.x\$schema_flattened_keys TO 'ro_$MYSQL_USER'@'%';
|
||||
CREATE FUNCTION IF NOT EXISTS bonus_accrual(Size bigint, Seedtime float, Seeders integer)
|
||||
RETURNS float DETERMINISTIC NO SQL
|
||||
RETURN Size / pow(1024, 3) * (0.0433 + (0.07 * ln(1 + Seedtime/24)) / pow(greatest(Seeders, 1), 0.35));
|
||||
|
||||
@@ -0,0 +1,67 @@
|
||||
<?php
|
||||
|
||||
declare(strict_types=1);
|
||||
|
||||
use Phinx\Migration\AbstractMigration;
|
||||
|
||||
final class RemoveRedundantIndexes extends AbstractMigration {
|
||||
public function up(): void {
|
||||
$this->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();
|
||||
}
|
||||
}
|
||||
@@ -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(),
|
||||
|
||||
@@ -47,11 +47,13 @@
|
||||
<tr>
|
||||
<th>Index name</th>
|
||||
<th>Rows read</th>
|
||||
<th>Column list and cardinalities</th>
|
||||
</tr>
|
||||
{% for r in index_read %}
|
||||
<tr>
|
||||
<td>{{ r.INDEX_NAME }}</td>
|
||||
<td>{{ r.ROWS_READ|number_format }}</td>
|
||||
<td>{{ r.index_name }}</td>
|
||||
<td>{{ r.rows_read|number_format }}</td>
|
||||
<td>{{ r.column_list }}</td>
|
||||
</tr>
|
||||
{% endfor %}
|
||||
</table>
|
||||
|
||||
@@ -96,22 +96,82 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;}
|
||||
<h3>Tables lacking a primary key</h3>
|
||||
<div class="box pad">
|
||||
{% for table in site_info.tablesWithoutPK %}
|
||||
{% if loop.first %}
|
||||
{% if loop.first %}
|
||||
<ul class="stats nobullet">
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
<li><a href="/tools.php?action=db-mysql&table={{ table }}">{{ table }}</a></li>
|
||||
{% if loop.last %}
|
||||
{% if loop.last %}
|
||||
</ul>
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
{% else %}
|
||||
<p>All tables have a primary key defined</p>
|
||||
{% endfor %}
|
||||
</div>
|
||||
|
||||
<h3>Tables with redundant indexes</h3>
|
||||
<div class="box pad">
|
||||
{% for t in index.redundant %}
|
||||
{% if loop.first %}
|
||||
<div class="thin">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.</div>
|
||||
<table>
|
||||
<tr class="colhead">
|
||||
<td>Table</td>
|
||||
<td>Covering index</td>
|
||||
<td>Redundant index</td>
|
||||
<td>Covering read</td>
|
||||
<td>Redundant read</td>
|
||||
</tr>
|
||||
{% endif %}
|
||||
<tr>
|
||||
<td>{{ t.table_name }}</td>
|
||||
<td>{{ t.covering_index }}</td>
|
||||
<td>{{ t.redundant_index }}</td>
|
||||
<td>{{ t.covering_read|number_format }}</td>
|
||||
<td>{{ t.redundant_read|number_format }}</td>
|
||||
</tr>
|
||||
{% if loop.last %}
|
||||
</table>
|
||||
{% endif %}
|
||||
{% else %}
|
||||
<p>There are no redundant indexes on any of the tables</p>
|
||||
{% endfor %}
|
||||
</div>
|
||||
|
||||
<h3>Tables with unused indexes</h3>
|
||||
<div class="box pad">
|
||||
{% for t in index.unused %}
|
||||
{% if loop.first %}
|
||||
<div class="thin">The following indexes are unused. When removing an
|
||||
unused column, verify that it is not used to maintain a foreign key
|
||||
association.</div>
|
||||
<table>
|
||||
<tr class="colhead">
|
||||
<td>Table</td>
|
||||
<td>Index</td>
|
||||
<td>Columns and cardinality</td>
|
||||
</tr>
|
||||
{% endif %}
|
||||
<tr>
|
||||
<td>{{ t.table_name }}</td>
|
||||
<td>{{ t.index_name }}</td>
|
||||
<td>{{ t.column_list }}</td>
|
||||
</tr>
|
||||
{% if loop.last %}
|
||||
</table>
|
||||
{% endif %}
|
||||
{% else %}
|
||||
<p>There are no unused indexes on any of the tables</p>
|
||||
{% endfor %}
|
||||
</div>
|
||||
|
||||
<h3>Tables with duplicate foreign keys</h3>
|
||||
<div class="box pad">
|
||||
{% for table in site_info.tablesWithDuplicateForeignKeys %}
|
||||
{% if loop.first %}
|
||||
{% if loop.first %}
|
||||
<div class="thin">The following tables have redundant foreign key definitions.
|
||||
All but one of the definitions per table/column may safely be removed.</div><br />
|
||||
<table>
|
||||
@@ -122,7 +182,7 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;}
|
||||
<td>Referenced column</td>
|
||||
<td>Constraint name</td>
|
||||
</tr>
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
<tr>
|
||||
<td>{{ table.TABLE_NAME }}</td>
|
||||
<td>{{ table.COLUMN_NAME }}</td>
|
||||
@@ -133,9 +193,9 @@ div#phpinfo hr {width: 934px; background-color: #ccc; border: 0; height: 1px;}
|
||||
<tr>
|
||||
<td colspan="5">To correct: <tt>ALTER TABLE {{ table.TABLE_NAME }} DROP CONSTRAINT {{ table.CONSTRAINT_NAME }};</tt></td>
|
||||
</tr>
|
||||
{% if loop.last %}
|
||||
{% if loop.last %}
|
||||
</table>
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
{% else %}
|
||||
<p>All tables have a correct foreign keys</p>
|
||||
{% endfor %}
|
||||
|
||||
@@ -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);
|
||||
|
||||
@@ -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',
|
||||
);
|
||||
|
||||
Reference in New Issue
Block a user