├── capture_awr.sql ├── capture_cc.sql ├── check_components.sql ├── check_inv_objects.sql ├── check_patches.sql ├── check_patches_18.sql ├── check_patches_19.sql ├── check_patches_size.sql ├── export_sts_stagingtable.sql ├── import_sts_stagingtable.sql ├── list_stmts_sqlset.sql ├── spa_buffer.sql ├── spa_cpu.sql ├── spa_elapsed.sql ├── spa_report_buffer.sql ├── spa_report_cpu.sql ├── spa_report_elapsed.sql ├── spm_load_all.sql ├── sta_awr.sql ├── sta_cc.sql └── unload_blob_from_table.sql /capture_awr.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/capture_awr.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Capture SQL Statements from AWR into a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @capture_awr.sql 7 | -- Last Modified: 09/11/2023 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LINESIZE 400 14 | 15 | -- 16 | -- Drop the SQL Tuning SET if it exists 17 | -- 18 | 19 | DECLARE 20 | 21 | sts_exists number; 22 | stmt_count number; 23 | cur sys_refcursor; 24 | begin_id number; 25 | end_id number; 26 | 27 | BEGIN 28 | 29 | SELECT count(*) 30 | INTO sts_exists 31 | FROM DBA_SQLSET 32 | WHERE rownum = 1 AND 33 | name = 'STS_CaptureAWR'; 34 | 35 | IF sts_exists = 1 THEN 36 | SYS.DBMS_SQLTUNE.DROP_SQLSET( 37 | sqlset_name=>'STS_CaptureAWR' 38 | ); 39 | ELSE 40 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does not exist - will be created ...'); 41 | END IF; 42 | 43 | 44 | -- 45 | -- Create a SQL Tuning SET 'STS_CaptureCursorCache' 46 | -- 47 | 48 | SYS.DBMS_SQLTUNE.CREATE_SQLSET( 49 | sqlset_name=>'STS_CaptureAWR', 50 | description=>'Statements from AWR Before-Change' 51 | ); 52 | 53 | DBMS_WORKLOAD_REPOSITORY.CREATE_SNAPSHOT; 54 | 55 | SELECT min(snap_id) 56 | INTO begin_id 57 | FROM dba_hist_snapshot; 58 | 59 | 60 | SELECT max(snap_id) 61 | INTO end_id 62 | FROM dba_hist_snapshot; 63 | 64 | DBMS_OUTPUT.PUT_LINE('Snapshot Range between ' || begin_id || ' and ' || end_id || '.'); 65 | 66 | open cur for 67 | select value(p) from table(dbms_sqltune.select_workload_repository( 68 | begin_snap => begin_id, 69 | end_snap => end_id, 70 | basic_filter => 'parsing_schema_name not in (''DBSNMP'',''SYS'',''ORACLE_OCM'')', 71 | ranking_measure1 => 'elapsed_time', 72 | result_limit => 5000)) p; 73 | dbms_sqltune.load_sqlset('STS_CaptureAWR', cur); 74 | close cur; 75 | 76 | -- 77 | -- Display the amount of statements collected in the STS 78 | -- 79 | 80 | SELECT statement_count 81 | INTO stmt_count 82 | FROM dba_sqlset 83 | WHERE name = 'STS_CaptureAWR'; 84 | 85 | DBMS_OUTPUT.PUT_LINE('There are ' || stmt_count || ' SQL Statements in STS_CaptureAWR.'); 86 | -- 87 | -- If you need more details please use: 88 | -- 89 | -- SELECT sql_text,cpu_time,elapsed_time, executions, buffer_gets 90 | -- FROM dba_sqlset_statements 91 | -- WHERE sqlset_name='STS_CaptureAWR'; 92 | -- 93 | 94 | END; 95 | / 96 | -------------------------------------------------------------------------------- /capture_cc.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/capture_cc.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Capture SQL Statements from Cursor Cache into a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @capture_cc.sql 7 | -- Last Modified: 29/05/2017 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LINESIZE 400 14 | 15 | -- 16 | -- Drop the SQL Tuning SET if it exists 17 | -- 18 | 19 | DECLARE 20 | 21 | sts_exists number; 22 | stmt_count number; 23 | 24 | BEGIN 25 | 26 | SELECT count(*) 27 | INTO sts_exists 28 | FROM DBA_SQLSET 29 | WHERE rownum = 1 AND 30 | name = 'STS_CaptureCursorCache'; 31 | 32 | IF sts_exists = 1 THEN 33 | SYS.DBMS_SQLTUNE.DROP_SQLSET( 34 | sqlset_name=>'STS_CaptureCursorCache' 35 | ); 36 | ELSE 37 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does not exist - will be created ...'); 38 | END IF; 39 | 40 | 41 | -- 42 | -- Create a SQL Tuning SET 'STS_CaptureCursorCache' 43 | -- 44 | 45 | SYS.DBMS_SQLTUNE.CREATE_SQLSET( 46 | sqlset_name=>'STS_CaptureCursorCache', 47 | description=>'Statements from Before-Change' 48 | ); 49 | 50 | 51 | -- 52 | -- Poll the Cursor Cache 53 | -- time_limit: The total amount of time, in seconds, to execute 54 | -- repeat_interval: The amount of time, in seconds, to pause between sampling 55 | -- Adjust both settings based on needs 56 | -- 57 | 58 | DBMS_OUTPUT.PUT_LINE('Now polling the cursor cache for 30 seconds every 5 seconds ...'); 59 | 60 | DBMS_SQLTUNE.CAPTURE_CURSOR_CACHE_SQLSET( 61 | sqlset_name => 'STS_CaptureCursorCache', 62 | time_limit => 30, 63 | repeat_interval => 5, 64 | capture_option => 'MERGE', 65 | capture_mode => DBMS_SQLTUNE.MODE_ACCUMULATE_STATS, 66 | basic_filter => NULL, 67 | sqlset_owner => NULL, 68 | recursive_sql => 'HAS_RECURSIVE_SQL'); 69 | 70 | -- 71 | -- Display the amount of statements collected in the STS 72 | -- 73 | 74 | SELECT statement_count 75 | INTO stmt_count 76 | FROM dba_sqlset 77 | WHERE name = 'STS_CaptureCursorCache'; 78 | 79 | DBMS_OUTPUT.PUT_LINE('There are now ' || stmt_count || ' SQL Statements in this STS.'); 80 | 81 | -- 82 | -- If you need more details please use: 83 | -- 84 | -- SELECT sql_text,cpu_time,elapsed_time, executions, buffer_gets 85 | -- FROM dba_sqlset_statements 86 | -- WHERE sqlset_name='STS_CaptureCursorCache'; 87 | -- 88 | 89 | END; 90 | / 91 | -------------------------------------------------------------------------------- /check_components.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/check_componets.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Displays installed components from DBA_REGISTRY 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_components.sql 7 | -- Last Modified: 24/07/2017 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | set line 200 11 | set pages 1000 12 | col COMP_ID format a8 13 | col COMP_NAME format a34 14 | col SCHEMA format a12 15 | col STATUS format a10 16 | col VERSION format a12 17 | col CON_ID format 99 18 | 19 | select CON_ID, COMP_ID, comp_name, schema, status, version from CDB_REGISTRY order by 1,2; 20 | -------------------------------------------------------------------------------- /check_inv_objects.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/check_inv_objs.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Shows invalid objects CDB-wide per CON_ID 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_inv_objs.sql 7 | -- Last Modified: 24/07/2017 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | set line 200 11 | set pages 1000 12 | col owner format a12 13 | col object_type format a12 14 | col object_name format a30 15 | col STATUS format a8 16 | col CON_ID format 9 17 | 18 | select con_id, owner, object_type, object_name, status from CDB_OBJECTS where status='INVALID' order by 1,2,3; -------------------------------------------------------------------------------- /check_patches.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/check_patches.sql 3 | -- Author : Mike Dietrich (2nd query borrowed from Tim Hall) 4 | -- Description : Displays contents of the patches (BP/PSU) registry and history 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_patches.sql 7 | -- Last Modified: 13/07/2018 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET LINESIZE 500 11 | SET PAGESIZE 1000 12 | SET SERVEROUT ON 13 | SET LONG 2000000 14 | 15 | COLUMN action_time FORMAT A12 16 | COLUMN action FORMAT A10 17 | COLUMN bundle_series FORMAT A4 18 | COLUMN comments FORMAT A30 19 | COLUMN description FORMAT A40 20 | COLUMN namespace FORMAT A20 21 | COLUMN status FORMAT A10 22 | COLUMN version FORMAT A10 23 | 24 | spool check_patches.txt 25 | 26 | SELECT TO_CHAR(action_time, 'YYYY-MM-DD') AS action_time, 27 | action, 28 | status, 29 | description, 30 | version, 31 | patch_id, 32 | bundle_series 33 | FROM sys.dba_registry_sqlpatch 34 | ORDER by action_time; 35 | 36 | 37 | spool off -------------------------------------------------------------------------------- /check_patches_18.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/18c/check_patchesi_18.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Displays contents of the patches (BP/PSU) registry and history 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_patches_18.sql 7 | -- Last Modified: 24/07/2018 8 | -- Database Rel.: Oracle 12.2.0.1, Oracle 18c, Oracle 19c 9 | -- ----------------------------------------------------------------------------------- 10 | 11 | SET LINESIZE 500 12 | SET PAGESIZE 1000 13 | SET SERVEROUT ON 14 | SET LONG 2000000 15 | 16 | COLUMN action_time FORMAT A12 17 | COLUMN action FORMAT A10 18 | COLUMN patch_type FORMAT A10 19 | COLUMN description FORMAT A32 20 | COLUMN status FORMAT A10 21 | COLUMN version FORMAT A10 22 | 23 | alter session set "_exclude_seed_cdb_view"=FALSE; 24 | 25 | spool check_patches_18.txt 26 | 27 | select CON_ID, 28 | TO_CHAR(action_time, 'YYYY-MM-DD') AS action_time, 29 | PATCH_ID, 30 | PATCH_TYPE, 31 | ACTION, 32 | DESCRIPTION, 33 | SOURCE_VERSION, 34 | TARGET_VERSION 35 | from CDB_REGISTRY_SQLPATCH 36 | order by CON_ID, action_time, patch_id; 37 | 38 | 39 | 40 | spool off -------------------------------------------------------------------------------- /check_patches_19.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/19/check_patchesi_19.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Displays contents of the patches (BP/PSU) registry and history 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_patches_19.sql 7 | -- Last Modified: 24/03/2020 8 | -- Database Rel.: Oracle 19c 9 | -- ----------------------------------------------------------------------------------- 10 | 11 | SET LINESIZE 500 12 | SET PAGESIZE 1000 13 | SET SERVEROUT ON 14 | SET LONG 2000000 15 | 16 | COLUMN action_time FORMAT A20 17 | COLUMN action FORMAT A10 18 | COLUMN status FORMAT A10 19 | COLUMN description FORMAT A40 20 | COLUMN source_version FORMAT A13 21 | COLUMN target_version FORMAT A13 22 | COLUMN version_full FORMAT A13 23 | COLUMN comp_id FORMAT A8 24 | 25 | 26 | alter session set "_exclude_seed_cdb_view"=FALSE; 27 | 28 | spool check_patches_19.txt 29 | 30 | select CON_ID, 31 | TO_CHAR(action_time, 'YYYY-MM-DD') AS action_time, 32 | PATCH_ID, 33 | PATCH_TYPE, 34 | ACTION, 35 | DESCRIPTION, 36 | SOURCE_VERSION, 37 | TARGET_VERSION 38 | from CDB_REGISTRY_SQLPATCH 39 | order by CON_ID, action_time, patch_id; 40 | 41 | select CON_ID, 42 | COMP_ID, 43 | VERSION_FULL, 44 | STATUS 45 | from CDB_REGISTRY 46 | order by CON_ID, COMP_ID; 47 | 48 | spool off 49 | -------------------------------------------------------------------------------- /check_patches_size.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/check_patches_size.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Displays the space being used to store patch rollback zip files 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @check_patches_size.sql 7 | -- Last Modified: 15/01/2024 8 | -- Database Rel.: Oracle 19c 9 | -- ----------------------------------------------------------------------------------- 10 | 11 | 12 | column patch_id format 9999999999 13 | column ru_version format a15 14 | column lob_size_md format 9999 15 | COLUMN ru_build_ts FORMAT A20 16 | COLUMN SUBSTR(description,1,40) FORMAT A40 17 | 18 | set linesize 100 19 | set pagesize 300 20 | 21 | ALTER SESSION SET NLS_TIMESTAMP_FORMAT = 'MM/DD/YY HH24:MI'; 22 | ALTER SESSION SET "_EXCLUDE_SEED_CDB_VIEW" = FALSE; 23 | 24 | SELECT 25 | patch_id, 26 | ru_version, 27 | TO_CHAR(ru_build_timestamp, 'MM/DD/YYYY HH24:MI:SS') AS ru_build_ts, 28 | round(dbms_lob.getlength(patch_directory) / 1024 / 1024) lob_size_mb 29 | FROM 30 | sys.registry$sqlpatch_ru_info; 31 | 32 | SELECT 33 | patch_id, 34 | SUBSTR(description,1,40) PATCH_DESCRIPTION, 35 | TO_CHAR(source_build_timestamp, 'MM/DD/YYYY HH24:MI:SS') AS patch_build_ts, 36 | round(dbms_lob.getlength(patch_directory) / 1024 / 1024) lob_size_mb 37 | FROM 38 | sys.registry$sqlpatch 39 | WHERE 40 | patch_type<>'RU'; 41 | 42 | 43 | 44 | SELECT 45 | con_id, round(sum(dbms_lob.getlength(patch_directory) / 1024 / 1024)) total_lob_size_mba 46 | FROM 47 | containers(sys.registry$sqlpatch_ru_info) 48 | GROUP BY 49 | con_id 50 | ORDER BY 51 | con_id; 52 | 53 | SELECT 54 | con_id, round(sum(dbms_lob.getlength(patch_directory) / 1024 / 1024)) total_lob_size_mba 55 | FROM 56 | containers(sys.registry$sqlpatch) 57 | GROUP BY 58 | con_id 59 | ORDER BY 60 | con_id; 61 | 62 | -------------------------------------------------------------------------------- /export_sts_stagingtable.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/export_sts_stagingtable.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Pack a SQL Tuning Set into a staging table and export it 5 | -- Requirements : User TPCC needs READ, WRITE ON DIRECTORY DATA_PUMP_DIR 6 | -- User TPCC needs EXP_FULL_DATABASE or at least parts of it 7 | -- The SQL Tuning Set (STS) to be exported is owned by TPCC 8 | -- Call Syntax : @sts_staging_exp.sql 9 | -- Last Modified: 06/11/2023 10 | -- Database Rel.: Oracle 19c and others 11 | -- ----------------------------------------------------------------------------------- 12 | 13 | 14 | 15 | DECLARE 16 | 17 | l_dp_handle number; 18 | 19 | BEGIN 20 | 21 | -- 22 | -- Check if Staging Table exists 23 | -- If it does exist, drop it 24 | -- If it does not exist, create it 25 | -- In 23c improved syntax using IF NOT EXISTS would shorten code 26 | -- 27 | 28 | EXECUTE IMMEDIATE 'DROP TABLE TPCC.TAB_STAGE1'; 29 | EXCEPTION 30 | WHEN OTHERS THEN 31 | IF SQLCODE != -942 THEN 32 | RAISE; 33 | END IF; 34 | 35 | 36 | 37 | DBMS_SQLTUNE.CREATE_STGTAB_SQLSET ( 38 | table_name => 'TAB_STAGE1', 39 | schema_name => 'TPCC'); 40 | 41 | DBMS_OUTPUT.PUT_LINE('Staging table TPCC.TAB_STAGE1 has been created successfully.'); 42 | 43 | 44 | -- 45 | -- Move STS into the staging table 46 | -- 47 | 48 | DBMS_SQLTUNE.PACK_STGTAB_SQLSET( 49 | sqlset_name =>'STS_CaptureCursorCache', 50 | sqlset_owner=>'TPCC', 51 | -- staging_table_owner =>'TPCC', 52 | staging_table_name =>'TAB_STAGE1'); 53 | 54 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set STS_CaptureCursorCache has been moved into staging table.'); 55 | 56 | 57 | -- 58 | -- Export the staging table into the DATA_PUMP_DIR 59 | -- See: https://oracle-base.com/articles/misc/data-pump-api#table-export 60 | -- 61 | 62 | -- Open a table export job. 63 | l_dp_handle := dbms_datapump.open( 64 | operation => 'EXPORT', 65 | job_mode => 'TABLE', 66 | remote_link => NULL, 67 | job_name => 'STS_STAGING_EXPORT', 68 | version => 'LATEST'); 69 | 70 | -- Specify the dump file name and directory object name. 71 | dbms_datapump.add_file( 72 | handle => l_dp_handle, 73 | filename => 'sts_staging_export.dmp', 74 | directory => 'DATA_PUMP_DIR'); 75 | 76 | 77 | -- Specify the log file name and directory object name. 78 | dbms_datapump.add_file( 79 | handle => l_dp_handle, 80 | filename => 'sts_staging_export_LOG.log', 81 | directory => 'DATA_PUMP_DIR', 82 | filetype => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE); 83 | 84 | -- Specify the table to be exported, filtering the schema and table. 85 | dbms_datapump.metadata_filter( 86 | handle => l_dp_handle, 87 | name => 'SCHEMA_EXPR', 88 | value => '= ''TPCC'''); 89 | 90 | dbms_datapump.metadata_filter( 91 | handle => l_dp_handle, 92 | name => 'NAME_EXPR', 93 | value => '= ''TAB_STAGE1'''); 94 | 95 | dbms_datapump.start_job(l_dp_handle); 96 | 97 | dbms_datapump.detach(l_dp_handle); 98 | 99 | END; 100 | / 101 | -------------------------------------------------------------------------------- /import_sts_stagingtable.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/import_sts_stagingtable.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Import a SQL Tuning Set from a staging table export 5 | -- Requirements : User TPCC needs READ, WRITE ON DIRECTORY DATA_PUMP_IMP 6 | -- User TPCC needs IMP_FULL_DATABASE, or at least parts of it 7 | -- Call Syntax : @sts_staging_exp.sql 8 | -- Last Modified: 06/11/2023 9 | -- Database Rel.: Oracle 19c and others 10 | -- Import Script: https://oracle-base.com/articles/misc/data-pump-api 11 | -- ----------------------------------------------------------------------------------- 12 | 13 | SET SERVEROUT ON 14 | COLUMN NAME FORMAT A30 15 | COLUMN OWNER FORMAT A30 16 | 17 | 18 | declare 19 | l_dp_handle number; 20 | 21 | begin 22 | -- Open a schema import job. 23 | l_dp_handle := dbms_datapump.open( 24 | operation => 'IMPORT', 25 | job_mode => 'TABLE', 26 | remote_link => NULL, 27 | job_name => 'TESTUSER1_EMP_IMPORT', 28 | version => 'LATEST'); 29 | 30 | -- Specify the dump file name and directory object name. 31 | dbms_datapump.add_file( 32 | handle => l_dp_handle, 33 | filename => 'sts_staging_export.dmp', 34 | directory => 'DATA_PUMP_IMP'); 35 | 36 | -- Specify the log file name and directory object name. 37 | dbms_datapump.add_file( 38 | handle => l_dp_handle, 39 | filename => 'sts_staging_import_LOG.log', 40 | directory => 'DATA_PUMP_IMP', 41 | filetype => DBMS_DATAPUMP.KU$_FILE_TYPE_LOG_FILE); 42 | 43 | dbms_datapump.start_job(l_dp_handle); 44 | 45 | dbms_datapump.detach(l_dp_handle); 46 | 47 | dbms_output.put_line('Import of staging table TAB_STAGE1 has been finished.'); 48 | 49 | -- 50 | -- The following section is neceesary to avoid errors such as: 51 | -- ORA-15705: staging table does not exist 52 | -- ORA-19385: staging table is empty 53 | -- This seems to be credited to the timing. 54 | -- The commits and the 10 second sleep are only there to ensure 55 | -- that the staging table is present and rows are seen. 56 | -- 57 | 58 | 59 | commit; 60 | dbms_session.sleep(10); 61 | dbms_output.put_line('Import of staging table TAB_STAGE1 has been finished.'); 62 | commit; 63 | 64 | -- 65 | -- Unpack the staging table 66 | -- into a SQL Tuning Set 67 | -- 68 | 69 | DBMS_SQLTUNE.UNPACK_STGTAB_SQLSET ( 70 | sqlset_name => 'STS_CaptureCursorCache', 71 | sqlset_owner => 'TPCC', 72 | replace => TRUE, 73 | staging_table_name => 'TAB_STAGE1', 74 | staging_schema_owner => 'TPCC' ); 75 | 76 | dbms_output.put_line('Staging table TAB_STAGE1 has been unpacked into STS_CaptureCursorCache.'); 77 | 78 | end; 79 | / 80 | -------------------------------------------------------------------------------- /list_stmts_sqlset.sql: -------------------------------------------------------------------------------- 1 | -- --------------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/list_stmts_sqlset.sql 3 | -- Author : Mike Dietrich 4 | -- Description : List the contents of a SQL Tuning Set, here: STS_CaptureCursorCache 5 | -- Call Syntax : @list_stmts_sqlset.sql 6 | -- Last Modified: 12/11/2023 7 | -- Database Rel.: Oracle 19c and others 8 | -- Credits : Ulrike Schwinn 9 | -- https://blogs.oracle.com/coretec/post/oracle-sql-tuning-sets-the-basis-for-sql-tuning 10 | -- --------------------------------------------------------------------------------------- 11 | 12 | set linesize window 13 | set pages 50000 14 | set long 300000 15 | 16 | 17 | 18 | select 19 | sql_id, 20 | executions, 21 | trunc(elapsed_time/1000,0) ELAPSED_IN_MS, 22 | trunc(cpu_time/1000,0) CPU_IN_MS, 23 | substr(sql_text,1,100) SQL_STATEMENT 24 | from 25 | dba_sqlset_statements 26 | where 27 | sqlset_name = 'STS_CaptureCursorCache' and 28 | sqlset_owner = 'TPCC' 29 | ORDER BY 3 desc; 30 | -------------------------------------------------------------------------------- /spa_buffer.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/run_spa.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Run SQL Performance Analyzer on a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @run_spa.sql 7 | -- Last Modified: 20/06/2018 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LINESIZE 400 14 | 15 | -- 16 | -- Check if SQL Tuning SET if it exists 17 | -- 18 | 19 | DECLARE 20 | 21 | sts_exists number; 22 | sts_task VARCHAR2(64); 23 | tname VARCHAR2(100); 24 | spa_exists number; 25 | 26 | BEGIN 27 | 28 | SELECT count(*) 29 | INTO sts_exists 30 | FROM DBA_SQLSET 31 | WHERE rownum = 1 AND 32 | name = 'STS_CaptureAWR'; 33 | 34 | IF sts_exists <> 1 THEN 35 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does not exist - creating it ...'); 36 | SYS.DBMS_SQLTUNE.CREATE_SQLSET( 37 | sqlset_name=>'STS_CaptureAWR', 38 | description=>'Statements from AWR Before-Change' 39 | ); 40 | ELSE 41 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does exist - will run SPA now ...'); 42 | END IF; 43 | 44 | 45 | SELECT count(*) 46 | INTO spa_exists 47 | FROM DBA_ADVISOR_TASKS 48 | WHERE rownum = 1 AND 49 | task_name = 'UPGRADE_TO_19C_3'; 50 | 51 | IF spa_exists = 1 THEN 52 | SYS.DBMS_SQLPA.DROP_ANALYSIS_TASK( 53 | task_name=>'UPGRADE_TO_19C_3' 54 | ); 55 | ELSE 56 | DBMS_OUTPUT.PUT_LINE('SQL Performance Analyzer Task does not exist - will be created ...'); 57 | END IF; 58 | 59 | -- 60 | -- Create a SPA Task and parameterize it 61 | -- 62 | 63 | 64 | tname := DBMS_SQLPA.CREATE_ANALYSIS_TASK( 65 | sqlset_name=>'STS_CaptureAWR', 66 | task_name=>'UPGRADE_TO_19C_3', 67 | description=>'Move on to 19c'); 68 | 69 | -- 70 | -- Set Parameters for SPA Task 71 | -- 72 | 73 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 74 | task_name => 'UPGRADE_TO_19C_3', 75 | parameter => 'workload_impact_threshold', 76 | value => 2); 77 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 78 | task_name => 'UPGRADE_TO_19C_3', 79 | parameter => 'sql_impact_threshold', 80 | value => 2); 81 | 82 | -- 83 | -- Convert STS information from 11.2.0.4 84 | -- 85 | 86 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 87 | task_name => 'UPGRADE_TO_19C_3', 88 | execution_name => 'EXEC_SPA_TASK_11204', 89 | execution_type => 'CONVERT SQLSET', 90 | execution_desc => 'Convert 11204 Workload'); 91 | 92 | -- 93 | -- Simulate execution of STS in 19c 94 | -- 95 | 96 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 97 | task_name => 'UPGRADE_TO_19C_3', 98 | execution_name => 'EXEC_SPA_TASK_19C_3', 99 | execution_type => 'TEST EXECUTE', 100 | execution_desc => 'Test 11204 Workload in 19c'); 101 | 102 | -- 103 | -- Compare performance before/after on BUFFER_GETS 104 | -- 105 | 106 | 107 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 108 | task_name => 'UPGRADE_TO_19C_3', 109 | execution_name => 'Compare 11204 to 19c BUFFER_GETS', 110 | execution_type => 'COMPARE PERFORMANCE', 111 | execution_params => 112 | DBMS_ADVISOR.ARGLIST( 113 | 'comparison_metric', 114 | 'buffer_gets', 115 | 'execution_name1','EXEC_SPA_TASK_11204', 116 | 'execution_name2','EXEC_SPA_TASK_19C_3'), 117 | execution_desc => 'Compare 11204 to 19c BUFFER_GETS' 118 | ); 119 | 120 | 121 | END; 122 | / 123 | 124 | -------------------------------------------------------------------------------- /spa_cpu.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/run_spa.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Run SQL Performance Analyzer on a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @run_spa.sql 7 | -- Last Modified: 20/06/2018 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LINESIZE 400 14 | 15 | -- 16 | -- Check if SQL Tuning SET if it exists 17 | -- 18 | 19 | DECLARE 20 | 21 | sts_exists number; 22 | sts_task VARCHAR2(64); 23 | tname VARCHAR2(100); 24 | spa_exists number; 25 | 26 | BEGIN 27 | 28 | SELECT count(*) 29 | INTO sts_exists 30 | FROM DBA_SQLSET 31 | WHERE rownum = 1 AND 32 | name = 'STS_CaptureAWR'; 33 | 34 | IF sts_exists <> 1 THEN 35 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does not exist - creating it ...'); 36 | SYS.DBMS_SQLTUNE.CREATE_SQLSET( 37 | sqlset_name=>'STS_CaptureAWR', 38 | description=>'Statements from AWR Before-Change' 39 | ); 40 | ELSE 41 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does exist - will run SPA now ...'); 42 | END IF; 43 | 44 | 45 | SELECT count(*) 46 | INTO spa_exists 47 | FROM DBA_ADVISOR_TASKS 48 | WHERE rownum = 1 AND 49 | task_name = 'UPGRADE_TO_19C'; 50 | 51 | IF spa_exists = 1 THEN 52 | SYS.DBMS_SQLPA.DROP_ANALYSIS_TASK( 53 | task_name=>'UPGRADE_TO_19C' 54 | ); 55 | ELSE 56 | DBMS_OUTPUT.PUT_LINE('SQL Performance Analyzer Task does not exist - will be created ...'); 57 | END IF; 58 | 59 | -- 60 | -- Create a SPA Task and parameterize it 61 | -- 62 | 63 | 64 | tname := DBMS_SQLPA.CREATE_ANALYSIS_TASK( 65 | sqlset_name=>'STS_CaptureAWR', 66 | task_name=>'UPGRADE_TO_19C', 67 | description=>'Move to 19c'); 68 | 69 | -- 70 | -- Set Parameters for SPA Task 71 | -- 72 | 73 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 74 | task_name => 'UPGRADE_TO_19C', 75 | parameter => 'workload_impact_threshold', 76 | value => 2); 77 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 78 | task_name => 'UPGRADE_TO_19C', 79 | parameter => 'sql_impact_threshold', 80 | value => 2); 81 | 82 | -- 83 | -- Convert STS information from 11.2.0.4 84 | -- 85 | 86 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 87 | task_name => 'UPGRADE_TO_19C', 88 | execution_name => 'EXEC_SPA_TASK_11204', 89 | execution_type => 'CONVERT SQLSET', 90 | execution_desc => 'Convert 11204 Workload'); 91 | 92 | -- 93 | -- Simulate execution of STS in 19c 94 | -- 95 | 96 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 97 | task_name => 'UPGRADE_TO_19C', 98 | execution_name => 'EXEC_SPA_TASK_19C', 99 | execution_type => 'TEST EXECUTE', 100 | execution_desc => 'Test 11204 Workload in 19c'); 101 | 102 | -- 103 | -- Compare performance before/after on CPU_TIME 104 | -- 105 | 106 | 107 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 108 | task_name => 'UPGRADE_TO_19C', 109 | execution_name => 'Compare 11204 to 19c CPU_TIME', 110 | execution_type => 'COMPARE PERFORMANCE', 111 | execution_params => 112 | DBMS_ADVISOR.ARGLIST( 113 | 'comparison_metric', 114 | 'cpu_time', 115 | 'execution_name1','EXEC_SPA_TASK_11204', 116 | 'execution_name2','EXEC_SPA_TASK_19C'), 117 | execution_desc => 'Compare 11204 to 19c CPU_TIME' 118 | ); 119 | 120 | 121 | END; 122 | / 123 | 124 | -------------------------------------------------------------------------------- /spa_elapsed.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/12c/run_spa.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Run SQL Performance Analyzer on a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @run_spa.sql 7 | -- Last Modified: 20/06/2018 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LINESIZE 400 14 | 15 | -- 16 | -- Check if SQL Tuning SET if it exists 17 | -- 18 | 19 | DECLARE 20 | 21 | sts_exists number; 22 | sts_task VARCHAR2(64); 23 | tname VARCHAR2(100); 24 | spa_exists number; 25 | 26 | BEGIN 27 | 28 | SELECT count(*) 29 | INTO sts_exists 30 | FROM DBA_SQLSET 31 | WHERE rownum = 1 AND 32 | name = 'STS_CaptureAWR'; 33 | 34 | IF sts_exists <> 1 THEN 35 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does not exist - creating it ...'); 36 | SYS.DBMS_SQLTUNE.CREATE_SQLSET( 37 | sqlset_name=>'STS_CaptureAWR', 38 | description=>'Statements from AWR Before-Change' 39 | ); 40 | ELSE 41 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Set does exist - will run SPA now ...'); 42 | END IF; 43 | 44 | 45 | SELECT count(*) 46 | INTO spa_exists 47 | FROM DBA_ADVISOR_TASKS 48 | WHERE rownum = 1 AND 49 | task_name = 'UPGRADE_TO_19C_2'; 50 | 51 | IF spa_exists = 1 THEN 52 | SYS.DBMS_SQLPA.DROP_ANALYSIS_TASK( 53 | task_name=>'UPGRADE_TO_19C_2' 54 | ); 55 | ELSE 56 | DBMS_OUTPUT.PUT_LINE('SQL Performance Analyzer Task does not exist - will be created ...'); 57 | END IF; 58 | 59 | -- 60 | -- Create a SPA Task and parameterize it 61 | -- 62 | 63 | 64 | tname := DBMS_SQLPA.CREATE_ANALYSIS_TASK( 65 | sqlset_name=>'STS_CaptureAWR', 66 | task_name=>'UPGRADE_TO_19C_2', 67 | description=>'Move on from 19c'); 68 | 69 | -- 70 | -- Set Parameters for SPA Task 71 | -- 72 | 73 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 74 | task_name => 'UPGRADE_TO_19C_2', 75 | parameter => 'workload_impact_threshold', 76 | value => 2); 77 | DBMS_SQLPA.SET_ANALYSIS_TASK_PARAMETER( 78 | task_name => 'UPGRADE_TO_19C_2', 79 | parameter => 'sql_impact_threshold', 80 | value => 2); 81 | 82 | 83 | -- 84 | -- Convert STS information from 11.2.0.4 85 | -- 86 | 87 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 88 | task_name => 'UPGRADE_TO_19C_2', 89 | execution_name => 'EXEC_SPA_TASK_11204_2', 90 | execution_type => 'CONVERT SQLSET', 91 | execution_desc => 'Convert 11204 Workload'); 92 | 93 | -- 94 | -- Simulate execution of STS in 19c 95 | -- 96 | 97 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 98 | task_name => 'UPGRADE_TO_19C_2', 99 | execution_name => 'EXEC_SPA_TASK_18C_2', 100 | execution_type => 'TEST EXECUTE', 101 | execution_desc => 'Test 11204 Workload in 19c'); 102 | 103 | -- 104 | -- Compare performance before/after on ELAPSED_TIME 105 | -- 106 | 107 | 108 | DBMS_SQLPA.EXECUTE_ANALYSIS_TASK( 109 | task_name => 'UPGRADE_TO_19C_2', 110 | execution_name => 'Compare 11204 to 19c ELAPSED', 111 | execution_type => 'COMPARE PERFORMANCE', 112 | execution_params => 113 | DBMS_ADVISOR.ARGLIST( 114 | 'comparison_metric', 115 | 'elapsed_time', 116 | 'execution_name1','EXEC_SPA_TASK_11204_2', 117 | 'execution_name2','EXEC_SPA_TASK_18C_2'), 118 | execution_desc => 'Compare 11204 to 19c ELAPSED' 119 | ); 120 | 121 | 122 | END; 123 | / 124 | 125 | -------------------------------------------------------------------------------- /spa_report_buffer.sql: -------------------------------------------------------------------------------- 1 | SET PAGESIZE 0 2 | SET LINESIZE 1000 3 | SET LONG 1000000 4 | SET LONGCHUNKSIZE 1000000 5 | SET TRIMSPOOL ON 6 | SET TRIM ON 7 | 8 | set echo on 9 | column filename new_val filename 10 | select 'compare_spa_runs_' || to_char(sysdate, 'yyyymmddhh24miss' ) || '.html' filename from dual; 11 | 12 | spool &filename 13 | 14 | set echo off 15 | set feedback off 16 | 17 | SELECT DBMS_SQLPA.report_analysis_task( 18 | 'UPGRADE_TO_19C_3', 19 | 'HTML', 20 | 'ALL', 21 | 'ALL' 22 | ) 23 | FROM dual; 24 | 25 | SPOOL OFF 26 | -------------------------------------------------------------------------------- /spa_report_cpu.sql: -------------------------------------------------------------------------------- 1 | SET PAGESIZE 0 2 | SET LINESIZE 1000 3 | SET LONG 1000000 4 | SET LONGCHUNKSIZE 1000000 5 | SET TRIMSPOOL ON 6 | SET TRIM ON 7 | 8 | set echo on 9 | column filename new_val filename 10 | select 'compare_spa_runs_' || to_char(sysdate, 'yyyymmddhh24miss' ) || '.html' filename from dual; 11 | 12 | spool &filename 13 | 14 | set echo off 15 | set feedback off 16 | 17 | SELECT DBMS_SQLPA.report_analysis_task( 18 | 'UPGRADE_TO_19C', 19 | 'HTML', 20 | 'ALL', 21 | 'ALL' 22 | ) 23 | FROM dual; 24 | 25 | SPOOL OFF 26 | -------------------------------------------------------------------------------- /spa_report_elapsed.sql: -------------------------------------------------------------------------------- 1 | SET PAGESIZE 0 2 | SET LINESIZE 1000 3 | SET LONG 1000000 4 | SET LONGCHUNKSIZE 1000000 5 | SET TRIMSPOOL ON 6 | SET TRIM ON 7 | 8 | set echo on 9 | column filename new_val filename 10 | select 'compare_spa_runs_' || to_char(sysdate, 'yyyymmddhh24miss' ) || '.html' filename from dual; 11 | 12 | spool &filename 13 | 14 | set echo off 15 | set feedback off 16 | 17 | SELECT DBMS_SQLPA.report_analysis_task( 18 | 'UPGRADE_TO_19C_2', 19 | 'HTML', 20 | 'ALL', 21 | 'ALL' 22 | ) 23 | FROM dual; 24 | 25 | SPOOL OFF 26 | -------------------------------------------------------------------------------- /spm_load_all.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://MikeDietrichDE.com/wp-content/scripts/19/spm_load_all.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Load all plans from a SQL Tuning Set into SPM 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @spm_load_all.sql 7 | -- Last Modified: 06/11/2023 8 | -- Database Rel.: Oracle 19c and others 9 | -- ----------------------------------------------------------------------------------- 10 | 11 | SET SERVEROUT ON 12 | SET PAGESIZE 1000 13 | SET LONG 2000000 14 | SET LINESIZE 400 15 | 16 | 17 | DECLARE 18 | 19 | l_plans_loaded PLS_INTEGER; 20 | 21 | BEGIN 22 | 23 | l_plans_loaded := DBMS_SPM.load_plans_from_sqlset( 24 | sqlset_name => 'STS_CaptureCursorCache', 25 | fixed => 'YES', 26 | enabled => 'YES' 27 | ); 28 | 29 | END; 30 | / 31 | -------------------------------------------------------------------------------- /sta_awr.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/sta_awr.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Run SQL Tuning Advisor on a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @sta_awr.sql 7 | -- Last Modified: 06/11/2023 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LONGCHUNKSIZE 100000 14 | SET LINESIZE 10000 15 | SET PAGESIZE 10000 16 | 17 | 18 | DECLARE 19 | 20 | sts_task VARCHAR2(64); 21 | tname VARCHAR2(100); 22 | sta_exists number; 23 | 24 | BEGIN 25 | 26 | SELECT count(*) 27 | INTO sta_exists 28 | FROM DBA_ADVISOR_TASKS 29 | WHERE rownum = 1 AND 30 | task_name = 'STA_UPGRADE_TO_19C_AWR'; 31 | 32 | IF sta_exists = 1 THEN 33 | SYS.DBMS_SQLTUNE.DROP_TUNING_TASK( 34 | task_name=>'STA_UPGRADE_TO_19C_AWR' 35 | ); 36 | ELSE 37 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Task does not exist - will be created ...'); 38 | END IF; 39 | 40 | -- 41 | -- Create a STA Task and parameterize it 42 | -- 43 | 44 | 45 | tname := DBMS_SQLTUNE.CREATE_TUNING_TASK( 46 | sqlset_name => 'STS_CaptureAWR', 47 | rank1 => 'BUFFER_GETS', 48 | time_limit => 360, 49 | task_name => 'STA_UPGRADE_TO_19C_AWR', 50 | description => 'Tune AWR Workload for upgrade to 19c'); 51 | 52 | 53 | 54 | -- 55 | -- Simulate execution of STS in 19c 56 | -- 57 | 58 | DBMS_SQLTUNE.EXECUTE_TUNING_TASK( 59 | task_name => 'STA_UPGRADE_TO_19C_AWR'); 60 | 61 | END; 62 | / 63 | 64 | -- 65 | -- Just in case you'd like to monitor the progress of a task 66 | -- 67 | -- SELECT sofar, totalwork FROM V$ADVISOR_PROGRESS WHERE task_id = (SELECT task_id FROM USER_ADVISOR_TASKS WHERE task_name='STA_UPGRADE_TO_19C_AWR'); 68 | -- 69 | 70 | SELECT DBMS_SQLTUNE.REPORT_TUNING_TASK(task_name=>'STA_UPGRADE_TO_19C_AWR', section=>'FINDINGS', result_limit => 20) FROM DUAL; 71 | 72 | SELECT DBMS_SQLTUNE.SCRIPT_TUNING_TASK(task_name=>'STA_UPGRADE_TO_19C_AWR', rec_type=>'ALL') FROM DUAL; 73 | -------------------------------------------------------------------------------- /sta_cc.sql: -------------------------------------------------------------------------------- 1 | -- ----------------------------------------------------------------------------------- 2 | -- File Name : https://github.com/MikeDietrichDE/scripts/blob/main/sta_cc.sql 3 | -- Author : Mike Dietrich 4 | -- Description : Run SQL Tuning Advisor on a SQL Tuning Set 5 | -- Requirements : Access to the DBA role. 6 | -- Call Syntax : @sta_cc.sql 7 | -- Last Modified: 06/11/2023 8 | -- ----------------------------------------------------------------------------------- 9 | 10 | SET SERVEROUT ON 11 | SET PAGESIZE 1000 12 | SET LONG 2000000 13 | SET LONGCHUNKSIZE 100000 14 | SET LINESIZE 10000 15 | SET PAGESIZE 10000 16 | 17 | 18 | DECLARE 19 | 20 | sts_task VARCHAR2(64); 21 | tname VARCHAR2(100); 22 | sta_exists number; 23 | 24 | BEGIN 25 | 26 | SELECT count(*) 27 | INTO sta_exists 28 | FROM DBA_ADVISOR_TASKS 29 | WHERE rownum = 1 AND 30 | task_name = 'STA_UPGRADE_TO_19C_CC'; 31 | 32 | IF sta_exists = 1 THEN 33 | SYS.DBMS_SQLTUNE.DROP_TUNING_TASK( 34 | task_name=>'STA_UPGRADE_TO_19C_CC' 35 | ); 36 | ELSE 37 | DBMS_OUTPUT.PUT_LINE('SQL Tuning Task does not exist - will be created ...'); 38 | END IF; 39 | 40 | -- 41 | -- Create a STA Task and parameterize it 42 | -- 43 | 44 | 45 | tname := DBMS_SQLTUNE.CREATE_TUNING_TASK( 46 | sqlset_name => 'STS_CaptureCursorCache', 47 | rank1 => 'BUFFER_GETS', 48 | time_limit => 360, 49 | task_name => 'STA_UPGRADE_TO_19C_CC', 50 | description => 'Tune CC Workload for upgrade to 19c'); 51 | 52 | 53 | 54 | -- 55 | -- Simulate execution of STS in 19c 56 | -- 57 | 58 | DBMS_SQLTUNE.EXECUTE_TUNING_TASK( 59 | task_name => 'STA_UPGRADE_TO_19C_CC'); 60 | 61 | END; 62 | / 63 | 64 | -- 65 | -- Just in case you'd like to monitor the progress of a task 66 | -- 67 | -- SELECT sofar, totalwork FROM V$ADVISOR_PROGRESS WHERE task_id = (SELECT task_id FROM USER_ADVISOR_TASKS WHERE task_name='STA_UPGRADE_TO_19C_CC'); 68 | -- 69 | 70 | SELECT DBMS_SQLTUNE.REPORT_TUNING_TASK(task_name=>'STA_UPGRADE_TO_19C_CC', section=>'FINDINGS', result_limit => 20) FROM DUAL; 71 | 72 | SELECT DBMS_SQLTUNE.SCRIPT_TUNING_TASK(task_name=>'STA_UPGRADE_TO_19C_CC', rec_type=>'ALL') FROM DUAL; 73 | 74 | -------------------------------------------------------------------------------- /unload_blob_from_table.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- procedure adopted from: 3 | -- https://www.codeproject.com/Questions/898270/How-I-Can-Export-Oracle-blob-Field-to-a-file-on-di 4 | -- and adjusted to my needs. 5 | --- 6 | 7 | 8 | CREATE DIRECTORY ZIP AS '/home/oracle/zip'; 9 | 10 | GRANT READ, WRITE ON DIRECTORY ZIP TO PUBLIC; 11 | 12 | CREATE OR REPLACE PROCEDURE UNLOAD_ZIP ( 13 | p_directory IN VARCHAR2 14 | ) 15 | IS 16 | v_blob BLOB; 17 | v_start NUMBER := 1; 18 | v_bytelen NUMBER := 2000; 19 | v_len NUMBER; 20 | v_raw RAW (2000); 21 | v_x NUMBER; 22 | v_output UTL_FILE.file_type; 23 | v_file_name VARCHAR2 (200); 24 | BEGIN 25 | 26 | FOR i IN (SELECT DBMS_LOB.getlength (PATCH_DIRECTORY) v_len, RU_VERSION v_file_name, 27 | PATCH_DIRECTORY v_blob 28 | FROM SYS.REGISTRY$SQLPATCH_RU_INFO) 29 | 30 | LOOP 31 | v_output := UTL_FILE.fopen (p_directory, i.v_file_name || '.zip', 'wb', 32760); 32 | v_x := i.v_len; 33 | v_start := 1; 34 | v_bytelen := 2000; 35 | 36 | WHILE v_start < i.v_len AND v_bytelen > 0 37 | LOOP 38 | DBMS_LOB.READ (i.v_blob, v_bytelen, v_start, v_raw); 39 | UTL_FILE.put_raw (v_output, v_raw); 40 | UTL_FILE.fflush (v_output); 41 | v_start := v_start + v_bytelen; 42 | v_x := v_x - v_bytelen; 43 | 44 | IF v_x < 2000 45 | THEN 46 | v_bytelen := v_x; 47 | END IF; 48 | END LOOP; 49 | 50 | UTL_FILE.fclose (v_output); 51 | END LOOP; 52 | END UNLOAD_ZIP; 53 | / 54 | 55 | exec unload_zip('ZIP'); 56 | --------------------------------------------------------------------------------