From cba34b54c930e7e02471d78fa84ffc69febd8663 Mon Sep 17 00:00:00 2001 From: Graham Date: Sun, 21 Mar 2021 17:01:38 +0000 Subject: [PATCH] Add resolve_{group,index} functions These functions reduce the amount of group resolution logic significantly, concentrating it in a single place. In addition to the usual code de-duplication benefits, many of the queries are now much simpler as the complexity is hidden behind the function calls. This change also allows us to make the group resolution logic more complicated. The first change is that the functions are guaranteed to only return a single row, which was not true with the old JOIN-based approach. The row that is chosen is chosen deterministically. The resolution logic will probably be improved in the future, so we can make a better decision where there are multiple possible groups, due to collisions. Signed-off-by: Graham --- .../openrs2/archive/cache/CacheImporter.kt | 12 +-- .../openrs2/archive/migrations/V1__init.sql | 77 ++++++++++++++----- 2 files changed, 59 insertions(+), 30 deletions(-) diff --git a/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt b/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt index d78b0509..2f3e6514 100644 --- a/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt +++ b/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt @@ -247,11 +247,7 @@ public class CacheImporter @Inject constructor( FROM master_index_archives a LEFT JOIN master_index_archives a2 ON a2.master_index_id = ? AND a2.archive_id = a.archive_id AND a2.crc32 = a.crc32 AND a2.version = a.version - LEFT JOIN groups g ON g.archive_id = 255 AND g.group_id = a2.archive_id::INTEGER AND - g.version = a2.version AND NOT g.version_truncated AND - g.container_id IN (SELECT id FROM containers WHERE crc32 = a2.crc32) - LEFT JOIN containers c ON c.id = g.container_id - LEFT JOIN indexes i ON i.container_id = g.container_id AND i.version = a2.version + LEFT JOIN LATERAL resolve_index(a2.archive_id, a2.crc32, a2.version) c ON TRUE WHERE a.master_index_id = ? ORDER BY a.archive_id ASC """.trimIndent() @@ -312,10 +308,8 @@ public class CacheImporter @Inject constructor( i.archive_id = ? LEFT JOIN index_groups ig2 ON ig2.container_id = i.container_id AND ig2.group_id = ig.group_id AND ig2.crc32 = ig.crc32 AND ig2.version = ig.version - LEFT JOIN groups g ON g.archive_id = i.archive_id AND g.group_id = ig2.group_id AND - g.version = ig2.version AND NOT g.version_truncated AND - g.container_id IN (SELECT id FROM containers WHERE crc32 = ig2.crc32) - WHERE ig.container_id = ? AND g.container_id IS NULL + LEFT JOIN LATERAL resolve_group(i.archive_id, ig2.group_id, ig2.crc32, ig2.version) c ON TRUE + WHERE ig.container_id = ? AND c.id IS NULL ORDER BY ig.group_id ASC """.trimIndent() ).use { stmt -> diff --git a/archive/src/main/resources/org/openrs2/archive/migrations/V1__init.sql b/archive/src/main/resources/org/openrs2/archive/migrations/V1__init.sql index 8486dcff..25a89ecb 100644 --- a/archive/src/main/resources/org/openrs2/archive/migrations/V1__init.sql +++ b/archive/src/main/resources/org/openrs2/archive/migrations/V1__init.sql @@ -163,14 +163,61 @@ CREATE TABLE names ( CREATE UNIQUE INDEX ON names (hash, name); +CREATE FUNCTION resolve_index(archive_id uint1, crc32 INTEGER, version INTEGER) RETURNS containers AS $$ +#variable_conflict use_variable +DECLARE + resolved containers%ROWTYPE; +BEGIN + SELECT c.* + INTO resolved + FROM groups g + JOIN containers c ON c.id = g.container_id + JOIN indexes i ON i.container_id = c.id + WHERE g.archive_id = 255 AND g.group_id = archive_id::INTEGER AND c.crc32 = crc32 AND g.version = version AND + NOT g.version_truncated AND i.version = version + ORDER BY c.id ASC + LIMIT 1; + + RETURN resolved; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION resolve_group(archive_id uint1, group_id INTEGER, crc32 INTEGER, version INTEGER) RETURNS containers AS $$ +#variable_conflict use_variable +DECLARE + resolved containers%ROWTYPE; +BEGIN + SELECT c.* + INTO resolved + FROM groups g + JOIN containers c ON c.id = g.container_id + WHERE g.archive_id = archive_id AND g.group_id = group_id AND c.crc32 = crc32 AND g.version = version AND + NOT g.version_truncated + ORDER BY c.id ASC + LIMIT 1; + + IF FOUND THEN + RETURN resolved; + END IF; + + SELECT c.* + INTO resolved + FROM groups g + JOIN containers c ON c.id = g.container_id + WHERE g.archive_id = archive_id AND g.group_id = group_id AND c.crc32 = crc32 AND g.version = version & 65535 AND + g.version_truncated + ORDER BY c.id ASC + LIMIT 1; + + RETURN resolved; +END; +$$ LANGUAGE plpgsql; + CREATE VIEW resolved_indexes AS -SELECT m.id AS master_index_id, a.archive_id, c.data, g.container_id +SELECT m.id AS master_index_id, a.archive_id, c.data, c.id AS 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; +JOIN LATERAL resolve_index(a.archive_id, a.crc32, a.version) c ON TRUE; CREATE VIEW resolved_groups (master_index_id, archive_id, group_id, name_hash, version, data, key_id) AS WITH i AS NOT MATERIALIZED ( @@ -183,11 +230,7 @@ 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 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 LATERAL resolve_group(i.archive_id, ig.group_id, ig.crc32, ig.version) c ON TRUE; CREATE MATERIALIZED VIEW master_index_stats ( master_index_id, @@ -210,14 +253,10 @@ FROM master_indexes m LEFT JOIN ( SELECT a.master_index_id, - COUNT(DISTINCT a.archive_id) FILTER (WHERE i.container_id IS NOT NULL OR (a.version = 0 AND a.crc32 = 0)) AS valid_indexes, + COUNT(DISTINCT a.archive_id) FILTER (WHERE c.id IS NOT NULL OR (a.version = 0 AND a.crc32 = 0)) AS valid_indexes, COUNT(DISTINCT a.archive_id) AS indexes FROM master_index_archives a - LEFT 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 AND - g.container_id IN (SELECT id FROM containers WHERE crc32 = a.crc32) - LEFT JOIN containers c ON c.id = g.container_id - LEFT JOIN indexes i ON i.container_id = g.container_id AND i.version = a.version + LEFT JOIN LATERAL resolve_index(a.archive_id, a.crc32, a.version) c ON TRUE GROUP BY a.master_index_id ) a ON a.master_index_id = m.id LEFT JOIN ( @@ -229,11 +268,7 @@ LEFT JOIN ( COUNT(DISTINCT (i.archive_id, ig.group_id)) FILTER (WHERE c.encrypted) AS keys FROM resolved_indexes i JOIN index_groups ig ON ig.container_id = i.container_id - LEFT JOIN groups g ON g.archive_id = i.archive_id 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) - ) AND g.container_id IN (SELECT id FROM containers WHERE crc32 = ig.crc32) - LEFT JOIN containers c ON c.id = g.container_id + LEFT JOIN LATERAL resolve_group(i.archive_id, ig.group_id, ig.crc32, ig.version) c ON TRUE LEFT JOIN keys k ON k.id = c.key_id GROUP BY i.master_index_id ) g ON g.master_index_id = m.id;