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: optimizer_mode=FIRST_ROWS

Re: optimizer_mode=FIRST_ROWS

From: Jonathan Lewis <jonathan_at_jlcomp.demon.co.uk>
Date: Tue, 18 Mar 2003 04:31:23 -0800
Message-ID: <F001.0056C518.20030318043123@fatcity.com>

Which version of Oracle is this ?
The views have changed over time,
and I can't spot why your first query
needs a join to dba_tables - all the
relevant columns seem to exist in
dba_tab_columns in my version of 8.1

As a general rule, when there is no
obvious quick and clean way of joining
catalog views, one option is to use
the no_merge hint and in-line views.
This isn't necessarily the fastest or
cleverest solution, but it can be the
most obvious to implement.

select {list of columns}
from

    (select /*+ no_merge */

            cols from dba_indexes
     where index_owner = 'ASDF'

    ) ix,
    (select /*+ no_merge */
        cols form dba_ind_columns
     where index_owner = 'ASDF'

    ) ic
where
    ic.index_owner = ix.owner
and ic.index_name = ix.index_name
and ....

This may result in two fairly efficient
queries running separately, followed
by a hash join (or perhaps merge join)
between the two sets of generated data.

Regards

Jonathan Lewis
http://www.jlcomp.demon.co.uk

Now available One-day tutorials:
  Cost Based Optimisation
  Trouble-shooting and Tuning
  Indexing Strategies

(see http://www.jlcomp.demon.co.uk/tutorial.html )

____UK_______April 8th
____UK_______April 22nd

____Denmark May 21-23rd

____USA_(FL)_May 2nd

Next dates for the 3-day seminar:
(see http://www.jlcomp.demon.co.uk/seminar.html )

____UK_(Manchester)_May
____USA_(CA, TX)_August

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

> All,
>
> I've run into the following queries "hanging" when ran on a database
with the
> optimizer_mode set to FIRST_ROWS. If the optimizer_mode is CHOOSE,
no
> problems. When set to FIRST_ROWS both queries show never-ending
wait events
> for "direct path read". I killed the sessions before they finished
after
> waiting for almost an hour for the queries to complete.
>
> I re-wrote the 1st query against dba_tables to use EXISTS (also
shown below)
> and that seemed to work fine. But I'm not sure why or how to
re-write the 2nd
> query to also be able to work....I've tried a couple of things with
no luck.
>
> Any ideas?
>
> Thanks for the help,
> Karen Morton
>
>
>
>
> select dba_tab_columns.table_name, dba_tab_columns.column_name,
> dba_tab_columns.column_id, dba_tab_columns.data_length,
> dba_tab_columns.data_type, dba_tab_columns.nullable,
> dba_tab_columns.data_precision
> from dba_tables, dba_tab_columns
> where dba_tables.owner = 'XYZDBA'
> and dba_tables.table_name = dba_tab_columns.table_name
> order by dba_tab_columns.table_name, dba_tab_columns.column_id ;
>
>
> select dba_indexes.table_name, dba_indexes.index_name,
> dba_indexes.uniqueness, dba_ind_columns.column_name,
> dba_ind_columns.column_position
> from dba_indexes, dba_ind_columns
> where dba_indexes.owner = 'XYZDBA'
> and dba_indexes.index_name = dba_ind_columns.index_name
> order by dba_indexes.table_name, dba_indexes.index_name,
> dba_ind_columns.column_position ;
>

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jonathan Lewis
  INET: jonathan_at_jlcomp.demon.co.uk

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 Mar 18 2003 - 06:31:23 CST

Original text of this message

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