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

Sat, 22 Jul 2023 22:32:04 +0200

author
Mike Becker <universe@uap-core.de>
date
Sat, 22 Jul 2023 22:32:04 +0200
changeset 284
671c1c8fbf1c
parent 268
ca5501d851fa
child 292
703591e739f4
permissions
-rw-r--r--

add full support for commit references - fixes #276

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

mercurial