-- ===========================================

-- SQL_ID Cross-Env Deep Dive Pack (copy all)

-- Runs without knowing a time window.

-- ===========================================


SET LINES 300 PAGES 200 TRIMSPOOL ON TAB OFF VERIFY OFF FEEDBACK ON TIMING ON

COLUMN inst_id              FORMAT 99

COLUMN sql_id               FORMAT A13

COLUMN child_number         FORMAT 999

COLUMN plan_hash_value      FORMAT 9999999999

COLUMN sql_plan_hash_value  FORMAT 9999999999

COLUMN last_active_time     FORMAT A19

COLUMN wait_or_class        FORMAT A40

COLUMN op                   FORMAT A45

COLUMN object_name          FORMAT A40

COLUMN snap_time            FORMAT A20

COLUMN name                 FORMAT A35

COLUMN value                FORMAT A40


-- >>>>> EDIT THIS <<<<<

DEFINE sql_id = 'put_your_sql_id_here';

DEFINE owner  = '%';  -- optional: schema filter for stats checks


PROMPT

PROMPT =========================  A) CURSOR CACHE (if present)  =========================

SELECT inst_id,

       sql_id,

       child_number,

       plan_hash_value,

       TO_CHAR(last_active_time,'YYYY-MM-DD HH24:MI:SS') last_active_time,

       executions                                                AS execs,

       ROUND(elapsed_time/1e6,2)                                 AS elapsed_s,

       ROUND(cpu_time/1e6,2)                                     AS cpu_s,

       ROUND(user_io_wait_time/1e6,2)                            AS io_s,

       buffer_gets,

       disk_reads,

       rows_processed                                            AS rows_proc

FROM   gv$sql

WHERE  sql_id='&sql_id'

ORDER  BY last_active_time DESC;


PROMPT

PROMPT =========================  B) BIND VALUES  =========================

PROMPT -- Current capture

SELECT inst_id, name, position, datatype_string, value_string, last_captured

FROM   gv$sql_bind_capture

WHERE  sql_id='&sql_id'

ORDER  BY last_captured DESC, position;


PROMPT -- Historical (AWR)

SELECT name, position, datatype_string, value_string, last_captured

FROM   dba_hist_sqlbind

WHERE  sql_id='&sql_id'

ORDER  BY last_captured DESC, position;


PROMPT

PROMPT =========================  C) AWR EXECUTION HISTORY (all snaps)  =================

WITH snaps AS (

  SELECT s.snap_id, s.instance_number, s.dbid, s.begin_interval_time

  FROM   dba_hist_snapshot s

)

SELECT TO_CHAR(s.begin_interval_time,'YYYY-MM-DD HH24:MI') snap_time,

       ss.plan_hash_value,

       ss.executions_delta                                  AS execs,

       ROUND(ss.elapsed_time_delta/1e6,2)                   AS elapsed_s,

       ROUND(ss.cpu_time_delta/1e6,2)                       AS cpu_s,

       ROUND(ss.iowait_delta/1e6,2)                         AS io_s,

       ROUND(ss.cluster_wait_time_delta/1e6,2)              AS gc_s,

       ss.buffer_gets_delta                                 AS buffer_gets,

       ss.disk_reads_delta                                  AS disk_reads,

       ss.rows_processed_delta                              AS rows_proc

FROM   dba_hist_sqlstat ss

JOIN   snaps s

  ON   s.snap_id=ss.snap_id AND s.dbid=ss.dbid AND s.instance_number=ss.instance_number

WHERE  ss.sql_id='&sql_id'

ORDER  BY s.begin_interval_time DESC;


PROMPT

PROMPT =========================  D) AWR TIME BY PLAN (sum over all snaps)  =============

SELECT ss.plan_hash_value,

       ROUND(SUM(ss.elapsed_time_delta)/1e6,1)            AS elapsed_s,

       ROUND(SUM(ss.cpu_time_delta)/1e6,1)                AS cpu_s,

       ROUND(SUM(ss.iowait_delta)/1e6,1)                  AS io_wait_s,

       ROUND(SUM(ss.cluster_wait_time_delta)/1e6,1)       AS gc_wait_s,

       SUM(ss.buffer_gets_delta)                           AS buffer_gets,

       SUM(ss.disk_reads_delta)                            AS disk_reads,

       SUM(ss.rows_processed_delta)                        AS rows_proc

FROM   dba_hist_sqlstat ss

WHERE  ss.sql_id='&sql_id'

GROUP  BY ss.plan_hash_value

ORDER  BY elapsed_s DESC;


PROMPT

PROMPT =========================  E) ASH WAIT PROFILE (all history for this SQL)  =======

SELECT NVL(event, wait_class) AS wait_or_class,

       COUNT(*)               AS samples,

       ROUND(100*RATIO_TO_REPORT(COUNT(*)) OVER (),1) AS pct

FROM   dba_hist_active_sess_history

WHERE  sql_id='&sql_id'

GROUP  BY NVL(event, wait_class)

ORDER  BY samples DESC FETCH FIRST 20 ROWS ONLY;


PROMPT

PROMPT =========================  F) ASH HOT PLAN LINES (use SQL_PLAN_HASH_VALUE)  ======

SELECT sql_plan_hash_value,

       sql_plan_line_id,

       sql_plan_operation||' '||sql_plan_options AS op,

       COUNT(*)                                  AS samples

FROM   dba_hist_active_sess_history

WHERE  sql_id='&sql_id'

GROUP  BY sql_plan_hash_value, sql_plan_line_id, sql_plan_operation, sql_plan_options

ORDER  BY samples DESC FETCH FIRST 25 ROWS ONLY;


PROMPT

PROMPT =========================  G) RAC: INSTANCE DISTRIBUTION & GC OBJECTS  ==========

PROMPT -- Samples by instance

SELECT instance_number, COUNT(*) AS samples

FROM   dba_hist_active_sess_history

WHERE  sql_id='&sql_id'

GROUP  BY instance_number

ORDER  BY samples DESC;


PROMPT -- Top objects involved when wait class = Cluster (GC)

SELECT NVL(o.owner||'.'||o.object_name,'-') AS object_name,

       COUNT(*) AS samples

FROM   dba_hist_active_sess_history a

LEFT   JOIN dba_objects o ON a.current_obj#=o.object_id

WHERE  a.sql_id='&sql_id'

AND    a.wait_class='Cluster'

GROUP  BY NVL(o.owner||'.'||o.object_name,'-')

ORDER  BY samples DESC FETCH FIRST 15 ROWS ONLY;


PROMPT

PROMPT =========================  H) TEMP/PGA SPILL INDICATORS (AWR)  ==================

-- Total TEMP allocated by this SQL across history

SELECT ROUND(SUM(temp_space_allocated_delta)/1024/1024/1024,3) AS temp_gb

FROM   dba_hist_sqlstat

WHERE  sql_id='&sql_id';


-- Current PGA headroom snapshot (runtime check; ignore if no privileges)

SELECT name, value

FROM   v$pgastat

WHERE  name IN ('total PGA allocated','PGA cache hit percentage');


PROMPT

PROMPT =========================  I) I/O LATENCY DURING PERIODS THIS SQL APPEARED  ======

-- Limit filestat range to min/max snaps where this SQL was seen

WITH r AS (

  SELECT MIN(snap_id) b, MAX(snap_id) e

  FROM   dba_hist_sqlstat

  WHERE  sql_id='&sql_id'

)

SELECT f.filetype_name,

       ROUND(f.readtim/decode(NULLIF(f.phyrds,0),0,1, f.phyrds),3)   AS ms_per_read,

       ROUND(f.writetim/decode(NULLIF(f.phywrts,0),0,1, f.phywrts),3) AS ms_per_write

FROM   dba_hist_filestatxs f, r

WHERE  f.snap_id BETWEEN r.b AND r.e

GROUP  BY f.filetype_name, f.readtim, f.phyrds, f.writetim, f.phywrts

ORDER  BY ms_per_read DESC;


PROMPT

PROMPT =========================  J) PLAN INVENTORY (current + historical)  ============

PROMPT -- Current (if in cache)

SELECT DISTINCT inst_id, plan_hash_value

FROM   gv$sql

WHERE  sql_id='&sql_id'

ORDER  BY inst_id;


PROMPT -- Historical plans seen in AWR

SELECT DISTINCT plan_hash_value, COUNT(*) occurrences

FROM   dba_hist_sql_plan

WHERE  sql_id='&sql_id'

GROUP  BY plan_hash_value

ORDER  BY occurrences DESC;


PROMPT -- Current plan with actuals (if cached recently)

SELECT * FROM gv$sql_plan_statistics_all

WHERE  sql_id='&sql_id'

ORDER  BY inst_id, plan_hash_value, id;


PROMPT

PROMPT =========================  K) OBJECT/TABLE STATS QUICK CHECK (optional)  ========

SELECT owner, table_name, last_analyzed, stale_stats

FROM   dba_tab_statistics

WHERE  owner LIKE '&owner' AND table_name IN (

  SELECT DISTINCT object_name

  FROM   dba_objects

  WHERE  object_id IN (

    SELECT DISTINCT current_obj#

    FROM   dba_hist_active_sess_history

    WHERE  sql_id='&sql_id'

  )

)

ORDER  BY last_analyzed DESC;


PROMPT

PROMPT =========================  L) KEY OPTIMIZER PARAMS SNAPSHOT (diff across envs) ==

SELECT name, value

FROM   v$parameter

WHERE  name IN (

  'optimizer_features_enable','optimizer_mode','cursor_sharing',

  'parallel_degree_policy','parallel_min_time_threshold',

  'pga_aggregate_target','pga_aggregate_limit'

)

ORDER  BY name;


PROMPT

PROMPT =========================  M) OPTIONAL: Real-time ASH (if currently running)  ===

-- Uncomment if you suspect it is running now

-- SELECT NVL(event,wait_class) wait_or_class, COUNT(*) samples

-- FROM   gv$active_session_history

-- WHERE  sql_id='&sql_id'

-- GROUP  BY NVL(event,wait_class)

-- ORDER  BY samples DESC;


-- End of pack

Popular posts from this blog