Re: Not getting the expected results for a simple where not in

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: Jonathan Moules <jonathan-lists(at)lightpear(dot)com>, pgsql-sql(at)postgresql(dot)org
Subject: Re: Not getting the expected results for a simple where not in
Date: 2017-06-07 12:49:43
Message-ID: e5c9f56a-2e1c-7f8a-6514-3691e076f176@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On 06/07/2017 05:20 AM, Jonathan Moules wrote:
> Hi List,
> I'm a little confused by what seems like it should be a simple query and
> was hoping someone could explain what's going on.
> Using PG 9.4.x
>
> CREATE TABLE aaa.testing_nulls
> (
> str character varying(10),
> status character varying(2)
> )
>
> Data:
> "first";"aa"
> "second";"aa"
> "third";null
> "fourth";"bb"
> null;"aa"
> null;"bb"
>
> If I run:
> select
> str
> from
> aaa.testing_nulls
> where
> status in ('aa')
>
> Against the table, I get the expected result:
> "first"
> "second"
> null
>
> But I want to get the items that don't have a value of 'aa'. Obviously
> in this case I can simply add "not" to the "where status in" but that's
> not suitable for my actual use-case (which is where this problem came to
> light). Instead, I'm nesting the original as a subquery:
>
> select
> *
> from
> aaa.testing_nulls
> where
> str not in
> (
> select
> str
> from
> aaa.testing_nulls
> where
> status in ('aa')
> )
>
> Conceptually to me at least, this should work. I expect to get the values:
> "third"
> "fourth"
> But instead when I run it I get 0 results.
>
> It seems to relate to the nulls. If I change the above and add "and str
> is not null" into the subquery:
>
> select
> *
> from
> aaa.testing_nulls
> where
> str not in
> (
> select
> str
> from
> aaa.testing_nulls
> where
> status in ('aa')
> and str is not null
> )
>
> It now gives the expected results.
> Why is this?

https://www.postgresql.org/docs/9.6/static/functions-subquery.html#FUNCTIONS-SUBQUERY-IN

"Note that if the left-hand expression yields null, or if there are no
equal right-hand values and at least one right-hand row yields null, the
result of the NOT IN construct will be null, not true. This is in
accordance with SQL's normal rules for Boolean combinations of null values."

> (I tested this in SQLite too, and get the same behaviour, so I guess
> it's a generic SQL thing I've never encountered before.)
> Thanks,
> Jonathan

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Adrian Klaver 2017-06-07 13:28:43 Re: Not getting the expected results for a simple where not in
Previous Message Jonathan Moules 2017-06-07 12:20:13 Not getting the expected results for a simple where not in