Add missing JOIN condition to index_stats view

Signed-off-by: Graham <gpe@openrs2.org>
Graham 2 years ago
parent d422934661
commit 448d06aee5
  1. 37
      archive/src/main/resources/org/openrs2/archive/migrations/V14__scopes_fix.sql

@ -0,0 +1,37 @@
-- @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(*) 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,
SUM(length(c.data) + 2) FILTER (WHERE c.id IS NOT NULL) AS size,
SUM(group_blocks(ig.group_id, length(c.data) + 2)) FILTER (WHERE c.id IS NOT NULL) 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
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;
Loading…
Cancel
Save