Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: query slow in 9i, but not slow in 8i -- solved

RE: query slow in 9i, but not slow in 8i -- solved

From: Guang Mei <gmei_at_incyte.com>
Date: Tue, 2 Mar 2004 14:58:26 -0500
Message-ID: <NJEDKDKJDGAKAEKKNEEJGEALCPAA.gmei@incyte.com>


I finally had chance to test various things for my orginal slow query. I bounced the 9i db to make sure that I have a fresh db to start with. Here are the things I tried:

  1. I tried to set workarea_size_policy to manual, leaving all other stuff unchanged. The query still slow, I had to kill the session.
  2. Keep workarea_size_policy to AUTO, which is default, change pga_aggregate_target to 1000M . The query still slow, I had to kill the session.
  3. Keep workarea_size_policy to AUTO, and keep pga_aggregate_target to 25M (set in init.ora), but add hint /*+ USE_HASH(identifier) */. The query took about 3 minutes to finish! So the work around for this particular query in 9i in to add a hint.

BTW, I also found that "Query Duration" not accurate (and I don't know how to get accurated Query Duration except putting time stamp before and after query). Uudo TS is 6G in 9i which should be good enough since we don't have too many processes running. (Our 8i db has 4G temp TS and it is running perfectly fine).

Finally, many thanks to all the people who have helped!

Guang

-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Juan Cachito Reyes Pacheco
Sent: Tuesday, March 02, 2004 2:36 PM
To: oracle-l_at_freelists.org
Subject: Re: query slow in 9i, but not slow in 8i

The problem here is you are doing several things like != what is forcing to do full scans

What I'll try if this query is really important is
-- Create indexes on all columns you query, toget a full index scan instead
a full table scan.
-- Be sure, there is an index on nvl(seqtable.valid, 'Y')

I think you have to optimize the access table by table, and then the order of tables, I agree you should try to find a way, if possible, to avoid distinct.

removing redundant "distinct" might help in this query too ...

Raj




Rajendra dot Jamadagni at nospamespn dot com All Views expressed in this email are strictly personal. select standard_disclaimer from company_requirements; QOTD: Any clod can have facts, having an opinion is an art !

-----Original Message-----
Guang Mei wrote:

> I understand that the cost value does not mean anything. But from my
> experience, when I see a query's cost from explain plan reaches six
> digits, usually something is not right.
>
> Anyway the actual query has much more stuff in it. The sql I showed in my
> orginal post was only part of it and that was the part that slowed the
thing down.
> I can not run the sql on 9i now since they are other stuff running. But
> the orgianl complex query took 20 minutes to finish on 8i, and the
> exact query produced this in 9i's alert log file:
>
> ORA-01555 caused by SQL statement below (Query Duration=199335 sec, SCN:
> 0x0000.01db218e):
> Sun Feb 29 23:20:46 2004
> select  distinct accession, id
> from    (
> select  distinct to_char(PID) accession, identifier.ID
> from    mt.genbankinfo, mt.seqtable, mt.identifier
> where   seqtable.ID = genbankinfo.SeqtabID
>         and     seqtable.GeneID = identifier.GeneID
>         and     PID is not null
>         and     identifier.type != 'A'
>         and     identifier.speciesid in
> (24,31,2,19,18,17,23,21,27,32,20,34,30,22,25,26,28,29)
>         and     nvl(seqtable.valid, 'Y') != 'N'
> union all
> select  distinct upper(strings.strtok(protein_id, '.')) accession,
>         identifier.id
> from    mt.genbankinfo, mt.seqtable, mt.identifier
> where   seqtable.ID = genbankinfo.SeqtabID
>         and     seqtable.GeneID = identifier.GeneID
>         and     protein_id is not null
>         and     identifier.t
> .....
----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Tue Mar 02 2004 - 13:54:40 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US