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: slowish query causing problems...

RE: slowish query causing problems...

From: Mark Richard <mrichard_at_transurban.com.au>
Date: Tue, 14 Jan 2003 14:04:40 -0800
Message-ID: <F001.0052FB3F.20030114140440@fatcity.com>


Denham,

Some others have already made good suggestions - including Thomas' reply which I would like to extend upon...

Thomas suggested:

SELECT DISTINCT (1)

           FROM fwepcode1
          WHERE (wotype = 'TST' AND func = 'C0NEPRF' AND EXP = '22222')
             OR not exists(select 1 FROM valuelist
                                 WHERE listname = 'STATUS'
                                   AND MAXVALUE = 'AAAAA'
                                   AND VALUE='INPRG' )

I would change it slightly to:

select 1
from fwepcode1
where ((wottype = 'TST' and func = 'CONEPRF' and exp = '22222')

              or not exists (select 1 from valuelist
                                        where listname = 'STATUS'
                                        and maxvalue = 'AAAAA'
                                        and value = 'INPRG'))
and rownum = 1;

Using "and rownum = 1" will cause it to use COUNT STOPKEY instead of SORT AGGREGATE. The sort is an unnecessarily large piece of work to test for existence. Perhaps this will also cause the optimisor to use an index - NDX9 seems the ideal candidate. If it still doesn't use the index then have you analyzed the table? Perhaps even try "analyze table fwepcode1 compute statistics for table for all indexes for all indexed columns" If the indexes are all analyzed then try the hint " /*+ index( fewpcode1 fwepcode1_ndx9 ) */ ". Let me know if it still refuses to use the index - although if you reach this point then perhaps a full table scan is the best approach, and the COUNT STOPKEY may be able to stop the FTS very quickly as soon as it finds 1 matching row anyway.

Also, I know you mentioned that the indexes are defined by somebody else but some of them look redundant - particularly NDX2 and NDX4 and maybe NDX9 if the columns are rearranged. Are a lot of updates/inserts/deletes performed on fwepcode1? If so you might get some gain by removing some indexes.

Regards,

     Mark.

                                                                                                                   
                    Denham Eva                                                                                     
                    <EvaD_at_TFMC.co.       To:     Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>       
                    za>                  cc:                                                                       
                    Sent by:             Subject:     RE: slowish query causing problems...                        
                    root_at_fatcity.c                                                                                 
                    om                                                                                             
                                                                                                                   
                                                                                                                   
                    15/01/2003                                                                                     
                    01:49                                                                                          
                    Please respond                                                                                 
                    to ORACLE-L                                                                                    
                                                                                                                   
                                                                                                                   




Hello,

Thanks for the replies
Here is the description of the table and the indexes, pls remember I have removed and tested each index seperately, still insisted on a Full search. 9 indexes is not my idea of a perfect situation these are created by the developers ( another company) so politics plays a big roll here.

CREATE TABLE FWEPCODE1 (

  RECORDID  INTEGER       NOT NULL,
  FUNC      VARCHAR2 (20),
  WOTYPE    VARCHAR2 (20),
  EXP       VARCHAR2 (20),
  PIK       VARCHAR2 (20),
  FUNCDESC  VARCHAR2 (80),
  EXPDESC   VARCHAR2 (80),
  PIKDESC   VARCHAR2 (80),
  EX1       VARCHAR2 (1),
  EX2       VARCHAR2 (10),
  EX3       VARCHAR2 (10),
  EX4       VARCHAR2 (10),
  EX5       VARCHAR2 (10),
  EX6       VARCHAR2 (10),
  EX7       VARCHAR2 (10),
  EX8       VARCHAR2 (10),
  EX9       VARCHAR2 (10),
  EX10      VARCHAR2 (10) ) ;

 FWEPCODE1_NDX1 ON FWEPCODE1(FUNC, WOTYPE, EXP, PIK);
 FWEPCODE1_NDX2 ON FWEPCODE1(FUNC);
 FWEPCODE1_NDX3 ON FWEPCODE1(EXP);
 FWEPCODE1_NDX4 ON FWEPCODE1(FUNC, WOTYPE);
 FWEPCODE1_NDX5 ON FWEPCODE1(FUNC, EX2);
 FWEPCODE1_NDX6 ON FWEPCODE1(EXPDESC);
 FWEPCODE1_NDX7 ON FWEPCODE1(FUNC, WOTYPE, PIK);
 FWEPCODE1_NDX8 ON FWEPCODE1(RECORDID);
 FWEPCODE1_NDX9 ON FWEPCODE1(WOTYPE, FUNC, EXP); I have added a CSV file as an attachment as requested by one lister of the plan_table.

Once again appreciation for all the help. Regards
Denham

     -----Original Message-----
     From: Mercadante, Thomas F [mailto:NDATFM_at_labor.state.ny.us]
     Sent: Tuesday, January 14, 2003 3:24 PM
     To: Multiple recipients of list ORACLE-L
     Subject: RE: slowish query causing problems...

     Eva,

     Is there an index on the fwepcode1 table with the three columns used
     in the where clause?  Are the three columns varchar or varchar2?  Make
     sure the EXP column is not a number!

     Secondly, I think I would change the query as follows:


     SELECT DISTINCT (1)
                FROM fwepcode1
               WHERE (wotype = 'TST' AND func = 'C0NEPRF' AND EXP
     = '22222')
                  OR not exists(select 1 FROM valuelist
                                      WHERE listname = 'STATUS'
                                        AND MAXVALUE = 'AAAAA'
                                        AND VALUE='INPRG' )





     Tom Mercadante
     Oracle Certified Professional


          -----Original Message-----
          From: Denham Eva [mailto:EvaD_at_TFMC.co.za]
          Sent: Tuesday, January 14, 2003 6:29 AM
          To: Multiple recipients of list ORACLE-L
          Subject: slowish query causing problems...



          Hello List,


          Pls help me on this problem. Our application does a validation
          when it uses a certain screen, as it so happens this screen is
          used very intensively. The performance is very slow, I have
          isolated the main culprit. I have tried the following.


          I have dropped all the indexes and tried recreating them
          individually. Each time I have run an explain plan on the query,
          the optimizer (both rule and Choose) have chosen to do a FULL
          table scan on the fwepcode table. Even when using a hint to
          explicitly use the index it still uses FULL.


          This is very frustrating indeed.


          SELECT DISTINCT (1)
                     FROM fwepcode1
                    WHERE (wotype = 'TST' AND func = 'C0NEPRF' AND EXP
          = '22222')
                       OR 'INPRG' NOT IN (SELECT VALUE
                                            FROM valuelist
                                           WHERE listname = 'STATUS'
                                             AND MAXVALUE = 'AAAAA')


          Is the reason that the optimizer does not use any of the indexes
          because of the SELECT DISTINCT (1)?
          I have tried adjusting this query slightly to remove this and it
          still insists on doing a full table scan.
          Funny enough the sub query on valuelist table does use a index.
          The table contains 8920 rows. The cost according to the explain
          plan is 703 and bytes 9834.


          The system is a Oracle 817 on Win2k.


          Pls advise, any options or help will be appreciated.
          Many Thanks
          Denham Eva
          Oracle DBA
          "UNIX is basically a simple operating system, but you have to be
          a genius to understand the simplicity."
          Dennis Ritchie.


          DISCLAIMER


          This message is for the named person's use only. It may contain
          confidential, proprietary or legally privileged information. No
          confidentiality or privilege is waived or lost by any
          mistransmission. If you receive this message in error, please
          immediately delete it and all copies of it from your system,
          destroy any hard copies of it and notify the sender. You must
          not, directly or indirectly, use, disclose, distribute, print, or
          copy any part of this message if you are not the intended
          recipient. TFMC, its holding company, and any of its subsidiaries
          each reserve the right to monitor and manage all e-mail
          communications through its networks.


          Any views expressed in this message are those of the individual
          sender, except where the message states otherwise and the sender
          is authorized to state them to be views of any such entity.


          This e-mail message has been scanned for Viruses and Content and
          cleared by MailMarshal - For more information please visit
          www.marshalsoftware.com


DISCLAIMER This message is for the named person's use only. It may contain confidential, proprietary or legally privileged information. No confidentiality or privilege is waived or lost by any mistransmission. If you receive this message in error, please immediately delete it and all copies of it from your system, destroy any hard copies of it and notify the sender. You must not, directly or indirectly, use, disclose, distribute, print, or copy any part of this message if you are not the intended recipient. TFMC, its holding company, and any of its subsidiaries each reserve the right to monitor and manage all e-mail communications through its networks.

Any views expressed in this message are those of the individual sender, except where the message states otherwise and the sender is authorized to state them to be views of any such entity.

This e-mail message has been scanned for Viruses and Content and cleared by MailMarshal - For more information please visit www.marshalsoftware.com (See attached file: plan_table.csv)

<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

   Privileged/Confidential information may be contained in this message.

          If you are not the addressee indicated in this message
       (or responsible for delivery of the message to such person),
            you may not copy or deliver this message to anyone.
In such case, you should destroy this message and kindly notify the sender
           by reply e-mail or by telephone on (61 3) 9612-6999.
   Please advise immediately if you or your employer does not consent to
                Internet e-mail for messages of this kind.
        Opinions, conclusions and other information in this message
              that do not relate to the official business of
                         Transurban City Link Ltd
         shall be understood as neither given nor endorsed by it.
<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<---->>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Mark Richard
  INET: mrichard_at_transurban.com.au

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: 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 Jan 14 2003 - 16:04:40 CST

Original text of this message

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