How To Diagnose And Fix Incorrect Post Comment Counts In WordPress

Introduction

If your WordPress comment counts got messed up, whether because of a plugin (I'm talking about you, DISQUS) or you messed with your database manually and did something wrong (yup, that's what I just did), fear not – I have a solution for you.

But first, a little background.

Comment Counts In WordPress

Here's how comment counts work in WP:

  • Posts live in a table called wp_posts and each has an ID.
  • Comments reside in a table called wp_comments, each referring to an ID in wp_posts.
  • However, to make queries faster, the comment count is also cached in the wp_posts table, rather than getting calculated on every page load.
    If this count ever gets out of sync with the actual number of comments for some reason, WordPress, while still displaying all comments properly, will simply show the wrong count.

How To Find Out Which Posts Are Out Of Sync

Fire up a MySQL shell or your favorite MySQL software (mine is Navicat) and run this query.

It assumes your database is called wordpress and the prefix is wp_, so adjust those accordingly.

SELECT wpp.id, wpp.post_title, wpp.comment_count, wpc.cnt
FROM wordpress.wp_posts wpp
LEFT JOIN
(SELECT comment_post_id AS c_post_id, count(*) AS cnt FROM wordpress.wp_comments
 WHERE comment_approved = 1 GROUP BY comment_post_id) wpc
ON wpp.id=wpc.c_post_id
WHERE wpp.post_type IN ('post', 'page')
      AND (wpp.comment_count!=wpc.cnt OR (wpp.comment_count != 0 AND wpc.cnt IS NULL));

The result of this query is a list of posts whose comment_counts differ from the actual number of comments associated with each of them.

The left count is the cached number, while the right one is the right one.

How To Fix The Counts Automatically

Please make a backup of your database before performing any altering queries such as the one below (I recommend mysqldump or the WP-DBManager plugin).

The following query will recalculate and fix the comment counts for all posts that are out of sync (ones we just queried for above):

UPDATE wordpress.wp_posts wpp
LEFT JOIN
(SELECT comment_post_id AS c_post_id, count(*) AS cnt FROM wordpress.wp_comments
 WHERE comment_approved = 1 GROUP BY comment_post_id) wpc
ON wpp.id=wpc.c_post_id
SET wpp.comment_count=wpc.cnt
WHERE wpp.post_type IN ('post', 'page')
      AND (wpp.comment_count!=wpc.cnt OR (wpp.comment_count != 0 AND wpc.cnt IS NULL));

I tested this approach on a few test cases but if you experience any problems, please do alert me in the comments and desribe your problem.

Happy WP hacking!