' not in ' function syntax.

Collapse
X
 
  • Time
  • Show
Clear All
new posts
  • kewldudehere
    New Member
    • Jan 2007
    • 58

    ' not in ' function syntax.

    Hi All,

    I am trying to execute this kind of query that uses'Not in ' function but unable to get 'Nulls'

    select * from table1 where col1 not in (select col2 from table2).
    Here col1 is not primary key in table1 and col2 is not foreign key for col1. They store same kind of data.
    There are few nulls for col1 in table 1 and no nulls for col2.
    If i execute the above statement , the rows with nulls for col1 are not retrieving.

    As these nulls are not in col2 of table2, they should be retrieved right?
  • chritzuk
    New Member
    • Dec 2007
    • 10

    #2
    Hi,

    NULL is considered "UNKNOWN". It is never "IN" or "NOT IN" anything. If you want to see the rows where COL1 is NULL, you have to do so explicitly using the "IS NULL" clause in your query.

    Example:

    [CODE=oracle]chris@XE> DROP TABLE t1;

    Table dropped.

    Elapsed: 00:00:00.03
    chris@XE>
    chris@XE> CREATE TABLE t1 (
    2 ID NUMBER(10),
    3 col1 VARCHAR2(1)
    4 );

    Table created.

    Elapsed: 00:00:00.00
    chris@XE>
    chris@XE> INSERT INTO t1
    2 VALUES (1, 'a');

    1 row created.

    Elapsed: 00:00:00.01
    chris@XE> INSERT INTO t1
    2 VALUES (2, 'b');

    1 row created.

    Elapsed: 00:00:00.00
    chris@XE> INSERT INTO t1
    2 VALUES (3, 'c');

    1 row created.

    Elapsed: 00:00:00.01
    chris@XE> INSERT INTO t1
    2 VALUES (4, 'd');

    1 row created.

    Elapsed: 00:00:00.00
    chris@XE> INSERT INTO t1
    2 VALUES (5, NULL);

    1 row created.

    Elapsed: 00:00:00.00
    chris@XE> INSERT INTO t1
    2 VALUES (6, 'e');

    1 row created.

    Elapsed: 00:00:00.03
    chris@XE> INSERT INTO t1
    2 VALUES (7, 'f');

    1 row created.

    Elapsed: 00:00:00.03
    chris@XE> INSERT INTO t1
    2 VALUES (8, NULL);

    1 row created.

    Elapsed: 00:00:00.01
    chris@XE> INSERT INTO t1
    2 VALUES (9, 'g');

    1 row created.

    Elapsed: 00:00:00.01
    chris@XE>
    chris@XE> COMMIT ;

    Commit complete.

    Elapsed: 00:00:00.01
    chris@XE>
    chris@XE> DROP TABLE t2;

    Table dropped.

    Elapsed: 00:00:00.06
    chris@XE>
    chris@XE> CREATE TABLE t2 (
    2 ID NUMBER(10),
    3 col2 VARCHAR2(1) NOT NULL
    4 );

    Table created.

    Elapsed: 00:00:00.03
    chris@XE>
    chris@XE> INSERT INTO t2
    2 VALUES (1, 'a');

    1 row created.

    Elapsed: 00:00:00.03
    chris@XE> INSERT INTO t2
    2 VALUES (3, 'c');

    1 row created.

    Elapsed: 00:00:00.03
    chris@XE> INSERT INTO t2
    2 VALUES (7, 'f');

    1 row created.

    Elapsed: 00:00:00.01
    chris@XE>
    chris@XE> COMMIT ;

    Commit complete.

    Elapsed: 00:00:00.01
    chris@XE>
    chris@XE> SELECT *
    2 FROM t1
    3 WHERE col1 NOT IN (SELECT col2
    4 FROM t2);

    ID C
    ---------- -
    2 b
    4 d
    6 e
    9 g

    Elapsed: 00:00:00.06
    chris@XE>
    chris@XE>
    chris@XE> SELECT *
    2 FROM t1
    3 WHERE col1 NOT IN (SELECT col2
    4 FROM t2)
    5 OR col1 IS NULL;

    ID C
    ---------- -
    2 b
    4 d
    5
    6 e
    8
    9 g

    6 rows selected.

    Elapsed: 00:00:00.07
    chris@XE> [/CODE]
    Last edited by debasisdas; Dec 21 '07, 04:54 AM. Reason: Formatted using code tags

    Comment

    Working...