Q
Problem solve Get help with specific problems with your technologies, process and projects.

Many-to-many links that aren't there

I have People linked to Roles with three tables: People, Links, Roles. People has PersonName and PersonID columns,...

Roles has RoleID, and RoleName columns, and Links has PersonID and RoleID columns. Each person can have zero or more roles, each role can have zero or more people. How do I select (distinct) all names that are NOT linked to a specified role?

I'm not totally sure whether you want to list people that are not linked to one specific role, or people that are not linked to any role at all. So let's answer both questions. Here's some sample data:

People
PersonID  PersonName
  24      Homer
  26      Marge
  31      Bart
  33      Lisa
  36      Maggie
  45      Apu

Roles RoleID RoleName 101 Technician 103 Homemaker 107 Student 111 Teacher
Links PersonID RoleID 24 101 26 103 31 107 33 107

Let's try to find people without a specific role, say Student. If we already know the RoleID, 107, then the query is:

select PersonName
  from People
left outer
  join Links
    on People.PersonID = Links.PersonID
   and                   Links.Roleid = 107
 where Links.PersonID is null

This query works by specifying the RoleID condition in the join, and then testing for no match. To see why this works, let's ignore the WHERE clause for a moment, and look at the rows produced by the left outer join. Remember, the only possible joins are to Links rows with Roleid 107:

People    People      Links     Links
PersonID  PersonName  PersonID  RoleID 
  24      Homer       null      null
  26      Marge       null      null
  31      Bart        31        107
  33      Lisa        33        107
  36      Maggie      null      null

The WHERE clause can now be applied, to select those people without a match to a RoleID 107 Links row. Homer, Marge, and Maggie are not Students.

The correct results are not produced if the Links.Roleid = 107 condition is moved from the ON clause to the WHERE clause. You can try this on your own if you wish.

Now, if the specific RoleID is not known, but the RoleName is, then just simply extend the left outer join to the third table:

select PersonName
  from People
left outer
  join Links
    on People.PersonID = Links.PersonID
left outer
  join Roles
    on Links.RoleID = Roles.RoleID
   and                Roles.RoleName = 'Student'
 where Roles.RoleID is null

Again, the technique here is to specify the restricting condition in an ON clause, rather than in the WHERE clause.

Finally, if you want people with no role at all, then use the first left outer join query, joining only People and Links, without any Roleid condition in the ON clause, again selecting unmatched rows in the WHERE clause. This will give you Apu.

By the way, you may have assumed from the title of this answer, Many-to-many links that aren't there, that the solution might involve a NOT EXISTS subquery. Yes, it's possible to do it that way:

select PersonName
  from People
 where not exists
       ( select 1
           from Links
          where PersonID = People.PersonID
            and Roleid = 107 )

However, I prefer the left outer join syntax.


This was last published in October 2002

Dig Deeper on Oracle and SQL

PRO+

Content

Find more PRO+ content and other member only offers, here.

Have a question for an expert?

Please add a title for your question

Get answers from a TechTarget expert on whatever's puzzling you.

You will be able to add details on the next page.

Start the conversation

Send me notifications when other members comment.

By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy

Please create a username to comment.

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close