Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: NOT IN performance problem
Try EXISTS.
SELECT personid FROM person WHERE NOT EXISTS (
SELECT 0 FROM phonenumber WHERE person.personid=phonenumber.personid
);
You'll get all persons without any telephone number.
JP
On Tuesday 25 June 2002 15:08, Nils Höglund wrote:
> Hello,
>
> I have encountered a performance problem. I use "Oracle8 Enterprise Edition
> Release 8.0.5.0.0 - Production."
>
> I have two tables. "phonenumber" and "person", each person has none, one or
> many phonenumbers referenced to him.
>
> The phonenumber-table is structured like:
> phonenumber.personid
> phonenumber.phonenumber
>
> The person-table is structured like:
> person.personid
> person.name
> person.address
>
>
> I wan't to know which persons that does NOT have any phonenumber(s).
>
> I can write the query as:
> SELECT personid FROM phonenumber WHERE personid NOT IN (
> SELECT personid FROM person);
>
> However, since my tables are quite large, it takes forever to run my query.
> In the real database both (or
> atleast one) of "person" or "phonenumber" are views.
>
> To figure out who _does_ have phonenumbers is SIGNIFICANTLY faster.
> (SELECT DISTINCT person.personid FROM person, phonenumber WHERE
> person.personid=phonenumber.personid)
>
> I'm wondering how I could restructure or rewrite my query ("who doesn't
> have any phoinenumbers?") to run faster,
> or if there is anything else I can do to optimize the query?
>
> Any suggestions?
-- Pruner Jan jan_at_pruner.cz http://jan.pruner.cz/ ----------------------------- Only Robinson Crusoe had all his work done by Friday -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Jan Pruner INET: jan_at_pruner.cz Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).Received on Tue Jun 25 2002 - 09:48:25 CDT
![]() |
![]() |