Skip to content

Commit

Permalink
Real-time SPM (#387)
Browse files Browse the repository at this point in the history
* real-time SPM

* real-time SPM

* intro fix

* get started

* fix title
  • Loading branch information
nigelbayliss authored Jan 21, 2025
1 parent 9d40bc7 commit a2375ae
Show file tree
Hide file tree
Showing 37 changed files with 1,261 additions and 0 deletions.
132 changes: 132 additions & 0 deletions shared/adb-real-time-spm/create-schema/create-schema.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,132 @@
# Create an Application Schema

## Introduction

In this lab you will create a test schema and enable real-time SPM.

Estimated Time: 5mins

### Objectives
- Create a schema for an application test query and enable real-time SQL plan management.

### Prerequisites
This lab assumes you have completed the following:

- Provision an Autonomous Database Instance

## Task 1: Prepare to Execute SQL statements in a SQL Query Window using Database Actions

We will now prepare to execute SQL statements.


1. From your Autonomous Database Details page, click "Database actions" and then "SQL":

![Invoke SQL Query Window](./images/setup-1.png)

2. Ensure you are connected to ADMIN via the LOW service (circled in red):

![Check Connection Settings](./images/setup-2.png)

## Task 2: Create and Populate an Application Tables

1. Drop the test table if it exists already.

```
<copy>
declare
ORA_00942 exception; pragma Exception_Init(ORA_00942, -00942);
begin
execute immediate 'drop table sales_area1 purge';
exception when ORA_00942 then null;
end;
/
declare
ORA_00942 exception; pragma Exception_Init(ORA_00942, -00942);
begin
execute immediate 'drop table sales_area2 purge';
exception when ORA_00942 then null;
end;
/
-- If you are using 23ai, you can use the following commands instead
-- drop table if exists sales_area1 purge;
-- drop table if exists sales_area2 purge;
</copy>
```
2. Create the tables
```
<copy>
create table sales_area1 (
sale_code number(10),
b varchar2(2000),
amount number(10,2),
sale_type number(10),
c varchar2(1000));
insert /*+ APPEND */ into sales_area1
select mod(rn,1000),
dbms_random.string('u',2000),
dbms_random.value(1,5),
mod(rn,100),
dbms_random.string('u',50)
from (
select trunc((rownum+1)/2) as rn, mod(rownum+1,2) as parity
from (select null from dual connect by level <= 150)
, (select null from dual connect by level <= 500)
);
commit;
create table sales_area2 as
select sale_code,
b,
dbms_random.value(1,3) amount,
sale_type,c
from sales_area1;
create index sales_area2i on sales_area2 (sale_code,c);
create index sales_typ1i on sales_area1 (sale_type,c);
begin
dbms_stats.gather_table_stats(user,'sales_area1',
method_opt=>'for all columns size 254',no_invalidate=>false);
dbms_stats.gather_table_stats(user,'sales_area2',
method_opt=>'for all columns size 254',no_invalidate=>false);
end;
/
</copy>
```
## Task 3: Enable Real-time SPM
1. Use the DBMS_SPM API to enable real-time SPM.
```
<copy>
begin
dbms_spm.configure('AUTO_SPM_EVOLVE_TASK', 'AUTO');
end;
/
</copy>
```
2. Confirm the mode is set to AUTO.
```
<copy>
select parameter_value spm_status
from DBA_SQL_MANAGEMENT_CONFIG
where parameter_name = 'AUTO_SPM_EVOLVE_TASK';
</copy>
```
```
SPM_STATUS
----------
AUTO
```
## Acknowledgements
* **Author** - Nigel Bayliss, Dec 2024
* **Last Updated By/Date** - Nigel Bayliss, Jan 2025
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
31 changes: 31 additions & 0 deletions shared/adb-real-time-spm/intro/intro.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
# Introduction #

## About this Workshop ##

SQL execution plan changes can sometimes cause performance regressions that have a significant impact on the service levels of an application. Real-time SQL plan management will compare the performance of a new execution plan with the performance of plans previously used by the SQL statement (should any other plans have been used within the last 53 weeks). If an earlier plan is known to perform significantly better, it will be reinstated automatically using a SQL plan baseline.

Estimated time for the entire workshop: 50 minutes

### Objectives
The aim of this workshop is to become familiar with real-time SQL plan management.

The steps are:

- Create a test schema
- Run a sample query that performs well
- Induce a plan performance regression
- Run the sample query again, and the performance regression will be repaired
- Reset the test
- Induce a plan performance regression, demonstrating a "runaway" query interrupted by Database Resource Manager
- Run the sample query again, and the performance regression will be repaired

### Prerequisites
- An Oracle Cloud Account - Please view this workshop's LiveLabs landing page to see which environments are supported.

## How it Works

If an execution plan for a known SQL statement canges, real-time SPM compares the performance of the new plan with a previous execution plan (stored in the automatic SQL tuning set). A SQL plan baseline will be created for the plan that performs best. In this way, automatic SPM reduces the risk of experiencing SQL performance regressions caused by execution plan changes.

## Acknowledgements
* **Author** - Nigel Bayliss, Dec 2024
* **Last Updated By/Date** - Nigel Bayliss, Jan 2025
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
104 changes: 104 additions & 0 deletions shared/adb-real-time-spm/provision-atp/provision-atp.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
# Provision an Autonomous Database Instance

## Introduction

This workshop walks you through the steps to get started using the Oracle Autonomous Database. For this workshop we're going to use an **Autonomous Database Optimized for Transaction Processing (ATP)**. You will provision a new database in just a few minutes. Real-time SPM was introduced in Oracle Database 23ai, but it was backported to Oracle _Autonomous_ Database 19c, so it is available in this version, too.

Oracle Autonomous Databases have the following characteristics:

**Self-driving**
Automates database provisioning, tuning, and scaling.

- Provisions highly available databases, configures and tunes for specific workloads, and scales compute resources when needed, all done automatically.

**Self-securing**
Automates data protection and security.

- Protect sensitive and regulated data automatically, patch your database for security vulnerabilities, and prevent unauthorized access—all with Oracle Autonomous Database.

**Self-repairing**
Automates failure detection, failover, and repair.

- Detect and protect from system failures and user errors automatically and provide failover to standby databases with zero data loss.

Estimated Lab Time: 15 minutes.

### Objectives
- Create an Autonomous Database with the latest features of Oracle Databases

## Task 1: Create a new Autonomous Transaction Processing Database

1. Click on the navigation menu at the upper left corner of the page.

This will produce a drop-down menu, click **Oracle Database** and then select **Autonomous Transaction Processing**.

![Oracle Cloud Web Console](./images/prov-1.png " ")

This will take you to the management console page.

To learn more about comparments, see [Managing Compartments](https://docs.cloud.oracle.com/en-us/iaas/Content/Identity/Tasks/managingcompartments.htm).

2. To create a new instance, click the **Create Autonomous Database** button.

![Create ADB](./images/prov-2.png)

Enter the required information and click the **Create Autonomous Database** button at the bottom of the form. For the purposes of this workshop, use the information below:

- **Compartment:** Verify that a compartment ( &lt;tenancy_name&gt; ) is selected.

By default, any OCI tenancy has a default ***root*** compartment, named after the tenancy itself. The tenancy administrator (default root compartment administrator) is any user who is a member of the default Administrators group. For the workshop purpose, you can use ***root***.

- **Display Name:** Enter the display name for your ATP Instance.

- **Database Name:** Enter any database name you choose that fits the requirements for ATP. The database name must consist of letters and numbers only, starting with a letter. The maximum length is 14 characters. You can leave the name provided. That field is not a mandatory one.
- **Workload Type:** Autonomous Transaction Processing

- **Deployment Type:** Serverless

- **Always Free:** Off

- **Compute auto scaling:** Unchecked

- **Choose database version:** 19c or 23ai (you can choose either)

- **Other settings (ECPU count, etc):** Leave as default

![ADB Creation Details](./images/prov-3.png)

3. Under **Create administration credentials** and **Choose network access** sections:

- **Administrator Password:** Enter any password you wish to use noting the specific requirements imposed by ATP.

- **Reminder:** Note your password in a safe location.

- **Access type**: Choose **Secure access from everywhere**

- **Contact email**: Enter a contact email address.

![ADB Creation](./images/prov-4.png)

4. Create the database.

When you have completed the required fields, scroll down and click on the **Create Autonomous Database** button at the bottom of the form:

![ADB Creation](./images/prov-5.png)

5. The Autonomous Database **Details** page will show information about your new instance. You should notice the various menu buttons that help you manage your new instance - because the instance is currently being provisioned all the management buttons are greyed out.

![ADB Creation Provisioning](./images/prov-6.png)

The provisioning process should take **under 5 minutes**.

6. After a short while, the status will change to **Available** and the "ATP" box will change color:

![ADB Creation Provisioning Green](./images/prov-7.png)

You have just created an Autonomous Database with the latest features of Oracle Databases.

You may now *proceed to the next lab.*

## Acknowledgements

- **Author** - Priscila Iruela - Technology Product Strategy Director, Juan Antonio Martin Pedro - Analytics Business Development
- **Contributors** - Victor Martin, Melanie Ashworth-March, Andrea Zengin
- **Last Updated By/Date** - Nigel Bayliss, Jan 2025
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading

0 comments on commit a2375ae

Please sign in to comment.