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

Wed, 18 Aug 2021 14:57:45 +0200

author
Mike Becker <universe@uap-core.de>
date
Wed, 18 Aug 2021 14:57:45 +0200
changeset 225
87328572e36f
parent 215
028792eda9b7
child 227
f0ede8046b59
permissions
-rw-r--r--

#159 adds release and eol dates

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

mercurial