Thread: Question regarding 'not in' and subselects
Hi. I'm using PostgreSQL 7.4.2 under Fedora Core 1. I have two tables with a single varchar(32) column in each. I'm trying to find all the rows from one table that don't exist in the other table. The query that I am using is: select u.user_name from users u where u.user_name not in (select user_name from iasusers); (Actually, I'm doing something a bit more complex but this illustrates the problem.) It always seems to return 0 rows. As a test, I inserted a row into users that I knew wasn't in iasuses but it didn't make a difference. If I remove the 'not', the query returns the rows that exist in both tables. If I replace the subselect with a list, it seems to work the way that I'd expect, i.e. "not in ('vic', 'joe')" it shows all the rows from users except for vic and joe. Am I doing something wrong or is this a bug? Thanks, -Vic
On Wed, May 26, 2004 at 13:57:37 -0400, Vic Ricker <vicricker@charter.net> wrote: > Hi. I'm using PostgreSQL 7.4.2 under Fedora Core 1. > > I have two tables with a single varchar(32) column in each. I'm trying > to find all the rows from one table that don't exist in the other > table. The query that I am using is: > > select u.user_name from users u where u.user_name not in (select > user_name from iasusers); > > (Actually, I'm doing something a bit more complex but this illustrates > the problem.) > > It always seems to return 0 rows. As a test, I inserted a row into > users that I knew wasn't in iasuses but it didn't make a difference. > > If I remove the 'not', the query returns the rows that exist in both > tables. > > If I replace the subselect with a list, it seems to work the way that > I'd expect, i.e. "not in ('vic', 'joe')" it shows all the rows from > users except for vic and joe. > > Am I doing something wrong or is this a bug? Are there any nulls in iasusers.user_name?
On Wed, 2004-05-26 at 14:38, Bruno Wolff III wrote: > On Wed, May 26, 2004 at 13:57:37 -0400, > Vic Ricker <vicricker@charter.net> wrote: > > Am I doing something wrong or is this a bug? > > Are there any nulls in iasusers.user_name? There was a null in iasusers. I removed it and that fixed the problem. I'm not sure that I understand why. It doesn't seem very intuitive... :-) Tom Innes's suggestion of: select u.user_name from users u where u.user_name not in (select user_name from iasusers ia where ia.user_name = u.user_name); also worked. Thanks guys! -- Vic Ricker http://www.ricker.us/