Delete with Left Join in Oracle 10g

Tables and data:

SQL> create table grp (id1 number null, id2 number null, id3 number null, id4 number null);    
Table created.

SQL> create table my_data (id1 number null, id2 number null, id3 number null, id4 number null);

Table created.

SQL> insert into grp values (1, 2, 3, 4);

1 row created.

SQL> insert into grp values (10, 20, 30, 40);

1 row created.

SQL> insert into grp values (1, 2, 30, 40);

1 row created.

SQL> insert into my_data values (1, 2, 3, 4);

1 row created.

SQL> commit;

Commit complete.

Using in. Note Do not use if the IDs in the subquery can be null. Not in of null never returns true.

SQL> delete grp where (id1, id2, id3, id4) not in (select id1, id2, id3, id4 from my_data);

2 rows deleted.

SQL> select * from grp;

       ID1        ID2        ID3        ID4
---------- ---------- ---------- ----------
         1          2          3          4

Using exists

SQL> rollback;

Rollback complete.

SQL> delete grp where not exists (select * from my_data where grp.id1 = my_data.id1 and grp.id2 = my_data.id2 and grp.id3 = my_data.id3 and grp.id4 = my_data.id4);

2 rows deleted.

SQL> select * from grp;

       ID1        ID2        ID3        ID4
---------- ---------- ---------- ----------
         1          2          3          4

SQL> 

Shannon's solution is the way to go: use the operator NOT IN (or NOT EXISTS).

You can however delete or update a join in Oracle, but the synthax is not the same as MS SQL Server:

SQL> DELETE FROM (SELECT grp.*
  2                  FROM grp
  3                  LEFT JOIN my_data ON grp.id1 = my_data.id1
  4                                   AND grp.id2 = my_data.id2
  5                                   AND grp.id3 = my_data.id3
  6                                   AND grp.id4 = my_data.id4
  7                 WHERE my_data.id1 IS NULL);

2 rows deleted

Additionally, Oracle will only let you update a join if there is no ambiguity as to which base row will be accessed by the statement. In particular, Oracle won't risk an update or a delete (the statement will fail) if there is a possibility that a row may appear twice in the join. In this case, the delete will only work if there is a UNIQUE constraint on my_data(id1, id2, id3, id4).