src/main/java/de/uapcore/lightpit/dao/postgres/PGIssueDao.java

Sat, 31 Oct 2020 09:50:15 +0100

author
Mike Becker <universe@uap-core.de>
date
Sat, 31 Oct 2020 09:50:15 +0100
changeset 154
3d10f2a390a1
parent 150
822b7e3d064d
permissions
-rw-r--r--

fixes issues that are assigned no version and no component are listed under all projects

universe@38 1 /*
universe@38 2 * DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER.
universe@38 3 *
universe@38 4 * Copyright 2018 Mike Becker. All rights reserved.
universe@38 5 *
universe@38 6 * Redistribution and use in source and binary forms, with or without
universe@38 7 * modification, are permitted provided that the following conditions are met:
universe@38 8 *
universe@38 9 * 1. Redistributions of source code must retain the above copyright
universe@38 10 * notice, this list of conditions and the following disclaimer.
universe@38 11 *
universe@38 12 * 2. Redistributions in binary form must reproduce the above copyright
universe@38 13 * notice, this list of conditions and the following disclaimer in the
universe@38 14 * documentation and/or other materials provided with the distribution.
universe@38 15 *
universe@38 16 * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
universe@38 17 * AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
universe@38 18 * IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
universe@38 19 * ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE
universe@38 20 * LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR
universe@38 21 * CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF
universe@38 22 * SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS
universe@38 23 * INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN
universe@38 24 * CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE)
universe@38 25 * ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE
universe@38 26 * POSSIBILITY OF SUCH DAMAGE.
universe@38 27 *
universe@38 28 */
universe@38 29 package de.uapcore.lightpit.dao.postgres;
universe@38 30
universe@62 31 import de.uapcore.lightpit.dao.IssueDao;
universe@62 32 import de.uapcore.lightpit.entities.*;
universe@38 33
universe@134 34 import java.sql.*;
universe@47 35 import java.util.ArrayList;
universe@47 36 import java.util.List;
universe@38 37 import java.util.Objects;
universe@134 38 import java.util.Optional;
universe@38 39
universe@62 40 import static de.uapcore.lightpit.dao.Functions.*;
universe@62 41
universe@62 42 public final class PGIssueDao implements IssueDao {
universe@38 43
universe@86 44 private final PreparedStatement insert, update, list, listForVersion, find;
universe@88 45 private final PreparedStatement affectedVersions, resolvedVersions;
universe@88 46 private final PreparedStatement clearAffected, clearResolved;
universe@88 47 private final PreparedStatement insertAffected, insertResolved;
universe@124 48 private final PreparedStatement insertComment, updateComment, listComments;
universe@38 49
universe@62 50 public PGIssueDao(Connection connection) throws SQLException {
universe@138 51 final var query = "select issueid, i.project, p.name as projectname, p.node as projectnode, "+
universe@138 52 "component, c.name as componentname, c.node as componentnode, " +
universe@134 53 "status, category, subject, i.description, " +
universe@75 54 "userid, username, givenname, lastname, mail, " +
universe@75 55 "created, updated, eta " +
universe@83 56 "from lpit_issue i " +
universe@134 57 "join lpit_project p on i.project = projectid " +
universe@134 58 "left join lpit_component c on component = c.id " +
universe@138 59 "left join lpit_user on userid = assignee ";
universe@138 60
universe@138 61 list = connection.prepareStatement(query +
universe@134 62 "where i.project = ? and coalesce(component, -1) = coalesce(?, component, -1)");
universe@86 63
universe@86 64 listForVersion = connection.prepareStatement(
universe@86 65 "with issue_version as ( "+
universe@86 66 "select issueid, versionid from lpit_issue_affected_version union "+
universe@86 67 "select issueid, versionid from lpit_issue_resolved_version) "+
universe@138 68 query +
universe@105 69 "left join issue_version using (issueid) "+
universe@154 70 "where i.project = ? "+
universe@154 71 "and coalesce(versionid,-1) = ? and coalesce(component, -1) = coalesce(?, component, -1)"
universe@86 72 );
universe@47 73
universe@138 74 find = connection.prepareStatement(query + "where issueid = ? ");
universe@38 75
universe@38 76 insert = connection.prepareStatement(
universe@134 77 "insert into lpit_issue (project, component, status, category, subject, description, assignee, eta) " +
universe@135 78 "values (?, ?, ?::issue_status, ?::issue_category, ?, ?, ?, ?) returning issueid"
universe@38 79 );
universe@38 80 update = connection.prepareStatement(
universe@134 81 "update lpit_issue set " +
universe@134 82 "updated = now(), component = ?, status = ?::issue_status, category = ?::issue_category, " +
universe@75 83 "subject = ?, description = ?, assignee = ?, eta = ? where issueid = ?"
universe@75 84 );
universe@75 85
universe@75 86 affectedVersions = connection.prepareStatement(
universe@83 87 "select versionid, name, status, ordinal " +
universe@83 88 "from lpit_version join lpit_issue_affected_version using (versionid) " +
universe@75 89 "where issueid = ? " +
universe@83 90 "order by ordinal, name"
universe@75 91 );
universe@83 92 clearAffected = connection.prepareStatement("delete from lpit_issue_affected_version where issueid = ?");
universe@83 93 insertAffected = connection.prepareStatement("insert into lpit_issue_affected_version (issueid, versionid) values (?,?)");
universe@75 94
universe@75 95 resolvedVersions = connection.prepareStatement(
universe@83 96 "select versionid, name, status, ordinal " +
universe@75 97 "from lpit_version v join lpit_issue_resolved_version using (versionid) " +
universe@75 98 "where issueid = ? " +
universe@83 99 "order by ordinal, name"
universe@38 100 );
universe@83 101 clearResolved = connection.prepareStatement("delete from lpit_issue_resolved_version where issueid = ?");
universe@83 102 insertResolved = connection.prepareStatement("insert into lpit_issue_resolved_version (issueid, versionid) values (?,?)");
universe@124 103
universe@124 104 insertComment = connection.prepareStatement(
universe@124 105 "insert into lpit_issue_comment (issueid, comment, userid) values (?, ? ,?)"
universe@124 106 );
universe@124 107 updateComment = connection.prepareStatement(
universe@124 108 "update lpit_issue_comment set comment = ?, updated = now(), updatecount = updatecount+1 where commentid = ?"
universe@124 109 );
universe@124 110 listComments = connection.prepareStatement(
universe@124 111 "select * from lpit_issue_comment left join lpit_user using (userid) where issueid = ? order by created"
universe@124 112 );
universe@38 113 }
universe@38 114
universe@75 115 private Issue mapColumns(ResultSet result) throws SQLException {
universe@75 116 final var project = new Project(result.getInt("project"));
universe@83 117 project.setName(result.getString("projectname"));
universe@138 118 project.setNode(result.getString("projectnode"));
universe@134 119 var component = new Component(result.getInt("component"));
universe@134 120 if (result.wasNull()) {
universe@134 121 component = null;
universe@134 122 } else {
universe@134 123 component.setName(result.getString("componentname"));
universe@138 124 component.setNode(result.getString("componentnode"));
universe@134 125 }
universe@86 126 final var issue = new Issue(result.getInt("issueid"));
universe@86 127 issue.setProject(project);
universe@134 128 issue.setComponent(component);
universe@75 129 issue.setStatus(IssueStatus.valueOf(result.getString("status")));
universe@75 130 issue.setCategory(IssueCategory.valueOf(result.getString("category")));
universe@75 131 issue.setSubject(result.getString("subject"));
universe@75 132 issue.setDescription(result.getString("description"));
universe@128 133 issue.setAssignee(PGUserDao.mapColumns(result));
universe@75 134 issue.setCreated(result.getTimestamp("created"));
universe@75 135 issue.setUpdated(result.getTimestamp("updated"));
universe@75 136 issue.setEta(result.getDate("eta"));
universe@62 137 return issue;
universe@38 138 }
universe@38 139
universe@86 140 private Version mapVersion(ResultSet result) throws SQLException {
universe@86 141 final var version = new Version(result.getInt("versionid"));
universe@83 142 version.setName(result.getString("name"));
universe@83 143 version.setOrdinal(result.getInt("ordinal"));
universe@83 144 version.setStatus(VersionStatus.valueOf(result.getString("status")));
universe@75 145 return version;
universe@75 146 }
universe@75 147
universe@83 148 private void updateVersionLists(Issue instance) throws SQLException {
universe@83 149 clearAffected.setInt(1, instance.getId());
universe@83 150 clearResolved.setInt(1, instance.getId());
universe@83 151 insertAffected.setInt(1, instance.getId());
universe@83 152 insertResolved.setInt(1, instance.getId());
universe@83 153 clearAffected.executeUpdate();
universe@83 154 clearResolved.executeUpdate();
universe@83 155 for (Version v : instance.getAffectedVersions()) {
universe@83 156 insertAffected.setInt(2, v.getId());
universe@83 157 insertAffected.executeUpdate();
universe@83 158 }
universe@83 159 for (Version v : instance.getResolvedVersions()) {
universe@83 160 insertResolved.setInt(2, v.getId());
universe@83 161 insertResolved.executeUpdate();
universe@83 162 }
universe@83 163 }
universe@83 164
universe@134 165 private int setData(PreparedStatement stmt, int column, Issue instance) throws SQLException {
universe@134 166 setForeignKeyOrNull(stmt, ++column, instance.getComponent(), Component::getId);
universe@134 167 stmt.setString(++column, instance.getStatus().name());
universe@134 168 stmt.setString(++column, instance.getCategory().name());
universe@134 169 stmt.setString(++column, instance.getSubject());
universe@134 170 setStringOrNull(stmt, ++column, instance.getDescription());
universe@134 171 setForeignKeyOrNull(stmt, ++column, instance.getAssignee(), User::getId);
universe@134 172 setDateOrNull(stmt, ++column, instance.getEta());
universe@134 173 return column;
universe@134 174 }
universe@134 175
universe@38 176 @Override
universe@128 177 public void save(Issue instance, Project project) throws SQLException {
universe@62 178 Objects.requireNonNull(instance.getSubject());
universe@128 179 instance.setProject(project);
universe@134 180 int column = 0;
universe@134 181 insert.setInt(++column, instance.getProject().getId());
universe@134 182 setData(insert, column, instance);
universe@75 183 // insert and retrieve the ID
universe@75 184 final var rs = insert.executeQuery();
universe@75 185 rs.next();
universe@75 186 instance.setId(rs.getInt(1));
universe@83 187 updateVersionLists(instance);
universe@38 188 }
universe@38 189
universe@38 190 @Override
universe@62 191 public boolean update(Issue instance) throws SQLException {
universe@75 192 if (instance.getId() < 0) return false;
universe@62 193 Objects.requireNonNull(instance.getSubject());
universe@134 194 int column = setData(update, 0, instance);
universe@134 195 update.setInt(++column, instance.getId());
universe@83 196 boolean success = update.executeUpdate() > 0;
universe@83 197 if (success) {
universe@83 198 updateVersionLists(instance);
universe@83 199 return true;
universe@83 200 } else {
universe@83 201 return false;
universe@83 202 }
universe@38 203 }
universe@47 204
universe@134 205 private List<Issue> executeQuery(PreparedStatement query) throws SQLException {
universe@75 206 List<Issue> issues = new ArrayList<>();
universe@86 207 try (var result = query.executeQuery()) {
universe@47 208 while (result.next()) {
universe@75 209 issues.add(mapColumns(result));
universe@47 210 }
universe@47 211 }
universe@75 212 return issues;
universe@47 213 }
universe@47 214
universe@47 215 @Override
universe@86 216 public List<Issue> list(Project project) throws SQLException {
universe@134 217 list.setInt(1, project.getId());
universe@134 218 list.setNull(2, Types.INTEGER);
universe@134 219 return executeQuery(list);
universe@86 220 }
universe@86 221
universe@86 222 @Override
universe@134 223 public List<Issue> list(Project project, Component component, Version version) throws SQLException {
universe@154 224 listForVersion.setInt(1, project.getId());
universe@154 225 listForVersion.setInt(2, Optional.ofNullable(version).map(Version::getId).orElse(-1));
universe@154 226 listForVersion.setInt(3, Optional.ofNullable(component).map(Component::getId).orElse(-1));
universe@134 227 return executeQuery(listForVersion);
universe@134 228 }
universe@134 229
universe@134 230 @Override
universe@134 231 public List<Issue> list(Project project, Version version) throws SQLException {
universe@154 232 listForVersion.setInt(1, project.getId());
universe@154 233 listForVersion.setInt(2, Optional.ofNullable(version).map(Version::getId).orElse(-1));
universe@154 234 listForVersion.setNull(3, Types.INTEGER);
universe@134 235 return executeQuery(listForVersion);
universe@134 236 }
universe@134 237
universe@134 238 @Override
universe@134 239 public List<Issue> list(Project project, Component component) throws SQLException {
universe@134 240 list.setInt(1, project.getId());
universe@134 241 list.setInt(2, Optional.ofNullable(component).map(Component::getId).orElse(-1));
universe@134 242 return executeQuery(list);
universe@86 243 }
universe@86 244
universe@86 245 @Override
universe@62 246 public Issue find(int id) throws SQLException {
universe@47 247 find.setInt(1, id);
universe@47 248 try (var result = find.executeQuery()) {
universe@47 249 if (result.next()) {
universe@47 250 return mapColumns(result);
universe@47 251 } else {
universe@47 252 return null;
universe@47 253 }
universe@47 254 }
universe@47 255 }
universe@75 256
universe@75 257 private List<Version> listVersions(PreparedStatement stmt, Issue issue) throws SQLException {
universe@75 258 stmt.setInt(1, issue.getId());
universe@75 259 List<Version> versions = new ArrayList<>();
universe@75 260 try (var result = stmt.executeQuery()) {
universe@75 261 while (result.next()) {
universe@86 262 versions.add(mapVersion(result));
universe@75 263 }
universe@75 264 }
universe@75 265 return versions;
universe@75 266 }
universe@75 267
universe@75 268 @Override
universe@75 269 public void joinVersionInformation(Issue issue) throws SQLException {
universe@75 270 Objects.requireNonNull(issue.getProject());
universe@75 271 issue.setAffectedVersions(listVersions(affectedVersions, issue));
universe@75 272 issue.setResolvedVersions(listVersions(resolvedVersions, issue));
universe@75 273 }
universe@124 274
universe@124 275 @Override
universe@124 276 public List<IssueComment> listComments(Issue issue) throws SQLException {
universe@124 277 listComments.setInt(1, issue.getId());
universe@124 278 List<IssueComment> comments = new ArrayList<>();
universe@124 279 try (var result = listComments.executeQuery()) {
universe@124 280 while (result.next()) {
universe@150 281 final var comment = new IssueComment(result.getInt("commentid"));
universe@124 282 comment.setCreated(result.getTimestamp("created"));
universe@124 283 comment.setUpdated(result.getTimestamp("updated"));
universe@124 284 comment.setUpdateCount(result.getInt("updatecount"));
universe@124 285 comment.setComment(result.getString("comment"));
universe@128 286 comment.setAuthor(PGUserDao.mapColumns(result));
universe@124 287 comments.add(comment);
universe@124 288 }
universe@124 289 }
universe@124 290 return comments;
universe@124 291 }
universe@124 292
universe@124 293 @Override
universe@150 294 public void saveComment(Issue issue, IssueComment comment) throws SQLException {
universe@124 295 if (comment.getId() >= 0) {
universe@124 296 updateComment.setString(1, comment.getComment());
universe@124 297 updateComment.setInt(2, comment.getId());
universe@124 298 updateComment.execute();
universe@124 299 } else {
universe@150 300 insertComment.setInt(1, issue.getId());
universe@124 301 insertComment.setString(2, comment.getComment());
universe@124 302 setForeignKeyOrNull(insertComment, 3, comment.getAuthor(), User::getId);
universe@124 303 insertComment.execute();
universe@124 304 }
universe@124 305 }
universe@38 306 }

mercurial