Re: SQL Tuning -- large, long-running outer join query

  • From: Wolfgang Breitling <breitliw@xxxxxxxxxxxxx>
  • To: jeff.thomas@xxxxxxxxxxx
  • Date: Thu, 19 Jan 2006 08:54:12 -0700

That query has no predicates whatsoever, apart from the join predicates and those are outer joins. What that means is that Oracle has to read every row of each of the five tables - at least once.
Like Mladen, I wonder what the original business question is which this query is supposed to answer. I have the funny feeling that the developer(s) threw in the outer join "just in case" for good measure, especially on the last two outer joins.
For the aql ASIS, I would try to replace the two "nested loop outer" with hash joins as well with full scans of IA_SALES_ORDLNS and OD_SALES_ORDLNS. And make sure you have the highest db_file_multi_block_read_count your OS can handle and potentially use parallel slaves.


Thomas Jeff wrote:

We have this purchased app that is generating the following query. It
runs
for 8 hours then crashes due to ORA-1555. I'm reluctant to tinker with
the undo settings or increase the undo tablespace size, as it appears
from
longops that this thing would likely run for another 7-8 hours before
completing. I'm at a loss on how to tune this -- I can't touch the
physical structure, and I don't know enough to see any hints that could
possibly help.


Any ideas?


SELET (boatload of columns)
FROM TS_SALES_ORDLNS, /* 465,175 rows, 20,930 blocks */
OD_SALES_ORDLNS, /* 18,733,125 rows, 1,247,303 blocks */
IA_SALES_ORDLNS, /* 18,631,135 rows, 603,410 blocks */
TS_SALES_ORDLNS_HD, /* 474,465 rows, 25,819 blocks */
TS_SALES_ORDLNS_LN /* 472,645 rows, 14,043 blocks */
WHERE
TS_SALES_ORDLNS.SALES_ORDER_NUM = TS_SALES_ORDLNS_HD.SALES_ORD_NUM(+)
AND TS_SALES_ORDLNS.SALES_ORDER_ITEM =
TS_SALES_ORDLNS_HD.SALES_ORD_ITEM(+)
AND TS_SALES_ORDLNS.SALES_ORDER_NUM =
TS_SALES_ORDLNS_LN.SALES_ORD_NUM(+)
AND TS_SALES_ORDLNS.SALES_ORDER_ITEM =
TS_SALES_ORDLNS_LN.SALES_ORD_ITEM(+)
AND TS_SALES_ORDLNS.KEY_ID = OD_SALES_ORDLNS.KEY_ID(+)
AND TS_SALES_ORDLNS.KEY_ID =IA_SALES_ORDLNS.KEY_ID(+);

-- Regards

Wolfgang Breitling
Centrex Consulting Corporation
www.centrexcc.com
--
//www.freelists.org/webpage/oracle-l


Other related posts: