Implications of Setting Oracle9iR2's Statistics Collection Level

Wednesday Apr 2nd 2003 by James Koopmann
Share:

Concerned about looking at statistics within Oracle? You should take a quick look at Oracles' new method of turning collections on or off.

Concerned about looking at statistics within Oracle? You should take a quick look at Oracles' new method of turning collections on or off.

It's New

In Oracle9iR2, Oracle has introduced a new initialization parameter called STATISTICS_LEVEL. Through this parameter, Oracle gives you the option to set different levels of statistical collection for major statistics and advisories.

Its Settings

There are three settings for this parameter: BASIC, TYPICAL, and ALL. The default setting is TYPICAL. Here is a quick matrix of what statistics and advisories are turned on depending on the setting you choose. I have added two columns to this matrix. The first is Session Affected which indicates those statistics that are affected by issuing the ALTER SESSION command for the STATISTICS_LEVEL parameter. The second is the initialization parameter that you can set in the SPFILE to override the STATISTICS_LEVEL setting.

Statistic / Advisory

BASIC

TYPICAL

ALL

Session Affected

Control Through SPFILE

Buffer Cache Advice


X

X


db_cache_advice

MTTR Advice

 

X

X

   

Shared Pool Advice

 

X

X

   

Segment Level Statistics

 

X

X

   

PGA Advice

 

X

X

   

Timed Statistics

 

X

X

X

timed_statistics

Timed OS Statistics

   

X

X

timed_os_statistics

Plan Execution Statistics

   

X

X

 

To take a look at the advisories and statistics controlled by the setting of the STATISTICS_LEVEL parameter or the entries in the SPFILE and what their current settings are, just issue the following SQL:

col statistics_name      for a30 head "Statistics Name"
col session_status       for a10 head "Session|Status"
col system_status        for a10 head "System|Status"
col activation_level     for a10 head "Activation|Level"
col session_settable     for a10 head "Session|Settable"

SELECT STATISTICS_NAME,
       SESSION_STATUS,
       SYSTEM_STATUS,
       ACTIVATION_LEVEL,
       SESSION_SETTABLE
  FROM v$statistics_level
 ORDER BY 1
/
 Session    System     Activation Session
Statistics Name                Status     Status     Level      Settable
------------------------------ ---------- ---------- ---------- ----------
Buffer Cache Advice            ENABLED    ENABLED    TYPICAL    NO
MTTR Advice                    ENABLED    ENABLED    TYPICAL    NO
PGA Advice                     ENABLED    ENABLED    TYPICAL    NO
Plan Execution Statistics      DISABLED   DISABLED   ALL        YES
Segment Level Statistics       ENABLED    ENABLED    TYPICAL    NO
Shared Pool Advice             ENABLED    ENABLED    TYPICAL    NO
Timed OS Statistics            DISABLED   DISABLED   ALL        YES
Timed Statistics               ENABLED    ENABLED    TYPICAL    YES

It's Dynamic

As with most of the new tuning parameters that Oracle is putting into their product, this parameter is dynamic. This means that you can set and unset it at any time. It is available for setting at the system level or at the session level. There is one small difference between dynamically changing this parameter for the system compared to changing it at the session level. If you modify this parameter for your particular session through the ALTER SESSION command, only certain advisories and statistics are affected. Take a look at the Session Affected column in the preceding matrix for what you will affect. If modified at the system level through the ALTER SYSTEM command, all advisories and statistics are affected for the database and every session.

It's Confusing

If you have any of the three parameters set in your SPFILE, that particular parameter setting will override the setting of the STATISTICS_LEVEL parameter. In order to use the STATISTICS_LEVEL parameter, you must reset the parameters you want the STATISTICS_LEVEL parameter to control.

To do this you should issue the following command:

ALTER SYSTEM RESET <parameter> SCOPE=SPFILE SID='*';

To Switch from SPFILE Control to STATISTICS_LEVEL Control

Under this example, I do not want to collect any statistics or advisories. I will take you through a current setting where I will show you that timed statistics are being collected even though the STATISTICS_LEVEL is set to BASIC. In order to not collect timed statistics, I will have to get rid of the SPFILE entry so that timed statistics is under complete control by the STATISTICS_LEVEL parameter.

Currently timed statistics are being collected

SELECT STATISTICS_NAME,
       SYSTEM_STATUS
  FROM v$statistics_level
 ORDER BY 1
/
                               System
Statistics Name                Status
------------------------------ ----------
Buffer Cache Advice            DISABLED
MTTR Advice                    DISABLED
PGA Advice                     DISABLED
Plan Execution Statistics      DISABLED
Segment Level Statistics       DISABLED
Shared Pool Advice             DISABLED
Timed OS Statistics            DISABLED
Timed Statistics               ENABLED

Currently I have timed_statistics under SPFILE control

SQL> show parameter timed_statistics
NAME                                 TYPE        VALUE
------------------------------------ ----------- ----------
timed_statistics                     boolean     TRUE

And my statistics level is set to BASIC

SQL> show parameter statistics_level
NAME                                 TYPE        VALUE
------------------------------------ ----------- -----------
statistics_level                     string      BASIC

Reset the timed_statistics parameter within SPFILE

Just by pure deduction, the fact that timed_statistics is TRUE and statistics_level is basic, you can infer that there is an entry in the spfile. In order for the timed_statistics parameter to be under the control of the STATISTICS_LEVEL parameter, you need to get rid of the parameter from within the SPFILE. To do this issue the following command:

ALTER SYSTEM RESET timed_statistics  SCOPE=SPFILE SID='*';

Bounce the Database

In order for the new setting of timed_statistics to take effect, you will need to bounce the database. This is not always the best thing to do and you are probably cringing as I would. Since timed_statistics is a dynamic parameter and your real intent is ultimately to have it set to false and then controlled by the STATISTICS_LEVEL parameter, just issue the following command to turn off timed_statistics:

ALTER SYSTEM SET timed_statistics=FALSE;

Verify that timed_statistics is under STATISTICS_LEVEL control

After the bounce of the database you can verify that timed_statistics is under the new STATISTICS_LEVEL parameter control by the following SQL:

SELECT STATISTICS_NAME,
       SYSTEM_STATUS
  FROM v$statistics_level
 ORDER BY 1;
                               System
Statistics Name                Status
------------------------------ ----------
Buffer Cache Advice            DISABLED
MTTR Advice                    DISABLED
PGA Advice                     DISABLED
Plan Execution Statistics      DISABLED
Segment Level Statistics       DISABLED
Shared Pool Advice             DISABLED
Timed OS Statistics            DISABLED
Timed Statistics               DISABLED

It's Better

Is this really better than setting individual parameters for statistical collection? It seems a bit easier, but also seems that we give up some more control. I have always liked controlling every small bit of information I could get out of Oracle. However, I am learning that sometimes, less control is better. I have said this once before in some other life of mine. When Oracle takes control from us as DBAs, to actively control information flow within the database, they are telling us that they can do it better and at a lower system cost. To me this is great news, just so long as their confidence in themselves pans out.

» See All Articles by Columnist James Koopmann

Share:
Home
Mobile Site | Full Site
Copyright 2017 © QuinStreet Inc. All Rights Reserved