Compare commits

...

4 Commits

Author SHA1 Message Date
Graham 3e2d6ee0ec Fix right-aligned columns 2 years ago
Graham 0158bc937b Add archive/index sizes and completion percentages to legacy cache pages 2 years ago
Graham aa316e273d Split version_list_stats table by index 2 years ago
Graham ee61999c6f Ensure size and block columns in index_stats are always non-NULL 2 years ago
  1. 94
      archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt
  2. 95
      archive/src/main/resources/org/openrs2/archive/migrations/V16__empty_index_size.sql
  3. 53
      archive/src/main/resources/org/openrs2/archive/migrations/V17__split_version_list_stats.sql
  4. 10
      archive/src/main/resources/org/openrs2/archive/templates/caches/index.html
  5. 70
      archive/src/main/resources/org/openrs2/archive/templates/caches/show.html

@ -77,12 +77,12 @@ public class CacheExporter @Inject constructor(
public val diskStoreValid: Boolean = blocks <= DiskStore.MAX_BLOCK
}
public data class Index(
public data class Archive(
val resolved: Boolean,
val stats: IndexStats?
val stats: ArchiveStats?
)
public data class IndexStats(
public data class ArchiveStats(
val validGroups: Long,
val groups: Long,
val validKeys: Long,
@ -107,6 +107,21 @@ public class CacheExporter @Inject constructor(
}
}
public data class IndexStats(
val validFiles: Long,
val files: Long,
val size: Long,
val blocks: Long
) {
public val allFilesValid: Boolean = files == validFiles
public val validFilesFraction: Double = if (files == 0L) {
1.0
} else {
validFiles.toDouble() / files
}
}
public data class Build(val major: Int, val minor: Int?) : Comparable<Build> {
override fun compareTo(other: Build): Int {
return compareValuesBy(this, other, Build::major, Build::minor)
@ -158,7 +173,8 @@ public class CacheExporter @Inject constructor(
val sources: List<Source>,
val updates: List<String>,
val stats: Stats?,
val indexes: List<Index>,
val archives: List<Archive>,
val indexes: List<IndexStats>?,
val masterIndex: Js5MasterIndex?,
val checksumTable: ChecksumTable?
)
@ -410,43 +426,81 @@ public class CacheExporter @Inject constructor(
}
}
val indexes = mutableListOf<Index>()
val archives = mutableListOf<Archive>()
connection.prepareStatement(
"""
SELECT c.id IS NOT NULL, s.valid_groups, s.groups, s.valid_keys, s.keys, s.size, s.blocks
SELECT a.archive_id, c.id IS NOT NULL, s.valid_groups, s.groups, s.valid_keys, s.keys, s.size, s.blocks
FROM master_index_archives a
LEFT JOIN resolve_index((SELECT id FROM scopes WHERE name = ?), a.archive_id, a.crc32, a.version) c ON TRUE
LEFT JOIN index_stats s ON s.container_id = c.id
WHERE a.master_index_id = ?
ORDER BY a.archive_id ASC
UNION ALL
SELECT a.archive_id, b.id IS NOT NULL, NULL, NULL, NULL, NULL, length(b.data), group_blocks(a.archive_id, length(b.data))
FROM crc_table_archives a
LEFT JOIN resolve_archive(a.archive_id, a.crc32) b ON TRUE
WHERE a.crc_table_id = ?
ORDER BY archive_id ASC
""".trimIndent()
).use { stmt ->
stmt.setString(1, scope)
stmt.setInt(2, id)
stmt.setInt(3, id)
stmt.executeQuery().use { rows ->
while (rows.next()) {
val resolved = rows.getBoolean(1)
val validGroups = rows.getLong(2)
val indexStats = if (!rows.wasNull()) {
val groups = rows.getLong(3)
val validKeys = rows.getLong(4)
val keys = rows.getLong(5)
val size = rows.getLong(6)
val blocks = rows.getLong(7)
IndexStats(validGroups, groups, validKeys, keys, size, blocks)
val resolved = rows.getBoolean(2)
val size = rows.getLong(7)
val archiveStats = if (!rows.wasNull()) {
val validGroups = rows.getLong(3)
val groups = rows.getLong(4)
val validKeys = rows.getLong(5)
val keys = rows.getLong(6)
val blocks = rows.getLong(8)
ArchiveStats(validGroups, groups, validKeys, keys, size, blocks)
} else {
null
}
indexes += Index(resolved, indexStats)
archives += Archive(resolved, archiveStats)
}
}
}
Cache(id, sources, updates, stats, indexes, masterIndex, checksumTable)
val indexes = if (checksumTable != null && archives[5].resolved) {
connection.prepareStatement(
"""
SELECT s.valid_files, s.files, s.size, s.blocks
FROM crc_table_archives a
JOIN resolve_archive(a.archive_id, a.crc32) b ON TRUE
JOIN version_list_stats s ON s.blob_id = b.id
WHERE a.crc_table_id = ? AND a.archive_id = 5
ORDER BY s.index_id ASC
""".trimIndent()
).use { stmt ->
stmt.setInt(1, id)
stmt.executeQuery().use { rows ->
val indexes = mutableListOf<IndexStats>()
while (rows.next()) {
val validFiles = rows.getLong(1)
val files = rows.getLong(2)
val size = rows.getLong(3)
val blocks = rows.getLong(4)
indexes += IndexStats(validFiles, files, size, blocks)
}
indexes
}
}
} else {
null
}
Cache(id, sources, updates, stats, archives, indexes, masterIndex, checksumTable)
}
}
@ -487,7 +541,7 @@ public class CacheExporter @Inject constructor(
val name = StringBuilder("$game-$environment-$language")
val builds = rows.getArray(4).array as Array<*>
for (build in builds.mapNotNull { o -> Build.fromPgObject(o as PGobject) }.toSortedSet()) {
for (build in builds.mapNotNull { o -> CacheExporter.Build.fromPgObject(o as PGobject) }.toSortedSet()) {
name.append("-b")
name.append(build)
}

@ -0,0 +1,95 @@
-- @formatter:off
CREATE MATERIALIZED VIEW index_stats_new (
scope_id,
archive_id,
container_id,
valid_groups,
groups,
valid_keys,
keys,
size,
blocks
) AS
SELECT
s.id AS scope_id,
g.group_id AS archive_id,
i.container_id,
COUNT(*) FILTER (WHERE c.id IS NOT NULL) AS valid_groups,
COUNT(*) FILTER (WHERE ig.container_id IS NOT NULL) AS groups,
COUNT(*) FILTER (WHERE c.encrypted AND (c.key_id IS NOT NULL OR c.empty_loc)) AS valid_keys,
COUNT(*) FILTER (WHERE c.encrypted) AS keys,
COALESCE(SUM(length(c.data) + 2) FILTER (WHERE c.id IS NOT NULL), 0) AS size,
COALESCE(SUM(group_blocks(ig.group_id, length(c.data) + 2)) FILTER (WHERE c.id IS NOT NULL), 0) AS blocks
FROM scopes s
CROSS JOIN indexes i
JOIN groups g ON g.scope_id = s.id AND g.container_id = i.container_id AND g.archive_id = 255 AND
NOT g.version_truncated AND g.version = i.version
LEFT JOIN index_groups ig ON ig.container_id = i.container_id
LEFT JOIN resolve_group(s.id, g.group_id::uint1, ig.group_id, ig.crc32, ig.version) c ON TRUE
GROUP BY s.id, g.group_id, i.container_id;
CREATE UNIQUE INDEX ON index_stats_new (scope_id, archive_id, container_id);
ALTER MATERIALIZED VIEW index_stats RENAME TO index_stats_old;
ALTER INDEX index_stats_scope_id_archive_id_container_id_idx RENAME TO index_stats_old_scope_id_archive_id_container_id_idx;
ALTER MATERIALIZED VIEW index_stats_new RENAME TO index_stats;
ALTER INDEX index_stats_new_scope_id_archive_id_container_id_idx RENAME TO index_stats_scope_id_archive_id_container_id_idx;
CREATE MATERIALIZED VIEW master_index_stats_new (
scope_id,
master_index_id,
valid_indexes,
indexes,
valid_groups,
groups,
valid_keys,
keys,
size,
blocks
) AS
SELECT
sc.id,
m.id,
COUNT(*) FILTER (WHERE c.id IS NOT NULL OR (a.version = 0 AND a.crc32 = 0)) AS valid_indexes,
COUNT(*) FILTER (WHERE a.master_index_id IS NOT NULL) AS indexes,
SUM(COALESCE(s.valid_groups, 0)) AS valid_groups,
SUM(COALESCE(s.groups, 0)) AS groups,
SUM(COALESCE(s.valid_keys, 0)) AS valid_keys,
SUM(COALESCE(s.keys, 0)) AS keys,
SUM(COALESCE(s.size, 0)) + SUM(COALESCE(length(c.data), 0)) AS size,
SUM(COALESCE(s.blocks, 0)) + SUM(COALESCE(group_blocks(a.archive_id, length(c.data)), 0)) AS blocks
FROM scopes sc
CROSS JOIN master_indexes m
LEFT JOIN master_index_archives a ON a.master_index_id = m.id
LEFT JOIN resolve_index(sc.id, a.archive_id, a.crc32, a.version) c ON TRUE
LEFT JOIN index_stats s ON s.scope_id = sc.id AND s.archive_id = a.archive_id AND s.container_id = c.id
GROUP BY sc.id, m.id;
CREATE UNIQUE INDEX ON master_index_stats_new (scope_id, master_index_id);
ALTER MATERIALIZED VIEW master_index_stats RENAME TO master_index_stats_old;
ALTER INDEX master_index_stats_scope_id_master_index_id_idx RENAME TO master_index_stats_old_scope_id_master_index_id_idx;
ALTER MATERIALIZED VIEW master_index_stats_new RENAME TO master_index_stats;
ALTER INDEX master_index_stats_new_scope_id_master_index_id_idx RENAME TO master_index_stats_scope_id_master_index_id_idx;
CREATE OR REPLACE VIEW cache_stats AS
SELECT
s.id AS scope_id,
c.id AS cache_id,
COALESCE(ms.valid_indexes, cs.valid_archives) AS valid_indexes,
COALESCE(ms.indexes, cs.archives) AS indexes,
COALESCE(ms.valid_groups, cs.valid_files) AS valid_groups,
COALESCE(ms.groups, cs.files) AS groups,
COALESCE(ms.valid_keys, 0) AS valid_keys,
COALESCE(ms.keys, 0) AS keys,
COALESCE(ms.size, cs.size) AS size,
COALESCE(ms.blocks, cs.blocks) AS blocks
FROM scopes s
CROSS JOIN caches c
LEFT JOIN master_index_stats ms ON ms.scope_id = s.id AND ms.master_index_id = c.id
LEFT JOIN crc_table_stats cs ON s.name = 'runescape' AND cs.crc_table_id = c.id;
DROP MATERIALIZED VIEW master_index_stats_old;
DROP MATERIALIZED VIEW index_stats_old;

@ -0,0 +1,53 @@
-- @formatter:off
DROP VIEW cache_stats;
DROP MATERIALIZED VIEW crc_table_stats;
DROP MATERIALIZED VIEW version_list_stats;
CREATE MATERIALIZED VIEW version_list_stats AS
SELECT
v.blob_id,
vf.index_id,
COUNT(*) FILTER (WHERE b.id IS NOT NULL) AS valid_files,
COUNT(*) AS files,
SUM(length(b.data) + 2) FILTER (WHERE b.id IS NOT NULL) AS size,
SUM(group_blocks(vf.file_id, length(b.data) + 2)) AS blocks
FROM version_lists v
JOIN version_list_files vf ON vf.blob_id = v.blob_id
LEFT JOIN resolve_file(vf.index_id, vf.file_id, vf.version, vf.crc32) b ON TRUE
GROUP BY v.blob_id, vf.index_id;
CREATE UNIQUE INDEX ON version_list_stats (blob_id, index_id);
CREATE MATERIALIZED VIEW crc_table_stats AS
SELECT
c.id AS crc_table_id,
COUNT(*) FILTER (WHERE b.id IS NOT NULL AND a.crc32 <> 0) AS valid_archives,
COUNT(*) FILTER (WHERE a.crc32 <> 0) AS archives,
SUM(COALESCE(s.valid_files, 0)) AS valid_files,
SUM(COALESCE(s.files, 0)) AS files,
SUM(COALESCE(s.size, 0)) + SUM(COALESCE(length(b.data), 0)) AS size,
SUM(COALESCE(s.blocks, 0)) + SUM(COALESCE(group_blocks(a.archive_id, length(b.data)), 0)) AS blocks
FROM crc_tables c
LEFT JOIN crc_table_archives a ON a.crc_table_id = c.id
LEFT JOIN resolve_archive(a.archive_id, a.crc32) b ON TRUE
LEFT JOIN version_list_stats s ON s.blob_id = b.id
GROUP BY c.id;
CREATE UNIQUE INDEX ON crc_table_stats (crc_table_id);
CREATE VIEW cache_stats AS
SELECT
s.id AS scope_id,
c.id AS cache_id,
COALESCE(ms.valid_indexes, cs.valid_archives) AS valid_indexes,
COALESCE(ms.indexes, cs.archives) AS indexes,
COALESCE(ms.valid_groups, cs.valid_files) AS valid_groups,
COALESCE(ms.groups, cs.files) AS groups,
COALESCE(ms.valid_keys, 0) AS valid_keys,
COALESCE(ms.keys, 0) AS keys,
COALESCE(ms.size, cs.size) AS size,
COALESCE(ms.blocks, cs.blocks) AS blocks
FROM scopes s
CROSS JOIN caches c
LEFT JOIN master_index_stats ms ON ms.scope_id = s.id AND ms.master_index_id = c.id
LEFT JOIN crc_table_stats cs ON s.name = 'runescape' AND cs.crc_table_id = c.id;

@ -34,7 +34,7 @@
<td th:text="${cache.game}">runescape</td>
<td th:text="${cache.environment}">live</td>
<td th:text="${cache.language}">en</td>
<td class="text-right">
<td class="text-end">
<span th:each="build, it : ${cache.builds}" th:remove="tag">
<span th:text="${build}">550</span>
<br th:remove="${it.last}? 'all' : 'none'" />
@ -47,7 +47,7 @@
</td>
<td th:text="${#strings.setJoin(cache.sources, ', ')}"></td>
<td th:classappend="${cache.stats}? (${cache.stats.allIndexesValid}? 'table-success' : 'table-danger')"
class="text-right">
class="text-end">
<span
th:text="${cache.stats}? ${cache.stats.validIndexes} + '&nbsp;/&nbsp;' + ${cache.stats.indexes} : 'Calculating...'"></span>
<br />
@ -55,7 +55,7 @@
th:text="${cache.stats}? '(' + ${#numbers.formatPercent(cache.stats.validIndexesFraction, 1, 2)} + ')'"></span>
</td>
<td th:classappend="${cache.stats}? (${cache.stats.allGroupsValid}? 'table-success' : 'table-warning')"
class="text-right">
class="text-end">
<span
th:text="${cache.stats}? ${#numbers.formatInteger(cache.stats.validGroups, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(cache.stats.groups, 1, 'COMMA')} : 'Calculating...'"></span>
<br />
@ -63,7 +63,7 @@
th:text="${cache.stats}? '(' + ${#numbers.formatPercent(cache.stats.validGroupsFraction, 1, 2)} + ')'"></span>
</td>
<td th:classappend="${cache.stats}? (${cache.stats.allKeysValid}? 'table-success' : 'table-warning')"
class="text-right">
class="text-end">
<span
th:text="${cache.stats}? ${#numbers.formatInteger(cache.stats.validKeys, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(cache.stats.keys, 1, 'COMMA')} : 'Calculating...'"></span>
<br />
@ -72,7 +72,7 @@
</td>
<!--/*@thymesVar id="#byteunits" type="org.openrs2.archive.web.ByteUnits"*/-->
<td th:text="${cache.stats}? ${#byteunits.format(cache.stats.size)} : 'Calculating...'"
class="text-right">Calculating...
class="text-end">Calculating...
</td>
<td>
<div class="btn-group">

@ -102,7 +102,7 @@
<td th:text="${source.game}">runescape</td>
<td th:text="${source.environment}">live</td>
<td th:text="${source.language}">en</td>
<td th:text="${source.build}" class="text-right">550</td>
<td th:text="${source.build}" class="text-end">550</td>
<td th:text="${#temporals.format(source.timestamp, 'yyyy-MM-dd HH:mm:ss')}"></td>
<td th:text="${source.name}"></td>
<td th:text="${source.description}"></td>
@ -130,28 +130,28 @@
</tr>
</thead>
<tbody>
<tr th:each="entry, it : ${cache.masterIndex.entries}" th:with="index=${cache.indexes[it.index]}">
<td th:text="${it.index}" class="text-right">0</td>
<td th:text="${#numbers.formatInteger(entry.version, 1, 'COMMA')}" class="text-right">0</td>
<td class="text-right">
<tr th:each="entry, it : ${cache.masterIndex.entries}" th:with="archive=${cache.archives[it.index]}">
<td th:text="${it.index}" class="text-end">0</td>
<td th:text="${#numbers.formatInteger(entry.version, 1, 'COMMA')}" class="text-end">0</td>
<td class="text-end">
<code th:text="${entry.checksum}">0</code>
</td>
<div th:switch="true" th:remove="tag">
<div th:case="${index.stats != null}" th:remove="tag">
<td th:classappend="${index.stats.allGroupsValid}? 'table-success' : 'table-warning'" class="text-right">
<span th:text="${#numbers.formatInteger(index.stats.validGroups, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(index.stats.groups, 1, 'COMMA')}"></span>
<div th:case="${archive.stats != null}" th:remove="tag">
<td th:classappend="${archive.stats.allGroupsValid}? 'table-success' : 'table-warning'" class="text-end">
<span th:text="${#numbers.formatInteger(archive.stats.validGroups, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(archive.stats.groups, 1, 'COMMA')}"></span>
<br />
<span th:text="'(' + ${#numbers.formatPercent(index.stats.validGroupsFraction, 1, 2)} + ')'"></span>
<span th:text="'(' + ${#numbers.formatPercent(archive.stats.validGroupsFraction, 1, 2)} + ')'"></span>
</td>
<td th:classappend="${index.stats.allKeysValid}? 'table-success' : 'table-warning'" class="text-right">
<span th:text="${#numbers.formatInteger(index.stats.validKeys, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(index.stats.keys, 1, 'COMMA')}"></span>
<td th:classappend="${archive.stats.allKeysValid}? 'table-success' : 'table-warning'" class="text-end">
<span th:text="${#numbers.formatInteger(archive.stats.validKeys, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(archive.stats.keys, 1, 'COMMA')}"></span>
<br />
<span th:text="'(' + ${#numbers.formatPercent(index.stats.validKeysFraction, 1, 2)} + ')'"></span>
<span th:text="'(' + ${#numbers.formatPercent(archive.stats.validKeysFraction, 1, 2)} + ')'"></span>
</td>
<!--/*@thymesVar id="#byteunits" type="org.openrs2.archive.web.ByteUnits"*/-->
<td th:text="${#byteunits.format(index.stats.size)}" class="text-right">0 B</td>
<td th:text="${#byteunits.format(archive.stats.size)}" class="text-end">0 B</td>
</div>
<div th:case="${index.resolved}" th:remove="tag">
<div th:case="${archive.resolved}" th:remove="tag">
<td class="text-center" colspan="3">Calculating...</td>
</div>
<div th:case="${entry.checksum != 0 || entry.version != 0}" th:remove="tag">
@ -176,18 +176,54 @@
<tr>
<th>Archive</th>
<th>Checksum</th>
<th>Size<sup><a href="/caches#size">2</a></sup></th>
</tr>
</thead>
<tbody>
<tr th:each="entry, it : ${cache.checksumTable.entries}">
<td th:text="${it.index}" class="text-right">0</td>
<td class="text-right">
<tr th:each="entry, it : ${cache.checksumTable.entries}" th:with="archive=${cache.archives[it.index]}">
<td th:text="${it.index}" class="text-end">0</td>
<td class="text-end">
<code th:text="${entry}">0</code>
</td>
<div th:switch="true" th:remove="tag">
<!--/*@thymesVar id="#byteunits" type="org.openrs2.archive.web.ByteUnits"*/-->
<td th:case="${archive.stats != null}" th:text="${#byteunits.format(archive.stats.size)}" class="text-end">0 B</td>
<td th:case="${archive.resolved}" class="text-center">Calculating...</td>
<td th:case="${entry != 0}" class="text-center table-danger">Missing</td>
<td th:case="true" class="text-center text-muted">N/A</td>
</div>
</tr>
</tbody>
</table>
</div>
<div th:if="${cache.indexes}" th:remove="tag">
<h2>Version list</h2>
<div class="table-responsive">
<table class="table table-striped table-bordered table-hover">
<thead class="table-dark">
<tr>
<th>Index</th>
<th>Files</th>
<th>Size<sup><a href="/caches#size">2</a></sup></th>
</tr>
</thead>
<tbody>
<tr th:each="index, it : ${cache.indexes}">
<td th:text="${it.index + 1}" class="text-end">0</td>
<td th:classappend="${index.allFilesValid}? 'table-success' : 'table-warning'" class="text-end">
<span th:text="${#numbers.formatInteger(index.validFiles, 1, 'COMMA')} + '&nbsp;/&nbsp;' + ${#numbers.formatInteger(index.files, 1, 'COMMA')}"></span>
<br />
<span th:text="'(' + ${#numbers.formatPercent(index.validFilesFraction, 1, 2)} + ')'"></span>
</td>
<!--/*@thymesVar id="#byteunits" type="org.openrs2.archive.web.ByteUnits"*/-->
<td th:text="${#byteunits.format(index.size)}" class="text-end">0 B</td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
</main>
</body>

Loading…
Cancel
Save