diff --git a/server/migrations/changelog.md b/server/migrations/changelog.md index b447970f5..d7fa669c1 100644 --- a/server/migrations/changelog.md +++ b/server/migrations/changelog.md @@ -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.19.6 | v2.19.6-improve-author-sort-queries | Adds AuthorNames(FirstLast\|LastFirst) to libraryItems to improve author sort queries | diff --git a/server/migrations/v2.19.6-improve-author-sort-queries.js b/server/migrations/v2.19.6-improve-author-sort-queries.js new file mode 100644 index 000000000..7d3c1846a --- /dev/null +++ b/server/migrations/v2.19.6-improve-author-sort-queries.js @@ -0,0 +1,264 @@ +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.19.6' +const migrationName = `${migrationVersion}-improve-author-sort-queries` +const loggerPrefix = `[${migrationVersion} migration]` + +// Migration constants +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 columnNames = columns.map((column) => column.name).join(', ') +const columnSourcesExpression = columns.map((column) => `GROUP_CONCAT(${column.source}, ', ')`).join(', ') +const authorsJoin = `${authors} JOIN ${bookAuthors} ON ${authors}.id = ${bookAuthors}.authorId` +const authorsSort = `${bookAuthors}.createdAt ASC` + +/** + * 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. + * + * @param {MigrationOptions} options - an object containing the migration context. + * @returns {Promise} - 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() + + 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. + * + * @param {MigrationOptions} options - an object containing the migration context. + * @returns {Promise} - 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 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 + ORDER BY ${authorsSort} + ` + 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 + ORDER BY ${authorsSort} + ` + 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 + ORDER BY ${authorsSort} + ` + + 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 } diff --git a/test/server/migrations/v2.19.6-improve-author-sort-queries.test.js b/test/server/migrations/v2.19.6-improve-author-sort-queries.test.js new file mode 100644 index 000000000..38102aa3d --- /dev/null +++ b/test/server/migrations/v2.19.6-improve-author-sort-queries.test.js @@ -0,0 +1,325 @@ +const chai = require('chai') +const sinon = require('sinon') +const { expect } = chai + +const { DataTypes, Sequelize } = require('sequelize') +const Logger = require('../../../server/Logger') + +const { up, down } = require('../../../server/migrations/v2.19.6-improve-author-sort-queries') + +const normalizeWhitespaceAndBackticks = (str) => str.replace(/\s+/g, ' ').trim().replace(/`/g, '') + +describe('Migration v2.19.6-improve-author-sort-queries', () => { + let sequelize + let queryInterface + let loggerInfoStub + + beforeEach(async () => { + sequelize = new Sequelize({ dialect: 'sqlite', storage: ':memory:', logging: false }) + queryInterface = sequelize.getQueryInterface() + loggerInfoStub = sinon.stub(Logger, 'info') + + await queryInterface.createTable('libraryItems', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + mediaId: { type: DataTypes.INTEGER, allowNull: false }, + mediaType: { type: DataTypes.STRING, allowNull: false }, + libraryId: { type: DataTypes.INTEGER, allowNull: false } + }) + + await queryInterface.createTable('authors', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + name: { type: DataTypes.STRING, allowNull: false }, + lastFirst: { type: DataTypes.STRING, allowNull: false } + }) + + await queryInterface.createTable('bookAuthors', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + bookId: { type: DataTypes.INTEGER, allowNull: false, references: { model: 'libraryItems', key: 'id', onDelete: 'CASCADE' } }, + authorId: { type: DataTypes.INTEGER, allowNull: false, references: { model: 'authors', key: 'id', onDelete: 'CASCADE' } }, + createdAt: { type: DataTypes.DATE, allowNull: false } + }) + + await queryInterface.bulkInsert('libraryItems', [ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1 }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1 } + ]) + + await queryInterface.bulkInsert('authors', [ + { id: 1, name: 'John Doe', lastFirst: 'Doe, John' }, + { id: 2, name: 'Jane Smith', lastFirst: 'Smith, Jane' }, + { id: 3, name: 'John Smith', lastFirst: 'Smith, John' } + ]) + + await queryInterface.bulkInsert('bookAuthors', [ + { id: 1, bookId: 1, authorId: 1, createdAt: '2025-01-01 00:00:00.000 +00:00' }, + { id: 2, bookId: 2, authorId: 2, createdAt: '2025-01-02 00:00:00.000 +00:00' }, + { id: 3, bookId: 1, authorId: 3, createdAt: '2025-01-03 00:00:00.000 +00:00' } + ]) + }) + + afterEach(() => { + sinon.restore() + }) + + describe('up', () => { + it('should add the authorNamesFirstLast and authorNamesLastFirst columns to the libraryItems table', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const libraryItems = await queryInterface.describeTable('libraryItems') + expect(libraryItems.authorNamesFirstLast).to.exist + expect(libraryItems.authorNamesLastFirst).to.exist + }) + + it('should populate the authorNamesFirstLast and authorNamesLastFirst columns with the author names for each libraryItem', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const [libraryItems] = await queryInterface.sequelize.query('SELECT * FROM libraryItems') + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'John Doe, John Smith', authorNamesLastFirst: 'Doe, John, Smith, John' }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'Jane Smith', authorNamesLastFirst: 'Smith, Jane' } + ]) + }) + + it('should create triggers to update the authorNamesFirstLast and authorNamesLastFirst columns when the corresponding bookAuthors and authors records are updated', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_insert'`) + expect(count).to.equal(1) + + const [[{ sql }]] = await queryInterface.sequelize.query(`SELECT sql FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_insert'`) + expect(normalizeWhitespaceAndBackticks(sql)).to.equal( + normalizeWhitespaceAndBackticks(` + CREATE TRIGGER update_library_items_author_names_on_book_authors_insert + AFTER insert ON bookAuthors + FOR EACH ROW + BEGIN + UPDATE libraryItems + SET (authorNamesFirstLast, authorNamesLastFirst) = ( + SELECT GROUP_CONCAT(authors.name, ', '), GROUP_CONCAT(authors.lastFirst, ', ') + FROM authors JOIN bookAuthors ON authors.id = bookAuthors.authorId + WHERE bookAuthors.bookId = NEW.bookId + ORDER BY bookAuthors.createdAt ASC + ) + WHERE mediaId = NEW.bookId; + END + `) + ) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_delete'`) + expect(count2).to.equal(1) + + const [[{ sql: sql2 }]] = await queryInterface.sequelize.query(`SELECT sql FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_delete'`) + expect(normalizeWhitespaceAndBackticks(sql2)).to.equal( + normalizeWhitespaceAndBackticks(` + CREATE TRIGGER update_library_items_author_names_on_book_authors_delete + AFTER delete ON bookAuthors + FOR EACH ROW + BEGIN + UPDATE libraryItems + SET (authorNamesFirstLast, authorNamesLastFirst) = ( + SELECT GROUP_CONCAT(authors.name, ', '), GROUP_CONCAT(authors.lastFirst, ', ') + FROM authors JOIN bookAuthors ON authors.id = bookAuthors.authorId + WHERE bookAuthors.bookId = OLD.bookId + ORDER BY bookAuthors.createdAt ASC + ) + WHERE mediaId = OLD.bookId; + END + `) + ) + + const [[{ count: count3 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_authors_update'`) + expect(count3).to.equal(1) + + const [[{ sql: sql3 }]] = await queryInterface.sequelize.query(`SELECT sql FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_authors_update'`) + expect(normalizeWhitespaceAndBackticks(sql3)).to.equal( + normalizeWhitespaceAndBackticks(` + CREATE TRIGGER update_library_items_author_names_on_authors_update + AFTER UPDATE OF name ON authors + FOR EACH ROW + BEGIN + UPDATE libraryItems + SET (authorNamesFirstLast, authorNamesLastFirst) = ( + SELECT GROUP_CONCAT(authors.name, ', '), GROUP_CONCAT(authors.lastFirst, ', ') + FROM authors JOIN bookAuthors ON authors.id = bookAuthors.authorId + WHERE bookAuthors.bookId = libraryItems.mediaId + ORDER BY bookAuthors.createdAt ASC + ) + WHERE mediaId IN (SELECT bookId FROM bookAuthors WHERE authorId = NEW.id); + END + `) + ) + }) + + it('should create indexes on the authorNamesFirstLast and authorNamesLastFirst columns', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_first_last'`) + expect(count).to.equal(1) + + const [[{ sql }]] = await queryInterface.sequelize.query(`SELECT sql FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_first_last'`) + expect(normalizeWhitespaceAndBackticks(sql)).to.equal( + normalizeWhitespaceAndBackticks(` + CREATE INDEX library_items_library_id_media_type_author_names_first_last ON libraryItems (libraryId, mediaType, authorNamesFirstLast COLLATE NOCASE) + `) + ) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_last_first'`) + expect(count2).to.equal(1) + + const [[{ sql: sql2 }]] = await queryInterface.sequelize.query(`SELECT sql FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_last_first'`) + expect(normalizeWhitespaceAndBackticks(sql2)).to.equal( + normalizeWhitespaceAndBackticks(` + CREATE INDEX library_items_library_id_media_type_author_names_last_first ON libraryItems (libraryId, mediaType, authorNamesLastFirst COLLATE NOCASE) + `) + ) + }) + + it('should trigger after update on authors', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + // update author name + await queryInterface.sequelize.query(`UPDATE authors SET (name, lastFirst) = ('John Wayne', 'Wayne, John') WHERE id = 1`) + + // check that the libraryItems table was updated + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'John Wayne, John Smith', authorNamesLastFirst: 'Wayne, John, Smith, John' }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'Jane Smith', authorNamesLastFirst: 'Smith, Jane' } + ]) + }) + + it('should trigger after insert on bookAuthors', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + // insert a new author + await queryInterface.sequelize.query(`INSERT INTO authors (id, name, lastFirst) VALUES (4, 'John Wayne', 'Wayne, John')`) + + // insert a new bookAuthor + await queryInterface.sequelize.query(`INSERT INTO bookAuthors (id, bookId, authorId, createdAt) VALUES (4, 1, 4, '2025-01-04 00:00:00.000 +00:00')`) + + // check that the libraryItems table was updated + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'John Doe, John Smith, John Wayne', authorNamesLastFirst: 'Doe, John, Smith, John, Wayne, John' }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'Jane Smith', authorNamesLastFirst: 'Smith, Jane' } + ]) + }) + + it('should trigger after delete on bookAuthors', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + // delete a bookAuthor + await queryInterface.sequelize.query(`DELETE FROM bookAuthors WHERE id = 1`) + + // check that the libraryItems table was updated + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'John Smith', authorNamesLastFirst: 'Smith, John' }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'Jane Smith', authorNamesLastFirst: 'Smith, Jane' } + ]) + }) + + it('should be idempotent', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await up({ context: { queryInterface, logger: Logger } }) + + const libraryItemsTable = await queryInterface.describeTable('libraryItems') + expect(libraryItemsTable.authorNamesFirstLast).to.exist + expect(libraryItemsTable.authorNamesLastFirst).to.exist + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_insert'`) + expect(count).to.equal(1) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_delete'`) + expect(count2).to.equal(1) + + const [[{ count: count3 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_authors_update'`) + expect(count3).to.equal(1) + + const [[{ count: count4 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_first_last'`) + expect(count4).to.equal(1) + + const [[{ count: count5 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_last_first'`) + expect(count5).to.equal(1) + + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'John Doe, John Smith', authorNamesLastFirst: 'Doe, John, Smith, John' }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1, authorNamesFirstLast: 'Jane Smith', authorNamesLastFirst: 'Smith, Jane' } + ]) + }) + }) + + describe('down', () => { + it('should remove the authorNamesFirstLast and authorNamesLastFirst columns from the libraryItems table', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + + const libraryItemsTable = await queryInterface.describeTable('libraryItems') + expect(libraryItemsTable.authorNamesFirstLast).to.not.exist + expect(libraryItemsTable.authorNamesLastFirst).to.not.exist + + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1 }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1 } + ]) + }) + + it('should remove the triggers from the libraryItems table', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_insert'`) + expect(count).to.equal(0) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_delete'`) + expect(count2).to.equal(0) + + const [[{ count: count3 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_authors_update'`) + expect(count3).to.equal(0) + }) + + it('should remove the indexes from the libraryItems table', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_first_last'`) + expect(count).to.equal(0) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_last_first'`) + expect(count2).to.equal(0) + }) + + it('should be idempotent', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + + const libraryItemsTable = await queryInterface.describeTable('libraryItems') + expect(libraryItemsTable.authorNamesFirstLast).to.not.exist + expect(libraryItemsTable.authorNamesLastFirst).to.not.exist + + const [libraryItems] = await queryInterface.sequelize.query(`SELECT * FROM libraryItems`) + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, mediaType: 'book', libraryId: 1 }, + { id: 2, mediaId: 2, mediaType: 'book', libraryId: 1 } + ]) + + const [[{ count }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_insert'`) + expect(count).to.equal(0) + + const [[{ count: count2 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_book_authors_delete'`) + expect(count2).to.equal(0) + + const [[{ count: count3 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_author_names_on_authors_update'`) + expect(count3).to.equal(0) + + const [[{ count: count4 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_first_last'`) + expect(count4).to.equal(0) + + const [[{ count: count5 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='index' AND name='library_items_library_id_media_type_author_names_last_first'`) + expect(count5).to.equal(0) + }) + }) +})