Added the post-newsletter relation (#14411)

refs https://github.com/TryGhost/Team/issues/1471

- This is a many-to-one relation so that many posts can be linked to a specific newsletter
- The `newsletters` table had to come first in the schema file so that it's initialized before the `posts` table (because of the foreign key)
- Updated the model to make sure the new field doesn't leak in the API for now
- This migration isn't using the `createAddColumnMigration` util because of a performance issue. In MySQL, adding/dropping a column without `algorithm=copy` uses the INPLACE algorithm which was too slow on big posts tables (~3 minutes for 10k posts). Switching to the COPY algorithm fixed the issue (~3 seconds for 10k posts).
- SQLite isn't using the codepath where we run a raw SQL query because `knex` is doing multiple queries to add/remove a column
This commit is contained in:
Thibaut Patel 2022-04-07 10:26:37 +02:00 committed by GitHub
parent 5d17e7b777
commit 2bfd8f8b7e
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
4 changed files with 132 additions and 20 deletions

View File

@ -0,0 +1,108 @@
const logging = require('@tryghost/logging');
const DatabaseInfo = require('@tryghost/database-info');
const commands = require('../../../schema/commands');
const {createTransactionalMigration} = require('../../utils');
const table = 'posts';
const column = 'newsletter_id';
const targetTable = 'newsletters';
const targetColumn = 'id';
const columnDefinition = {
type: 'string',
maxlength: 24,
nullable: true,
references: `${targetTable}.${targetColumn}`
};
/**
* This migration is adding a new column `newsletter_id` to the table posts
* that is a foreign key to `newsletters.id`.
*
* It isn't using the existing utils because of a performance issue. In MySQL,
* adding a new row without `algorithm=copy` uses the INPLACE algorithm which
* was too slow on big `posts` tables (~3 minutes for 10k posts). Switching to
* the COPY algorithm fixed the issue (~3 seconds for 10k posts).
*/
module.exports = createTransactionalMigration(
async function up(knex) {
const hasColumn = await knex.schema.hasColumn(table, column);
if (hasColumn) {
logging.info(`Adding ${table}.${column} column - skipping as table is correct`);
return;
}
logging.info(`Adding ${table}.${column} column`);
// Use the default flow for SQLite because .toSQL() is tricky with SQLite
if (DatabaseInfo.isSQLite(knex)) {
await commands.addColumn(table, column, knex, columnDefinition);
return;
}
// Add the column
let sql = knex.schema.table(table, function (t) {
t.string(column, 24);
}).toSQL()[0].sql;
if (DatabaseInfo.isMySQL(knex)) {
// Guard against an ending semicolon
sql = sql.replace(/;\s*$/, '') + ', algorithm=copy';
}
await knex.raw(sql);
// Add the foreign key constraint
await commands.addForeign({
fromTable: table,
fromColumn: column,
toTable: targetTable,
toColumn: targetColumn,
cascadeDelete: false,
transaction: knex
});
},
async function down(knex) {
const hasColumn = await knex.schema.hasColumn(table, column);
if (!hasColumn) {
logging.info(`Removing ${table}.${column} column - skipping as table is correct`);
return;
}
logging.info(`Removing ${table}.${column} column`);
// Use the default flow for SQLite because .toSQL() is tricky with SQLite
if (DatabaseInfo.isSQLite(knex)) {
await commands.dropColumn(table, column, knex, columnDefinition);
return;
}
// Drop the foreign key constraint
await commands.dropForeign({
fromTable: table,
fromColumn: column,
toTable: targetTable,
toColumn: targetColumn,
transaction: knex
});
// Drop the column
let sql = knex.schema.table(table, function (t) {
t.dropColumn(column);
}).toSQL()[0].sql;
if (DatabaseInfo.isMySQL(knex)) {
// Guard against an ending semicolon
sql = sql.replace(/;\s*$/, '') + ', algorithm=copy';
}
await knex.raw(sql);
}
);

View File

@ -8,6 +8,24 @@
* Long text = length 1,000,000,000
*/
module.exports = {
newsletters: {
id: {type: 'string', maxlength: 24, nullable: false, primary: true},
name: {type: 'string', maxlength: 191, nullable: false},
description: {type: 'string', maxlength: 2000, nullable: true},
sender_name: {type: 'string', maxlength: 191, nullable: false},
sender_email: {type: 'string', maxlength: 191, nullable: false, validations: {isEmail: true}},
sender_reply_to: {type: 'string', maxlength: 191, nullable: false, validations: {isEmail: true}},
default: {type: 'bool', nullable: false, defaultTo: false},
status: {type: 'string', maxlength: 50, nullable: false, defaultTo: 'active'},
recipient_filter: {
type: 'text',
maxlength: 1000000000,
nullable: false,
defaultTo: ''
},
subscribe_on_signup: {type: 'bool', nullable: false, defaultTo: false},
sort_order: {type: 'integer', nullable: false, unsigned: true, defaultTo: 0}
},
posts: {
id: {type: 'string', maxlength: 24, nullable: false, primary: true},
uuid: {type: 'string', maxlength: 36, nullable: false, validations: {isUUID: true}},
@ -56,6 +74,7 @@ module.exports = {
codeinjection_foot: {type: 'text', maxlength: 65535, nullable: true},
custom_template: {type: 'string', maxlength: 100, nullable: true},
canonical_url: {type: 'text', maxlength: 2000, nullable: true},
newsletter_id: {type: 'string', maxlength: 24, nullable: true, references: 'newsletters.id'},
'@@UNIQUE_CONSTRAINTS@@': [
['slug', 'type']
]
@ -712,24 +731,6 @@ module.exports = {
},
value: {type: 'text', maxlength: 65535, nullable: true}
},
newsletters: {
id: {type: 'string', maxlength: 24, nullable: false, primary: true},
name: {type: 'string', maxlength: 191, nullable: false},
description: {type: 'string', maxlength: 2000, nullable: true},
sender_name: {type: 'string', maxlength: 191, nullable: false},
sender_email: {type: 'string', maxlength: 191, nullable: false, validations: {isEmail: true}},
sender_reply_to: {type: 'string', maxlength: 191, nullable: false, validations: {isEmail: true}},
default: {type: 'bool', nullable: false, defaultTo: false},
status: {type: 'string', maxlength: 50, nullable: false, defaultTo: 'active'},
recipient_filter: {
type: 'text',
maxlength: 1000000000,
nullable: false,
defaultTo: ''
},
subscribe_on_signup: {type: 'bool', nullable: false, defaultTo: false},
sort_order: {type: 'integer', nullable: false, unsigned: true, defaultTo: 0}
},
members_newsletters: {
id: {type: 'string', maxlength: 24, nullable: false, primary: true},
member_id: {type: 'string', maxlength: 24, nullable: false, references: 'members.id', cascadeDelete: true},

View File

@ -557,7 +557,7 @@ Post = ghostBookshelf.Model.extend({
if (!tag.id && !tag.tag_id && tag.slug) {
// Clean up the provided slugs before we do any matching with existing tags
tag.slug = await ghostBookshelf.Model.generateSlug(
Tag,
Tag,
tag.slug,
{skipDuplicateChecks: true}
);
@ -878,6 +878,9 @@ Post = ghostBookshelf.Model.extend({
// CASE: never expose the revisions
delete attrs.mobiledoc_revisions;
// CASE: hide the newsletter_id for now
delete attrs.newsletter_id;
// If the current column settings allow it...
if (!options.columns || (options.columns && options.columns.indexOf('primary_tag') > -1)) {
// ... attach a computed property of primary_tag which is the first tag if it is public, else null

View File

@ -35,7 +35,7 @@ const validateRouteSettings = require('../../../../../core/server/services/route
*/
describe('DB version integrity', function () {
// Only these variables should need updating
const currentSchemaHash = '8bf6c2996ddd0238d41a9d3e1cb07bd9';
const currentSchemaHash = 'cbfa94566ed4af324defe7a2b561519c';
const currentFixturesHash = 'f4dd2a454e1999b6d149cc26ae52ced4';
const currentSettingsHash = '71fa38d0c805c18ceebe0fda80886230';
const currentRoutesHash = '3d180d52c663d173a6be791ef411ed01';