Tuesday May 28, 2013

Oracle SQL Profile Internals

Black Box

It is very easy to pick a piece of poor performing code either by SQL text or SQL ID and then execute the Oracle SQL tuning advisor against that code. When a SQL profile is recommended though, how many people know what has actually been suggested by the profile internally?

This update covers a little known database view DBMSHSXP_SQL_PROFILE_ATTR which when supplied with the SQL profile name displays the internal hints that the profile is suggesting in XML format. This provides the missing piece to understanding what the SQL profile.

As always, here is an example;

1.  Create SQL tuning task on the statement. This can be done by SQL_ID or by SQL text.

     SQL_ID:

            DECLARE
                  l_sql_tune_task_id varchar2(100);
            BEGIN
                  l_sql_tune_task_id := dbms_sqltune.create_tuning_task(
                                  begin_snap=>1234,
                                  end_snap=>1235,
                                  sql_id=> '9yycxkm1kb8jn',
                                  scope=>dbms_sqltune.scope_comprehensive,
                                  time_limit=>600,
                                  task_name=>'SQLID',
                                  description=>'Tuning Example by SQL ID');
            END;
             /

SQL TEXT:

DECLARE
l_sql_tune_task_id      varchar2(100);
my_sqltext              CLOB;
BEGIN
     my_sqltext := ‘select count(*) from scott.emp’;

     l_sql_tune_task_id := dbms_sqltune.create_tuning_task(
                          sql_text=> my_sqltext,
                          user_name=>’SCOTT’
                          scope=>dbms_sqltune.scope_comprehensive,
                          time_limit=>600,
                          task_name=>'SQLTEXT',
                          description=>'Tuning Example by SQL ID');
END;
/

2.  Now Execute the SQL tuning task created in Step 1.

SQL>exec dbms_sqltune.execute_tuning_task(task_name=>’SQLID’);

OR

            SQL>exec dbms_sqltune.execute_tuning_task(task_name=>’SQLTEXT’;

3.  Now run the report of the SQL tuning task recommendations. -

SQL>spool results.out

                       set long 999999999
                       set lines 80
                       set pages 0

SQL> select dbms_sqltune.report_tuning_task(‘SQLTEXT’) as recommended from dual;

See below some sample output recommending a SQL profile for the statement.


3- SQL Profile Finding (see explain plans section below)
--------------------------------------------------------
A potentially better execution plan was found for this statement.
Recommendation (estimated benefit: 98.05%)
-----------------------------------------
- Consider accepting the recommended SQL profile.
execute dbms_sqltune.accept_sql_profile(task_name => 'SQLTEXT', task_owner => 'SYS', replace => TRUE);

To actually accept the SQL profile

 SQL>execute dbms_sqltune.accept_sql_profile(task_name => 'SQLTEXT',task_owner => 'SYS', replace => TRUE);

To
check that profile has been saved in the data dictionary

SQL> SELECT NAME, SQL_TEXT
FROM DBA_SQL_PROFILES
WHERE SQL_TEXT LIKE 'select count(*) from Scott.emp%';

NAME SQL_TEXT
-----------------------------                     ------------------------------------------------            

SYS_SQLPROF_014c9e57e27g0006 select count(*) from scott.emp

To drop the sql tuning session if not applicable, or if the profile is implemented and it is wanted to remove, then  dbms_sqltune.drop_sql_profile can be executed also.

SQL> execute dbms_sqltune.drop_tuning_task(task_name=>’SQLTEXT’);

 4.  Finally to display the hints suggested by the profile for further analysis

 NOTE: Under Oracle 10g SQL profiles were stored in : SQLPROF$ and SQLPROF$ATTR.  However in 11g SQL profiles are stored in SQLOBJ$ and SQLOBJ$DATA and DBMSHSXP_SQL_PROFILE_ATTR. It is also necessary to convert the format as they are stored in XML format.

 SQL> SELECT *
FROM DBMSHSXP_SQL_PROFILE_ATTR

WHERE PROFILE_NAME='
SYS_SQLPROF_014c9e57e27g0006’;

 PROFILE_NAME COMP_DATA
 -----------------------------                       ------------------------------------------------

 SYS_SQLPROF_014c9e57e27g0006 <outline_data><hint><![CDATA[PARALLEL]]></hint></outline_data>

So it can be seen by analysis of the above that the Parallel hint has been suggested by the profile. However if other recommendations were made these in turn can be analyzed for relevance and understanding for further tuning.

  Some examples of other types of hint are:

 OPT_ESTIMATE(@"SEL$1", TABLE, "EMP"@"SEL$1", SCALE_ROWS=0.018)]]>

  The scale_rows figure is multiplied by the number of rows in the table to get an estimate on the number of rows to be retrieved by the query and supply to the optimizer.

 COLUMN_STATS("SCOTT"."EMP", "ID", scale, length=3)]]>

  The above is storing the estimate on the average column length of a field.

 TABLE_STATS("SCOTT"."EMP", scale, blocks=10123 rows=988.542)]]>

  The above is displaying the number of rows and blocks to the optimizer.

 IGNORE_OPTIM_EMBEDDED_HINTS]]>

  The above tells the optimizer to ignore any hints given in the statement itself.

 OPTIMIZER_FEATURES_ENABLE('9.0.0')]]>

The above tells the optimizer to execute the statement with features enabled in version 9.0.0

Monday May 06, 2013

Database Partitioning A Source Table With Golden Gate Replication In Place

GoldenGateAt a client site there was a requirement for performance of a SIEBEL database to partition an existing source table that happened to be also replicated with golden gate. The requirement was only to partition the source table and NOT the replicated target table.  During this process an issue occurred with duplicate data being replicated after the database partitioning occurred.  This article covers the issue found in the process and a workaround to that issue using a simple test case to demonstrate.  It firstly recreates the issue then secondly explains the root cause and solution.

Please note that in this example of golden gate, 'DDL' replication is NOT used.  As stated in this case the partitioning is only at the source side only.  It is a simple extract of the table SCOTT.EMP containing 14 rows and replicating to a new schema / table in the same database called REP.EMP.  The primary key is defined on the EMP table at both sites based on the EMPNO field as is default in the SCOTT sample schema.


The document also does not cover set up for this replication as it focuses on what happens when the source table is changed into a partitioned table from a non partitioned table and replication is in place.  However it does cover some basic outline steps for setting up the test-case.

Please Note these scripts were written only for demonstration purposes. They are not optimized and they have almost no error checking, so be careful!

Download The Full PDF here: Partitioning A Source_database_Table With_Golden_Gate_Replication.pdf

About

About Me Image
Andy Baker, Senior Principal Consultant for Oracle Consulting Services (@Bakers_byte), shares his news, views and ideas about the Oracle Database with a focus on innovation and emerging technologies.

Search

Archives
« May 2013 »
SunMonTueWedThuFriSat
   
1
2
3
4
5
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
29
30
31
 
       
Today