Skip to content

Commit

Permalink
Development: Avoid database queries with pagination and left join fet…
Browse files Browse the repository at this point in the history
…ch (#8741)
  • Loading branch information
krusche authored Aug 8, 2024
1 parent cda2ecf commit 3e55f73
Show file tree
Hide file tree
Showing 43 changed files with 931 additions and 234 deletions.
69 changes: 68 additions & 1 deletion docs/dev/guidelines/database.rst
Original file line number Diff line number Diff line change
Expand Up @@ -155,7 +155,7 @@ In order to load the relationships of an entity on demand, we then use one of 3
@EntityGraph(type = LOAD, attributePaths = { "exercises", "exercises.categories", "exercises.teamAssignmentConfig" })
Course findWithEagerExercisesById(long courseId);
2. **JOIN FETCH**: The ``JOIN FETCH`` keyword is used in a custom query to specify a graph of relationships to fetch. It should be used when a query is custom and has a custom ``@Query`` annotation. Example:
2. **JOIN FETCH**: The ``JOIN FETCH`` keyword is used in a custom query to specify a graph of relationships to fetch. It should be used when a query is custom and has a custom ``@Query`` annotation. You can see the example below. Also, explicitly or implicitly limiting queries in Hibernate can lead to in-memory paging. For more details, see the 'In-memory paging' section.

.. code-block:: java
Expand Down Expand Up @@ -204,6 +204,73 @@ In order to load the relationships of an entity on demand, we then use one of 3
final Set<ProgrammingExerciseFetchOptions> fetchOptions = withGradingCriteria ? Set.of(GradingCriteria, AuxiliaryRepositories) : Set.of(AuxiliaryRepositories);
var programmingExercise = programmingExerciseRepository.findByIdWithDynamicFetchElseThrow(exerciseId, fetchOptions);
4. **In memory paging**: Since the flag ``hibernate.query.fail_on_pagination_over_collection_fetch: true`` is now active, it is crucial to carefully craft database queries that involve FETCH statements with collections and thoroughly test the changes. In-memory paging would cause performance decrements and is, therefore, disabled. Any use of it will lead to runtime errors.
Queries that may result in this error can return Page<> and contain JOIN FETCHES or involve internal limiting in Hibernate, such as findFirst, findLast, or findOne. One solution is to split the original query into multiple queries and a default method. The first query fetches only the IDs of entities whose full dependencies need to be fetched. The second query eagerly fetches all necessary dependencies, and the third query uses counting to build Pages, if they are utilized.
When possible, use the default Spring Data/JPA methods for second(fetching) and third(counting) queries.
An example implementation could look like this:

.. code-block:: java
// Repository interface
default Page<User> searchAllByLoginOrNameInCourseAndReturnPage(Pageable pageable, String loginOrName, long courseId) {
List<Long> userIds = findUserIdsByLoginOrNameInCourse(loginOrName, courseId, pageable).stream().map(DomainObject::getId).toList();;
if (userIds.isEmpty()) {
return new PageImpl<>(Collections.emptyList(), pageable, 0);
}
List<User> users = findUsersWithGroupsByIds(userIds);
long total = countUsersByLoginOrNameInCourse(loginOrName, courseId);
return new PageImpl<>(users, pageable, total);
}
@Query("""
SELECT DISTINCT user
FROM User user
JOIN user.groups userGroup
JOIN Course course ON course.id = :courseId
WHERE user.isDeleted = FALSE
AND (
user.login LIKE :#{#loginOrName}%
OR CONCAT(user.firstName, ' ', user.lastName) LIKE %:#{#loginOrName}%
)
AND (course.studentGroupName = userGroup
OR course.teachingAssistantGroupName = userGroup
OR course.editorGroupName = userGroup
OR course.instructorGroupName = userGroup
)
""")
List<User> findUsersByLoginOrNameInCourse(@Param("loginOrName") String loginOrName, @Param("courseId") long courseId, Pageable pageable);
@Query("""
SELECT DISTINCT user
FROM User user
LEFT JOIN FETCH user.groups userGroup
WHERE user.id IN :ids
""")
List<User> findUsersWithGroupsByIds(@Param("ids") List<Long> ids);
@Query("""
SELECT COUNT(DISTINCT user)
FROM User user
JOIN user.groups userGroup
JOIN Course course ON course.id = :courseId
WHERE user.isDeleted = FALSE
AND (
user.login LIKE :#{#loginOrName}%
OR CONCAT(user.firstName, ' ', user.lastName) LIKE %:#{#loginOrName}%
)
AND (
course.studentGroupName = userGroup
OR course.teachingAssistantGroupName = userGroup
OR course.editorGroupName = userGroup
OR course.instructorGroupName = userGroup
)
""")
long countUsersByLoginOrNameInCourse(@Param("loginOrName") String loginOrName, @Param("courseId") long courseId);
Best Practices
Expand Down
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
package de.tum.in.www1.artemis.repository;

import static de.tum.in.www1.artemis.config.Constants.PROFILE_CORE;
import static org.springframework.data.jpa.repository.EntityGraph.EntityGraphType.LOAD;

import java.time.Duration;
import java.time.ZonedDateTime;
Expand All @@ -10,6 +11,7 @@

import org.springframework.context.annotation.Profile;
import org.springframework.data.domain.Page;
import org.springframework.data.domain.PageImpl;
import org.springframework.data.domain.Pageable;
import org.springframework.data.jpa.repository.EntityGraph;
import org.springframework.data.jpa.repository.JpaSpecificationExecutor;
Expand All @@ -33,9 +35,29 @@ public interface BuildJobRepository extends ArtemisJpaRepository<BuildJob, Long>

Optional<BuildJob> findBuildJobByResult(Result result);

// TODO: rewrite this query, pageable does not work well with EntityGraph
@EntityGraph(attributePaths = { "result", "result.participation", "result.participation.exercise", "result.submission" })
Page<BuildJob> findAll(Pageable pageable);
@Query("""
SELECT b.id
FROM BuildJob b
""")
List<Long> findAllIds(Pageable pageable);

@EntityGraph(type = LOAD, attributePaths = { "result", "result.participation", "result.participation.exercise", "result.submission" })
List<BuildJob> findWithDataByIdIn(List<Long> ids);

/**
* Retrieves a paginated list of all {@link BuildJob} entities.
*
* @param pageable the pagination information.
* @return a paginated list of {@link BuildJob} entities. If no entities are found, returns an empty page.
*/
default Page<BuildJob> findAllWithData(Pageable pageable) {
List<Long> ids = findAllIds(pageable);
if (ids.isEmpty()) {
return Page.empty(pageable);
}
List<BuildJob> result = findWithDataByIdIn(ids);
return new PageImpl<>(result, pageable, count());
}

// Cast to string is necessary. Otherwise, the query will fail on PostgreSQL.
@Query("""
Expand All @@ -56,17 +78,6 @@ Page<Long> findAllByFilterCriteria(@Param("buildStatus") BuildStatus buildStatus
@Param("startDate") ZonedDateTime startDate, @Param("endDate") ZonedDateTime endDate, @Param("searchTerm") String searchTerm, @Param("courseId") Long courseId,
@Param("durationLower") Duration durationLower, @Param("durationUpper") Duration durationUpper, Pageable pageable);

@Query("""
SELECT b
FROM BuildJob b
LEFT JOIN FETCH b.result r
LEFT JOIN FETCH r.participation p
LEFT JOIN FETCH p.exercise
LEFT JOIN FETCH r.submission
WHERE b.id IN :buildJobIds
""")
List<BuildJob> findAllByIdWithResults(@Param("buildJobIds") List<Long> buildJobIds);

@Query("""
SELECT new de.tum.in.www1.artemis.service.connectors.localci.dto.DockerImageBuild(
b.dockerImage,
Expand All @@ -77,9 +88,30 @@ Page<Long> findAllByFilterCriteria(@Param("buildStatus") BuildStatus buildStatus
""")
Set<DockerImageBuild> findAllLastBuildDatesForDockerImages();

// TODO: rewrite this query, pageable does not work well with EntityGraph
@EntityGraph(attributePaths = { "result", "result.participation", "result.participation.exercise", "result.submission" })
Page<BuildJob> findAllByCourseId(long courseId, Pageable pageable);
@Query("""
SELECT b.id
FROM BuildJob b
WHERE b.courseId = :courseId
""")
List<Long> findIdsByCourseId(@Param("courseId") long courseId, Pageable pageable);

long countBuildJobByCourseId(long courseId);

/**
* Retrieves a paginated list of all {@link BuildJob} entities that have a given course id.
*
* @param courseId the course id.
* @param pageable the pagination information.
* @return a paginated list of {@link BuildJob} entities. If no entities are found, returns an empty page.
*/
default Page<BuildJob> findAllWithDataByCourseId(long courseId, Pageable pageable) {
List<Long> ids = findIdsByCourseId(courseId, pageable);
if (ids.isEmpty()) {
return Page.empty(pageable);
}
List<BuildJob> result = findWithDataByIdIn(ids);
return new PageImpl<>(result, pageable, countBuildJobByCourseId(courseId));
}

@Query("""
SELECT new de.tum.in.www1.artemis.service.connectors.localci.dto.ResultBuildJob(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -9,8 +9,11 @@
import jakarta.validation.constraints.NotNull;

import org.springframework.data.domain.Page;
import org.springframework.data.domain.PageImpl;
import org.springframework.data.domain.Pageable;
import org.springframework.data.jpa.repository.EntityGraph;
import org.springframework.data.jpa.repository.Query;
import org.springframework.data.repository.query.Param;

import de.tum.in.www1.artemis.domain.PersistentAuditEvent;
import de.tum.in.www1.artemis.repository.base.ArtemisJpaRepository;
Expand All @@ -23,14 +26,55 @@ public interface PersistenceAuditEventRepository extends ArtemisJpaRepository<Pe
@EntityGraph(type = LOAD, attributePaths = { "data" })
List<PersistentAuditEvent> findByPrincipalAndAuditEventDateAfterAndAuditEventType(String principle, Instant after, String type);

@EntityGraph(type = LOAD, attributePaths = { "data" })
// TODO: rewrite this query, pageable does not work well with EntityGraph
Page<PersistentAuditEvent> findAllByAuditEventDateBetween(Instant fromDate, Instant toDate, Pageable pageable);
@Query("""
SELECT p.id
FROM PersistentAuditEvent p
WHERE p.auditEventDate BETWEEN :fromDate AND :toDate
""")
List<Long> findIdsByAuditEventDateBetween(@Param("fromDate") Instant fromDate, @Param("toDate") Instant toDate, Pageable pageable);

@NotNull
@EntityGraph(type = LOAD, attributePaths = { "data" })
// TODO: rewrite this query, pageable does not work well with EntityGraph
Page<PersistentAuditEvent> findAll(@NotNull Pageable pageable);
@EntityGraph(type = LOAD, attributePaths = "data")
List<PersistentAuditEvent> findWithDataByIdIn(List<Long> ids);

long countByAuditEventDateBetween(Instant fromDate, Instant toDate);

/**
* Retrieves a paginated list of {@link PersistentAuditEvent} entities that have an audit event date between the specified fromDate and toDate.
*
* @param fromDate the start date of the audit event date range (inclusive).
* @param toDate the end date of the audit event date range (inclusive).
* @param pageable the pagination information.
* @return a paginated list of {@link PersistentAuditEvent} entities within the specified date range. If no entities are found, returns an empty page.
*/
default Page<PersistentAuditEvent> findAllWithDataByAuditEventDateBetween(Instant fromDate, Instant toDate, Pageable pageable) {
List<Long> ids = findIdsByAuditEventDateBetween(fromDate, toDate, pageable);
if (ids.isEmpty()) {
return Page.empty(pageable);
}
List<PersistentAuditEvent> result = findWithDataByIdIn(ids);
return new PageImpl<>(result, pageable, countByAuditEventDateBetween(fromDate, toDate));
}

@Query("""
SELECT p.id
FROM PersistentAuditEvent p
""")
List<Long> findAllIds(Pageable pageable);

/**
* Retrieves a paginated list of {@link PersistentAuditEvent} entities.
*
* @param pageable the pagination information.
* @return a paginated list of {@link PersistentAuditEvent} entities. If no entities are found, returns an empty page.
*/
default Page<PersistentAuditEvent> findAllWithData(@NotNull Pageable pageable) {
List<Long> ids = findAllIds(pageable);
if (ids.isEmpty()) {
return Page.empty(pageable);
}
List<PersistentAuditEvent> result = findWithDataByIdIn(ids);
return new PageImpl<>(result, pageable, count());
}

@NotNull
@EntityGraph(type = LOAD, attributePaths = { "data" })
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -3,12 +3,14 @@
import static de.tum.in.www1.artemis.config.Constants.PROFILE_CORE;
import static org.springframework.data.jpa.repository.EntityGraph.EntityGraphType.LOAD;

import java.util.Collections;
import java.util.List;
import java.util.Optional;

import jakarta.validation.constraints.NotNull;

import org.springframework.context.annotation.Profile;
import org.springframework.data.domain.PageRequest;
import org.springframework.data.domain.Pageable;
import org.springframework.data.jpa.repository.EntityGraph;
import org.springframework.data.jpa.repository.Query;
Expand All @@ -17,6 +19,7 @@

import de.tum.in.www1.artemis.domain.ProgrammingSubmission;
import de.tum.in.www1.artemis.repository.base.ArtemisJpaRepository;
import de.tum.in.www1.artemis.service.dto.ProgrammingSubmissionIdAndSubmissionDateDTO;

/**
* Spring Data JPA repository for the ProgrammingSubmission entity.
Expand Down Expand Up @@ -44,36 +47,72 @@ default ProgrammingSubmission findFirstByParticipationIdAndCommitHashOrderByIdDe
return findByParticipationIdAndCommitHashOrderByIdDescWithFeedbacksAndTeamStudents(participationId, commitHash).stream().findFirst().orElse(null);
}

@EntityGraph(type = LOAD, attributePaths = "results")
Optional<ProgrammingSubmission> findFirstByParticipationIdOrderBySubmissionDateDesc(long participationId);
@Query(value = """
SELECT new de.tum.in.www1.artemis.service.dto.ProgrammingSubmissionIdAndSubmissionDateDTO(ps.id, ps.submissionDate)
FROM ProgrammingSubmission ps
WHERE ps.participation.id = :participationId ORDER BY ps.submissionDate DESC
""")
List<ProgrammingSubmissionIdAndSubmissionDateDTO> findFirstIdByParticipationIdOrderBySubmissionDateDesc(@Param("participationId") long participationId, Pageable pageable);

@EntityGraph(type = LOAD, attributePaths = { "results" })
Optional<ProgrammingSubmission> findProgrammingSubmissionWithResultsById(long programmingSubmissionId);

/**
* Provide a list of graded submissions. To be graded a submission must:
* - be of type 'INSTRUCTOR' or 'TEST'
* - have a submission date before the exercise due date
* - or related to an exercise without a due date
* Finds the first programming submission by participation ID, including its results, ordered by submission date in descending order. To avoid in-memory paging by retrieving
* the first submission directly from the database.
*
* @param participationId to which the submissions belong.
* @param pageable Pageable
* @return ProgrammingSubmission list (can be empty!)
* @param programmingSubmissionId the ID of the participation to find the submission for
* @return an {@code Optional} containing the first {@code ProgrammingSubmission} with results, ordered by submission date in descending order,
* or an empty {@code Optional} if no submission is found
*/
default Optional<ProgrammingSubmission> findFirstByParticipationIdWithResultsOrderBySubmissionDateDesc(long programmingSubmissionId) {
Pageable pageable = PageRequest.of(0, 1); // fetch the first row
// probably is not the prettiest variant, but we need a way to fetch the first row only, as sql limit does not work with JPQL, as the latter is SQL agnostic
List<ProgrammingSubmissionIdAndSubmissionDateDTO> result = findFirstIdByParticipationIdOrderBySubmissionDateDesc(programmingSubmissionId, pageable);
if (result.isEmpty()) {
return Optional.empty();
}
long id = result.getFirst().programmingSubmissionId();
return findProgrammingSubmissionWithResultsById(id);
}

@Query("""
SELECT s
SELECT new de.tum.in.www1.artemis.service.dto.ProgrammingSubmissionIdAndSubmissionDateDTO(s.id, s.submissionDate)
FROM ProgrammingSubmission s
LEFT JOIN s.participation p
LEFT JOIN p.exercise e
LEFT JOIN FETCH s.results r
JOIN s.participation p
JOIN p.exercise e
WHERE p.id = :participationId
AND (
s.type = de.tum.in.www1.artemis.domain.enumeration.SubmissionType.INSTRUCTOR
AND (s.type = de.tum.in.www1.artemis.domain.enumeration.SubmissionType.INSTRUCTOR
OR s.type = de.tum.in.www1.artemis.domain.enumeration.SubmissionType.TEST
OR e.dueDate IS NULL
OR s.submissionDate <= e.dueDate
)
OR s.submissionDate <= e.dueDate)
ORDER BY s.submissionDate DESC
""")
// TODO: rewrite this query, pageable does not work well with left join fetch, it needs to transfer all results and only page in java
List<ProgrammingSubmission> findGradedByParticipationIdOrderBySubmissionDateDesc(@Param("participationId") long participationId, Pageable pageable);
List<ProgrammingSubmissionIdAndSubmissionDateDTO> findSubmissionIdsAndDatesByParticipationId(@Param("participationId") long participationId, Pageable pageable);

@EntityGraph(type = LOAD, attributePaths = { "results" })
List<ProgrammingSubmission> findSubmissionsWithResultsByIdIn(List<Long> ids);

/**
* Provide a list of graded submissions. To be graded a submission must:
* - be of type 'INSTRUCTOR' or 'TEST'
* - have a submission date before the exercise due date
* - or related to an exercise without a due date
*
* @param participationId to which the submissions belong.
* @param pageable Pageable
* @return ProgrammingSubmission list (can be empty!)
*/
default List<ProgrammingSubmission> findGradedByParticipationIdWithResultsOrderBySubmissionDateDesc(long participationId, Pageable pageable) {
List<Long> ids = findSubmissionIdsAndDatesByParticipationId(participationId, pageable).stream().map(ProgrammingSubmissionIdAndSubmissionDateDTO::programmingSubmissionId)
.toList();

if (ids.isEmpty()) {
return Collections.emptyList();
}

return findSubmissionsWithResultsByIdIn(ids);
}

@EntityGraph(type = LOAD, attributePaths = "results.feedbacks")
Optional<ProgrammingSubmission> findWithEagerResultsAndFeedbacksById(long submissionId);
Expand Down
Loading

0 comments on commit 3e55f73

Please sign in to comment.