Skip to Main Content
  • Questions
  • CBO not hash joining with hash cluster

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Chris.

Asked: February 17, 2009 - 4:37 pm UTC

Last updated: February 19, 2009 - 11:43 am UTC

Version: 10.2.0.4

Viewed 1000+ times

You Asked

Tom,

Thanks again for all the support you give to the Oracle community.

I have a somewhat simple issue with the CBO choosing a nested loops join over a hash join. This whole issue came about while we were implementing rls, but I am able to reproduce it in a much smaller, simpler fashion. Here goes:

create cluster hash_cluster
        (hash_key varchar2(20))
        hashkeys 1000
        size 8192
/


create table t1 (
        username        varchar2(20) not null,
        countrycode     varchar2(7)
)
cluster hash_cluster(username)
/


insert into t1 select 'TOM', to_char(level * 2) from dual connect by level <= 10;



create table t2 (
 countrycode   varchar2(7),
 attempts  number
)
/



insert /*+ append */ into t2
select to_char(mod(level, 150)),
 mod(level, 5000)
from dual
connect by level <= 500000
/



exec dbms_stats.gather_table_stats(user, 'T1');
exec dbms_stats.gather_table_stats(user, 'T2');


set autotrace traceonly


select sum(attempts)
from t2
where countrycode in (select countrycode from t1 where username = 'TOM')
/

----------------------------------------------------------------------------
| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |      |     1 |    13 |   165   (8)| 00:00:02 |
|   1 |  SORT AGGREGATE     |      |     1 |    13 |            |          |
|   2 |   NESTED LOOPS SEMI |      | 32791 |   416K|   165   (8)| 00:00:02 |
|   3 |    TABLE ACCESS FULL| T2   |   495K|  3384K|   165   (8)| 00:00:02 |
|*  4 |    TABLE ACCESS HASH| T1   |     1 |     6 |            |          |
----------------------------------------------------------------------------



Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
      64315  consistent gets




Now, if I hint the correlated subquery, we get what we expect:

where countrycode in (select /*+ USE_HASH(t) */ countrycode from t1 t where username = 'TOM')


------------------------------------------------------------------------------
| Id  | Operation             | Name | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |     1 |    13 |   173  (13)| 00:00:03 |
|   1 |  SORT AGGREGATE       |      |     1 |    13 |            |          |
|*  2 |   HASH JOIN RIGHT SEMI|      | 32791 |   416K|   173  (13)| 00:00:03 |
|*  3 |    TABLE ACCESS HASH  | T1   |    10 |    60 |            |          |
|   4 |    TABLE ACCESS FULL  | T2   |   495K|  3384K|   165   (8)| 00:00:02 |
------------------------------------------------------------------------------

Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
        856  consistent gets





Is it that I am gathering stats wrong on the cluster? If we replace the cluster table with a normal heap table, we get the expected results without the hint:

create table t as select * from t1;
exec dbms_stats.gather_table_stats(user, 'T');


select sum(attempts)
from t2
where countrycode in (select countrycode from t where username = 'TOM')
/


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        856  consistent gets




Thanks,
Chris




and Tom said...

It is missing information on the hash cluster itself.set

ops$tkyte%ORA10GR2> set autotrace traceonly
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select sum(attempts)
  2  from t2
  3  where countrycode in (select countrycode from t1 where username = 'TOM')
  4  /


Execution Plan
----------------------------------------------------------
Plan hash value: 3679504953

----------------------------------------------------------------------------
| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |      |     1 |    13 |   299  (11)| 00:00:02 |
|   1 |  SORT AGGREGATE     |      |     1 |    13 |            |          |
|   2 |   NESTED LOOPS SEMI |      | 33155 |   420K|   299  (11)| 00:00:02 |
|   3 |    TABLE ACCESS FULL| T2   |   500K|  3422K|   299  (11)| 00:00:02 |
|*  4 |    TABLE ACCESS HASH| T1   |     1 |     6 |            |          |
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access("USERNAME"='TOM')
       filter("COUNTRYCODE"="COUNTRYCODE")


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
      21025  consistent gets
          0  physical reads
          0  redo size
        419  bytes sent via SQL*Net to client
        400  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA10GR2> analyze cluster hash_cluster compute statistics;

Cluster analyzed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select sum(attempts)
  2  from t2
  3  where countrycode in (select countrycode from t1 where username = 'TOM')
  4  /


Execution Plan
----------------------------------------------------------
Plan hash value: 3556062935

------------------------------------------------------------------------------
| Id  | Operation             | Name | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |     1 |    12 |   317  (15)| 00:00:02 |
|   1 |  SORT AGGREGATE       |      |     1 |    12 |            |          |
|*  2 |   HASH JOIN RIGHT SEMI|      | 33155 |   388K|   317  (15)| 00:00:02 |
|*  3 |    TABLE ACCESS HASH  | T1   |    10 |    50 |     1   (0)| 00:00:01 |
|   4 |    TABLE ACCESS FULL  | T2   |   500K|  3422K|   299  (11)| 00:00:02 |
------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("COUNTRYCODE"="COUNTRYCODE")
   3 - access("USERNAME"='TOM')


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
        882  consistent gets
          0  physical reads
          0  redo size
        419  bytes sent via SQL*Net to client
        400  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed


Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

CLUSTER HINT PROBLEM

Biswaranjan, December 24, 2012 - 3:35 am UTC

Hi Tom,

Hope you are doing good.

I was tryting to understand the CLUSTER hint and ran the below codes.

Oracle Database 10g Enterprise Edition Release 10.2.0.1.0
#########################################
create table dev1(a number,b number);

insert into dev1 select level,level+1 from dual connect by level<=500000;
commit;
CREATE CLUSTER personnel
(department NUMBER)
SIZE 512
STORAGE (initial 100K next 50K);

CREATE INDEX idx_personnel ON CLUSTER personnel;

CREATE TABLE a_dev1
CLUSTER personnel (a)
AS SELECT a FROM dev1;
analyze cluster personnel compute statistics;
analyze index idx_personnel compute statistics;
select /*+ cluster(dev1) */ * from dev1 where a =45;

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=3 Card=1 Bytes=5)
1 0 TABLE ACCESS (FULL) OF 'DEV1' (TABLE) (Cost=3 Card=1 Bytes
=5)

######################
Above plan didn't show "table access(cluster)".

Is it deprecated in 10g or I was doing something wrong??
I tried for has cluster(with some hash cluster creation) and it gave me expected table access as "hash".
Can you plz show me how to use this "CLUSTER HINT" with a small example.

Advance Merry christmas :)

BTW I was reading your cost vs time page(initially I thought Tom is little bit wrong ,but finally
came to know "you rock"(I have faced many situation like that small cost more time and vice versa :).
I must say "practical wins over theory".

regards,
Biswaranjan.

:)

Ranjan, December 25, 2012 - 12:16 pm UTC

Hi Tom,

So stupid of me.:)
I just read the cluster concept deeply and found the solution and complete idea about cluster(with single table and also with joins).
I knew it but never implemented it .
cluster hint should be used with clustered table :).
I did the same and, able to see table scan(cluster).

regards,
Biswaranjan.




More to Explore

Security

All of the vital components for a secure database are covered in the Security guide.