SitePoint Sponsor

User Tag List

Results 1 to 2 of 2
  1. #1
    SitePoint Guru mdumka's Avatar
    Join Date
    Jul 2003
    Location
    True North
    Posts
    642
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    need a little help with a SQL query

    Hello,

    I am have a problem and I just cant get the SQL right (using MS Access).

    I have a Table [Categories], the 2 fields I am looking at are [CategoryID] and [ParentID].

    This Table is for a navigation Structure, so I only want the [CategoryID] for categories that have No Child Categories.

    Table Example:
    CategoryID [1] ParentID [0] (Shows as Main Category)
    CategoryID [2] ParentID [0] (Shows as Main Category)
    CategoryID [3] ParentID [0] (Shows as Main Category)
    CategoryID [4] ParentID [3] (Shows as Child Of 3)
    CategoryID [5] ParentID [3] (Shows as Child Of 3)

    The result I am looking for is for Categories that have no children.

    Expected Results
    CategoryID's 1,2,4,5 (Missing 3 because it has children)

    Thanks for your help.

  2. #2
    SQL Consultant gold trophysilver trophybronze trophy
    r937's Avatar
    Join Date
    Jul 2002
    Location
    Toronto, Canada
    Posts
    39,215
    Mentioned
    58 Post(s)
    Tagged
    3 Thread(s)
    there are two ways to do it

    with a LEFT OUTER JOIN checking for unmatched left table rows --
    Code:
    select parent.CategoryID
      from Categories as parent
    left outer
      join Categories as child
        on parent.CategoryID
         = child.ParentID
     where child.CategoryID is null
    or with a NOT EXISTS correlated subquery --
    Code:
    select parent.CategoryID
      from Categories as parent
     where not exists
           ( select *
               from Categories as child
              where child.ParentID
                  = parent.CategoryID )
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL
    "giving out my real stuffs"


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
  •