Incidence du statistics level

La variable statistics level permet des stocker des statistiques dans certaines vues.

La requête suivante permet de voir quelle vue est impactée, à quel niveau de statistique et si le calcul de la statistique peut être modifié au niveau session

select decode(ACTIVATION_LEVEL,1,'Typical','All') "A Level"
, Name
, decode(SESSION_CHANGEABLE,1,'Ok',' -') "Modif"
, decode(SESSION_STATUS,1,'On',' -') "Sess"
, decode(SYSTEM_STATUS,1,'On',' -') "Sys"
, VIEW_NAME
from x$prmsltyx
order by ACTIVATION_LEVEL
/

En 11gR2 on obtient

A Level NAME                                                             Mo Se Sy VIEW_NAME
------- ---------------------------------------------------------------- -- -- -- -------------------------
Typical Buffer Cache Advice - On On V$DB_CACHE_ADVICE
Typical V$IOSTAT_* statistics - On On
Typical Timed Statistics Ok On On
Typical MTTR Advice - On On V$MTTR_TARGET_ADVICE
Typical Adaptive Thresholds Enabled - On On
Typical Segment Level Statistics - On On V$SEGSTAT
Typical PGA Advice - On On V$PGA_TARGET_ADVICE
Typical Shared Pool Advice - On On V$SHARED_POOL_ADVICE
Typical Modification Monitoring - On On
Typical Longops Statistics - On On V$SESSION_LONGOPS
Typical Bind Data Capture - On On V$SQL_BIND_CAPTURE
Typical Ultrafast Latch Statistics - On On
Typical Threshold-based Alerts - On On
Typical Global Cache Statistics - On On
Typical Active Session History - On On V$ACTIVE_SESSION_HISTORY
Typical Undo Advisor, Alerts and Fast Ramp up - On On V$UNDOSTAT
Typical Streams Pool Advice - On On V$STREAMS_POOL_ADVICE
Typical Time Model Events Ok On On V$SESS_TIME_MODEL
Typical Plan Execution Sampling Ok On On V$ACTIVE_SESSION_HISTORY
Typical Automated Maintenance Tasks - On On
Typical SQL Monitoring Ok On On V$SQL_MONITORING
All Plan Execution Statistics Ok - - V$SQL_PLAN_STATISTICS
All Timed OS Statistics Ok - -

En 10g on obtient

A Level NAME                                     Mo Se Sy VIEW_NAME
------- ---------------------------------------- -- -- -- ------------------------------
Typical Buffer Cache Advice - On On V$DB_CACHE_ADVICE
Typical Streams Pool Advice - On On V$STREAMS_POOL_ADVICE
Typical Timed Statistics Ok On On
Typical MTTR Advice - On On V$MTTR_TARGET_ADVICE
Typical Undo Advisor, Alerts and Fast Ramp up - On On V$UNDOSTAT
Typical Segment Level Statistics - On On V$SEGSTAT
Typical PGA Advice - On On V$PGA_TARGET_ADVICE
Typical Shared Pool Advice - On On V$SHARED_POOL_ADVICE
Typical Modification Monitoring - On On
Typical Longops Statistics - On On V$SESSION_LONGOPS
Typical Bind Data Capture - On On V$SQL_BIND_CAPTURE
Typical Ultrafast Latch Statistics - On On
Typical Threshold-based Alerts - On On
Typical Global Cache Statistics - On On
Typical Active Session History - On On V$ACTIVE_SESSION_HISTORY
All Plan Execution Statistics Ok - - V$SQL_PLAN_STATISTICS
All Timed OS Statistics Ok - -

En 9i on obtient

A Level NAME                           Mo Se Sy VIEW_NAME
------- ------------------------------ -- -- -- ------------------------------
Typical Buffer Cache Advice - On On V$DB_CACHE_ADVICE
Typical MTTR Advice - On On V$MTTR_TARGET_ADVICE
Typical Timed Statistics Ok On On
Typical PGA Advice - On On V$PGA_TARGET_ADVICE
Typical Shared Pool Advice - On On V$SHARED_POOL_ADVICE
Typical Segment Level Statistics - On On V$SEGSTAT
All Timed OS Statistics Ok - -
All Plan Execution Statistics Ok - - V$SQL_PLAN_STATISTICS

Générer des rapports statspack

Petite procédure pour générer un nombre important de rapports statspack.

SET SERVEROUTPUT OFF
set feedback off

var delta number;
var date_fin varchar2(20);
begin
:delta:=&1;
--  :date_fin:=&2;
end;
/

create or replace procedure dba_all_reports( delta in number
                                         , fin in varchar default to_char(sysdate, 'YYYYMMDDHH24MI') ) as
begin
for i in (select snap_id
        , snap_next
        , to_char(snap_time, 'MMDD_HH24MI') rpt_name
        , instance_name
      from (select s.SNAP_ID
              , lead(s.SNAP_ID,1) over (order by s.SNAP_ID) SNAP_NEXT
              , s.STARTUP_TIME
              , lead(s.STARTUP_TIME, 1) over (order by s.SNAP_ID) STARTUP_NEXT
              , s.SNAP_TIME
              , i.INSTANCE_NAME
            from stats$snapshot s, v$instance i)
      where SNAP_NEXT=SNAP_ID+1
      and STARTUP_TIME=STARTUP_NEXT
      and snap_time between to_date(fin,'YYYYMMDDHH24MI')-delta and to_date(fin,'YYYYMMDDHH24MI') )
loop
DBMS_OUTPUT.ENABLE (32000);
dbms_output.put_line ('define begin_snap='||i.snap_id);
dbms_output.put_line ('define end_snap='||i.snap_next);
dbms_output.put_line ('define report_name='||i.instance_name||'_'||i.rpt_name);
dbms_output.put_line ('@?/rdbms/admin/spreport.sql');
end loop;
end;
/

SET SERVEROUTPUT ON
spool reports.sql
-- execute dba_all_reports(:delta, :date_fin)
execute dba_all_reports(:delta)
spool off

@reports.sql

drop procedure dba_all_reports;

Les rapports ainsi générés sont nommés <ORACLE_SID>_<MOIS><JOUR>_<HEURE><MINUTES>.lst

On peut décommenter les lignes

--  :date_fin:=&2;

et

-- execute dba_all_reports(:delta, :date_fin)

et supprimer la ligne

execute

dba_all_reports(:delta)

de manière à générer des rapports anciens.

Les requêtes consommatrices

Bon un petit peu de technique histoire d’aider ma mémoire avec une requête bien sympatoche histoire de tracer la consommation SQL d’une base


select sql_id, dsk_rd, tot_rd, to_char((dsk_rd/tot_rd)*100,'999D99') || ' %' "PCT RDS"
from (select distinct 1 c1
, sql_id
, sum(disk_reads_DELTA) over (partition by sql_id) dsk_rd
, sum(disk_reads_delta) over (partition by 1) tot_rd
from DBA_HIST_SQLSTAT
where nvl(disk_reads_DELTA,0) > 0
order by 3 desc)
where rownum < 11
and tot_rd > 0

Au résultat on obtient un petit tableau de ce type


SQL_ID DSK_RD TOT_RD PCT RDS
------------- ---------- ---------- ---------
b7jn4mf49n569 6234 21773 28,63 %
gfjvxb25b773h 1990 21773 9,14 %
c7sn076yz7030 939 21773 4,31 %
cvn54b7yz0s8u 849 21773 3,90 %
cfz686a6qp0kg 808 21773 3,71 %
c2p32r5mzv8hb 709 21773 3,26 %
7q2wnyku8mfv0 630 21773 2,89 %
b3ys9bs1v9cch 547 21773 2,51 %
39m4sx9k63ba2 437 21773 2,01 %
02577v815yp77 412 21773 1,89 %

Bien cryptique ? Certes mais utile dans le cadre d’un audit de perf. (à partir de la version 10 d’oracle).

Pour tracer une évolution au travers des snapshots AWR (Automatic Workload Reppository) on pourra modifier de cette manière :


break on snap_id skip 1

select SNAP_ID
, SQL_ID
, disk_reads_DELTA
, to_char((disk_reads_delta/tot)*100,'999D99') || ' %' "PCT RDS"
from (select SNAP_ID
, SQL_ID
, disk_reads_DELTA
, dense_rank() over ( partition by snap_id order by disk_reads_DELTA desc, sql_id asc) rk
, sum(disk_reads_DELTA) over ( partition by snap_id) tot
from DBA_HIST_SQLSTAT
where nvl(disk_reads_DELTA,0) > 0)
where rk < 11
and tot > 0
order by snap_id, rk

La remontée est alors du type :


SNAP_ID SQL_ID DISK_READS_DELTA PCT RDS
---------- ------------- ---------------- ---------
273 b3ys9bs1v9cch 18 42,86 %
4ng4xn7jw3dbb 8 19,05 %
0a1k5zuh04f38 7 16,67 %
96g93hntrzjtr 3 7,14 %
bunssq950snhf 2 4,76 %
as3uq6ggb3gx6 1 2,38 %
f4fvybbfcbk5y 1 2,38 %
gc7b0drtzbyc6 1 2,38 %
8sd37ztuwkyyc 1 2,38 %

276 dnwpm0gdccrph 6 100,00 %

SNAP_ID SQL_ID DISK_READS_DELTA PCT RDS
---------- ------------- ---------------- ---------

287 g337099aatnuj 1 100,00 %

289 8yh7x8qkgswu2 2 100,00 %

297 b3ys9bs1v9cch 16 42,11 %
5rxbazwmcdfaz 7 18,42 %
70vs1d7ywk5m0 7 18,42 %
4ng4xn7jw3dbb 3 7,89 %
96g93hntrzjtr 3 7,89 %
as3uq6ggb3gx6 1 2,63 %

SNAP_ID SQL_ID DISK_READS_DELTA PCT RDS
---------- ------------- ---------------- ---------
297 gc7b0drtzbyc6 1 2,63 %