diff --git a/README.md b/README.md index 566c936..5c9c914 100644 --- a/README.md +++ b/README.md @@ -1,2 +1,3 @@ -# db_report - Database Report + +Exemple de script qui génère un rapport html avec quelques infos de la base, les fichiers, les logs et les sauvegardes + \ No newline at end of file diff --git a/rapport_mensuel.sh b/rapport_mensuel.sh new file mode 100644 index 0000000..5555259 --- /dev/null +++ b/rapport_mensuel.sh @@ -0,0 +1,37 @@ +DATETIME=`date +%Y%m%d%H%M` +HNAME=$(hostname) + +for r in $(ps -eaf | grep pmon | egrep -v 'grep|ASM1|APX1' | cut -d '_' -f3) +do + export ORAENV_ASK=NO + export ORACLE_SID=$r + export HTML_FILE=Rapport_$HNAME_${ORACLE_SID}_${DATETIME}.html + . oraenv -s > /dev/null +# echo " +# +# +# +# +# +# Rapport Oracle Database : ${ORACLE_SID} +# +# +# +#
+# +# " > ${HTML_FILE} + + # sqlplus -s "/ as sysdba" @rapport_html.sql >> ${HTML_FILE} + cat sql/00_html_header.html >> ${HTML_FILE} + for f in sql/*.sql + do + # sqlplus -s "/ as sysdba" @$f >> ${HTML_FILE} + sed '1 s/^/SET PAGES 999 FEEDBACK OFF MARKUP HTML ON SPOOL ON PREFORMAT OFF ENTMAP OFF\n/' $f | sqlplus -s / as sysdba >> ${HTML_FILE} + done + + sed -i 's/$//g' ${HTML_FILE} + + cat sql/99_html_footer.html >> ${HTML_FILE} + + echo Rapport dans le fichier html : ${HTML_FILE} +done diff --git a/sql/00_html_header.html b/sql/00_html_header.html new file mode 100644 index 0000000..9264ce0 --- /dev/null +++ b/sql/00_html_header.html @@ -0,0 +1,31 @@ + + + + + + + + + DB Report + + + diff --git a/sql/01_system_info.sql b/sql/01_system_info.sql new file mode 100644 index 0000000..0399cf6 --- /dev/null +++ b/sql/01_system_info.sql @@ -0,0 +1,58 @@ +prompt

System Information

+WITH /* 1a.1 */ + rac AS (SELECT /*+ MATERIALIZE NO_MERGE */ COUNT(*) instances, CASE COUNT(*) WHEN 1 THEN 'Single-instance' ELSE COUNT(*)||'-node RAC cluster' END db_type FROM gv$instance), +hrac AS (SELECT /*+ MATERIALIZE NO_MERGE */ CASE 1 WHEN 1 THEN ' (historically Single-instance in AWR)' ELSE ' (historicly 1-node RAC cluster in AWR)' END db_type + FROM rac WHERE TO_CHAR(RAC.instances)<>1), +mem AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) target FROM gv$system_parameter2 WHERE name = 'memory_target'), +sga AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) target FROM gv$system_parameter2 WHERE name = 'sga_target'), +pga AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) target FROM gv$system_parameter2 WHERE name = 'pga_aggregate_target'), +db_block AS (SELECT /*+ MATERIALIZE NO_MERGE */ value bytes FROM v$system_parameter2 WHERE name = 'db_block_size'), +db AS (SELECT /*+ MATERIALIZE NO_MERGE */ name, platform_name FROM v$database), + pdbs AS (SELECT /*+ MATERIALIZE NO_MERGE */ * FROM v$pdbs), -- need 12c flag +inst AS (SELECT /*+ MATERIALIZE NO_MERGE */ host_name, version db_version FROM v$instance), +data AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(bytes) bytes, COUNT(*) files, COUNT(DISTINCT ts#) tablespaces FROM v$datafile), +temp AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(bytes) bytes FROM v$tempfile), +log AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(bytes) * MAX(members) bytes FROM v$log), +control AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(block_size * file_size_blks) bytes FROM v$controlfile), +core AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) cnt FROM gv$osstat WHERE stat_name = 'NUM_CPU_CORES'), +cpu AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) cnt FROM gv$osstat WHERE stat_name = 'NUM_CPUS'), +pmem AS (SELECT /*+ MATERIALIZE NO_MERGE */ SUM(value) bytes FROM gv$osstat WHERE stat_name = 'PHYSICAL_MEMORY_BYTES') +SELECT /*+ NO_MERGE */ /* 1a.1 */ + 'Database name:' system_item, db.name system_value FROM db +UNION ALL + SELECT ' pdb:'||name, 'Open Mode:'||open_mode FROM pdbs -- need 12c flag + UNION ALL +SELECT 'Oracle Database version:', inst.db_version FROM inst + UNION ALL +SELECT 'Database block size:', TRIM(TO_CHAR(db_block.bytes / POWER(2,10), '90'))||' KB' FROM db_block + UNION ALL +SELECT 'Database size:', TRIM(TO_CHAR(ROUND((data.bytes + temp.bytes + log.bytes + control.bytes) / POWER(10,12), 3), '999,999,990.000'))||' TB' + FROM db, data, temp, log, control + UNION ALL +SELECT 'Datafiles:', data.files||' (on '||data.tablespaces||' tablespaces)' FROM data + UNION ALL +SELECT 'Instance configuration:', rac.db_type||(select hrac.db_type FROM hrac ) FROM rac + UNION ALL +SELECT 'Database memory:', +CASE WHEN mem.target > 0 THEN 'MEMORY '||TRIM(TO_CHAR(ROUND(mem.target / POWER(2,30), 1), '999,990.0'))||' GB, ' END|| +CASE WHEN sga.target > 0 THEN 'SGA ' ||TRIM(TO_CHAR(ROUND(sga.target / POWER(2,30), 1), '999,990.0'))||' GB, ' END|| +CASE WHEN pga.target > 0 THEN 'PGA ' ||TRIM(TO_CHAR(ROUND(pga.target / POWER(2,30), 1), '999,990.0'))||' GB, ' END|| +CASE WHEN mem.target > 0 THEN 'AMM' ELSE CASE WHEN sga.target > 0 THEN 'ASMM' ELSE 'MANUAL' END END + FROM mem, sga, pga + UNION ALL +SELECT 'Hardware:', 'Unknown' FROM dual + UNION ALL +SELECT 'Storage:','' FROM DUAL WHERE '' IS NOT NULL + UNION ALL +SELECT 'Storage Version:','' FROM DUAL WHERE '' IS NOT NULL + UNION ALL +SELECT 'Processor:', 'Common KVM processor' FROM DUAL + UNION ALL +SELECT 'Physical CPUs:', core.cnt||' cores'||CASE WHEN rac.instances > 0 THEN ', on '||rac.db_type END FROM rac, core + UNION ALL +SELECT 'Oracle CPUs:', cpu.cnt||' CPUs (threads)'||CASE WHEN rac.instances > 0 THEN ', on '||rac.db_type END FROM rac, cpu + UNION ALL +SELECT 'Physical RAM:', TRIM(TO_CHAR(ROUND(pmem.bytes / POWER(2,30), 1), '999,990.0'))||' GB'||CASE WHEN rac.instances > 0 THEN ', on '||rac.db_type END FROM rac, pmem + UNION ALL +SELECT 'Operating system:', db.platform_name FROM db; +exit diff --git a/sql/10_get_disk_size.sql b/sql/10_get_disk_size.sql new file mode 100644 index 0000000..b373dce --- /dev/null +++ b/sql/10_get_disk_size.sql @@ -0,0 +1,26 @@ +prompt

Disk Size df -h

+set echo off head off +prompt
+host df -h
+prompt 
+ +prompt

lsblk -f

+prompt
+host lsblk -f
+prompt 
+ +prompt

cat /etc/fstab

+prompt
+host cat /etc/fstab
+prompt 
+ +prompt

Memory Size free -h

+prompt
+host free -h
+prompt 
+ +prompt

lscpu

+prompt
+host lscpu
+prompt 
+exit \ No newline at end of file diff --git a/sql/11_get_db_size.sql b/sql/11_get_db_size.sql new file mode 100644 index 0000000..8a8ea44 --- /dev/null +++ b/sql/11_get_db_size.sql @@ -0,0 +1,72 @@ +prompt

Database Size

+-- set head off +-- col "Database Size" format 99,999.99 +-- select 'Database Size (Go) : ' || ( +-- SELECT ROUND(SUM(TAILLE_BYTES)/1024/1024/1024,2) "Database Size" FROM +-- ( +-- SELECT SUM(FILE_SIZE_BLKS*BLOCK_SIZE) TAILLE_BYTES FROM V$CONTROLFILE +-- UNION ALL +-- SELECT SUM(BYTES) FROM V$TEMPFILE +-- UNION ALL +-- SELECT SUM(BYTES) FROM V$DATAFILE +-- UNION ALL +-- SELECT SUM(MEMBERS*BYTES) FROM V$LOG +-- UNION ALL +-- SELECT BYTES FROM V$STANDBY_LOG SL, V$LOGFILE LF WHERE SL.GROUP# = LF.GROUP# +-- ) +-- ) +-- from dual; + +WITH +sizes AS ( +SELECT /*+ MATERIALIZE NO_MERGE */ /* 1f.60 */ + 'Data' file_type, + SUM(bytes) bytes + FROM v$datafile + UNION ALL +SELECT 'Temp' file_type, + SUM(bytes) bytes + FROM v$tempfile + UNION ALL +SELECT 'Log' file_type, + SUM(bytes) * MAX(members) bytes + FROM v$log + UNION ALL +SELECT 'Control' file_type, + SUM(block_size * file_size_blks) bytes + FROM v$controlfile +), +dbsize AS ( +SELECT /*+ MATERIALIZE NO_MERGE */ /* 1f.60 */ + 'Total' file_type, + SUM(bytes) bytes + FROM sizes +) +SELECT d.dbid, + d.name db_name, + s.file_type, + s.bytes, + CASE + WHEN s.bytes > POWER(10,15) THEN ROUND(s.bytes/POWER(10,15),3)||' P' + WHEN s.bytes > POWER(10,12) THEN ROUND(s.bytes/POWER(10,12),3)||' T' + WHEN s.bytes > POWER(10,9) THEN ROUND(s.bytes/POWER(10,9),3)||' G' + WHEN s.bytes > POWER(10,6) THEN ROUND(s.bytes/POWER(10,6),3)||' M' + WHEN s.bytes > POWER(10,3) THEN ROUND(s.bytes/POWER(10,3),3)||' K' + WHEN s.bytes > 0 THEN s.bytes||' B' END approx + FROM v$database d, + sizes s + UNION ALL +SELECT d.dbid, + d.name db_name, + s.file_type, + s.bytes, + CASE + WHEN s.bytes > POWER(10,15) THEN ROUND(s.bytes/POWER(10,15),3)||' P' + WHEN s.bytes > POWER(10,12) THEN ROUND(s.bytes/POWER(10,12),3)||' T' + WHEN s.bytes > POWER(10,9) THEN ROUND(s.bytes/POWER(10,9),3)||' G' + WHEN s.bytes > POWER(10,6) THEN ROUND(s.bytes/POWER(10,6),3)||' M' + WHEN s.bytes > POWER(10,3) THEN ROUND(s.bytes/POWER(10,3),3)||' K' + WHEN s.bytes > 0 THEN s.bytes||' B' END approx + FROM v$database d, + dbsize s; +exit \ No newline at end of file diff --git a/sql/12_check_db_restart.sql b/sql/12_check_db_restart.sql new file mode 100644 index 0000000..8416764 --- /dev/null +++ b/sql/12_check_db_restart.sql @@ -0,0 +1,5 @@ +prompt

Database Status

+alter session set nls_date_format='YYYY/MM/DD HH24:MI:SS'; +SELECT instance_name, host_name, startup_time, status, logins FROM gv$instance ORDER BY 1; +exit + diff --git a/sql/12_instance_status.sql b/sql/12_instance_status.sql new file mode 100644 index 0000000..79beef7 --- /dev/null +++ b/sql/12_instance_status.sql @@ -0,0 +1,14 @@ +select + inst_id, + instance_name, + status, + VERSION_FULL, + EDITION, + ARCHIVER, + INSTANCE_ROLE, + database_status +FROM gv$instance; + +SELECT inst_id, name, to_char(CREATED ,'DD/MM/YYYY') CREATED , open_mode, DATABASE_ROLE, log_mode, FORCE_LOGGING, CURRENT_SCN FROM gv$database; + +exit diff --git a/sql/13_database_parameters.sql b/sql/13_database_parameters.sql new file mode 100644 index 0000000..9b7e815 --- /dev/null +++ b/sql/13_database_parameters.sql @@ -0,0 +1,3 @@ +prompt

Database Parameters

+select NAME, DISPLAY_VALUE from v$parameter where ISDEFAULT='FALSE' order by name; +exit \ No newline at end of file diff --git a/sql/14_nls_database_parameters.sql b/sql/14_nls_database_parameters.sql new file mode 100644 index 0000000..42f3f08 --- /dev/null +++ b/sql/14_nls_database_parameters.sql @@ -0,0 +1,3 @@ +prompt

NLS Database Parameters

+select * from nls_database_parameters ; +exit diff --git a/sql/15_check_supplemntal_logging.sql b/sql/15_check_supplemntal_logging.sql new file mode 100644 index 0000000..0e5f6d6 --- /dev/null +++ b/sql/15_check_supplemntal_logging.sql @@ -0,0 +1,10 @@ +prompt

Database supplemental logging

+SELECT + supplemental_log_data_min data_min, + supplemental_log_data_pk data_pk, + supplemental_log_data_ui data_ui, + supplemental_log_data_fk data_fk, + supplemental_log_data_all data_all, + supplemental_log_data_pl data_pl +FROM v$database; +exit diff --git a/sql/16_dba_registry.sql b/sql/16_dba_registry.sql new file mode 100644 index 0000000..e8c2b1b --- /dev/null +++ b/sql/16_dba_registry.sql @@ -0,0 +1,10 @@ +prompt

Registry (DBA_REGISTRY)

+SELECT /*+ NO_MERGE */ + x.* + --,c.name con_name + FROM dba_registry x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id +ORDER BY + --x.con_id, + x.comp_id; +exit; diff --git a/sql/17_resource_limits.sql b/sql/17_resource_limits.sql new file mode 100644 index 0000000..898a6b7 --- /dev/null +++ b/sql/17_resource_limits.sql @@ -0,0 +1,8 @@ +prompt

Resource Limit (GV$RESOURCE_LIMIT)

+SELECT /*+ NO_MERGE */ + * + FROM gv$resource_limit + ORDER BY + resource_name, + inst_id; +exit \ No newline at end of file diff --git a/sql/18_memory_configuration.sql b/sql/18_memory_configuration.sql new file mode 100644 index 0000000..c2f708e --- /dev/null +++ b/sql/18_memory_configuration.sql @@ -0,0 +1,81 @@ +prompt

Memory Information

+WITH +system_parameter AS ( +SELECT inst_id, + name, + value + FROM gv$system_parameter2 + WHERE name IN +( 'memory_max_target' +, 'memory_target' +, 'pga_aggregate_target' +, 'sga_max_size' +, 'sga_target' +, 'db_cache_size' +, 'shared_pool_size' +, 'shared_pool_reserved_size' +, 'large_pool_size' +, 'java_pool_size' +, 'streams_pool_size' +, 'result_cache_max_size' +, 'db_keep_cache_size' +, 'db_recycle_cache_size' +, 'db_32k_cache_size' +, 'db_16k_cache_size' +, 'db_8k_cache_size' +, 'db_4k_cache_size' +, 'db_2k_cache_size' +)), +spparameter_inst AS ( +SELECT i.inst_id, + p.name, + p.display_value + FROM v$spparameter p, + gv$instance i + WHERE p.isspecified = 'TRUE' + AND p.sid <> '*' + AND i.instance_name = p.sid +), +spparameter_all AS ( +SELECT p.name, + p.display_value + FROM v$spparameter p + WHERE p.isspecified = 'TRUE' + AND p.sid = '*' +) +SELECT s.name, + s.inst_id, + CASE WHEN i.name IS NOT NULL THEN TO_CHAR(i.inst_id) ELSE (CASE WHEN a.name IS NOT NULL THEN '*' END) END spfile_sid, + NVL(i.display_value, a.display_value) spfile_value, + CASE s.value WHEN '0' THEN '0' ELSE TRIM(TO_CHAR(ROUND(TO_NUMBER(s.value)/POWER(2,30),3),'9990.000'))||'G' END current_gb, + NULL recommended_gb + FROM system_parameter s, + spparameter_inst i, + spparameter_all a + WHERE i.inst_id(+) = s.inst_id + AND i.name(+) = s.name + AND a.name(+) = s.name + ORDER BY + CASE s.name + WHEN 'memory_max_target' THEN 1 + WHEN 'memory_target' THEN 2 + WHEN 'pga_aggregate_target' THEN 3 + WHEN 'sga_max_size' THEN 4 + WHEN 'sga_target' THEN 5 + WHEN 'db_cache_size' THEN 6 + WHEN 'shared_pool_size' THEN 7 + WHEN 'shared_pool_reserved_size' THEN 8 + WHEN 'large_pool_size' THEN 9 + WHEN 'java_pool_size' THEN 10 + WHEN 'streams_pool_size' THEN 11 + WHEN 'result_cache_max_size' THEN 12 + WHEN 'db_keep_cache_size' THEN 13 + WHEN 'db_recycle_cache_size' THEN 14 + WHEN 'db_32k_cache_size' THEN 15 + WHEN 'db_16k_cache_size' THEN 16 + WHEN 'db_8k_cache_size' THEN 17 + WHEN 'db_4k_cache_size' THEN 18 + WHEN 'db_2k_cache_size' THEN 19 + END, + s.inst_id; +exit diff --git a/sql/19_memory_resize_operations.sql b/sql/19_memory_resize_operations.sql new file mode 100644 index 0000000..279900e --- /dev/null +++ b/sql/19_memory_resize_operations.sql @@ -0,0 +1,9 @@ +prompt

Memory Resize Operations

+SELECT /*+ NO_MERGE */ + * + FROM gv$memory_resize_ops + ORDER BY + inst_id, + start_time DESC, + component; +exit diff --git a/sql/20_tbs_details.sql b/sql/20_tbs_details.sql new file mode 100644 index 0000000..6c5bf8d --- /dev/null +++ b/sql/20_tbs_details.sql @@ -0,0 +1,38 @@ +prompt

Tablespace details

+COL TABLESPACE_NAME FORMAT A20 HEAD "Nom espace|disque logique" +COL PCT_OCCUPATION_THEORIQUE FORMAT 990.00 HEAD "%occ|Theo" +COL TAILLE_MIB FORMAT 99999990.00 HEAD "Taille|MiB" +COL TAILLE_MAX_MIB FORMAT 99999990.00 HEAD "Taille max|MiB" +COL TAILLE_OCCUPEE_MIB FORMAT 99999990.00 HEAD "Espace occupé|MiB" +WITH TS_FREE_SPACE AS +(select tablespace_name, file_id, sum(bytes) FREE_O from dba_free_space group by tablespace_name, file_id +), TEMP_ALLOC AS +(select tablespace_name, file_id, sum(bytes) USED_O from v$temp_extent_map group by tablespace_name, file_id +) +SELECT + TABLESPACE_NAME, + SUM(TAILLE_MIB) TAILLE_MIB, + SUM(TAILLE_MAX_MIB) TAILLE_MAX_MIB, + SUM(TAILLE_OCCUPEE_MIB) TAILLE_OCCUPEE_MIB, + ROUND(SUM(TAILLE_OCCUPEE_MIB)*100/SUM(GREATEST(TAILLE_MAX_MIB,TAILLE_MIB)),2) PCT_OCCUPATION_THEORIQUE +FROM +( + SELECT D.FILE_NAME, D.TABLESPACE_NAME, D.BYTES/1024/1024 TAILLE_MIB, DECODE(D.AUTOEXTENSIBLE,'NO',D.BYTES,D.MAXBYTES)/1024/1024 TAILLE_MAX_MIB, + (D.BYTES-FO.FREE_O)/1024/1024 TAILLE_OCCUPEE_MIB + FROM + DBA_DATA_FILES D, TS_FREE_SPACE FO + WHERE + D.TABLESPACE_NAME=FO.TABLESPACE_NAME + AND D.FILE_ID=FO.FILE_ID + UNION ALL + SELECT T.FILE_NAME, T.TABLESPACE_NAME, T.BYTES/1024/1024 TAILLE_MIB, DECODE(T.AUTOEXTENSIBLE,'NO',T.BYTES,T.MAXBYTES)/1024/1024 TAILLE_MAX_MIB, + (TA.USED_O)/1024/1024 TAILLE_OCCUPEE_MIB + FROM + DBA_TEMP_FILES T, TEMP_ALLOC TA + WHERE + T.TABLESPACE_NAME=TA.TABLESPACE_NAME + AND T.FILE_ID=TA.FILE_ID +) +GROUP BY TABLESPACE_NAME +ORDER BY TABLESPACE_NAME; +exit diff --git a/sql/21_datafile.sql b/sql/21_datafile.sql new file mode 100644 index 0000000..64db479 --- /dev/null +++ b/sql/21_datafile.sql @@ -0,0 +1,10 @@ +prompt

Datafiles

+SELECT /*+ NO_MERGE */ + x.file_name, x.file_id, x.tablespace_name, round(x.bytes/1024/1024,0) "Bytes_Mo", x.status, x.autoextensible, round(x.maxbytes/1024/1024/1024,0) "MaxBytes_Go", x.online_status + --,c.name con_name + FROM dba_data_files x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id + ORDER BY + --x.con_id, + x.file_name; +exit \ No newline at end of file diff --git a/sql/22_online_log.sql b/sql/22_online_log.sql new file mode 100644 index 0000000..4130d23 --- /dev/null +++ b/sql/22_online_log.sql @@ -0,0 +1,19 @@ +prompt

Redolog

+SELECT /*+ NO_MERGE */ + * + FROM v$log + ORDER BY 1, 2, 3, 4; + +prompt

Redolog Files

+COL MEMBER FORMAT A90 WRAPPED +BREAK ON GROUP# SKIP 1 ON THREAD# ON SEQUENCE# ON TAILLE_MIB ON "STATUS(ARCHIVED)" +SELECT 'OnlineLog' T, G.GROUP#, G.THREAD#, G.SEQUENCE#, G.BYTES/1024/1024 TAILLE_MIB, G.STATUS||'('||G.ARCHIVED||')' "STATUS(ARCHIVED)", F.MEMBER +FROM V$LOG G, V$LOGFILE F +WHERE G.GROUP#=F.GROUP# +UNION ALL +SELECT 'StandbyLog',G.GROUP#, G.THREAD#, G.SEQUENCE#, G.BYTES/1024/1024 TAILLE_MIB, G.STATUS||'('||G.ARCHIVED||')' "STATUS(ARCHIVED)", F.MEMBER +FROM V$STANDBY_LOG G, V$LOGFILE F +WHERE G.GROUP#=F.GROUP# +ORDER BY 1,3,4,2; +exit + diff --git a/sql/23_archive_log_per_day.sql b/sql/23_archive_log_per_day.sql new file mode 100644 index 0000000..2e448a2 --- /dev/null +++ b/sql/23_archive_log_per_day.sql @@ -0,0 +1,78 @@ +prompt

Taille des redolog par jours / heure

+set head off +select max('Taille des fichiers redolog (Mo) : ' || bytes/1024/1024) from v$log; + +set head on +set pages 999 lines 200 +col Date for a12 +col Total for 9999 +col 00 for 999 +col 01 for 999 +col 02 for 999 +col 03 for 999 +col 04 for 999 +col 05 for 999 +col 06 for 999 +col 07 for 999 +col 08 for 999 +col 09 for 999 +col 10 for 999 +col 11 for 999 +col 12 for 999 +col 13 for 999 +col 14 for 999 +col 15 for 999 +col 16 for 999 +col 17 for 999 +col 18 for 999 +col 19 for 999 +col 20 for 999 +col 21 for 999 +col 22 for 999 +col 23 for 999 +col 24 for 999 + + +select to_char(first_time, 'YYYY/MM/dd') "Date", +count(1) "Total", +sum(decode(to_char(first_time, 'hh24'),'00',1,0)) "00", +sum(decode(to_char(first_time, 'hh24'),'01',1,0)) "01", +sum(decode(to_char(first_time, 'hh24'),'02',1,0)) "02", +sum(decode(to_char(first_time, 'hh24'),'03',1,0)) "03", +sum(decode(to_char(first_time, 'hh24'),'04',1,0)) "04", +sum(decode(to_char(first_time, 'hh24'),'05',1,0)) "05", +sum(decode(to_char(first_time, 'hh24'),'06',1,0)) "06", +sum(decode(to_char(first_time, 'hh24'),'07',1,0)) "07", +sum(decode(to_char(first_time, 'hh24'),'08',1,0)) "08", +sum(decode(to_char(first_time, 'hh24'),'09',1,0)) "09", +sum(decode(to_char(first_time, 'hh24'),'10',1,0)) "10", +sum(decode(to_char(first_time, 'hh24'),'11',1,0)) "11", +sum(decode(to_char(first_time, 'hh24'),'12',1,0)) "12", +sum(decode(to_char(first_time, 'hh24'),'13',1,0)) "13", +sum(decode(to_char(first_time, 'hh24'),'14',1,0)) "14", +sum(decode(to_char(first_time, 'hh24'),'15',1,0)) "15", +sum(decode(to_char(first_time, 'hh24'),'16',1,0)) "16", +sum(decode(to_char(first_time, 'hh24'),'17',1,0)) "17", +sum(decode(to_char(first_time, 'hh24'),'18',1,0)) "18", +sum(decode(to_char(first_time, 'hh24'),'19',1,0)) "19", +sum(decode(to_char(first_time, 'hh24'),'20',1,0)) "20", +sum(decode(to_char(first_time, 'hh24'),'21',1,0)) "21", +sum(decode(to_char(first_time, 'hh24'),'22',1,0)) "22", +sum(decode(to_char(first_time, 'hh24'),'23',1,0)) "23", +sum(decode(to_char(first_time, 'hh24'),'24',1,0)) "24" +from v$log_history +group by to_char(first_time, 'YYYY/MM/dd') +order by to_char(first_time, 'YYYY/MM/dd') +; + +prompt

Taille des redolog par jour

+select + to_char(first_time, 'YYYY/MM/dd') "Jour", + count(*) "Nbr de fichiers", + ROUND(sum(BLOCKS*BLOCK_SIZE)/1024/1024, 0) "Taille_Mo" +from v$archived_log +group by to_char(first_time, 'YYYY/MM/dd') +order by to_char(first_time, 'YYYY/MM/dd') +; + +exit diff --git a/sql/24_fra_usage.sql b/sql/24_fra_usage.sql new file mode 100644 index 0000000..a64601f --- /dev/null +++ b/sql/24_fra_usage.sql @@ -0,0 +1,10 @@ +prompt

Fast Recovery Area Usage

+SELECT VALUE/1024/1024 TAILLE_FRA_MiB, ROUND((VALUE*TOT_PCT/100)/1024/1024,0) ESPACE_UTILISE_MiB, + TOT_PCT POURCENTAGE_UTILISE +FROM + V$PARAMETER P, + (SELECT SUM(PERCENT_SPACE_USED) TOT_PCT FROM V$FLASH_RECOVERY_AREA_USAGE) PCT_U +WHERE NAME='db_recovery_file_dest_size'; +prompt +SELECT * FROM V$FLASH_RECOVERY_AREA_USAGE; +exit \ No newline at end of file diff --git a/sql/25_last_alertlog_errors.sql b/sql/25_last_alertlog_errors.sql new file mode 100644 index 0000000..09b0b32 --- /dev/null +++ b/sql/25_last_alertlog_errors.sql @@ -0,0 +1,7 @@ +prompt

Last alertlog errors

+ +set pages 999 lines 150 +select to_char(ORIGINATING_TIMESTAMP, 'DD-MM-YYYY HH-MM-SS') || ' : ' || message_text "Last alertlog (30 days)" +FROM X$DBGALERTEXT +WHERE originating_timestamp > systimestamp - 30 AND regexp_like(message_text, '(ORA-)'); +exit diff --git a/sql/27_last_rman_backup.sql b/sql/27_last_rman_backup.sql new file mode 100644 index 0000000..b17d723 --- /dev/null +++ b/sql/27_last_rman_backup.sql @@ -0,0 +1,21 @@ +prompt

Last RMAN backups

+alter session set nls_date_format='DD/MM/YYYY HH24:MI:SS' ; +set linesize 250 heading off; +set heading on pagesize 999; +column status format a25; +column input_bytes_display format a12; +column output_bytes_display format a12; +column device_type format a10; + +select + b.input_type, + b.status, + to_char(b.start_time,'DD-MM-YYYY HH24:MI') "Start Time", + to_char(b.end_time,'DD-MM-YYYY HH24:MI') "End Time", + b.output_device_type device_type, + b.input_bytes_display, + b.output_bytes_display +FROM v$rman_backup_job_details b +WHERE b.start_time > (SYSDATE - 30) +ORDER BY b.start_time asc; +exit diff --git a/sql/28_sysaux_occupants.sql b/sql/28_sysaux_occupants.sql new file mode 100644 index 0000000..e5b28d5 --- /dev/null +++ b/sql/28_sysaux_occupants.sql @@ -0,0 +1,6 @@ +prompt

SYSAUX Occupants

+SELECT /*+ NO_MERGE */ + v.*, ROUND(v.space_usage_kbytes / POWER(10,6), 3) space_usage_gbs + FROM v$sysaux_occupants v + ORDER BY 1; + exit \ No newline at end of file diff --git a/sql/30_users.sql b/sql/30_users.sql new file mode 100644 index 0000000..181fe68 --- /dev/null +++ b/sql/30_users.sql @@ -0,0 +1,20 @@ +prompt

Database Users

+set pages 999 +ALTER SESSION SET NLS_DATE_FORMAT ='YYYY/MM/DD HH24:MI'; +-- select USERNAME, ACCOUNT_STATUS, PROFILE, DEFAULT_TABLESPACE DEF_TBS, TEMPORARY_TABLESPACE TMP_TBS, CREATED, PASSWORD_VERSIONS from dba_users order by created; +SELECT /*+ NO_MERGE */ + x.username, + x.user_id, + x.account_status, + x.lock_date, + x.expiry_date, + x.default_tablespace, + x.temporary_tablespace, + x.created, + x.profile, x.password_versions, x.password_change_date + --,c.name con_name + FROM dba_users x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id + ORDER BY x.username + --,x.con_id; +exit diff --git a/sql/31_who_is_connected.sql b/sql/31_who_is_connected.sql new file mode 100644 index 0000000..2b55294 --- /dev/null +++ b/sql/31_who_is_connected.sql @@ -0,0 +1,71 @@ +-- Qui est connecté à la base : +prompt

Sessions Aggregate per User and Type

+WITH x as ( +SELECT COUNT(*), + --con_id, + username, + inst_id, + type, + server, + status, + state + FROM gv$session + GROUP BY + --con_id, + username, + inst_id, + type, + server, + status, + state +) +SELECT x.* + --,c.name con_name +FROM x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id + ORDER BY + 1 DESC, + --x.con_id, + x.username, x.inst_id, x.type, x.server, x.status, x.state; + + +prompt

Sessions Aggregate per Module and Action

+WITH x AS ( +SELECT COUNT(*), + --con_id, + module, + action, + inst_id, + type, + server, + status, + state + FROM gv$session + GROUP BY + --con_id, + module, + action, + inst_id, + type, + server, + status, + state +) +SELECT x.* + --,c.name con_name +FROM x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id + ORDER BY + 1 DESC, + --x.con_id, + x.module, x.action, x.inst_id, x.type, x.server, x.status, x.state; + +prompt

Who is connected ?

+ +set pages 999 lines 200 +col PROGRAM for a35 +col MACHINE for a20 +col OSUSER for a10 +alter session set nls_date_format='YYYY/MM/DD HH24:MI:SS'; +select OSUSER, MACHINE, PROGRAM, STATE, LOGON_TIME, EVENT from v$session order by LOGON_TIME asc; +exit diff --git a/sql/32_invalid_objects.sql b/sql/32_invalid_objects.sql new file mode 100644 index 0000000..4bcd765 --- /dev/null +++ b/sql/32_invalid_objects.sql @@ -0,0 +1,3 @@ +prompt

Invalid objects

+select owner, count(*) "invalid objects" FROM dba_objects WHERE status <> 'VALID' group by owner order by owner; +exit diff --git a/sql/34_disable_auto_tasks.sql b/sql/34_disable_auto_tasks.sql new file mode 100644 index 0000000..f2b2ebc --- /dev/null +++ b/sql/34_disable_auto_tasks.sql @@ -0,0 +1,3 @@ +prompt

Autotasks status

+select client_name, status,attributes,service_name from dba_autotask_client; +exit diff --git a/sql/35_get_cursor_usage.sql b/sql/35_get_cursor_usage.sql new file mode 100644 index 0000000..51a6ce7 --- /dev/null +++ b/sql/35_get_cursor_usage.sql @@ -0,0 +1,50 @@ +-- SCRIPT - to Set the 'SESSION_CACHED_CURSORS' and 'OPEN_CURSORS' Parameters Based on Usage (Doc ID 208857.1) +prompt

Sessions and Cursors usage

+select +'session_cached_cursors' parameter, +lpad(value, 5) value, +decode(value, 0, ' n/a', to_char(100 * used / value, '990') || '%') usage +from +( select +max(s.value) used +from +v$statname n, +v$sesstat s +where +n.name = 'session cursor cache count' and +s.statistic# = n.statistic# +), +( select +value +from +v$parameter +where +name = 'session_cached_cursors' +) +union all +select +'open_cursors', +lpad(value, 5), +to_char(100 * used / value, '990') || '%' +from +( select +max(sum(s.value)) used +from +v$statname n, +v$sesstat s +where +n.name in ('opened cursors current') and +s.statistic# = n.statistic# +group by +s.sid +), +( select +value +from +v$parameter +where +name = 'open_cursors' +) +; + +exit \ No newline at end of file diff --git a/sql/36_check_failed_cheduler_jobs.sql b/sql/36_check_failed_cheduler_jobs.sql new file mode 100644 index 0000000..618e3ad --- /dev/null +++ b/sql/36_check_failed_cheduler_jobs.sql @@ -0,0 +1,7 @@ +prompt

Failed scheduled jobs

+SELECT owner, job_name, job_type, state, TRUNC(start_date) SDATE, TRUNC(next_run_date) NXTRUN, failure_count +FROM dba_scheduler_jobs +WHERE failure_count <> 0; +exit + + diff --git a/sql/37_table_statistics_summary.sql b/sql/37_table_statistics_summary.sql new file mode 100644 index 0000000..5a27b7a --- /dev/null +++ b/sql/37_table_statistics_summary.sql @@ -0,0 +1,42 @@ +prompt

Table Statistics Summary

+alter session set nls_date_format='YYYY/MM/DD HH24:MI:SS'; +WITH x as ( +SELECT /*+ NO_MERGE */ + --con_id, + owner, + object_type, + COUNT(*) type_count, + SUM(DECODE(last_analyzed, NULL, 1, 0)) not_analyzed, + SUM(DECODE(stattype_locked, NULL, 0, 1)) stats_locked, + SUM(DECODE(stale_stats, 'YES', 1, 0)) stale_stats, + SUM(num_rows) sum_num_rows, + MAX(num_rows) max_num_rows, + SUM(blocks) sum_blocks, + MAX(blocks) max_blocks, + MIN(last_analyzed) min_last_analyzed, + MAX(last_analyzed) max_last_analyzed, + MEDIAN(last_analyzed) median_last_analyzed, + PERCENTILE_DISC(0.75) WITHIN GROUP (ORDER BY last_analyzed) last_analyzed_75_percentile, + PERCENTILE_DISC(0.90) WITHIN GROUP (ORDER BY last_analyzed) last_analyzed_90_percentile, + PERCENTILE_DISC(0.95) WITHIN GROUP (ORDER BY last_analyzed) last_analyzed_95_percentile, + PERCENTILE_DISC(0.99) WITHIN GROUP (ORDER BY last_analyzed) last_analyzed_99_percentile + FROM dba_tab_statistics s + WHERE table_name NOT LIKE 'BIN$%' -- bug 9930151 reported by brad peek + AND NOT EXISTS ( +SELECT /*+ NO_MERGE */ NULL + FROM dba_external_tables e + WHERE e.owner = s.owner + --AND e.con_id = s.con_id + AND e.table_name = s.table_name) +GROUP BY + --con_id, + owner, object_type +) +SELECT x.* + --,c.name con_name +FROM x + --LEFT OUTER JOIN v$containers c ON c.con_id = x.con_id + ORDER BY + --x.con_id, + owner, object_type; +exit \ No newline at end of file diff --git a/sql/99_html_footer.html b/sql/99_html_footer.html new file mode 100644 index 0000000..534f4ee --- /dev/null +++ b/sql/99_html_footer.html @@ -0,0 +1,4 @@ + +
+ +