Hi,
I have a view which is not merged by the CBO. I mean the CBO decides to apply the filter predicate after the execution of the view.
Here is the definition of the view
CREATE OR REPLACE VIEW VUNSCP AS
SELECT X.DASFM,X.COINT,X.NUCPT,X.RGCOD,X.RGCID,X.CODEV,X.CTDEV,X.CDVRF,X.TXCHJ,X.MTNLV,X.MTVDP,
LEAD(X.MTNLV+X.MTVDP,1) OVER (PARTITION BY X.COINT,X.NUCPT,X.CDVRF,X.CTDEV,X.CODEV,X.RGCOD,X.RGCID ORDER BY X.DASFM DESC),
SUM(X.MTNLV) OVER (PARTITION BY X.COINT,X.CODEV,X.RGCOD)
FROM SFMCPT X
The query is:
explain plan for
select * from VUNSCP where dasfm='30-apr-10';
select * from table(dbms_xplan.display);
Plan hash value: 2545326530
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 13M| 1529M| | 195K (1)| 00:39:11 |
|* 1 | VIEW | VUNSCP | 13M| 1529M| | 195K (1)| 00:39:11 |
| 2 | WINDOW SORT | | 13M| 646M| 1996M| 195K (1)| 00:39:11 |
| 3 | TABLE ACCESS FULL| SFMCPT | 13M| 646M| | 27991 (4)| 00:05:36 |
--------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("DASFM"='30-apr-10')
You can see that a FTS is performed on SFMCPT (>1 million of rows) and that the filter predicate is applied only after the view has been instantiated.
So the index on DASFM can't be used.
This query is returning about 30 000 rows. We see on the plan that the CBO is mistaken beacause it reckons that there's going to be 13M of rows.
If I add the filter predicate directly on the view'script I get the correct plan:
explain plan for
SELECT X.DASFM,X.COINT,X.NUCPT,X.RGCOD,X.RGCID,X.CODEV,X.CTDEV,X.CDVRF,X.TXCHJ,X.MTNLV,X.MTVDP,
LEAD(X.MTNLV+X.MTVDP,1) OVER (PARTITION BY X.COINT,X.NUCPT,X.CDVRF,X.CTDEV,X.CODEV,X.RGCOD,X.RGCID ORDER BY X.DASFM DESC),
SUM(X.MTNLV) OVER (PARTITION BY X.COINT,X.CODEV,X.RGCOD)
FROM SFMCPT X where dasfm='30-apr-10';
select * from table(dbms_xplan.display);
Plan hash value: 1865390099
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 14357 | 729K| 13271 (1)| 00:02:40 |
| 1 | WINDOW SORT | | 14357 | 729K| 13271 (1)| 00:02:40 |
| 2 | TABLE ACCESS BY INDEX ROWID| SFMCPT | 14357 | 729K| 13269 (1)| 00:02:40 |
|* 3 | INDEX RANGE SCAN | SFMCPT1 | 14357 | | 67 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("DASFM"='30-apr-10')
The index is now used and the rows estimated seem closer to the actual rows.
I tried several things:
- disabling the "OPTIMZER_COST_BASED_TRANSFORMATION" hidden parameter
- use the MERGE hint
- alter session set optimizer_features_enable = '9.2.0.8';
All these workarounds don't work => I'm still getting the bad execution plan.
According to Jonathan LEWIS' s book the 9i optimzer always merge views But here even if I set the optimizer_features_enable parameter to 9i the view is not merged.
It's sure that the issue is due to the analytical functions but why ?
Can please someone help me to understand what is going on ?
Edited by: Ahmed AANGOUR on 5 mai 2010 08:41