mirror of
https://github.com/TryGhost/Ghost.git
synced 2024-12-19 08:31:43 +03:00
Added migration to backfill offer ids in subscriptions (#14511)
refs https://github.com/TryGhost/Team/issues/1520 - Sets the `offer_id` in the `members_stripe_customers_subscriptions` table based on the `offer_redemptions` that have the same tier and cadence - We currently use the same subscription <-> offer linking when viewing a member - The MySQL query is quite optimized in a single UPDATE query, but in SQLite we'll need to run (maximum) one UPDATE query for every offer (not per subscription). - Best to merge this migration in 4.x (not in 5.0) because it is better (less error prone) to run this migration before starting to fill the offer_id field for updated migrations instead of after (https://github.com/TryGhost/Ghost/pull/14488) - We need the SQLite migration for sites that will only migrate to MySQL at 5.0
This commit is contained in:
parent
52a855f314
commit
9def4e6edc
@ -0,0 +1,60 @@
|
||||
const logging = require('@tryghost/logging');
|
||||
const DatabaseInfo = require('@tryghost/database-info');
|
||||
|
||||
const {createTransactionalMigration} = require('../../utils');
|
||||
|
||||
module.exports = createTransactionalMigration(
|
||||
async function up(knex) {
|
||||
logging.info('Backfilling "offer_id" column in "members_stripe_customers_subscriptions" by matching tier and cadence');
|
||||
|
||||
const subquery = `
|
||||
SELECT
|
||||
members_stripe_customers_subscriptions.id as subscription_id,
|
||||
offer_redemptions.offer_id as offer_id
|
||||
FROM
|
||||
members_stripe_customers_subscriptions
|
||||
JOIN offer_redemptions ON offer_redemptions.subscription_id = members_stripe_customers_subscriptions.id
|
||||
JOIN offers ON offers.id = offer_redemptions.offer_id
|
||||
JOIN stripe_prices ON members_stripe_customers_subscriptions.stripe_price_id = stripe_prices.stripe_price_id
|
||||
JOIN stripe_products ON stripe_prices.stripe_product_id = stripe_products.stripe_product_id
|
||||
WHERE
|
||||
offers.product_id = stripe_products.product_id
|
||||
AND offers.interval = stripe_prices.interval
|
||||
AND members_stripe_customers_subscriptions.offer_id is null
|
||||
`;
|
||||
|
||||
if (DatabaseInfo.isSQLite(knex)) {
|
||||
// Less optimized for SQLite
|
||||
const result = await knex.raw(subquery);
|
||||
const updatedRows = result.length;
|
||||
const subscriptionsToUpdate = result;
|
||||
|
||||
logging.info(`Setting the offer_id for ${updatedRows} members_stripe_customers_subscriptions`);
|
||||
|
||||
// eslint-disable-next-line no-restricted-syntax
|
||||
for (const u of subscriptionsToUpdate) {
|
||||
// eslint-disable-next-line no-restricted-syntax
|
||||
await knex('members_stripe_customers_subscriptions')
|
||||
.update('offer_id', u.offer_id)
|
||||
.where('id', u.subscription_id);
|
||||
}
|
||||
} else {
|
||||
// Single update query
|
||||
const query = `
|
||||
UPDATE
|
||||
members_stripe_customers_subscriptions,
|
||||
(${subquery}) as c
|
||||
SET members_stripe_customers_subscriptions.offer_id = c.offer_id
|
||||
WHERE c.subscription_id = members_stripe_customers_subscriptions.id
|
||||
`;
|
||||
|
||||
const result = await knex.raw(query);
|
||||
const updatedRows = result[0].affectedRows;
|
||||
|
||||
logging.info(`Updated ${updatedRows} members_stripe_customers_subscriptions with an offer_id`);
|
||||
}
|
||||
},
|
||||
async function down() {
|
||||
// We risk losing data if we would reset offer_id here
|
||||
}
|
||||
);
|
Loading…
Reference in New Issue
Block a user