SitePoint Sponsor

User Tag List

Results 1 to 6 of 6
  1. #1
    SitePoint Member
    Join Date
    Aug 2007
    Posts
    15
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Displaying News with # of comments

    Hello,

    I want to keep queries down to a minimum and so I don't really want to do a query for every news article on my homepage to see how many comments that article has.

    Here is my current query to pull the news. Is there anyway I can add to this, to find the number of comments, or will I have to do a select query for every article?

    Code:
    $query = "SELECT n.*, u.user_name, u.country
           FROM news AS n 
           LEFT JOIN users AS u ON n.user_id = u.user_id
           WHERE published = '1'
           ORDER BY datetime DESC
    LIMIT 0, 8";
    Thanks.

  2. #2
    Theoretical Physics Student bronze trophy Jake Arkinstall's Avatar
    Join Date
    May 2006
    Location
    Lancaster University, UK
    Posts
    7,062
    Mentioned
    2 Post(s)
    Tagged
    0 Thread(s)
    Im not an expert on joining mysql tables, but I think you can do another join to the comments table, adding count(comments.*) in the select part of the query, and matching the comment's article id to the article ID.
    Jake Arkinstall
    "Sometimes you don't need to reinvent the wheel;
    Sometimes its enough to make that wheel more rounded"-Molona

  3. #3
    SitePoint Member
    Join Date
    Aug 2007
    Posts
    15
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    I have tried:

    Code:
    		$query = "SELECT n.*, u.user_name, u.country, count(c.*) as comcount 
            		 FROM news AS n 
             		 LEFT JOIN users AS u ON n.user_id = u.user_id
    				 LEFT JOIN comments AS c ON c.news_id = n.news_id
            		 WHERE published = '1'
             		 ORDER BY datetime DESC
    				 LIMIT 0, 8";
    But I get a syntax error.

  4. #4
    SitePoint Addict Wildhoney's Avatar
    Join Date
    Apr 2006
    Location
    Nottingham
    Posts
    246
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    You will also have to add in the constraints to the inner SELECT as your published is equivocal in that context to an outsider.

    Code:
    SELECT
    	n.*,
    	u.user_name,
    	u.country,
    	(
    		SELECT
    			COUNT(*)
    		FROM
    			comments
    	) AS comcount
    FROM
    	news AS n 
    	LEFT JOIN users AS u ON n.user_id = u.user_id
    	LEFT JOIN comments ON comments.news_id = n.news_id
    WHERE
    	published = 1
    ORDER BY
    	datetime
    DESC
    LIMIT
    	0, 8
    TalkPHP.com - The Friendly PHP Community

    Watch Reaper Online - Watch Chuck Online

  5. #5
    SQL Consultant gold trophysilver trophybronze trophy
    r937's Avatar
    Join Date
    Jul 2002
    Location
    Toronto, Canada
    Posts
    39,350
    Mentioned
    63 Post(s)
    Tagged
    3 Thread(s)
    if each news story must have a user, then you want INNER JOIN, not LEFT JOIN
    Code:
    SELECT n.*
         , u.user_name
         , u.country
         , ( SELECT COUNT(*)
               FROM comments
              WHERE news_id = n.news_id ) as comment_count
      FROM news AS n 
    LEFT 
      JOIN users AS u 
        ON u.user_id = n.user_id
     WHERE n.published = 1
    ORDER 
        BY n.datetime DESC LIMIT 8
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL
    "giving out my real stuffs"

  6. #6
    SitePoint Member
    Join Date
    Aug 2007
    Posts
    15
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    Thanks r937, worked a treat. I changed LEFT JOIN to INNER JOIN too.


Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •