From f1b935de59e7c9acb4c683ccb60590c5986da08e Mon Sep 17 00:00:00 2001 From: Dmitry Vdovin Date: Thu, 2 Nov 2017 16:21:28 +0200 Subject: [PATCH 1/4] Add post statistics (counters) caching --- .../20171101114954_posts_cached_counters.js | 147 ++++++++++++++++++ src/api/consts.js | 1 + 2 files changed, 148 insertions(+) create mode 100644 migrations/20171101114954_posts_cached_counters.js diff --git a/migrations/20171101114954_posts_cached_counters.js b/migrations/20171101114954_posts_cached_counters.js new file mode 100644 index 00000000..9478aaf2 --- /dev/null +++ b/migrations/20171101114954_posts_cached_counters.js @@ -0,0 +1,147 @@ +export async function up(knex) { + async function createTriggers(table, countColName) { + // Create triggers that update post statistics: like_count, fav_count, comment_count. + await knex.raw(` + CREATE OR REPLACE FUNCTION get_post_score(like_count int, fav_count int, comment_count int) RETURNS float AS $$ + BEGIN + RETURN like_count + fav_count + comment_count; + END; + $$ LANGUAGE 'plpgsql'; + + CREATE OR REPLACE FUNCTION cache_post_${countColName}_on_insert() RETURNS trigger AS $$ + BEGIN + UPDATE posts SET + ${countColName} = ${countColName} + 1 + WHERE id = NEW.post_id; + UPDATE posts SET + score = get_post_score(like_count, fav_count, comment_count) + WHERE id = NEW.post_id; + RETURN NULL; + END; + $$ LANGUAGE 'plpgsql'; + + CREATE TRIGGER ${table}_on_insert_update_count_on_posts + AFTER INSERT ON ${table} + FOR EACH ROW + EXECUTE PROCEDURE cache_post_${countColName}_on_insert(); + + CREATE OR REPLACE FUNCTION cache_post_${countColName}_on_delete() RETURNS trigger AS $$ + BEGIN + UPDATE posts SET + ${countColName} = GREATEST(${countColName} - 1, 0) + WHERE id = OLD.post_id; + UPDATE posts SET + score = get_post_score(like_count, fav_count, comment_count) + WHERE id = OLD.post_id; + RETURN NULL; + END; + $$ LANGUAGE 'plpgsql'; + + CREATE TRIGGER ${table}_on_delete_update_count_on_posts + AFTER DELETE ON ${table} + FOR EACH ROW + EXECUTE PROCEDURE cache_post_${countColName}_on_delete(); + `); + } + + // Add timestamps to likes and favourites + await knex.schema.table('likes', function (table) { + table.timestamp('created_at').default(knex.raw("(now() at time zone 'utc')")); + table.index(['post_id', 'created_at']); + }); + + await knex.schema.table('favourites', function (table) { + table.timestamp('created_at').default(knex.raw("(now() at time zone 'utc')")); + table.index(['post_id', 'created_at']); + }); + + await knex.schema.table('comments', function (table) { + table.index(['post_id', 'created_at']); + }); + + await knex.schema.table('posts', function (table) { + // all time stats. Updated with triggers. + table.integer('like_count').default(0); + table.integer('fav_count').default(0); + table.integer('comment_count').default(0); + // last 30 days' stats. Updated in intervls. + table.integer('new_like_count').default(0); + table.integer('new_fav_count').default(0); + table.integer('new_comment_count').default(0); + // post score based on last 30 days' stats. + table.float('score').default(0); + }); + + // Add triggers + await createTriggers('likes', 'like_count'); + await createTriggers('favourites', 'fav_count'); + await createTriggers('comments', 'comment_count'); + + // Calculate counters + await knex.raw(` + UPDATE posts SET + like_count = (SELECT count(*) FROM likes WHERE post_id = posts.id), + fav_count = (SELECT count(*) FROM favourites WHERE post_id = posts.id), + comment_count = (SELECT count(*) FROM comments WHERE post_id = posts.id), + new_like_count = ( + SELECT count(*) FROM likes WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ), + new_fav_count = ( + SELECT count(*) FROM favourites WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ), + new_comment_count = ( + SELECT count(*) FROM comments WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ) + `); + + // Calculate initial score + await knex.raw(` + UPDATE posts SET + score = new_like_count + new_fav_count + new_comment_count; + `); +} + +export async function down(knex) { + async function destroyTriggers(table, countColName) { + await knex.raw(` + DROP TRIGGER ${table}_on_insert_update_count_on_posts ON ${table}; + DROP FUNCTION cache_post_${countColName}_on_insert(); + DROP TRIGGER ${table}_on_delete_update_count_on_posts ON ${table}; + DROP FUNCTION cache_post_${countColName}_on_delete(); + `); + } + + await destroyTriggers('likes', 'like_count'); + await destroyTriggers('favourites', 'fav_count'); + await destroyTriggers('comments', 'comment_count'); + + await knex.raw(`DROP FUNCTION get_post_score(int, int, int)`); + + await knex.schema.table('posts', function (table) { + table.dropColumns([ + 'like_count', 'fav_count', 'comment_count', + 'new_like_count', 'new_fav_count', 'new_comment_count', + 'score' + ]); + }); + + await knex.schema.table('likes', function (table) { + table.dropColumn('created_at'); + table.dropIndex(['post_id', 'created_at']); + }); + + await knex.schema.table('favourites', function (table) { + table.dropColumn('created_at'); + table.dropIndex(['post_id', 'created_at']); + }); + + await knex.schema.table('comments', function (table) { + table.dropIndex(['post_id', 'created_at']); + }); +} diff --git a/src/api/consts.js b/src/api/consts.js index 1427bcb6..ac86a398 100644 --- a/src/api/consts.js +++ b/src/api/consts.js @@ -41,6 +41,7 @@ export const POST_PUBLIC_COLUMNS = [ 'id', 'user_id', 'text', 'type', 'created_at', 'updated_at', 'more', 'fully_published_at', 'liked_hashtag_id', 'liked_school_id', 'liked_geotag_id', 'url_name', '_sphinx_id', 'text_source', 'text_type', + 'like_count', 'fav_count', 'comment_count', 'score' ]; export const POST_DEFAULT_COLUMNS = without(POST_PUBLIC_COLUMNS, 'text', 'text_source'); From 0769b8cfa45786468235a1cb1db9572eb647215c Mon Sep 17 00:00:00 2001 From: Dmitry Vdovin Date: Sun, 5 Nov 2017 08:57:25 +0200 Subject: [PATCH 2/4] Use pre-cached `post.comment_count` instead of `post.comments` --- src/api/controllers/posts.js | 4 --- src/api/controllers/search.js | 13 +-------- src/api/utils/comments.js | 48 -------------------------------- src/api/utils/posts.js | 10 ------- src/components/post/comments.js | 2 +- src/pages/tools/my-posts-tool.js | 6 ++-- src/store/posts.js | 6 ---- 7 files changed, 5 insertions(+), 84 deletions(-) delete mode 100644 src/api/utils/comments.js diff --git a/src/api/controllers/posts.js b/src/api/controllers/posts.js index 9e2e09dc..76f3bb88 100644 --- a/src/api/controllers/posts.js +++ b/src/api/controllers/posts.js @@ -31,8 +31,6 @@ export async function getPost(ctx) { let post = await Post.where({ id: ctx.params.id }).fetch({ require: true, withRelated: POST_RELATIONS }); - post.attributes.comments = post.relations.post_comments.length; - post = seq([ PostUtils.filterUsersReactions.forUser(ctx.state.user), PostUtils.serialize @@ -632,8 +630,6 @@ export async function userFavouredPosts(ctx) { // Helpers export async function preparePosts(ctx, posts) { - posts = await PostUtils.countPostComments(ctx.bookshelf, posts); - posts = posts.map( seq([ PostUtils.filterUsersReactions.forUser(ctx.state.user), diff --git a/src/api/controllers/search.js b/src/api/controllers/search.js index 1cc5b42d..49450c58 100644 --- a/src/api/controllers/search.js +++ b/src/api/controllers/search.js @@ -20,7 +20,6 @@ import _ from 'lodash'; import * as PostUtils from '../utils/posts'; import { seq } from '../../utils/lang'; -import { countComments } from '../utils/comments'; import { SearchQueryValidator } from '../validators'; import { SEARCH_INDEXES_TABLE, SEARCH_RESPONSE_TABLE, POST_RELATIONS } from '../consts'; @@ -93,19 +92,9 @@ export async function search(ctx) { if (type === 'Post') { return Model.forge().query(qb => qb.whereIn('id', ids)) .fetchAll({ require: false, withRelated: POST_RELATIONS }) - .then(posts => Promise.all([posts, countComments(ctx.bookshelf, posts)])) - .then(([posts, postCommentsCount]) => { + .then(posts => { const ps = posts.map( seq([ - post => { - post.relations.schools = post.relations.schools.map(row => ({ - id: row.id, - name: row.attributes.name, - url_name: row.attributes.url_name - })); - post.attributes.comments = postCommentsCount[post.get('id')]; - return post; - }, PostUtils.filterUsersReactions.forUser(ctx.session && ctx.session.user), PostUtils.serialize ]) diff --git a/src/api/utils/comments.js b/src/api/utils/comments.js deleted file mode 100644 index 6a50090d..00000000 --- a/src/api/utils/comments.js +++ /dev/null @@ -1,48 +0,0 @@ -/* - This file is a part of libertysoil.org website - Copyright (C) 2015 Loki Education (Social Enterprise) - - This program is free software: you can redistribute it and/or modify - it under the terms of the GNU Affero General Public License as published by - the Free Software Foundation, either version 3 of the License, or - (at your option) any later version. - - This program is distributed in the hope that it will be useful, - but WITHOUT ANY WARRANTY; without even the implied warranty of - MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the - GNU Affero General Public License for more details. - - You should have received a copy of the GNU Affero General Public License - along with this program. If not, see . -*/ -import _ from 'lodash'; - -export async function countComments(bookshelf, posts) { - const ids = posts.map(post => { - return post.get('id'); - }); - - if (ids.length < 1) { - return {}; - } - const Comment = bookshelf.model('Comment'); - const q = Comment.forge() - .query(qb => { - qb - .select('post_id') - .count('id as comment_count') - .where('post_id', 'IN', ids) - .groupBy('post_id'); - }); - - const raw_counts = await q.fetchAll(); - - const mapped_counts = _.mapValues(_.keyBy(raw_counts.toJSON(), 'post_id'), (item => { - return parseInt(item.comment_count); - })); - - const missing = _.difference(ids, _.keys(mapped_counts)); - - const zeroes = _.fill(_.clone(missing), 0, 0, missing.length); - return _.merge(_.zipObject(missing, zeroes), mapped_counts); -} diff --git a/src/api/utils/posts.js b/src/api/utils/posts.js index b27151f1..71a63438 100644 --- a/src/api/utils/posts.js +++ b/src/api/utils/posts.js @@ -20,8 +20,6 @@ import { pick } from 'lodash'; import type { Model } from 'bookshelf/lib/model'; import type { UserId } from '../../definitions/users'; -import type { Post } from '../../definitions/posts'; -import { countComments } from './comments'; export function serialize(model: Model): Object { if (model.relations.schools) { @@ -76,11 +74,3 @@ function keepOwnPostReactions(userId: UserId, post: Model): Model { return post; } - -export async function countPostComments(bookshelf: Object, posts: Array): Promise> { - const commentCounts = await countComments(bookshelf, posts); - return posts.map((post: Model): Post => { - post.attributes.comments = commentCounts[post.get('id')]; - return post; - }); -} diff --git a/src/components/post/comments.js b/src/components/post/comments.js index 4df95aa9..5777f6ef 100644 --- a/src/components/post/comments.js +++ b/src/components/post/comments.js @@ -90,7 +90,7 @@ class Comments extends Component { } = this.state; const commentsData = comments.get(post.get('id')); - const hasComments = post.get('comments') && commentsData && commentsData.size; + const hasComments = post.get('comment_count') && commentsData && commentsData.size; let postComments = []; if (hasComments) { diff --git a/src/pages/tools/my-posts-tool.js b/src/pages/tools/my-posts-tool.js index 9de920fd..98d71aee 100644 --- a/src/pages/tools/my-posts-tool.js +++ b/src/pages/tools/my-posts-tool.js @@ -145,17 +145,17 @@ class MyPostsToolPage extends React.Component {
- {post.get('likers').size} + {post.get('like_count')} - {post.get('favourers').size} + {post.get('fav_count')} - {post.get('comments')} + {post.get('comment_count')}
diff --git a/src/store/posts.js b/src/store/posts.js index 1a535be0..a8637a25 100644 --- a/src/store/posts.js +++ b/src/store/posts.js @@ -87,12 +87,6 @@ export default function reducer(state = initialState, action) { break; } - case a.comments.SET_POST_COMMENTS: { - if (action.payload.postId && action.payload.comments) { - state = state.setIn([action.payload.postId, 'comments'], action.payload.comments.length); - } - break; - } case a.posts.SET_PROFILE_POSTS: { const posts = _.keyBy(action.payload.posts, 'id'); state = state.merge(i.fromJS(posts)); From 384a7792a69f641f11eca803937c16e20f7a4874 Mon Sep 17 00:00:00 2001 From: Dmitry Vdovin Date: Sun, 5 Nov 2017 10:33:22 +0200 Subject: [PATCH 3/4] Add tests for post stats caching --- test/integration/api/db/post.js | 42 +++++++++++++++++++++++++++++++++ 1 file changed, 42 insertions(+) diff --git a/test/integration/api/db/post.js b/test/integration/api/db/post.js index aca1aadb..d3e19d5b 100644 --- a/test/integration/api/db/post.js +++ b/test/integration/api/db/post.js @@ -22,6 +22,7 @@ import { createGeotag } from '../../../../test-helpers/factories/geotag'; import { createPost } from '../../../../test-helpers/factories/post'; import { createSchool } from '../../../../test-helpers/factories/school'; import { createHashtag } from '../../../../test-helpers/factories/hashtag'; +import { createComment } from '../../../../test-helpers/factories/comment'; describe('Post', () => { @@ -48,6 +49,47 @@ describe('Post', () => { expect(school.get('updated_at'), 'not to be null'); }); + describe('cached counters', () => { + describe('like_count', () => { + it('updates when a post is liked/unliked', async () => { + await post.likers().attach(user.id); + await post.refresh(); + expect(post.attributes.like_count, 'to equal', 1); + await post.likers().detach(user.id); + await post.refresh(); + expect(post.attributes.like_count, 'to equal', 0); + }); + }); + + describe('fav_count', () => { + it('updates when a post is favorited/unfavorited', async () => { + await post.favourers().attach(user.id); + await post.refresh(); + expect(post.attributes.fav_count, 'to equal', 1); + await post.favourers().detach(user.id); + await post.refresh(); + expect(post.attributes.fav_count, 'to equal', 0); + }); + }); + + describe('comment_count', () => { + it('updates when a comment is created/destroyed', async () => { + const comment = await createComment({ user_id: user.id, post_id: post.id }); + await post.refresh(); + expect(post.attributes.comment_count, 'to equal', 1); + await comment.destroy(); + await post.refresh(); + expect(post.attributes.comment_count, 'to equal', 0); + }); + }); + + describe('score', () => { + it('updates on like/fav/comment', () => { + + }); + }); + }); + describe('geotags', () => { const geotags = []; const geotagIds = []; From f6b09dc569a6a7ff7696e7e4ae22e444eb307c8e Mon Sep 17 00:00:00 2001 From: Dmitry Vdovin Date: Sun, 12 Nov 2017 19:52:10 +0200 Subject: [PATCH 4/4] Add node-schedule job for counting post stats --- package.json | 1 + tasks.js | 35 +++++++++++++++++++++++++++++++++++ 2 files changed, 36 insertions(+) diff --git a/package.json b/package.json index 18d78f74..3107f350 100644 --- a/package.json +++ b/package.json @@ -115,6 +115,7 @@ "mime": "~2.0.2", "moment": "^2.10.6", "mysql2": "~1.4.2", + "node-schedule": "^1.2.5", "oniguruma": "~7.0.0", "passport-facebook": "^2.1.1", "passport-github": "^1.1.0", diff --git a/tasks.js b/tasks.js index 94b8939e..06ef3181 100644 --- a/tasks.js +++ b/tasks.js @@ -16,6 +16,7 @@ along with this program. If not, see . */ import kueLib from 'kue'; +import schedule from 'node-schedule'; import config from './config'; import { renderVerificationTemplate, renderResetTemplate, renderWelcomeTemplate, renderNewCommentTemplate } from './src/email-templates/index'; @@ -28,10 +29,44 @@ import initBookshelf from './src/api/db'; const dbEnv = process.env.DB_ENV || 'development'; const knexConfig = dbConfig[dbEnv]; const bookshelf = initBookshelf(knexConfig); +const knex = bookshelf.knex; export default function startServer(/*params*/) { const queue = kueLib.createQueue(config.kue); + // Every 10 minutes, update post statistics. + schedule.scheduleJob('*/10 * * * *', async function () { + try { + await knex.raw(` + UPDATE posts SET + new_like_count = ( + SELECT count(*) FROM likes WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ), + new_fav_count = ( + SELECT count(*) FROM favourites WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ), + new_comment_count = ( + SELECT count(*) FROM comments WHERE + post_id = posts.id AND + created_at > (current_timestamp at time zone 'UTC')::date - 30 + ) + `); + await knex.raw(` + UPDATE posts SET + score = new_like_count + new_fav_count + new_comment_count; + `); + + // TODO: Use propper logger + console.log('Post stats updated'); // eslint-disable-line no-console + } catch (e) { + console.error('Failed to update post stats: ', e); // eslint-disable-line no-console + } + }); + queue.on('error', (err) => { process.stderr.write(`${err.message}\n`); });