RE: sql optimization question

2003-08-28 Thread Guang Mei
Dave:

Thanks! That works great.

Guang

-Original Message-
Dave Hau
Sent: Wednesday, August 27, 2003 4:29 PM
To: Multiple recipients of list ORACLE-L


select distinct n.cognateid, m.isirefid,4, linkdate
from mt.externallink l, refidmatch m, nametag n
where l.objectid = n.geneid
and m.pubmedid = l.identifier
and externaldbid = 9
and l.identifier in
(select identifier from mt.externallink
where externaldbid = 9
group by identifier
having count(distinct objectid)  6);


HTH,
Dave

[EMAIL PROTECTED] wrote:
 Hi,

 This query took a few minues to return 126K rows (fast):

 select distinct n.cognateid, m.isirefid,4, linkdate
 from mt.externallink l, refidmatch m, nametag n
 where l.objectid = n.geneid
 and m.pubmedid = l.identifier
 and externaldbid = 9;

 But this query took hours and still no result, I had to kill it:

 select distinct n.cognateid, m.isirefid,4, linkdate
 from mt.externallink l, refidmatch m, nametag n
 where l.objectid = n.geneid
 and m.pubmedid = l.identifier
 and externaldbid = 9
 and (select count(distinct objectid) from mt.externallink k
  where k.identifier = l.identifier
  and externaldbid = 9
  and l.objectid !=k.objectid)5;


 All the related columns are indexed and table are analyzed. Is there a way
 to re-write the part

 select count(distinct objectid) from mt.externallink k
  where k.identifier = l.identifier
  and externaldbid = 9
  and l.objectid !=k.objectid)5

 to make the whole thing faster?

 TIA.

 Guang

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Guang Mei
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).


Re: sql optimization question

2003-08-27 Thread Dave Hau
select distinct n.cognateid, m.isirefid,4, linkdate
from mt.externallink l, refidmatch m, nametag n
where l.objectid = n.geneid
and m.pubmedid = l.identifier
and externaldbid = 9
and l.identifier in
(select identifier from mt.externallink
where externaldbid = 9
group by identifier
having count(distinct objectid)  6);
HTH,
Dave




[EMAIL PROTECTED] wrote:
Hi,

This query took a few minues to return 126K rows (fast):

select distinct n.cognateid, m.isirefid,4, linkdate
from mt.externallink l, refidmatch m, nametag n
where l.objectid = n.geneid
and m.pubmedid = l.identifier
and externaldbid = 9;
But this query took hours and still no result, I had to kill it:

select distinct n.cognateid, m.isirefid,4, linkdate
from mt.externallink l, refidmatch m, nametag n
where l.objectid = n.geneid
and m.pubmedid = l.identifier
and externaldbid = 9
and (select count(distinct objectid) from mt.externallink k
 where k.identifier = l.identifier
 and externaldbid = 9
 and l.objectid !=k.objectid)5;
All the related columns are indexed and table are analyzed. Is there a way
to re-write the part
select count(distinct objectid) from mt.externallink k
 where k.identifier = l.identifier
 and externaldbid = 9
 and l.objectid !=k.objectid)5
to make the whole thing faster?

TIA.

Guang



--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Dave Hau
 INET: [EMAIL PROTECTED]
Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).