Thursday Apr 25, 2013

'IS NULL' SQL Tuning

NULLFrequently at client sites some very slow queries contain the SQL involving the ‘IS NULL’ criteria in the where clause. It is commonly known Oracle does not store NULL values in indexes so even though an index may exist for the column it is NOT usable in this case. However there is a solution to this situation and FULL table scans can be avoided!

Example: SQL> Select name from emp where dept_id is null;

So in the above example even if the dept_id is indexed on the table emp, due to the ‘IS NULL’ criteria it will NOT be used.

Many developers believe that this type of statement cannot be tuned and that a FULL table scan is the only option. However here is a solution to this issue, simply create an appropriate index but add in an additional constant value to the end of the index so that now NULL values are actually stored!

Example: SQL> create index E1 on EMP (DEPT_ID, -1);

Running an explain plan and executing the SQL it can be seen that the new index will now be used as NULL values are now indexed.

Real life example: At a particular customer site there was a situation where a table had over 11 million rows. A SQL statement had a lot of table joins but only 2 constraints in the where clause as below.

AND T28.PRIV_FLG = ‘N’

AND T28.INTEGRTION_ID IS NULL

From analyzing the table almost every row had the PRIV_FLG = ‘N’ so that was not going to help, however looking at the integration_id from the 11 million rows, only 51,167 were null values. The field 'integration_id' was already indexed however this would not be used due to only wanting NULL values. By indexing as in the above example the new index helped optimize the query significantly as the number of rows in the driving table had been significantly reduced without any full table scans!

Thursday Apr 18, 2013

Changing the Explain plan for one SQL statement to another with NO code changes or Hints

CheetahOn a client site and had an issue with a 3rd party product to do with an inbuilt query executing from an application. A specific query was taking forever to run and the execution plan was not ideal.  Nothing obvious had shown anything useful such as hints or indexes etc. 

Obviously as the code is submitted from a product itself therefore it could not be changed!  Table and Index statistics were up to date and the query had always been pretty poor in performance when examining the AWR history.

However during an initial analysis of the code a much better performing execution plan was located, the difference between the 2 pieces of code were simply that one was using a bind variable and the second was a hard coded value given as a test case.  There are documented examples of how to simulate code in PLSQL with bind variables so that this issue does not actually occur, however the interesting thing was that without the bind variable the plan was just what the customer wanted.

 The real answer to the above question would be to look at dynamic sampling / statistics gathering etc to ensure nothing is being influenced due to the bind variables (such as bind variable peeking or histograms etc), however a really simple solution was how to get the explain plan of SQL A over to SQL B with no actual code change.

There is a blog entry already showing how to introduce hints and also parallelism when a code change is not possible:  https://blogs.oracle.com/Bakers_Byte/entry/applying_a_hint_to_sql

However this is a test case where we simply want to link the execution plan of SQL A to that of SQL B.

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

  1. The first thing required is to know the SQL_ID for the SQL that you wish to change the explain plan. (poor performer)
  2. The Second thing required to know is the SQL_ID and Plan_Hash_Value for the SQL that has the desired execution plan.

 Then it is simply a matter of running the following PL/SQL block:

The above once executed created a baseline entry in dba_sql_baselines.  By executing the following query this could be seen :

SQLPLUS > select fixed,accepted,enabled,created,sql_text,sql_handle from dba_sql_plan_baselines;

Other useful baseline queries are:

SQLPLUS> select * from table(dbms_xplan.display_cursor(‘&1’,&2));

NOTE:  above needs &1 set to the sql_id and &2 the child number.  At the end of the explain plan you can see if the baseline has been used or not.

SQLPLUS> select * from table(dbms_xplan.display_sql_plan_baseline(sql_handle=>’xxxxxx’, format=>’basic’));

NOTE:   xxxxxx is the sql_handle from dba_sql_plan_baselines.

As it could be seen the baseline was taken and being used so the final step was also to fix the baseline:

If the baseline is not applicable anymore or did not work then it is easy to tidy up and remove it as below:

Conclusion: Although the long term solution is still to review the code and database to see really why the bind variable execution was giving a considerably poorer execution plan to that of the hard coded SQL. The issue was at least resolved with a nice work around due to being able to use a baseline and influence the explain plan as desired.

Friday Mar 15, 2013

Applying a Parallel Hint to SQL Code that cannot change

PerformanceLast night during investigation of a performance issue for a client it was found that due to significant growth in the database a select query was suddenly taking hours to run instead of minutes. Obvious things like statistics and the database were checked and it was clear to see the SQL code needed a review. However this code is from a vendor and cannot be changed so the client was interested in anything that could be done to assist them in the short term. This blog update covers the analysis and final answer which was to introduce the parallel hint into the SQL code with NO actual code change using the ‘ dbms_sqldiag’ package and ‘i_create_patch’ procedure.

The first answer and quickest to implement was to execute the SQL tuning advisor against the code and that prompted a couple of SQL profiles for answers. The most positive of these was a PX_PROFILE which would introduce parallelism of a DOP (48) into the query and although warning about resource increases it looked good enough to investigate further. To take a stage forward the query was tested using the PARALLEL hint to see how much benefit parallelism would introduce. It should be noted that care is required before jumping into parallelism as a solution. For example in Oracle RAC what is the value of ‘parallel_force_local’ and what is the available CPU, memory, ‘large_pool’ etc.

Developers executed the code from SQL developer using the PARALLEL hint as below to see the real effect of the parallelism suggestion.

Note this is not the actual code but just an example of using the PARALLEL hint.

Select /*+PARALLEL */ count(*) from test_table;

The test was very positive with execution now taking around four minutes to complete which was a large difference from over 2 hours previously. However examining the explain plan with the PARALLEL hint showed it was very different to that of the explain plan for the SQL profile produced by the SQL tuning advisor. This meant the SQL profile was not the answer as the requested approach was now to get the PARALLEL hint implemented as tested and proven and not the execution as the SQL profile suggested with the PX_PROFILE.

Easy, create a baseline was the next answer to adopt. Baselines are very easy to generate from the SQL cache linking the execution plan for the SQL with the hint to that of the SQL without the hint. References on how to do this are contained in the acknowledgements.

After the baseline was introduced the code was re-tested to ensure correct results. Although the baseline was enabled and accepted the original code refused to implement the new baseline. The execution was not going to parallel execution as desired. What was wrong?

Researching this further, the reason why the baseline was not being selected is that the PARALLEL hint does not make it into the plan hints of the baseline but is obviously essential to force the parallel plan and get the appropriate hash plan value. Again this is not going to be discussed further here as it is available in other blog entries elsewhere, see acknowledgements.

So a profile and a baseline were now ruled out as possible solutions. It was then that an alternative arose called SQL PATCH. There are some pre-requisites in what SQL PATCH will and won’t do as also referenced in the acknowledgements section. However for a straight /*+PARALLEL */ hint it worked a treat!

To add the parallel hint to the query with SQL PATCH:

DECLARE

Sqltext clob;

BEGIN

SELECT sql_text into sqltext FROM DBA_HIST_SQLTEXT WHERE sql_id =’9h8a1m1a4fwzc’;

DBMS_SQLDIAG_INTERNAL.I_CREATE_PATCH(Sql_text => sqltext, Hint_text=> ‘PARALLEL’,Name=>’PARALLEL Hint Patch’);

END;

/

NOTE: The SQL text was obtained from the view DBA_HIST_SQLTEXT with the sql_id as it was a large query.

After submitting the above and testing with explain plan and execution finally we have the PARALLEL hint being used as was desired without any code change. In the explain plan there is even a note showing the name as above which aids in identification later.

If required at a later stage to drop the above it can be implemented with the code as below:

BEGIN

     DBMS_SQLDIAG.DROP_SQL_PATCH(name=>’PARALLEL Hint Patch’);

END;

/

Acknowledgements:

The following blogs were referenced in this research piece:

1. http://metekarar.blogspot.com.au/2012/07/adding-hints-with-sql-patch.html

2. http://orastory.wordpress.com/2013/03/09/sql-patch-iii-plus-parallel-baselines/

3. http://orastory.wordpress.com/2011/10/13/no-need-to-change-source-code-hint-it-using-a-baseline/

4. http://docs.oracle.com/cd/B28359_01/server.111/b28274/sql_tune.html

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
« April 2014
SunMonTueWedThuFriSat
  
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
   
       
Today