X

Insights into Statistics, Query Optimization and the Oracle Optimizer

Tips on SQL Plan Management and Oracle Database In-Memory Part 1

Nigel Bayliss
Product Manager

If you follow Oracle’s In-Memory blog then you probably came across a post mentioning how you should use SQL Plan Management when you’re upgrading to Oracle Database In-Memory. Whether you have read that post or not, you might be wondering what will happen if you have some SQL plan baselines and you begin to populate the In-Memory column store with a bunch of tables as used by those baselines. That’s what this post is about. Well, in fact, I’m going to break the topic up into a few posts because (as ever!) there is a little bit of subtlety to cover. Luckily, this will make your life easier rather than more difficult because you can get immediate benefit from In-Memory even if you don’t evolve SQL plan baselines on day one.  

When I started to think about this post I thought that I would start with the first scenario that probably comes to mind if you’re familiar with SQL Plan Management (SPM): 
  • The Optimizer comes up with a new execution plan for a SQL statement because something has changed, and Oracle Database In-Memory would be a very good example of that! 
  • If there’s a SQL plan baseline for the statement, the database will use the baseline execution plan and capture the new plan.
  • Where appropriate, the new plan will be validated and accepted using SQL plan evolution. 

I will get to that, but first it’s better to start with a couple of more subtle points. With this information in our back pocket it will be easier to understand (and explain) the more traditional aspects of SQL plan evolution in the context of Oracle Database In-Memory. 

Here, I will cover the following example:

  • There is a table called MYSALES that’s not yet populated into the In-Memory column store. 
  • A query (called “Q1”) includes a full table scan of MYSALES. There is no index on the table that’s useful to Q1. 
  • Q1 has an active SQL plan baseline.
  • MYSALES is subsequently populated into the In-Memory column store.

Let’s take a look at Q1 and its SQL execution plan before populating MYSALES into the In-Memory column store (and I'll explain the significance of the highlighted text further down)...

SQL_ID  4ss4zbb813250, child number 0
-------------------------------------
SELECT /* SPM */ COUNT(*) FROM   mysales WHERE  val = 'X'
 
Plan hash value: 3292460164
 
------------------------------------------------------------------------------
  Id  | Operation          | Name    | Rows  | Bytes | Cost  %CPU | Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |         |       |       |    69 (100)|          |
|   1 |  SORT AGGREGATE    |         |     1 |     2 |            |          |
|*  2 |   TABLE ACCESS FULL| MYSALES | 99991 |   195K|    69   (2)| 00:00:01 |
------------------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
  2 - filter("VAL"='X')
 
Note
-----
  - SQL plan baseline SQL_PLAN_7469nmnn7nsu3c69cec1f used for this statement
 
Q1 performs a full table scan of MYSALES. The "note" section makes it clear that a SQL plan baseline is used. This is what that looks like:
 
SELECT PLAN_TABLE_OUTPUT
FROM   V$SQL s, DBA_SQL_PLAN_BASELINES b,
      TABLE(
        DBMS_XPLAN.DISPLAY_SQL_PLAN_BASELINE(b.sql_handle,b.plan_name,'basic')
      ) t
WHERE  s.EXACT_MATCHING_SIGNATURE=b.SIGNATURE
AND    b.PLAN_NAME=s.SQL_PLAN_BASELINE
AND    s.SQL_ID='4ss4zbb813250';
 
--------------------------------------------------------------------------------
SQL handle: SQL_7219349d287a6343
SQL text: SELECT /* SPM */ COUNT(*) FROM   mysales WHERE  val = 'X'
--------------------------------------------------------------------------------
 
--------------------------------------------------------------------------------
Plan name: SQL_PLAN_7469nmnn7nsu3c69cec1f         Plan id: 3332172831
Enabled: YES     Fixed: NO      Accepted: YES     Origin: AUTO-CAPTURE

Plan rows: From dictionary
--------------------------------------------------------------------------------
 
Plan hash value: 3292460164
 
--------------------------------------
  Id  | Operation          | Name    |
--------------------------------------
|   0 | SELECT STATEMENT   |         |
|   1 |  SORT AGGREGATE    |         |
|   2 |   TABLE ACCESS FULL| MYSALES |
--------------------------------------
 

What happens if MYSALES is now populated into the In-Memory column store? 

-- Mark MYSALES with the In-Memory attribute

ALTER TABLE mysales INMEMORY;
 

-- Access MYSALES to trigger population into In-Memory column store

SELECT count(*) FROM mysales;
 

Let’s rerun our query and examine the execution plan:

SQL_ID  4ss4zbb813250, child number 1
-------------------------------------
SELECT /* SPM */ COUNT(*) FROM   mysales WHERE  val = 'X'
 
Plan hash value: 3292460164
 
---------------------------------------------------------------------------------------
  Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |         |       |       |     3 (100)|          |
|   1 |  SORT AGGREGATE             |         |     1 |     2 |            |          |
|*  2 |   TABLE ACCESS INMEMORY FULL| MYSALES |   100K|   195K|     3   (0)| 00:00:01 |
---------------------------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
   2 - inmemory("VAL"='X')
       filter("VAL"='X')
 
Note
-----
   - SQL plan baseline SQL_PLAN_7469nmnn7nsu3c69cec1f used for this statement
 

There is still a full table scan, but this time the query will read data from MYSALES via the In-Memory column store rather than the storage-resident table and, even better, the same SQL plan baseline is used. That was pretty easy! The Optimizer chose a full table scan in both cases, so the same SQL plan baseline was used both cases. The INMEMORY annotation for the full table scan is “for your information only”; it tells you that the query scanned some or all of the data for your table via the In-Memory column store but as far as the Optimizer is concerned it is “just” a full table scan, as the keyword INMEMORY does not affect the plan hash value, so it will match the existing the SQL plan baseline (above, you can see that the plan hash value is always "3292460164" ).

Why do I say the INMEMORY keyword indicates some or all of the data for your table is scanned via the In-Memory column store? Remember until all of the data belonging to MYSALES has been populated into the In-Memory column store, Oracle will automatically pick up the rest of the data from wherever it resides. That could be from memory (e.g. the buffer cache) or from flash or from disk.

It should be pretty obvious by now that if we decide to remove MYSALES from the In-Memory column store, the query will revert to scanning the storage-resident table and the plan will display “TABLE ACCESS FULL”. 

This example is very simple, but the principle applies to queries that have the same execution plan for In-Memory versus non-In-Memory. What happens if there are execution plan changes and, in particular, if indexes are involved? Start by looking at Part 2.

If you want to try out this example for yourself, the scripts are in GitHub.

Be the first to comment

Comments ( 0 )
Please enter your name.Please provide a valid email address.Please enter a comment.CAPTCHA challenge response provided was incorrect. Please try again.Captcha
Oracle

Integrated Cloud Applications & Platform Services