Strange explain plan
500442Mar 16 2009 — edited Mar 18 2009I wrote a SQL in Oracle EBS, please see the following:
SELECT msi.segment1 item_num, mmt.revision revision,
msi.description description_en,
msi_tl.long_description description_cn,
mmt.transfer_organization_id mfg_org_id,
xxuts_inv_trh_pkg.get_organization_name(mmt.transfer_organization_id),
mmt.subinventory_code subinv, mmt.locator_id,
mtln.lot_number lot_num, mmt.transaction_id txn_id,
mmt.transfer_subinventory co_subinv, mmt.transfer_locator_id,
mmt.transaction_date txn_date, fn.user_name user_name,
mts.transaction_source_type_name txn_source_type,
wie.wip_entity_name order_num,
xxuts_inv_trh_pkg.get_qty_before (mmt.organization_id,
mmt.inventory_item_id,
mmt.revision,
mmt.subinventory_code,
mmt.transaction_id,
mmt.transaction_date
),
DECODE (msi.lot_control_code,
2, mtln.transaction_quantity,
mmt.transaction_quantity
) txn_qty,
mtt.transaction_type_name txn_type, mmt.actual_cost item_cost,
DECODE (msi.lot_control_code,
2, mtln.transaction_quantity,
mmt.transaction_quantity
)
* mmt.actual_cost amount,
mtln.primary_quantity primary_qty,
NVL
(mtr.reason_name,
(SELECT mtrh.attribute1 || mtrh.attribute2 || mtrh.attribute3
FROM mtl_txn_request_headers mtrh
WHERE EXISTS (
SELECT 'X'
FROM mtl_txn_request_lines mtrl
WHERE mtrh.header_id = mtrl.header_id
AND mtrl.transaction_header_id =
mmt.transaction_set_id
AND mtrl.txn_source_id = mmt.transaction_source_id
AND mtrl.line_id = mmt.source_line_id))
) reason,
mmt.transaction_reference REFERENCE
FROM mtl_system_items_b msi --250,
mtl_system_items_tl msi_tl --500,
mtl_transaction_lot_numbers mtln -210,
mtl_material_transactions mmt -333,
mtl_transaction_types mtt,
mtl_txn_source_types mts,
mtl_item_categories mic -800,
mtl_transaction_reasons mtr,
fnd_user fn,
wip_entities wie --5
WHERE msi.inventory_item_id = mmt.inventory_item_id
AND msi.inventory_item_id = msi_tl.inventory_item_id
AND msi.organization_id = msi_tl.organization_id
AND mtr.reason_id(+) = mmt.reason_id
AND msi_tl.LANGUAGE = USERENV ('LANG')
AND mmt.transaction_id = mtln.transaction_id(+)
AND mic.inventory_item_id = mmt.inventory_item_id
AND mic.organization_id = mmt.organization_id
AND mic.category_set_id = :b15
AND mmt.transaction_type_id = mtt.transaction_type_id
AND mmt.transaction_source_type_id = mts.transaction_source_type_id
AND msi.organization_id = mmt.organization_id
AND mmt.transaction_source_id = wie.wip_entity_id
AND mmt.transaction_source_type_id IN (5)
AND fn.user_id = mmt.created_by
AND mmt.organization_id = :b14
AND msi.segment1 >= NVL (:b13, msi.segment1)
AND msi.segment1 <= NVL (:b12, msi.segment1)
AND NVL (mmt.revision, '-99') = NVL (NVL (:b11, mmt.revision), '-99')
AND mmt.subinventory_code >= NVL (:b10, mmt.subinventory_code)
AND mmt.subinventory_code <= NVL (:b9, mmt.subinventory_code)
AND mmt.transaction_date BETWEEN :b8 AND :b7
AND mmt.creation_date BETWEEN :b6 AND :b5
AND mmt.transaction_type_id = NVL (:b4, mmt.transaction_type_id)
AND mmt.transaction_source_type_id = NVL (:b3, mmt.transaction_source_type_id)
AND mmt.transaction_id = NVL (:b2, mmt.transaction_id)
AND fn.user_id = NVL (:b1, fn.user_id)
It's explain plan is:
-------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------------------------------------------
| 0 | INSERT STATEMENT | | | | 33 (100)| |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | NESTED LOOPS | | 1 | 312 | 17 (0)| 00:00:01 |
| 4 | NESTED LOOPS | | 1 | 297 | 15 (0)| 00:00:01 |
| 5 | NESTED LOOPS OUTER | | 1 | 282 | 13 (0)| 00:00:01 |
| 6 | NESTED LOOPS | | 1 | 257 | 10 (0)| 00:00:01 |
| 7 | NESTED LOOPS | | 1 | 188 | 8 (0)| 00:00:01 |
| 8 | NESTED LOOPS | | 1 | 174 | 7 (0)| 00:00:01 |
| 9 | NESTED LOOPS | | 1 | 148 | 6 (0)| 00:00:01 |
| 10 | NESTED LOOPS OUTER | | 1 | 128 | 5 (0)| 00:00:01 |
| 11 | NESTED LOOPS | | 1 | 108 | 4 (0)| 00:00:01 |
| 12 | TABLE ACCESS BY INDEX ROWID| MTL_TXN_SOURCE_TYPES | 1 | 18 | 1 (0)| 00:00:01 |
|* 13 | INDEX UNIQUE SCAN | MTL_TXN_SOURCE_TYPES_U1 | 1 | | 0 (0)| |
|* 14 | TABLE ACCESS BY INDEX ROWID| MTL_MATERIAL_TRANSACTIONS | 1 | 90 | 3 (0)| 00:00:01 |
|* 15 | INDEX RANGE SCAN | MTL_MATERIAL_TRANSACTIONS_N8 | 1 | | 2 (0)| 00:00:01 |
| 16 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_REASONS | 1 | 20 | 1 (0)| 00:00:01 |
|* 17 | INDEX UNIQUE SCAN | MTL_TRANSACTION_REASONS_U1 | 1 | | 0 (0)| |
| 18 | TABLE ACCESS BY INDEX ROWID | WIP_ENTITIES | 1 | 20 | 1 (0)| 00:00:01 |
|* 19 | INDEX UNIQUE SCAN | WIP_ENTITIES_U1 | 1 | | 0 (0)| |
| 20 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_TYPES | 1 | 26 | 1 (0)| 00:00:01 |
|* 21 | INDEX UNIQUE SCAN | MTL_TRANSACTION_TYPES_U1 | 1 | | 0 (0)| |
| 22 | TABLE ACCESS BY INDEX ROWID | FND_USER | 1 | 14 | 1 (0)| 00:00:01 |
|* 23 | INDEX UNIQUE SCAN | FND_USER_U1 | 1 | | 0 (0)| |
|* 24 | TABLE ACCESS BY INDEX ROWID | MTL_SYSTEM_ITEMS_B | 1 | 69 | 2 (0)| 00:00:01 |
|* 25 | INDEX UNIQUE SCAN | MTL_SYSTEM_ITEMS_B_U1 | 1 | | 1 (0)| 00:00:01 |
| 26 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_LOT_NUMBERS | 1 | 25 | 3 (0)| 00:00:01 |
|* 27 | INDEX RANGE SCAN | MTL_TRANSACTION_LOT_NUMBERS_N1 | 1 | | 2 (0)| 00:00:01 |
|* 28 | INDEX RANGE SCAN | MTL_ITEM_CATEGORIES_U1 | 1 | 15 | 2 (0)| 00:00:01 |
| 29 | TABLE ACCESS BY INDEX ROWID | MTL_SYSTEM_ITEMS_TL | 1 | 15 | 2 (0)| 00:00:01 |
|* 30 | INDEX UNIQUE SCAN | MTL_SYSTEM_ITEMS_TL_U1 | 1 | | 1 (0)| 00:00:01 |
|* 31 | FILTER | | | | | |
| 32 | NESTED LOOPS OUTER | | 1 | 312 | 16 (0)| 00:00:01 |
| 33 | NESTED LOOPS | | 1 | 287 | 13 (0)| 00:00:01 |
| 34 | NESTED LOOPS | | 1 | 272 | 11 (0)| 00:00:01 |
| 35 | NESTED LOOPS | | 1 | 257 | 9 (0)| 00:00:01 |
| 36 | NESTED LOOPS | | 1 | 188 | 7 (0)| 00:00:01 |
| 37 | NESTED LOOPS OUTER | | 1 | 162 | 6 (0)| 00:00:01 |
| 38 | NESTED LOOPS | | 1 | 142 | 5 (0)| 00:00:01 |
| 39 | NESTED LOOPS | | 1 | 128 | 4 (0)| 00:00:01 |
| 40 | NESTED LOOPS | | 1 | 108 | 3 (0)| 00:00:01 |
| 41 | TABLE ACCESS BY INDEX ROWID| MTL_TXN_SOURCE_TYPES | 1 | 18 | 1 (0)| 00:00:01 |
|* 42 | INDEX UNIQUE SCAN | MTL_TXN_SOURCE_TYPES_U1 | 1 | | 0 (0)| |
|* 43 | TABLE ACCESS BY INDEX ROWID| MTL_MATERIAL_TRANSACTIONS | 1 | 90 | 2 (0)| 00:00:01 |
|* 44 | INDEX UNIQUE SCAN | MTL_MATERIAL_TRANSACTIONS_U1 | 1 | | 1 (0)| 00:00:01 |
| 45 | TABLE ACCESS BY INDEX ROWID | WIP_ENTITIES | 48143 | 940K| 1 (0)| 00:00:01 |
|* 46 | INDEX UNIQUE SCAN | WIP_ENTITIES_U1 | 1 | | 0 (0)| |
| 47 | TABLE ACCESS BY INDEX ROWID | FND_USER | 1 | 14 | 1 (0)| 00:00:01 |
|* 48 | INDEX UNIQUE SCAN | FND_USER_U1 | 1 | | 0 (0)| |
| 49 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_REASONS | 36 | 720 | 1 (0)| 00:00:01 |
|* 50 | INDEX UNIQUE SCAN | MTL_TRANSACTION_REASONS_U1 | 1 | | 0 (0)| |
| 51 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_TYPES | 98 | 2548 | 1 (0)| 00:00:01 |
|* 52 | INDEX UNIQUE SCAN | MTL_TRANSACTION_TYPES_U1 | 1 | | 0 (0)| |
|* 53 | TABLE ACCESS BY INDEX ROWID | MTL_SYSTEM_ITEMS_B | 297 | 20493 | 2 (0)| 00:00:01 |
|* 54 | INDEX UNIQUE SCAN | MTL_SYSTEM_ITEMS_B_U1 | 1 | | 1 (0)| 00:00:01 |
| 55 | TABLE ACCESS BY INDEX ROWID | MTL_SYSTEM_ITEMS_TL | 96026 | 1406K| 2 (0)| 00:00:01 |
|* 56 | INDEX UNIQUE SCAN | MTL_SYSTEM_ITEMS_TL_U1 | 1 | | 1 (0)| 00:00:01 |
|* 57 | INDEX RANGE SCAN | MTL_ITEM_CATEGORIES_U1 | 1 | 15 | 2 (0)| 00:00:01 |
| 58 | TABLE ACCESS BY INDEX ROWID | MTL_TRANSACTION_LOT_NUMBERS | 1 | 25 | 3 (0)| 00:00:01 |
|* 59 | INDEX RANGE SCAN | MTL_TRANSACTION_LOT_NUMBERS_N1 | 1 | | 2 (0)| 00:00:01 |
-------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter((:B6<=:B5 AND :B8<=:B7 AND :B2 IS NULL))
13 - access("MTS"."TRANSACTION_SOURCE_TYPE_ID"=5)
14 - filter(("MMT"."TRANSACTION_SOURCE_ID" IS NOT NULL AND
"MMT"."TRANSACTION_TYPE_ID"=NVL(:B4,"MMT"."TRANSACTION_TYPE_ID") AND
"MMT"."SUBINVENTORY_CODE">=NVL(:B10,"MMT"."SUBINVENTORY_CODE") AND
"MMT"."SUBINVENTORY_CODE"<=NVL(:B9,"MMT"."SUBINVENTORY_CODE") AND
NVL("MMT"."REVISION",'-99')=NVL(NVL(:B11,"MMT"."REVISION"),'-99') AND "MMT"."TRANSACTION_ID" IS NOT NULL AND
"MMT"."CREATION_DATE">=:B6 AND "MMT"."CREATION_DATE"<=:B5))
15 - access("MMT"."TRANSACTION_SOURCE_TYPE_ID"=5 AND "MMT"."ORGANIZATION_ID"=:B14 AND
"MMT"."TRANSACTION_DATE">=:B8 AND "MMT"."TRANSACTION_DATE"<=:B7)
filter(NVL(:B3,"MMT"."TRANSACTION_SOURCE_TYPE_ID")=5)
17 - access("MTR"."REASON_ID"="MMT"."REASON_ID")
19 - access("MMT"."TRANSACTION_SOURCE_ID"="WIE"."WIP_ENTITY_ID")
21 - access("MMT"."TRANSACTION_TYPE_ID"="MTT"."TRANSACTION_TYPE_ID")
23 - access("FN"."USER_ID"="MMT"."CREATED_BY")
filter("FN"."USER_ID"=NVL(:B1,"FN"."USER_ID"))
24 - filter(("MSI"."SEGMENT1">=NVL(:B13,"MSI"."SEGMENT1") AND "MSI"."SEGMENT1"<=NVL(:B12,"MSI"."SEGMENT1")))
25 - access("MSI"."INVENTORY_ITEM_ID"="MMT"."INVENTORY_ITEM_ID" AND "MSI"."ORGANIZATION_ID"=:B14)
27 - access("MMT"."TRANSACTION_ID"="MTLN"."TRANSACTION_ID")
28 - access("MIC"."ORGANIZATION_ID"=:B14 AND "MIC"."INVENTORY_ITEM_ID"="MMT"."INVENTORY_ITEM_ID" AND
"MIC"."CATEGORY_SET_ID"=:B15)
30 - access("MSI"."INVENTORY_ITEM_ID"="MSI_TL"."INVENTORY_ITEM_ID" AND "MSI_TL"."ORGANIZATION_ID"=:B14 AND
"MSI_TL"."LANGUAGE"=USERENV('LANG'))
31 - filter((:B6<=:B5 AND :B8<=:B7 AND :B2 IS NOT NULL))
42 - access("MTS"."TRANSACTION_SOURCE_TYPE_ID"=5)
43 - filter(("MMT"."TRANSACTION_SOURCE_ID" IS NOT NULL AND "MMT"."TRANSACTION_DATE">=:B8 AND
"MMT"."ORGANIZATION_ID"=:B14 AND "MMT"."TRANSACTION_SOURCE_TYPE_ID"=5 AND
NVL(:B3,"MMT"."TRANSACTION_SOURCE_TYPE_ID")=5 AND "MMT"."TRANSACTION_TYPE_ID"=NVL(:B4,"MMT"."TRANSACTION_TYPE_ID"
) AND "MMT"."SUBINVENTORY_CODE">=NVL(:B10,"MMT"."SUBINVENTORY_CODE") AND
"MMT"."SUBINVENTORY_CODE"<=NVL(:B9,"MMT"."SUBINVENTORY_CODE") AND
NVL("MMT"."REVISION",'-99')=NVL(NVL(:B11,"MMT"."REVISION"),'-99') AND "MMT"."TRANSACTION_DATE"<=:B7 AND
"MMT"."CREATION_DATE">=:B6 AND "MMT"."CREATION_DATE"<=:B5))
44 - access("MMT"."TRANSACTION_ID"=:B2)
46 - access("MMT"."TRANSACTION_SOURCE_ID"="WIE"."WIP_ENTITY_ID")
48 - access("FN"."USER_ID"="MMT"."CREATED_BY")
filter("FN"."USER_ID"=NVL(:B1,"FN"."USER_ID"))
50 - access("MTR"."REASON_ID"="MMT"."REASON_ID")
52 - access("MMT"."TRANSACTION_TYPE_ID"="MTT"."TRANSACTION_TYPE_ID")
53 - filter(("MSI"."SEGMENT1">=NVL(:B13,"MSI"."SEGMENT1") AND "MSI"."SEGMENT1"<=NVL(:B12,"MSI"."SEGMENT1")))
54 - access("MSI"."INVENTORY_ITEM_ID"="MMT"."INVENTORY_ITEM_ID" AND "MSI"."ORGANIZATION_ID"=:B14)
56 - access("MSI"."INVENTORY_ITEM_ID"="MSI_TL"."INVENTORY_ITEM_ID" AND "MSI_TL"."ORGANIZATION_ID"=:B14 AND
"MSI_TL"."LANGUAGE"=USERENV('LANG'))
57 - access("MIC"."ORGANIZATION_ID"=:B14 AND "MIC"."INVENTORY_ITEM_ID"="MMT"."INVENTORY_ITEM_ID" AND
"MIC"."CATEGORY_SET_ID"=:B15)
59 - access("MMT"."TRANSACTION_ID"="MTLN"."TRANSACTION_ID")
I am doubt why to perform two times explain plan(Predicate -2 and 31).
Thanks