Rendre dbms_metadata lisible

DBMS_METADATA lisible, comment faire ?

Le package dbms_metadata existe depuis la version 9i et permet de regénerer les commandes DDL relatives aux objets ORACLE … Maintenant, pour l’utilisation et la liste des focntion au choix : RTFM ou RTFDB (DB pour Donald B le bien connu copiste en chef de la documentation Oracle) ce qui, au final revient à peu près au même. Cependant, souvent sa sortie contient des informations dont on se passerait bien, comme la gestion des extents ou autres alors qu’on utilise la plupart du temps les paramètres par défaut du tablespace.

Deux trois petites astuces bien sympa à retenir

  • Ne jamais faire un dbms_metadata sur une liste d’objets (si un objet plante, les suivants ne sont pas traités)
  • Utiliser long 9999999 et longc 9999999
  • Utiliser des lignes larges (300 à 400 caractères, on peut aller jusqu’à 32768 soit 32k) et un “trimspool on” s’il on choisit de rediriger la sortie dans un fichier.
  • Demander la mise en forme avec les terminaisons SQL ( / ou ; )
    exec dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', TRUE ); 
  • Eviter les paramètres de stockage afin d’utiliser ceux du tablespace :
    exec dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'STORAGE', false); 

L’exemple suivant donne le DDL de la table WRH$_SQL_PLAN dans ses deux versions

Comportement par défaut de DBMS_METADATA

select dbms_metadata.get_ddl('TABLE','WRH$_SQL_PLAN',USER) from sys.dual ;
DBMS_METADATA.GET_DDL('TABLE','WRH$_SQL_PLAN',USER)
--------------------------------------------------------------------------

  CREATE TABLE "SYS"."WRH$_SQL_PLAN"
   (    "SNAP_ID" NUMBER,
        "DBID" NUMBER NOT NULL ENABLE,

        [...]
        
        "OTHER_XML" CLOB,
         CONSTRAINT "WRH$_SQL_PLAN_PK" PRIMARY KEY ("DBID", "SQL_ID", "PLAN_HASH_VALUE", "ID")
  USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT)
  TABLESPACE "SYSAUX"  ENABLE
   ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
 NOCOMPRESS LOGGING
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT)
  TABLESPACE "SYSAUX"
 LOB ("OTHER_XML") STORE AS BASICFILE (
  TABLESPACE "SYSAUX" ENABLE STORAGE IN ROW CHUNK 8192 RETENTION
  NOCACHE LOGGING
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT))

DBMS_METADATA lisible, ou du moins beaucoup moins inutilement chargé

Paramétrage

exec dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', TRUE );

PL/SQL procedure successfully completed.

exec dbms_metadata.set_transform_param( DBMS_METADATA.SESSION_TRANSFORM, 'STORAGE', false);

PL/SQL procedure successfully completed.

sortie DBMS_METADATA lisible

select dbms_metadata.get_ddl('TABLE','WRH$_SQL_PLAN',USER) from sys.dual ;
DBMS_METADATA.GET_DDL('TABLE','WRH$_SQL_PLAN',USER)
--------------------------------------------------------------------------

  CREATE TABLE "SYS"."WRH$_SQL_PLAN"
   (    "SNAP_ID" NUMBER,
        "DBID" NUMBER NOT NULL ENABLE,

        [...]

        "OTHER_XML" CLOB,
         CONSTRAINT "WRH$_SQL_PLAN_PK" PRIMARY KEY ("DBID", "SQL_ID", "PLAN_HASH_VALUE", "ID")
  USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
  TABLESPACE "SYSAUX"  ENABLE
   ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
 NOCOMPRESS LOGGING
  TABLESPACE "SYSAUX"
 LOB ("OTHER_XML") STORE AS BASICFILE (
  TABLESPACE "SYSAUX" ENABLE STORAGE IN ROW CHUNK 8192 RETENTION
  NOCACHE LOGGING ) ;

Paramètres internes de l’instance

La table x$kvit donne une liste de paramètres dynamiques utilisés au moment du select.

La version 10g remonte la liste suivante :

select KVITTAG
, KVITDSC
, KVITVAL
from x$kvit
/

KVITTAG KVITDSC KVITVAL
-------------------- ---------------------------------------------------------------- ----------
ksbcpu number of logical CPUs in the system used by Oracle 2
ksbcpucore number of physical CPU cores in the system used by Oracle 0
ksbcpusocket number of physical CPU sockets in the system used by Oracle 0
ksbcpu_hwm high water mark of number of CPUs used by Oracle 2
ksbcpucore_hwm high water mark of number of CPU cores on system 0
ksbcpusocket_hwm high water mark of number of CPU sockets on system 0
ksbcpu_actual number of available CPUs in the system 2
ksbcpu_dr CPU dynamic reconfiguration supported 1
kcbnbh number of buffers 136551
kcbldq large dirty queue if kcbclw reaches this 25
kcbfsp Max percentage of LRU list foreground can scan for free 40
kcbcln Initial percentage of LRU list to keep clean 2
kcbnbf number buffer objects 750
kcbwst Flag that indicates recovery or db suspension 0
kcteln Error Log Number for thread open 0
kcvgcw SGA: opcode for checkpoint cross-instance call 0
kcvgcw SGA:opcode for pq checkpoint cross-instance call 0

La version 9i remonte la liste suivante :


KVITTAG KVITDSC KVITVAL
-------------------- ---------------------------------------------------------------- ----------
kcbnbh number of buffers 381120
kcbldq large dirty queue if kcbclw reaches this 25
kcbdsp Max percentage of LRU list dbwriter can scan for dirty 25
kcbfsp Max percentage of LRU list foreground can scan for free 40
kcbnbf number buffer objects 5000
kcbwst Flag that indicates recovery or db suspension 0
kcteln Error Log Number for thread open 0
kcvgcw SGA: opcode for checkpoint cross-instance call 0

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.