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

Sat, 17 Oct 2020 20:06:14 +0200

author
Mike Becker <universe@uap-core.de>
date
Sat, 17 Oct 2020 20:06:14 +0200
changeset 135
bafc315294fd
parent 134
f47e82cd6077
child 138
e2aa673dd473
permissions
-rw-r--r--

fixes missing placeholder in insert statement

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@47 51 list = connection.prepareStatement(
universe@134 52 "select issueid, i.project, p.name as projectname, component, c.name as componentname, " +
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@75 59 "left join lpit_user on userid = assignee " +
universe@134 60 "where i.project = ? and coalesce(component, -1) = coalesce(?, component, -1)");
universe@86 61
universe@86 62 listForVersion = connection.prepareStatement(
universe@86 63 "with issue_version as ( "+
universe@86 64 "select issueid, versionid from lpit_issue_affected_version union "+
universe@86 65 "select issueid, versionid from lpit_issue_resolved_version) "+
universe@134 66 "select issueid, i.project, p.name as projectname, component, c.name as componentname, " +
universe@134 67 "status, category, subject, i.description, " +
universe@86 68 "userid, username, givenname, lastname, mail, " +
universe@86 69 "created, updated, eta " +
universe@86 70 "from lpit_issue i " +
universe@134 71 "join lpit_project p on i.project = projectid " +
universe@134 72 "left join lpit_component c on component = c.id " +
universe@105 73 "left join issue_version using (issueid) "+
universe@86 74 "left join lpit_user on userid = assignee " +
universe@134 75 "where coalesce(versionid,-1) = ? and coalesce(component, -1) = coalesce(?, component, -1)"
universe@86 76 );
universe@47 77
universe@47 78 find = connection.prepareStatement(
universe@134 79 "select issueid, i.project, p.name as projectname, component, c.name as componentname, " +
universe@134 80 "status, category, subject, i.description, " +
universe@75 81 "userid, username, givenname, lastname, mail, " +
universe@75 82 "created, updated, eta " +
universe@83 83 "from lpit_issue i " +
universe@134 84 "join lpit_project p on i.project = projectid " +
universe@134 85 "left join lpit_component c on component = c.id " +
universe@75 86 "left join lpit_user on userid = assignee " +
universe@75 87 "where issueid = ? ");
universe@38 88
universe@38 89 insert = connection.prepareStatement(
universe@134 90 "insert into lpit_issue (project, component, status, category, subject, description, assignee, eta) " +
universe@135 91 "values (?, ?, ?::issue_status, ?::issue_category, ?, ?, ?, ?) returning issueid"
universe@38 92 );
universe@38 93 update = connection.prepareStatement(
universe@134 94 "update lpit_issue set " +
universe@134 95 "updated = now(), component = ?, status = ?::issue_status, category = ?::issue_category, " +
universe@75 96 "subject = ?, description = ?, assignee = ?, eta = ? where issueid = ?"
universe@75 97 );
universe@75 98
universe@75 99 affectedVersions = connection.prepareStatement(
universe@83 100 "select versionid, name, status, ordinal " +
universe@83 101 "from lpit_version join lpit_issue_affected_version using (versionid) " +
universe@75 102 "where issueid = ? " +
universe@83 103 "order by ordinal, name"
universe@75 104 );
universe@83 105 clearAffected = connection.prepareStatement("delete from lpit_issue_affected_version where issueid = ?");
universe@83 106 insertAffected = connection.prepareStatement("insert into lpit_issue_affected_version (issueid, versionid) values (?,?)");
universe@75 107
universe@75 108 resolvedVersions = connection.prepareStatement(
universe@83 109 "select versionid, name, status, ordinal " +
universe@75 110 "from lpit_version v join lpit_issue_resolved_version using (versionid) " +
universe@75 111 "where issueid = ? " +
universe@83 112 "order by ordinal, name"
universe@38 113 );
universe@83 114 clearResolved = connection.prepareStatement("delete from lpit_issue_resolved_version where issueid = ?");
universe@83 115 insertResolved = connection.prepareStatement("insert into lpit_issue_resolved_version (issueid, versionid) values (?,?)");
universe@124 116
universe@124 117 insertComment = connection.prepareStatement(
universe@124 118 "insert into lpit_issue_comment (issueid, comment, userid) values (?, ? ,?)"
universe@124 119 );
universe@124 120 updateComment = connection.prepareStatement(
universe@124 121 "update lpit_issue_comment set comment = ?, updated = now(), updatecount = updatecount+1 where commentid = ?"
universe@124 122 );
universe@124 123 listComments = connection.prepareStatement(
universe@124 124 "select * from lpit_issue_comment left join lpit_user using (userid) where issueid = ? order by created"
universe@124 125 );
universe@38 126 }
universe@38 127
universe@75 128 private Issue mapColumns(ResultSet result) throws SQLException {
universe@75 129 final var project = new Project(result.getInt("project"));
universe@83 130 project.setName(result.getString("projectname"));
universe@134 131 var component = new Component(result.getInt("component"));
universe@134 132 if (result.wasNull()) {
universe@134 133 component = null;
universe@134 134 } else {
universe@134 135 component.setName(result.getString("componentname"));
universe@134 136 }
universe@86 137 final var issue = new Issue(result.getInt("issueid"));
universe@86 138 issue.setProject(project);
universe@134 139 issue.setComponent(component);
universe@75 140 issue.setStatus(IssueStatus.valueOf(result.getString("status")));
universe@75 141 issue.setCategory(IssueCategory.valueOf(result.getString("category")));
universe@75 142 issue.setSubject(result.getString("subject"));
universe@75 143 issue.setDescription(result.getString("description"));
universe@128 144 issue.setAssignee(PGUserDao.mapColumns(result));
universe@75 145 issue.setCreated(result.getTimestamp("created"));
universe@75 146 issue.setUpdated(result.getTimestamp("updated"));
universe@75 147 issue.setEta(result.getDate("eta"));
universe@62 148 return issue;
universe@38 149 }
universe@38 150
universe@86 151 private Version mapVersion(ResultSet result) throws SQLException {
universe@86 152 final var version = new Version(result.getInt("versionid"));
universe@83 153 version.setName(result.getString("name"));
universe@83 154 version.setOrdinal(result.getInt("ordinal"));
universe@83 155 version.setStatus(VersionStatus.valueOf(result.getString("status")));
universe@75 156 return version;
universe@75 157 }
universe@75 158
universe@83 159 private void updateVersionLists(Issue instance) throws SQLException {
universe@83 160 clearAffected.setInt(1, instance.getId());
universe@83 161 clearResolved.setInt(1, instance.getId());
universe@83 162 insertAffected.setInt(1, instance.getId());
universe@83 163 insertResolved.setInt(1, instance.getId());
universe@83 164 clearAffected.executeUpdate();
universe@83 165 clearResolved.executeUpdate();
universe@83 166 for (Version v : instance.getAffectedVersions()) {
universe@83 167 insertAffected.setInt(2, v.getId());
universe@83 168 insertAffected.executeUpdate();
universe@83 169 }
universe@83 170 for (Version v : instance.getResolvedVersions()) {
universe@83 171 insertResolved.setInt(2, v.getId());
universe@83 172 insertResolved.executeUpdate();
universe@83 173 }
universe@83 174 }
universe@83 175
universe@134 176 private int setData(PreparedStatement stmt, int column, Issue instance) throws SQLException {
universe@134 177 setForeignKeyOrNull(stmt, ++column, instance.getComponent(), Component::getId);
universe@134 178 stmt.setString(++column, instance.getStatus().name());
universe@134 179 stmt.setString(++column, instance.getCategory().name());
universe@134 180 stmt.setString(++column, instance.getSubject());
universe@134 181 setStringOrNull(stmt, ++column, instance.getDescription());
universe@134 182 setForeignKeyOrNull(stmt, ++column, instance.getAssignee(), User::getId);
universe@134 183 setDateOrNull(stmt, ++column, instance.getEta());
universe@134 184 return column;
universe@134 185 }
universe@134 186
universe@38 187 @Override
universe@128 188 public void save(Issue instance, Project project) throws SQLException {
universe@62 189 Objects.requireNonNull(instance.getSubject());
universe@128 190 instance.setProject(project);
universe@134 191 int column = 0;
universe@134 192 insert.setInt(++column, instance.getProject().getId());
universe@134 193 setData(insert, column, instance);
universe@75 194 // insert and retrieve the ID
universe@75 195 final var rs = insert.executeQuery();
universe@75 196 rs.next();
universe@75 197 instance.setId(rs.getInt(1));
universe@83 198 updateVersionLists(instance);
universe@38 199 }
universe@38 200
universe@38 201 @Override
universe@62 202 public boolean update(Issue instance) throws SQLException {
universe@75 203 if (instance.getId() < 0) return false;
universe@62 204 Objects.requireNonNull(instance.getSubject());
universe@134 205 int column = setData(update, 0, instance);
universe@134 206 update.setInt(++column, instance.getId());
universe@83 207 boolean success = update.executeUpdate() > 0;
universe@83 208 if (success) {
universe@83 209 updateVersionLists(instance);
universe@83 210 return true;
universe@83 211 } else {
universe@83 212 return false;
universe@83 213 }
universe@38 214 }
universe@47 215
universe@134 216 private List<Issue> executeQuery(PreparedStatement query) throws SQLException {
universe@75 217 List<Issue> issues = new ArrayList<>();
universe@86 218 try (var result = query.executeQuery()) {
universe@47 219 while (result.next()) {
universe@75 220 issues.add(mapColumns(result));
universe@47 221 }
universe@47 222 }
universe@75 223 return issues;
universe@47 224 }
universe@47 225
universe@47 226 @Override
universe@86 227 public List<Issue> list(Project project) throws SQLException {
universe@134 228 list.setInt(1, project.getId());
universe@134 229 list.setNull(2, Types.INTEGER);
universe@134 230 return executeQuery(list);
universe@86 231 }
universe@86 232
universe@86 233 @Override
universe@134 234 public List<Issue> list(Project project, Component component, Version version) throws SQLException {
universe@134 235 listForVersion.setInt(1, Optional.ofNullable(version).map(Version::getId).orElse(-1));
universe@134 236 listForVersion.setInt(2, Optional.ofNullable(component).map(Component::getId).orElse(-1));
universe@134 237 return executeQuery(listForVersion);
universe@134 238 }
universe@134 239
universe@134 240 @Override
universe@134 241 public List<Issue> list(Project project, Version version) throws SQLException {
universe@134 242 listForVersion.setInt(1, Optional.ofNullable(version).map(Version::getId).orElse(-1));
universe@134 243 listForVersion.setNull(2, Types.INTEGER);
universe@134 244 return executeQuery(listForVersion);
universe@134 245 }
universe@134 246
universe@134 247 @Override
universe@134 248 public List<Issue> list(Project project, Component component) throws SQLException {
universe@134 249 list.setInt(1, project.getId());
universe@134 250 list.setInt(2, Optional.ofNullable(component).map(Component::getId).orElse(-1));
universe@134 251 return executeQuery(list);
universe@86 252 }
universe@86 253
universe@86 254 @Override
universe@62 255 public Issue find(int id) throws SQLException {
universe@47 256 find.setInt(1, id);
universe@47 257 try (var result = find.executeQuery()) {
universe@47 258 if (result.next()) {
universe@47 259 return mapColumns(result);
universe@47 260 } else {
universe@47 261 return null;
universe@47 262 }
universe@47 263 }
universe@47 264 }
universe@75 265
universe@75 266 private List<Version> listVersions(PreparedStatement stmt, Issue issue) throws SQLException {
universe@75 267 stmt.setInt(1, issue.getId());
universe@75 268 List<Version> versions = new ArrayList<>();
universe@75 269 try (var result = stmt.executeQuery()) {
universe@75 270 while (result.next()) {
universe@86 271 versions.add(mapVersion(result));
universe@75 272 }
universe@75 273 }
universe@75 274 return versions;
universe@75 275 }
universe@75 276
universe@75 277 @Override
universe@75 278 public void joinVersionInformation(Issue issue) throws SQLException {
universe@75 279 Objects.requireNonNull(issue.getProject());
universe@75 280 issue.setAffectedVersions(listVersions(affectedVersions, issue));
universe@75 281 issue.setResolvedVersions(listVersions(resolvedVersions, issue));
universe@75 282 }
universe@124 283
universe@124 284 @Override
universe@124 285 public List<IssueComment> listComments(Issue issue) throws SQLException {
universe@124 286 listComments.setInt(1, issue.getId());
universe@124 287 List<IssueComment> comments = new ArrayList<>();
universe@124 288 try (var result = listComments.executeQuery()) {
universe@124 289 while (result.next()) {
universe@124 290 final var comment = new IssueComment(result.getInt("commentid"), issue);
universe@124 291 comment.setCreated(result.getTimestamp("created"));
universe@124 292 comment.setUpdated(result.getTimestamp("updated"));
universe@124 293 comment.setUpdateCount(result.getInt("updatecount"));
universe@124 294 comment.setComment(result.getString("comment"));
universe@128 295 comment.setAuthor(PGUserDao.mapColumns(result));
universe@124 296 comments.add(comment);
universe@124 297 }
universe@124 298 }
universe@124 299 return comments;
universe@124 300 }
universe@124 301
universe@124 302 @Override
universe@124 303 public void saveComment(IssueComment comment) throws SQLException {
universe@124 304 Objects.requireNonNull(comment.getComment());
universe@124 305 Objects.requireNonNull(comment.getIssue());
universe@124 306 if (comment.getId() >= 0) {
universe@124 307 updateComment.setString(1, comment.getComment());
universe@124 308 updateComment.setInt(2, comment.getId());
universe@124 309 updateComment.execute();
universe@124 310 } else {
universe@124 311 insertComment.setInt(1, comment.getIssue().getId());
universe@124 312 insertComment.setString(2, comment.getComment());
universe@124 313 setForeignKeyOrNull(insertComment, 3, comment.getAuthor(), User::getId);
universe@124 314 insertComment.execute();
universe@124 315 }
universe@124 316 }
universe@38 317 }

mercurial