Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Removed use of subqueries in email analytics queries #19917

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
23 changes: 15 additions & 8 deletions ghost/core/core/server/services/email-analytics/lib/queries.js
Expand Up @@ -41,10 +41,16 @@ module.exports = {
},

async aggregateEmailStats(emailId) {
const {totalCount} = await db.knex('emails').select(db.knex.raw('email_count as totalCount')).where('id', emailId).first() || {totalCount: 0};
// use IS NULL here because that will typically match far fewer rows than IS NOT NULL making the query faster
const [undeliveredCount] = await db.knex('email_recipients').count('id as count').whereRaw('email_id = ? AND delivered_at IS NULL', [emailId]);
const [openedCount] = await db.knex('email_recipients').count('id as count').whereRaw('email_id = ? AND opened_at IS NOT NULL', [emailId]);
const [failedCount] = await db.knex('email_recipients').count('id as count').whereRaw('email_id = ? AND failed_at IS NOT NULL', [emailId]);

await db.knex('emails').update({
delivered_count: db.knex.raw(`(SELECT COUNT(id) FROM email_recipients WHERE email_id = ? AND delivered_at IS NOT NULL)`, [emailId]),
opened_count: db.knex.raw(`(SELECT COUNT(id) FROM email_recipients WHERE email_id = ? AND opened_at IS NOT NULL)`, [emailId]),
failed_count: db.knex.raw(`(SELECT COUNT(id) FROM email_recipients WHERE email_id = ? AND failed_at IS NOT NULL)`, [emailId])
delivered_count: totalCount - undeliveredCount.count,
opened_count: openedCount.count,
failed_count: failedCount.count
}).where('id', emailId);
},

Expand All @@ -56,15 +62,16 @@ module.exports = {
.where('emails.track_opens', true)
.first() || {};

const [emailCount] = await db.knex('email_recipients').count('id as count').whereRaw('member_id = ?', [memberId]);
const [emailOpenedCount] = await db.knex('email_recipients').count('id as count').whereRaw('member_id = ? AND opened_at IS NOT NULL', [memberId]);

const updateQuery = {
email_count: db.knex.raw('(SELECT COUNT(id) FROM email_recipients WHERE member_id = ?)', [memberId]),
email_opened_count: db.knex.raw('(SELECT COUNT(id) FROM email_recipients WHERE member_id = ? AND opened_at IS NOT NULL)', [memberId])
email_count: emailCount.count,
email_opened_count: emailOpenedCount.count
};

if (trackedEmailCount >= MIN_EMAIL_COUNT_FOR_OPEN_RATE) {
updateQuery.email_open_rate = db.knex.raw(`
ROUND(((SELECT COUNT(id) FROM email_recipients WHERE member_id = ? AND opened_at IS NOT NULL) * 1.0 / ? * 100), 0)
`, [memberId, trackedEmailCount]);
updateQuery.email_open_rate = Math.round(emailOpenedCount.count / trackedEmailCount * 100);
}

await db.knex('members')
Expand Down
Expand Up @@ -491,7 +491,7 @@ Object {
Object {
"created_at": StringMatching /\\\\d\\{4\\}-\\\\d\\{2\\}-\\\\d\\{2\\}T\\\\d\\{2\\}:\\\\d\\{2\\}:\\\\d\\{2\\}\\\\\\.000Z/,
"delivered_count": 1,
"email_count": 2,
"email_count": 6,
"error": null,
"error_data": null,
"failed_count": 1,
Expand All @@ -517,7 +517,7 @@ Object {
},
Object {
"created_at": StringMatching /\\\\d\\{4\\}-\\\\d\\{2\\}-\\\\d\\{2\\}T\\\\d\\{2\\}:\\\\d\\{2\\}:\\\\d\\{2\\}\\\\\\.000Z/,
"delivered_count": 0,
"delivered_count": 3,
"email_count": 3,
"error": "Everything went south",
"error_data": null,
Expand Down Expand Up @@ -690,7 +690,7 @@ Object {
Object {
"created_at": StringMatching /\\\\d\\{4\\}-\\\\d\\{2\\}-\\\\d\\{2\\}T\\\\d\\{2\\}:\\\\d\\{2\\}:\\\\d\\{2\\}\\\\\\.000Z/,
"delivered_count": 1,
"email_count": 2,
"email_count": 6,
"error": null,
"error_data": null,
"failed_count": 1,
Expand Down Expand Up @@ -736,7 +736,7 @@ Object {
"emails": Array [
Object {
"created_at": StringMatching /\\\\d\\{4\\}-\\\\d\\{2\\}-\\\\d\\{2\\}T\\\\d\\{2\\}:\\\\d\\{2\\}:\\\\d\\{2\\}\\\\\\.000Z/,
"delivered_count": 0,
"delivered_count": 3,
"email_count": 3,
"error": "Everything went south",
"error_data": null,
Expand Down
4 changes: 2 additions & 2 deletions ghost/core/test/utils/fixtures/data-generator.js
Expand Up @@ -731,7 +731,7 @@ DataGenerator.Content = {
id: ObjectId().toHexString(),
uuid: '6b6afda6-4b5e-4893-bff6-f16859e8349a',
status: 'submitted',
email_count: 2,
email_count: 6, // match the number of email_recipients relations below
recipient_filter: 'all',
subject: 'You got mailed!',
html: '<p>Look! I\'m an email</p>',
Expand All @@ -745,7 +745,7 @@ DataGenerator.Content = {
uuid: '365daa11-4bf0-4614-ad43-6346387ffa00',
status: 'failed',
error: 'Everything went south',
email_count: 3,
email_count: 3, // doesn't match the number of email_recipients relations below, some calculations may be off
subject: 'You got mailed! Again!',
html: '<p>What\'s that? Another email!</p>',
plaintext: 'yes this is an email',
Expand Down