Home » RDBMS Server » Performance Tuning » Why the Index is not used, even if its forced?
Why the Index is not used, even if its forced? [message #125119] |
Thu, 23 June 2005 06:47 |
nabeelkhan
Messages: 73 Registered: May 2005 Location: Kuwait
|
Member |
|
|
SELECT ALL /*+ index (pt_policy, POL_PDS_CODE_01) */ a.DIVN_BL_NAME, b.POL_NO,b.pol_pds_code,
b.POL_CUST_CODE, b.POL_ASSURED_NAME,
c.PSC_FIELD_2, c.PSC_FIELD_4,
c.PSC_FIELD_7, c.PSC_FIELD_8,
c.PSC_FIELD_9, c.PSC_FIELD_3,
b.POL_NL_PERIOD_DESC
FROM PM_DIVISION a, PT_POLICY b, PT_POLICY_SCHEDULE c
WHERE (b.POL_PDS_CODE IN ('080', '088', '089')
AND c.PSC_FIELD_3 LIKE '&CIVIL_ID%')
AND ((c.PSC_POL_SYS_ID=b.POL_SYS_ID)
AND (a.DIVN_CODE=b.POL_DIVN_CODE))
ORDER BY a.DIVN_BL_NAME ASC,
b.POL_NO ASC, b.POL_CUST_CODE ASC;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=14 Card=2 Bytes=258)
1 0 SORT (ORDER BY) (Cost=14 Card=2 Bytes=258)
2 1 NESTED LOOPS (Cost=12 Card=2 Bytes=258)
3 2 NESTED LOOPS (Cost=10 Card=2 Bytes=232)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'PT_POLICY_SCHEDULE
' (Cost=4 Card=2 Bytes=110)
5 4 INDEX (RANGE SCAN) OF 'PSC_FIELD_3' (NON-UNIQUE) (
Cost=3 Card=2)
6 3 TABLE ACCESS (BY INDEX ROWID) OF 'PT_POLICY' (Cost=3
Card=1265 Bytes=77165)
7 6 INDEX (RANGE SCAN) OF 'IDX_PIX_POL_6' (UNIQUE) (Co
st=2 Card=1)
8 2 TABLE ACCESS (BY INDEX ROWID) OF 'PM_DIVISION' (Cost=1
Card=1 Bytes=13)
9 8 INDEX (UNIQUE SCAN) OF 'PK_PM_DIVISION' (UNIQUE)
Statistics
----------------------------------------------------------
2 recursive calls
0 db block gets
9 consistent gets
0 physical reads
0 redo size
757 bytes sent via SQL*Net to client
328 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
Even used the table alias
1 SELECT ALL /*+ index (b, POL_PDS_CODE_01) */ a.DIVN_BL_NAME, b.POL_NO,b.pol_pds_code,
2 b.POL_CUST_CODE, b.POL_ASSURED_NAME,
3 c.PSC_FIELD_2, c.PSC_FIELD_4,
4 c.PSC_FIELD_7, c.PSC_FIELD_8,
5 c.PSC_FIELD_9, c.PSC_FIELD_3,
6 b.POL_NL_PERIOD_DESC
7 FROM PM_DIVISION a, PT_POLICY b, PT_POLICY_SCHEDULE c
8 WHERE (b.POL_PDS_CODE IN ('080', '088', '089')
9 AND c.PSC_FIELD_3 LIKE '&CIVIL_ID%')
10 AND ((c.PSC_POL_SYS_ID=b.POL_SYS_ID)
11 AND (a.DIVN_CODE=b.POL_DIVN_CODE))
12 ORDER BY a.DIVN_BL_NAME ASC,
13* b.POL_NO ASC, b.POL_CUST_CODE ASC
SQL> /
Enter value for civil_id: 27809176546
old 9: AND c.PSC_FIELD_3 LIKE '&CIVIL_ID%')
new 9: AND c.PSC_FIELD_3 LIKE '27809176546%')
no rows selected
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=14 Card=2 Bytes=258)
1 0 SORT (ORDER BY) (Cost=14 Card=2 Bytes=258)
2 1 NESTED LOOPS (Cost=12 Card=2 Bytes=258)
3 2 NESTED LOOPS (Cost=10 Card=2 Bytes=232)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'PT_POLICY_SCHEDULE
' (Cost=4 Card=2 Bytes=110)
5 4 INDEX (RANGE SCAN) OF 'PSC_FIELD_3' (NON-UNIQUE) (
Cost=3 Card=2)
6 3 TABLE ACCESS (BY INDEX ROWID) OF 'PT_POLICY' (Cost=3
Card=1265 Bytes=77165)
7 6 INDEX (RANGE SCAN) OF 'IDX_PIX_POL_6' (UNIQUE) (Co
st=2 Card=1)
8 2 TABLE ACCESS (BY INDEX ROWID) OF 'PM_DIVISION' (Cost=1
Card=1 Bytes=13)
9 8 INDEX (UNIQUE SCAN) OF 'PK_PM_DIVISION' (UNIQUE)
Statistics
----------------------------------------------------------
2 recursive calls
0 db block gets
9 consistent gets
0 physical reads
0 redo size
757 bytes sent via SQL*Net to client
328 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
0 rows processed
But in this query its been used
SQL> select /*+ index (pt_policy, POL_PDS_CODE_01) */ pol_no, pol_pds_code from pt_policy
2 WHERE POL_NO LIKE '01/351/2005/201%'
3 /
POL_NO POL
-------------------- ---
01/351/2005/201 351
01/351/2005/2010 351
01/351/2005/2011 351
......
11 rows selected.
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=306419 Card=1 Bytes=
19)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'PT_POLICY' (Cost=306419
Card=1 Bytes=19)
2 1 INDEX (FULL SCAN) OF 'POL_PDS_CODE_01' (NON-UNIQUE) (Cos
t=2980 Card=765260)
Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
327836 consistent gets
414 physical reads
472 redo size
654 bytes sent via SQL*Net to client
426 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
11 rows processed
All tables used are analyzed and stats are collected. Im using 9iR2
|
|
|
|
|
|
|
|
|
|
|
Re: Why the Index is not used, even if its forced? [message #125776 is a reply to message #125119] |
Wed, 29 June 2005 03:49 |
MauriceM
Messages: 7 Registered: June 2005
|
Junior Member |
|
|
in your 3rd query you use the following where condition:
WHERE POL_NO LIKE '01/351/2005/201%'
So I'm suprised to see that Oracle uses the index when you set a where condition against a column which is not contained in this index.
could you please provide the SQL statment used to create the index POL_PDS_CODE_01.
|
|
|
|
|
Re: Why the Index is not used, even if its forced? [message #125791 is a reply to message #125119] |
Wed, 29 June 2005 04:43 |
nabeelkhan
Messages: 73 Registered: May 2005 Location: Kuwait
|
Member |
|
|
-I used this sql to creat the index, Do I have to use Toad, Designer to get this sql?
-First query gives
SQL> select OWNER ,
2 INDEX_NAME ,
3 INDEX_TYPE ,
4 TABLE_OWNER ,
5 TABLE_NAME ,
6 TABLE_TYPE ,
7 UNIQUENESS ,
8 COMPRESSION ,
9 PREFIX_LENGTH ,
10 TABLESPACE_NAME
11 from all_indexes
12* where index_name = 'POL_PDS_CODE_01'
SQL> /
OWNER INDEX_NAME INDEX_TYPE TABLE_OWNER
------------------------------ ------------------------------ --------------------------- ----------
TABLE_NAME TABLE UNIQUENES COMPRESS PREFIX_LENGTH TABLESPACE_NAME
------------------------------ ----- --------- -------- ------------- ------------------------------
PREMPROD POL_PDS_CODE_01 NORMAL PREMPROD
PT_POLICY TABLE NONUNIQUE DISABLED PREMIDXTAB
1 row selected.
-Second query gives
SQL> select *
2 from all_ind_columns
3 where index_name = 'POL_PDS_CODE_01'
4 /
INDEX_OWNER INDEX_NAME TABLE_OWNER TABLE_NAME
------------------------------ ------------------------------ ------------------------------ -------
COLUMN_NAME
----------------------------------------------------------------------------------------------------
COLUMN_POSITION COLUMN_LENGTH CHAR_LENGTH DESC
--------------- ------------- ----------- ----
PREMPROD POL_PDS_CODE_01 PREMPROD PT_POLICY
POL_PDS_CODE
1 3 3 ASC
1 row selected.
|
|
|
Re: Why the Index is not used, even if its forced? [message #125807 is a reply to message #125791] |
Wed, 29 June 2005 05:31 |
MauriceM
Messages: 7 Registered: June 2005
|
Junior Member |
|
|
I still don't understand the execuion plan of the 3rd query.
So I got one last question: could you please execute the following SQLs.
explain plan for
select /*+ index (pt_policy, POL_PDS_CODE_01) */
pol_no,
pol_pds_code
from pt_policy
WHERE POL_NO LIKE '01/351/2005/201%';
select * from table(dbms_xplan.display);
|
|
|
|
Re: Why the Index is not used, even if its forced? [message #126227 is a reply to message #125813] |
Fri, 01 July 2005 13:01 |
ziggy
Messages: 27 Registered: July 2005 Location: Moscow, Russia
|
Junior Member |
|
|
Hi Nabeelkhan!
I agree with MauriceM that it is a mistake of course.
Using the index POL_PDS_CODE_01 without column POL_NO absolutly unreal. I hope you message isn't joke )
It may be a different schemes with different column in indexes with same name, different servers or something like this.
Pleas give us script for creation table PT_POLICY and all indexes for this table.
Also I hope that you gather statistics for table and indexes so please.
Please execute the folowing statement after gather statistics:
select table_name, index_name, index_type,
blevel, distinct_keys, clustering_factor
from user_indexes
where table_name = 'PT_POLICY'
As trick try to drop index POL_PDS_CODE_01 and create a new one on the same table with same column and different name.
Don't give up,
Oleg.
|
|
|
|
Goto Forum:
Current Time: Sat Nov 23 16:30:09 CST 2024
|