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 takes ages in Oracle 10G

Re: Query takes ages in Oracle 10G

From: Jonathan Lewis <jonathan_at_jlcomp.demon.co.uk>
Date: Fri, 22 Sep 2006 06:53:03 +0100
Message-ID: <019c01c6de0b$5e6ebd00$0300a8c0@Primary>

Step 1:

    explain plan for
    {your query};

    select * from table(dbms_xplan.display);

Repeat for the 9i and 10g databases.
You will probably find that you get some filtered subqueries in 9i that change to anti joins in 10g, which may confuse the issue, but check carefully the indexes used and the predicate information.

Given your other comments, repeat the
exercise with just the offending subquery.

Regards

Jonathan Lewis
http://www.oracle.com/technology/community/oracle_ace/ace1.html#lewis

The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/faq/ind_faq.html

Cost Based Oracle: Fundamentals
http://www.jlcomp.demon.co.uk/cbo_book/ind_book.html

Hi all,

I am trying to run a query with sub-queries in Oracle 10G Release 2 and it is taking ages, I divided the query into parts and I have no problems running the first and third subqueries (together and each one separated) but when I try to run the second subquery along with the other two or just itself, it takes ages (I generated a trace and returned a wait of 22 minutes executing the query giving no results at all).
The table has 22567 records in it and runs PERFECTLY in Oracle 9i, we didn't change anything while migrating to 10G. It seems there is a problem with the date being invoked in the second subquery. Do you have any clue about what can be happening with this query?. Thanks

  SELECT *
FROM TITULO

WHERE  TITULO_ESCENA_CODIGO___ = 'REAL'  AND
       TITULO_PORTAF_CODIGO___ = 'OBL'  AND
       TITULO_TIPTIT_CODIGO___ = 'TES_TF'  AND
       (TITULO_INDTITGAR IS NULL OR TITULO_INDTITGAR = 4) AND
       TITULO_FUTURO___ IS NULL  AND
       TITULO_ESTADO___ = 2 AND
       TITULO_CLASIFICA <> 3 AND
       TITULO_NUMERO___ NOT IN (SELECT OPETIT_TITULO_NUMERO___
                                FROM   OPETIT, OPERAC
                                WHERE  OPETIT_ESCENA_CODIGO____OPE =
'REAL' AND
                                       OPETIT_PORTAF_CODIGO____OPE = 'OBL'
AND
                                       OPETIT_OPERAC_NUMERO___ =
OPERAC_NUMERO___ AND
                                       OPERAC_ESCENA_CODIGO___ = 'REAL' AND
                                       OPERAC_PORTAF_CODIGO___ = 'OBL' AND
                                       OPERAC_TIPOPE_CODIGO___ = 2 AND
                                       OPERAC_ESTADO___ IN (2, 3)) AND
       TITULO_NUMERO___ NOT IN (SELECT VENCIM_TITULO_NUMERO___
                                FROM   VENCIM
                                WHERE  VENCIM_ESCENA_CODIGO___ = 'REAL' AND
                                       VENCIM_PORTAF_CODIGO___ = 'OBL' AND
                                       VENCIM_ESTADO___ = 2
   AND
                                       VENCIM_FECCOBORI <= '21/09/2006') AND
       TITULO_NUMERO___ NOT IN (SELECT T_TITU.TITULO_NUMERO___
                                FROM   T_TITU, T_OPTI
                                WHERE  T_TITU.TITULO_ESCENA_CODIGO___ = 'REAL' 
AND
  T_TITU.TITULO_PORTAF_CODIGO___ = 'OBL' AND
                                       T_TITU.TITULO_NUMERO___        = 
OPETIT_TITULO_NUMERO___ AND
                                       OPETIT_ESCENA_CODIGO____OPE = 'REAL' AND
                                       OPETIT_PORTAF_CODIGO____OPE = 'OBL'
AND
                                       OPETIT_OPERAC_NUMERO___     = 58)

 

--
http://www.freelists.org/webpage/oracle-l
Received on Fri Sep 22 2006 - 00:53:03 CDT

Original text of this message

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