Chapter 11

Overview

Oracle8i allows a developer to save a set of 'hints to the server' describing how to execute a specific SQL statement in the database. This feature is referred to as Optimizer Plan Stability and is implemented via a stored query plan outline, similar to an outline for a book. This chapter takes a detailed look at this feature, covering:

  • Why you may want to use Optimizer Plan Stability in your applications, and the typical scenarios where it may be useful.

  • Some interesting alternative uses of this feature as well C uses not necessarily intended by the developers of this feature.

  • How to implement the feature and how to manage the stored plans in the database, via both DDL and the OUTLN_PKG package.

  • Important caveats, including the importance of case sensitivity, issues with ALTER SESSION, OR-Expansion, and performance.

  • Errors you may encounter, and what to do about them, including cases where no options are specified for ALTER OUTLINE, or if an outline already exists.

In order to execute the examples in this chapter you will need to have Oracle8i release 1 (version 8.1.5) or higher. Additionally, this must be an Enterprise or Personal version of Oracle8i as the Optimizer Plan Stability feature is not included in the Standard Edition.

An Overview of the Feature

For a given query or set of SQL statements, Optimizer Plan Stability allows us to save the optimal set of hints for their run-time execution, without having to 'hint' the query ourselves in the application. This allows us to:

  1. Develop an application.

  2. Test and tune the queries within it.

  3. Have those finely tuned plans saved into the database for later use by the optimizer.

This feature helps to protect us from many changes to the underlying database. Typical changes in the underlying database that could cause query plans to change dramatically, include:

  • Re-analyzing a table after changing the amount of data in it.

  • Re-analyzing a table after changing the distribution of data in it.

  • Re-analyzing the table using different parameters or methods.

  • Changing various init.ora parameters that affect the optimizer's behavior such as db_block_buffers.

  • Adding indexes.

  • Upgrading the Oracle software to a new release.

Using Optimizer Plan Stability, however, we can preserve our existing execution plans, and isolate our application from these changes.

It should be noted that, in most cases, it is desirable that the query plans change over time in reaction to the events in the above list. If the distribution of data changes radically in a column, the optimizer is designed to change its query plan to accommodate this. If an index is added, the optimizer is designed to recognize that, and take advantage of it. Optimizer Plan Stability can be used to help prevent these changes from happening, which might be useful in an environment where changes must be made gradually, after testing. For example, before permitting the general use of a new index, you might want to test queries that may be affected one-by-one to ensure that the addition of that index does not adversely affect some other system component. The same would be true of a change to an initialization parameter or of a database upgrade.

A key point to remember about Optimizer Plan Stability is that it is implemented via hints. Hints are not mandates; hints are not rules. While the hinting mechanism used by Optimizer Plan Stability is a stronger one than is exposed to us via the documented hinting mechanism, the optimizer is still, as always, free to follow them or not at run-time. This is a double-edged sword - it sounds like a defect but in reality it is a feature. If changes are made to the database that render a set of hints obsolete (as will happen if you, say, drop an index) then Oracle will ignore the hints and generate the best plan it can.

A quick example will demonstrate what Optimizer Plan Stability offers. Below, we will see one method we can use to save a stored outline for a query. After storing the outline, we will make certain changes to the database (we will analyze the table) that causes the plan to change. Lastly, we'll see how, by enabling optimizer plan stability, we can have Oracle use the plan we stored in the first place - even in light of the changes we made. First, we create a copy of the SCOTT.EMP table and set up a primary key on it:

tkyte@TKYTE816> create table emp   2  as   3  select ename, empno from scott.emp group by ename, empno   4  /      Table created.      tkyte@TKYTE816> alter table emp   2  add constraint emp_pk   3  primary key(empno)   4  /      Table altered.      

If you do not have access to the EMP table, you will need to have SELECT privileges granted to you. The primary key we created is used in the example; we generate a query that will use it. Next, we set the optimizer goal to CHOOSE:

tkyte@TKYTE816> alter session set optimizer_goal=choose   2  /      Session altered.      

This is done purely for the sake of consistency in running this example. Of course, in the absence of any statistics, the rule-based optimizer (RBO) is invoked. However, if your optimizer goal is set to some other value, FIRST_ROWS for example, the Cost Based Optimizer will be invoked and the change we make to the database later might not have any effect on the query plan. Finally, here is the execution plan for our query:

tkyte@TKYTE816> set autotrace traceonly explain tkyte@TKYTE816> select empno, ename from emp where empno > 0      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE    1    0   TABLE ACCESS (BY INDEX ROWID) OF 'EMP'    2    1     INDEX (RANGE SCAN) OF 'EMP_PK' (UNIQUE) 

Let's assume this query comes from an interactive application where the end user would like to get some data very quickly, and the index access does this for us nicely. We are happy with this plan, and would like it to always be used, so the next thing to do is to create an outline for it. We create the outline explicitly (we can also create them implicitly, as is demonstrated in the A Method to Implement Tuning section):

tkyte@TKYTE816> create or replace outline MyOutline   2  for category mycategory   3  ON   4  select empno, ename from emp where empno > 0   5  /      Outline created. 

The CREATE OR REPLACE OUTLINE command created our query outline, and stored it in the database (where it is stored and how, will be explained later in this chapter). Since we explicitly created the outline, we had the ability to name it (MYOUTLINE). Additionally, we placed this query outline into a specific category (MYCATEGORY).

Before moving on, it's worth pointing out that if you are working along with this example you may receive the following error from the above CREATE OUTLINE command:

select empno, ename from emp where empno > 0                          * ERROR at line 4: ORA-18005: create any outline privilege is required for this operation 

If so, you need to have the DBA grant you the CREATE ANY OUTLINE privilege. All of the necessary privileges you may need for creating and manipulating outlines are covered in the How Optimizer Plan Stability Works section below.

OK, we have our outline that defines our required execution plan (it uses our index). Let's now make a change to the database - we will simply analyze our table:

tkyte@TKYTE816> analyze table emp compute statistics   2  /      Table analyzed.      

Now, let's take another look at the execution plan for our query:

tkyte@TKYTE816> set autotrace traceonly explain tkyte@TKYTE816> select empno, ename from emp where empno > 0   2  /      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=14 Bytes=112)    1    0   TABLE ACCESS (FULL) OF 'EMP' (Cost=1 Card=14 Bytes=112) 

Instead of using our index, as we were with the RBO, we now have the statistics to allow the CBO to be invoked, and it is choosing a full table scan. The CBO has in fact chosen the correct plan. There are only 14 rows and it understands that all of them satisfy the predicate in this case. However, for our particular application, we still wish to use the index. In order to get back to our preferred plan, we need to use the Optimizer Plan Stability feature. To do that, we simply issue the following command:

tkyte@TKYTE816> alter session set use_stored_outlines = mycategory   2  /      Session altered. 

This enforces use of our MYCATEGORY stored outline. If we take a look at our execution plan:

tkyte@TKYTE816> set autotrace traceonly explain tkyte@TKYTE816> select empno, ename from emp where empno > 0   2  /      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=14 Bytes=112)    1    0   TABLE ACCESS (BY INDEX ROWID) OF 'EMP' (Cost=2 Card=14    2    1     INDEX (RANGE SCAN) OF 'EMP_PK' (UNIQUE) (Cost=1 Card=14) 

We find that we are back to using the original plan with the index again. This is the goal of optimizer plan stability - to allow you to 'freeze' the query plans for your finely tuned application as much as possible. It insulates you from changes to optimizer plans that take place at the database level (such as a DBA analyzing your tables, or changing some init.ora parameters, or upgrading the software). Like most features, it's a double-edged sword. The fact that it insulates you from external changes may be both good and bad. It can be good in that you will get performance results that are consistent over time (since your plan never changes). However, it could be bad in that you may miss out on a newer plan that could cause the query to run even faster.

Uses of Optimizer Plan Stability

In this section, we will explore various scenarios where you might choose to use this feature. We will use many of the features of outline generation in this section with minimal explanation, the details of how to use the commands, create outlines, manage them, and so on are in the later sections that follow.

A Method to Implement Tuning

Many times, people ask 'How can I hint a query in an existing application without actually hinting it?' Generally, they have access only to the binary code for the application and cannot make modifications to it, but need to be able to change the plan without modifying the application itself.

These people know the problem query, and have found that, through various session environment settings, the query can perform well. If they could inject a simple ALTER SESSION into the application (to enable or disable a hash join for example) or place a simple hint into the query (for example, /*+ RULE */ or /*+ ALL_ROWS */) it would run much better. Optimizer Plan Stability will give you this capability. You can independently create and store optimal query outlines outside of the existing application. You might utilize an ON LOGON database trigger (a method to run a snippet of code upon a user login to the database) or similar mechanism, causing the existing application to pick up your stored outline transparently.

For example, let's say you used SQL_TRACE to capture the SQL being performed by an application or report. You've used the TKPROF tool to analyze the resulting trace file and have found a query that runs very poorly. You've read through the Oracle-supplied Designing and Tuning for Performance guide, and tried out the hints that are documented. You find that if you execute the query with FIRST_ROWS optimization enabled, it runs very well, but if you enable FIRST_ROWS for the entire application, it affects overall performance in a very bad way. So, we'd like to have FIRST_ROWS optimization for this one query, and the default CHOOSE optimization for the remainder. Normally, we would just add a /*+ FIRST_ROWS */ hint to the query and be done with it. We cannot do this though, since we cannot modify the query. What we can do now is use the CREATE OUTLINE command, exactly as we did above, to create a named outline and then place it into the DEFAULT set of outlines, or some named category. We will set our environment such that the plan we want gets generated. For example, in this case we would have issued ALTER SESSION set optimizer_goal = first_rows, and then created the query outline. Then, we could utilize an ON LOGON trigger to enable this stored outline whenever the users of this application logged in.

This can be a little tricky to do since the query text for which we must generate the stored outline, must be exactly the same query text, byte-for-byte, as is embedded in the application itself. What we'll do here is demonstrate, in a step-by-step fashion, how we might perform this operation in the easiest way possible. We'll continue to use the EMP table query from the previous example C this is the query that we want to execute with FIRST_ROWS. The rest of the application should execute under CHOOSE. We have an 'application' that contains the following code:

tkyte@TKYTE816> create or replace procedure show_emps   2  as   3  begin   4      for x in ( select ename, empno   5                   from emp   6                  where empno > 0 )   7      loop   8          dbms_output.put_line( x.empno || ',' || x.ename );   9      end loop;  10  end;  11  /      Procedure created. 

Now, we've executed this procedure using SQL_TRACE and determined from the TKPROF report that it is using an undesirable plan (See Chapter 10 on Tuning Strategies and Tools for more information on SQL_TRACE and TKPROF, and how you might enable them in various environments). Here, we will just use a simple ALTER SESSION command since it is a PL/SQL routine that we can run in SQL*PLUS:

tkyte@TKYTE816> alter session set sql_trace=true;      Session altered.      tkyte@TKYTE816> exec show_emps 7876,ADAMS ... 7521,WARD      PL/SQL procedure successfully completed. 

Next, we run TKPROF on the resulting trace:

SELECT ENAME,EMPNO FROM  EMP  WHERE EMPNO > 0      call     count       cpu    elapsed  disk      query    current        rows ------- ------  -------- ---------- ----- ---------- ----------  ---------- Parse        2      0.01       0.01     0          0          0           0      Execute      2      0.00       0.00     0          0          0           0 Fetch       30      0.00       0.00     0         36         24          28 ------- ------  -------- ---------- ----- ---------- ----------  ---------- total       34      0.01       0.01     0         36         24          28      Misses in library cache during parse: 1 Optimizer goal: CHOOSE Parsing user id: 224     (recursive depth: 1)      Rows     Row Source Operation -------  ---------------------------------------------------      14  TABLE ACCESS FULL EMP 

The first thing to notice here is that the query in the TKPROF looks very different (in format) from the query in the application. This is a side effect of how PL/SQL processes SQL: it rewrites all static SQL, and the resulting query may look very different from the actual query in the original source code. When we create the stored outline, we must make sure we use the query that the database actually uses because Optimizer Plan Stability does exact string matching only C we must use the exact query the database sees, down to spaces, tabs and newlines. However, neither the text of the query in the PL/SQL routine nor the text in the TKPROF report is what we want! Fortunately, we can use the stored outline mechanisms themselves to capture the query we really need to work with. We will enable implicit stored outline generation, and this will capture the actual SQL text into a database table for us:

tkyte@TKYTE816> alter session set create_stored_outlines = hr_application;      Session altered.      tkyte@TKYTE816> exec show_emps 7876,ADAMS ... 7521,WARD      PL/SQL procedure successfully completed.      tkyte@TKYTE816> alter session set create_stored_outlines = FALSE;      Session altered.      tkyte@TKYTE816> set long 50000 tkyte@TKYTE816> select name, sql_text   2    from user_outlines   3   where category = 'HR_APPLICATION'   4  /      NAME                          SQL_TEXT ----------------------------- ---------------------------------------------- SYS_OUTLINE_0104120951400008  SELECT ENAME,EMPNO   FROM EMP  WHERE EMPNO > 0 

We used the ALTER SESSION command to enable automatic stored outline generation for a category named HR_APPLICATION, and ran our application.

The SET LONG command was used to ensure that SQL*PLUS would show us the entire SQL query; by default it would only show us the first 80 bytes.

We could have used an ON LOGON database trigger, such as the following, to achieve the same result:

tkyte@TKYTE816> create or replace trigger tkyte_logon   2  after logon on database   3  begin   4     if ( user = 'TKYTE' ) then   5        execute immediate   6               'alter session set use_stored_outlines = hr_application';   7     end if;   8  end;   9  /      Trigger created. 
Note 

You need the privileges CREATE TRIGGER and ADMINISTER DATABASE TRIGGER in order to create a LOGON trigger. Additionally, the owner of this trigger needs the ALTER SESSION privilege granted directly to them, rather than via a role.

You would adopt this approach for an application where you cannot issue the ALTER SESSION command in any other fashion.

So, now that we have our query we are ready to generate the stored outline with the plan we would like to have the query use. It is interesting to notice that it is different from the query in the PL/SQL code C it is all in uppercase. It is also different from the query in the TKPROF report C that one had newlines in it. Since stored outline usage is very picky about using the exact same query, I'm going to show how to change the set of hints associated with outline we've captured in the easiest way possible. Notice how, in the above output from the query on the USER_OUTLINES view, we selected the NAME and the SQL_TEXT so we can easily identify the query we want to fix and now we know the stored outline name, SYS_OUTLINE_0104120951400008.

So, we can change our environment to FIRST_ROWS, rebuild our named outline, and we are done:

tkyte@TKYTE816> alter session set optimizer_goal=first_rows   2  /      Session altered.      tkyte@TKYTE816> alter outline SYS_OUTLINE_0104120951400008 rebuild   2  /      Outline altered.      tkyte@TKYTE816> alter session set optimizer_goal=CHOOSE;      Session altered. 

We started by setting the optimizer goal to FIRST_ROWS instead of CHOOSE. We know that if we execute our query under FIRST_ROWS optimization, it gets the plan we want (we know this because that is the scenario we set up in this case C we would have discovered it through tuning and testing). Instead of executing the query now, we simply REBUILD the outline C the REBUILD will use our current environment to generate the plan for us.

Now to see that this actually works, we need to enable this category of outlines. For demonstration purposes, we will use a simple ALTER SESSION command interactively, but to make this transparent you might use the ON LOGON trigger to set this immediately upon logging onto the database. To verify this fix is in place, we will re-run the application:

tkyte@TKYTE816> alter session set optimizer_goal=CHOOSE;      Session altered.      tkyte@TKYTE816> alter session set USE_STORED_OUTLINES = hr_application;      Session altered.      tkyte@TKYTE816> alter session set sql_trace=true;      Session altered.      tkyte@TKYTE816> exec show_emps 7369,SMITH ... 7934,MILLER      PL/SQL procedure successfully completed. 

We set the optimizer goal back to the default value, directed Oracle to use the stored outlines in the category HR_APPLICATION, and ran the application. Now the TKPROF report will show us:

SELECT ENAME,EMPNO FROM  EMP  WHERE EMPNO > 0           call     count       cpu    elapsed  disk      query    current        rows ------- ------  -------- ---------- ----- ---------- ----------  ---------- Parse        1      0.01       0.01     0          0          1           0 Execute      1      0.00       0.00     0          0          0           0 Fetch       15      0.00       0.00     0         28          0          14 ------- ------  -------- ---------- ----- ---------- ----------  ---------- total       17      0.01       0.01     0         28          1          14      Misses in library cache during parse: 1 Optimizer goal: CHOOSE Parsing user id: 224     (recursive depth: 1)      Rows     Row Source Operation -------  ---------------------------------------------------      14  TABLE ACCESS BY INDEX ROWID EMP      15   INDEX RANGE SCAN (object id 28094) 

This proves that our plan is now in effect. When we execute our application, this ALTER SESSION SET USE_STORED_OUTLINE has enabled the outlines we've stored. The one exact query we targeted will be optimized using the hints we stored C the hints generated with the FIRST_ROWS optimizer mode. The remaining queries in the application will be optimized exactly as they were before.

A Development Tool

Let's say you are building a new application that is to be delivered to lots of people. You are building the next 'killer app'. You will have little or no control over the target database environment C you might be installed into an instance that is 'all your own,' or you may be installed into an instance that has many other applications already running in it. These databases will have various init.ora settings that affect the optimizer such as DB_BLOCK_BUFFERS, DB_FILE_MULTIBLOCK_READ_COUNT, HASH_MULTIBLOCK_IO_COUNT, OPTIMIZER_GOAL, HASH_JOIN_ENABLED, and so on. They may or may not have parallel query enabled. They may or may not have a large SGA on a big machine. They might have version 8.1.6.1, 8.1.7, or 8.1.6.2. And so on. There are many factors that may influence the plan generated by the optimizer.

You will go to great lengths while developing your applications to get them to access the data in 'just the right way'. In your development tests and scaling tests, against real live large data sets on your machines, the application runs extremely well. Everything runs as expected. So why do people call your help desk with performance-related issues? It is because on their own machines, with their own configurations, the query plans are coming out slightly differently.

You can use Optimizer Plan Stability to level the playing field here. Once you have tuned your application in-house, tested it thoroughly against real data (appropriate number and mix of rows), the last step to undertake before shipping the application is to generate query outlines for all of your queries. This can be done very easily using the ON LOGON trigger, once again, but this time coding something like this:

sys@TKYTE816> create or replace trigger tkyte_logon   2  after logon on database   3  begin   4     if ( user = 'TKYTE' ) then   5        execute immediate   6               'alter session set create_stored_outlines = KillerApp';   7     end if;   8  end;   9  /      Trigger created. 
Note 

This was executed as the user SYS who, by default, has all of the necessary privileges to do this trigger.

Now, when I log in, every single query I execute will create an outline for me, name it and store it in the category KillerApp. I will run the full battery of tests against the application, exercising all of the SQL and, as I do that, I'm collecting the outlines for every query in the application. Once this is done, I can use the Oracle utility, EXP, to export my outlines, and install them as part of my import, using the utility IMP (this is discussed later in the chapter, in the section Moving Outlines from Database to Database). The applications we wrote will always issue the following command, right after they connect:

alter session set use_stored_outlines = KillerApp; 

In this way, I know for sure that the query plan I worked so hard to achieve is being used, regardless of the settings on my customers' machines. This makes sense not just for 'external' customers, but also when moving an application from the test database instance, to the production instance. This will cut way down the number of times you hear 'Well it runs great in the test instance, but when we move it to the production instance it goes really slow'. This statement is usually followed by 'Both instances are exactly the same'. Then you discover they have different amounts of RAM, CPUs and their init.ora files are different to reflect the different hardware configuration. Any one of these factors can, and will, influence the optimizer, leading to different plans. Optimizer Plan Stability will avoid this issue altogether.

It should be noted however, that you might be missing out on the benefits of the latest and greatest optimizer enhancements. If you have installed new software, new features, it would be a good idea to disable this feature every now and again during the development and testing phase of your application, so that you can identify queries that would execute quicker with some new plan that the optimizer can come up with.

To See the Indexes Used

This is not actually one of the intended uses of stored outlines, more of a side effect C but, hey, it works! A frequently asked question is 'I have lots and lots of indexes in my database and I'm sure some of them are not being used, but I'm not sure which ones. How can I tell?' Well, one way is via the stored outlines C they'll list the name of every index they use in a query access plan. If you use an ON LOGON trigger to enable automatic outline generation, run your system for a while, and then disable it C you'll have a fairly inclusive list of what indexes are used in the system (and by which queries). As we see below, all of the 'hints' that stored outlines use are stored in a data dictionary table. It becomes very easy to see what indexes are used (and by what queries) and which are not. For example, using the output of our two examples above, we can see which queries use the index EMP_PK we have created in our database via:

tkyte@TKYTE816> select name, hint   2  from user_outline_hints   3  where hint like 'INDEX%EMP_PK%'   4  /      NAME            HINT --------------- -------------------- MYOUTLINE       INDEX(EMP EMP_PK) FIRST_ROWS_EMP  INDEX(EMP EMP_PK) 

We can use the NAME column from this query to go back to the actual SQL query stored in USER_OUTLINES, to see the original query text that is making use of this index.

To See what SQL is Executed by an Application

Again, this is a side effect rather than one of the actual intended uses of stored outlines, but it works. Frequently, people want to know what SQL their application actually executes. They cannot modify the application and setting SQL_TRACE ON is far too costly. Using an ON LOGON trigger for some users of the application, we can automatically capture, into the OUTLINE tables, all of the SQL the application executes at run-time. We can use this for tuning or analysis later.

You should be aware that this would only capture SQL as it is executed. In order to see an exhaustive list of the SQL an application might issue, you must cause that application to execute all of its SQL and this will entail using every feature and function in every combination.

How Optimizer Plan Stability Works

Optimizer Plan Stability works via the Oracle 'hinting' mechanism. Using our previous EMP example, we will be able to look at the hints that were stored for our query, and how they would be applied at run-time. We'll also look at the OUTLN schema, which holds all stored query outlines and their hints.

The first step in getting Optimizer Plan Stability working is to collect a query outline. Since we have already done that in the previous example, via the CREATE OUTLINE command, we'll use it here to look at how the database processes these outlines.

OUTLINES and OUTLINE_HINTS

There are only two views to consider with query outlines and they exhibit a master-detail relationship. The master table is the OUTLINES table (of which there are the three usual version: DBA_, ALL_, and USER_). The detail table is OUTLINE_HINTS (with, again, the three normal variants). The following sections explain what each of these are and how they are used:

The _OUTLINES Views

These views show the number of stored outlines in the database. DBA_OUTLINES has an entry for each and every stored outline by user, whereas ALL_ and USER_OUTLINES will only expose the rows relevant to the current user (the outlines they have created). Since DBA_OUTLINES and USER_OUTLINES only differ by one column (the DBA table has an OWNER column representing the schema that created the outline), we'll look at DBA_OUTLINES:

So, for example, after executing our example queries from above, we have in USER_OUTLINES, the following information:

tkyte@TKYTE816> select * from user_outlines;      NAME           CATEGORY       USED TIMESTAMP VERSION   SQL_TEXT -------------- -------------- ---- --------- --------- --------------------- MYOUTLINE      MYCATEGORY     USED 11-APR-01 8.1.6.0.0 select empno, ename                                                        from emp where empno                                                        > 0      FIRST_ROWS_EMP HR_APPLICATION USED 12-APR-01 8.1.6.0.0 SELECT ENAME,EMPNO                                                        FROM EMP  WHERE EMPNO                                                        > 0 

This shows all of the described information, as expected.

The _OUTLINE_HINTS Views

These views show the actual hints that must be applied to various internal phases of the developed query plan. The server internally rewrites our submitted query with these hints embedded in it in the appropriate locations, giving us the query plan we desire. We'll never see these hints in the query text itself - this is all done against internal query plan structures. Again, the only difference between the DBA_OUTLINE_HINTS view, and the USER_OUTLINE_HINTS and ALL_OUTLINE_HINTS views is the inclusion of an OWNER column identifying the schema that created the outline:

Looking at the results from out initial example, we have:

tkyte@TKYTE816> break on stage skip 1      tkyte@TKYTE816> select stage, name, node, join_pos, hint   2    from user_outline_hints   3   where name = 'MYOUTLINE'   4   order by stage   5  /      STAGE NAME      NODE   JOIN_POS HINT ----- --------- ---- ---------- --------------------     1 MYOUTLINE    1          0 NOREWRITE       MYOUTLINE    1          0 RULE          2 MYOUTLINE    1          0 NOREWRITE          3 MYOUTLINE    1          0 NO_EXPAND       MYOUTLINE    1          0 ORDERED       MYOUTLINE    1          0 NO_FACT(EMP)       MYOUTLINE    1          1 INDEX(EMP EMP_PK)      7 rows selected. 

This shows that at stage 1, the server will apply the NOREWRITE and RULE hints. The NOREWRITE hint will prevent query rewrite from taking place at run-time (if someone later adds a feature or enables a system/session parameter that could invoke QUERY_REWRITE). The RULE hint will use the rule-based optimizer at run-time, regardless of the current setting of the OPTIMIZER_GOAL or the presence (or lack thereof) of statistics on the table.

At stage 2, it will again prevent query rewrite from taking place. In stage 3, we are injecting the hints that will really make the query do what we want. It applies an ORDERED hint which makes use of the order of the tables in the FROM clause to join tables (since we accessed a single table in our example, this is somewhat superfluous). It applies a NO_EXPAND hint (this applies to object related conditions and since there are no object relations in our example, it is not really necessary). It then applies an internal, undocumented hint NO_FACT. Lastly, the access method hint INDEX() is to be used against table 1 (the JOIN_POS column), which is the EMP table using the index EMP_PK, our primary key.

So, those are the mechanics of Optimizer Plan Stability. You store a plan in a named or default category. At run-time your application chooses to 'use' a certain category of plans, and the database optimizer will merge the requisite hints into your query text to have the result plan come out the same way every time.

Creating Stored Outlines

There are two ways to generate plans. We've already loosely introduced them in the previous examples. One method is via SQL DDL, and the other is by setting a session state variable. We'll look at both and consider when each one might be used. In either case, however, you'll want to make sure the schema generating the outlines has the appropriate privileges needed to create and manage outlines.

Privileges Needed for Stored Outlines

When using stored outlines, there are four relevant privileges:

It should be noted that these are ANY privileges. This means that if you have the ability to CREATE OR REPLACE ANY outline, you have the ability to overwrite someone else's outline, without their permission. Outlines, unlike most other database objects, are not really owned by anyone. They have a creator, but not an owner in the normal sense. If you can drop your own outlines, then you can also (inadvertently) drop anyone else's outline, so care must be exercised with these privileges. See The Namespace of Outlines is Global in the Caveats section for more information on this.

Using DDL

In order to create stored outlines using DDL, we use a SQL command of the following structure:

CREATE <OR REPLACE> OUTLINE OUTLINE_NAME <FOR CATEGORY CATEGORY_NAME> ON STATEMENT_TO_STORE_OUTLINE_FOR 

Where:

Generating outlines via DDL is most useful if you have an application that stores all of its SQL statements externally. That is, you have a resource file of some sort that has all of the SQL you ever execute in it. In this case, it is a simple matter to generate a CREATE OUTLINE script from this resource file, and run it through the database. This ensures that you generate outlines for 100 percent of your queries (given that 100 percent of your queries exist in these resource files). It also safeguards against accidentally generating stored outlines for queries that are not relevant. For example, if you use the ON LOGON trigger and log into SQL*PLUS afterwards, you'll find that the queries SQL*PLUS runs on your behalf, have outlines generated for them.

Additionally, the DDL approach is useful when you have a small handful of individual queries for which you wish to generate outlines. For example, you might use this approach when using query outlines as a tuning tool. So, when you want to generate stored outlines for a small percentage of an application, you would use DDL to generate the outlines for just the queries you wanted, instead of every query you execute.

Using ALTER SESSION

This is a more general-purpose method for generating query outlines. It works in a similar manner to SQL_TRACE when tracing a program. From the time you issue an ALTER SESSION statement until you turn off the creation of stored outlines, every query you issue will have its outline saved (well, almost every query, see the Caveats section below for cases where your outline will not be saved).

You might use this method on any application where you want all of the plans to be stabilized. That is, when you want to know what the query plans for your SQL will be, regardless of the database version your application is installed in, regardless of the settings in the init.ora on that database, and so on. In order to do this for your application, you might utilize the ON LOGON trigger as demonstrated previously, and then fully exercise your entire application, executing every possible query. You would do this in your test database instance as part of your final testing before delivery. After you collect all of the plans, you would use the EXP tool to extract them, and utilize the IMP tool as part of your delivery mechanism. See Moving Outlines From Database to Database later for the exact details of that process.

You will also use this method when utilizing the database feature of auto binding. The Caveats section will go into more details on this feature, and its interaction with Optimizer Plan Stability.

The syntax of the ALTER SESSION method is very straightforward:

ALTER SESSION SET CREATE_STORED_OUTLINES = TRUE; ALTER SESSION SET CREATE_STORED_OUTLINES = FALSE; ALTER SESSION SET CREATE_STORED_OUTLINES = some_category_you_choose; 

If you set CREATE_STORED_OUTLINES to TRUE, then Oracle will generate stored outlines into the DEFAULT category. The DEFAULT category is simply a category named DEFAULT - it must be enabled, as any other category would be. Once you set CREATE_STORED_OUTLINES to FALSE, Oracle will cease generating stored outlines in your session.

By setting CREATE_STORED_OUTLINES to some_category_you_choose, Oracle will generate query outlines for all queries issued, and store them into that named category. This is the preferred way of using this method. It is recommended, for clarity, that your application use a category of its own, especially if you are going to install your application into a shared database that might have lots of other applications utilizing this feature. It will prevent conflicts between these applications, and make it clear to whom a given outline belongs.

The OUTLN User

The schema OUTLN is now created in all Oracle8i databases, with a default password of OUTLN. The DBA can and should change the password of this account immediately after an install, just as they do for other accounts such as SYS and SYSTEM.

This schema holds two tables and some indexes that, by default, are in the SYSTEM tablespace. If you plan on using Optimizer Plan Stability heavily (especially with regards to using the ALTER SESSION method of capturing query plans), you might consider moving the objects out of the SYSTEM tablespace and into a tablespace you have set up just for them. One of the two tables contains a LONG column so cannot easily be moved, using the usual ALTER TABLE tablename MOVE syntax. Rather, we must use export and import to move these objects. The following steps describe how to move the entire OUTLN schema from the SYSTEM tablespace to the TOOLS tablespace:

  1. Export the OUTLN user:

    exp userid=outln/outln owner=outln 
  2. Alter the OUTLN user to change their default tablespace from SYSTEM to TOOLS, give them an unlimited quota on TOOLS and a 0k quota on SYSTEM:

    alter user outln default tablespace tools; revoke unlimited tablespace from outln; alter user outln quota 0k on system; alter user outln quota unlimited on tools; 
  3. Drop the OL$ and OL$HINTS table from the OUTLN schema:

    drop table ol$; drop table ol$hints; 
  4. Import the OUTLN user:

    imp userid=outln/outln full=yes 

Note that if a system is using outlines already, the above operation should be done in single user mode if at all possible, and in a database with no active end users.

You might consider monitoring the space utilization of the OL$ and OL$HINTS table and the corresponding indexes over time.

Moving Outlines from Database to Database

Having reviewed how to move the entire OUTLN schema from tablespace to tablespace within a database, let's look at how to export query outlines from your database, and import them into a totally different instance. This would be in support of using outlines to ensure Optimizer Plan Stability of an application you are going to install at various customer sites, or are moving from your test instance into your production instance.

The easiest way to do this is via a parameter file (to avoid any issues with sh escaping issues and NT command line nuances). I set up an exp.par file for export that looks like this:

query="where category='HR_APPLICATION'" tables=(ol$,ol$hints) 

This is set up to export all of the stored outlines for the HR_APPLICATION category. The only thing you'll change in the exp.par file from run to run would be the name of the category you are moving. We would then execute:

exp userid=outln/<password> parfile=exp.par 

replacing <password> with the correct password for OUTLN of course. This will export only the rows in which we are interested. We would move the resulting expdat.dmp file to the target server, or run IMP over the network, to do a full import of it. This command would be:

imp userid=outln/outln full=y ignore=yes 

We must use the IGNORE=YES clause this time since we are adding rows to an existing table, not trying to move it as we were in the last section. Optimizer Plan Stability fully supports export and import - you are allowed to do this. You should never directly modify the OL$ or OL$HINT tables, but you can use EXP/IMP to move them around from database to database. In fact, EXP/IMP is the only tool that will perform this task safely. Consider what would happen if you had a database with a stored outline called MYOUTLINE, you exported this outline, and took it to another database, but that other database already had an outline called MYOUTLINE. If you were to use any tool other than EXP/IMP, you would corrupt the outline in the other database. Suppose you just tried to copy the data over using SQL. Some of the rows might copy, but others would not, due to key conflicts. You would end up with bits and pieces of two stored outlines mixed together. Only import and export know the proper way to accomplish this task, and have special hooks to utilize to make sure an outline from one database does not overwrite the outlines in another database (discussed in more detail in The OUTLN_PKG Package section a little later).

Getting Just the Right Outline

The question 'How can we get just the right optimizer plan going?' might arise, if we are using this for a tuning tool. Earlier, I demonstrated how altering the session and running a specific query could generate a 'good' plan. This is by far the easiest method. If it were at all possible, you would simply issue the requisite ALTER SESSION directives to set up your session's environment appropriately, and then issue the CREATE OUTLINE for this query. Alternatively, if the query is already in the outline tables, rebuild it with the new environment as we did above. This second case is desirable as it guarantees the query text will match. This is possible in many cases, such as when:

Well, what happens when simply setting a session level attribute such as HASH_JOIN_ENABLED doesn't change the query plan in the manner you desire C when the only thing that has the desired effect is physically hinting the query itself? Well, you can certainly use hints with Optimizer Plan Stability, in that you can create a stored outline on a query containing hints, but that is probably not what you want. You want a query that is executed without the hints, to use this plan. However, in order to use this stored plan you must execute queries that exactly match the SQL used to generate the outline. You want to be able to store an outline for an un-hinted query, and have that query pick up that plan. Due to the implementation of Optimizer Plan Stability, we can, in fact, do that C just in a circuitous fashion. Here is how it would work.

Let's suppose we started with the query:

scott@TKYTE816> set autotrace traceonly explain scott@TKYTE816> select * from emp, dept where emp.deptno = dept.deptno;      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE    1    0   NESTED LOOPS    2    1     TABLE ACCESS (FULL) OF 'EMP'    3    1     TABLE ACCESS (BY INDEX ROWID) OF 'DEPT'    4    3       INDEX (UNIQUE SCAN) OF 'DEPT_PK' (UNIQUE) 

We discovered through testing and tuning that the following query works much better for us:

scott@TKYTE816> select *   2    from ( select /*+ use_hash(emp) */ * from emp ) emp,   3         ( select /*+ use_hash(dept) */ * from dept ) dept   4  where emp.deptno = dept.deptno   5  /      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE (Cost=3 Card=67 Bytes=7839)    1    0   HASH JOIN (Cost=3 Card=67 Bytes=7839)    2    1     TABLE ACCESS (FULL) OF 'EMP' (Cost=1 Card=82 Bytes=7134)    3    1     TABLE ACCESS (FULL) OF 'DEPT' (Cost=1 Card=82 Bytes=2460) 

The performance is incredible when compared to the nested loops query. We would like the applications that issue the first query, to get the hash join plan rather than the nested loop plan, but we need this to happen without changing the application code (for whatever reason, we cannot add hints to the code).

Well, since query plan outlines are based on character string comparisons, we can accomplish this using a different schema and some hinted views. Since the above objects are in the SCOTT schema, we are going to use the TKYTE schema to set up some views:

scott@TKYTE816> grant select on emp to tkyte;      Grant succeeded.      scott@TKYTE816> grant select on dept to tkyte;      Grant succeeded.      scott@TKYTE816> connect tkyte/tkyte Connected. tkyte@TKYTE816> drop table emp;      Table dropped.      tkyte@TKYTE816> drop table dept;      Table dropped.      tkyte@TKYTE816> create or replace view emp as   2  select /*+ use_hash(emp) */ * from scott.emp emp   3  /      View created.      tkyte@TKYTE816> create or replace view dept as   2  select /*+ use_hash(dept) */  * from scott.dept dept   3  /      View created. 

Now we generate a stored outline for our application query:

tkyte@TKYTE816> create or replace outline my_outline   2  for category my_category   3  on select * from emp, dept where emp.deptno = dept.deptno;      Outline created. 

So, in the TKYTE schema, we have our hinted views of the base objects and we've created a stored outline of the query we wanted in that schema. We could drop the views at this point if we wanted to C we have what we want, the stored outline using hash joins. Now, when we log in as SCOTT again, we see the following:

scott@TKYTE816> connect scott/tiger scott@TKYTE816> alter session set use_stored_outlines=my_category;      Session altered.      scott@TKYTE816> set autotrace traceonly explain scott@TKYTE816> select * from emp, dept where emp.deptno = dept.deptno;      Execution Plan ----------------------------------------------------------    0      SELECT STATEMENT Optimizer=CHOOSE (Cost=3 Card=67 Bytes=7839)    1    0   HASH JOIN (Cost=3 Card=67 Bytes=7839)    2    1     TABLE ACCESS (FULL) OF 'EMP' (Cost=1 Card=82 Bytes=7134)    3    1     TABLE ACCESS (FULL) OF 'DEPT' (Cost=1 Card=82 Bytes=2460) 

Simply by using the appropriate outline category, we are now picking up the desired plan. That is because the Optimizer Plan Stability does not, by design, resolve object references in the SQL text. It just stores a string, and when it gets another string that matches in the category you have enabled, it will utilize the stored hints. This is intended by design.

Utilizing this string-matching feature, we can use views and/or synonyms to create query outlines that utilize our hints in the generation of the final query plan. Combine this with the ALTER SESSION method above and it is safe to say you could generate most plans you need.

Managing Outlines

We will now take an in-depth look at the facilities used to manage outlines: using either DDL (ALTER and DROP), or the supplied OUTLN_PKG package.

Via DDL

In addition to the CREATE command, we also use the ALTER and DROP commands to manage query outlines. The ALTER command allows us to:

The DROP command simply drops a stored outline by name.

ALTER OUTLINE

The ALTER command has three variants and we will take a look at each one. To review how this command works, we will first create a stored outline and then alter it in various ways:

tkyte@TKYTE816> create or replace outline my_outline   2  for category my_category   3  on select * from all_objects   4  /      Outline created.      tkyte@TKYTE816> select name, category, sql_text from user_outlines;      NAME                           CATEGORY       SQL_TEXT ------------------------------ -------------- --------------------- MY_OUTLINE                     MY_CATEGORY    select * from                                               all_objects      tkyte@TKYTE816> select count(*) from user_outline_hints                                                   where name = 'MY_OUTLINE';        COUNT(*) ----------        138 

So, the outline we are working with is named MY_OUTLINE, in category MY_CATEGORY, and currently has 138 hints associated with it (your mileage may vary depending on your optimizer setting!).

The first use of the ALTER OUTLINE command simply allows us to rename a stored outline. The syntax for this command is:

alter outline outline_name rename to new_name 

So, we will use this command to rename our outline from MY_OUTLINE to PLAN_FOR_ALL_OBJECTS as follows:

tkyte@TKYTE816> alter outline my_outline rename to plan_for_all_objects   2  /      Outline altered.      

A simple query verifies that it worked as planned:

tkyte@TKYTE816> select name, category, sql_text from user_outlines   2  /      NAME                           CATEGORY       SQL_TEXT ------------------------------ -------------- --------------------- PLAN_FOR_ALL_OBJECTS           MY_CATEGORY    select * from                                               all_objects 

The next step is to use the ALTER OUTLINE command to change the category in which this outline is currently stored. The syntax for this command is:

alter outline outline_name change category to new_category_name; 

So, let's change the category of our stored outline from MY_CATEGORY to a category named DICTIONARY_PLANS:

tkyte@TKYTE816> alter outline plan_for_all_objects change category to   2             dictionary_plans   3  /      Outline altered.      tkyte@TKYTE816> select name, category, sql_text from user_outlines   2  /      NAME                           CATEGORY             SQL_TEXT ------------------------------ -------------------- --------------------- PLAN_FOR_ALL_OBJECTS           DICTIONARY_PLANS     select * from                                                     all_objects 

Again, this is very straightforward. The ALTER command simply updated the category name for us in the OUTLN schema. To demonstrate the last usage of the ALTER command, we'll rebuild the query plan using the current environment. The basic syntax is as follows:

alter outline outline_name rebuild; 

As it currently stands, we are logged into SQL*PLUS with the OPTIMIZER_GOAL set to CHOOSE. Since data dictionary objects are not analyzed, the optimizer being used by the above query is the rule-based optimizer (when the optimizer goal is CHOOSE, and no referenced objects are analyzed, we use the rule-based optimizer). We will set the optimizer goal to ALL_ROWS, forcing use of the cost-based optimizer, and rebuild the plan.

tkyte@TKYTE816> alter session set optimizer_goal = all_rows   2  /      Session altered.      tkyte@TKYTE816> alter outline plan_for_all_objects rebuild   2  / Outline altered.      

Looking at the number of resulting hints, we can confirm that the generated plan was in fact rebuilt and is different from the original plan:

tkyte@TKYTE816> SELECT COUNT (*)   2    FROM USER_OUTLINE_HINTS   3   WHERE NAME = 'PLAN_FOR_ALL_OBJECTS'   4  /        COUNT(*) ----------        139 

The plan is definitely different C we now have 139 hints C and it is now optimized using ALL_ROWS instead of CHOOSE.

DROP OUTLINE

The command to drop the outline is very simple. The syntax is:

drop outline outline_name; 

Continuing our example, we will use this DDL command to drop our existing stored outline:

tkyte@TKYTE816> drop outline plan_for_all_objects   2  /      Outline dropped.      tkyte@TKYTE816> select * from user_outlines;      no rows selected 

That's about as simple as it gets. The following section details some more robust procedures to manipulate groups of outlines.

The OUTLN_PKG Package

We will now look at the OUTLN_PKG. This package is provided for two reasons:

We will describe and demonstrate the usage of the OUTLN_PKG functions for bulk operations. We will not look at the API calls in the package that are for the use of export and import. Those functions are undocumented and not intended to be invoked by any tool other than IMP and EXP.

The OUTLN_PKG is created by the dbmsol.sql and prvtol.plb scripts found in [ORACLE_HOME]/rdbms/admin. This script is executed by catproc.sql (found in the same place) and will be installed by default in your database. In addition to creating the OUTLN_PKG, this script inserts the necessary rows into the EXP dictionary tables to register its functions with the EXP/IMP tools. It should be installed by the user SYS or INTERNAL using SVRMGRL. As it is installed on an upgrade or an install of the database, it should never be necessary for you to run this script yourself.

The OUTLN_PKG has three entry points of interest to us:

OUTLN_PKG.DROP_UNUSED

This procedure, which takes no inputs, drops every unused outline from every category. It simply finds every outline whose USED field is set to UNUSED, and does the equivalent of DROP OUTLINE outline_name against it. An example usage is:

tkyte@TKYTE816> exec outln_pkg.drop_unused;      PL/SQL procedure successfully completed. 

Since this procedure works against all categories, care should be exercised in its use. You may inadvertently drop a stored outline in a category you should not have. This could interfere with someone else who had generated the outlines but had not yet used them.

OUTLN_PKG.DROP_BY_CAT

The DROP_BY_CAT procedure will remove all stored outlines in a given category. You might use this when testing, for example, to remove categories of stored outlines that did not meet your needs. Alternatively, you may use it to remove the outlines from a category. This will allow an application to start generating plans using the optimizer directly, where before it was using the outlines. Here is a brief example using this routine:

tkyte@TKYTE816> select category from user_outlines;      CATEGORY -------------- DICTIONARY_PLANS      tkyte@TKYTE816> exec outln_pkg.drop_by_cat( 'DICTIONARY_PLANS' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select category from user_outlines;      no rows selected 

OUTLN_PKG.UPDATE_BY_CAT

This procedure allows you to rename an existing category, or to merge one category into another. The syntax of this procedure is simply:

outln_pkg.update_by_cat(old_category_name, new_category_name); 

It works as follows:

Let's look at an example that demonstrates this feature:

tkyte@TKYTE816> create outline outline_1   2  for category CAT_1   3  on select * from dual   4  /      Outline created.      tkyte@TKYTE816> create outline outline_2   2  for category CAT_2   3  on select * from dual   4  / Outline created.      tkyte@TKYTE816> create outline outline_3   2  for category CAT_2   3  on select * from dual A   4  / Outline created. 

So, we have three stored outlines in two categories. The query SELECT * FROM DUAL has two stored outlines while the query SELECT * FROM DUAL A has one. Looking at what we have so far:

tkyte@TKYTE816> select category, name, sql_text   2    from user_outlines   3   order by category, name   4  /      CATEGORY       NAME                           SQL_TEXT -------------- ------------------------------ --------------------- CAT_1          OUTLINE_1                      select * from dual CAT_2          OUTLINE_2                      select * from dual CAT_2          OUTLINE_3                      select * from dual A 

we can see CAT_1 with 1 outline and CAT_2 with 2 outlines. Further, we clearly see that CAT_2 has a SQL_TEXT entry that already exists in CAT_1. Then we perform the merge:

tkyte@TKYTE816> exec outln_pkg.update_by_cat( 'CAT_2', 'CAT_1' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select category, name, sql_text   2    from user_outlines   3   order by category, name   4  /      CATEGORY       NAME                           SQL_TEXT -------------- ------------------------------ --------------------- CAT_1          OUTLINE_1                      select * from dual CAT_1          OUTLINE_3                      select * from dual A CAT_2          OUTLINE_2                      select * from dual 

We can see the outlines from CAT_2 that did not already exist in CAT_1 were moved over. The stored outline for the duplicate query however, was not moved over. This is because there is uniqueness enforced on the columns (NAME) and (CATEGORY, SIGNATURE). Within a category, the SQL_TEXT must be unique. This is enforced by the generation of a unique signature for the SQL_TEXT. If you want to move OUTLINE_2 from CAT_2 into CAT_1, you will have to drop OUTLINE_1 from CAT_1 before you run UPDATE_BY_CAT.

tkyte@TKYTE816> drop outline outline_1;      Outline dropped.      tkyte@TKYTE816> exec outln_pkg.update_by_cat( 'CAT_2', 'CAT_1' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select category, name, sql_text   2    from user_outlines   3   order by category, name   4  /           CATEGORY       NAME                           SQL_TEXT -------------- ------------------------------ --------------------- CAT_1          OUTLINE_2                      select * from dual CAT_1          OUTLINE_3                      select * from dual A 

Caveats

As with any feature, some nuances need to be noted in the way query outlines function. This section attempts to address some of them in turn.

Outline Names and Case

The OUTLN_PKG has two entry points that take in the name of an outline category, or an outline itself. Since it accepts a string as input, care must be taken with regards to the case used. Oracle will store object names by default in UPPERCASE but object names may be in mixed case if you used quoted identifiers. You must make certain that the case of the category name you pass into DROP_BY_CAT for example, matches the case of the category, as it is stored in the data dictionary. The following example will demonstrate this caveat for us:

tkyte@TKYTE816> create or replace outline my_outline   2  for category my_category   3  on select * from dual   4  /      Outline created.      tkyte@TKYTE816> create or replace outline my_other_outline   2  for category "My_Category"   3  on select * from dual   4  / Outline created.      tkyte@TKYTE816> select name, category, sql_text from user_outlines;      NAME                           CATEGORY       SQL_TEXT ------------------------------ -------------- --------------------- MY_OUTLINE                     MY_CATEGORY    select * from dual MY_OTHER_OUTLINE               My_Category    select * from dual 

So we have our two outlines. Note that the category names are the same, but are in a different case. These are two distinctly different categories. We achieved this via the 'quoted' identifier in the second CREATE OUTLINE command. Now, it would seem natural enough to use lower case when dropping the category, but as we see below, this does not work:

tkyte@TKYTE816> exec outln_pkg.drop_by_cat( 'my_category' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select name, category, sql_text from user_outlines;      NAME                           CATEGORY       SQL_TEXT ------------------------------ -------------- --------------------- MY_OUTLINE                     MY_CATEGORY    select * from dual MY_OTHER_OUTLINE               My_Category    select * from dual 

Both categories remain. This is because there is no category stored in all lower case characters. Now we will drop the upper case category:

tkyte@TKYTE816> exec outln_pkg.drop_by_cat( 'MY_CATEGORY' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select name, category, sql_text from user_outlines      NAME                           CATEGORY       SQL_TEXT ------------------------------ -------------- --------------------- MY_OTHER_OUTLINE               My_Category    select * from dual 

And now the lower case category:

tkyte@TKYTE816> exec outln_pkg.drop_by_cat( 'My_Category' );      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select name, category, sql_text from user_outlines;      no rows selected 

This side effect, of passing the name of an object instead of the 'object' itself, has been known to cause some confusion. Similar issues exist elsewhere with BFILES and DIRECTORY objects since they pass object names as strings as well.

I would strongly discourage you from using quoted identifiers. They will only lead to confusion in the long run and unless you always quote them, you cannot access them. I've seen more than one database tool go awry trying to work with mixed case identifiers.

ALTER SESSION Issue

It should be noted that if you do not have the CREATE ANY OUTLINE system privilege, either via a role or directly, the ALTER SESSION will silently succeed, but no outlines will be generated. Therefore, if you alter your session and notice no outlines being generated, this is the cause. You need to have CREATE ANY OUTLINE granted to you, or a role you have. This is true even if an ALTER SYSTEM command was used to generate query plans for every session. Only sessions that are authenticated using an account with the CREATE ANY OUTLINE privilege will actually create outlines.

DROP USER does not Drop Outlines

Normally, if you drop a user with the CASCADE option, all objects owned by that user are dropped from the database. Stored outlines are an exception to that rule. For example:

sys@TKYTE816> select owner, name from dba_outlines where owner = 'TKYTE';      OWNER                          NAME ------------------------------ ------------------------------ TKYTE                          OUTLINE_1 TKYTE                          OUTLINE_2 TKYTE                          OUTLINE_3      sys@TKYTE816> drop user tkyte cascade;      User dropped.      sys@TKYTE816> select owner, name from dba_outlines where owner = 'TKYTE';      OWNER                          NAME ------------------------------ ------------------------------ TKYTE                          OUTLINE_1 TKYTE                          OUTLINE_2 TKYTE                          OUTLINE_3 

shows that even after dropping my account, the outlines from the previous example exists and would continue to be used.

'CURSOR_SHARING = FORCE' and Outlines

Oracle release 8.1.6 introduced a feature I refer to as 'auto binding'. In Chapter 10 in Tuning Strategies and Tools, I stressed the importance of using bind variables, and demonstrated a new feature in the database whereby the database kernel itself will rewrite queries that use constants to use bind variables instead. This feature, cursor sharing, has an anomaly with regards to stored outlines. Depending on how the outline was generated, we will either store the plan for a query with a bind variable, or not. An example will help to clarify. We will run the same exact query in a session where CURSOR_SHARING is enabled. In one case, we will generate the outline using DDL via the CREATE OUTLINE command and in the other case, we will use the ALTER SESSION command to have outlines generated for us. We can then compare the SQL_TEXT stored for each:

tkyte@TKYTE816> alter session set cursor_sharing = force;      Session altered.      tkyte@TKYTE816> create or replace outline my_outline   2  for category my_category   3  on select * from dual where dummy = 'X';      Outline created.      tkyte@TKYTE816> alter session set create_stored_outlines = true;      Session altered.      tkyte@TKYTE816> select * from dual where dummy = 'X';      D - X      tkyte@TKYTE816> alter session set create_stored_outlines = false;      Session altered.      tkyte@TKYTE816> select name, category, sql_text from user_outlines;      NAME                          CATEGORY        SQL_TEXT ----------------------------- --------------- ------------------------------ SYS_OUTLINE_0104122003150057  DEFAULT         select * from dual where dummy                                                 = :SYS_B_0      MY_OUTLINE                    MY_CATEGORY     select * from dual where dummy                                                 = 'X' 

As you can see, the stored queries are very different from each other. The one we generated via the CREATE OUTLINE command is exactly as we had entered it. The CURSOR_SHARING code was not executed in this case, since we did not actually run the query. The query text was stored verbatim. On the other hand, the query text for the implicitly generated outline shows the effect of the query rewrite for us. We can plainly see that our constant X was turned into a bind variable for us. This SQL was stored for us.

Depending on your needs, both methods may be applicable. It is just important to understand that there is a subtle different between the explicitly generated plan, and the implicitly generated one with CURSOR_SHARING enabled.

Outlines Use Simple Text Matching

The outline mechanism, the mechanism for finding and using a stored outline, is a very simple one. It does it purely by text matching. It is not like the matching that takes place in the shared pool with parsed query plans; it is much more straightforward.

With query outlines, Oracle stops at the matching of SQL text. No attempt is made to verify or ascertain that the underlying objects are in fact the same objects. We used this to our advantage in a previous section Getting Just the Right Outline. We created a schema in which we created hinted views named after 'real' base tables in another schema. We then generated outlines against queries on these views. These outlines were very much influenced by our hints. We then saw that when we ran the same exact query in the original schema with the 'real' tables (not the views), Oracle picked up the stored outline, even though the underlying tables were totally different. This is the expected designed behavior of this feature. It was intended that exact matches based on SQL text alone would get the same set of hints associated with them.

It should be noted that this string matching is exact string matching. Spaces, tabs, newlines, case - everything counts. These two queries:

select * from dual; SELECT * FROM DUAL; 

are different as far as stored outlines are concerned.

Outlines by Default are in the SYSTEM Tablespace

By default, outlines are stored in the SYSTEM tablespace. If you plan on making heavy use of stored outlines, you should consider moving them to another tablespace. The method for achieving that was given in the section on The OUTLN User earlier. The outline hints table can get very large very quickly (our one example shows a simple select * from all_objects generated over 100 rows in this hint table). Unless you want your system tablespace to grow extremely large, moving the OUTLN users objects to another tablespace is recommended.

OR-Expansion

Given that the query outline mechanism is done via hints, and is limited to what hinting can achieve, there is one case that bears pointing out as not being a suitable candidate for stored outlines. This is the class of queries that use OR-Expansion. OR-Expansion would take a query like:

select * from T where x = 5 or x = 6; 

and rewrite it as:

select * from T where x = 5 Union All select * from T where x = 6; 

The outline mechanism does not have the ability to redistribute the hints to this internally rewritten plan. All of the stored hints would be applied to the first part of the UNION ALL query and not the subsequent queries. Oracle, in the readme supplied with the database ([ORACLE_HOME]/rdbms/doc/README.txt), states:

7.4.2 OR-Expansion
------------------
For execution plans that involve OR-expansion, you should avoid using stored outlines if possible. This recommendation is due both to the nature of stored outlines, which use hints to influence the execution plan, and to the nature of OR-expansion, which is represented internally through a set of OR chains, each of which represents a distinct join order. Hints are only useful for influencing a single join order, as there is no way to target a specific OR chain. Therefore an outline's hints are applied to the first OR chain represented internally. The net effect is that these hints simply get propagated across the remaining OR chains by the optimizer, often leading to suboptimal execution plans that differ from the originally saved plans.

Workaround:
Stored outlines that involve OR-expansion can be identified by querying the USER_OUTLINE_HINTS view for hint text containing USE_CONCAT. Issue the following query:

     SELECT NAME, HINT FROM USER_OUTLINE_HINTS WHERE HINT LIKE 'USE_CONCAT%';

Any outline containing this hint should either be dropped using the DROP OUTLINE command or moved to an unused category with the following command:

     ALTER OUTLINE <outline-name> CHANGE CATEGORY TO <unused-category-name>;

Performance

An obvious question is 'How does this facility affect my run-time performance?' The answer is, marginally. This feature adds marginal overhead during the parse phase of a query, with the most overhead occurring the first time the query plan is generated and saved (as might be expected).

What I did to test this was to set up a small PL/SQL block that would cause x number of 'simple' queries to be parsed, executed and fetched from (select * from T1, where T1 was a one row, one column table). In this fashion, I was measuring mostly the parse time. In order to set this up, I ran the following block to create 100 tables:

tkyte@TKYTE816> begin   2     for i in 1 .. 100 loop   3           begin   4                execute immediate 'drop table t'||i;   5           exception   6                when others then null;   7           end;   8           execute immediate 'create table t'||i||' ( dummy char(1) )';   9           execute immediate 'insert into t'||i||' values ( ''x'' )';  10     end loop;  11  end;  12  /      PL/SQL procedure successfully completed. 

So after creating 100 tables named T1 to T100 I ran a block of code just to get the shared SQL parsed and ready to go. We want to see the impact of creating outlines, not parsing the query:

tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .89 seconds 

Once the cache was warmed up, I ran the block a couple of more times to see how long it would take:

tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .02 seconds 

It was consistently taking about .02 seconds. Then I turned on outline creation:

tkyte@TKYTE816> alter session set create_stored_outlines = testing;      Session altered.      tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .82 seconds 

The first time round, when it really did store the outlines for the first time, it took about .82 seconds. This is just about the same amount of time it took to parse the queries in the first place. What I discovered after this was that subsequent runs took .02 seconds. After the initial hit of storing the outlines, the run-time went back down to what it was before outline creation was enabled. Now, in a heavy, multi-user situation, your mileage may vary, you may have to perform some amount of tuning on the OUTLN tables (freelist adjustment for example) to handle a high level of concurrent insertions.

There is one thing to consider here. The standard mode is not to run with CREATE_STORED_OUTLINES = TRUE. Rather, this is done once for some period of time to capture the queries and their associated plans. It will be more typical to run with USE_STORED_OUTLINES = TRUE in production, not CREATE. The point being that, even if the overhead of generating the plans was excessive, you do not intend to run in this mode in production, in any event. Only in the test and development instances will the overhead would be acceptable.

Now, lets look at the overhead associated with actually using these stored plans on this simple query:

tkyte@TKYTE816> alter session set use_stored_outlines=testing;      Session altered.      tkyte@TKYTE816> select used, count(*) from user_outlines group by used;      USED        COUNT(*) --------- ---------- UNUSED           100      tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .32 seconds      PL/SQL procedure successfully completed.      tkyte@TKYTE816> select used, count(*) from user_outlines group by used;      USED        COUNT(*) --------- ---------- USED             100      tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .03 seconds      PL/SQL procedure successfully completed.      tkyte@TKYTE816> declare l_tmp char(1); l_start number :=                                                dbms_utility.get_time; begin   2  select * into l_tmp from t1;   3  select * into l_tmp from t2;   4  select * into l_tmp from t3; ...  ... ...  ... ...  ...  99  select * into l_tmp from t98; 100  select * into l_tmp from t99; 101  select * into l_tmp from t100; 102  dbms_output.put_line( round( (dbms_utility.get_time-l_start)/100,                                                          2 )||' seconds' ); 103  end; 104  / .03 seconds      PL/SQL procedure successfully completed. 

The first time we re-parse these queries after enabling stored outlines, it took 0.32 seconds to execute. When we compare this to the initial parse without stored outlines (without saving them or using them), we find the parse time to be not materially affected. We have verified as well, that we are using the stored outlines as the USED column went from UNUSED to USED in all cases after executing our block. We know based on this, that the hints were actually used in our queries. The subsequent re-execution of that block shows that once the hints have been merged and shared SQL kicks in, the effect of stored outlines on performance is totally gone.

In short, the utilization of stored outlines in your application will not materially affect the run-time performance after the parse of the query for the first time into the shared pool. The effect of using stored outlines, in as much as it influences the query plan, might affect your run-time, but the fact that stored outlines are being merged with your query will not.

The Namespace of Outlines is Global

At first glance, it would appear that outlines are much like any other database object, tables for example, and that their names must be unique within an OWNER. This is not the case however. The name of an outline must be unique database-wide, much like a tablespace or directory entry. The existence of an OWNER column and the USER_OUTLINES view is misleading, as no one truly owns an outline. The OWNER column is really the name of the user that created the outline.

We can see this easily with a small test:

tkyte@TKYTE816> create outline the_outline   2  on select * from dual;      Outline created.      tkyte@TKYTE816> connect system      system@TKYTE816> select owner, name from dba_outlines;      OWNER                          NAME ------------------------------ ------------------------------ TKYTE                          THE_OUTLINE      system@TKYTE816> create outline the_outline   2  on select * from dual; on select * from dual                  * ERROR at line 2: ORA-18004: outline already exists      system@TKYTE816> drop outline the_outline;      Outline dropped.      system@TKYTE816> select owner, name from dba_outlines;      no rows selected 

So, as you can see, SYSTEM cannot create another outline called THE_OUTLINE, unless it used the CREATE OR REPLACE statement (which would overwrite my outline), or it drops the outline. (Note, there is no need for an OWNER.OUTLINE_NAME as for other objects).

This is something you will have to consider in order to avoid accidentally overwriting someone else's outline inadvertently. If you use implicit outline creation via the ALTER SESSION SET CREATE_STORED_OUTLINES, this issue is not relevant, as a unique name will always be generated. This only really affects outlines you yourself create, and name.

Errors you Might Encounter

This section will list the errors you may see when using outlines.

ORA-18001 "no options specified for ALTER OUTLINE"

// *Cause:  The parser detected that no clause was specified on the command // *Action: Re-issue the command, specifying a valid ALTER OUTLINE clause. 

You will receive this only when you use the ALTER outline command improperly. For example:

ops$tkyte@DEV816> alter outline xxxx   2  / alter outline xxxx                  * ERROR at line 1: ORA-18001: no options specified for ALTER OUTLINE 

The solution is clear; supply one of the three valid options (RENAME, REBUILD, CHANGE) to the command, and rerun it. See the Managing Outlines section for more information on this subject.

ORA-18002 "the specified outline does not exist"

// *Cause:  Either the outline did not exist to begin with, or a timing //          window allowed for another thread to drop or alter the outline //          midstream. // *Action: 

This error is pretty straightforward as well. The outline you referred to no longer exists C either it never did or someone else has dropped it.

ORA-18003 "an outline already exists with this signature"

// *Cause:  The signature generation algorithm generates signatures that are //      are 16 bytes in length so it is highly unlikely that any 2 //      signatures will be identical. This message is raised in such a //      rare case. // *Action: Either re-issue the statement that led to the outline being //      created with some whitespace added or force the outline to be //      created in a different category. 

I was unable to come up with a test case for this C you would have to be extremely unlucky to hit this particular error. The signatures of queries are computed to allow us to perform a fast lookup on them. Since the query text can be very long, the numeric signature is used instead for fast lookups.

ORA-18004 "outline already exists"

// *Cause:  An outline already exists, either with the specified name, or //          for the specified SQL text. // *Action: 

This error is self-explanatory. You have attempted to CREATE a named outline but an outline with that name already exists. Your options are:

ORA-18005-18007

These three errors are very inter-related, hence I will discuss all three at the same time:

These errors will occur when you attempt to perform an operation on an outline, but you do not have the requisite privilege. It can be somewhat confusing, especially when working with your own outlines. As indicated in the Caveats section however, outlines are not truly owned by anyone; their namespace is global (like a tablespace). Therefore, you may be able to CREATE an outline, but not subsequently DROP or ALTER it. You might be able to ALTER outlines but not CREATE or DROP them, and so on.

See the section on Privileges Needed for Stored Outlines for details on the privileges you need.

Summary

In this chapter, we thoroughly explored the Optimizer Plan Stability feature of Oracle8i. This feature was designed to allow a set of SQL statements performance to remain stable, regardless of changes in the database itself (for example, version upgrades, init.ora parameter changes, and so on). We have found some other useful functions of this feature, such as tuning applications that we cannot modify for whatever reason, finding out what indexes we really use, what SQL we really execute, and so on. Given that stored outlines are so transparent to an application, and add little or no overhead at run-time, their usefulness is increased. There are some crucial caveats to be aware of with regards to this feature, but once educated about them, stored outlines can be very powerful.



Expert One on One Oracle
Full Frontal PR: Getting People Talking about You, Your Business, or Your Product
ISBN: 1590595254
EAN: 2147483647
Year: 2005
Pages: 41
Authors: Richard Laermer, Michael Prichinello
BUY ON AMAZON

flylib.com © 2008-2017.
If you may any questions please contact us: flylib@qtcs.net