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

Fri, 09 Oct 2020 15:35:48 +0200

author
Mike Becker <universe@uap-core.de>
date
Fri, 09 Oct 2020 15:35:48 +0200
changeset 121
428dca747d6b
parent 105
250c5cbb8276
child 124
ed2e7aef2a3e
permissions
-rw-r--r--

adds application level issue sorting (fixes #19)

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

mercurial