Skip to content

Commit eaa4211

Browse files
committed
Added tests and implementation for getReferrersForPost method
1 parent d71a6ca commit eaa4211

File tree

2 files changed

+278
-102
lines changed

2 files changed

+278
-102
lines changed

ghost/core/core/server/services/stats/PostsStatsService.js

+180-93
Original file line numberDiff line numberDiff line change
@@ -2,9 +2,9 @@ const logging = require('@tryghost/logging');
22
const errors = require('@tryghost/errors');
33

44
/**
5-
* @typedef {Object} TopPostsOptions
5+
* @typedef {Object} StatsServiceOptions
66
* @property {string} [order='free_members desc'] - field to order by (free_members, paid_members, or mrr) and direction
7-
* @property {number} [limit=20] - maximum number of results to return
7+
* @property {number|string} [limit=20] - maximum number of results to return
88
* @property {string} [date_from] - optional start date filter (YYYY-MM-DD)
99
* @property {string} [date_to] - optional end date filter (YYYY-MM-DD)
1010
* @property {string} [timezone='UTC'] - optional timezone for date interpretation
@@ -19,6 +19,14 @@ const errors = require('@tryghost/errors');
1919
* @property {number} mrr - Total MRR from paid conversions attributed to this post
2020
*/
2121

22+
/**
23+
* @typedef {Object} ReferrerStatsResult
24+
* @property {string} source - The referrer source (e.g., domain)
25+
* @property {number} free_members - Count of members who signed up via this post/referrer but did not have a paid conversion attributed to the same post/referrer
26+
* @property {number} paid_members - Count of members whose paid conversion event was attributed to this post/referrer
27+
* @property {number} mrr - Total MRR from paid conversions attributed to this post/referrer
28+
*/
29+
2230
class PostsStatsService {
2331
/**
2432
* @param {object} deps
@@ -31,14 +39,13 @@ class PostsStatsService {
3139
/**
3240
* Get top posts by attribution metrics (free_members, paid_members, or mrr)
3341
*
34-
* @param {TopPostsOptions} options
42+
* @param {StatsServiceOptions} options
3543
* @returns {Promise<{data: TopPostResult[]}>} The top posts based on the requested attribution metric
3644
*/
3745
async getTopPosts(options = {}) {
38-
logging.info('TopPostsStatsService.getTopPosts called with options:', options);
3946
try {
4047
const order = options.order || 'free_members desc';
41-
const limitRaw = Number.parseInt(options.limit, 10);
48+
const limitRaw = Number.parseInt(String(options.limit ?? 20), 10); // Ensure options.limit is a string for parseInt
4249
const limit = Number.isFinite(limitRaw) && limitRaw > 0 ? limitRaw : 20;
4350
const [orderField, orderDirection = 'desc'] = order.split(' ');
4451

@@ -74,7 +81,6 @@ class PostsStatsService {
7481
.leftJoin('paid', 'p.id', 'paid.post_id')
7582
.leftJoin('mrr', 'p.id', 'mrr.post_id');
7683

77-
// Apply final ordering and limiting (Removed the WHERE clause filtering for activity)
7884
const results = await query
7985
.orderBy(orderField, orderDirection)
8086
.limit(limit);
@@ -87,142 +93,124 @@ class PostsStatsService {
8793
}
8894

8995
/**
90-
* Get referrers for a post
96+
* Get referrers for a specific post by attribution metrics
9197
* @param {string} postId
92-
* @param {TopPostsOptions} options
93-
* @returns {Promise<{data: TopPostResult[]}>} The referrers for the post
98+
* @param {StatsServiceOptions} options
99+
* @returns {Promise<{data: ReferrerStatsResult[]}>} The referrers for the post, ranked by the specified metric
94100
*/
95-
async getReferrersForPost(postId, options) {
96-
const knex = this.knex;
97-
const freeMembers = await knex('members_created_events as mce')
98-
.select('mce.referrer_source as source')
99-
.countDistinct('mce.member_id as free_members')
100-
.leftJoin('members_subscription_created_events as msce', function () {
101-
this.on('mce.member_id', '=', 'msce.member_id')
102-
.andOn('mce.attribution_id', '=', 'msce.attribution_id')
103-
.andOnVal('msce.attribution_type', '=', 'post');
104-
})
105-
.where('mce.attribution_id', postId)
106-
.where('mce.attribution_type', 'post')
107-
.whereNull('msce.id')
108-
.groupBy('mce.referrer_source');
109-
110-
const paidMembers = await knex('members_subscription_created_events as msce')
111-
.select('msce.referrer_source as source')
112-
.countDistinct('msce.member_id as paid_members')
113-
.where('msce.attribution_id', postId)
114-
.where('msce.attribution_type', 'post')
115-
.groupBy('msce.referrer_source');
101+
async getReferrersForPost(postId, options = {}) {
102+
try {
103+
const order = options.order || 'free_members desc';
104+
const limitRaw = Number.parseInt(String(options.limit ?? 20), 10);
105+
const limit = Number.isFinite(limitRaw) && limitRaw > 0 ? limitRaw : 20;
106+
const [orderField, orderDirection = 'desc'] = order.split(' ');
116107

117-
const mrr = await knex('members_subscription_created_events as msce')
118-
.select('msce.referrer_source as source')
119-
.sum('mpse.mrr_delta as mrr')
120-
.join('members_paid_subscription_events as mpse', function () {
121-
this.on('mpse.subscription_id', '=', 'msce.subscription_id')
122-
.andOn('mpse.member_id', '=', 'msce.member_id');
123-
})
124-
.where('msce.attribution_id', postId)
125-
.where('msce.attribution_type', 'post')
126-
.groupBy('msce.referrer_source');
108+
if (!['free_members', 'paid_members', 'mrr'].includes(orderField)) {
109+
throw new errors.BadRequestError({
110+
message: `Invalid order field: ${orderField}. Must be one of: free_members, paid_members, mrr`
111+
});
112+
}
113+
if (!['asc', 'desc'].includes(orderDirection.toLowerCase())) {
114+
throw new errors.BadRequestError({
115+
message: `Invalid order direction: ${orderDirection}`
116+
});
117+
}
127118

128-
const map = new Map();
129-
for (const row of freeMembers) {
130-
map.set(row.source, {
131-
source: row.source,
132-
free_members: row.free_members,
133-
paid_members: 0,
134-
mrr: 0
135-
});
136-
}
119+
const freeReferrersCTE = this._buildFreeReferrersSubquery(postId, options);
120+
const paidReferrersCTE = this._buildPaidReferrersSubquery(postId, options);
121+
const mrrReferrersCTE = this._buildMrrReferrersSubquery(postId, options);
137122

138-
for (const row of paidMembers) {
139-
const existing = map.get(row.source) ?? {
140-
source: row.source,
141-
free_members: 0,
142-
paid_members: 0,
143-
mrr: 0
144-
};
145-
existing.paid_members = row.paid_members;
146-
map.set(row.source, existing);
147-
}
123+
const baseReferrersQuery = this.knex('members_created_events as mce')
124+
.select('mce.referrer_source as source')
125+
.where('mce.attribution_id', postId)
126+
.where('mce.attribution_type', 'post')
127+
.union((qb) => {
128+
qb.select('msce.referrer_source as source')
129+
.from('members_subscription_created_events as msce')
130+
.where('msce.attribution_id', postId)
131+
.where('msce.attribution_type', 'post');
132+
});
148133

149-
for (const row of mrr) {
150-
const existing = map.get(row.source) ?? {
151-
source: row.source,
152-
free_members: 0,
153-
paid_members: 0,
154-
mrr: 0
155-
};
156-
existing.mrr = row.mrr;
157-
map.set(row.source, existing);
158-
}
134+
let query = this.knex
135+
.with('free_referrers', freeReferrersCTE)
136+
.with('paid_referrers', paidReferrersCTE)
137+
.with('mrr_referrers', mrrReferrersCTE)
138+
.with('all_referrers', baseReferrersQuery)
139+
.select(
140+
'ar.source',
141+
this.knex.raw('COALESCE(fr.free_members, 0) as free_members'),
142+
this.knex.raw('COALESCE(pr.paid_members, 0) as paid_members'),
143+
this.knex.raw('COALESCE(mr.mrr, 0) as mrr')
144+
)
145+
.from('all_referrers as ar')
146+
.leftJoin('free_referrers as fr', 'ar.source', 'fr.source')
147+
.leftJoin('paid_referrers as pr', 'ar.source', 'pr.source')
148+
.leftJoin('mrr_referrers as mr', 'ar.source', 'mr.source')
149+
.whereNotNull('ar.source');
159150

160-
const results = [...map.values()].sort((a, b) => b.mrr - a.mrr);
151+
const results = await query
152+
.orderBy(orderField, orderDirection)
153+
.limit(limit);
161154

162-
return {data: results};
155+
return {data: results};
156+
} catch (error) {
157+
logging.error(`Error fetching referrers for post ${postId}:`, error);
158+
return {data: []};
159+
}
163160
}
164161

165162
/**
166-
* Build a subquery/CTE for free_members count
163+
* Build a subquery/CTE for free_members count (Post-level)
167164
* (Signed up on Post, Paid Elsewhere/Never)
168165
* @private
169-
* @param {TopPostsOptions} options
166+
* @param {StatsServiceOptions} options
170167
* @returns {import('knex').Knex.QueryBuilder}
171168
*/
172169
_buildFreeMembersSubquery(options) {
173170
const knex = this.knex;
174-
// Find members who signed up via this post (mce.attribution_id)
175-
// but did NOT have a paid conversion via the SAME post (msce.attribution_id)
176171
let subquery = knex('members_created_events as mce')
177172
.select('mce.attribution_id as post_id')
178173
.countDistinct('mce.member_id as free_members')
179174
.leftJoin('members_subscription_created_events as msce', function () {
180175
this.on('mce.member_id', '=', 'msce.member_id')
181-
.andOn('mce.attribution_id', '=', 'msce.attribution_id') // Important: check paid conversion attributed to SAME post
176+
.andOn('mce.attribution_id', '=', 'msce.attribution_id')
182177
.andOnVal('msce.attribution_type', '=', 'post');
183178
})
184179
.where('mce.attribution_type', 'post')
185-
.whereNull('msce.id') // Keep only those where the left join found no matching paid conversion on the same post
180+
.whereNull('msce.id')
186181
.groupBy('mce.attribution_id');
187182

188-
// Apply date filter to the signup event
189183
this._applyDateFilter(subquery, options, 'mce.created_at');
190-
191184
return subquery;
192185
}
193186

194187
/**
195-
* Build a subquery/CTE for paid_members count
188+
* Build a subquery/CTE for paid_members count (Post-level)
196189
* (Paid conversion attributed to this post)
197190
* @private
198-
* @param {TopPostsOptions} options
191+
* @param {StatsServiceOptions} options
199192
* @returns {import('knex').Knex.QueryBuilder}
200193
*/
201194
_buildPaidMembersSubquery(options) {
202195
const knex = this.knex;
203-
// Count distinct members for whom a paid conversion event (subscription creation)
204-
// was attributed to this post_id.
205196
let subquery = knex('members_subscription_created_events as msce')
206197
.select('msce.attribution_id as post_id')
207198
.countDistinct('msce.member_id as paid_members')
208199
.where('msce.attribution_type', 'post')
209200
.groupBy('msce.attribution_id');
210201

211-
// Apply date filter to the paid conversion event timestamp
212202
this._applyDateFilter(subquery, options, 'msce.created_at');
213-
214203
return subquery;
215204
}
216205

217206
/**
218-
* Build a subquery/CTE for mrr sum
207+
* Build a subquery/CTE for mrr sum (Post-level)
219208
* (Paid Conversions Attributed to Post)
220209
* @private
221-
* @param {TopPostsOptions} options
210+
* @param {StatsServiceOptions} options
222211
* @returns {import('knex').Knex.QueryBuilder}
223212
*/
224213
_buildMrrSubquery(options) {
225-
// Logic remains the same: Sum MRR for all paid conversions attributed to the post
226214
let subquery = this.knex('members_subscription_created_events as msce')
227215
.select('msce.attribution_id as post_id')
228216
.sum('mpse.mrr_delta as mrr')
@@ -233,27 +221,126 @@ class PostsStatsService {
233221
.where('msce.attribution_type', 'post')
234222
.groupBy('msce.attribution_id');
235223

224+
this._applyDateFilter(subquery, options, 'msce.created_at');
225+
return subquery;
226+
}
227+
228+
// --- Subqueries for getReferrersForPost ---
229+
230+
/**
231+
* Build subquery for free members count per referrer for a specific post.
232+
* (Signed up via Post/Referrer, Did NOT convert via SAME Post/Referrer)
233+
* @private
234+
* @param {string} postId
235+
* @param {StatsServiceOptions} options
236+
* @returns {import('knex').Knex.QueryBuilder}
237+
*/
238+
_buildFreeReferrersSubquery(postId, options) {
239+
const knex = this.knex;
240+
241+
// Simpler approach mirroring _buildFreeMembersSubquery
242+
let subquery = knex('members_created_events as mce')
243+
.select('mce.referrer_source as source')
244+
.countDistinct('mce.member_id as free_members')
245+
.leftJoin('members_subscription_created_events as msce', function () {
246+
this.on('mce.member_id', '=', 'msce.member_id')
247+
.andOn('mce.attribution_id', '=', 'msce.attribution_id') // Conversion must be for the SAME post
248+
.andOn('mce.referrer_source', '=', 'msce.referrer_source') // And the SAME referrer
249+
.andOnVal('msce.attribution_type', '=', 'post');
250+
})
251+
.where('mce.attribution_id', postId)
252+
.where('mce.attribution_type', 'post')
253+
.whereNull('msce.id') // Keep only signups where no matching paid conversion (same post/referrer) exists
254+
.groupBy('mce.referrer_source');
255+
256+
this._applyDateFilter(subquery, options, 'mce.created_at'); // Filter based on signup time
257+
return subquery;
258+
}
259+
260+
/**
261+
* Build subquery for paid members count per referrer for a specific post.
262+
* (Paid conversion attributed to this Post/Referrer)
263+
* @private
264+
* @param {string} postId
265+
* @param {StatsServiceOptions} options
266+
* @returns {import('knex').Knex.QueryBuilder}
267+
*/
268+
_buildPaidReferrersSubquery(postId, options) {
269+
const knex = this.knex;
270+
let subquery = knex('members_subscription_created_events as msce')
271+
.select('msce.referrer_source as source')
272+
.countDistinct('msce.member_id as paid_members')
273+
.where('msce.attribution_id', postId)
274+
.where('msce.attribution_type', 'post')
275+
.groupBy('msce.referrer_source');
276+
236277
// Apply date filter to the paid conversion event timestamp
237278
this._applyDateFilter(subquery, options, 'msce.created_at');
279+
return subquery;
280+
}
238281

282+
/**
283+
* Build subquery for MRR sum per referrer for a specific post.
284+
* (MRR from paid conversions attributed to this Post/Referrer)
285+
* @private
286+
* @param {string} postId
287+
* @param {StatsServiceOptions} options
288+
* @returns {import('knex').Knex.QueryBuilder}
289+
*/
290+
_buildMrrReferrersSubquery(postId, options) {
291+
const knex = this.knex;
292+
let subquery = knex('members_subscription_created_events as msce')
293+
.select('msce.referrer_source as source')
294+
.sum('mpse.mrr_delta as mrr')
295+
.join('members_paid_subscription_events as mpse', function () {
296+
this.on('mpse.subscription_id', '=', 'msce.subscription_id');
297+
// Ensure we join on member_id as well for accuracy if subscription_id isn't unique across members? (Safeguard)
298+
this.andOn('mpse.member_id', '=', 'msce.member_id');
299+
})
300+
.where('msce.attribution_id', postId)
301+
.where('msce.attribution_type', 'post')
302+
.groupBy('msce.referrer_source');
303+
304+
// Apply date filter to the paid conversion event timestamp
305+
this._applyDateFilter(subquery, options, 'msce.created_at');
239306
return subquery;
240307
}
241308

242309
/**
243310
* Apply date filters to a query builder instance
244311
* @private
245312
* @param {import('knex').Knex.QueryBuilder} query
246-
* @param {TopPostsOptions} options
247-
* @param {string} [dateColumn='created_at'] - The date column to filter on
313+
* @param {StatsServiceOptions} options
314+
* @param {string} dateColumn - The date column to filter on
248315
*/
249-
_applyDateFilter(query, options, dateColumn = 'created_at') {
316+
_applyDateFilter(query, options, dateColumn) {
250317
// Note: Timezone handling might require converting dates before querying,
251318
// depending on how created_at is stored (UTC assumed here).
252319
if (options.date_from) {
253-
query.where(dateColumn, '>=', options.date_from);
320+
try {
321+
// Attempt to parse and validate the date
322+
const fromDate = new Date(options.date_from);
323+
if (!isNaN(fromDate.getTime())) {
324+
query.where(dateColumn, '>=', options.date_from);
325+
} else {
326+
logging.warn(`Invalid date_from format: ${options.date_from}. Skipping filter.`);
327+
}
328+
} catch (e) {
329+
logging.warn(`Error parsing date_from: ${options.date_from}. Skipping filter.`);
330+
}
254331
}
255332
if (options.date_to) {
256-
query.where(dateColumn, '<=', options.date_to + ' 23:59:59');
333+
try {
334+
const toDate = new Date(options.date_to);
335+
if (!isNaN(toDate.getTime())) {
336+
// Include the whole day for the 'to' date
337+
query.where(dateColumn, '<=', options.date_to + ' 23:59:59');
338+
} else {
339+
logging.warn(`Invalid date_to format: ${options.date_to}. Skipping filter.`);
340+
}
341+
} catch (e) {
342+
logging.warn(`Error parsing date_to: ${options.date_to}. Skipping filter.`);
343+
}
257344
}
258345
}
259346
}

0 commit comments

Comments
 (0)