From 2eee15704b18beaedcc328f74e54ddde59d5520a Mon Sep 17 00:00:00 2001 From: nigelbayliss Date: Thu, 18 Jun 2020 09:38:49 +0100 Subject: [PATCH 1/5] security update --- optimizer/spm_plan_control/README.md | 8 ++++++-- optimizer/spm_plan_control/SE/connect_user.sql | 3 ++- optimizer/spm_plan_control/SE/example_outln.sql | 3 ++- optimizer/spm_plan_control/SE/example_se.sql | 3 ++- optimizer/spm_plan_control/connect_user.sql | 3 ++- optimizer/spm_plan_control/example.sql | 3 ++- optimizer/spm_plan_control/example2.sql | 3 ++- 7 files changed, 18 insertions(+), 8 deletions(-) diff --git a/optimizer/spm_plan_control/README.md b/optimizer/spm_plan_control/README.md index 26c7fce7..d8b676b2 100755 --- a/optimizer/spm_plan_control/README.md +++ b/optimizer/spm_plan_control/README.md @@ -1,5 +1,11 @@

Using SQL Plan Management to Control SQL Execution Plans

+Note that some scripts will DROP AND CREATE a new user called SPM_TESTU. + +EDIT the following scripts to set the SPM_TESTU password and connect strings: + +- example.sql, example2.sql, connect_user.sql ./SE/example_outln.sql ./SE/example_se.sql ./SE/connect_user.sql + Based on this blog article. The example.sql script demonstrates how to control SQL execution plans using SQL plan management. @@ -12,8 +18,6 @@ Scripts create utility procedures called "set_my_plan" and "add_my_plan" (see pr Example output is shown in example.lst and example2.lst. -Note that example.sql example2.sql scripts will DROP AND CREATE a new user called SPM_TESTU. - Scripts tested in Oracle Database 11g Release 2, Oracle Database 12c Release 2 and Oracle Database 18c. The only caveat is that in Oracle Database 11g DBMS_XPLAN sometimes returns ORA-01403, but the example still works. Now included: SPM example for Oracle Database 18c Standard Edition (see SE directory) diff --git a/optimizer/spm_plan_control/SE/connect_user.sql b/optimizer/spm_plan_control/SE/connect_user.sql index c5f7cedb..98e139ff 100755 --- a/optimizer/spm_plan_control/SE/connect_user.sql +++ b/optimizer/spm_plan_control/SE/connect_user.sql @@ -1,2 +1,3 @@ -connect spm_testu/spm_testu +--##### EDIT HERE TO SET PASSWORD/CONNECT STRING ##### +connect spm_testu/ diff --git a/optimizer/spm_plan_control/SE/example_outln.sql b/optimizer/spm_plan_control/SE/example_outln.sql index 2719cb48..b2b8f16d 100755 --- a/optimizer/spm_plan_control/SE/example_outln.sql +++ b/optimizer/spm_plan_control/SE/example_outln.sql @@ -8,7 +8,8 @@ set echo on pause p... drop user spm_testu cascade; -create user spm_testu identified by spm_testu; +--##### EDIT HERE TO SET PASSWORD ##### +create user spm_testu identified by ; grant connect,resource to spm_testu; grant unlimited tablespace to spm_testu; grant select on v_$sqlarea to spm_testu; diff --git a/optimizer/spm_plan_control/SE/example_se.sql b/optimizer/spm_plan_control/SE/example_se.sql index 4c68a302..697cfc9e 100755 --- a/optimizer/spm_plan_control/SE/example_se.sql +++ b/optimizer/spm_plan_control/SE/example_se.sql @@ -8,7 +8,8 @@ set echo on pause p... drop user spm_testu cascade; -create user spm_testu identified by spm_testu; +--##### EDIT HERE TO SET PASSWORD ##### +create user spm_testu identified by ; grant connect,resource to spm_testu; grant unlimited tablespace to spm_testu; grant select on v_$sqlarea to spm_testu; diff --git a/optimizer/spm_plan_control/connect_user.sql b/optimizer/spm_plan_control/connect_user.sql index c5f7cedb..98e139ff 100755 --- a/optimizer/spm_plan_control/connect_user.sql +++ b/optimizer/spm_plan_control/connect_user.sql @@ -1,2 +1,3 @@ -connect spm_testu/spm_testu +--##### EDIT HERE TO SET PASSWORD/CONNECT STRING ##### +connect spm_testu/ diff --git a/optimizer/spm_plan_control/example.sql b/optimizer/spm_plan_control/example.sql index 548a7c8d..23327d40 100755 --- a/optimizer/spm_plan_control/example.sql +++ b/optimizer/spm_plan_control/example.sql @@ -8,7 +8,8 @@ set echo on pause p... drop user spm_testu cascade; -create user spm_testu identified by spm_testu; +--##### EDIT HERE TO SET PASSWORD ##### +create user spm_testu identified by ; grant connect,resource to spm_testu; grant unlimited tablespace to spm_testu; grant select on v_$sqlarea to spm_testu; diff --git a/optimizer/spm_plan_control/example2.sql b/optimizer/spm_plan_control/example2.sql index 1df67d6b..0555f140 100755 --- a/optimizer/spm_plan_control/example2.sql +++ b/optimizer/spm_plan_control/example2.sql @@ -8,7 +8,8 @@ set echo on pause p... drop user spm_testu cascade; -create user spm_testu identified by spm_testu; +--##### EDIT HERE TO SET PASSWORD ##### +create user spm_testu identified by ; grant connect,resource to spm_testu; grant unlimited tablespace to spm_testu; grant select on v_$sqlarea to spm_testu; From c83d9ad29a1fedfdb67bc22217824180af615561 Mon Sep 17 00:00:00 2001 From: nigelbayliss Date: Thu, 18 Jun 2020 09:39:26 +0100 Subject: [PATCH 2/5] security update --- optimizer/faster_stats/README.md | 7 +++++-- optimizer/faster_stats/cusr.sql | 2 +- optimizer/faster_stats/user.sql | 2 +- 3 files changed, 7 insertions(+), 4 deletions(-) diff --git a/optimizer/faster_stats/README.md b/optimizer/faster_stats/README.md index 57f038f2..098df35f 100644 --- a/optimizer/faster_stats/README.md +++ b/optimizer/faster_stats/README.md @@ -1,10 +1,13 @@ -First, create a user called STEST by adapting the the user.sql script to use an appropriate tablespace (which needs to have about 1.5GB free). +First, create a user called STEST. + +EDIT user.sql script to use an appropriate tablespace and password (which needs to have about 1.5GB free). +EDIT cusr.sql to set the password/connect string Two 'connect' scripts are available: cadm.sql <-- Connects to SYSDBA account -cusr.sql <-- Connects to the STEST user account +cusr.sql <-- Connects to the STEST user account - EDIT THIS TO SET YOUR PASSWORD You can edit these to suit you system, particularly if you are using a multitenant environment. Create tables: diff --git a/optimizer/faster_stats/cusr.sql b/optimizer/faster_stats/cusr.sql index 01d07bae..bd2a40aa 100644 --- a/optimizer/faster_stats/cusr.sql +++ b/optimizer/faster_stats/cusr.sql @@ -1 +1 @@ -connect stest/stest +connect stest/ diff --git a/optimizer/faster_stats/user.sql b/optimizer/faster_stats/user.sql index c91f1321..099ab903 100644 --- a/optimizer/faster_stats/user.sql +++ b/optimizer/faster_stats/user.sql @@ -1,4 +1,4 @@ -create user stest identified by stest; +create user stest identified by ; grant dba to stest; grant sysdba to stest; alter user stest default tablespace big; From 581d4e5b48f384445ead371386e5ca9dc085b900 Mon Sep 17 00:00:00 2001 From: nigelbayliss Date: Thu, 18 Jun 2020 09:40:38 +0100 Subject: [PATCH 3/5] security update --- optimizer/topn/eg1.sql | 2 -- optimizer/topn/eg2.sql | 2 -- optimizer/topn/eg3.sql | 2 -- 3 files changed, 6 deletions(-) diff --git a/optimizer/topn/eg1.sql b/optimizer/topn/eg1.sql index da69159a..cc2b4ed3 100644 --- a/optimizer/topn/eg1.sql +++ b/optimizer/topn/eg1.sql @@ -1,5 +1,3 @@ -connect scott/tiger - SELECT deptno, job, APPROX_SUM(sal), APPROX_RANK(partition by deptno ORDER BY APPROX_SUM(sal) desc) rk FROM emp diff --git a/optimizer/topn/eg2.sql b/optimizer/topn/eg2.sql index fb49b815..b5b82a1f 100644 --- a/optimizer/topn/eg2.sql +++ b/optimizer/topn/eg2.sql @@ -1,5 +1,3 @@ -connect scott/tiger - SELECT deptno, job, APPROX_SUM(sal), APPROX_COUNT(*) FROM emp GROUP BY deptno, job diff --git a/optimizer/topn/eg3.sql b/optimizer/topn/eg3.sql index fb25bf74..b166a02b 100644 --- a/optimizer/topn/eg3.sql +++ b/optimizer/topn/eg3.sql @@ -1,5 +1,3 @@ -connect scott/tiger - SELECT deptno, job, APPROX_SUM(sal) sum_sal, APPROX_SUM(sal,'MAX_ERROR') sum_sal_err FROM emp From 388bc869d92c41e989eba05732b12e0a5b051440 Mon Sep 17 00:00:00 2001 From: nigelbayliss Date: Tue, 25 May 2021 16:36:06 +0100 Subject: [PATCH 4/5] SPA helper example --- optimizer/spm_19c_debug/README.md | 4 +- optimizer/spm_19c_debug/in_cache/README.md | 25 +++++++ optimizer/spm_19c_debug/in_cache/spb.sql | 73 ++++++++++++++++++ optimizer/spm_19c_debug/in_cache/spb_noex.sql | 74 +++++++++++++++++++ .../spm_19c_debug/in_cache/spm_report.lst | 59 +++++++++++++++ .../spm_19c_debug/in_cache/test_setup.sql | 65 ++++++++++++++++ 6 files changed, 299 insertions(+), 1 deletion(-) create mode 100644 optimizer/spm_19c_debug/in_cache/README.md create mode 100644 optimizer/spm_19c_debug/in_cache/spb.sql create mode 100644 optimizer/spm_19c_debug/in_cache/spb_noex.sql create mode 100644 optimizer/spm_19c_debug/in_cache/spm_report.lst create mode 100644 optimizer/spm_19c_debug/in_cache/test_setup.sql diff --git a/optimizer/spm_19c_debug/README.md b/optimizer/spm_19c_debug/README.md index dccfcdfb..46d75dc7 100644 --- a/optimizer/spm_19c_debug/README.md +++ b/optimizer/spm_19c_debug/README.md @@ -4,7 +4,9 @@ To execute the spm.sql script you will need certain privileges. An example is in If you don't have a database you can use yourself, take a look at the spooled output in spm.lst -In particualr, look at the "Hint Report" section towards the end of the file. +In particular, look at the "Hint Report" section towards the end of the file. + +Additional scripts are available in the "in_cache" directory. These scripts us SQL performance analyzer to make it east to check SQL statements in the cursor cache, without the need to run them in SQL plus. ### DISCLAIMER diff --git a/optimizer/spm_19c_debug/in_cache/README.md b/optimizer/spm_19c_debug/in_cache/README.md new file mode 100644 index 00000000..45137f2c --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/README.md @@ -0,0 +1,25 @@ +This directory contains an example of deugging a SQL plan baseline in Oracle Database 19c. + +Note: these scripts use SQL performance analyzer. + +The scripts make it easy to check SQL statements in the cursor cache. + +You can set up an example by running test_setup.sql in a DBA account. Be aware it will drop and create SQL plan baselines. A SQL ID is displayed at the end of the script. You can enter this SQL ID when you run the "spb" scripts. + +In most cases, you can use spb_noex.sql - it explains the plan of the relevant SQL statement in the cursor cache. + +Alternatively, if you want to test execute the SQL statement, use spb.sql instead. + +### DISCLAIMER + +* These scripts are provided for educational purposes only. +* They are NOT supported by Oracle World Wide Technical Support. +* The scripts have been tested and they appear to work as intended. +* You should always run scripts on a test instance. + +### WARNING + +* These scripts drop and create SQL plan baselines. For use on test databases +* You need a license to use SQL performance analyzer to use these scripts +* Check the license user manual for your database version +* Oracle Database 19c: https://docs.oracle.com/en/database/oracle/oracle-database/19/dblic/ diff --git a/optimizer/spm_19c_debug/in_cache/spb.sql b/optimizer/spm_19c_debug/in_cache/spb.sql new file mode 100644 index 00000000..5df0d149 --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/spb.sql @@ -0,0 +1,73 @@ +set echo off +set verify off +set feedback off +set long 10000000 +set pagesize 10000 +set linesize 250 +set trims on +set tab off +column report format a200 + +whenever sqlerror exit + +var ccount number +var spa_task_name varchar2(30); +var execution_name varchar2(30); +var report_text clob; + +-- +-- You must be licensed to use SPA +-- +accept check prompt 'Enter YES/yes if you have a license to use SQL Performance Analyzer: ' default 'NO' + +BEGIN + IF upper('&check') != 'YES' + THEN + RAISE_APPLICATION_ERROR(-20001, 'License not confirmed'); + END IF; +END; +/ + +-- +-- Get the SQL ID to test +-- +accept sqlid prompt 'Enter the SQL ID: ' + +-- +-- Check it's in cache +-- +BEGIN + select count(*) into :ccount from v$sql where sql_id = '&sqlid'; + IF :ccount = 0 + THEN + RAISE_APPLICATION_ERROR(-20002, 'SQL ID not found'); + END IF; +END; +/ + +-- +-- Spool the report +-- +spool spm_report + +exec :spa_task_name := dbms_sqlpa.create_analysis_task(sql_id => '&sqlid'); + +exec dbms_sqlpa.set_analysis_task_parameter(:spa_task_name, 'disable_multi_exec', 'TRUE'); + +-- +-- Enable the diag mode and run the task +-- +alter session set "_sql_plan_management_control"=4; + +exec :execution_name := dbms_sqlpa.execute_analysis_task (task_name => :spa_task_name, execution_type => 'execute'); + +alter session set "_sql_plan_management_control"=0; + +-- +-- Generate the report +-- +exec :report_text := dbms_sqlpa.report_analysis_task (task_name => :spa_task_name, type => 'text', level => 'typical', section => 'all', execution_name => :execution_name); + +select :report_text report from dual; + +spool off diff --git a/optimizer/spm_19c_debug/in_cache/spb_noex.sql b/optimizer/spm_19c_debug/in_cache/spb_noex.sql new file mode 100644 index 00000000..41bb91a8 --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/spb_noex.sql @@ -0,0 +1,74 @@ +set echo off +set verify off +set feedback off +set long 10000000 +set pagesize 10000 +set linesize 250 +set trims on +set tab off +column report format a200 + +whenever sqlerror exit + +var ccount number +var spa_task_name varchar2(30); +var execution_name varchar2(30); +var report_text clob; + +-- +-- You must be licensed to use SPA +-- +accept check prompt 'Enter YES/yes if you have a license to use SQL Performance Analyzer: ' default 'NO' + + +BEGIN + IF upper('&check') != 'YES' + THEN + RAISE_APPLICATION_ERROR(-20001, 'License not confirmed'); + END IF; +END; +/ + +-- +-- Get the SQL ID to test +-- +accept sqlid prompt 'Enter the SQL ID: ' + +-- +-- Check it's in cache +-- +BEGIN + select count(*) into :ccount from v$sql where sql_id = '&sqlid'; + IF :ccount = 0 + THEN + RAISE_APPLICATION_ERROR(-20002, 'SQL ID not found'); + END IF; +END; +/ + +-- +-- Spool the report +-- +spool spm_report + +exec :spa_task_name := dbms_sqlpa.create_analysis_task(sql_id => '&sqlid'); + +exec dbms_sqlpa.set_analysis_task_parameter(:spa_task_name, 'disable_multi_exec', 'TRUE'); + +-- +-- Enable the diag mode and run the task +-- +alter session set "_sql_plan_management_control"=4; + +exec :execution_name := dbms_sqlpa.execute_analysis_task (task_name => :spa_task_name, execution_type => 'explain plan'); + +alter session set "_sql_plan_management_control"=0; + +-- +-- Generate the report +-- +exec :report_text := dbms_sqlpa.report_analysis_task (task_name => :spa_task_name, type => 'text', level => 'typical', section => 'all', execution_name => :execution_name); + +select :report_text report from dual; + +spool off diff --git a/optimizer/spm_19c_debug/in_cache/spm_report.lst b/optimizer/spm_19c_debug/in_cache/spm_report.lst new file mode 100644 index 00000000..18693721 --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/spm_report.lst @@ -0,0 +1,59 @@ + +REPORT +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- +GENERAL INFORMATION SECTION +------------------------------------------------------------------------------- +Tuning Task Name : TASK_17952 +Tuning Task Owner : ADHOC +Workload Type : Single SQL Statement +Execution Count : 1 +Current Execution : EXEC_20550 +Execution Type : EXPLAIN PLAN +Scope : COMPREHENSIVE +Completion Status : COMPLETED +Started at : 05/25/2021 08:17:28 +Completed at : 05/25/2021 08:17:28 + +------------------------------------------------------------------------------- +Schema Name: ADHOC +SQL ID : 21y39zhmkh4pt +SQL Text : select /* SPM_TEST */ num from example_spm_table where id = + :bindv +Bind Variables : + 1 - (NUMBER):100 + +------------------------------------------------------------------------------- + Explain Plan Statistics +------------------------------------------------------------------------------- + Parse Time (s): .000205 + Optimizer Cost: 3 + +------------------------------------------------------------------------------- +EXPLAIN PLANS SECTION +------------------------------------------------------------------------------- + +1- Original +----------- +Plan hash value: 2448381833 + +--------------------------------------------------------------------------------------- +| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | +--------------------------------------------------------------------------------------- +| 0 | SELECT STATEMENT | | 1 | 8 | 3 (0)| 00:00:01 | +|* 1 | TABLE ACCESS FULL| EXAMPLE_SPM_TABLE | 1 | 8 | 3 (0)| 00:00:01 | +--------------------------------------------------------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 1 - filter("ID"=:BINDV) + +Hint Report (identified by operation id / Query Block Name / Object Alias): +Total hints for statement: 1 (U - Unused (1)) +--------------------------------------------------------------------------- + + 1 - SEL$1 / EXAMPLE_SPM_TABLE@SEL$1 + U - INDEX_RS_ASC(@"SEL$1" "EXAMPLE_SPM_TABLE"@"SEL$1" ("EXAMPLE_SPM_TABLE"."ID")) + +------------------------------------------------------------------------------- + diff --git a/optimizer/spm_19c_debug/in_cache/test_setup.sql b/optimizer/spm_19c_debug/in_cache/test_setup.sql new file mode 100644 index 00000000..8891b08b --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/test_setup.sql @@ -0,0 +1,65 @@ +-- +-- This script sets up a SQL statement with a non-reproducible plan +-- It does this by dropping an index used in the SQL plan baseline plan +-- Be sure to run this script on a TEST SYSTEM ONLY - since it drops SQL plan baselines +-- +set echo on +set tab off +set pagesize 1000 +set linesize 200 +set trims on + +var bindv number +var sqlid varchar2(50) + +exec select 100 into :bindv from dual; + +DECLARE + l_plans_dropped PLS_INTEGER; +BEGIN + FOR REC IN (SELECT DISTINCT SQL_HANDLE FROM DBA_SQL_PLAN_BASELINES where sql_text like '%SPM_TEST%') + LOOP + L_PLANS_DROPPED := DBMS_SPM.DROP_SQL_PLAN_BASELINE ( + sql_handle => rec.sql_handle, + PLAN_NAME => NULL); + END LOOP; +END; +/ + +drop table example_spm_table purge; + +create table example_spm_table (id number(10), num number(10), num2 number(10)); +create unique index spm_tab_pk on example_spm_table(id); +create index spm_tab_num1 on example_spm_table(num1); + +begin + for i in 1..1000 + loop + insert into example_spm_table values (i,i,i); + end loop; +end; +/ +commit; + +exec dbms_stats.gather_table_stats (ownname=>null,tabname=>'example_spm_table'); + +select /* SPM_TEST */ num from example_spm_table where id = :bindv; + +declare + r number; +begin + r:=DBMS_SPM.LOAD_PLANS_FROM_CURSOR_CACHE (attribute_name=>'SQL_TEXT',attribute_value=>'select /* SPM_TEST */ num from example_spm_table where id = :bindv'); +end; +/ + +drop index spm_tab_pk; + +select /* SPM_TEST */ num from example_spm_table where id = :bindv; + +exec select sql_id into :sqlid from v$sqlarea where sql_text = 'select /* SPM_TEST */ num from example_spm_table where id = :bindv'; + +select :sqlid from dual; + +select sql_text,accepted from dba_sql_plan_baselines where sql_text like '%SPM_TEST%'; + +select sql_id from v$sql where sql_text = 'select /* SPM_TEST */ num from example_spm_table where id = :bindv'; From 1e3ae6acad2385c1d06e7ba98a61c5f127791481 Mon Sep 17 00:00:00 2001 From: nigelbayliss Date: Wed, 26 May 2021 16:43:55 +0100 Subject: [PATCH 5/5] Explain version script --- optimizer/spm_19c_debug/in_cache/README.md | 11 ++-- .../spm_19c_debug/in_cache/spm_explain.sql | 58 +++++++++++++++++++ 2 files changed, 63 insertions(+), 6 deletions(-) create mode 100644 optimizer/spm_19c_debug/in_cache/spm_explain.sql diff --git a/optimizer/spm_19c_debug/in_cache/README.md b/optimizer/spm_19c_debug/in_cache/README.md index 45137f2c..46cefa58 100644 --- a/optimizer/spm_19c_debug/in_cache/README.md +++ b/optimizer/spm_19c_debug/in_cache/README.md @@ -1,14 +1,14 @@ This directory contains an example of deugging a SQL plan baseline in Oracle Database 19c. -Note: these scripts use SQL performance analyzer. - +Note: spb.sqlc and spb_noex.sql use SQL performance analyzer (SPA) + The scripts make it easy to check SQL statements in the cursor cache. You can set up an example by running test_setup.sql in a DBA account. Be aware it will drop and create SQL plan baselines. A SQL ID is displayed at the end of the script. You can enter this SQL ID when you run the "spb" scripts. -In most cases, you can use spb_noex.sql - it explains the plan of the relevant SQL statement in the cursor cache. +In most cases, you can use spb_explain.sql (EXPLAIN) or spb_noex.sql (SPA version) - which explain the plan of the relevant SQL statement in the cursor cache. -Alternatively, if you want to test execute the SQL statement, use spb.sql instead. +Alternatively, if you want to parse and test execute the SQL statement, use spb.sql (uses SPA) ### DISCLAIMER @@ -20,6 +20,5 @@ Alternatively, if you want to test execute the SQL statement, use spb.sql instea ### WARNING * These scripts drop and create SQL plan baselines. For use on test databases -* You need a license to use SQL performance analyzer to use these scripts -* Check the license user manual for your database version +* Check the license user manual for your database version if you want to use SPA versions * Oracle Database 19c: https://docs.oracle.com/en/database/oracle/oracle-database/19/dblic/ diff --git a/optimizer/spm_19c_debug/in_cache/spm_explain.sql b/optimizer/spm_19c_debug/in_cache/spm_explain.sql new file mode 100644 index 00000000..71e38fcc --- /dev/null +++ b/optimizer/spm_19c_debug/in_cache/spm_explain.sql @@ -0,0 +1,58 @@ +-- +-- This script explains a SQL statement in the cursor cache +-- and produces a hint report - useful for diagnosing +-- SQL plan baseline issues +-- +set echo off +set verify off +set feedback off +set long 10000000 +set pagesize 10000 +set linesize 250 +set trims on +set tab off +column report format a200 + +whenever sqlerror exit + +var ccount number +-- +-- Get the SQL ID to test +-- +accept sqlid prompt 'Enter the SQL ID: ' + +-- +-- Check it's in cache +-- +BEGIN + select count(*) into :ccount from v$sqlarea where sql_id = '&sqlid'; + IF :ccount = 0 + THEN + RAISE_APPLICATION_ERROR(-20002, 'SQL ID not found'); + END IF; +END; +/ + +-- +-- Spool the report +-- +spool spm_report + +alter session set "_sql_plan_management_control"=4; + +-- +-- Explain plan +-- +declare + stmt clob; +begin + select sql_fulltext into stmt from v$sqlarea where sql_id = '&sqlid'; + execute immediate 'explain plan for '||stmt; +end; +/ + +alter session set "_sql_plan_management_control"=0; + +select * from table(dbms_xplan.display(format=>'hint_report')); + +spool off