/*
* TASK POST CAPTURE
* Get AWR from Capture
*
*/
-- Define these values
-- replace every name with current date, example: 'xxxx_20210818'
define sqlsettable = 'TABLE_STS_database_20210818'
define sqlset = 'STS_database_RAT_PROD_0210818'
define baseline = 'database_baseline_0210818'
-- Please create a new snapshot:
execute dbms_workload_repository.create_snapshot();
-- Execute this query and get capture id
-- (the last row it must to be the last capture finished)
column id new_value capture_id
select max(id) id--,name
from dba_workload_captures ;
-- Generating Workload Capture Reports Using APIs
DECLARE
cap_id NUMBER;
cap_rpt CLOB;
BEGIN
cap_id := DBMS_WORKLOAD_CAPTURE.GET_CAPTURE_INFO(dir => 'dec06');
cap_rpt := DBMS_WORKLOAD_CAPTURE.REPORT(capture_id => cap_id,
format => DBMS_WORKLOAD_CAPTURE.TYPE_TEXT);
END;
/
-- This will generate dmp into de DB directory capture
-- using the previous capture_id
BEGIN
DBMS_WORKLOAD_CAPTURE.EXPORT_AWR (capture_id => &capture_id);
END;
/
-- Create baseline using the snaps id beetwen the start and finish capture hours.
column AWR_BEGIN_SNAP new_value begin_snap
column AWR_END_SNAP new_value end_snap
select AWR_BEGIN_SNAP,AWR_END_SNAP
from dba_workload_captures
where id = &capture_id;
EXECUTE DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE (start_snap_id => &begin_snap, end_snap_id => &end_snap ,baseline_name => '&baseline');
-- Create SQLSET TABLE
BEGIN
DBMS_SQLTUNE.create_stgtab_sqlset (table_name => '&sqlsettable', schema_name => 'SYSTEM', tablespace_name => 'SYSTEM' );
END;
/
-- Create SQLSET
BEGIN
DBMS_SQLTUNE.CREATE_SQLSET (
sqlset_name => '&sqlset',
description => '12c STS database');
END;
/
-- LOAD_SQLSET with the baseline, using the begin and end snap of capture
declare
baseline_ref_cur DBMS_SQLTUNE.SQLSET_CURSOR;
begin
open baseline_ref_cur for select VALUE(p) from table(
DBMS_SQLTUNE.SELECT_WORKLOAD_REPOSITORY(&begin_snap,&end_snap, 'parsing_schema_name not in (''DBSNMP'',''SYS'')' ,NULL,NULL,NULL,NULL,NULL,NULL,'ALL')) p;
DBMS_SQLTUNE.LOAD_SQLSET('&sqlset', baseline_ref_cur);
end;
/
-- pack the sqlset into the sqlset_table
BEGIN
DBMS_SQLTUNE.pack_stgtab_sqlset(sqlset_name => '&sqlset',
sqlset_owner => 'SYS',
staging_table_name => '&sqlsettable',
staging_schema_owner => 'SYSTEM');
END;
/
-- Please generate dump with the SQLSet table and copy to the exa target
-- (the value of &sqlsettable)
exp system/xxxxx tables='&sqlsettable' file=exp_sts_database_rat.dmp log=exp_sts_database_rat.log
--- After we need to copy this file to the target database environment.