SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Help with "NOT IN"
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

DaveBF
Yak Posting Veteran

89 Posts

Posted - 12/10/2012 :  08:38:30  Show Profile  Reply with Quote
I have a query which is not doing what I thought it would do and I'd like to know what I'm doing wrong.

I have a Person table with a Primary key, Person_ID, and a DepartureDate.

And I have a Position table with a foreign key to Person. It's called Pos_Person_ID. Position also has a PositionStatus which says it's Encumbered.

I want to find all of the Persons who's DepartureDate is NULL and who are not in an Encumbered Position. Here is my non-working query which incorrectly returns no results. Thank you!

select * from Person where DepartureDate is null and Person_ID not in
(select pos_person_ID from Position where PositionStatus='Encumbered')

nigelrivett
Flowing Fount of Yak Knowledge

United Kingdom
3383 Posts

Posted - 12/10/2012 :  08:49:17  Show Profile  Visit nigelrivett's Homepage  Reply with Quote
Looks ok.
Maybe the Position table isn't what you think it is.

Does it return more or less or just different rows from what you expect?

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page

DaveBF
Yak Posting Veteran

89 Posts

Posted - 12/10/2012 :  08:57:17  Show Profile  Reply with Quote
quote:
Originally posted by nigelrivett

Looks ok.
Maybe the Position table isn't what you think it is.

Does it return more or less or just different rows from what you expect?




My query returns no results. By the way, here is an equivalent query which does work:

select * from Person where Person_ID in (
select person_id from Person where DepartureDate is null except
select pos_person_ID from position where PositionStatus='Encumbered')

So my question is what's the difference between this query and my original query?
Go to Top of Page

sunitabeck
Flowing Fount of Yak Knowledge

5155 Posts

Posted - 12/10/2012 :  09:11:13  Show Profile  Reply with Quote
It may be because of NULL in PositionStatus column. Try the following:
SELECT *
FROM   Person
WHERE  DepartureDate IS NULL
       AND Person_ID NOT IN 
       (SELECT pos_person_ID
         FROM   Position
         WHERE  ISNULL(PositionStatus,'') = 'Encumbered'
       )
If that works, you might try this, which I like better (but probably will generate the same query plan)
SELECT *
FROM Person p1
WHERE DepartureDate IS NULL
AND NOT EXISTS ( 
	SELECT * FROM Position p2 WHERE p2.pos_person_ID = p1.person_id
	AND p2.PositionStatus = 'Encumbered'
)
Go to Top of Page

DaveBF
Yak Posting Veteran

89 Posts

Posted - 12/10/2012 :  09:40:33  Show Profile  Reply with Quote
Your first query returns no results but your second query correctly returns the results that I expect.
Go to Top of Page

DaveBF
Yak Posting Veteran

89 Posts

Posted - 12/10/2012 :  09:47:47  Show Profile  Reply with Quote
Sunitabeck:
Your reply helped me figure it out.
This is my original query which did not work:

select ssn from Person where DepartureDate is null and Person_ID not in (
select pos_person_ID from Position where PositionStatus='encumbered')

but this does work:

select ssn from Person where DepartureDate is null and Person_ID not in (
select ISNULL(pos_person_ID,0) from Position where PositionStatus='encumbered')

Thanks,
Dave
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000