Wednesday, August 29, 2007

Unique indexes on materialized views

One of the uses of materialized views is replication. Mviews can be used to replicate a table to another database to prevent users from accessing several databases through database links. This can improve the performance of queries which frequently access that table by removing the latency of the database link.

Today the refresh job of one of the mviews we use for this purpose started getting "ORA-00001 unique constraint violated" error. This was an mview with a unique index on it. After a simple search in Metalink I have found the reason of this behavior.

I will provide a simple test case to reproduce the problem.


SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.2.0.8.0 - 64bit Production
PL/SQL Release 9.2.0.8.0 - Production
CORE 9.2.0.8.0 Production
TNS for Solaris: Version 9.2.0.8.0 - Production
NLSRTL Version 9.2.0.8.0 - Production

SQL> create table master as select rownum r,'ROW'||rownum line from all_objects where rownum<=5;
Table created.

SQL> alter table master add primary key(r);


Table altered.

SQL> create unique index master_ind on master(line);

Index created.

SQL> create materialized view log on master with primary key;

Materialized view log created.

SQL> create materialized view snap refresh fast with primary key as select * from master;

Materialized view created.

SQL> create unique index snap_ind on snap(line);

Index created.

SQL> select * from master;

R LINE
---------- -------------------------------------------
1 ROW1
2 ROW2
3 ROW3
4 ROW4
5 ROW5

After these steps we have now one master table, an mview log on it and a fast refreshable mview of the master table. Now we make some updates to the master table to switch the LINE column's data of two rows.

SQL> update master set line='DUMMY' where r=1;

1 row updated.

SQL> update master set line='ROW1' where r=2;

1 row updated.

SQL> update master set line='ROW2' where r=1;

1 row updated.

SQL> commit;

Commit complete.

SQL> select * from master;

R LINE
---------- -------------------------------------------
1 ROW2
2 ROW1
3 ROW3
4 ROW4
5 ROW5

Now when we try to refresh the mview we get the error.

SQL> exec dbms_mview.refresh('SNAP');
BEGIN dbms_mview.refresh('SNAP'); END;

*
ERROR at line 1:
ORA-12008: error in materialized view refresh path
ORA-00001: unique constraint (YAS.SNAP_IND) violated
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 820
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 877
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 858
ORA-06512: at line 1

If we drop the unique index and recreate it as nonunique we can refresh the mview without errors.

SQL> drop index snap_ind;

Index dropped.

SQL> create index snap_ind on snap(line);

Index created.

SQL> exec dbms_mview.refresh('SNAP');

PL/SQL procedure successfully completed.

SQL> select * from snap;

R LINE
---------- -------------------------------------------
1 ROW2
2 ROW1
3 ROW3
4 ROW4
5 ROW5

The reason of this error is explained in Metalink note 284101.1. According to that note the refresh mechanism may temporarily leave the data in an inconsistent state during the refresh. The modifications are not made with the same order as the modifications to the master table. Because of this creating unique indexes, foreign keys or primary keys on mviews can cause problems in the refresh process. This totally makes sense as it is better to keep the integrity checks on the master table rather than the mview. An mview is just a copy of the master table, so if we define the integrity constraints on the master table the mview will take care of itself.

This behaviour reproduces in 10G also.

Wednesday, August 15, 2007

Invisible indexes in 11G

11G has a new feature called Invisible Indexes. An invisible index is invisible to the optimizer as default. Using this feature we can test a new index without effecting the execution plans of the existing sql statements or we can test the effect of dropping an index without dropping it.

We can create an index as invisible or we can alter an index to become invisible.


YAS@11G>drop table t;

Table dropped.

YAS@11G>create table t as select * from all_objects;

Table created.

YAS@11G>create index t_ind on t(object_name) invisible;

Index created.

USER_INDEXES has a new column named VISIBILITY to indicate whether the index is visible or not.

YAS@11G>select index_name,VISIBILITY from user_indexes where index_name='T_IND';

INDEX_NAME VISIBILIT
------------------------------ ---------
T_IND INVISIBLE

There is a new initialization parameter modifiable at system or session level called OPTIMIZER_USE_INVISIBLE_INDEXES. This parameter is FALSE as default, meaning the optimizer will not consider invisible indexes when evaluating alternative execution plans.

YAS@11G>show parameter visible

NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
optimizer_use_invisible_indexes boolean FALSE

We can alter an existing index to become invisible or visible.

YAS@11G>alter index t_ind visible;

Index altered.

YAS@11G>select index_name,VISIBILITY from user_indexes where index_name='T_IND';

INDEX_NAME VISIBILIT
------------------------------ ---------
T_IND VISIBLE

YAS@11G>alter index t_ind invisible;

Index altered.

YAS@11G>select index_name,VISIBILITY from user_indexes where index_name='T_IND';

INDEX_NAME VISIBILIT
------------------------------ ---------
T_IND INVISIBLE

We can see that the invisible index is not considered by the optimizer using a 10053 trace.

YAS@11G>alter session set events '10053 trace name context forever, level 1';

Session altered.

YAS@11G>explain plan for select * from t where object_name='STANDARD';

Explained.

In the trace file the index is marked as UNUSABLE and is not considered.

BASE STATISTICAL INFORMATION
***********************
Table Stats::
Table: T Alias: T (NOT ANALYZED)
#Rows: 80129 #Blks: 981 AvgRowLen: 100.00
Index Stats::
Index: T_IND Col#: 2
LVLS: 2 #LB: 323 #DK: 38565 LB/K: 1.00 DB/K: 1.00 CLUF: 33236.00
UNUSABLE

And the plan is:

YAS@11G>explain plan for select * from t where object_name='STANDARD';

Explained.

YAS@11G>select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 11 | 1738 | 268 (1)| 00:00:04 |
|* 1 | TABLE ACCESS FULL| T | 11 | 1738 | 268 (1)| 00:00:04 |
--------------------------------------------------------------------------

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

1 - filter("OBJECT_NAME"='STANDARD')

Note
-----
- dynamic sampling used for this statement

17 rows selected.

We can change the parameter OPTIMIZER_USE_INVISIBLE_INDEXES to see if the index will be used.

YAS@11G>alter session set optimizer_use_invisible_indexes=true;

Session altered.

YAS@11G>explain plan for select * from t where object_name='STANDARD';

Explained.

YAS@11G>select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
Plan hash value: 1376202287

-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 202 | 4 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| T | 2 | 202 | 4 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T_IND | 2 | | 3 (0)| 00:00:01 |
-------------------------------------------------------------------------------------

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

2 - access("OBJECT_NAME"='STANDARD')

14 rows selected.

YAS@11G>alter session set optimizer_use_invisible_indexes=false;

Session altered.

If we make the index visible we see that the index is considered and used.

YAS@11G>alter index t_ind visible;

Index altered.

YAS@11G>explain plan for select * from t where object_name='STANDARD';

Explained.

YAS@11G>select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
Plan hash value: 1376202287

-------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 316 | 4 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| T | 2 | 316 | 4 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | T_IND | 2 | | 3 (0)| 00:00:01 |
-------------------------------------------------------------------------------------

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

2 - access("OBJECT_NAME"='STANDARD')

Note
-----
- dynamic sampling used for this statement

18 rows selected.

Trying to gather statistics on an invisible index using either gather_index_stats or gather_table_stats with the cascade option gets an error.

YAS@11G>alter index t_ind invisible;

Index altered.

YAS@11G>exec dbms_stats.gather_index_stats(user,'T_IND');
BEGIN dbms_stats.gather_index_stats(user,'T_IND'); END;

*
ERROR at line 1:
ORA-00904: : invalid identifier
ORA-06512: at "SYS.DBMS_STATS", line 14037
ORA-06512: at "SYS.DBMS_STATS", line 14060
ORA-06512: at line 1

YAS@11G>exec dbms_stats.gather_table_stats(user,'T',cascade=>true);
BEGIN dbms_stats.gather_table_stats(user,'T',cascade=>true); END;

*
ERROR at line 1:
ORA-00904: : invalid identifier
ORA-06512: at "SYS.DBMS_STATS", line 17806
ORA-06512: at "SYS.DBMS_STATS", line 17827
ORA-06512: at line 1

YAS@11G>alter index t_ind visible;

Index altered.

YAS@11G>exec dbms_stats.gather_index_stats(user,'T_IND');

PL/SQL procedure successfully completed.

YAS@11G>exec dbms_stats.gather_table_stats(user,'T',cascade=>true);

PL/SQL procedure successfully completed.

I did not search if this is a bug or intended behaviour but we need a way to collect statistics for an invisible index, otherwise how can we test if it will be used or not? There is a way to collect statistics for an invisible index, which is to set the parameter OPTIMIZER_USE_INVISIBLE_INDEXES.

YAS@11G>alter session set optimizer_use_invisible_indexes=true;

Session altered.

YAS@11G>exec dbms_stats.gather_index_stats(user,'T_IND');

PL/SQL procedure successfully completed.

YAS@11G>alter session set optimizer_use_invisible_indexes=false;

Session altered.

Tuesday, August 14, 2007

Bind variable peeking in 11G

In one of my recent posts I mentioned about Gregory Guillou's posts about bind variable peeking in 11G. I did a simple test and research on this.

First here is the test case.


YAS@11G>create table t(id number,name varchar2(30));

Table created.

YAS@11G>insert into t select mod(rownum,2),object_name from all_objects;

64901 rows created.

YAS@11G>commit;

Commit complete.

YAS@11G>create index t_ind on t(id);

Index created.

YAS@11G>drop table t;

Table dropped.

YAS@11G>create table t(id number,name varchar2(30));

Table created.

YAS@11G>insert into t select mod(rownum,2),object_name from all_objects;

64901 rows created.

YAS@11G>insert into t select 2,'test' from dual;

1 row created.

YAS@11G>create index t_ind on t(id);

Index created.

YAS@11G>exec dbms_stats.gather_table_stats(user,'T',cascade=>true,method_opt=>'for columns id size 254');

PL/SQL procedure successfully completed.

Now we have a table with three distinct values in its ID column, values 0 and 1 have more than 30,000 rows each and value 2 has only one row.

YAS@11G>var v_id number;
YAS@11G>exec :v_id := 0;

PL/SQL procedure successfully completed.

YAS@11G>set lines 200
YAS@11G>column PLAN_TABLE_OUTPUT format a100
YAS@11G>set pages 50
YAS@11G>select count(name) from t where id = :v_id;

COUNT(NAME)
-----------
32450

YAS@11G>select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID gsmm31bu4zyca, child number 0
-------------------------------------
select count(name) from t where id = :v_id

Plan hash value: 2966233522

---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 103 (100)| |
| 1 | SORT AGGREGATE | | 1 | 20 | | |
|* 2 | TABLE ACCESS FULL| T | 32433 | 633K| 103 (1)| 00:00:02 |
---------------------------------------------------------------------------

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

2 - filter("ID"=:V_ID)

19 rows selected.




A plan using a full table scan is used for this value. Prior to 11G this plan would be fixed and used for all other bind variables regardless of their value if you have CURSOR_SHARING=EXACT, if cursor_sharing is not set to EXACT things are different.
In 11G if we run the same sql with a different value things change.

YAS@11G>exec :v_id := 2;

PL/SQL procedure successfully completed.

YAS@11G>select count(name) from t where id = :v_id;

COUNT(NAME)
-----------
1

YAS@11G>select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID gsmm31bu4zyca, child number 1
-------------------------------------
select count(name) from t where id = :v_id

Plan hash value: 2602990223

--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 2 (100)| |
| 1 | SORT AGGREGATE | | 1 | 20 | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T | 1 | 20 | 2 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | T_IND | 1 | | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------

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

3 - access("ID"=:V_ID)

20 rows selected.


Notice that I had to run this sql several times for this plan to change. After several runs of the same statement with the value 2 the plan changes to an index range scan. Why is this so?

This is a change in behaviour in bind variable peeking in 11G described here. No need to rephrase what the documentation says here, just to quote:

"To ensure the optimal choice of cursor for a given bind value, Oracle Database uses bind-aware cursor matching. The system monitors the data access performed by the query over time, depending on the bind values. If bind peeking takes place, and a histogram is used to compute selectivity of the predicate containing the bind variable, then the cursor is marked as a bind-sensitive cursor. Whenever a cursor is determined to produce significantly different data access patterns depending on the bind values, that cursor is marked as bind-aware, and Oracle Database will switch to bind-aware cursor matching to select the cursor for that statement. When bind-aware cursor matching is enabled, plans are selected based on the bind value and the optimizer's estimate of its selectivity. With bind-aware cursor matching, it is possible that a SQL statement with user-defined bind variable will have multiple execution plans, depending on the bind values."


The view V$SQL_CS_STATISTICS gives information about the cursor statistics. We can use that to see the effect of this change.

YAS@11G>alter system flush shared_pool;

System altered.

YAS@11G>exec :v_id := 0;

PL/SQL procedure successfully completed.

YAS@11G>select /* test */ count(name) from t where id = :v_id;

COUNT(NAME)
-----------
32450

YAS@11G>select sql_text,sql_id from v$sql where upper(sql_text) like 'SELECT%TEST%';

SQL_TEXT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID
-------------
select /* test */ count(name) from t where id = :v_id
12dcwm6639zmr

select sql_text,sql_id from v$sql where upper(sql_text) like 'SELECT%TEST%'
51hmrnzmuaswy


YAS@11G>select child_number,BIND_SET_HASH_VALUE,PEEKED,EXECUTIONS,ROWS_PROCESSED,BUFFER_GETS
2 from V$SQL_CS_STATISTICS
3 where sql_id='12dcwm6639zmr';

CHILD_NUMBER BIND_SET_HASH_VALUE P EXECUTIONS ROWS_PROCESSED BUFFER_GETS
------------ ------------------- - ---------- -------------- -----------
0 1475158189 Y 1 32451 380

YAS@11G>exec :v_id := 2;

PL/SQL procedure successfully completed.

YAS@11G>select /* test */ count(name) from t where id = :v_id;

COUNT(NAME)
-----------
1

YAS@11G>select child_number,BIND_SET_HASH_VALUE,PEEKED,EXECUTIONS,ROWS_PROCESSED,BUFFER_GETS
2 from V$SQL_CS_STATISTICS
3 where sql_id='12dcwm6639zmr';

CHILD_NUMBER BIND_SET_HASH_VALUE P EXECUTIONS ROWS_PROCESSED BUFFER_GETS
------------ ------------------- - ---------- -------------- -----------
1 2064090006 Y 1 3 3
0 1475158189 Y 1 32451 380


As you can see there are two child cursors for this sql because of the different bind values.

First 11G installation

I have finished my first 11G installation using Vmware Server and Oracle Enterprise Linux 5 and created my first 11G database. The installation is no different than the 10G installation. There are a few differences in the database creation. I have created the database using dbca.

When it comes to setting the SGA and PGA sizes it asks if I want to use automatic memory management or not. Using automatic memory management we can set a single value for both SGA and PGA and the database adjusts the memory automatically. If this option is not selected it reverts back to the 10G behaviour.

There is a new option related to the security settings. 11G asks if you want to use enhanced 11G security settings. This option includes settings related to password management and auditing. If you select this option it enables these password policies in the default profile and starts auditing these privileges.

There is a new step asking if you want to enable automatic maintenance tasks. By selecting this option you enable automatic tasks such as statistics gathering, automatic segment advisor and sql tuning advisor.

Other than these the database creation is like 10G.

Friday, August 10, 2007

11G excitement in the community

Today when I was walking through the OraNA feed I saw that nearly all of the posts were about 11G being available for download. 11G is starting to get hot it seems. I am sure we will start seeing lots of posts about the new features soon.

Gregory Guillou of the Pythian Group has two posts about bind variable peeking in 11G, here and here. This is an interesting change in the cursor sharing behavior. I will test this and see how it behaves myself if I can finish my download. It is going really slow for now.

By the way the zip file is more than twice the size of the file for 10G R2. 10G R2 installation zip file was about 700MB while this is 1.7GB.

11G Available for Linux

11G for Linux is available for download here and I have just started downloading it.

At about the same time the first three parts of The Top New Features series by Arup Nanda has been published: database replay, partitioning and schema management. You can subscribe to this series' rss feed here.