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

Tue, 11 May 2021 17:30:36 +0200

author
Mike Becker <universe@uap-core.de>
date
Tue, 11 May 2021 17:30:36 +0200
changeset 190
a83f1ab56898
parent 189
f7de8158b41c
child 203
7d5b16379768
permissions
-rw-r--r--

fixes #138 - ResultSet processing for summaries

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@167 29 import de.uapcore.lightpit.types.WebColor
universe@184 30 import de.uapcore.lightpit.util.*
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@190 132 //</editor-fold>
universe@167 133
universe@167 134 //<editor-fold desc="Version">
universe@167 135 //language=SQL
universe@167 136 private val versionQuery = "select versionid, project, name, node, ordinal, status 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@189 143 status = getEnum("status")
universe@189 144 }
universe@189 145
universe@189 146 override fun listVersions(project: Project): List<Version> =
universe@189 147 withStatement("$versionQuery where project = ? order by ordinal desc, lower(name) desc") {
universe@189 148 setInt(1, project.id)
universe@189 149 queryAll { it.extractVersion() }
universe@189 150 }
universe@189 151
universe@189 152 override fun listVersionSummaries(project: Project): List<VersionSummary> =
universe@189 153 withStatement(
universe@184 154 """
universe@184 155 with version_map(issueid, versionid, isresolved) as (
universe@190 156 select issueid, versionid, true
universe@184 157 from lpit_issue_resolved_version
universe@184 158 union
universe@190 159 select issueid, versionid, false
universe@184 160 from lpit_issue_affected_version
universe@184 161 ),
universe@184 162 issues as (
universe@184 163 select versionid, phase, isresolved, count(issueid) as total
universe@184 164 from lpit_issue
universe@184 165 join version_map using (issueid)
universe@184 166 join lpit_issue_phases using (status)
universe@184 167 group by versionid, phase, isresolved
universe@184 168 ),
universe@184 169 summary as (
universe@184 170 select versionid, phase, isresolved, total
universe@184 171 from lpit_version v
universe@184 172 left join issues using (versionid)
universe@184 173 )
universe@190 174 select v.versionid, project, name, node, ordinal, status,
universe@190 175 ro.total as resolved_open, ra.total as resolved_active, rd.total as resolved_done,
universe@190 176 ao.total as affected_open, aa.total as affected_active, ad.total as affected_done
universe@190 177 from lpit_version v
universe@190 178 left join summary ro on ro.versionid = v.versionid and ro.phase = 0 and ro.isresolved
universe@190 179 left join summary ra on ra.versionid = v.versionid and ra.phase = 1 and ra.isresolved
universe@190 180 left join summary rd on rd.versionid = v.versionid and rd.phase = 2 and rd.isresolved
universe@190 181 left join summary ao on ao.versionid = v.versionid and ao.phase = 0 and not ao.isresolved
universe@190 182 left join summary aa on aa.versionid = v.versionid and aa.phase = 1 and not aa.isresolved
universe@190 183 left join summary ad on ad.versionid = v.versionid and ad.phase = 2 and not ad.isresolved
universe@190 184 where v.project = ?
universe@184 185 order by ordinal, name
universe@189 186 """.trimIndent()
universe@189 187 ) {
universe@189 188 setInt(1, project.id)
universe@190 189 queryAll { rs ->
universe@190 190 VersionSummary(rs.extractVersion()).apply {
universe@190 191 reportedTotal.open = rs.getInt("affected_open")
universe@190 192 reportedTotal.active = rs.getInt("affected_active")
universe@190 193 reportedTotal.done = rs.getInt("affected_done")
universe@190 194 resolvedTotal.open = rs.getInt("resolved_open")
universe@190 195 resolvedTotal.active = rs.getInt("resolved_active")
universe@190 196 resolvedTotal.done = rs.getInt("resolved_done")
universe@190 197 }
universe@184 198 }
universe@189 199 }
universe@184 200
universe@189 201 override fun findVersion(id: Int): Version? =
universe@189 202 withStatement("$versionQuery where versionid = ?") {
universe@189 203 setInt(1, id)
universe@189 204 querySingle { it.extractVersion() }
universe@189 205 }
universe@167 206
universe@189 207 override fun findVersionByNode(project: Project, node: String): Version? =
universe@189 208 withStatement("$versionQuery where project = ? and node = ?") {
universe@189 209 setInt(1, project.id)
universe@189 210 setString(2, node)
universe@189 211 querySingle { it.extractVersion() }
universe@189 212 }
universe@167 213
universe@167 214 override fun insertVersion(version: Version) {
universe@189 215 withStatement("insert into lpit_version (name, node, ordinal, status, project) values (?, ?, ?, ?::version_status, ?)") {
universe@189 216 with(version) {
universe@189 217 setStringSafe(1, name)
universe@189 218 setStringSafe(2, node)
universe@189 219 setInt(3, ordinal)
universe@189 220 setEnum(4, status)
universe@189 221 setInt(5, version.projectid)
universe@189 222 }
universe@189 223 executeUpdate()
universe@189 224 }
universe@189 225
universe@167 226 }
universe@167 227
universe@167 228 override fun updateVersion(version: Version) {
universe@189 229 withStatement("update lpit_version set name = ?, node = ?, ordinal = ?, status = ?::version_status where versionid = ?") {
universe@189 230 with(version) {
universe@189 231 setStringSafe(1, name)
universe@189 232 setStringSafe(2, node)
universe@189 233 setInt(3, ordinal)
universe@189 234 setEnum(4, status)
universe@189 235 setInt(5, id)
universe@189 236 }
universe@189 237 executeUpdate()
universe@189 238 }
universe@167 239 }
universe@190 240 //</editor-fold>
universe@167 241
universe@167 242 //<editor-fold desc="Component">
universe@167 243 //language=SQL
universe@167 244 private val componentQuery =
universe@167 245 """
universe@167 246 select id, project, name, node, color, ordinal, description,
universe@167 247 userid, username, givenname, lastname, mail
universe@167 248 from lpit_component
universe@167 249 left join lpit_user on lead = userid
universe@189 250 """.trimIndent()
universe@167 251
universe@189 252 private fun ResultSet.extractComponent(): Component =
universe@189 253 Component(getInt("id"), getInt("project")).apply {
universe@189 254 name = getString("name")
universe@189 255 node = getString("node")
universe@189 256 color = try {
universe@189 257 WebColor(getString("color"))
universe@189 258 } catch (ex: IllegalArgumentException) {
universe@189 259 WebColor("000000")
universe@189 260 }
universe@189 261 ordinal = getInt("ordinal")
universe@189 262 description = getString("description")
universe@189 263 lead = extractOptionalUser()
universe@189 264 }
universe@189 265
universe@189 266 private fun PreparedStatement.setComponent(index: Int, component: Component): Int {
universe@189 267 with(component) {
universe@189 268 var i = index
universe@189 269 setStringSafe(i++, name)
universe@189 270 setStringSafe(i++, node)
universe@189 271 setStringSafe(i++, color.hex)
universe@189 272 setInt(i++, ordinal)
universe@189 273 setStringOrNull(i++, description)
universe@189 274 setIntOrNull(i++, lead?.id)
universe@189 275 return i
universe@189 276 }
universe@167 277 }
universe@189 278
universe@189 279 override fun listComponents(project: Project): List<Component> =
universe@189 280 withStatement("$componentQuery where project = ? order by ordinal, lower(name)") {
universe@189 281 setInt(1, project.id)
universe@189 282 queryAll { it.extractComponent() }
universe@189 283 }
universe@189 284
universe@189 285 override fun listComponentSummaries(project: Project): List<ComponentSummary> =
universe@189 286 withStatement(
universe@184 287 """
universe@184 288 with issues as (
universe@184 289 select component, phase, count(issueid) as total
universe@184 290 from lpit_issue
universe@184 291 join lpit_issue_phases using (status)
universe@184 292 group by component, phase
universe@184 293 ),
universe@184 294 summary as (
universe@184 295 select c.id, phase, total
universe@184 296 from lpit_component c
universe@184 297 left join issues i on c.id = i.component
universe@184 298 )
universe@184 299 select c.id, project, name, node, color, ordinal, description,
universe@190 300 userid, username, givenname, lastname, mail,
universe@190 301 open.total as open, active.total as active, done.total as done
universe@184 302 from lpit_component c
universe@184 303 left join lpit_user on lead = userid
universe@190 304 left join summary open on c.id = open.id and open.phase = 0
universe@190 305 left join summary active on c.id = active.id and active.phase = 1
universe@190 306 left join summary done on c.id = done.id and done.phase = 2
universe@190 307 where c.project = ?
universe@184 308 order by ordinal, name
universe@189 309 """.trimIndent()
universe@189 310 ) {
universe@189 311 setInt(1, project.id)
universe@190 312 queryAll { rs ->
universe@190 313 ComponentSummary(rs.extractComponent()).apply {
universe@190 314 issueSummary.open = rs.getInt("open")
universe@190 315 issueSummary.active = rs.getInt("active")
universe@190 316 issueSummary.done = rs.getInt("done")
universe@190 317 }
universe@184 318 }
universe@189 319 }
universe@184 320
universe@189 321 override fun findComponent(id: Int): Component? =
universe@189 322 withStatement("$componentQuery where id = ?") {
universe@189 323 setInt(1, id)
universe@189 324 querySingle { it.extractComponent() }
universe@189 325 }
universe@167 326
universe@189 327 override fun findComponentByNode(project: Project, node: String): Component? =
universe@189 328 withStatement("$componentQuery where project = ? and node = ?") {
universe@189 329 setInt(1, project.id)
universe@189 330 setString(2, node)
universe@189 331 querySingle { it.extractComponent() }
universe@189 332 }
universe@167 333
universe@167 334 override fun insertComponent(component: Component) {
universe@189 335 withStatement("insert into lpit_component (name, node, color, ordinal, description, lead, project) values (?, ?, ?, ?, ?, ?, ?)") {
universe@189 336 val col = setComponent(1, component)
universe@189 337 setInt(col, component.projectid)
universe@189 338 executeUpdate()
universe@189 339 }
universe@167 340 }
universe@167 341
universe@167 342 override fun updateComponent(component: Component) {
universe@189 343 withStatement("update lpit_component set name = ?, node = ?, color = ?, ordinal = ?, description = ?, lead = ? where id = ?") {
universe@189 344 val col = setComponent(1, component)
universe@189 345 setInt(col, component.id)
universe@189 346 executeUpdate()
universe@167 347 }
universe@167 348 }
universe@167 349
universe@189 350 //</editor-fold>
universe@189 351
universe@189 352 //<editor-fold desc="Project">
universe@167 353
universe@167 354 //language=SQL
universe@167 355 private val projectQuery =
universe@167 356 """
universe@175 357 select projectid, name, node, ordinal, description, repourl,
universe@167 358 userid, username, lastname, givenname, mail
universe@167 359 from lpit_project
universe@167 360 left join lpit_user owner on lpit_project.owner = owner.userid
universe@189 361 """.trimIndent()
universe@167 362
universe@189 363 private fun ResultSet.extractProject() =
universe@189 364 Project(getInt("projectid")).apply {
universe@189 365 name = getString("name")
universe@189 366 node = getString("node")
universe@189 367 ordinal = getInt("ordinal")
universe@189 368 description = getString("description")
universe@189 369 repoUrl = getString("repourl")
universe@189 370 owner = extractOptionalUser()
universe@189 371 }
universe@189 372
universe@189 373 private fun PreparedStatement.setProject(index: Int, project: Project): Int {
universe@189 374 var i = index
universe@189 375 with(project) {
universe@189 376 setStringSafe(i++, name)
universe@189 377 setStringSafe(i++, node)
universe@189 378 setInt(i++, ordinal)
universe@189 379 setStringOrNull(i++, description)
universe@189 380 setStringOrNull(i++, repoUrl)
universe@189 381 setIntOrNull(i++, owner?.id)
universe@189 382 }
universe@189 383 return i
universe@167 384 }
universe@189 385
universe@189 386 override fun listProjects(): List<Project> =
universe@189 387 withStatement("$projectQuery order by ordinal, lower(name)") {
universe@189 388 queryAll { it.extractProject() }
universe@189 389 }
universe@189 390
universe@189 391 override fun findProject(id: Int): Project? =
universe@189 392 withStatement("$projectQuery where projectid = ?") {
universe@189 393 setInt(1, id)
universe@189 394 querySingle { it.extractProject() }
universe@189 395 }
universe@189 396
universe@189 397 override fun findProjectByNode(node: String): Project? =
universe@189 398 withStatement("$projectQuery where node = ?") {
universe@189 399 setString(1, node)
universe@189 400 querySingle { it.extractProject() }
universe@189 401 }
universe@189 402
universe@189 403 override fun insertProject(project: Project) {
universe@189 404 withStatement("insert into lpit_project (name, node, ordinal, description, repourl, owner) values (?, ?, ?, ?, ?, ?)") {
universe@189 405 setProject(1, project)
universe@189 406 executeUpdate()
universe@189 407 }
universe@167 408 }
universe@189 409
universe@189 410 override fun updateProject(project: Project) {
universe@189 411 withStatement("update lpit_project set name = ?, node = ?, ordinal = ?, description = ?, repourl = ?, owner = ? where projectid = ?") {
universe@189 412 val col = setProject(1, project)
universe@189 413 setInt(col, project.id)
universe@189 414 executeUpdate()
universe@189 415 }
universe@167 416 }
universe@189 417
universe@189 418 override fun collectIssueSummary(project: Project): IssueSummary =
universe@189 419 withStatement(
universe@167 420 """
universe@167 421 select phase, count(*) as total
universe@167 422 from lpit_issue
universe@167 423 join lpit_issue_phases using(status)
universe@167 424 where project = ?
universe@167 425 group by phase
universe@189 426 """.trimIndent()
universe@189 427 ) {
universe@189 428 setInt(1, project.id)
universe@189 429 executeQuery().use {
universe@189 430 val summary = IssueSummary()
universe@189 431 while (it.next()) {
universe@189 432 val phase = it.getInt("phase")
universe@189 433 val total = it.getInt("total")
universe@189 434 when (phase) {
universe@189 435 0 -> summary.open = total
universe@189 436 1 -> summary.active = total
universe@189 437 2 -> summary.done = total
universe@189 438 }
universe@167 439 }
universe@189 440 summary
universe@167 441 }
universe@167 442 }
universe@167 443
universe@189 444 //</editor-fold>
universe@189 445
universe@189 446 //<editor-fold desc="Issue">
universe@167 447
universe@167 448 //language=SQL
universe@167 449 private val issueQuery =
universe@167 450 """
universe@167 451 select issueid,
universe@167 452 i.project, p.name as projectname, p.node as projectnode,
universe@167 453 component, c.name as componentname, c.node as componentnode,
universe@167 454 status, category, subject, i.description,
universe@167 455 userid, username, givenname, lastname, mail,
universe@167 456 created, updated, eta
universe@167 457 from lpit_issue i
universe@167 458 join lpit_project p on i.project = projectid
universe@167 459 left join lpit_component c on component = c.id
universe@167 460 left join lpit_user on userid = assignee
universe@189 461 """.trimIndent()
universe@167 462
universe@189 463 private fun ResultSet.extractIssue(): Issue {
universe@189 464 val proj = Project(getInt("project")).apply {
universe@189 465 name = getString("projectname")
universe@189 466 node = getString("projectnode")
universe@189 467 }
universe@189 468 val comp = getInt("component").let {
universe@189 469 if (wasNull()) null else
universe@189 470 Component(it, proj.id).apply {
universe@189 471 name = getString("componentname")
universe@189 472 node = getString("componentnode")
universe@189 473 }
universe@189 474 }
universe@189 475 val issue = Issue(getInt("issueid"), proj).apply {
universe@189 476 component = comp
universe@189 477 status = getEnum("status")
universe@189 478 category = getEnum("category")
universe@189 479 subject = getString("subject")
universe@189 480 description = getString("description")
universe@189 481 assignee = extractOptionalUser()
universe@189 482 created = getTimestamp("created")
universe@189 483 updated = getTimestamp("updated")
universe@189 484 eta = getDate("eta")
universe@189 485 }
universe@189 486
universe@189 487 fun versionQuery(table: String) =
universe@167 488 """
universe@167 489 select versionid, project, name, status, ordinal, node
universe@189 490 from lpit_version join $table using (versionid)
universe@167 491 where issueid = ?
universe@167 492 order by ordinal, name
universe@189 493 """.trimIndent()
universe@189 494
universe@189 495 issue.affectedVersions = withStatement(versionQuery("lpit_issue_affected_version")) {
universe@189 496 setInt(1, issue.id)
universe@189 497 queryAll { it.extractVersion() }
universe@189 498 }
universe@189 499 issue.resolvedVersions = withStatement(versionQuery("lpit_issue_resolved_version")) {
universe@189 500 setInt(1, issue.id)
universe@189 501 queryAll { it.extractVersion() }
universe@189 502 }
universe@189 503 return issue
universe@167 504 }
universe@167 505
universe@189 506 private fun PreparedStatement.setIssue(index: Int, issue: Issue): Int {
universe@189 507 var i = index
universe@189 508 with(issue) {
universe@189 509 setIntOrNull(i++, component?.id)
universe@189 510 setEnum(i++, status)
universe@189 511 setEnum(i++, category)
universe@189 512 setStringSafe(i++, subject)
universe@189 513 setStringOrNull(i++, description)
universe@189 514 setIntOrNull(i++, assignee?.id)
universe@189 515 setDateOrNull(i++, eta)
universe@189 516 }
universe@189 517 return i
universe@167 518 }
universe@167 519
universe@189 520 override fun listIssues(filter: IssueFilter): List<Issue> =
universe@189 521 withStatement(
universe@167 522 """
universe@167 523 with issue_version as (
universe@167 524 select issueid, versionid from lpit_issue_affected_version
universe@167 525 union select issueid, versionid from lpit_issue_resolved_version
universe@183 526 ),
universe@189 527 filtered_issues as (
universe@183 528 select distinct issueid from lpit_issue
universe@183 529 left join issue_version using (issueid)
universe@183 530 where
universe@183 531 (not ? or project = ?) and
universe@183 532 (not ? or versionid = ?) and (not ? or versionid is null) and
universe@183 533 (not ? or component = ?) and (not ? or component is null)
universe@183 534 )
universe@189 535 $issueQuery join filtered_issues using (issueid)
universe@189 536 """.trimIndent()
universe@189 537 ) {
universe@189 538 fun <T : Entity> applyFilter(filter: Filter<T>, fflag: Int, nflag: Int, idcol: Int) {
universe@189 539 when (filter) {
universe@189 540 is AllFilter -> {
universe@189 541 setBoolean(fflag, false)
universe@189 542 setBoolean(nflag, false)
universe@189 543 setInt(idcol, 0)
universe@189 544 }
universe@189 545 is NoneFilter -> {
universe@189 546 setBoolean(fflag, false)
universe@189 547 setBoolean(nflag, true)
universe@189 548 setInt(idcol, 0)
universe@189 549 }
universe@189 550 is SpecificFilter -> {
universe@189 551 setBoolean(fflag, true)
universe@189 552 setBoolean(nflag, false)
universe@189 553 setInt(idcol, filter.obj.id)
universe@189 554 }
universe@189 555 else -> {
universe@189 556 TODO("Implement range filter.")
universe@189 557 }
universe@189 558 }
universe@189 559 }
universe@189 560 when (filter.project) {
universe@189 561 is AllFilter -> {
universe@189 562 setBoolean(1, false)
universe@189 563 setInt(2, 0)
universe@189 564 }
universe@189 565 is SpecificFilter -> {
universe@189 566 setBoolean(1, true)
universe@189 567 setInt(2, filter.project.obj.id)
universe@189 568 }
universe@189 569 else -> throw IllegalArgumentException()
universe@189 570 }
universe@189 571 applyFilter(filter.version, 3, 5, 4)
universe@189 572 applyFilter(filter.component, 6, 8, 7)
universe@167 573
universe@189 574 queryAll { it.extractIssue() }
universe@189 575 }
universe@167 576
universe@189 577 override fun findIssue(id: Int): Issue? =
universe@189 578 withStatement("$issueQuery where issueid = ?") {
universe@189 579 setInt(1, id)
universe@189 580 querySingle { it.extractIssue() }
universe@189 581 }
universe@189 582
universe@189 583 private fun insertVersionInfo(id: Int, issue: Issue) {
universe@189 584 withStatement("insert into lpit_issue_affected_version (issueid, versionid) values (?,?)") {
universe@189 585 setInt(1, id)
universe@189 586 issue.affectedVersions.forEach {
universe@189 587 setInt(2, it.id)
universe@189 588 executeUpdate()
universe@167 589 }
universe@189 590 }
universe@189 591 withStatement("insert into lpit_issue_resolved_version (issueid, versionid) values (?,?)") {
universe@189 592 setInt(1, id)
universe@189 593 issue.resolvedVersions.forEach {
universe@189 594 setInt(2, it.id)
universe@189 595 executeUpdate()
universe@167 596 }
universe@167 597 }
universe@167 598 }
universe@167 599
universe@189 600 override fun insertIssue(issue: Issue): Int {
universe@189 601 val id = withStatement(
universe@167 602 """
universe@167 603 insert into lpit_issue (component, status, category, subject, description, assignee, eta, project)
universe@167 604 values (?, ?::issue_status, ?::issue_category, ?, ?, ?, ?, ?)
universe@167 605 returning issueid
universe@189 606 """.trimIndent()
universe@189 607 ) {
universe@189 608 val col = setIssue(1, issue)
universe@189 609 setInt(col, issue.project.id)
universe@189 610 querySingle { it.getInt(1) }!!
universe@167 611 }
universe@188 612 insertVersionInfo(id, issue)
universe@184 613 return id
universe@167 614 }
universe@167 615
universe@167 616 override fun updateIssue(issue: Issue) {
universe@189 617 withStatement(
universe@189 618 """
universe@189 619 update lpit_issue set updated = now(),
universe@189 620 component = ?, status = ?::issue_status, category = ?::issue_category, subject = ?,
universe@189 621 description = ?, assignee = ?, eta = ?
universe@189 622 where issueid = ?
universe@189 623 """.trimIndent()
universe@189 624 ) {
universe@189 625 val col = setIssue(1, issue)
universe@189 626 setInt(col, issue.id)
universe@189 627 executeUpdate()
universe@189 628 }
universe@189 629
universe@167 630 // TODO: improve by only inserting / deleting changed version information
universe@189 631 withStatement("delete from lpit_issue_affected_version where issueid = ?") {
universe@189 632 setInt(1, issue.id)
universe@189 633 executeUpdate()
universe@189 634 }
universe@189 635 withStatement("delete from lpit_issue_resolved_version where issueid = ?") {
universe@189 636 setInt(1, issue.id)
universe@189 637 executeUpdate()
universe@189 638 }
universe@188 639 insertVersionInfo(issue.id, issue)
universe@167 640 }
universe@167 641
universe@189 642 //</editor-fold>
universe@167 643
universe@189 644 //<editor-fold desc="IssueComment">
universe@167 645
universe@189 646 private fun ResultSet.extractIssueComment() =
universe@189 647 IssueComment(getInt("commentid"), getInt("issueid")).apply {
universe@189 648 created = getTimestamp("created")
universe@189 649 updated = getTimestamp("updated")
universe@189 650 updateCount = getInt("updatecount")
universe@189 651 comment = getString("comment")
universe@189 652 author = extractOptionalUser()
universe@189 653 }
universe@189 654
universe@189 655 override fun listComments(issue: Issue): List<IssueComment> =
universe@189 656 withStatement("select * from lpit_issue_comment left join lpit_user using (userid) where issueid = ? order by created") {
universe@189 657 setInt(1, issue.id)
universe@189 658 queryAll { it.extractIssueComment() }
universe@189 659 }
universe@189 660
universe@189 661 override fun insertComment(issueComment: IssueComment) {
universe@189 662 useStatement("update lpit_issue set updated = now() where issueid = ?") { updateIssueDate ->
universe@189 663 withStatement("insert into lpit_issue_comment (issueid, comment, userid) values (?, ? ,?)") {
universe@189 664 with(issueComment) {
universe@189 665 updateIssueDate.setInt(1, issueid)
universe@189 666 setInt(1, issueid)
universe@189 667 setStringSafe(2, comment)
universe@189 668 setIntOrNull(3, author?.id)
universe@189 669 }
universe@189 670 executeUpdate()
universe@189 671 updateIssueDate.executeUpdate()
universe@167 672 }
universe@167 673 }
universe@167 674 }
universe@189 675 //</editor-fold>
universe@167 676 }

mercurial