From 23a750214fcd0927d9bbbde52dcb4f17d040455d Mon Sep 17 00:00:00 2001 From: mikiher Date: Sun, 16 Feb 2025 08:35:51 +0200 Subject: [PATCH] Add migration in preparation for podcast query optimization --- server/migrations/changelog.md | 1 + .../v2.19.3-improve-podcast-queries.js | 219 +++++++++++++++ .../v2.19.3-improve-podcast-queries.test.js | 265 ++++++++++++++++++ 3 files changed, 485 insertions(+) create mode 100644 server/migrations/v2.19.3-improve-podcast-queries.js create mode 100644 test/server/migrations/v2.19.3-improve-podcast-queries.test.js diff --git a/server/migrations/changelog.md b/server/migrations/changelog.md index acccef90..64b2d671 100644 --- a/server/migrations/changelog.md +++ b/server/migrations/changelog.md @@ -14,3 +14,4 @@ Please add a record of every database migration that you create to this file. Th | v2.17.6 | v2.17.6-share-add-isdownloadable | Adds the isDownloadable column to the mediaItemShares table | | 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.3 | v2.19.3-improve-podcast-queries | Adds numEpisodes to podcasts, adds podcastId to mediaProgresses, copies podcast title to libraryItems | diff --git a/server/migrations/v2.19.3-improve-podcast-queries.js b/server/migrations/v2.19.3-improve-podcast-queries.js new file mode 100644 index 00000000..4e64d3ff --- /dev/null +++ b/server/migrations/v2.19.3-improve-podcast-queries.js @@ -0,0 +1,219 @@ +const util = require('util') + +/** + * @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.3' +const migrationName = `${migrationVersion}-improve-podcast-queries` +const loggerPrefix = `[${migrationVersion} migration]` + +/** + * This upward migration adds a numEpisodes column to the podcasts table and populates it. + * It also adds a podcastId column to the mediaProgresses table and populates it. + * It also copies the title and titleIgnorePrefix columns from the podcasts table to the libraryItems table, + * and adds triggers to update them when the corresponding columns in the podcasts table are updated. + * + * @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 } }) { + // Upwards migration script + logger.info(`${loggerPrefix} UPGRADE BEGIN: ${migrationName}`) + + // Add numEpisodes column to podcasts table + await addColumn(queryInterface, logger, 'podcasts', 'numEpisodes', { type: queryInterface.sequelize.Sequelize.INTEGER, allowNull: false, defaultValue: 0 }) + + // Populate numEpisodes column with the number of episodes for each podcast + await populateNumEpisodes(queryInterface, logger) + + // Add podcastId column to mediaProgresses table + await addColumn(queryInterface, logger, 'mediaProgresses', 'podcastId', { type: queryInterface.sequelize.Sequelize.UUID, allowNull: true }) + + // Populate podcastId column with the podcastId for each mediaProgress + await populatePodcastId(queryInterface, logger) + + // Copy title and titleIgnorePrefix columns from podcasts to libraryItems + await copyColumn(queryInterface, logger, 'podcasts', 'title', 'id', 'libraryItems', 'title', 'mediaId') + await copyColumn(queryInterface, logger, 'podcasts', 'titleIgnorePrefix', 'id', 'libraryItems', 'titleIgnorePrefix', 'mediaId') + + // Add triggers to update title and titleIgnorePrefix in libraryItems + await addTrigger(queryInterface, logger, 'podcasts', 'title', 'id', 'libraryItems', 'title', 'mediaId') + await addTrigger(queryInterface, logger, 'podcasts', 'titleIgnorePrefix', 'id', 'libraryItems', 'titleIgnorePrefix', 'mediaId') + + logger.info(`${loggerPrefix} UPGRADE END: ${migrationName}`) +} + +/** + * This downward migration removes the triggers on the podcasts table, + * the numEpisodes column from the podcasts table, and the podcastId column from the mediaProgresses table. + * + * @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}`) + + // Remove triggers from libraryItems + await removeTrigger(queryInterface, logger, 'podcasts', 'title', 'libraryItems', 'title') + await removeTrigger(queryInterface, logger, 'podcasts', 'titleIgnorePrefix', 'libraryItems', 'titleIgnorePrefix') + + // Remove numEpisodes column from podcasts table + await removeColumn(queryInterface, logger, 'podcasts', 'numEpisodes') + + // Remove podcastId column from mediaProgresses table + await removeColumn(queryInterface, logger, 'mediaProgresses', 'podcastId') + + logger.info(`${loggerPrefix} DOWNGRADE END: ${migrationName}`) +} + +async function populateNumEpisodes(queryInterface, logger) { + logger.info(`${loggerPrefix} populating numEpisodes column in podcasts table`) + await queryInterface.sequelize.query(` + UPDATE podcasts + SET numEpisodes = (SELECT COUNT(*) FROM podcastEpisodes WHERE podcastEpisodes.podcastId = podcasts.id) + `) + logger.info(`${loggerPrefix} populated numEpisodes column in podcasts table`) +} + +async function populatePodcastId(queryInterface, logger) { + logger.info(`${loggerPrefix} populating podcastId column in mediaProgresses table`) + // bulk update podcastId to the podcastId of the podcastEpisode if the mediaItemType is podcastEpisode + await queryInterface.sequelize.query(` + UPDATE mediaProgresses + SET podcastId = (SELECT podcastId FROM podcastEpisodes WHERE podcastEpisodes.id = mediaProgresses.mediaItemId) + WHERE mediaItemType = 'podcastEpisode' + `) + logger.info(`${loggerPrefix} populated podcastId column in mediaProgresses table`) +} + +/** + * Utility function to add a column to a table. If the column already exists, it logs a message and continues. + * + * @param {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object. + * @param {import('../Logger')} logger - a Logger object. + * @param {string} table - the name of the table to add the column to. + * @param {string} column - the name of the column to add. + * @param {Object} options - the options for the column. + */ +async function addColumn(queryInterface, logger, table, column, options) { + logger.info(`${loggerPrefix} adding column "${column}" to table "${table}"`) + const tableDescription = await queryInterface.describeTable(table) + if (!tableDescription[column]) { + await queryInterface.addColumn(table, column, options) + logger.info(`${loggerPrefix} added column "${column}" to table "${table}"`) + } else { + logger.info(`${loggerPrefix} column "${column}" already exists in table "${table}"`) + } +} + +/** + * Utility function to remove a column from a table. If the column does not exist, it logs a message and continues. + * + * @param {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object. + * @param {import('../Logger')} logger - a Logger object. + * @param {string} table - the name of the table to remove the column from. + * @param {string} column - the name of the column to remove. + */ +async function removeColumn(queryInterface, logger, table, column) { + logger.info(`${loggerPrefix} removing column "${column}" from table "${table}"`) + const tableDescription = await queryInterface.describeTable(table) + if (tableDescription[column]) { + await queryInterface.sequelize.query(`ALTER TABLE ${table} DROP COLUMN ${column}`) + logger.info(`${loggerPrefix} removed column "${column}" from table "${table}"`) + } else { + logger.info(`${loggerPrefix} column "${column}" does not exist in table "${table}"`) + } +} + +/** + * Utility function to add a trigger to update a column in a target table when a column in a source table is updated. + * If the trigger already exists, it drops it and creates a new one. + * sourceIdColumn and targetIdColumn are used to match the source and target rows. + * + * @param {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object. + * @param {import('../Logger')} logger - a Logger object. + * @param {string} sourceTable - the name of the source table. + * @param {string} sourceColumn - the name of the column to update. + * @param {string} sourceIdColumn - the name of the id column of the source table. + * @param {string} targetTable - the name of the target table. + * @param {string} targetColumn - the name of the column to update. + * @param {string} targetIdColumn - the name of the id column of the target table. + */ +async function addTrigger(queryInterface, logger, sourceTable, sourceColumn, sourceIdColumn, targetTable, targetColumn, targetIdColumn) { + logger.info(`${loggerPrefix} adding trigger to update ${targetTable}.${targetColumn} when ${sourceTable}.${sourceColumn} is updated`) + const triggerName = convertToSnakeCase(`update_${targetTable}_${targetColumn}_from_${sourceTable}_${sourceColumn}`) + + await queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`) + + await queryInterface.sequelize.query(` + CREATE TRIGGER ${triggerName} + AFTER UPDATE OF ${sourceColumn} ON ${sourceTable} + FOR EACH ROW + BEGIN + UPDATE ${targetTable} + SET ${targetColumn} = NEW.${sourceColumn} + WHERE ${targetTable}.${targetIdColumn} = NEW.${sourceIdColumn}; + END; + `) + logger.info(`${loggerPrefix} added trigger to update ${targetTable}.${targetColumn} when ${sourceTable}.${sourceColumn} is updated`) +} + +/** + * Utility function to remove an update trigger from a table. + * + * @param {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object. + * @param {import('../Logger')} logger - a Logger object. + * @param {string} sourceTable - the name of the source table. + * @param {string} sourceColumn - the name of the column to update. + * @param {string} targetTable - the name of the target table. + * @param {string} targetColumn - the name of the column to update. + */ +async function removeTrigger(queryInterface, logger, sourceTable, sourceColumn, targetTable, targetColumn) { + logger.info(`${loggerPrefix} removing trigger to update ${targetTable}.${targetColumn}`) + const triggerName = convertToSnakeCase(`update_${targetTable}_${targetColumn}_from_${sourceTable}_${sourceColumn}`) + await queryInterface.sequelize.query(`DROP TRIGGER IF EXISTS ${triggerName}`) + logger.info(`${loggerPrefix} removed trigger to update ${targetTable}.${targetColumn}`) +} + +/** + * Utility function to copy a column from a source table to a target table. + * sourceIdColumn and targetIdColumn are used to match the source and target rows. + * + * @param {import('sequelize').QueryInterface} queryInterface - a suquelize QueryInterface object. + * @param {import('../Logger')} logger - a Logger object. + * @param {string} sourceTable - the name of the source table. + * @param {string} sourceColumn - the name of the column to copy. + * @param {string} sourceIdColumn - the name of the id column of the source table. + * @param {string} targetTable - the name of the target table. + * @param {string} targetColumn - the name of the column to copy to. + * @param {string} targetIdColumn - the name of the id column of the target table. + */ +async function copyColumn(queryInterface, logger, sourceTable, sourceColumn, sourceIdColumn, targetTable, targetColumn, targetIdColumn) { + logger.info(`${loggerPrefix} copying column "${sourceColumn}" from table "${sourceTable}" to table "${targetTable}"`) + await queryInterface.sequelize.query(` + UPDATE ${targetTable} + SET ${targetColumn} = ${sourceTable}.${sourceColumn} + FROM ${sourceTable} + WHERE ${targetTable}.${targetIdColumn} = ${sourceTable}.${sourceIdColumn} + `) + logger.info(`${loggerPrefix} copied column "${sourceColumn}" from table "${sourceTable}" to table "${targetTable}"`) +} + +/** + * 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.3-improve-podcast-queries.test.js b/test/server/migrations/v2.19.3-improve-podcast-queries.test.js new file mode 100644 index 00000000..ae3784b9 --- /dev/null +++ b/test/server/migrations/v2.19.3-improve-podcast-queries.test.js @@ -0,0 +1,265 @@ +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.3-improve-podcast-queries') + +describe('Migration v2.19.3-improve-podcast-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 }, + title: { type: DataTypes.STRING, allowNull: true }, + titleIgnorePrefix: { type: DataTypes.STRING, allowNull: true } + }) + await queryInterface.createTable('podcasts', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + title: { type: DataTypes.STRING, allowNull: false }, + titleIgnorePrefix: { type: DataTypes.STRING, allowNull: false } + }) + + await queryInterface.createTable('podcastEpisodes', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + podcastId: { type: DataTypes.INTEGER, allowNull: false, references: { model: 'podcasts', key: 'id', onDelete: 'CASCADE' } } + }) + + await queryInterface.createTable('mediaProgresses', { + id: { type: DataTypes.INTEGER, allowNull: false, primaryKey: true, unique: true }, + userId: { type: DataTypes.INTEGER, allowNull: false }, + mediaItemId: { type: DataTypes.INTEGER, allowNull: false }, + mediaItemType: { type: DataTypes.STRING, allowNull: false }, + isFinished: { type: DataTypes.BOOLEAN, allowNull: false, defaultValue: false } + }) + + await queryInterface.bulkInsert('libraryItems', [ + { id: 1, mediaId: 1, title: null, titleIgnorePrefix: null }, + { id: 2, mediaId: 2, title: null, titleIgnorePrefix: null } + ]) + + await queryInterface.bulkInsert('podcasts', [ + { id: 1, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + await queryInterface.bulkInsert('podcastEpisodes', [ + { id: 1, podcastId: 1 }, + { id: 2, podcastId: 1 }, + { id: 3, podcastId: 2 } + ]) + + await queryInterface.bulkInsert('mediaProgresses', [ + { id: 1, userId: 1, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 2, userId: 1, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 3, userId: 1, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 4, userId: 2, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 5, userId: 2, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 6, userId: 2, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 7, userId: 1, mediaItemId: 1, mediaItemType: 'book', isFinished: 1 }, + { id: 8, userId: 1, mediaItemId: 2, mediaItemType: 'book', isFinished: 0 } + ]) + }) + + afterEach(() => { + sinon.restore() + }) + + describe('up', () => { + it('should add numEpisodes column to podcasts', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const [podcasts] = await queryInterface.sequelize.query('SELECT * FROM podcasts') + expect(podcasts).to.deep.equal([ + { id: 1, numEpisodes: 2, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, numEpisodes: 1, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + // Make sure podcastEpisodes are not affected due to ON DELETE CASCADE + const [podcastEpisodes] = await queryInterface.sequelize.query('SELECT * FROM podcastEpisodes') + expect(podcastEpisodes).to.deep.equal([ + { id: 1, podcastId: 1 }, + { id: 2, podcastId: 1 }, + { id: 3, podcastId: 2 } + ]) + }) + + it('should add podcastId column to mediaProgresses', async () => { + await up({ context: { queryInterface, logger: Logger } }) + + const [mediaProgresses] = await queryInterface.sequelize.query('SELECT * FROM mediaProgresses') + expect(mediaProgresses).to.deep.equal([ + { id: 1, userId: 1, mediaItemId: 1, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 1 }, + { id: 2, userId: 1, mediaItemId: 2, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 0 }, + { id: 3, userId: 1, mediaItemId: 3, mediaItemType: 'podcastEpisode', podcastId: 2, isFinished: 1 }, + { id: 4, userId: 2, mediaItemId: 1, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 0 }, + { id: 5, userId: 2, mediaItemId: 2, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 1 }, + { id: 6, userId: 2, mediaItemId: 3, mediaItemType: 'podcastEpisode', podcastId: 2, isFinished: 0 }, + { id: 7, userId: 1, mediaItemId: 1, mediaItemType: 'book', podcastId: null, isFinished: 1 }, + { id: 8, userId: 1, mediaItemId: 2, mediaItemType: 'book', podcastId: null, isFinished: 0 } + ]) + }) + + it('should copy title and titleIgnorePrefix from podcasts to libraryItems', 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, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, mediaId: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + }) + + it('should add trigger to update title in libraryItems', 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_title_from_podcasts_title'`) + expect(count).to.equal(1) + }) + + it('should add trigger to update titleIgnorePrefix in libraryItems', 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_title_ignore_prefix_from_podcasts_title_ignore_prefix'`) + expect(count).to.equal(1) + }) + + it('should be idempotent', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await up({ context: { queryInterface, logger: Logger } }) + + const [podcasts] = await queryInterface.sequelize.query('SELECT * FROM podcasts') + expect(podcasts).to.deep.equal([ + { id: 1, numEpisodes: 2, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, numEpisodes: 1, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + const [mediaProgresses] = await queryInterface.sequelize.query('SELECT * FROM mediaProgresses') + expect(mediaProgresses).to.deep.equal([ + { id: 1, userId: 1, mediaItemId: 1, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 1 }, + { id: 2, userId: 1, mediaItemId: 2, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 0 }, + { id: 3, userId: 1, mediaItemId: 3, mediaItemType: 'podcastEpisode', podcastId: 2, isFinished: 1 }, + { id: 4, userId: 2, mediaItemId: 1, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 0 }, + { id: 5, userId: 2, mediaItemId: 2, mediaItemType: 'podcastEpisode', podcastId: 1, isFinished: 1 }, + { id: 6, userId: 2, mediaItemId: 3, mediaItemType: 'podcastEpisode', podcastId: 2, isFinished: 0 }, + { id: 7, userId: 1, mediaItemId: 1, mediaItemType: 'book', podcastId: null, isFinished: 1 }, + { id: 8, userId: 1, mediaItemId: 2, mediaItemType: 'book', podcastId: null, isFinished: 0 } + ]) + + const [libraryItems] = await queryInterface.sequelize.query('SELECT * FROM libraryItems') + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, mediaId: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + const [[{ count: count1 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_title_from_podcasts_title'`) + expect(count1).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_title_ignore_prefix_from_podcasts_title_ignore_prefix'`) + expect(count2).to.equal(1) + }) + }) + + describe('down', () => { + it('should remove numEpisodes column from podcasts', async () => { + await up({ context: { queryInterface, logger: Logger } }) + try { + await down({ context: { queryInterface, logger: Logger } }) + } catch (error) { + console.log(error) + } + + const [podcasts] = await queryInterface.sequelize.query('SELECT * FROM podcasts') + expect(podcasts).to.deep.equal([ + { id: 1, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + // Make sure podcastEpisodes are not affected due to ON DELETE CASCADE + const [podcastEpisodes] = await queryInterface.sequelize.query('SELECT * FROM podcastEpisodes') + expect(podcastEpisodes).to.deep.equal([ + { id: 1, podcastId: 1 }, + { id: 2, podcastId: 1 }, + { id: 3, podcastId: 2 } + ]) + }) + + it('should remove podcastId column from mediaProgresses', async () => { + await up({ context: { queryInterface, logger: Logger } }) + await down({ context: { queryInterface, logger: Logger } }) + + const [mediaProgresses] = await queryInterface.sequelize.query('SELECT * FROM mediaProgresses') + expect(mediaProgresses).to.deep.equal([ + { id: 1, userId: 1, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 2, userId: 1, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 3, userId: 1, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 4, userId: 2, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 5, userId: 2, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 6, userId: 2, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 7, userId: 1, mediaItemId: 1, mediaItemType: 'book', isFinished: 1 }, + { id: 8, userId: 1, mediaItemId: 2, mediaItemType: 'book', isFinished: 0 } + ]) + }) + + it('should remove trigger to update title in libraryItems', 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_title_from_podcasts_title'`) + expect(count).to.equal(0) + }) + + it('should remove trigger to update titleIgnorePrefix in libraryItems', 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_title_ignore_prefix_from_podcasts_title_ignore_prefix'`) + expect(count).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 [podcasts] = await queryInterface.sequelize.query('SELECT * FROM podcasts') + expect(podcasts).to.deep.equal([ + { id: 1, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + const [mediaProgresses] = await queryInterface.sequelize.query('SELECT * FROM mediaProgresses') + expect(mediaProgresses).to.deep.equal([ + { id: 1, userId: 1, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 2, userId: 1, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 3, userId: 1, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 4, userId: 2, mediaItemId: 1, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 5, userId: 2, mediaItemId: 2, mediaItemType: 'podcastEpisode', isFinished: 1 }, + { id: 6, userId: 2, mediaItemId: 3, mediaItemType: 'podcastEpisode', isFinished: 0 }, + { id: 7, userId: 1, mediaItemId: 1, mediaItemType: 'book', isFinished: 1 }, + { id: 8, userId: 1, mediaItemId: 2, mediaItemType: 'book', isFinished: 0 } + ]) + + const [libraryItems] = await queryInterface.sequelize.query('SELECT * FROM libraryItems') + expect(libraryItems).to.deep.equal([ + { id: 1, mediaId: 1, title: 'The Podcast 1', titleIgnorePrefix: 'Podcast 1, The' }, + { id: 2, mediaId: 2, title: 'The Podcast 2', titleIgnorePrefix: 'Podcast 2, The' } + ]) + + const [[{ count: count1 }]] = await queryInterface.sequelize.query(`SELECT COUNT(*) as count FROM sqlite_master WHERE type='trigger' AND name='update_library_items_title_from_podcasts_title'`) + expect(count1).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_title_ignore_prefix_from_podcasts_title_ignore_prefix'`) + expect(count2).to.equal(0) + }) + }) +})