Skip to content
This repository has been archived by the owner on Oct 1, 2019. It is now read-only.

Commit

Permalink
Merge f6b09dc into 0773691
Browse files Browse the repository at this point in the history
  • Loading branch information
voidxnull committed Nov 12, 2017
2 parents 0773691 + f6b09dc commit 6f37d2a
Show file tree
Hide file tree
Showing 12 changed files with 231 additions and 84 deletions.
147 changes: 147 additions & 0 deletions migrations/20171101114954_posts_cached_counters.js
Original file line number Diff line number Diff line change
@@ -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']);
});
}
1 change: 1 addition & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -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",
Expand Down
1 change: 1 addition & 0 deletions src/api/consts.js
Original file line number Diff line number Diff line change
Expand Up @@ -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');
Expand Down
4 changes: 0 additions & 4 deletions src/api/controllers/posts.js
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -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),
Expand Down
13 changes: 1 addition & 12 deletions src/api/controllers/search.js
Original file line number Diff line number Diff line change
Expand Up @@ -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';

Expand Down Expand Up @@ -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
])
Expand Down
48 changes: 0 additions & 48 deletions src/api/utils/comments.js

This file was deleted.

10 changes: 0 additions & 10 deletions src/api/utils/posts.js
Original file line number Diff line number Diff line change
Expand Up @@ -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) {
Expand Down Expand Up @@ -76,11 +74,3 @@ function keepOwnPostReactions(userId: UserId, post: Model): Model {

return post;
}

export async function countPostComments(bookshelf: Object, posts: Array<Post>): Promise<Array<Post>> {
const commentCounts = await countComments(bookshelf, posts);
return posts.map((post: Model): Post => {
post.attributes.comments = commentCounts[post.get('id')];
return post;
});
}
2 changes: 1 addition & 1 deletion src/components/post/comments.js
Original file line number Diff line number Diff line change
Expand Up @@ -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) {
Expand Down
6 changes: 3 additions & 3 deletions src/pages/tools/my-posts-tool.js
Original file line number Diff line number Diff line change
Expand Up @@ -145,17 +145,17 @@ class MyPostsToolPage extends React.Component {
<div className="layout">
<span className="card__toolbar_item">
<Icon icon="favorite_border" outline size="small" />
<span className="card__toolbar_item_value">{post.get('likers').size}</span>
<span className="card__toolbar_item_value">{post.get('like_count')}</span>
</span>

<span className="card__toolbar_item">
<Icon icon="star_border" outline size="small" />
<span className="card__toolbar_item_value">{post.get('favourers').size}</span>
<span className="card__toolbar_item_value">{post.get('fav_count')}</span>
</span>

<span className="card__toolbar_item" >
<Icon icon="chat_bubble_outline" outline size="small" />
<span className="card__toolbar_item_value">{post.get('comments')}</span>
<span className="card__toolbar_item_value">{post.get('comment_count')}</span>
</span>
</div>
</Link>
Expand Down
6 changes: 0 additions & 6 deletions src/store/posts.js
Original file line number Diff line number Diff line change
Expand Up @@ -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));
Expand Down
35 changes: 35 additions & 0 deletions tasks.js
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@
along with this program. If not, see <http://www.gnu.org/licenses/>.
*/
import kueLib from 'kue';
import schedule from 'node-schedule';

import config from './config';
import { renderVerificationTemplate, renderResetTemplate, renderWelcomeTemplate, renderNewCommentTemplate } from './src/email-templates/index';
Expand All @@ -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`);
});
Expand Down
Loading

0 comments on commit 6f37d2a

Please sign in to comment.