From e72ff784e8f5e9cf42e9fa2f0902f7b902cf1144 Mon Sep 17 00:00:00 2001 From: Gauthier Roebroeck Date: Mon, 9 Sep 2024 11:26:05 +0800 Subject: [PATCH] perf(api): make on deck much faster --- ...152500__read_progress_series_read_date.sql | 16 +++ .../infrastructure/jooq/main/BookCommonDao.kt | 112 ++++++++++++++++++ .../infrastructure/jooq/main/BookDtoDao.kt | 48 +++----- .../jooq/main/ReadProgressDao.kt | 2 + .../jooq/main/BookDtoDaoTest.kt | 4 +- komga/src/test/resources/application-test.yml | 1 + 6 files changed, 147 insertions(+), 36 deletions(-) create mode 100644 komga/src/flyway/resources/db/migration/sqlite/V20240906152500__read_progress_series_read_date.sql create mode 100644 komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookCommonDao.kt diff --git a/komga/src/flyway/resources/db/migration/sqlite/V20240906152500__read_progress_series_read_date.sql b/komga/src/flyway/resources/db/migration/sqlite/V20240906152500__read_progress_series_read_date.sql new file mode 100644 index 000000000..8f5b35a77 --- /dev/null +++ b/komga/src/flyway/resources/db/migration/sqlite/V20240906152500__read_progress_series_read_date.sql @@ -0,0 +1,16 @@ +alter table READ_PROGRESS_SERIES + add MOST_RECENT_READ_DATE datetime NULL; +alter table READ_PROGRESS_SERIES + add LAST_MODIFIED_DATE datetime NULL; + +update READ_PROGRESS_SERIES +set MOST_RECENT_READ_DATE = (select max(r.READ_DATE) + from READ_PROGRESS r + inner join BOOK b on r.BOOK_ID = b.ID + where b.SERIES_ID = READ_PROGRESS_SERIES.SERIES_ID); + +update READ_PROGRESS_SERIES +set LAST_MODIFIED_DATE = (select max(r.LAST_MODIFIED_DATE) + from READ_PROGRESS r + inner join BOOK b on r.BOOK_ID = b.ID + where b.SERIES_ID = READ_PROGRESS_SERIES.SERIES_ID); diff --git a/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookCommonDao.kt b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookCommonDao.kt new file mode 100644 index 000000000..7b79fb598 --- /dev/null +++ b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookCommonDao.kt @@ -0,0 +1,112 @@ +package org.gotson.komga.infrastructure.jooq.main + +import org.gotson.komga.domain.model.ContentRestrictions +import org.gotson.komga.infrastructure.jooq.toCondition +import org.gotson.komga.jooq.main.Tables +import org.jooq.DSLContext +import org.jooq.Field +import org.jooq.Record +import org.jooq.Record1 +import org.jooq.SelectConditionStep +import org.jooq.SelectJoinStep +import org.jooq.impl.DSL +import org.jooq.impl.DSL.falseCondition +import org.jooq.impl.DSL.name +import org.jooq.impl.DSL.select +import org.springframework.stereotype.Component +import java.time.LocalDateTime + +@Component +class BookCommonDao( + private val dsl: DSLContext, +) { + private val b = Tables.BOOK + private val m = Tables.MEDIA + private val d = Tables.BOOK_METADATA + private val r = Tables.READ_PROGRESS + private val rs = Tables.READ_PROGRESS_SERIES + private val s = Tables.SERIES + private val sd = Tables.SERIES_METADATA + + fun getBooksOnDeckQuery( + userId: String, + restrictions: ContentRestrictions, + filterOnLibraryIds: Collection?, + selectFields: Array>, + ): Triple, Field, SelectJoinStep>> { + // On Deck books are the first unread book in a series that has at least one book read, but is not in progress + // cteSeries will return On Deck series + val cteSeries = + name("cte_series") + .`as`( + select(s.ID, rs.MOST_RECENT_READ_DATE) + .from(s) + .innerJoin(rs).on(s.ID.eq(rs.SERIES_ID).and(rs.USER_ID.eq(userId))) + .innerJoin(sd).on(s.ID.eq(sd.SERIES_ID)) + .where(rs.IN_PROGRESS_COUNT.eq(0)) + .and(rs.READ_COUNT.ne(s.BOOK_COUNT)) + .and(restrictions.toCondition(dsl)) + .apply { filterOnLibraryIds?.let, Unit> { and(s.LIBRARY_ID.`in`(it)) } }, + ) + + val cteBooksFieldBookId = b.ID.`as`("cte_books_book_id") + val cteBooksFieldSeriesId = b.SERIES_ID.`as`("cte_books_series_id") + val cteBooksFieldNumberSort = d.NUMBER_SORT.`as`("cte_books_number_sort") + val cteBooks = + name("cte_books") + .`as`( + select( + cteBooksFieldBookId, + cteBooksFieldSeriesId, + cteBooksFieldNumberSort, + ).from(b) + .innerJoin(d).on(b.ID.eq(d.BOOK_ID)) + .leftJoin(r).on(b.ID.eq(r.BOOK_ID)).and(r.USER_ID.eq(userId)) + .where(r.COMPLETED.isNull) + .and( + b.SERIES_ID.`in`(select(cteSeries.field(s.ID)).from(cteSeries)), + ), + ) + + // finding the first unread book by number_sort is similar to finding the greatest-n-per-group + val b1 = cteBooks.`as`("b1") + val b2 = cteBooks.`as`("b2") + val query = + dsl + .with(cteSeries) + .with(cteBooks) + .select(*selectFields) + .from(cteSeries) + .innerJoin(b1).on(cteSeries.field(s.ID)!!.eq(b1.field(cteBooksFieldSeriesId))) + // we join the cteBooks table on itself, using the grouping ID (seriesId) using a left outer join + // it returns the row b1 for which no other row b2 exists with the same seriesId and a smaller numberSort + // when b2 is null, it means the left outer join fond no such match, and therefore b1 has the smaller value of numberSort + .leftOuterJoin(b2).on( + b1.field(cteBooksFieldSeriesId)!!.eq(b2.field(cteBooksFieldSeriesId)) + .and( + b1.field(cteBooksFieldNumberSort)!!.gt(b2.field(cteBooksFieldNumberSort)) + .or( + b1.field(cteBooksFieldNumberSort)!!.eq(b2.field(cteBooksFieldNumberSort)) + .and(b1.field(cteBooksFieldBookId)!!.gt(b2.field(cteBooksFieldBookId))), + ), + ), + ) + .innerJoin(b).on(b1.field(cteBooksFieldBookId)!!.eq(b.ID)) + .innerJoin(m).on(b.ID.eq(m.BOOK_ID)) + .innerJoin(d).on(b.ID.eq(d.BOOK_ID)) + .innerJoin(sd).on(b.SERIES_ID.eq(sd.SERIES_ID)) + // fetchAndMap expects some values for ReadProgress + // On Deck books are by definition unread, thus don't have read progress + // we join on the table to keep fetchAndMap, with a false condition to only get null values + .leftOuterJoin(r).on(falseCondition()) + .where(b2.field(cteBooksFieldBookId)!!.isNull) + + val mostRecentReadDateQuery = + dsl + .with(cteSeries) + .select(DSL.max(cteSeries.field(rs.MOST_RECENT_READ_DATE))) + .from(cteSeries) + + return Triple(query, cteSeries.field(rs.MOST_RECENT_READ_DATE)!!, mostRecentReadDateQuery) + } +} diff --git a/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDao.kt b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDao.kt index 98095cc6e..863ac58b7 100644 --- a/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDao.kt +++ b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDao.kt @@ -29,14 +29,12 @@ import org.gotson.komga.jooq.main.tables.records.BookRecord import org.gotson.komga.jooq.main.tables.records.MediaRecord import org.gotson.komga.jooq.main.tables.records.ReadProgressRecord import org.gotson.komga.language.toUTC -import org.jooq.AggregateFunction import org.jooq.Condition import org.jooq.DSLContext import org.jooq.Record import org.jooq.ResultQuery import org.jooq.impl.DSL import org.jooq.impl.DSL.falseCondition -import org.jooq.impl.DSL.inline import org.jooq.impl.DSL.noCondition import org.springframework.beans.factory.annotation.Value import org.springframework.data.domain.Page @@ -46,7 +44,6 @@ import org.springframework.data.domain.Pageable import org.springframework.data.domain.Sort import org.springframework.stereotype.Component import org.springframework.transaction.support.TransactionTemplate -import java.math.BigDecimal import java.net.URL @Component @@ -55,11 +52,13 @@ class BookDtoDao( private val luceneHelper: LuceneHelper, @Value("#{@komgaProperties.database.batchChunkSize}") private val batchSize: Int, private val transactionTemplate: TransactionTemplate, + private val bookCommonDao: BookCommonDao, ) : BookDtoRepository { private val b = Tables.BOOK private val m = Tables.MEDIA private val d = Tables.BOOK_METADATA private val r = Tables.READ_PROGRESS + private val rs = Tables.READ_PROGRESS_SERIES private val a = Tables.BOOK_METADATA_AUTHOR private val s = Tables.SERIES private val sd = Tables.SERIES_METADATA @@ -67,9 +66,7 @@ class BookDtoDao( private val bt = Tables.BOOK_METADATA_TAG private val bl = Tables.BOOK_METADATA_LINK - private val countUnread: AggregateFunction = DSL.sum(DSL.`when`(r.COMPLETED.isNull, 1).otherwise(0)) - private val countRead: AggregateFunction = DSL.sum(DSL.`when`(r.COMPLETED.isTrue, 1).otherwise(0)) - private val countInProgress: AggregateFunction = DSL.sum(DSL.`when`(r.COMPLETED.isFalse, 1).otherwise(0)) + private val onDeckFields = b.fields() + m.fields() + d.fields() + r.fields() + sd.TITLE private val sorts = mapOf( @@ -231,39 +228,22 @@ class BookDtoDao( pageable: Pageable, restrictions: ContentRestrictions, ): Page { - val seriesIds = - dsl.select(s.ID) - .from(s) - .leftJoin(b).on(s.ID.eq(b.SERIES_ID)) - .leftJoin(r).on(b.ID.eq(r.BOOK_ID)).and(readProgressCondition(userId)) - .leftJoin(sd).on(b.SERIES_ID.eq(sd.SERIES_ID)) - .where(restrictions.toCondition(dsl)) - .apply { filterOnLibraryIds?.let { and(s.LIBRARY_ID.`in`(it)) } } - .groupBy(s.ID) - .having(countUnread.ge(inline(1.toBigDecimal()))) - .and(countRead.ge(inline(1.toBigDecimal()))) - .and(countInProgress.eq(inline(0.toBigDecimal()))) - .orderBy(DSL.max(r.LAST_MODIFIED_DATE).desc()) - .fetchInto(String::class.java) + val (query, sortField, _) = bookCommonDao.getBooksOnDeckQuery(userId, restrictions, filterOnLibraryIds, onDeckFields) + val count = dsl.fetchCount(query) val dtos = - seriesIds - .drop(pageable.pageNumber * pageable.pageSize) - .take(pageable.pageSize) - .mapNotNull { seriesId -> - selectBase(userId) - .where(b.SERIES_ID.eq(seriesId)) - .and(r.COMPLETED.isNull) - .orderBy(d.NUMBER_SORT.asc()) - .limit(1) - .fetchAndMap() - .firstOrNull() - } + query + .orderBy(sortField.desc()) + .apply { if (pageable.isPaged) limit(pageable.pageSize).offset(pageable.offset) } + .fetchAndMap() return PageImpl( dtos, - PageRequest.of(pageable.pageNumber, pageable.pageSize, pageable.sort), - seriesIds.size.toLong(), + if (pageable.isPaged) + PageRequest.of(pageable.pageNumber, pageable.pageSize, Sort.unsorted()) + else + PageRequest.of(0, maxOf(count, 20), Sort.unsorted()), + count.toLong(), ) } diff --git a/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/ReadProgressDao.kt b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/ReadProgressDao.kt index 85499b27c..ea17d702c 100644 --- a/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/ReadProgressDao.kt +++ b/komga/src/main/kotlin/org/gotson/komga/infrastructure/jooq/main/ReadProgressDao.kt @@ -191,6 +191,8 @@ class ReadProgressDao( dsl.select(b.SERIES_ID, r.USER_ID) .select(DSL.sum(DSL.`when`(r.COMPLETED.isTrue, 1).otherwise(0))) .select(DSL.sum(DSL.`when`(r.COMPLETED.isFalse, 1).otherwise(0))) + .select(DSL.max(r.READ_DATE)) + .select(DSL.currentTimestamp()) .from(b) .innerJoin(r).on(b.ID.eq(r.BOOK_ID)) .where(b.SERIES_ID.`in`(seriesIdsQuery)) diff --git a/komga/src/test/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDaoTest.kt b/komga/src/test/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDaoTest.kt index 626b20790..b24e98ed5 100644 --- a/komga/src/test/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDaoTest.kt +++ b/komga/src/test/kotlin/org/gotson/komga/infrastructure/jooq/main/BookDtoDaoTest.kt @@ -376,12 +376,12 @@ class BookDtoDaoTest( seriesLifecycle.addBooks( series, (1..3).map { - makeBook("$it", seriesId = series.id, libraryId = library.id) + makeBook("$it", seriesId = series.id, libraryId = library.id).copy(number = it) }, ) val books = bookRepository.findAll().sortedBy { it.name } - books.elementAt(0).let { readProgressRepository.save(ReadProgress(it.id, user.id, 5, true)) } + books.first().let { readProgressRepository.save(ReadProgress(it.id, user.id, 5, true)) } // when val found = diff --git a/komga/src/test/resources/application-test.yml b/komga/src/test/resources/application-test.yml index 5e4721511..0f2700030 100644 --- a/komga/src/test/resources/application-test.yml +++ b/komga/src/test/resources/application-test.yml @@ -16,3 +16,4 @@ logging: level: org.gotson.komga: DEBUG # org.jooq: DEBUG +# org.jooq.tools.LoggerListener: DEBUG