Add master_index_valid_{indexes,groups} views to reduce duplication

The CTE is now declared as NOT MATERIALIZED to ensure Postgres is able
to push the WHERE master_index_id condition inside it.

Signed-off-by: Graham <gpe@openrs2.org>
Graham 4 years ago
parent 60812f22eb
commit 5d8f89e319
  1. 50
      archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt
  2. 27
      archive/src/main/resources/org/openrs2/archive/V1__init.sql

@ -70,31 +70,12 @@ public class CacheExporter @Inject constructor(
} }
public suspend fun export(id: Long, store: Store) { public suspend fun export(id: Long, store: Store) {
// TODO(gpe): think about what to do if there is a collision
database.execute { connection -> database.execute { connection ->
connection.prepareStatement( connection.prepareStatement(
""" """
WITH t AS ( SELECT archive_id, group_id, data, version
SELECT a.archive_id, c.data, g.container_id FROM master_index_valid_groups
FROM master_indexes m WHERE master_index_id = ?
JOIN master_index_archives a ON a.master_index_id = m.id
JOIN groups g ON g.archive_id = 255 AND g.group_id = a.archive_id::INTEGER
AND g.version = a.version AND NOT g.version_truncated
JOIN containers c ON c.id = g.container_id AND c.crc32 = a.crc32
JOIN indexes i ON i.container_id = g.container_id AND i.version = a.version
WHERE m.id = ?
)
SELECT 255::uint1, t.archive_id::INTEGER, t.data, NULL
FROM t
UNION ALL
SELECT t.archive_id, ig.group_id, c.data, g.version
FROM t
JOIN index_groups ig ON ig.container_id = t.container_id
JOIN groups g ON g.archive_id = t.archive_id::INTEGER AND g.group_id = ig.group_id AND (
(g.version = ig.version AND NOT g.version_truncated) OR
(g.version = ig.version & 65535 AND g.version_truncated)
)
JOIN containers c ON c.id = g.container_id AND c.crc32 = ig.crc32
""".trimIndent() """.trimIndent()
).use { stmt -> ).use { stmt ->
stmt.fetchSize = BATCH_SIZE stmt.fetchSize = BATCH_SIZE
@ -133,26 +114,11 @@ public class CacheExporter @Inject constructor(
return database.execute { connection -> return database.execute { connection ->
connection.prepareStatement( connection.prepareStatement(
""" """
WITH t AS ( SELECT v.archive_id, v.group_id, v.name_hash, n.name, (k.key).k0, (k.key).k1, (k.key).k2, (k.key).k3
SELECT a.archive_id, c.data, g.container_id FROM master_index_valid_groups v
FROM master_indexes m JOIN keys k ON k.id = v.key_id
JOIN master_index_archives a ON a.master_index_id = m.id LEFT JOIN names n ON n.hash = v.name_hash AND n.name ~ '^l(?:[0-9]|[1-9][0-9])_(?:[0-9]|[1-9][0-9]|1[0-9]{2}|2[0-4][0-9]|25[0-5])$'
JOIN groups g ON g.archive_id = 255 AND g.group_id = a.archive_id::INTEGER WHERE v.master_index_id = ?
AND g.version = a.version AND NOT g.version_truncated
JOIN containers c ON c.id = g.container_id AND c.crc32 = a.crc32
JOIN indexes i ON i.container_id = g.container_id AND i.version = a.version
WHERE m.id = ?
)
SELECT t.archive_id, ig.group_id, ig.name_hash, n.name, (k.key).k0, (k.key).k1, (k.key).k2, (k.key).k3
FROM t
JOIN index_groups ig ON ig.container_id = t.container_id
JOIN groups g ON g.archive_id = t.archive_id::INTEGER AND g.group_id = ig.group_id AND (
(g.version = ig.version AND NOT g.version_truncated) OR
(g.version = ig.version & 65535 AND g.version_truncated)
)
JOIN containers c ON c.id = g.container_id AND c.crc32 = ig.crc32
JOIN keys k ON k.id = c.key_id
LEFT JOIN names n ON n.hash = ig.name_hash AND n.name ~ '^l(?:[0-9]|[1-9][0-9])_(?:[0-9]|[1-9][0-9]|1[0-9]{2}|2[0-4][0-9]|25[0-5])$'
""".trimIndent() """.trimIndent()
).use { stmt -> ).use { stmt ->
stmt.setLong(1, id) stmt.setLong(1, id)

@ -123,4 +123,31 @@ CREATE TABLE names (
); );
CREATE UNIQUE INDEX ON names (hash, name); CREATE UNIQUE INDEX ON names (hash, name);
CREATE VIEW master_index_valid_indexes AS
SELECT m.id AS master_index_id, a.archive_id, c.data, g.container_id
FROM master_indexes m
JOIN master_index_archives a ON a.master_index_id = m.id
JOIN groups g ON g.archive_id = 255 AND g.group_id = a.archive_id::INTEGER AND
g.version = a.version AND NOT g.version_truncated
JOIN containers c ON c.id = g.container_id AND c.crc32 = a.crc32
JOIN indexes i ON i.container_id = g.container_id AND i.version = a.version;
-- TODO(gpe): think about what to do if there is a collision
CREATE VIEW master_index_valid_groups (master_index_id, archive_id, group_id, name_hash, version, data, key_id) AS
WITH i AS NOT MATERIALIZED (
SELECT master_index_id, archive_id, data, container_id
FROM master_index_valid_indexes
)
SELECT i.master_index_id, 255::uint1, i.archive_id::INTEGER, NULL, NULL, i.data, NULL
FROM i
UNION ALL
SELECT i.master_index_id, i.archive_id, ig.group_id, ig.name_hash, ig.version, c.data, c.key_id
FROM i
JOIN index_groups ig ON ig.container_id = i.container_id
JOIN groups g ON g.archive_id = i.archive_id::INTEGER AND g.group_id = ig.group_id AND (
(g.version = ig.version AND NOT g.version_truncated) OR
(g.version = ig.version & 65535 AND g.version_truncated)
)
JOIN containers c ON c.id = g.container_id AND c.crc32 = ig.crc32;
-- @formatter:on -- @formatter:on

Loading…
Cancel
Save