Archive

Archive for May, 2011

Negativ probability

23/05/2011 Leave a comment

Not really, but this is the first thing that came to my mind, when I looked at a query, where the optimizer calculated that “condition A AND condition B” produces more rows than “condition A OR condition B”.

See for yourself on Oracle 10.2.0.4:

create table test_sz_t
 (i number, 
  d number, 
  c number, 
  v varchar2(400));

insert into test_sz_t
with gen as (select rownum-1 rn from dual connect by level <=1e5)
select rn, mod(rn, 100), trunc(rn/1000), lpad('a',300,'x') from gen;
commit;

begin
    dbms_stats.gather_table_stats(user, 'TEST_SZ_T');
end;
/

explain plan set statement_id='or' for
select * from test_sz_t where 2=:a or (3=:b  and i > -1);
select cardinality or_card from  plan_table where id=0 and statement_id='or';

explain plan set statement_id='and' for
select * from test_sz_t where 2=:a and (3=:b  and i > -1);
select cardinality and_card from  plan_table where id=0 and statement_id='and';

and here the of the expected rowcounts output. I just read the first line of the plan to get the final rowcounts.

    OR_CARD
-----------
       1990

   AND_CARD
-----------
     100000

The i> -1 will not reduce the number of rows. In the OR case, assuming independent conditions, the probability is as expected, ProbA + ProbB – ProbA*ProbB. This corresponds to the probability 1% for the completely unknown conditions number=:a, eg 1%+1% – 1%*1%. If I had used number > :a, then 5% would have been used instead of 1%.
Now in the AND case, you should expect 1%*1% e.g. 10 rows, howver this is not the case. A higher rowcount is reported, and this is only possible with a negatve probability or an oddity/bug within the optimizer.

When you look a the full plans, I omitted above, you notice quite easily what is going on, however I have to say in the orginal statements it was not so clear at first, and unfortunate, as it happend early as part of a larger query.

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 2387583053

-------------------------------------------------------------------------------
| Id  | Operation         | Name      | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |           |  1990 |   604K|  1034   (2)| 00:00:13 |
|*  1 |  TABLE ACCESS FULL| TEST_SZ_T |  1990 |   604K|  1034   (2)| 00:00:13 |
-------------------------------------------------------------------------------

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

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------

   1 - filter(TO_NUMBER(:A)=2 OR TO_NUMBER(:B)=3 AND "I">(-1))



PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 2687592283

--------------------------------------------------------------------------------
| Id  | Operation          | Name      | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |           |   100K|    29M|  1031   (2)| 00:00:13 |
|*  1 |  FILTER            |           |       |       |            |          |
|*  2 |   TABLE ACCESS FULL| TEST_SZ_T |   100K|    29M|  1031   (2)| 00:00:13 |
--------------------------------------------------------------------------------

Predicate Information (identified by operation id):

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
---------------------------------------------------

   1 - filter(TO_NUMBER(:B)=3 AND TO_NUMBER(:A)=2)
   2 - filter("I">(-1))

You see the condition now is evaluated as filter in the and case, and this filter had no influence on the cardinality at all.

Obviously this is a very simple and maybe unfair example, but it shows the issue I also faced for a more complex query. What was my “real life” problem? A historised rule table with two different sys_context and other conditions to select relevant rows.

Categories: Uncategorized

Undocumented parameter – _bloom_filter_enabled

21/05/2011 Leave a comment

Update 24.5.2011: Turns out I seem to be wrong, these are two to separate features. So additinally I should understand those features, but kind of hard, if they are not documented. Anyway, here is the orginal artical:

You should not use undocumented parameters unless directed by Oracle Support. You ever read this? Here is post to remind, one should not set _ parameters and blindly assume they continue to work for a follow up release.

On one instance, 10g, due to some bug, directed by Oracle support _bloom_pruning_enabled was set to false. Then there was an upgrade, the parameter “survived” and one day I looked at an excecution plan, and hey, bloom filters in partition pruning appeard again.

Turns out, there is a new setting _bloom_pruning_enabled that controls now this behaviour. I do not know wheater this supercedes the former, is finer modeled or is a replacement . At least on 11.1.0.7 (no other tests done) the former setting _bloom_filter_enabled=false does not work fully.

The test:

create table testsz
(
  i number,
  j number,
  l number,
  x varchar2(1000)
)
partition by range (i)
 (
 partition partition_p1 values less than (1000) ,
 partition partition_p2 values less than (2000) ,
 partition partition_p3 values less than (3000) ,
 partition partition_p4 values less than (4000) ,
 partition partition_p5 values less than (5000) ,
 partition partition_p6 values less than (6000) ,
 partition partition_p7 values less than (7000) ,
 partition partition_p8 values less than (8000) ,
 partition partition_p9 values less than (9000) ,
 partition partition_p10 values less than (10000),
 partition partionte_max values less than (maxvalue)
 );

insert into testsz
with gen as (select rownum rn  from dual connect by levelselect rn, mod(rn, 100), trunc(rn,100),  lpad('x',300,'x') from gen;
commit;

create table testsz2 (i number);
insert into testsz2
select rownum*10 from dual connect by level commit;

exec dbms_stats.gather_table_stats(user, 'TESTSZ');
exec dbms_stats.gather_table_stats(user, 'TESTSZ2');

set echo on
set timing on

alter session set "_bloom_filter_enabled"=false;      
alter session set "_bloom_pruning_enabled"=true;   

explain plan for
  SELECT *
    FROM testsz A,
         testsz2 b
   WHERE A.i=B.i;

select * from table(dbms_xplan.display());

alter session set "_bloom_filter_enabled"=false;
alter session set "_bloom_pruning_enabled"=false;

explain plan for
  SELECT  *
    FROM testsz A,
         testsz2 b
   WHERE A.i=B.i;

select * from table(dbms_xplan.display());

and here is the output, the plans, clearly show the effect of the new parameter:

TEST @ PX> alter session set "_bloom_filter_enabled"=false;

Session altered.

Elapsed: 00:00:00.11
TEST @ PX> alter session set "_bloom_pruning_enabled"=true;

Session altered.

Elapsed: 00:00:00.04
TEST @ PX> 
TEST @ PX> explain plan for
  2    SELECT *
  3      FROM testsz A,
  4           testsz2 b
  5     WHERE A.i=B.i;

Explained.

Elapsed: 00:00:00.32
TEST @ PX> 
TEST @ PX> select * from table(dbms_xplan.display());

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
Plan hash value: 4003749116

--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |         |    50 | 15800 |    61   (9)| 00:00:01 |       |       |
|*  1 |  HASH JOIN                   |         |    50 | 15800 |    61   (9)| 00:00:01 |       |       |
|   2 |   PART JOIN FILTER CREATE    | :BF0000 |    50 |   150 |     3   (0)| 00:00:01 |       |       |
|   3 |    TABLE ACCESS FULL         | TESTSZ2 |    50 |   150 |     3   (0)| 00:00:01 |       |       |
|   4 |   PARTITION RANGE JOIN-FILTER|         |   100K|    29M|    56   (6)| 00:00:01 |:BF0000|:BF0000|
|   5 |    TABLE ACCESS FULL         | TESTSZ  |   100K|    29M|    56   (6)| 00:00:01 |:BF0000|:BF0000|

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
--------------------------------------------------------------------------------------------------------

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

   1 - access("A"."I"="B"."I")

Note
-----
   - 'PLAN_TABLE' is old version

21 rows selected.

Elapsed: 00:00:00.92
TEST @ PX> 
TEST @ PX> alter session set "_bloom_filter_enabled"=false;

Session altered.

Elapsed: 00:00:00.03
TEST @ PX> alter session set "_bloom_pruning_enabled"=false;

Session altered.

Elapsed: 00:00:00.04
TEST @ PX> 
TEST @ PX> explain plan for
  2    SELECT  *
  3      FROM testsz A,
  4           testsz2 b
  5     WHERE A.i=B.i;

Explained.

Elapsed: 00:00:00.03
TEST @ PX> 
TEST @ PX> select * from table(dbms_xplan.display());

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1042833598

------------------------------------------------------------------------------------------------
| Id  | Operation            | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |         |    50 | 15800 |    61   (9)| 00:00:01 |       |       |
|*  1 |  HASH JOIN           |         |    50 | 15800 |    61   (9)| 00:00:01 |       |       |
|   2 |   TABLE ACCESS FULL  | TESTSZ2 |    50 |   150 |     3   (0)| 00:00:01 |       |       |
|   3 |   PARTITION RANGE ALL|         |   100K|    29M|    56   (6)| 00:00:01 |     1 |    11 |
|   4 |    TABLE ACCESS FULL | TESTSZ  |   100K|    29M|    56   (6)| 00:00:01 |     1 |    11 |
------------------------------------------------------------------------------------------------

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------

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

   1 - access("A"."I"="B"."I")

Note
-----
   - 'PLAN_TABLE' is old version

20 rows selected.

and by the way, the statement with bloom filter pruning was faster (I mean the actual one from the application). and do not say anything about old plan table ……

Categories: Uncategorized