Re: Sub-query having NULL row returning FALSE result - Mailing list pgsql-general

From Tom Lane
Subject Re: Sub-query having NULL row returning FALSE result
Date
Msg-id 25435.1467181683@sss.pgh.pa.us
Whole thread Raw
In response to Sub-query having NULL row returning FALSE result  (Sridhar N Bamandlapally <sridhar.bn1@gmail.com>)
Responses Re: Sub-query having NULL row returning FALSE result  (Sridhar N Bamandlapally <sridhar.bn1@gmail.com>)
List pgsql-general
Sridhar N Bamandlapally <sridhar.bn1@gmail.com> writes:
> postgres=# CREATE TABLE emp (id INTEGER unique, ename VARCHAR);
> postgres=# INSERT INTO emp VALUES (null, 'aaa');
> ...
> postgres=# INSERT INTO emp SELECT * FROM (SELECT 5::integer id,
> 'eee'::varchar ename) nr WHERE id NOT IN (SELECT id FROM emp);
> INSERT 0 0

This is expected.  NOT IN can never succeed if there are any nulls
returned by the sub-select, because the nulls represent "unknown",
and so it's unknown whether there is a match to the outer "id"
value, and WHERE takes a null (unknown) result as false not true.
Certainly there are things to quibble with in that behavior, but
it's what's been required by the SQL standard since 1992.

> but this is working with other databases

Really?  None that are compliant with the SQL standard, for sure.

            regards, tom lane


pgsql-general by date:

Previous
From: Sridhar N Bamandlapally
Date:
Subject: Sub-query having NULL row returning FALSE result
Next
From: Sridhar N Bamandlapally
Date:
Subject: Re: Sub-query having NULL row returning FALSE result