Added Dashboard 5.0 migrations (#14716)

refs https://github.com/TryGhost/Team/issues/1515
refs https://github.com/TryGhost/Team/issues/1516
refs https://github.com/TryGhost/Team/issues/1455

The updates the `mrr` column for subscriptions and the `mrr_deltas` for events
so that both Offers and canceled Subscriptions are correctly handled.

We must apply the canceled Subscription changes after the Offers, so that they
interact correctly, and that the `mrr` column has the necessary data for each migration.

Co-authored-by: Simon Backx <simon@ghost.org>
This commit is contained in:
Fabien 'egg' O'Carroll 2022-05-09 12:46:46 +01:00 committed by GitHub
parent 62164ecdf2
commit 895ffee90b
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
5 changed files with 290 additions and 0 deletions

View File

@ -0,0 +1,36 @@
const DatabaseInfo = require('@tryghost/database-info/lib/database-info');
const logging = require('@tryghost/logging');
const {createTransactionalMigration} = require('../../utils');
module.exports = createTransactionalMigration(
async function up(knex) {
if (DatabaseInfo.isSQLite(knex)) {
const duplicates = await knex('offer_redemptions')
.select('subscription_id')
.count('subscription_id as count')
.groupBy('subscription_id')
.having('count', '>', 1);
logging.info(`Deleting all offer redemptions which have duplicates`);
await knex('offer_redemptions')
.whereIn('subscription_id', duplicates.map(row => row.subscription_id))
.del();
return;
}
const result = await knex.raw(`
DELETE
duplicate_redemptions
FROM
offer_redemptions AS duplicate_redemptions,
offer_redemptions
WHERE
duplicate_redemptions.subscription_id = offer_redemptions.subscription_id
AND
duplicate_redemptions.created_at < offer_redemptions.created_at
`);
logging.info(`Deleted ${result[0].affectedRows} duplicate offer redemptions`);
},
async function down() {}
);

View File

@ -0,0 +1,107 @@
const logging = require('@tryghost/logging');
const {uniq} = require('lodash');
const {createTransactionalMigration} = require('../../utils');
module.exports = createTransactionalMigration(
async function up(knex) {
logging.info('Adjusting MRR based on Offer Redemptions');
const offerRedemptions = await knex
.select('or.*', 'o.discount_type', 'o.discount_amount', 'o.interval AS discount_interval', 's.mrr AS mrr', 's.id AS subscription_id', 'p.amount AS amount', 'p.interval AS interval')
.from('offer_redemptions AS or')
.join('offers AS o', 'or.offer_id', '=', 'o.id')
.join('members_stripe_customers_subscriptions AS s', 'or.subscription_id', '=', 's.id')
.join('stripe_prices AS p', 'p.stripe_price_id', '=', 's.stripe_price_id')
.where('o.duration', '=', 'forever')
.whereNotNull('s.offer_id')
.where('s.mrr', '!=', 0)
.orderBy('or.created_at', 'asc');
if (offerRedemptions.length === 0) {
logging.info('No Offers redeemed, skipping migration');
return;
} else {
logging.info(`Adjusting MRR for ${offerRedemptions.length} Offer Redemptions`);
}
const memberIds = uniq(offerRedemptions.map(redemption => redemption.member_id));
const mrrCreatedEvents = await knex
.select('*')
.from('members_paid_subscription_events')
.where('type', 'created')
.whereIn('member_id', memberIds);
function storeEventOnMemberId(storage, event) {
return {
...storage,
[event.member_id]: storage[event.member_id] ? storage[event.member_id].concat(event) : [event]
};
}
const mrrCreatedEventsByMemberId = mrrCreatedEvents.reduce(storeEventOnMemberId, {});
const updatedEvents = [];
function calculateMRR(subscription, redemption) {
if (redemption && subscription.interval !== redemption.discount_interval) {
logging.error('Found invalid price & redemption pair');
return calculateMRR(subscription);
}
if (!redemption) {
return subscription.interval === 'year' ? subscription.amount / 12 : subscription.amount;
}
if (redemption.discount_type === 'percent') {
return calculateMRR({
interval: subscription.interval,
amount: subscription.amount * (100 - redemption.discount_amount) / 100
});
}
return calculateMRR({
interval: subscription.interval,
amount: subscription.amount - redemption.discount_amount
});
}
offerRedemptions.forEach((redemption) => {
const memberEvents = mrrCreatedEventsByMemberId[redemption.member_id];
// If a member has had multiple subscriptions we ignore because we cannot easily work out which event is correct.
if (memberEvents.length !== 1) {
return;
}
const firstEvent = memberEvents[0];
const mrr = calculateMRR({
interval: redemption.interval,
amount: redemption.amount
}, redemption);
updatedEvents.push({
id: firstEvent.id,
type: 'created',
subscription_id: redemption.subscription_id,
member_id: firstEvent.member_id,
from_plan: firstEvent.from_plan,
to_plan: firstEvent.to_plan,
currency: firstEvent.currency,
source: firstEvent.source,
created_at: firstEvent.created_at,
mrr_delta: mrr
});
});
if (updatedEvents.length === 0) {
return;
}
const idsToDelete = updatedEvents.map(event => event.id);
await knex('members_paid_subscription_events').whereIn('id', idsToDelete).del();
await knex.batchInsert('members_paid_subscription_events', updatedEvents);
},
async function down() {}
);

View File

@ -0,0 +1,44 @@
const logging = require('@tryghost/logging');
const {createTransactionalMigration} = require('../../utils');
module.exports = createTransactionalMigration(
async function up(knex) {
const subscriptionsToUpdate = await knex('members_stripe_customers_subscriptions AS s')
.join('offers AS o', 's.offer_id', '=', 'o.id')
.where('o.duration', '=', 'forever')
.andWhere('s.mrr', '!=', 0)
.select('s.*', 'o.discount_type AS offer_type', 'o.discount_amount AS offer_amount');
if (!subscriptionsToUpdate.length) {
logging.info('No subscriptions found needing updating');
return;
}
const toInsert = subscriptionsToUpdate.map((subscription) => {
let discountedAmount;
if (subscription.offer_type === 'percent') {
discountedAmount = subscription.plan_amount * (100 - subscription.offer_amount) / 100;
} else {
discountedAmount = subscription.plan_amount - subscription.offer_amount;
}
const newSubscription = {
...subscription,
mrr: subscription.plan_interval === 'year' ? discountedAmount / 12 : discountedAmount
};
delete newSubscription.offer_type;
delete newSubscription.offer_amount;
return newSubscription;
});
const toDelete = toInsert.map(sub => sub.id);
logging.info(`Replacing ${toDelete.length} subscriptions with updated MRR based on Offers`);
await knex('members_stripe_customers_subscriptions').whereIn('id', toDelete).del();
await knex.batchInsert('members_stripe_customers_subscriptions', toInsert);
},
async function down() {}
);

View File

@ -0,0 +1,72 @@
const ObjectID = require('bson-objectid').default;
const logging = require('@tryghost/logging');
const {createTransactionalMigration} = require('../../utils');
module.exports = createTransactionalMigration(
async function up(knex) {
const canceledSubscriptions = await knex('members_stripe_customers_subscriptions')
.select(
'members_stripe_customers_subscriptions.id',
'members_stripe_customers_subscriptions.updated_at',
'members_stripe_customers_subscriptions.mrr',
'members_stripe_customers_subscriptions.stripe_price_id',
'members_stripe_customers_subscriptions.plan_currency',
'members_stripe_customers.member_id'
)
.join('members_stripe_customers', 'members_stripe_customers_subscriptions.customer_id', '=', 'members_stripe_customers.customer_id')
.join('members', 'members_stripe_customers.member_id', '=', 'members.id')
.where('cancel_at_period_end', '=', true)
.where('mrr', '!=', 0);
if (canceledSubscriptions.length === 0) {
logging.info('No canceled subscriptions found, skipping migration.');
return;
} else {
logging.info(`Found ${canceledSubscriptions.length} canceled subscriptions, updating MRR events`);
}
const canceledEvents = await knex('members_paid_subscription_events')
.select('*')
.where('type', '=', 'canceled')
.whereIn('subscription_id', canceledSubscriptions.map(x => x.id))
.orderBy('created_at', 'desc');
const toUpdate = [];
const toInsert = [];
// eslint-disable-next-line no-restricted-syntax
for (const subscription of canceledSubscriptions) {
const event = canceledEvents.find(e => e.subscription_id === subscription.id);
if (event) {
// if an event exists, update it
// we always update the latest event for a subscription due to the orderBy DESC
toUpdate.push({
...event,
mrr_delta: -subscription.mrr
});
} else {
toInsert.push({
id: ObjectID().toHexString(),
type: 'canceled',
source: 'migration',
created_at: subscription.updated_at,
from_plan: subscription.stripe_price_id,
to_plan: subscription.stripe_price_id,
subscription_id: subscription.id,
member_id: subscription.member_id,
currency: subscription.plan_currency,
mrr_delta: -subscription.mrr
});
}
}
logging.info(`Inserting ${toInsert.length} MRR events for canceled subscriptions`);
await knex.batchInsert('members_paid_subscription_events', toInsert);
logging.info(`Updating ${toUpdate.length} MRR events for canceled subscriptions`);
await knex('members_paid_subscription_events').whereIn('id', toUpdate.map(row => row.id)).del();
await knex.batchInsert('members_paid_subscription_events', toUpdate);
},
async function down() {}
);

View File

@ -0,0 +1,31 @@
const logging = require('@tryghost/logging');
const {createTransactionalMigration} = require('../../utils');
module.exports = createTransactionalMigration(
async function up(knex) {
logging.info('Setting "mrr" to 0 for all canceled subscriptions in "members_stripe_customers_subscriptions"');
await knex('members_stripe_customers_subscriptions')
.update('mrr', 0)
.where('cancel_at_period_end', true);
},
async function down(knex) {
logging.info('Setting "mrr" for all canceled and not yet expired subscriptions in "members_stripe_customers_subscriptions"');
await knex('members_stripe_customers_subscriptions')
.update('mrr', knex.raw(`
CASE WHEN plan_interval = 'year' THEN
FLOOR(plan_amount / 12)
WHEN plan_interval = 'week' THEN
plan_amount * 4
WHEN plan_interval = 'day' THEN
plan_amount * 30
ELSE
plan_amount
END
`))
.where('cancel_at_period_end', true)
.whereNotIn('status', ['trialing', 'incomplete', 'incomplete_expired', 'canceled']);
}
);