From b4f2f5103281697708b655199b395f113922e8d2 Mon Sep 17 00:00:00 2001 From: Stefan Schallerl Date: Thu, 6 Feb 2025 10:41:42 +0100 Subject: [PATCH] Removes sqlite-jdbc in favor of SQLDelight. --- app/build.gradle.kts | 4 +- .../filemure/controller/DocumentController.kt | 25 +- .../filemure/repository/SqliteRepository.kt | 412 ++++++------------ app/src/main/sqldelight/database.sql | 51 --- .../net/h34t/filemure/db/Database.sq | 172 ++++++++ 5 files changed, 320 insertions(+), 344 deletions(-) delete mode 100644 app/src/main/sqldelight/database.sql create mode 100644 app/src/main/sqldelight/net/h34t/filemure/db/Database.sq diff --git a/app/build.gradle.kts b/app/build.gradle.kts index 4d224c8..117aa4a 100644 --- a/app/build.gradle.kts +++ b/app/build.gradle.kts @@ -11,7 +11,7 @@ plugins { dependencies { implementation("app.cash.sqldelight:sqlite-driver:2.0.2") - implementation("org.xerial:sqlite-jdbc:3.48.0.0") + // implementation("org.xerial:sqlite-jdbc:3.48.0.0") implementation("com.fasterxml.jackson.core:jackson-databind:2.18.2") implementation("com.fasterxml.jackson.module:jackson-module-kotlin:2.18.+") implementation(libs.slf4jsimple) @@ -24,7 +24,7 @@ dependencies { application { // Define the Fully Qualified Name for the application main class // (Note that Kotlin compiles `App.kt` to a class with FQN `com.example.app.AppKt`.) - mainClass = "net.h34t.app.AppKt" + mainClass = "net.h34t.filemure.ServerKt" } sourceSets { diff --git a/app/src/main/kotlin/net/h34t/filemure/controller/DocumentController.kt b/app/src/main/kotlin/net/h34t/filemure/controller/DocumentController.kt index fc57d96..a27c05b 100644 --- a/app/src/main/kotlin/net/h34t/filemure/controller/DocumentController.kt +++ b/app/src/main/kotlin/net/h34t/filemure/controller/DocumentController.kt @@ -5,6 +5,7 @@ import io.javalin.http.Context import io.javalin.http.ForbiddenResponse import io.javalin.http.Header import net.h34t.filemure.* +import net.h34t.filemure.core.entity.State import net.h34t.filemure.core.entity.Tag import net.h34t.filemure.repository.SqliteRepository import net.h34t.filemure.tpl.* @@ -20,9 +21,9 @@ class DocumentController(val modifiers: TemplateModifiers, val repository: Sqlit fun documentDetail(ctx: Context) { val session = ctx.requireSession() - val extId = ctx.pathParam("extId") + val extId = ExtId(ctx.pathParam("extId")) - val document = repository.getDocumentByExtId(accountId = session.id, extId = extId) + val document = repository.getDocumentByExtId(accountId = session.id, extId = extId, state = State.ACTIVE) ctx.tempolin( Frame( @@ -121,7 +122,14 @@ class DocumentController(val modifiers: TemplateModifiers, val repository: Sqlit ?: throw BadRequestResponse("") val fileExtIds = ctx.formParams("file_id") - val extId = repository.addDocument(session.id, title, referenceDate, tags, description, fileExtIds) + val extId = + repository.addDocument( + session.id, + title, + referenceDate, + tags.map { Tag(it) }, + description, + fileExtIds.map { ExtId(it) }) ctx.redirectPRG("/document/$extId") } @@ -134,7 +142,7 @@ class DocumentController(val modifiers: TemplateModifiers, val repository: Sqlit val session = ctx.requireSession() val extId = ctx.pathParam("extId") - val file = repository.loadFile(accountId = session.id, extId = extId) + val file = repository.loadFile(accountId = session.id, extId = ExtId(extId)) file.contentType?.also { ctx.header(Header.CONTENT_TYPE, it) } ctx.result(file.content) @@ -144,7 +152,7 @@ class DocumentController(val modifiers: TemplateModifiers, val repository: Sqlit val session = ctx.requireSession() val extId = ctx.pathParam("extId") - val document = repository.getDocumentByExtId(accountId = session.id, extId = extId) + val document = repository.getDocumentByExtId(accountId = session.id, extId = ExtId(extId), state = State.ACTIVE) ctx.tempolin( Frame( @@ -183,8 +191,11 @@ class DocumentController(val modifiers: TemplateModifiers, val repository: Sqlit val session = ctx.requireSession() val extId = ctx.pathParam("extId") - val document = repository.getDocumentByExtId(accountId = session.id, extId = extId) - + val document = repository.getDocumentByExtId( + accountId = session.id, + extId = ExtId(extId), + state = State.ACTIVE + ) val title = ctx.formParam("title") val referenceDate = ctx.formParam("reference_date") diff --git a/app/src/main/kotlin/net/h34t/filemure/repository/SqliteRepository.kt b/app/src/main/kotlin/net/h34t/filemure/repository/SqliteRepository.kt index 419dcb7..8699817 100644 --- a/app/src/main/kotlin/net/h34t/filemure/repository/SqliteRepository.kt +++ b/app/src/main/kotlin/net/h34t/filemure/repository/SqliteRepository.kt @@ -1,191 +1,112 @@ package net.h34t.filemure.repository +import app.cash.sqldelight.db.SqlDriver +import app.cash.sqldelight.driver.jdbc.sqlite.JdbcSqliteDriver import net.h34t.filemure.ExtId import net.h34t.filemure.core.entity.* import net.h34t.filemure.core.entity.Tag.Companion.serialize +import net.h34t.filemure.db.Database import java.io.InputStream -import java.sql.Connection -import java.sql.DriverManager import java.time.LocalDateTime import java.time.format.DateTimeFormatter class SqliteRepository(url: String) { - private val dtf = DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss") + private val sqliteDtf = DateTimeFormatter.ofPattern("yyyy-MM-dd HH:mm:ss") - val connection: Connection = DriverManager.getConnection(url) + // private val connection: Connection = DriverManager.getConnection(url) + private val database: Database + + init { + val driver: SqlDriver = JdbcSqliteDriver("jdbc:sqlite:test.db") + Database.Schema.create(driver) + database = Database(driver) + } + + private fun toLDT(value: String) = LocalDateTime.parse(value, sqliteDtf) fun addFileToLimbo(accountId: Long, filename: String, contentType: String?, size: Long, content: InputStream) { - connection.prepareStatement("INSERT INTO file (account_id, ext_id, filename, content_type, file_size, content) VALUES (?,?,?,?,?,?)") - .use { stmt -> - stmt.setLong(1, accountId) - stmt.setString(2, ExtId.generate().toString()) - stmt.setString(3, filename) - stmt.setString(4, contentType) - stmt.setLong(5, size) - stmt.setBytes(6, content.readAllBytes()) - - val res = stmt.executeUpdate() - - require(res == 1) - } + database.databaseQueries.insertFileIntoLimbo( + account_id = accountId, + ext_id = ExtId.generate().value, + filename = filename, + content_type = contentType, + file_size = size, + content = content.readAllBytes() + ) } fun getLimboFileCount(accountId: Long, state: State = State.ACTIVE): Long { - connection.prepareStatement("SELECT count(*) AS count FROM file WHERE account_id=? AND document_id IS NULL AND state=?") - .use { stmt -> - stmt.setLong(1, accountId) - stmt.setInt(2, state.code) - val rs = stmt.executeQuery() - rs.next() - return rs.getLong(1) - } + return database.databaseQueries.getLimboFileCount(account_id = accountId, state = state.code.toLong()) + .executeAsOne() } fun getFilesInLimbo(accountId: Long, state: State = State.ACTIVE): List { - connection.prepareStatement( - """ - |SELECT - | id, - | ext_id, - | account_id, - | filename, - | content_type, - | content_extracted, - | file_size, - | created, - | state - |FROM - | file - |WHERE - | account_id=? AND - | document_id IS NULL - | AND state=? - |ORDER BY - | created DESC - """.trimMargin() - ).use { stmt -> - stmt.setLong(1, accountId) - stmt.setInt(2, state.code) - val res = stmt.executeQuery() - - val list = mutableListOf() - - while (res.next()) { - list += FileRef( - id = res.getLong("id"), - extId = res.getString("ext_id"), - accountId = res.getLong("account_id"), + return database.databaseQueries.getFilesInLimbo(account_id = accountId, state = state.code.toLong()) + .executeAsList() + .map { + FileRef( + id = it.id, + accountId = it.account_id, + extId = it.ext_id, documentId = null, - filename = res.getString("filename"), - contentType = res.getString("content_type"), - contentExtracted = res.getString("content_extracted"), - fileSize = res.getLong("file_size"), - created = LocalDateTime.parse(res.getString("created"), dtf), - state = State.fromCode(res.getInt("state")) + filename = it.filename, + fileSize = it.file_size, + contentType = it.content_type, + contentExtracted = it.content_extracted, + created = toLDT(it.created), + state = State.fromCode(it.state.toInt()) ) } - - return list - } } fun addDocument( accountId: Long, title: String, referenceDate: LocalDateTime, - tags: List, + tags: List, description: String, - fileExtIds: List + fileExtIds: List ): ExtId { + val extId = ExtId.generate() + database.databaseQueries.transaction { + database.databaseQueries.addDocument( + account_id = accountId, + ext_id = extId.value, + title = title, + description = description, + tags = tags.serialize(), + reference_date = referenceDate.format(sqliteDtf) + ) - val savePoint = connection.setSavepoint() - try { - val extId = ExtId.generate() + val documentId = database.databaseQueries.getLastInsertRowId().executeAsOne() - val documentId = connection.prepareStatement( - """INSERT INTO document - |(account_id, ext_id, title, description, tags, created, reference_date) - |VALUES - |(?, ?, ?, ?, ?, datetime(), ?)""".trimMargin() - ).use { stmt -> - stmt.setLong(1, accountId) - stmt.setString(2, extId.value) - stmt.setString(3, title) - stmt.setString(4, description) - stmt.setString(5, tags.joinToString(",")) - stmt.setString(6, referenceDate.format(dtf)) - stmt.executeUpdate() - val gks = stmt.generatedKeys - gks.next() - gks.getLong(1) - } - - val extIds = fileExtIds.joinToString(",") { "'$it'" } - - connection.prepareStatement("""UPDATE file SET document_id=? WHERE account_id=? AND ext_id IN ($extIds)""") - .use { stmt -> - stmt.setLong(1, documentId) - stmt.setLong(2, accountId) - val affected = stmt.executeUpdate() - require(affected == fileExtIds.size) - } - - connection.commit() - return extId - } catch (exception: Exception) { - connection.rollback(savePoint) - throw exception + database.databaseQueries.attachLimboFilesToDocument( + account_id = accountId, + document_id = documentId, + ext_id = fileExtIds.map { it.value } + ) } + + return extId; } fun getDocuments(accountId: Long, state: State = State.ACTIVE): List { - connection.prepareStatement( - """ - |SELECT - | d.id, - | d.account_id, - | d.ext_id, - | d.title, - | d.description, - | d.tags, - | d.created, - | d.reference_date, - | d.state - |FROM - | document d - |WHERE - | account_id=? AND - | state=? - """.trimMargin() - ).use { stmt -> - stmt.setLong(1, accountId) - stmt.setInt(2, state.code) - val res = stmt.executeQuery() - - val documentList = mutableListOf() - - while (res.next()) { - documentList.add( - Document( - id = res.getLong("id"), - extId = res.getString("ext_id"), - title = res.getString("title"), - description = res.getString("description"), - tags = res.getString("tags") - ?.let { if (it.isNotBlank()) it.split(",").map { tag -> Tag(tag) } else emptyList() } - ?: emptyList(), - created = LocalDateTime.parse(res.getString("created"), dtf), - referenceDate = LocalDateTime.parse(res.getString("reference_date"), dtf), - state = State.fromCode(res.getInt("state")), - files = emptyList() - ) + return database.databaseQueries.getDocuments(account_id = accountId, state = state.code.toLong()) + .executeAsList() + .map { + Document( + id = it.id, + extId = it.ext_id, + title = it.title, + description = it.description, + tags = Tag.parse(it.tags), + created = toLDT(it.created), + referenceDate = toLDT(it.reference_date), + state = State.fromCode(it.state.toInt()), + files = emptyList() ) } - - - return documentList.toList() - } } fun updateDocument( @@ -197,145 +118,68 @@ class SqliteRepository(url: String) { description: String, state: State = State.ACTIVE, ) { - connection.prepareStatement( - """ - |UPDATE - | document - |SET - | title=?, - | reference_date=?, - | tags=?, - | description=?, - | state=? - |WHERE - | account_id=? AND - | id=? - """.trimMargin() - ).use { stmt -> - stmt.setString(1, title) - stmt.setString(2, dtf.format(referenceDate)) - stmt.setString(3, tags.serialize()) - stmt.setString(4, description) - stmt.setInt(5, state.code) - stmt.setLong(6, accountId) - stmt.setLong(7, id) + database.databaseQueries.updateDocument( + id = id, + title = title, + reference_date = referenceDate.format(sqliteDtf), + tags = tags.serialize(), + description = description, + state = state.code.toLong(), + account_id = accountId, + ) + } + + fun getDocumentByExtId(accountId: Long, extId: ExtId, state: State): Document { + return database.databaseQueries.getDocumentByExtId( + account_id = accountId, + ext_id = extId.value, + state = state.code.toLong() + ).executeAsOne().let { d -> + Document( + id = d.id, + extId = d.ext_id, + title = d.title, + description = d.description, + tags = Tag.parse(d.tags), + created = toLDT(d.created), + referenceDate = toLDT(d.reference_date), + state = State.fromCode(d.state.toInt()), + files = database.databaseQueries.getFilesForDocument( + document_id = d.id, + account_id = accountId + ).executeAsList().map { f -> + FileRef( + id = f.id, + extId = f.ext_id, + accountId = f.account_id, + documentId = f.document_id, + filename = f.filename, + contentType = f.content_type, + contentExtracted = f.content_extracted, + fileSize = f.file_size, + created = toLDT(f.created), + state = State.fromCode(f.state.toInt()) + ) + } + ) - stmt.executeUpdate() } } - fun getDocumentByExtId(accountId: Long, extId: String): Document { - return connection.prepareStatement( - """ - |SELECT - | d.id as d_id, - | d.account_id d_account_id, - | d.ext_id d_ext_id, - | d.title d_title, - | d.description d_description, - | d.tags d_tags, - | d.created d_created, - | d.reference_date d_reference_date, - | d.state as d_state, - | f.id f_id, - | f.ext_id f_ext_id, - | f.account_id f_account_id, - | f.document_id f_document_id, - | f.filename f_filename, - | f.content_type f_content_type, - | f.content_extracted f_content_extracted, - | f.file_size f_file_size, - | f.created f_created, - | f.state f_state - |FROM - | document d LEFT OUTER JOIN file f ON (d.id = f.document_id) - |WHERE - | d.ext_id=? AND - | d.account_id=? - """.trimMargin() - ) - .use { stmt -> - - - stmt.setString(1, extId) - stmt.setLong(2, accountId) - val res = stmt.executeQuery() - var document: Document? = null - val files = mutableListOf() - - while (res.next()) { - if (document == null) { - document = Document( - id = res.getLong("d_id"), - extId = res.getString("d_ext_id"), - title = res.getString("d_title"), - description = res.getString("d_description"), - tags = Tag.parse(res.getString("d_tags")), - created = LocalDateTime.parse(res.getString("d_created"), dtf), - referenceDate = LocalDateTime.parse(res.getString("d_reference_date"), dtf), - state = State.fromCode(res.getInt("d_state")), - files = emptyList() - ) - } - - val fid: Long = res.getLong("f_id") - val wasNull = res.wasNull() - - if (!wasNull) { - files.add( - FileRef( - id = fid, - extId = res.getString("f_ext_id"), - accountId = res.getLong("f_account_id"), - documentId = res.getLong("f_document_id"), - filename = res.getString("f_filename"), - contentType = res.getString("f_content_type"), - contentExtracted = res.getString("f_content_extracted"), - fileSize = res.getLong("f_file_size"), - created = LocalDateTime.parse(res.getString("f_created"), dtf), - state = State.fromCode(res.getInt("f_state")) - ) - ) - } - - } - - requireNotNull(document) - document.copy(files = files) + fun loadFile(accountId: Long, extId: ExtId): FileContent { + return database + .databaseQueries + .getFile(account_id = accountId, ext_id = extId.value) + .executeAsOne().let { f -> + FileContent( + id = f.id, + extId = f.ext_id, + filename = f.filename, + contentType = f.content_type, + contentExtracted = f.content_extracted, + fileSize = f.file_size, + content = f.content + ) } } - - fun loadFile(accountId: Long, extId: String): FileContent { - return connection.prepareStatement( - """ - |SELECT - | id, - | ext_id, - | filename, - | content_type, - | content_extracted, - | file_size, - | content - |FROM - | file - |WHERE - | account_id=? AND - | ext_id=? - """.trimMargin() - ).use { stmt -> - stmt.setLong(1, accountId) - stmt.setString(2, extId) - val res = stmt.executeQuery() - - FileContent( - id = res.getLong(1), - extId = res.getString(2), - filename = res.getString(3), - contentType = res.getString(4), - contentExtracted = res.getString(5), - fileSize = res.getLong(6), - content = res.getBytes(7) - ) - } - } } \ No newline at end of file diff --git a/app/src/main/sqldelight/database.sql b/app/src/main/sqldelight/database.sql deleted file mode 100644 index 5de5c0c..0000000 --- a/app/src/main/sqldelight/database.sql +++ /dev/null @@ -1,51 +0,0 @@ --- account definition - -CREATE TABLE account ( - id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - email TEXT NOT NULL, - password TEXT NOT NULL, - created TEXT DEFAULT (CURRENT_TIMESTAMP) NOT NULL, - state INTEGER DEFAULT (1) NOT NULL, - unique(email) -); - -CREATE INDEX account_state_IDX ON account (state); - - --- document definition - -CREATE TABLE document ( - id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - account_id INTEGER NOT NULL, - ext_id TEXT NOT NULL, - title TEXT NOT NULL, - description TEXT NOT NULL, - tags TEXT NOT NULL, - created TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, - reference_date TEXT, state INTEGER DEFAULT (1) NOT NULL, - CONSTRAINT document_account_FK FOREIGN KEY (account_id) REFERENCES account(id) ON DELETE CASCADE, - unique(ext_id) -); - -CREATE INDEX document_state_IDX ON document (state); - - --- file definition - -CREATE TABLE file ( - id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, - account_id INTEGER NOT NULL, - document_id INTEGER DEFAULT null, - ext_id TEXT NOT NULL, - filename TEXT NOT NULL, - file_size INTEGER NOT NULL, - content BLOB NOT NULL, - content_type TEXT, - content_extracted TEXT, - created TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, state INTEGER DEFAULT (1) NOT NULL, - CONSTRAINT file_account_FK FOREIGN KEY (account_id) REFERENCES account(id) ON DELETE CASCADE, - CONSTRAINT file_document_FK FOREIGN KEY (document_id) REFERENCES document(id) ON DELETE CASCADE, - unique(ext_id) -); - -CREATE INDEX file_state_IDX ON file (state); \ No newline at end of file diff --git a/app/src/main/sqldelight/net/h34t/filemure/db/Database.sq b/app/src/main/sqldelight/net/h34t/filemure/db/Database.sq new file mode 100644 index 0000000..5c626f5 --- /dev/null +++ b/app/src/main/sqldelight/net/h34t/filemure/db/Database.sq @@ -0,0 +1,172 @@ +-- account definition + +CREATE TABLE account ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + email TEXT NOT NULL, + password TEXT NOT NULL, + created TEXT DEFAULT (CURRENT_TIMESTAMP) NOT NULL, + state INTEGER DEFAULT (1) NOT NULL +); + +CREATE INDEX account_state_IDX ON account (state); +CREATE UNIQUE INDEX account_email_IDX ON account (email); + +-- document definition + +CREATE TABLE document ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + account_id INTEGER NOT NULL, + ext_id TEXT NOT NULL, + title TEXT NOT NULL, + description TEXT NOT NULL, + tags TEXT NOT NULL, + created TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, + reference_date TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, + state INTEGER NOT NULL DEFAULT (1), + CONSTRAINT document_account_FK FOREIGN KEY (account_id) REFERENCES account(id) ON DELETE CASCADE +); + +CREATE INDEX document_state_IDX ON document (state); +CREATE UNIQUE INDEX document_ext_id_IDX ON document (ext_id); + + +-- file definition + +CREATE TABLE file ( + id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + account_id INTEGER NOT NULL, + document_id INTEGER DEFAULT NULL, + ext_id TEXT NOT NULL, + filename TEXT NOT NULL, + file_size INTEGER NOT NULL, + content BLOB NOT NULL, + content_type TEXT, + content_extracted TEXT, + created TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, + state INTEGER NOT NULL DEFAULT (1), + CONSTRAINT file_account_FK FOREIGN KEY (account_id) REFERENCES account(id) ON DELETE CASCADE, + CONSTRAINT file_document_FK FOREIGN KEY (document_id) REFERENCES document(id) ON DELETE CASCADE +); + +CREATE INDEX file_state_IDX ON file (state); +CREATE UNIQUE INDEX file_ext_id_IDX ON file (ext_id); + +--- +insertFileIntoLimbo: +INSERT INTO file (account_id, ext_id, filename, content_type, file_size, content) VALUES (?,?,?,?,?,?); + +getLimboFileCount: +SELECT count(*) AS count FROM file WHERE account_id=? AND document_id IS NULL AND state=?; + +getFilesInLimbo: +SELECT + id, + ext_id, + account_id, + filename, + content_type, + content_extracted, + file_size, + created, + state +FROM + file +WHERE + account_id=? AND + document_id IS NULL + AND state=? +ORDER BY + created DESC; + +addDocument: +INSERT INTO document + (account_id, ext_id, title, description, tags, created, reference_date) +VALUES + (?, ?, ?, ?, ?, datetime(), ?); + +attachLimboFilesToDocument: +UPDATE file SET document_id=? WHERE account_id=? AND ext_id IN ?; + +getDocuments: +SELECT + d.id, + d.account_id, + d.ext_id, + d.title, + d.description, + d.tags, + d.created, + d.reference_date, + d.state +FROM + document d +WHERE + account_id=? AND + state=?; + +updateDocument: +UPDATE + document +SET + title=?, + reference_date=?, + tags=?, + description=?, + state=? +WHERE + account_id=? AND + id=?; + +getDocumentByExtId: +SELECT + id, + account_id, + ext_id, + title, + description, + tags, + created, + reference_date, + state +FROM + document d +WHERE + account_id=? AND + ext_id=? AND + state=?; + +getFilesForDocument: +SELECT + id, + ext_id, + account_id, + document_id, + filename, + content_type, + content_extracted, + file_size, + created, + state +FROM + file +WHERE + document_id=? AND + account_id=?; + +getFile: +SELECT + id, + ext_id, + filename, + content_type, + content_extracted, + file_size, + content +FROM + file +WHERE + account_id=? AND + ext_id=?; + +getLastInsertRowId: +SELECT last_insert_rowid();