Skip to content
pvmehta.com

pvmehta.com

  • Home
  • About Me
  • Toggle search form
  • find_err.sql for finding errors from dba_errors. Oracle
  • How to analyze statspack or AWR report. Oracle
  • 284785.1 How to check RAC Option is currently linked into the Oracle Binary Oracle
  • get_vmstat_linux Oracle
  • My Minimum Tuning Programs Oracle
  • Single character replacement in Unix Linux/Unix
  • oradebug ipcrm ipcs Oracle
  • pvmehta.com SQL scripts
    Find which sessions is accessing object that prevent your session to have exclusive locks in Oracle Oracle
  • How can I tell if ASO is installed ? Oracle
  • How to choose Driver table in SQL statement Oracle
  • backspace in SQL Plus not working then..? Linux/Unix
  • Renaming the column name Oracle
  • rm_backup_arch_file.ksh Linux/Unix
  • 339939.1 Running Cluster Verification Utility to Diagnose Install Problems Oracle
  • newupload.html PHP/MYSQL/Wordpress

Find_planinfo.sql

Posted on 08-Apr-202322-Apr-2025 By Admin No Comments on Find_planinfo.sql
/********************************************
Author: Paresh Mehta
Script Name : find_planinfo.sql
********************************************/
set lines 200
set pages 500
set echo off
col execs for 999,999,999
col avg_etime for 999,999.999
col avg_lio for 999,999,999.9
col begin_interval_time for a30
col node for 99999
col plan_hash_value format 99999999999999
col sql_profile format a30
col intrvl format a29
col component format a20


alter session set nls_date_format='DD-MON-RRRR:HH24:MI:SS';

--break on plan_hash_value,sql_profile on startup_time skip 1

accept v_sql_id prompt 'Enter SQL_ID ->'

select s.instance_number, to_char(begin_interval_time,'DD-MON:HH24:MI') || ' To '
|| to_char(END_INTERVAL_TIME,'DD-MON:HH24:MI') intrvl , plan_hash_value, s.sql_profile,
nvl(executions_delta,0) execs,
(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime,
(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio,
round(IO_OFFLOAD_ELIG_BYTES_DELTA,2)/(1024*1024) smart_scan_elig_mb,
round(IO_OFFLOAD_RETURN_BYTES_DELTA,2)/(1024*1024) smart_scan_actual_mb,
parse_calls_delta, version_count,
resops.start_time, resops.end_time, resops.component, resops.oper_type, resops.oper_mode,
resops.initial_size/1024/1024 "from",
resops.TARGET_SIZE/1024/1024 "to", resops.status
from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS, gv$sga_resize_ops resops
where sql_id = '&v_sql_id'
and ss.snap_id = S.snap_id
and ss.instance_number = S.instance_number
and resops.inst_id(+) = s.instance_number
and executions_delta > 0
and resops.START_TIME(+) >= begin_interval_time
and resops.START_TIME(+) <= END_INTERVAL_TIME
and resops.END_TIME(+) >= begin_interval_time
and resops.END_TIME(+) <= END_INTERVAL_TIME
order by begin_interval_time;

select inst_id, sql_id, child_number, plan_hash_value, max(TIMESTAMP)
from gV$sql_plan
where sql_id= '&v_sql_id'
group by inst_id, sql_id, child_number, plan_hash_value
order by 5;

set lines 200 pages 200 feedback 1
col created format a30
col sql_handle format a25
col plan_name format a35
col PLAN_HASH_VALUE format 999999999999999
col sql_plan_baseline format a30
col executions format 99999999

alter session set nls_date_format='DD-MON-RRRR:HH24:MI:SS';

col EXACT_MATCHING_SIGNATURE format 999999999999999999999999999


SELECT distinct a.created, b.sql_id, sql_handle,
( select to_number(regexp_replace(plan_table_output,'^[^0-9]*'))
from table(
dbms_xplan.display_sql_plan_baseline(sql_handle,plan_name)
) where plan_table_output like 'Plan hash value: %') plan_hash_value, plan_name, a.enabled, a.accepted, a.fixed, a.autopurge, a.EXECUTIONS
FROM dba_sql_plan_baselines a, gv$sql b
WHERE a.signature = b.exact_matching_signature
and sql_id='&v_sql_id'
order by 6,8;

set echo on
Oracle, SQL scripts

Post navigation

Previous Post: Wait.sql
Next Post: DBA_HIST_SQLSTAT contents

Related Posts

  • export import with parameter file. Oracle
  • sbind.sql Find Bind variable from sql_id sqlid Oracle
  • This is from Temi Oracle
  • Renaming Global Name GLOBAL_NAME Oracle
  • SCRIPT TO LIST RECURSIVE DEPENDENCY BETWEEN OBJECTS UTLDTREE.sql Oracle
  • All About Trace Fils Oracle

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Categories

  • AWS (2)
  • Azure (1)
  • Linux/Unix (149)
  • Oracle (392)
  • PHP/MYSQL/Wordpress (10)
  • Power-BI (0)
  • Python/PySpark (7)
  • RAC (17)
  • rman-dataguard (26)
  • shell (149)
  • SQL scripts (341)
  • Uncategorized (0)
  • Videos (0)

Recent Posts

  • load SPM baseline from cursor cache05-Jun-2025
  • Drop all SPM baselines for SQL handle05-Jun-2025
  • Load SPM baseline from AWR05-Jun-2025
  • Drop specific SQL plan baseline – spm05-Jun-2025
  • findinfo.sql (SQL for getting CPU and Active session info)27-May-2025
  • SQL Tracker by SID sqltrackerbysid.sql22-Apr-2025
  • How to connect to Oracle Database with Wallet with Python.21-Mar-2025
  • JSON/XML Types in Oracle18-Mar-2025
  • CPU Core related projections12-Mar-2025
  • Exadata Basics10-Dec-2024

Archives

  • 2025
  • 2024
  • 2023
  • 2010
  • 2009
  • 2008
  • 2007
  • 2006
  • 2005
  • In Addition to previous note, following grants needed on PERFSTAT user. Oracle
  • Logic to chech # of parameters command line parameters Linux/Unix
  • dbms_job.submit example Oracle
  • get_aix_vmstat.ksh Oracle
  • how to find OS block size Oracle
  • Implementing Listener Security Oracle
  • Jai Shree Ram Oracle
  • myfile Oracle

Copyright © 2025 pvmehta.com.

Powered by PressBook News WordPress theme