mirror of
https://github.com/TryGhost/Ghost.git
synced 2025-04-08 02:52:39 -05:00
✨ Added Admin API endpoint for basic member stats (#11840)
no issue - moves members stats generation for the admin graph from the client to the server - outputs a basic totals count across a requested date range of 30, 90, 365 days, or all time. See below for the response shape - leaves heavy lifting of the counts to the SQL engines - tested on a dataset of 100k members and query performance is <100ms ``` GET /ghost/api/canary/members/stats/?days=30 { total: 100000, total_in_range: 20000, total_on_date: { '2020-04-25': 19000, '2020-04-26': 19500, // continues until today's date }, new_today: 200 } ```
This commit is contained in:
parent
cf3ee559c1
commit
071ab9774b
5 changed files with 235 additions and 2 deletions
|
@ -1,11 +1,15 @@
|
|||
// NOTE: We must not cache references to membersService.api
|
||||
// as it is a getter and may change during runtime.
|
||||
const Promise = require('bluebird');
|
||||
const moment = require('moment-timezone');
|
||||
const errors = require('@tryghost/errors');
|
||||
const config = require('../../config');
|
||||
const models = require('../../models');
|
||||
const membersService = require('../../services/members');
|
||||
const settingsCache = require('../../services/settings/cache');
|
||||
const {i18n, logging} = require('../../lib/common');
|
||||
const errors = require('@tryghost/errors');
|
||||
const fsLib = require('../../lib/fs');
|
||||
const db = require('../../data/db');
|
||||
const _ = require('lodash');
|
||||
|
||||
const decorateWithSubscriptions = async function (member) {
|
||||
|
@ -405,6 +409,126 @@ const members = {
|
|||
};
|
||||
});
|
||||
}
|
||||
},
|
||||
|
||||
stats: {
|
||||
options: [
|
||||
'days'
|
||||
],
|
||||
permissions: {
|
||||
method: 'browse'
|
||||
},
|
||||
validation: {
|
||||
options: {
|
||||
days: {
|
||||
values: ['30', '90', '365', 'all-time']
|
||||
}
|
||||
}
|
||||
},
|
||||
async query(frame) {
|
||||
const dateFormat = 'YYYY-MM-DD HH:mm:ss';
|
||||
const isSQLite = config.get('database:client') === 'sqlite3';
|
||||
const siteTimezone = settingsCache.get('active_timezone');
|
||||
const tzOffsetMins = moment.tz(siteTimezone).utcOffset();
|
||||
|
||||
const days = frame.options.days === 'all-time' ? 'all-time' : Number(frame.options.days || 30);
|
||||
|
||||
// get total members before other stats because the figure is used multiple times
|
||||
async function getTotalMembers() {
|
||||
const result = await db.knex.raw('SELECT COUNT(id) AS total FROM members');
|
||||
return isSQLite ? result[0].total : result[0][0].total;
|
||||
}
|
||||
const totalMembers = await getTotalMembers();
|
||||
|
||||
async function getTotalMembersInRange() {
|
||||
if (days === 'all-time') {
|
||||
return totalMembers;
|
||||
}
|
||||
|
||||
const startOfRange = moment.tz(siteTimezone).subtract(days - 1, 'days').startOf('day').utc().format(dateFormat);
|
||||
const result = await db.knex.raw('SELECT COUNT(id) AS total FROM members WHERE created_at >= ?', [startOfRange]);
|
||||
return isSQLite ? result[0].total : result[0][0].total;
|
||||
}
|
||||
|
||||
async function getTotalMembersOnDatesInRange() {
|
||||
const startOfRange = moment.tz(siteTimezone).subtract(days - 1, 'days').startOf('day').utc().format(dateFormat);
|
||||
let result;
|
||||
|
||||
if (isSQLite) {
|
||||
const dateModifier = `+${tzOffsetMins} minutes`;
|
||||
|
||||
result = await db.knex('members')
|
||||
.select(db.knex.raw('DATE(created_at, ?) AS created_at, COUNT(DATE(created_at, ?)) AS count', [dateModifier, dateModifier]))
|
||||
.where((builder) => {
|
||||
if (days !== 'all-time') {
|
||||
builder.whereRaw('created_at >= ?', [startOfRange]);
|
||||
}
|
||||
}).groupByRaw('DATE(created_at, ?)', [dateModifier]);
|
||||
} else {
|
||||
const mins = tzOffsetMins % 60;
|
||||
const hours = (tzOffsetMins - mins) / 60;
|
||||
const utcOffset = `${Math.sign(tzOffsetMins) === -1 ? '-' : '+'}${hours}:${mins < 10 ? '0' : ''}${mins}`;
|
||||
|
||||
result = await db.knex('members')
|
||||
.select(db.knex.raw('DATE(CONVERT_TZ(created_at, \'+00:00\', ?)) AS created_at, COUNT(CONVERT_TZ(created_at, \'+00:00\', ?)) AS count', [utcOffset, utcOffset]))
|
||||
.where((builder) => {
|
||||
if (days !== 'all-time') {
|
||||
builder.whereRaw('created_at >= ?', [startOfRange]);
|
||||
}
|
||||
})
|
||||
.groupByRaw('DATE(CONVERT_TZ(created_at, \'+00:00\', ?))', [utcOffset]);
|
||||
}
|
||||
|
||||
// sql doesn't return rows with a 0 count so we build an object
|
||||
// with sparse results to reference by date rather than performing
|
||||
// multiple finds across an array
|
||||
const resultObject = {};
|
||||
result.forEach((row) => {
|
||||
resultObject[moment(row.created_at).format('YYYY-MM-DD')] = row.count;
|
||||
});
|
||||
|
||||
// loop over every date in the range so we can return a contiguous range object
|
||||
const totalInRange = Object.values(resultObject).reduce((acc, value) => acc + value, 0);
|
||||
let runningTotal = totalMembers - totalInRange;
|
||||
let currentRangeDate;
|
||||
|
||||
if (days === 'all-time') {
|
||||
// start from the date of first created member
|
||||
currentRangeDate = moment(moment(result[0].created_at).format('YYYY-MM-DD')).tz(siteTimezone);
|
||||
} else {
|
||||
currentRangeDate = moment.tz(siteTimezone).subtract(days - 1, 'days');
|
||||
}
|
||||
|
||||
let endDate = moment.tz(siteTimezone).add(1, 'hour');
|
||||
const output = {};
|
||||
|
||||
while (currentRangeDate.isBefore(endDate)) {
|
||||
let dateStr = currentRangeDate.format('YYYY-MM-DD');
|
||||
runningTotal += resultObject[dateStr] || 0;
|
||||
output[dateStr] = runningTotal;
|
||||
|
||||
currentRangeDate = currentRangeDate.add(1, 'day');
|
||||
}
|
||||
|
||||
return output;
|
||||
}
|
||||
|
||||
async function getNewMembersToday() {
|
||||
const startOfToday = moment.tz(siteTimezone).startOf('day').utc().format(dateFormat);
|
||||
const result = await db.knex.raw('SELECT count(id) AS total FROM members WHERE created_at >= ?', [startOfToday]);
|
||||
return isSQLite ? result[0].total : result[0][0].total;
|
||||
}
|
||||
|
||||
// perform final calculations in parallel
|
||||
const results = await Promise.props({
|
||||
total: totalMembers,
|
||||
total_in_range: getTotalMembersInRange(),
|
||||
total_on_date: getTotalMembersOnDatesInRange(),
|
||||
new_today: getNewMembersToday()
|
||||
});
|
||||
|
||||
return results;
|
||||
}
|
||||
}
|
||||
};
|
||||
|
||||
|
|
|
@ -92,7 +92,11 @@ module.exports = {
|
|||
|
||||
importCSV(data, apiConfig, frame) {
|
||||
debug('importCSV');
|
||||
frame.response = data;
|
||||
},
|
||||
|
||||
stats(data, apiConfig, frame) {
|
||||
debug('stats');
|
||||
frame.response = data;
|
||||
}
|
||||
};
|
||||
|
|
|
@ -86,6 +86,8 @@ module.exports = function apiRoutes() {
|
|||
router.get('/members', shared.middlewares.labs.members, mw.authAdminApi, http(apiCanary.members.browse));
|
||||
router.post('/members', shared.middlewares.labs.members, mw.authAdminApi, http(apiCanary.members.add));
|
||||
|
||||
router.get('/members/stats', shared.middlewares.labs.members, mw.authAdminApi, http(apiCanary.members.stats));
|
||||
|
||||
router.get('/members/csv', shared.middlewares.labs.members, mw.authAdminApi, http(apiCanary.members.exportCSV));
|
||||
router.post('/members/csv',
|
||||
shared.middlewares.labs.members,
|
||||
|
|
|
@ -256,4 +256,26 @@ describe('Members API', function () {
|
|||
jsonResponse.meta.stats.invalid.should.equal(0);
|
||||
});
|
||||
});
|
||||
|
||||
it('Can fetch stats', function () {
|
||||
return request
|
||||
.get(localUtils.API.getApiQuery('members/stats/'))
|
||||
.set('Origin', config.get('url'))
|
||||
.expect('Content-Type', /json/)
|
||||
.expect('Cache-Control', testUtils.cacheRules.private)
|
||||
.expect(200)
|
||||
.then((res) => {
|
||||
should.not.exist(res.headers['x-cache-invalidate']);
|
||||
const jsonResponse = res.body;
|
||||
|
||||
should.exist(jsonResponse);
|
||||
should.exist(jsonResponse.total);
|
||||
should.exist(jsonResponse.total_in_range);
|
||||
should.exist(jsonResponse.total_on_date);
|
||||
should.exist(jsonResponse.new_today);
|
||||
|
||||
// 2 from fixtures, 2 from above posts, 2 from above import
|
||||
jsonResponse.total.should.equal(6);
|
||||
});
|
||||
});
|
||||
});
|
||||
|
|
|
@ -26,7 +26,7 @@ describe('Members API', function () {
|
|||
request = supertest.agent(config.get('url'));
|
||||
})
|
||||
.then(function () {
|
||||
return localUtils.doAuth(request, 'member');
|
||||
return localUtils.doAuth(request, 'members');
|
||||
});
|
||||
});
|
||||
|
||||
|
@ -166,4 +166,85 @@ describe('Members API', function () {
|
|||
jsonResponse.meta.stats.invalid.should.equal(2);
|
||||
});
|
||||
});
|
||||
|
||||
it('Can fetch stats with no ?days param', function () {
|
||||
return request
|
||||
.get(localUtils.API.getApiQuery('members/stats/'))
|
||||
.set('Origin', config.get('url'))
|
||||
.expect('Content-Type', /json/)
|
||||
.expect('Cache-Control', testUtils.cacheRules.private)
|
||||
// .expect(200) - doesn't surface underlying errors in tests
|
||||
.then((res) => {
|
||||
res.status.should.equal(200, JSON.stringify(res.body));
|
||||
|
||||
should.not.exist(res.headers['x-cache-invalidate']);
|
||||
const jsonResponse = res.body;
|
||||
|
||||
should.exist(jsonResponse);
|
||||
should.exist(jsonResponse.total);
|
||||
should.exist(jsonResponse.total_in_range);
|
||||
should.exist(jsonResponse.total_on_date);
|
||||
should.exist(jsonResponse.new_today);
|
||||
|
||||
// 2 from fixtures and 3 imported in previous tests
|
||||
jsonResponse.total.should.equal(5);
|
||||
});
|
||||
});
|
||||
|
||||
it('Can fetch stats with ?days=90', function () {
|
||||
return request
|
||||
.get(localUtils.API.getApiQuery('members/stats/?days=90'))
|
||||
.set('Origin', config.get('url'))
|
||||
.expect('Content-Type', /json/)
|
||||
.expect('Cache-Control', testUtils.cacheRules.private)
|
||||
// .expect(200) - doesn't surface underlying errors in tests
|
||||
.then((res) => {
|
||||
res.status.should.equal(200, JSON.stringify(res.body));
|
||||
|
||||
should.not.exist(res.headers['x-cache-invalidate']);
|
||||
const jsonResponse = res.body;
|
||||
|
||||
should.exist(jsonResponse);
|
||||
should.exist(jsonResponse.total);
|
||||
should.exist(jsonResponse.total_in_range);
|
||||
should.exist(jsonResponse.total_on_date);
|
||||
should.exist(jsonResponse.new_today);
|
||||
|
||||
// 2 from fixtures and 3 imported in previous tests
|
||||
jsonResponse.total.should.equal(5);
|
||||
});
|
||||
});
|
||||
|
||||
it('Can fetch stats with ?days=all-time', function () {
|
||||
return request
|
||||
.get(localUtils.API.getApiQuery('members/stats/?days=all-time'))
|
||||
.set('Origin', config.get('url'))
|
||||
.expect('Content-Type', /json/)
|
||||
.expect('Cache-Control', testUtils.cacheRules.private)
|
||||
// .expect(200) - doesn't surface underlying errors in tests
|
||||
.then((res) => {
|
||||
res.status.should.equal(200, JSON.stringify(res.body));
|
||||
|
||||
should.not.exist(res.headers['x-cache-invalidate']);
|
||||
const jsonResponse = res.body;
|
||||
|
||||
should.exist(jsonResponse);
|
||||
should.exist(jsonResponse.total);
|
||||
should.exist(jsonResponse.total_in_range);
|
||||
should.exist(jsonResponse.total_on_date);
|
||||
should.exist(jsonResponse.new_today);
|
||||
|
||||
// 2 from fixtures and 3 imported in previous tests
|
||||
jsonResponse.total.should.equal(5);
|
||||
});
|
||||
});
|
||||
|
||||
it('Errors when fetching stats with unknown days param value', function () {
|
||||
return request
|
||||
.get(localUtils.API.getApiQuery('members/stats/?days=nope'))
|
||||
.set('Origin', config.get('url'))
|
||||
.expect('Content-Type', /json/)
|
||||
.expect('Cache-Control', testUtils.cacheRules.private)
|
||||
.expect(422);
|
||||
});
|
||||
});
|
||||
|
|
Loading…
Add table
Reference in a new issue