mirror of
https://github.com/advplyr/audiobookshelf.git
synced 2025-08-04 18:24:46 +02:00
Improve book library page query performance for author sort order (#4080)
* Add migration to create authorNames* columns, in libraryItems including update triggers and indices * Add authorNames columns and indices to LibraryItem model * Add database triggers for updating author names in libraryItems (for new databases) * Populate authorNames during book scanning * Update book sorting to use new authorNames columns * Add an index on podcastEpisodes.publishedAt * Fix group_concat order by and update to sqlite 3.44.2 --------- Co-authored-by: advplyr <advplyr@protonmail.com>
This commit is contained in:
parent
bba09626a7
commit
40504da4d7
11 changed files with 1133 additions and 151 deletions
|
@ -782,6 +782,7 @@ class Database {
|
|||
await this.addTriggerIfNotExists('books', 'titleIgnorePrefix', 'id', 'libraryItems', 'titleIgnorePrefix', 'mediaId')
|
||||
await this.addTriggerIfNotExists('podcasts', 'title', 'id', 'libraryItems', 'title', 'mediaId')
|
||||
await this.addTriggerIfNotExists('podcasts', 'titleIgnorePrefix', 'id', 'libraryItems', 'titleIgnorePrefix', 'mediaId')
|
||||
await this.addAuthorNamesTriggersIfNotExist()
|
||||
}
|
||||
|
||||
async addTriggerIfNotExists(sourceTable, sourceColumn, sourceIdColumn, targetTable, targetColumn, targetIdColumn) {
|
||||
|
@ -806,6 +807,74 @@ class Database {
|
|||
`)
|
||||
}
|
||||
|
||||
async addAuthorNamesTriggersIfNotExist() {
|
||||
const libraryItems = 'libraryItems'
|
||||
const bookAuthors = 'bookAuthors'
|
||||
const authors = 'authors'
|
||||
const columns = [
|
||||
{ name: 'authorNamesFirstLast', source: `${authors}.name`, spec: { type: Sequelize.STRING, allowNull: true } },
|
||||
{ name: 'authorNamesLastFirst', source: `${authors}.lastFirst`, spec: { type: Sequelize.STRING, allowNull: true } }
|
||||
]
|
||||
const authorsSort = `${bookAuthors}.createdAt ASC`
|
||||
const columnNames = columns.map((column) => column.name).join(', ')
|
||||
const columnSourcesExpression = columns.map((column) => `GROUP_CONCAT(${column.source}, ', ' ORDER BY ${authorsSort})`).join(', ')
|
||||
const authorsJoin = `${authors} JOIN ${bookAuthors} ON ${authors}.id = ${bookAuthors}.authorId`
|
||||
|
||||
const addBookAuthorsTriggerIfNotExists = async (action) => {
|
||||
const modifiedRecord = action === 'delete' ? 'OLD' : 'NEW'
|
||||
const triggerName = this.convertToSnakeCase(`update_${libraryItems}_authorNames_on_${bookAuthors}_${action}`)
|
||||
const authorNamesSubQuery = `
|
||||
SELECT ${columnSourcesExpression}
|
||||
FROM ${authorsJoin}
|
||||
WHERE ${bookAuthors}.bookId = ${modifiedRecord}.bookId
|
||||
`
|
||||
const [[{ count }]] = await this.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='${triggerName}'`)
|
||||
if (count > 0) return // Trigger already exists
|
||||
|
||||
Logger.info(`[Database] Adding trigger ${triggerName}`)
|
||||
|
||||
await this.sequelize.query(`
|
||||
CREATE TRIGGER ${triggerName}
|
||||
AFTER ${action} ON ${bookAuthors}
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE ${libraryItems}
|
||||
SET (${columnNames}) = (${authorNamesSubQuery})
|
||||
WHERE mediaId = ${modifiedRecord}.bookId;
|
||||
END;
|
||||
`)
|
||||
}
|
||||
|
||||
const addAuthorsUpdateTriggerIfNotExists = async () => {
|
||||
const triggerName = this.convertToSnakeCase(`update_${libraryItems}_authorNames_on_authors_update`)
|
||||
const authorNamesSubQuery = `
|
||||
SELECT ${columnSourcesExpression}
|
||||
FROM ${authorsJoin}
|
||||
WHERE ${bookAuthors}.bookId = ${libraryItems}.mediaId
|
||||
`
|
||||
|
||||
const [[{ count }]] = await this.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='${triggerName}'`)
|
||||
if (count > 0) return // Trigger already exists
|
||||
|
||||
Logger.info(`[Database] Adding trigger ${triggerName}`)
|
||||
|
||||
await this.sequelize.query(`
|
||||
CREATE TRIGGER ${triggerName}
|
||||
AFTER UPDATE OF name ON ${authors}
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE ${libraryItems}
|
||||
SET (${columnNames}) = (${authorNamesSubQuery})
|
||||
WHERE mediaId IN (SELECT bookId FROM ${bookAuthors} WHERE authorId = NEW.id);
|
||||
END;
|
||||
`)
|
||||
}
|
||||
|
||||
await addBookAuthorsTriggerIfNotExists('insert')
|
||||
await addBookAuthorsTriggerIfNotExists('delete')
|
||||
await addAuthorsUpdateTriggerIfNotExists()
|
||||
}
|
||||
|
||||
convertToSnakeCase(str) {
|
||||
return str.replace(/([A-Z])/g, '_$1').toLowerCase()
|
||||
}
|
||||
|
|
|
@ -15,3 +15,4 @@ Please add a record of every database migration that you create to this file. Th
|
|||
| v2.17.7 | v2.17.7-add-indices | Adds indices to the libraryItems and books tables to reduce query times |
|
||||
| v2.19.1 | v2.19.1-copy-title-to-library-items | Copies title and titleIgnorePrefix to the libraryItems table, creates update triggers and indices |
|
||||
| v2.19.4 | v2.19.4-improve-podcast-queries | Adds numEpisodes to podcasts, adds podcastId to mediaProgresses, copies podcast title to libraryItems |
|
||||
| v2.20.0 | v2.20.0-improve-author-sort-queries | Adds AuthorNames(FirstLast\|LastFirst) to libraryItems to improve author sort queries |
|
||||
|
|
272
server/migrations/v2.20.0-improve-author-sort-queries.js
Normal file
272
server/migrations/v2.20.0-improve-author-sort-queries.js
Normal file
|
@ -0,0 +1,272 @@
|
|||
const util = require('util')
|
||||
const { Sequelize } = require('sequelize')
|
||||
|
||||
/**
|
||||
* @typedef MigrationContext
|
||||
* @property {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object.
|
||||
* @property {import('../Logger')} logger - a Logger object.
|
||||
*
|
||||
* @typedef MigrationOptions
|
||||
* @property {MigrationContext} context - an object containing the migration context.
|
||||
*/
|
||||
|
||||
const migrationVersion = '2.20.0'
|
||||
const migrationName = `${migrationVersion}-improve-author-sort-queries`
|
||||
const loggerPrefix = `[${migrationVersion} migration]`
|
||||
|
||||
// Migration constants
|
||||
const libraryItems = 'libraryItems'
|
||||
const bookAuthors = 'bookAuthors'
|
||||
const authors = 'authors'
|
||||
const podcastEpisodes = 'podcastEpisodes'
|
||||
const columns = [
|
||||
{ name: 'authorNamesFirstLast', source: `${authors}.name`, spec: { type: Sequelize.STRING, allowNull: true } },
|
||||
{ name: 'authorNamesLastFirst', source: `${authors}.lastFirst`, spec: { type: Sequelize.STRING, allowNull: true } }
|
||||
]
|
||||
const authorsSort = `${bookAuthors}.createdAt ASC`
|
||||
const columnNames = columns.map((column) => column.name).join(', ')
|
||||
const columnSourcesExpression = columns.map((column) => `GROUP_CONCAT(${column.source}, ', ' ORDER BY ${authorsSort})`).join(', ')
|
||||
const authorsJoin = `${authors} JOIN ${bookAuthors} ON ${authors}.id = ${bookAuthors}.authorId`
|
||||
|
||||
/**
|
||||
* This upward migration adds an authorNames column to the libraryItems table and populates it.
|
||||
* It also creates triggers to update the authorNames column when the corresponding bookAuthors and authors records are updated.
|
||||
* It also creates an index on the authorNames column.
|
||||
*
|
||||
* It also adds an index on publishedAt to the podcastEpisodes table.
|
||||
*
|
||||
* @param {MigrationOptions} options - an object containing the migration context.
|
||||
* @returns {Promise<void>} - A promise that resolves when the migration is complete.
|
||||
*/
|
||||
async function up({ context: { queryInterface, logger } }) {
|
||||
const helper = new MigrationHelper(queryInterface, logger)
|
||||
|
||||
// Upwards migration script
|
||||
logger.info(`${loggerPrefix} UPGRADE BEGIN: ${migrationName}`)
|
||||
|
||||
// Add authorNames columns to libraryItems table
|
||||
await helper.addColumns()
|
||||
|
||||
// Populate authorNames columns with the author names for each libraryItem
|
||||
await helper.populateColumnsFromSource()
|
||||
|
||||
// Create triggers to update the authorNames column when the corresponding bookAuthors and authors records are updated
|
||||
await helper.addTriggers()
|
||||
|
||||
// Create indexes on the authorNames columns
|
||||
await helper.addIndexes()
|
||||
|
||||
// Add index on publishedAt to the podcastEpisodes table
|
||||
await helper.addIndex(podcastEpisodes, ['publishedAt'])
|
||||
|
||||
logger.info(`${loggerPrefix} UPGRADE END: ${migrationName}`)
|
||||
}
|
||||
|
||||
/**
|
||||
* This downward migration removes the authorNames column from the libraryItems table,
|
||||
* the triggers on the bookAuthors and authors tables, and the index on the authorNames column.
|
||||
*
|
||||
* It also removes the index on publishedAt from the podcastEpisodes table.
|
||||
*
|
||||
* @param {MigrationOptions} options - an object containing the migration context.
|
||||
* @returns {Promise<void>} - A promise that resolves when the migration is complete.
|
||||
*/
|
||||
async function down({ context: { queryInterface, logger } }) {
|
||||
// Downward migration script
|
||||
logger.info(`${loggerPrefix} DOWNGRADE BEGIN: ${migrationName}`)
|
||||
|
||||
const helper = new MigrationHelper(queryInterface, logger)
|
||||
|
||||
// Remove triggers to update authorNames columns
|
||||
await helper.removeTriggers()
|
||||
|
||||
// Remove index on publishedAt from the podcastEpisodes table
|
||||
await helper.removeIndex(podcastEpisodes, ['publishedAt'])
|
||||
|
||||
// Remove indexes on the authorNames columns
|
||||
await helper.removeIndexes()
|
||||
|
||||
// Remove authorNames columns from libraryItems table
|
||||
await helper.removeColumns()
|
||||
|
||||
logger.info(`${loggerPrefix} DOWNGRADE END: ${migrationName}`)
|
||||
}
|
||||
|
||||
class MigrationHelper {
|
||||
constructor(queryInterface, logger) {
|
||||
this.queryInterface = queryInterface
|
||||
this.logger = logger
|
||||
}
|
||||
|
||||
async addColumn(table, column, options) {
|
||||
this.logger.info(`${loggerPrefix} adding column "${column}" to table "${table}"`)
|
||||
const tableDescription = await this.queryInterface.describeTable(table)
|
||||
if (!tableDescription[column]) {
|
||||
await this.queryInterface.addColumn(table, column, options)
|
||||
this.logger.info(`${loggerPrefix} added column "${column}" to table "${table}"`)
|
||||
} else {
|
||||
this.logger.info(`${loggerPrefix} column "${column}" already exists in table "${table}"`)
|
||||
}
|
||||
}
|
||||
|
||||
async addColumns() {
|
||||
this.logger.info(`${loggerPrefix} adding ${columnNames} columns to ${libraryItems} table`)
|
||||
for (const column of columns) {
|
||||
await this.addColumn(libraryItems, column.name, column.spec)
|
||||
}
|
||||
this.logger.info(`${loggerPrefix} added ${columnNames} columns to ${libraryItems} table`)
|
||||
}
|
||||
|
||||
async removeColumn(table, column) {
|
||||
this.logger.info(`${loggerPrefix} removing column "${column}" from table "${table}"`)
|
||||
const tableDescription = await this.queryInterface.describeTable(table)
|
||||
if (tableDescription[column]) {
|
||||
await this.queryInterface.sequelize.query(`ALTER TABLE ${table} DROP COLUMN ${column}`)
|
||||
this.logger.info(`${loggerPrefix} removed column "${column}" from table "${table}"`)
|
||||
} else {
|
||||
this.logger.info(`${loggerPrefix} column "${column}" does not exist in table "${table}"`)
|
||||
}
|
||||
}
|
||||
|
||||
async removeColumns() {
|
||||
this.logger.info(`${loggerPrefix} removing ${columnNames} columns from ${libraryItems} table`)
|
||||
for (const column of columns) {
|
||||
await this.removeColumn(libraryItems, column.name)
|
||||
}
|
||||
this.logger.info(`${loggerPrefix} removed ${columnNames} columns from ${libraryItems} table`)
|
||||
}
|
||||
|
||||
async populateColumnsFromSource() {
|
||||
this.logger.info(`${loggerPrefix} populating ${columnNames} columns in ${libraryItems} table`)
|
||||
const authorNamesSubQuery = `
|
||||
SELECT ${columnSourcesExpression}
|
||||
FROM ${authorsJoin}
|
||||
WHERE ${bookAuthors}.bookId = ${libraryItems}.mediaId
|
||||
`
|
||||
await this.queryInterface.sequelize.query(`
|
||||
UPDATE ${libraryItems}
|
||||
SET (${columnNames}) = (${authorNamesSubQuery})
|
||||
WHERE mediaType = 'book';
|
||||
`)
|
||||
this.logger.info(`${loggerPrefix} populated ${columnNames} columns in ${libraryItems} table`)
|
||||
}
|
||||
|
||||
async addBookAuthorsTrigger(action) {
|
||||
this.logger.info(`${loggerPrefix} adding trigger to update ${libraryItems} ${columnNames} on ${bookAuthors} ${action}`)
|
||||
const modifiedRecord = action === 'delete' ? 'OLD' : 'NEW'
|
||||
const triggerName = convertToSnakeCase(`update_${libraryItems}_authorNames_on_${bookAuthors}_${action}`)
|
||||
const authorNamesSubQuery = `
|
||||
SELECT ${columnSourcesExpression}
|
||||
FROM ${authorsJoin}
|
||||
WHERE ${bookAuthors}.bookId = ${modifiedRecord}.bookId
|
||||
`
|
||||
await this.queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`)
|
||||
|
||||
await this.queryInterface.sequelize.query(`
|
||||
CREATE TRIGGER ${triggerName}
|
||||
AFTER ${action} ON ${bookAuthors}
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE ${libraryItems}
|
||||
SET (${columnNames}) = (${authorNamesSubQuery})
|
||||
WHERE mediaId = ${modifiedRecord}.bookId;
|
||||
END;
|
||||
`)
|
||||
this.logger.info(`${loggerPrefix} added trigger to update ${libraryItems} ${columnNames} on ${bookAuthors} ${action}`)
|
||||
}
|
||||
|
||||
async addAuthorsUpdateTrigger() {
|
||||
this.logger.info(`${loggerPrefix} adding trigger to update ${libraryItems} ${columnNames} on ${authors} update`)
|
||||
const triggerName = convertToSnakeCase(`update_${libraryItems}_authorNames_on_authors_update`)
|
||||
const authorNamesSubQuery = `
|
||||
SELECT ${columnSourcesExpression}
|
||||
FROM ${authorsJoin}
|
||||
WHERE ${bookAuthors}.bookId = ${libraryItems}.mediaId
|
||||
`
|
||||
|
||||
await this.queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`)
|
||||
|
||||
await this.queryInterface.sequelize.query(`
|
||||
CREATE TRIGGER ${triggerName}
|
||||
AFTER UPDATE OF name ON ${authors}
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE ${libraryItems}
|
||||
SET (${columnNames}) = (${authorNamesSubQuery})
|
||||
WHERE mediaId IN (SELECT bookId FROM ${bookAuthors} WHERE authorId = NEW.id);
|
||||
END;
|
||||
`)
|
||||
this.logger.info(`${loggerPrefix} added trigger to update ${libraryItems} ${columnNames} on ${authors} update`)
|
||||
}
|
||||
|
||||
async addTriggers() {
|
||||
await this.addBookAuthorsTrigger('insert')
|
||||
await this.addBookAuthorsTrigger('delete')
|
||||
await this.addAuthorsUpdateTrigger()
|
||||
}
|
||||
|
||||
async removeBookAuthorsTrigger(action) {
|
||||
this.logger.info(`${loggerPrefix} removing trigger to update ${libraryItems} ${columnNames} on ${bookAuthors} ${action}`)
|
||||
const triggerName = convertToSnakeCase(`update_${libraryItems}_authorNames_on_${bookAuthors}_${action}`)
|
||||
await this.queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`)
|
||||
this.logger.info(`${loggerPrefix} removed trigger to update ${libraryItems} ${columnNames} on ${bookAuthors} ${action}`)
|
||||
}
|
||||
|
||||
async removeAuthorsUpdateTrigger() {
|
||||
this.logger.info(`${loggerPrefix} removing trigger to update ${libraryItems} ${columnNames} on ${authors} update`)
|
||||
const triggerName = convertToSnakeCase(`update_${libraryItems}_authorNames_on_authors_update`)
|
||||
await this.queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`)
|
||||
this.logger.info(`${loggerPrefix} removed trigger to update ${libraryItems} ${columnNames} on ${authors} update`)
|
||||
}
|
||||
|
||||
async removeTriggers() {
|
||||
await this.removeBookAuthorsTrigger('insert')
|
||||
await this.removeBookAuthorsTrigger('delete')
|
||||
await this.removeAuthorsUpdateTrigger()
|
||||
}
|
||||
|
||||
async addIndex(tableName, columns) {
|
||||
const columnString = columns.map((column) => util.inspect(column)).join(', ')
|
||||
const indexName = convertToSnakeCase(`${tableName}_${columns.map((column) => (typeof column === 'string' ? column : column.name)).join('_')}`)
|
||||
try {
|
||||
this.logger.info(`${loggerPrefix} adding index on [${columnString}] to table ${tableName}. index name: ${indexName}"`)
|
||||
await this.queryInterface.addIndex(tableName, columns)
|
||||
this.logger.info(`${loggerPrefix} added index on [${columnString}] to table ${tableName}. index name: ${indexName}"`)
|
||||
} catch (error) {
|
||||
if (error.name === 'SequelizeDatabaseError' && error.message.includes('already exists')) {
|
||||
this.logger.info(`${loggerPrefix} index [${columnString}] for table "${tableName}" already exists`)
|
||||
} else {
|
||||
throw error
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
async addIndexes() {
|
||||
for (const column of columns) {
|
||||
await this.addIndex(libraryItems, ['libraryId', 'mediaType', { name: column.name, collate: 'NOCASE' }])
|
||||
}
|
||||
}
|
||||
|
||||
async removeIndex(tableName, columns) {
|
||||
this.logger.info(`${loggerPrefix} removing index [${columns.join(', ')}] from table "${tableName}"`)
|
||||
await this.queryInterface.removeIndex(tableName, columns)
|
||||
this.logger.info(`${loggerPrefix} removed index [${columns.join(', ')}] from table "${tableName}"`)
|
||||
}
|
||||
|
||||
async removeIndexes() {
|
||||
for (const column of columns) {
|
||||
await this.removeIndex(libraryItems, ['libraryId', 'mediaType', column.name])
|
||||
}
|
||||
}
|
||||
}
|
||||
/**
|
||||
* Utility function to convert a string to snake case, e.g. "titleIgnorePrefix" -> "title_ignore_prefix"
|
||||
*
|
||||
* @param {string} str - the string to convert to snake case.
|
||||
* @returns {string} - the string in snake case.
|
||||
*/
|
||||
function convertToSnakeCase(str) {
|
||||
return str.replace(/([A-Z])/g, '_$1').toLowerCase()
|
||||
}
|
||||
|
||||
module.exports = { up, down }
|
|
@ -77,6 +77,10 @@ class LibraryItem extends Model {
|
|||
this.title // Only used for sorting
|
||||
/** @type {string} */
|
||||
this.titleIgnorePrefix // Only used for sorting
|
||||
/** @type {string} */
|
||||
this.authorNamesFirstLast // Only used for sorting
|
||||
/** @type {string} */
|
||||
this.authorNamesLastFirst // Only used for sorting
|
||||
}
|
||||
|
||||
/**
|
||||
|
@ -683,7 +687,9 @@ class LibraryItem extends Model {
|
|||
libraryFiles: DataTypes.JSON,
|
||||
extraData: DataTypes.JSON,
|
||||
title: DataTypes.STRING,
|
||||
titleIgnorePrefix: DataTypes.STRING
|
||||
titleIgnorePrefix: DataTypes.STRING,
|
||||
authorNamesFirstLast: DataTypes.STRING,
|
||||
authorNamesLastFirst: DataTypes.STRING
|
||||
},
|
||||
{
|
||||
sequelize,
|
||||
|
@ -710,6 +716,12 @@ class LibraryItem extends Model {
|
|||
{
|
||||
fields: ['libraryId', 'mediaType', { name: 'titleIgnorePrefix', collate: 'NOCASE' }]
|
||||
},
|
||||
{
|
||||
fields: ['libraryId', 'mediaType', { name: 'authorNamesFirstLast', collate: 'NOCASE' }]
|
||||
},
|
||||
{
|
||||
fields: ['libraryId', 'mediaType', { name: 'authorNamesLastFirst', collate: 'NOCASE' }]
|
||||
},
|
||||
{
|
||||
fields: ['libraryId', 'mediaId', 'mediaType']
|
||||
},
|
||||
|
|
|
@ -122,6 +122,10 @@ class PodcastEpisode extends Model {
|
|||
{
|
||||
name: 'podcastEpisode_createdAt_podcastId',
|
||||
fields: ['createdAt', 'podcastId']
|
||||
},
|
||||
{
|
||||
name: 'podcast_episodes_published_at',
|
||||
fields: ['publishedAt']
|
||||
}
|
||||
]
|
||||
}
|
||||
|
|
|
@ -523,6 +523,8 @@ class BookScanner {
|
|||
libraryItemObj.extraData = {}
|
||||
libraryItemObj.title = bookMetadata.title
|
||||
libraryItemObj.titleIgnorePrefix = getTitleIgnorePrefix(bookMetadata.title)
|
||||
libraryItemObj.authorNamesFirstLast = bookMetadata.authors.join(', ')
|
||||
libraryItemObj.authorNamesLastFirst = bookMetadata.authors.map((author) => Database.authorModel.getLastFirst(author)).join(', ')
|
||||
|
||||
// Set isSupplementary flag on ebook library files
|
||||
for (const libraryFile of libraryItemObj.libraryFiles) {
|
||||
|
|
|
@ -264,9 +264,9 @@ module.exports = {
|
|||
} else if (sortBy === 'media.metadata.publishedYear') {
|
||||
return [[Sequelize.literal(`CAST(\`book\`.\`publishedYear\` AS INTEGER)`), dir]]
|
||||
} else if (sortBy === 'media.metadata.authorNameLF') {
|
||||
return [[Sequelize.literal('author_name COLLATE NOCASE'), dir]]
|
||||
return [[Sequelize.literal('`libraryItem`.`authorNamesLastFirst` COLLATE NOCASE'), dir]]
|
||||
} else if (sortBy === 'media.metadata.authorName') {
|
||||
return [[Sequelize.literal('author_name COLLATE NOCASE'), dir]]
|
||||
return [[Sequelize.literal('`libraryItem`.`authorNamesFirstLast` COLLATE NOCASE'), dir]]
|
||||
} else if (sortBy === 'media.metadata.title') {
|
||||
if (collapseseries) {
|
||||
return [[Sequelize.literal('display_title COLLATE NOCASE'), dir]]
|
||||
|
@ -397,18 +397,7 @@ module.exports = {
|
|||
const includeRSSFeed = include.includes('rssfeed')
|
||||
const includeMediaItemShare = !!user?.isAdminOrUp && include.includes('share')
|
||||
|
||||
// For sorting by author name an additional attribute must be added
|
||||
// with author names concatenated
|
||||
let bookAttributes = null
|
||||
if (sortBy === 'media.metadata.authorNameLF') {
|
||||
bookAttributes = {
|
||||
include: [[Sequelize.literal(`(SELECT group_concat(lastFirst, ", ") FROM (SELECT a.lastFirst FROM authors AS a, bookAuthors as ba WHERE ba.authorId = a.id AND ba.bookId = book.id ORDER BY ba.createdAt ASC))`), 'author_name']]
|
||||
}
|
||||
} else if (sortBy === 'media.metadata.authorName') {
|
||||
bookAttributes = {
|
||||
include: [[Sequelize.literal(`(SELECT group_concat(name, ", ") FROM (SELECT a.name FROM authors AS a, bookAuthors as ba WHERE ba.authorId = a.id AND ba.bookId = book.id ORDER BY ba.createdAt ASC))`), 'author_name']]
|
||||
}
|
||||
}
|
||||
|
||||
const libraryItemWhere = {
|
||||
libraryId
|
||||
|
|
|
@ -465,7 +465,7 @@ module.exports = {
|
|||
async getRecentEpisodes(user, library, limit, offset) {
|
||||
const userPermissionPodcastWhere = this.getUserPermissionPodcastWhereQuery(user)
|
||||
|
||||
const episodes = await Database.podcastEpisodeModel.findAll({
|
||||
const findOptions = {
|
||||
where: {
|
||||
'$mediaProgresses.isFinished$': {
|
||||
[Sequelize.Op.or]: [null, false]
|
||||
|
@ -496,7 +496,11 @@ module.exports = {
|
|||
subQuery: false,
|
||||
limit,
|
||||
offset
|
||||
})
|
||||
}
|
||||
|
||||
const findtAll = process.env.QUERY_PROFILING ? profile(Database.podcastEpisodeModel.findAll.bind(Database.podcastEpisodeModel)) : Database.podcastEpisodeModel.findAll.bind(Database.podcastEpisodeModel)
|
||||
|
||||
const episodes = await findtAll(findOptions)
|
||||
|
||||
const episodeResults = episodes.map((ep) => {
|
||||
ep.podcast.podcastEpisodes = [] // Not needed
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue