src/main/kotlin/de/uapcore/lightpit/dao/PostgresDataAccessObject.kt

Fri, 30 Dec 2022 19:04:34 +0100

author
Mike Becker <universe@uap-core.de>
date
Fri, 30 Dec 2022 19:04:34 +0100
changeset 263
aa22103809cd
parent 260
fb2ae2d63a56
child 268
ca5501d851fa
permissions
-rw-r--r--

#29 add possibility to relate issues

universe@167 1 /*
universe@180 2 * Copyright 2021 Mike Becker. All rights reserved.
universe@167 3 *
universe@167 4 * Redistribution and use in source and binary forms, with or without
universe@167 5 * modification, are permitted provided that the following conditions are met:
universe@167 6 *
universe@167 7 * 1. Redistributions of source code must retain the above copyright
universe@167 8 * notice, this list of conditions and the following disclaimer.
universe@167 9 *
universe@167 10 * 2. Redistributions in binary form must reproduce the above copyright
universe@167 11 * notice, this list of conditions and the following disclaimer in the
universe@167 12 * documentation and/or other materials provided with the distribution.
universe@167 13 *
universe@167 14 * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
universe@167 15 * AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
universe@167 16 * IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
universe@167 17 * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE
universe@167 18 * FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
universe@167 19 * DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR
universe@167 20 * SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER
universe@167 21 * CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY,
universe@167 22 * OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
universe@167 23 * OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
universe@167 24 */
universe@167 25
universe@167 26 package de.uapcore.lightpit.dao
universe@167 27
universe@167 28 import de.uapcore.lightpit.entities.*
universe@232 29 import de.uapcore.lightpit.types.IssueHistoryType
universe@167 30 import de.uapcore.lightpit.types.WebColor
universe@184 31 import de.uapcore.lightpit.viewmodel.ComponentSummary
universe@184 32 import de.uapcore.lightpit.viewmodel.IssueSummary
universe@184 33 import de.uapcore.lightpit.viewmodel.VersionSummary
universe@189 34 import org.intellij.lang.annotations.Language
universe@167 35 import java.sql.Connection
universe@167 36 import java.sql.PreparedStatement
universe@167 37 import java.sql.ResultSet
universe@167 38
universe@167 39 class PostgresDataAccessObject(private val connection: Connection) : DataAccessObject {
universe@167 40
universe@189 41 /**
universe@189 42 * Prepares the given [sql] statement and executes the [block] function with the prepared statement as receiver.
universe@189 43 * The statement is then closed properly.
universe@189 44 */
universe@189 45 private fun <R> withStatement(@Language("SQL") sql: String, block: PreparedStatement.() -> R) =
universe@189 46 connection.prepareStatement(sql).use(block)
universe@189 47
universe@189 48 /**
universe@189 49 * Prepares the given [sql] statement and executes the [block] function on that statement.
universe@189 50 * The statement is then closed properly.
universe@189 51 */
universe@189 52 private fun <R> useStatement(@Language("SQL") sql: String, block: (PreparedStatement) -> R) =
universe@189 53 connection.prepareStatement(sql).use(block)
universe@189 54
universe@189 55 /**
universe@189 56 * Executes the statement and iterates the whole result set extracting the rows with the given [extractor] function.
universe@189 57 */
universe@189 58 private fun <T> PreparedStatement.queryAll(extractor: (ResultSet) -> T): List<T> = executeQuery().use {
universe@189 59 sequence {
universe@189 60 while (it.next()) {
universe@189 61 yield(extractor(it))
universe@189 62 }
universe@189 63 }.toList()
universe@189 64 }
universe@189 65
universe@189 66 /**
universe@189 67 * Executes the statement and extracts a single row with the given [extractor] function.
universe@189 68 * If the result set is empty, null is returned.
universe@189 69 */
universe@189 70 private fun <T> PreparedStatement.querySingle(extractor: (ResultSet) -> T): T? = executeQuery().use {
universe@189 71 return if (it.next()) extractor(it) else null
universe@189 72 }
universe@189 73
universe@167 74 //<editor-fold desc="User">
universe@189 75 //language=SQL
universe@189 76 private val userQuery = "select userid, username, lastname, givenname, mail from lpit_user"
universe@189 77
universe@189 78 private fun ResultSet.extractUser() = User(getInt("userid")).apply {
universe@189 79 username = getString("username")
universe@189 80 givenname = getString("givenname")
universe@189 81 lastname = getString("lastname")
universe@189 82 mail = getString("mail")
universe@189 83 }
universe@189 84
universe@189 85 private fun ResultSet.containsUserInfo(): Boolean {
universe@189 86 getInt("userid")
universe@189 87 return !wasNull()
universe@189 88 }
universe@189 89
universe@189 90 private fun ResultSet.extractOptionalUser() = if (containsUserInfo()) extractUser() else null
universe@189 91
universe@189 92 override fun listUsers() =
universe@189 93 withStatement("$userQuery where userid > 0 order by username") {
universe@189 94 queryAll { it.extractUser() }
universe@189 95 }
universe@189 96
universe@189 97 override fun findUser(id: Int): User? =
universe@189 98 withStatement("$userQuery where userid = ?") {
universe@189 99 setInt(1, id)
universe@189 100 querySingle { it.extractUser() }
universe@189 101 }
universe@189 102
universe@189 103 override fun findUserByName(username: String): User? =
universe@189 104 withStatement("$userQuery where lower(username) = lower(?)") {
universe@189 105 setString(1, username)
universe@189 106 querySingle { it.extractUser() }
universe@189 107 }
universe@189 108
universe@189 109 override fun insertUser(user: User) {
universe@189 110 withStatement("insert into lpit_user (username, lastname, givenname, mail) values (?, ?, ?, ?)") {
universe@189 111 with(user) {
universe@189 112 setStringSafe(1, username)
universe@189 113 setStringOrNull(2, lastname)
universe@189 114 setStringOrNull(3, givenname)
universe@189 115 setStringOrNull(4, mail)
universe@167 116 }
universe@189 117 executeUpdate()
universe@167 118 }
universe@167 119 }
universe@167 120
universe@189 121 override fun updateUser(user: User) {
universe@189 122 withStatement("update lpit_user set lastname = ?, givenname = ?, mail = ? where userid = ?") {
universe@189 123 with(user) {
universe@189 124 setStringOrNull(1, lastname)
universe@189 125 setStringOrNull(2, givenname)
universe@189 126 setStringOrNull(3, mail)
universe@189 127 setInt(4, id)
universe@189 128 }
universe@189 129 executeUpdate()
universe@167 130 }
universe@167 131 }
universe@225 132 //</editor-fold>
universe@167 133
universe@167 134 //<editor-fold desc="Version">
universe@167 135 //language=SQL
universe@225 136 private val versionQuery = "select versionid, project, name, node, ordinal, status, release, eol from lpit_version"
universe@167 137
universe@189 138 private fun ResultSet.extractVersion() =
universe@189 139 Version(getInt("versionid"), getInt("project")).apply {
universe@189 140 name = getString("name")
universe@189 141 node = getString("node")
universe@189 142 ordinal = getInt("ordinal")
universe@225 143 release = getDate("release")
universe@225 144 eol = getDate("eol")
universe@189 145 status = getEnum("status")
universe@189 146 }
universe@189 147
universe@189 148 override fun listVersions(project: Project): List<Version> =
universe@189 149 withStatement("$versionQuery where project = ? order by ordinal desc, lower(name) desc") {
universe@189 150 setInt(1, project.id)
universe@189 151 queryAll { it.extractVersion() }
universe@189 152 }
universe@189 153
universe@189 154 override fun listVersionSummaries(project: Project): List<VersionSummary> =
universe@189 155 withStatement(
universe@231 156 """with
universe@231 157 version_map as (
universe@231 158 select issueid, status, resolved as versionid, true as isresolved from lpit_issue
universe@231 159 union all
universe@231 160 select issueid, status, affected as versionid, false as isresolved from lpit_issue
universe@231 161 ), issues as (
universe@231 162 select versionid, phase, isresolved, count(issueid) as total from version_map
universe@184 163 join lpit_issue_phases using (status)
universe@184 164 group by versionid, phase, isresolved
universe@184 165 ),
universe@184 166 summary as (
universe@184 167 select versionid, phase, isresolved, total
universe@184 168 from lpit_version v
universe@184 169 left join issues using (versionid)
universe@184 170 )
universe@225 171 select v.versionid, project, name, node, ordinal, status, release, eol,
universe@190 172 ro.total as resolved_open, ra.total as resolved_active, rd.total as resolved_done,
universe@190 173 ao.total as affected_open, aa.total as affected_active, ad.total as affected_done
universe@190 174 from lpit_version v
universe@190 175 left join summary ro on ro.versionid = v.versionid and ro.phase = 0 and ro.isresolved
universe@190 176 left join summary ra on ra.versionid = v.versionid and ra.phase = 1 and ra.isresolved
universe@190 177 left join summary rd on rd.versionid = v.versionid and rd.phase = 2 and rd.isresolved
universe@190 178 left join summary ao on ao.versionid = v.versionid and ao.phase = 0 and not ao.isresolved
universe@190 179 left join summary aa on aa.versionid = v.versionid and aa.phase = 1 and not aa.isresolved
universe@190 180 left join summary ad on ad.versionid = v.versionid and ad.phase = 2 and not ad.isresolved
universe@190 181 where v.project = ?
universe@203 182 order by ordinal desc, lower(name) desc
universe@189 183 """.trimIndent()
universe@189 184 ) {
universe@189 185 setInt(1, project.id)
universe@190 186 queryAll { rs ->
universe@190 187 VersionSummary(rs.extractVersion()).apply {
universe@190 188 reportedTotal.open = rs.getInt("affected_open")
universe@190 189 reportedTotal.active = rs.getInt("affected_active")
universe@190 190 reportedTotal.done = rs.getInt("affected_done")
universe@190 191 resolvedTotal.open = rs.getInt("resolved_open")
universe@190 192 resolvedTotal.active = rs.getInt("resolved_active")
universe@190 193 resolvedTotal.done = rs.getInt("resolved_done")
universe@190 194 }
universe@184 195 }
universe@189 196 }
universe@184 197
universe@189 198 override fun findVersion(id: Int): Version? =
universe@189 199 withStatement("$versionQuery where versionid = ?") {
universe@189 200 setInt(1, id)
universe@189 201 querySingle { it.extractVersion() }
universe@189 202 }
universe@167 203
universe@189 204 override fun findVersionByNode(project: Project, node: String): Version? =
universe@189 205 withStatement("$versionQuery where project = ? and node = ?") {
universe@189 206 setInt(1, project.id)
universe@189 207 setString(2, node)
universe@189 208 querySingle { it.extractVersion() }
universe@189 209 }
universe@167 210
universe@167 211 override fun insertVersion(version: Version) {
universe@225 212 withStatement("insert into lpit_version (name, node, ordinal, status, project, release, eol) values (?, ?, ?, ?::version_status, ?, ?, ?)") {
universe@189 213 with(version) {
universe@189 214 setStringSafe(1, name)
universe@189 215 setStringSafe(2, node)
universe@189 216 setInt(3, ordinal)
universe@189 217 setEnum(4, status)
universe@260 218 setInt(5, projectid)
universe@260 219 setDateOrNull(6, release)
universe@260 220 setDateOrNull(7, eol)
universe@189 221 }
universe@189 222 executeUpdate()
universe@189 223 }
universe@189 224
universe@167 225 }
universe@167 226
universe@167 227 override fun updateVersion(version: Version) {
universe@225 228 withStatement("update lpit_version set name = ?, node = ?, ordinal = ?, status = ?::version_status, release=?,eol=? where versionid = ?") {
universe@189 229 with(version) {
universe@189 230 setStringSafe(1, name)
universe@189 231 setStringSafe(2, node)
universe@189 232 setInt(3, ordinal)
universe@189 233 setEnum(4, status)
universe@225 234 setDateOrNull(5, version.release)
universe@225 235 setDateOrNull(6, version.eol)
universe@225 236 setInt(7, id)
universe@189 237 }
universe@189 238 executeUpdate()
universe@189 239 }
universe@167 240 }
universe@225 241 //</editor-fold>
universe@167 242
universe@167 243 //<editor-fold desc="Component">
universe@167 244 //language=SQL
universe@167 245 private val componentQuery =
universe@167 246 """
universe@227 247 select id, project, name, node, color, ordinal, description, active,
universe@167 248 userid, username, givenname, lastname, mail
universe@167 249 from lpit_component
universe@167 250 left join lpit_user on lead = userid
universe@189 251 """.trimIndent()
universe@167 252
universe@189 253 private fun ResultSet.extractComponent(): Component =
universe@189 254 Component(getInt("id"), getInt("project")).apply {
universe@189 255 name = getString("name")
universe@189 256 node = getString("node")
universe@189 257 color = try {
universe@189 258 WebColor(getString("color"))
universe@189 259 } catch (ex: IllegalArgumentException) {
universe@189 260 WebColor("000000")
universe@189 261 }
universe@189 262 ordinal = getInt("ordinal")
universe@189 263 description = getString("description")
universe@227 264 active = getBoolean("active")
universe@189 265 lead = extractOptionalUser()
universe@189 266 }
universe@189 267
universe@189 268 private fun PreparedStatement.setComponent(index: Int, component: Component): Int {
universe@189 269 with(component) {
universe@189 270 var i = index
universe@189 271 setStringSafe(i++, name)
universe@189 272 setStringSafe(i++, node)
universe@189 273 setStringSafe(i++, color.hex)
universe@189 274 setInt(i++, ordinal)
universe@189 275 setStringOrNull(i++, description)
universe@227 276 setBoolean(i++, active)
universe@189 277 setIntOrNull(i++, lead?.id)
universe@189 278 return i
universe@189 279 }
universe@167 280 }
universe@189 281
universe@189 282 override fun listComponents(project: Project): List<Component> =
universe@189 283 withStatement("$componentQuery where project = ? order by ordinal, lower(name)") {
universe@189 284 setInt(1, project.id)
universe@189 285 queryAll { it.extractComponent() }
universe@189 286 }
universe@189 287
universe@189 288 override fun listComponentSummaries(project: Project): List<ComponentSummary> =
universe@189 289 withStatement(
universe@184 290 """
universe@184 291 with issues as (
universe@184 292 select component, phase, count(issueid) as total
universe@184 293 from lpit_issue
universe@184 294 join lpit_issue_phases using (status)
universe@184 295 group by component, phase
universe@184 296 ),
universe@184 297 summary as (
universe@184 298 select c.id, phase, total
universe@184 299 from lpit_component c
universe@184 300 left join issues i on c.id = i.component
universe@184 301 )
universe@227 302 select c.id, project, name, node, color, ordinal, description, active,
universe@190 303 userid, username, givenname, lastname, mail,
universe@227 304 open.total as open, wip.total as wip, done.total as done
universe@184 305 from lpit_component c
universe@184 306 left join lpit_user on lead = userid
universe@190 307 left join summary open on c.id = open.id and open.phase = 0
universe@227 308 left join summary wip on c.id = wip.id and wip.phase = 1
universe@190 309 left join summary done on c.id = done.id and done.phase = 2
universe@190 310 where c.project = ?
universe@184 311 order by ordinal, name
universe@189 312 """.trimIndent()
universe@189 313 ) {
universe@189 314 setInt(1, project.id)
universe@190 315 queryAll { rs ->
universe@190 316 ComponentSummary(rs.extractComponent()).apply {
universe@190 317 issueSummary.open = rs.getInt("open")
universe@227 318 issueSummary.active = rs.getInt("wip")
universe@190 319 issueSummary.done = rs.getInt("done")
universe@190 320 }
universe@184 321 }
universe@189 322 }
universe@184 323
universe@189 324 override fun findComponent(id: Int): Component? =
universe@189 325 withStatement("$componentQuery where id = ?") {
universe@189 326 setInt(1, id)
universe@189 327 querySingle { it.extractComponent() }
universe@189 328 }
universe@167 329
universe@189 330 override fun findComponentByNode(project: Project, node: String): Component? =
universe@189 331 withStatement("$componentQuery where project = ? and node = ?") {
universe@189 332 setInt(1, project.id)
universe@189 333 setString(2, node)
universe@189 334 querySingle { it.extractComponent() }
universe@189 335 }
universe@167 336
universe@167 337 override fun insertComponent(component: Component) {
universe@227 338 withStatement("insert into lpit_component (name, node, color, ordinal, description, active, lead, project) values (?, ?, ?, ?, ?, ?, ?, ?)") {
universe@189 339 val col = setComponent(1, component)
universe@189 340 setInt(col, component.projectid)
universe@189 341 executeUpdate()
universe@189 342 }
universe@167 343 }
universe@167 344
universe@167 345 override fun updateComponent(component: Component) {
universe@227 346 withStatement("update lpit_component set name = ?, node = ?, color = ?, ordinal = ?, description = ?, active = ?, lead = ? where id = ?") {
universe@189 347 val col = setComponent(1, component)
universe@189 348 setInt(col, component.id)
universe@189 349 executeUpdate()
universe@167 350 }
universe@167 351 }
universe@167 352
universe@225 353 //</editor-fold>
universe@189 354
universe@225 355 //<editor-fold desc="Project">
universe@167 356
universe@167 357 //language=SQL
universe@167 358 private val projectQuery =
universe@167 359 """
universe@175 360 select projectid, name, node, ordinal, description, repourl,
universe@167 361 userid, username, lastname, givenname, mail
universe@167 362 from lpit_project
universe@167 363 left join lpit_user owner on lpit_project.owner = owner.userid
universe@189 364 """.trimIndent()
universe@167 365
universe@189 366 private fun ResultSet.extractProject() =
universe@189 367 Project(getInt("projectid")).apply {
universe@189 368 name = getString("name")
universe@189 369 node = getString("node")
universe@189 370 ordinal = getInt("ordinal")
universe@189 371 description = getString("description")
universe@189 372 repoUrl = getString("repourl")
universe@189 373 owner = extractOptionalUser()
universe@189 374 }
universe@189 375
universe@189 376 private fun PreparedStatement.setProject(index: Int, project: Project): Int {
universe@189 377 var i = index
universe@189 378 with(project) {
universe@189 379 setStringSafe(i++, name)
universe@189 380 setStringSafe(i++, node)
universe@189 381 setInt(i++, ordinal)
universe@189 382 setStringOrNull(i++, description)
universe@189 383 setStringOrNull(i++, repoUrl)
universe@189 384 setIntOrNull(i++, owner?.id)
universe@189 385 }
universe@189 386 return i
universe@167 387 }
universe@189 388
universe@189 389 override fun listProjects(): List<Project> =
universe@189 390 withStatement("$projectQuery order by ordinal, lower(name)") {
universe@189 391 queryAll { it.extractProject() }
universe@189 392 }
universe@189 393
universe@189 394 override fun findProject(id: Int): Project? =
universe@189 395 withStatement("$projectQuery where projectid = ?") {
universe@189 396 setInt(1, id)
universe@189 397 querySingle { it.extractProject() }
universe@189 398 }
universe@189 399
universe@189 400 override fun findProjectByNode(node: String): Project? =
universe@189 401 withStatement("$projectQuery where node = ?") {
universe@189 402 setString(1, node)
universe@189 403 querySingle { it.extractProject() }
universe@189 404 }
universe@189 405
universe@189 406 override fun insertProject(project: Project) {
universe@189 407 withStatement("insert into lpit_project (name, node, ordinal, description, repourl, owner) values (?, ?, ?, ?, ?, ?)") {
universe@189 408 setProject(1, project)
universe@189 409 executeUpdate()
universe@189 410 }
universe@167 411 }
universe@189 412
universe@189 413 override fun updateProject(project: Project) {
universe@189 414 withStatement("update lpit_project set name = ?, node = ?, ordinal = ?, description = ?, repourl = ?, owner = ? where projectid = ?") {
universe@189 415 val col = setProject(1, project)
universe@189 416 setInt(col, project.id)
universe@189 417 executeUpdate()
universe@189 418 }
universe@167 419 }
universe@189 420
universe@189 421 override fun collectIssueSummary(project: Project): IssueSummary =
universe@189 422 withStatement(
universe@167 423 """
universe@167 424 select phase, count(*) as total
universe@167 425 from lpit_issue
universe@167 426 join lpit_issue_phases using(status)
universe@167 427 where project = ?
universe@167 428 group by phase
universe@189 429 """.trimIndent()
universe@189 430 ) {
universe@189 431 setInt(1, project.id)
universe@189 432 executeQuery().use {
universe@189 433 val summary = IssueSummary()
universe@189 434 while (it.next()) {
universe@189 435 val phase = it.getInt("phase")
universe@189 436 val total = it.getInt("total")
universe@189 437 when (phase) {
universe@189 438 0 -> summary.open = total
universe@189 439 1 -> summary.active = total
universe@189 440 2 -> summary.done = total
universe@189 441 }
universe@167 442 }
universe@189 443 summary
universe@167 444 }
universe@167 445 }
universe@167 446
universe@257 447 override fun collectIssueSummary(assignee: User): IssueSummary =
universe@257 448 withStatement(
universe@257 449 """
universe@257 450 select phase, count(*) as total
universe@257 451 from lpit_issue
universe@257 452 join lpit_issue_phases using(status)
universe@257 453 where assignee = ?
universe@257 454 group by phase
universe@257 455 """.trimIndent()
universe@257 456 ) {
universe@257 457 setInt(1, assignee.id)
universe@257 458 executeQuery().use {
universe@257 459 val summary = IssueSummary()
universe@257 460 while (it.next()) {
universe@257 461 val phase = it.getInt("phase")
universe@257 462 val total = it.getInt("total")
universe@257 463 when (phase) {
universe@257 464 0 -> summary.open = total
universe@257 465 1 -> summary.active = total
universe@257 466 2 -> summary.done = total
universe@257 467 }
universe@257 468 }
universe@257 469 summary
universe@257 470 }
universe@257 471 }
universe@257 472
universe@225 473 //</editor-fold>
universe@189 474
universe@225 475 //<editor-fold desc="Issue">
universe@167 476
universe@167 477 //language=SQL
universe@167 478 private val issueQuery =
universe@167 479 """
universe@167 480 select issueid,
universe@167 481 i.project, p.name as projectname, p.node as projectnode,
universe@167 482 component, c.name as componentname, c.node as componentnode,
universe@167 483 status, category, subject, i.description,
universe@167 484 userid, username, givenname, lastname, mail,
universe@231 485 created, updated, eta, affected, resolved
universe@167 486 from lpit_issue i
universe@167 487 join lpit_project p on i.project = projectid
universe@167 488 left join lpit_component c on component = c.id
universe@167 489 left join lpit_user on userid = assignee
universe@189 490 """.trimIndent()
universe@167 491
universe@189 492 private fun ResultSet.extractIssue(): Issue {
universe@189 493 val proj = Project(getInt("project")).apply {
universe@189 494 name = getString("projectname")
universe@189 495 node = getString("projectnode")
universe@189 496 }
universe@189 497 val comp = getInt("component").let {
universe@189 498 if (wasNull()) null else
universe@189 499 Component(it, proj.id).apply {
universe@189 500 name = getString("componentname")
universe@189 501 node = getString("componentnode")
universe@189 502 }
universe@189 503 }
universe@189 504 val issue = Issue(getInt("issueid"), proj).apply {
universe@189 505 component = comp
universe@189 506 status = getEnum("status")
universe@189 507 category = getEnum("category")
universe@189 508 subject = getString("subject")
universe@189 509 description = getString("description")
universe@189 510 assignee = extractOptionalUser()
universe@189 511 created = getTimestamp("created")
universe@189 512 updated = getTimestamp("updated")
universe@189 513 eta = getDate("eta")
universe@231 514 affected = getInt("affected").takeIf { it > 0 }?.let { findVersion(it) }
universe@231 515 resolved = getInt("resolved").takeIf { it > 0 }?.let { findVersion(it) }
universe@189 516 }
universe@189 517
universe@189 518 return issue
universe@167 519 }
universe@167 520
universe@189 521 private fun PreparedStatement.setIssue(index: Int, issue: Issue): Int {
universe@189 522 var i = index
universe@189 523 with(issue) {
universe@189 524 setIntOrNull(i++, component?.id)
universe@189 525 setEnum(i++, status)
universe@189 526 setEnum(i++, category)
universe@189 527 setStringSafe(i++, subject)
universe@189 528 setStringOrNull(i++, description)
universe@189 529 setIntOrNull(i++, assignee?.id)
universe@189 530 setDateOrNull(i++, eta)
universe@231 531 setIntOrNull(i++, affected?.id)
universe@231 532 setIntOrNull(i++, resolved?.id)
universe@189 533 }
universe@189 534 return i
universe@167 535 }
universe@167 536
universe@263 537 override fun listIssues(project: Project): List<Issue> =
universe@263 538 withStatement("$issueQuery where i.project = ?") {
universe@263 539 setInt(1, project.id)
universe@263 540 queryAll { it.extractIssue() }
universe@263 541 }
universe@263 542
universe@248 543 override fun listIssues(project: Project, version: Version?, component: Component?): List<Issue> =
universe@189 544 withStatement(
universe@263 545 """$issueQuery where i.project = ? and
universe@231 546 (not ? or ? in (resolved, affected)) and (not ? or (resolved is null and affected is null)) and
universe@183 547 (not ? or component = ?) and (not ? or component is null)
universe@189 548 """.trimIndent()
universe@189 549 ) {
universe@248 550 fun <T : Entity> applyFilter(search: T?, fflag: Int, nflag: Int, idcol: Int) {
universe@248 551 if (search == null) {
universe@248 552 setBoolean(fflag, false)
universe@248 553 setBoolean(nflag, false)
universe@248 554 setInt(idcol, 0)
universe@248 555 } else {
universe@248 556 setBoolean(fflag, true)
universe@248 557 setBoolean(nflag, false)
universe@248 558 setInt(idcol, search.id)
universe@189 559 }
universe@189 560 }
universe@263 561 setInt(1, project.id)
universe@263 562 applyFilter(version, 2, 4, 3)
universe@263 563 applyFilter(component, 5, 7, 6)
universe@167 564
universe@189 565 queryAll { it.extractIssue() }
universe@189 566 }
universe@167 567
universe@189 568 override fun findIssue(id: Int): Issue? =
universe@189 569 withStatement("$issueQuery where issueid = ?") {
universe@189 570 setInt(1, id)
universe@189 571 querySingle { it.extractIssue() }
universe@189 572 }
universe@189 573
universe@189 574 override fun insertIssue(issue: Issue): Int {
universe@189 575 val id = withStatement(
universe@167 576 """
universe@231 577 insert into lpit_issue (component, status, category, subject, description, assignee, eta, affected, resolved, project)
universe@232 578 values (?, ?::issue_status, ?::issue_category, ?, ?, ?, ?, ?, ?, ?)
universe@167 579 returning issueid
universe@189 580 """.trimIndent()
universe@189 581 ) {
universe@189 582 val col = setIssue(1, issue)
universe@189 583 setInt(col, issue.project.id)
universe@189 584 querySingle { it.getInt(1) }!!
universe@167 585 }
universe@184 586 return id
universe@167 587 }
universe@167 588
universe@167 589 override fun updateIssue(issue: Issue) {
universe@189 590 withStatement(
universe@189 591 """
universe@189 592 update lpit_issue set updated = now(),
universe@189 593 component = ?, status = ?::issue_status, category = ?::issue_category, subject = ?,
universe@231 594 description = ?, assignee = ?, eta = ?, affected = ?, resolved = ?
universe@189 595 where issueid = ?
universe@189 596 """.trimIndent()
universe@189 597 ) {
universe@189 598 val col = setIssue(1, issue)
universe@189 599 setInt(col, issue.id)
universe@189 600 executeUpdate()
universe@189 601 }
universe@167 602 }
universe@167 603
universe@232 604 override fun insertHistoryEvent(issue: Issue, newId: Int) {
universe@232 605 val type = if (newId > 0) IssueHistoryType.New else IssueHistoryType.Update
universe@232 606 val issueid = if (newId > 0) newId else issue.id
universe@232 607
universe@232 608 val eventid =
universe@242 609 withStatement("insert into lpit_issue_history_event(issueid, subject, type) values (?,?,?::issue_history_event) returning eventid") {
universe@232 610 setInt(1, issueid)
universe@242 611 setString(2, issue.subject)
universe@242 612 setEnum(3, type)
universe@232 613 querySingle { it.getInt(1) }!!
universe@232 614 }
universe@232 615 withStatement(
universe@232 616 """
universe@242 617 insert into lpit_issue_history_data (component, status, category, description, assignee, eta, affected, resolved, eventid)
universe@242 618 values (?, ?::issue_status, ?::issue_category, ?, ?, ?, ?, ?, ?)
universe@232 619 """.trimIndent()
universe@232 620 ) {
universe@232 621 setStringOrNull(1, issue.component?.name)
universe@232 622 setEnum(2, issue.status)
universe@232 623 setEnum(3, issue.category)
universe@242 624 setStringOrNull(4, issue.description)
universe@242 625 setStringOrNull(5, issue.assignee?.shortDisplayname)
universe@242 626 setDateOrNull(6, issue.eta)
universe@242 627 setStringOrNull(7, issue.affected?.name)
universe@242 628 setStringOrNull(8, issue.resolved?.name)
universe@242 629 setInt(9, eventid)
universe@232 630 executeUpdate()
universe@232 631 }
universe@232 632 }
universe@232 633
universe@225 634 //</editor-fold>
universe@167 635
universe@263 636 //<editor-fold desc="Issue Relations">
universe@263 637 override fun insertIssueRelation(rel: IssueRelation) {
universe@263 638 withStatement(
universe@263 639 """
universe@263 640 insert into lpit_issue_relation (from_issue, to_issue, type)
universe@263 641 values (?, ?, ?::relation_type)
universe@263 642 on conflict do nothing
universe@263 643 """.trimIndent()
universe@263 644 ) {
universe@263 645 if (rel.reverse) {
universe@263 646 setInt(2, rel.from.id)
universe@263 647 setInt(1, rel.to.id)
universe@263 648 } else {
universe@263 649 setInt(1, rel.from.id)
universe@263 650 setInt(2, rel.to.id)
universe@263 651 }
universe@263 652 setEnum(3, rel.type)
universe@263 653 executeUpdate()
universe@263 654 }
universe@263 655 }
universe@263 656
universe@263 657 override fun deleteIssueRelation(rel: IssueRelation) {
universe@263 658 withStatement("delete from lpit_issue_relation where from_issue = ? and to_issue = ? and type=?::relation_type") {
universe@263 659 if (rel.reverse) {
universe@263 660 setInt(2, rel.from.id)
universe@263 661 setInt(1, rel.to.id)
universe@263 662 } else {
universe@263 663 setInt(1, rel.from.id)
universe@263 664 setInt(2, rel.to.id)
universe@263 665 }
universe@263 666 setEnum(3, rel.type)
universe@263 667 executeUpdate()
universe@263 668 }
universe@263 669 }
universe@263 670
universe@263 671 override fun listIssueRelations(issue: Issue): List<IssueRelation> = buildList {
universe@263 672 withStatement("select to_issue, type from lpit_issue_relation where from_issue = ?") {
universe@263 673 setInt(1, issue.id)
universe@263 674 queryAll { IssueRelation(issue, findIssue(it.getInt("to_issue"))!!, it.getEnum("type"), false) }
universe@263 675 }.forEach(this::add)
universe@263 676 withStatement("select from_issue, type from lpit_issue_relation where to_issue = ?") {
universe@263 677 setInt(1, issue.id)
universe@263 678 queryAll { IssueRelation(issue, findIssue(it.getInt("from_issue"))!!, it.getEnum("type"), true) }
universe@263 679 }.forEach(this::add)
universe@263 680 }
universe@263 681 //</editor-fold>
universe@263 682
universe@225 683 //<editor-fold desc="IssueComment">
universe@167 684
universe@189 685 private fun ResultSet.extractIssueComment() =
universe@189 686 IssueComment(getInt("commentid"), getInt("issueid")).apply {
universe@189 687 created = getTimestamp("created")
universe@189 688 updated = getTimestamp("updated")
universe@189 689 updateCount = getInt("updatecount")
universe@189 690 comment = getString("comment")
universe@189 691 author = extractOptionalUser()
universe@189 692 }
universe@189 693
universe@189 694 override fun listComments(issue: Issue): List<IssueComment> =
universe@189 695 withStatement("select * from lpit_issue_comment left join lpit_user using (userid) where issueid = ? order by created") {
universe@189 696 setInt(1, issue.id)
universe@189 697 queryAll { it.extractIssueComment() }
universe@189 698 }
universe@189 699
universe@207 700 override fun findComment(id: Int): IssueComment? =
universe@207 701 withStatement("select * from lpit_issue_comment left join lpit_user using (userid) where commentid = ?") {
universe@207 702 setInt(1, id)
universe@207 703 querySingle { it.extractIssueComment() }
universe@207 704 }
universe@207 705
universe@232 706 override fun insertComment(issueComment: IssueComment): Int =
universe@189 707 useStatement("update lpit_issue set updated = now() where issueid = ?") { updateIssueDate ->
universe@232 708 withStatement("insert into lpit_issue_comment (issueid, comment, userid) values (?, ? ,?) returning commentid") {
universe@189 709 with(issueComment) {
universe@189 710 updateIssueDate.setInt(1, issueid)
universe@189 711 setInt(1, issueid)
universe@189 712 setStringSafe(2, comment)
universe@189 713 setIntOrNull(3, author?.id)
universe@189 714 }
universe@232 715 val commentid = querySingle { it.getInt(1) }!!
universe@189 716 updateIssueDate.executeUpdate()
universe@232 717 commentid
universe@167 718 }
universe@167 719 }
universe@207 720
universe@207 721 override fun updateComment(issueComment: IssueComment) {
universe@207 722 useStatement("update lpit_issue set updated = now() where issueid = ?") { updateIssueDate ->
universe@207 723 withStatement("update lpit_issue_comment set comment = ?, updatecount = updatecount + 1, updated = now() where commentid = ?") {
universe@207 724 with(issueComment) {
universe@207 725 updateIssueDate.setInt(1, issueid)
universe@207 726 setStringSafe(1, comment)
universe@207 727 setInt(2, id)
universe@207 728 }
universe@207 729 executeUpdate()
universe@207 730 updateIssueDate.executeUpdate()
universe@207 731 }
universe@207 732 }
universe@207 733 }
universe@232 734
universe@232 735
universe@242 736 override fun insertHistoryEvent(issue: Issue, issueComment: IssueComment, newId: Int) {
universe@232 737 val type = if (newId > 0) IssueHistoryType.NewComment else IssueHistoryType.UpdateComment
universe@232 738 val commentid = if (newId > 0) newId else issueComment.id
universe@232 739
universe@232 740 val eventid =
universe@242 741 withStatement("insert into lpit_issue_history_event(issueid, subject, type) values (?,?,?::issue_history_event) returning eventid") {
universe@232 742 setInt(1, issueComment.issueid)
universe@244 743 setString(2, issue.subject)
universe@242 744 setEnum(3, type)
universe@232 745 querySingle { it.getInt(1) }!!
universe@232 746 }
universe@245 747 withStatement("insert into lpit_issue_comment_history (commentid, eventid, comment) values (?,?,?)") {
universe@232 748 setInt(1, commentid)
universe@232 749 setInt(2, eventid)
universe@232 750 setString(3, issueComment.comment)
universe@232 751 executeUpdate()
universe@232 752 }
universe@232 753 }
universe@232 754
universe@225 755 //</editor-fold>
universe@235 756
universe@235 757 //<editor-fold desc="Issue History">
universe@235 758
universe@235 759 override fun listIssueHistory(projectId: Int, days: Int) =
universe@235 760 withStatement(
universe@235 761 """
universe@241 762 select u.username as current_assignee, evt.*, evtdata.*
universe@235 763 from lpit_issue_history_event evt
universe@241 764 join lpit_issue issue using (issueid)
universe@241 765 left join lpit_user u on u.userid = issue.assignee
universe@235 766 join lpit_issue_history_data evtdata using (eventid)
universe@235 767 where project = ?
universe@235 768 and time > now() - (? * interval '1' day)
universe@235 769 order by time desc
universe@235 770 """.trimIndent()
universe@235 771 ) {
universe@235 772 setInt(1, projectId)
universe@235 773 setInt(2, days)
universe@235 774 queryAll { rs->
universe@235 775 with(rs) {
universe@235 776 IssueHistoryEntry(
universe@242 777 subject = getString("subject"),
universe@242 778 time = getTimestamp("time"),
universe@242 779 type = getEnum("type"),
universe@242 780 currentAssignee = getString("current_assignee"),
universe@242 781 issueid = getInt("issueid"),
universe@242 782 component = getString("component") ?: "",
universe@242 783 status = getEnum("status"),
universe@242 784 category = getEnum("category"),
universe@242 785 description = getString("description") ?: "",
universe@242 786 assignee = getString("assignee") ?: "",
universe@242 787 eta = getDate("eta"),
universe@242 788 affected = getString("affected") ?: "",
universe@242 789 resolved = getString("resolved") ?: ""
universe@235 790 )
universe@235 791 }
universe@235 792 }
universe@235 793 }
universe@235 794
universe@241 795 override fun listIssueCommentHistory(projectId: Int, days: Int) =
universe@241 796 withStatement(
universe@241 797 """
universe@241 798 select u.username as current_assignee, evt.*, evtdata.*
universe@241 799 from lpit_issue_history_event evt
universe@241 800 join lpit_issue issue using (issueid)
universe@241 801 left join lpit_user u on u.userid = issue.assignee
universe@241 802 join lpit_issue_comment_history evtdata using (eventid)
universe@241 803 where project = ?
universe@241 804 and time > now() - (? * interval '1' day)
universe@241 805 order by time desc
universe@241 806 """.trimIndent()
universe@241 807 ) {
universe@241 808 setInt(1, projectId)
universe@241 809 setInt(2, days)
universe@241 810 queryAll { rs->
universe@241 811 with(rs) {
universe@241 812 IssueCommentHistoryEntry(
universe@242 813 subject = getString("subject"),
universe@242 814 time = getTimestamp("time"),
universe@242 815 type = getEnum("type"),
universe@242 816 currentAssignee = getString("current_assignee"),
universe@242 817 issueid = getInt("issueid"),
universe@242 818 commentid = getInt("commentid"),
universe@242 819 comment = getString("comment")
universe@241 820 )
universe@241 821 }
universe@241 822 }
universe@241 823 }
universe@241 824
universe@235 825 //</editor-fold>
universe@167 826 }

mercurial