Oracle 19c - New Feature - Automatic SQL Plan Management - SPM with available options in Oracle 19c!
In this video, we are going to see another oracle 19c new feature Automatic SQL plan management and SQL regressions with an available options.
What is automatic SQL Plan Management (SPM)?
Oracle Database 19c adds a new feature called automatic SQL plan management.
What is automatic SQL plan management and how it works.
How to configure.
Summary.
Where is it available?
This is an autonomous feature so it is only available on some platforms. See Automatic SQL Plan Management in the following link table 1-6.
https://docs.oracle.com/en/database/oracle/oracle-database/19/dblic/Licensing-Information.html#GUID-0F9EB85D-4610-4EDF-89C2-4916A0E7AC87
If you are not using a supported platform, there are still some great SPM enhancements in Oracle Database 19c for you to make use of - see the below link.
https://blogs.oracle.com/optimizer/repairing-sql-performance-regression-with-sql-plan-management
What is it?
Automatic SQL plan management identifies SQL statements that are consuming significant system resources (by inspecting the AWR and SQL tuning sets). Historic performance information (again in the AWR and SQL tuning sets) is used to establish whether there has been a likely performance regression. Perhaps application query Q1 has been completing in 1 minute for the past two years but today it takes 30 minutes. Alternate SQL execution plans are located automatically and test executed (using SPM evolution). The best plans are then enforced using SQL plan baselines without DBA intervention.
In short: SQL statement performance regressions are repaired automatically.
How is it enabled?
The automatic mode is enabled by setting the DBMS_SPM parameter ALTERNATE_PLAN_BASELINE to AUTO. This setting not available on all platforms.
The ALTERNATE_PLAN_SOURCE parameter can be set to AUTO on supported platforms and it is currently equivalent to "AUTOMATIC_WORKLOAD_REPOSITORY+CURSOR_CACHE+SQL_TUNING_SET".
How does it work?
Here is a summary of the flow:
Automatic SQL plan management
The Automatic Workload Repository (AWR) is inspected for SQL execution plans that consume significant system resources. In addition, the database inspects the automatic SQL tuning set (ASTS) if it is available (this is a tuning set maintained by the database primarily for automatic indexing).
The database looks for alternative SQL execution plans in various sources such as AWR, SQL tuning sets and the cursor cache. The plans identified are added to the SQL plan history.
The SPM evolve advisor test executes the alternative plans and compares their performance.
The evolve advisor decides which plans perform best and adds them to the SQL plan baseline.
SQL plan baselines prevent 'regressed' execution plans from being used.
How is it configured?
I am aware that some DBAs use SQL plan management in a tactical fashion; controlling regression in a carefully chosen set of SQL statements. Some DBAs will capture SQL statements according to a predetermined schedule and perhaps run SPM evolution manually as-and-when required. Some DBAs disable SPM evolution altogether, choosing exactly when and how to evolve a particular SQL statement.
If you currently have a particular way of using SPM, then when you upgrade to Oracle Database 19c you will need to decide whether to choose:
Option#1: Use the new 'auto regime' in Oracle Database 19c alone.
Option#2: Continue to use SPM in the way you have in the past, but in conjunction with automatic SPM.
Option#3: Disable automatic SPM and continue to use SPM in the way you have used it in the past.
Option #1:
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK' ,
parameter => 'ALTERNATE_PLAN_BASELINE',
value => 'AUTO');
END;
/
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK',
parameter => 'ALTERNATE_PLAN_SOURCE',
value => 'AUTO');
END;
/
Option #2:
Use AUTO and continue to capture and evolve as you see fit. The automatic approach can work along-side existing strategies.
Option #3:
The Oracle Database 19c defaults are now the same as Oracle Database 12c Release 2 and Oracle Database 18c:
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK' ,
parameter => 'ALTERNATE_PLAN_BASELINE',
value => 'EXISTING'); /* The Default */
END;
/
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK',
parameter => 'ALTERNATE_PLAN_SOURCE',
value => 'CURSOR_CACHE+AUTOMATIC_WORKLOAD_REPOSITORY'); /* The Default */
END;
/
If you want to use the same settings in Oracle Database 19c as the Oracle Database 12c Release 1 defaults:
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK' ,
parameter => 'ALTERNATE_PLAN_BASELINE',
value => '');
END;
/
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK',
parameter => 'ALTERNATE_PLAN_SOURCE',
value => '');
END;
/
To view current parameter settings:
SELECT PARAMETER_NAME, PARAMETER_VALUE
FROM DBA_ADVISOR_PARAMETERS
WHERE TASK_NAME = 'SYS_AUTO_SPM_EVOLVE_TASK';
If you want to accept evolved execution plans manually, I recommend that you continue to allow the automatic SPM evolve advisor task to execute (so that you can view SPM reports and findings). Then, to prevent alternative plans from being accepted automatically, use the following setting:
BEGIN
DBMS_SPM.SET_EVOLVE_TASK_PARAMETER(
task_name => 'SYS_AUTO_SPM_EVOLVE_TASK' ,
parameter => 'ACCEPT_PLANS',
value => FALSE);
END;
/
Note that the evolve advisor task, SYS_AUTO_SPM_EVOLVE_TASK, was introduced in Oracle Database 12c.
How to switch between different behavior?
Summary:
Automatic SQL plan management is a great new way to prevent query performance regressions and capture SQL plan baselines transparently, without any management overhead.
The parameters used above were first introduced in Oracle Database 12c Release 2. The internal implementation for identifying alternative plans continued to be enhanced in Oracle Database 18c and Oracle Database 19c.
References:
https://blogs.oracle.com/optimizer/what-is-automatic-sql-plan-management-and-why-should-you-care#:~:text=Automatic%20SQL%20plan%20management%20identifies,AWR%20and%20SQL%20tuning%20sets).&text=The%20best%20plans%20are%20then,performance%20regressions%20are%20repaired%20automatically.
https://blogs.oracle.com/optimizer/repairing-sql-performance-regression-with-sql-plan-management
https://docs.oracle.com/en/database/oracle/oracle-database/19/dblic/Licensing-Information.html#GUID-0F9EB85D-4610-4EDF-89C2-4916A0E7AC87
Cheers!
Ramesh.
Post a Comment: