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

Commit

Permalink
[WIP] Add post statistics (counters) caching
Browse files Browse the repository at this point in the history
  • Loading branch information
voidxnull committed Nov 2, 2017
1 parent 77d5e58 commit 45adac8
Showing 1 changed file with 84 additions and 0 deletions.
84 changes: 84 additions & 0 deletions migrations/20171101114954_posts_cached_counters.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
export async function up(knex) {
/**
* Creates INSERT/DELETE triggers which update counters on associated posts.
*/
async function createTriggers(table, countColName) {
await knex.raw(`
CREATE OR REPLACE FUNCTION cache_post_${countColName}(_post_id uuid) RETURNS void AS $$
DECLARE
post_${countColName} int;
BEGIN
SELECT count(*) INTO STRICT post_${countColName}
FROM ${table} WHERE post_id = _post_id;
UPDATE posts SET ${countColName} = post_${countColName} WHERE id = _post_id;
END;
$$ LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION cache_post_${countColName}_on_insert() RETURNS trigger AS $$
BEGIN
EXECUTE cache_post_${countColName}(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
EXECUTE cache_post_${countColName}(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();
`);
}

await knex.schema.table('posts', function (table) {
table.integer('like_count').default(0);
table.integer('fav_count').default(0);
table.integer('comment_count').default(0);
table.integer('score').default(0);
});

// Set 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);
`);

// Add triggers
await createTriggers('likes', 'like_count');
await createTriggers('favourites', 'fav_count');
await createTriggers('comments', 'comment_count');

// TODO: Score
}

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();
DROP FUNCTION cache_post_${countColName}(_post_id uuid);
`);
}

await destroyTriggers('likes', 'like_count');
await destroyTriggers('favourites', 'fav_count');
await destroyTriggers('comments', 'comment_count');

await knex.schema.table('posts', function (table) {
table.dropColumns(['like_count', 'fav_count', 'comment_count', 'score']);
});
}

0 comments on commit 45adac8

Please sign in to comment.