From 1c061c0f6670a8c94c1975a09d9334cda8f036be Mon Sep 17 00:00:00 2001 From: Graham Date: Sun, 7 Feb 2021 01:04:46 +0000 Subject: [PATCH] Store master index format in the database We can't reliably infer it based on the contents of the container. Signed-off-by: Graham --- .../openrs2/archive/cache/CacheExporter.kt | 10 +-- .../openrs2/archive/cache/CacheImporter.kt | 87 ++++++++++++------- .../org/openrs2/archive/V1__init.sql | 17 +++- 3 files changed, 74 insertions(+), 40 deletions(-) diff --git a/archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt b/archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt index 3393cbf0a0..c4443ecfc6 100644 --- a/archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt +++ b/archive/src/main/kotlin/org/openrs2/archive/cache/CacheExporter.kt @@ -39,7 +39,7 @@ public class CacheExporter @Inject constructor( return database.execute { connection -> connection.prepareStatement( """ - SELECT c.id, c.whirlpool, g.name, m.build, m.timestamp, m.name + SELECT m.id, c.whirlpool, g.name, m.build, m.timestamp, m.name FROM master_indexes m JOIN games g ON g.id = m.game_id JOIN containers c ON c.id = m.container_id @@ -79,12 +79,12 @@ public class CacheExporter @Inject constructor( WITH t AS ( SELECT a.archive_id, c.data, g.container_id FROM master_indexes m - JOIN master_index_archives a ON a.container_id = m.container_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 - WHERE m.container_id = ? + WHERE m.id = ? ) SELECT 255::uint1, t.archive_id::INTEGER, t.data, NULL FROM t @@ -138,12 +138,12 @@ public class CacheExporter @Inject constructor( WITH t AS ( SELECT a.archive_id, c.data, g.container_id FROM master_indexes m - JOIN master_index_archives a ON a.container_id = m.container_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 - WHERE m.container_id = ? + 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 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 c7dd892d07..41d861dee1 100644 --- a/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt +++ b/archive/src/main/kotlin/org/openrs2/archive/cache/CacheImporter.kt @@ -338,7 +338,7 @@ public class CacheImporter @Inject constructor( overwrite: Boolean ) { val containerId = addContainer(connection, masterIndex) - var exists: Boolean + var masterIndexId: Int? = null var newBuild: Int? var newTimestamp: Instant? @@ -347,28 +347,31 @@ public class CacheImporter @Inject constructor( connection.prepareStatement( """ - SELECT game_id, build, timestamp, name, description + SELECT id, game_id, build, timestamp, name, description FROM master_indexes - WHERE container_id = ? + WHERE container_id = ? AND format = ?::master_index_format FOR UPDATE """.trimIndent() ).use { stmt -> stmt.setLong(1, containerId) + stmt.setString(2, masterIndex.index.format.name.toLowerCase()) stmt.executeQuery().use { rows -> - exists = rows.next() + if (rows.next()) { + masterIndexId = rows.getInt(1) + } - if (exists && !overwrite) { - val oldGameId = rows.getInt(1) + if (masterIndexId != null && !overwrite) { + val oldGameId = rows.getInt(2) - var oldBuild: Int? = rows.getInt(2) + var oldBuild: Int? = rows.getInt(3) if (rows.wasNull()) { oldBuild = null } - val oldTimestamp: Instant? = rows.getTimestamp(3)?.toInstant() - val oldName: String? = rows.getString(4) - val oldDescription: String? = rows.getString(5) + val oldTimestamp: Instant? = rows.getTimestamp(4)?.toInstant() + val oldName: String? = rows.getString(5) + val oldDescription: String? = rows.getString(6) check(oldGameId == gameId) @@ -417,47 +420,69 @@ public class CacheImporter @Inject constructor( } } + if (masterIndexId != null) { + connection.prepareStatement( + """ + UPDATE master_indexes + SET build = ?, timestamp = ?, name = ?, description = ? + WHERE id = ? + """.trimIndent() + ).use { stmt -> + stmt.setObject(1, newBuild, Types.INTEGER) + + if (newTimestamp != null) { + val offsetDateTime = OffsetDateTime.ofInstant(newTimestamp, ZoneOffset.UTC) + stmt.setObject(2, offsetDateTime, Types.TIMESTAMP_WITH_TIMEZONE) + } else { + stmt.setNull(2, Types.TIMESTAMP_WITH_TIMEZONE) + } + + stmt.setString(3, newName) + stmt.setString(4, newDescription) + stmt.setInt(5, masterIndexId!!) + + stmt.execute() + + return@addMasterIndex + } + } + connection.prepareStatement( """ - INSERT INTO master_indexes (container_id, game_id, build, timestamp, name, description) - VALUES (?, ?, ?, ?, ?, ?) - ON CONFLICT (container_id) DO UPDATE SET - game_id = EXCLUDED.game_id, - build = EXCLUDED.build, - timestamp = EXCLUDED.timestamp, - name = EXCLUDED.name, - description = EXCLUDED.description + INSERT INTO master_indexes (container_id, format, game_id, build, timestamp, name, description) + VALUES (?, ?::master_index_format, ?, ?, ?, ?, ?) + RETURNING id """.trimIndent() ).use { stmt -> stmt.setLong(1, containerId) - stmt.setInt(2, gameId) - stmt.setObject(3, newBuild, Types.INTEGER) + stmt.setString(2, masterIndex.index.format.name.toLowerCase()) + stmt.setInt(3, gameId) + stmt.setObject(4, newBuild, Types.INTEGER) if (newTimestamp != null) { val offsetDateTime = OffsetDateTime.ofInstant(newTimestamp, ZoneOffset.UTC) - stmt.setObject(4, offsetDateTime, Types.TIMESTAMP_WITH_TIMEZONE) + stmt.setObject(5, offsetDateTime, Types.TIMESTAMP_WITH_TIMEZONE) } else { - stmt.setNull(4, Types.TIMESTAMP_WITH_TIMEZONE) + stmt.setNull(5, Types.TIMESTAMP_WITH_TIMEZONE) } - stmt.setString(5, newName) - stmt.setString(6, newDescription) + stmt.setString(6, newName) + stmt.setString(7, newDescription) - stmt.execute() - } - - if (exists) { - return + stmt.executeQuery().use { rows -> + check(rows.next()) + masterIndexId = rows.getInt(1) + } } connection.prepareStatement( """ - INSERT INTO master_index_archives (container_id, archive_id, crc32, version) + INSERT INTO master_index_archives (master_index_id, archive_id, crc32, version) VALUES (?, ?, ?, ?) """.trimIndent() ).use { stmt -> for ((i, entry) in masterIndex.index.entries.withIndex()) { - stmt.setLong(1, containerId) + stmt.setInt(1, masterIndexId!!) stmt.setInt(2, i) stmt.setInt(3, entry.checksum) stmt.setInt(4, entry.version) diff --git a/archive/src/main/resources/org/openrs2/archive/V1__init.sql b/archive/src/main/resources/org/openrs2/archive/V1__init.sql index c33c1ae0ae..9c9dfc5db8 100644 --- a/archive/src/main/resources/org/openrs2/archive/V1__init.sql +++ b/archive/src/main/resources/org/openrs2/archive/V1__init.sql @@ -82,22 +82,31 @@ CREATE TABLE index_files ( FOREIGN KEY (container_id, group_id) REFERENCES index_groups (container_id, group_id) ); +CREATE TYPE master_index_format AS ENUM ( + 'original', + 'versioned', + 'whirlpool' +); + CREATE TABLE master_indexes ( - container_id BIGINT PRIMARY KEY NOT NULL REFERENCES containers (id), + id SERIAL PRIMARY KEY NOT NULL, + container_id BIGINT NOT NULL REFERENCES containers (id), + format master_index_format NOT NULL, game_id INTEGER NOT NULL REFERENCES games (id), build INTEGER NULL, timestamp TIMESTAMPTZ NULL, name TEXT NULL, - description TEXT NULL + description TEXT NULL, + UNIQUE (container_id, format) ); CREATE TABLE master_index_archives ( - container_id BIGINT NOT NULL REFERENCES master_indexes (container_id), + master_index_id INTEGER NOT NULL REFERENCES master_indexes (id), archive_id uint1 NOT NULL, crc32 INTEGER NOT NULL, whirlpool BYTEA NULL, version INTEGER NOT NULL, - PRIMARY KEY (container_id, archive_id) + PRIMARY KEY (master_index_id, archive_id) ); CREATE TABLE names (