Unique Indexes Force Hints To Be “Ignored” Part II (One Of The Few) February 19, 2019
Posted by Richard Foote in CBO, Hash Join, Hints, Oracle Indexes, Transitive Closure, Unique Indexes.5 comments
In Part I, I showed a demo of how the introduction of a Unique Index appears to force a hint to be “ignored”. This is a classic case of what difference a Unique Index can make in the CBO deliberations.
So what’s going on here?
When I run the first, un-hinted query:
SQL> select * from bowie1, bowie2 where bowie1.id=bowie2.code and bowie1.id=1;
Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("BOWIE1"."ID"=1) 6 - access("BOWIE2"."CODE"=1)
------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | | 1 | MERGE JOIN CARTESIAN | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX RANGE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | BUFFER SORT | | 50 | 350 | 3 (0) | 00:00:01 | | 5 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 6 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | -------------------------------------------------------------------------------------------------------
SQL> select /*+ use_hash(bowie2) */ * from bowie1, bowie2 where bowie1.id=bowie2.code and bowie1.id=1;
Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("BOWIE1"."ID"="BOWIE2"."CODE") 3 - access("BOWIE1"."ID"=1) 5 - access("BOWIE2"."CODE"=1)
------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | |* 1 | HASH JOIN | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX RANGE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 5 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("BOWIE1"."ID"=1) 5 - access("BOWIE2"."CODE"=1)
------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | | 1 | NESTED LOOPS | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX UNIQUE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 5 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------
“Oracle Indexing Internals and Best Practices” Seminar – Berlin 8-9 May: DOAG Website February 8, 2019
Posted by Richard Foote in Oracle Indexes.add a comment
Just a short note to say that DOAG have now a registration page for my upcoming “Oracle Indexing Internals and Best Practices” seminar running in Berlin, Germany on 8-9 May 2019.
For all the details regarding this acclaimed educational experience and how to book your place, please visit:
https://www.doag.org/de/eventdetails?tx_doagevents_single[id]=577320
Please mention you heard this seminar from me when booking and just note that places are strictly limited for these events, so please book early to avoid disappointment.
This is likely to be the only time I run this seminar in mainland Europe this year, so don’t miss this unique opportunity to learn in person all that’s worth learning in to how to use and maintain indexes judiciously to improve Oracle database/application performance.
If you have any questions, don’t hesitate to contact me at richard@richardfooteconsulting.com.
Unique Indexes Force Hints To Be “Ignored” Part I (What’s Really Happening) February 5, 2019
Posted by Richard Foote in CBO, Hash Join, Hints, Non-Unique Indexes, Oracle Indexes, Unique Indexes.2 comments
As I was compiling my new “Oracle Diagnostics and Performance Tuning” seminar, I realised there were quite a number of indexing performance issues I haven’t discussed here previously.
The following is a classic example of what difference a Unique Index can have over a Non-Unique index, while also covering the classic myth that Oracle sometimes chooses to “ignore” hints that might be present in your SQL.
To set the scene, I’m going to create two simple little tables, but importantly initially create only non-unique indexes for columns of interest (Note: I’ve had to remove the “<” in the “<=” predicate when populating the table to avoid formatting issues):
SQL> create table bowie1 as select rownum id, 'David Bowie' name from dual connect by level = 1000; Table created. SQL> create table bowie2 as select rownum id, mod(rownum,20)+1 code from dual connect by level = 1000; Table created. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=>'BOWIE1', method_opt=>'FOR ALL COLUMNS SIZE 1'); PL/SQL procedure successfully completed. SQL> exec dbms_stats.gather_table_stats(ownname=> null, tabname=>'BOWIE2', method_opt=>'FOR ALL COLUMNS SIZE 1'); PL/SQL procedure successfully completed. SQL> create index bowie1_id_i on bowie1(id); Index created. SQL> create index bowie2_id_i on bowie2(id); Index created. SQL> create index bowie2_code_i on bowie2(code); Index created.
I’m now going to run the following query which does a simple join between the two tables and filters on the ID column from the BOWIE1 table:
SQL> select * from bowie1, bowie2 where bowie1.id=bowie2.code and bowie1.id=1; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 4266778954 ------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | | 1 | MERGE JOIN CARTESIAN | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX RANGE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | BUFFER SORT | | 50 | 350 | 3 (0) | 00:00:01 | | 5 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 6 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("BOWIE1"."ID"=1) 6 - access("BOWIE2"."CODE"=1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 8 consistent gets 0 physical reads 0 redo size 1815 bytes sent via SQL*Net to client 641 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 1 sorts (memory) 0 sorts (disk) 50 rows processed
The query uses a MERGE JOIN which I (incorrectly) think is a concern and decide that a HASH JOIN should be a better option. So I now put in a basic USE_HASH hint:
SQL> select /*+ use_hash(bowie2) */ * from bowie1, bowie2 where bowie1.id=bowie2.code and bowie1.id=1; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1413846643 ------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | |* 1 | HASH JOIN | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX RANGE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 5 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("BOWIE1"."ID"="BOWIE2"."CODE") 3 - access("BOWIE1"."ID"=1) 5 - access("BOWIE2"."CODE"=1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 15 consistent gets 0 physical reads 0 redo size 1815 bytes sent via SQL*Net to client 641 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 50 rows processed
And the hint has worked as I had hoped.
I then decide that perhaps a Unique Index on the ID column might be a good idea (perhaps because I read up on all the advantages on Unique Indexes in this blog). So I drop and recreate the index as a Unique Index:
SQL> drop index bowie1_id_i; Index dropped. SQL> create unique index bowie1_id_i on bowie1(id); Index created.
I now re-run my hinted query to again use the Hash Join:
SQL> select /*+ use_hash(bowie2) */ * from bowie1, bowie2 where bowie1.id=bowie2.code and bowie1.id=1; 50 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 4272245076 ------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU) | Time | ------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 50 | 1150 | 5 (0) | 00:00:01 | | 1 | NESTED LOOPS | | 50 | 1150 | 5 (0) | 00:00:01 | | 2 | TABLE ACCESS BY INDEX ROWID | BOWIE1 | 1 | 16 | 2 (0) | 00:00:01 | |* 3 | INDEX UNIQUE SCAN | BOWIE1_ID_I | 1 | | 1 (0) | 00:00:01 | | 4 | TABLE ACCESS BY INDEX ROWID BATCHED | BOWIE2 | 50 | 350 | 3 (0) | 00:00:01 | |* 5 | INDEX RANGE SCAN | BOWIE2_CODE_I | 50 | | 1 (0) | 00:00:01 | ------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("BOWIE1"."ID"=1) 5 - access("BOWIE2"."CODE"=1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 15 consistent gets 0 physical reads 0 redo size 1815 bytes sent via SQL*Net to client 641 bytes received via SQL*Net from client 5 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 50 rows processed
And we notice the hint is now being “ignored”. The hint isn’t really ignored, it’s just no longer relevant to how the CBO has now constructed the query and associated plan with the Unique Index now making a key difference (no pun intended).
I’ll discuss in Part II why the Unique Index has made such a difference and why the hint is no longer viable.
Of course, to learn all this and a lot lot more, you can always attend my new Oracle Diagnostics and Performance Tuning” seminar one day 🙂