SitePoint Sponsor

User Tag List

Results 1 to 4 of 4
  1. #1
    SitePoint Zealot NZ Joe's Avatar
    Join Date
    Apr 2001
    Location
    Kapiti, New Zealand
    Posts
    182
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Selecting names from multiple rows

    The seems to me to be a basic query that I'll probably figure out as soon as I hit the submit button and think d'oh. How do I select a user from a table where their name is against multiple entries. e.g. From the table below select names where that person has status 2 AND 3

    |ID|Name|Status|
    |1|Alice|2|
    |2|Alice|3|
    |3|Bob|1|
    |4|Bob|3|
    |5|Charlie|2|

    Query should return Alice
    Gravity always wins

  2. #2
    SitePoint Wizard rbutler's Avatar
    Join Date
    Jul 2003
    Location
    Springfield, MO
    Posts
    1,867
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    Code:
    SELECT Name, Status 
    FROM Table_Name 
    WHERE Status=2 AND 3
    I would recommend breaking the status column out into a separate table because I'm assuming some people could have the same status or the status value 2 or 3 could possibly change, if it does, with the current design, you'll be somewhat hosed.
    Ryan Butler

    Midwest Web Design

  3. #3
    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)
    this is actually a bit trickier than it seems

    first of all, you can't do it with just a WHERE condition, because a given status value can be 2 or 3 but not both at the same time (sorry, ryan)

    so what's actually being searched for here is a person who has more than one row that meets one of the given conditions

    thus, GROUP BY is required

    Code:
    select ID
         , Name
     where Status in ( 2, 3 )
    group
        by ID
         , Name
    having count(*) > 1
    you have to look at it a few times to really get how it works

    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL
    "giving out my real stuffs"

  4. #4
    SitePoint Zealot NZ Joe's Avatar
    Join Date
    Apr 2001
    Location
    Kapiti, New Zealand
    Posts
    182
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    Thanks. That's the answer I needed.
    Gravity always wins


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
  •