diff --git a/Daily/sql/1_get_db_size.sql b/Daily/sql/00_get_db_size.sql similarity index 100% rename from Daily/sql/1_get_db_size.sql rename to Daily/sql/00_get_db_size.sql diff --git a/Daily/sql/0_check_db_restart.sql b/Daily/sql/01_check_db_restart.sql similarity index 100% rename from Daily/sql/0_check_db_restart.sql rename to Daily/sql/01_check_db_restart.sql diff --git a/Daily/sql/2_instance_status.sql b/Daily/sql/02_instance_status.sql similarity index 100% rename from Daily/sql/2_instance_status.sql rename to Daily/sql/02_instance_status.sql diff --git a/Daily/sql/3_database_parameters.sql b/Daily/sql/03_database_parameters.sql similarity index 100% rename from Daily/sql/3_database_parameters.sql rename to Daily/sql/03_database_parameters.sql diff --git a/Daily/sql/04_nls_database_parameters.sql b/Daily/sql/04_nls_database_parameters.sql new file mode 100644 index 0000000..6e21c4e --- /dev/null +++ b/Daily/sql/04_nls_database_parameters.sql @@ -0,0 +1,2 @@ +select * from nls_database_parameters ; +exit diff --git a/Daily/sql/check_supplemntal_logging.sql b/Daily/sql/05_check_supplemntal_logging.sql similarity index 100% rename from Daily/sql/check_supplemntal_logging.sql rename to Daily/sql/05_check_supplemntal_logging.sql diff --git a/Daily/sql/10_tbs_details.sql b/Daily/sql/10_tbs_details.sql new file mode 100644 index 0000000..f61de4c --- /dev/null +++ b/Daily/sql/10_tbs_details.sql @@ -0,0 +1,37 @@ +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/Daily/sql/11_temp_tbs_details.sql b/Daily/sql/11_temp_tbs_details.sql new file mode 100644 index 0000000..c34e624 --- /dev/null +++ b/Daily/sql/11_temp_tbs_details.sql @@ -0,0 +1,10 @@ +SELECT A.tablespace_name tablespace, D.mb_total,SUM (A.used_blocks * D.block_size) / 1024 / 1024 mb_used, +D.mb_total - SUM (A.used_blocks * D.block_size) / 1024 / 1024 mb_free +FROM v$sort_segment A, +( +SELECT B.name, C.block_size, SUM (C.bytes) / 1024 / 1024 mb_total +FROM v$tablespace B, v$tempfile C +WHERE B.ts#= C.ts# GROUP BY B.name, C.block_size +) D +WHERE A.tablespace_name = D.name GROUP by A.tablespace_name, D.mb_total; +exit diff --git a/Daily/sql/12_online_log.sql b/Daily/sql/12_online_log.sql new file mode 100644 index 0000000..ac50945 --- /dev/null +++ b/Daily/sql/12_online_log.sql @@ -0,0 +1,12 @@ +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/Daily/sql/13_archive_log_per_day.sql b/Daily/sql/13_archive_log_per_day.sql new file mode 100644 index 0000000..b72f5cc --- /dev/null +++ b/Daily/sql/13_archive_log_per_day.sql @@ -0,0 +1,77 @@ +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/Daily/sql/redolog_freq_switch.sql b/Daily/sql/14_redolog_freq_switch.sql similarity index 100% rename from Daily/sql/redolog_freq_switch.sql rename to Daily/sql/14_redolog_freq_switch.sql diff --git a/Daily/sql/15_last_alertlog_errors.sql b/Daily/sql/15_last_alertlog_errors.sql new file mode 100644 index 0000000..2977064 --- /dev/null +++ b/Daily/sql/15_last_alertlog_errors.sql @@ -0,0 +1,5 @@ +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/Daily/sql/redolog_size_per_days.sql b/Daily/sql/16_redolog_size_per_days.sql similarity index 100% rename from Daily/sql/redolog_size_per_days.sql rename to Daily/sql/16_redolog_size_per_days.sql diff --git a/Daily/sql/17_last_rman_backup.sql b/Daily/sql/17_last_rman_backup.sql new file mode 100644 index 0000000..dc7eba6 --- /dev/null +++ b/Daily/sql/17_last_rman_backup.sql @@ -0,0 +1,20 @@ +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/Daily/sql/20_users.sql b/Daily/sql/20_users.sql new file mode 100644 index 0000000..bcb182e --- /dev/null +++ b/Daily/sql/20_users.sql @@ -0,0 +1,3 @@ +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; +exit diff --git a/Daily/sql/who_is_connected.sql b/Daily/sql/21_who_is_connected.sql similarity index 100% rename from Daily/sql/who_is_connected.sql rename to Daily/sql/21_who_is_connected.sql diff --git a/Daily/sql/check_pga_use.sql b/Daily/sql/22_check_pga_use.sql similarity index 100% rename from Daily/sql/check_pga_use.sql rename to Daily/sql/22_check_pga_use.sql diff --git a/Daily/sql/check_sort_area.sql b/Daily/sql/23_check_sort_area.sql similarity index 100% rename from Daily/sql/check_sort_area.sql rename to Daily/sql/23_check_sort_area.sql diff --git a/Daily/sql/disable_auto_tasks.sql b/Daily/sql/24_disable_auto_tasks.sql similarity index 100% rename from Daily/sql/disable_auto_tasks.sql rename to Daily/sql/24_disable_auto_tasks.sql diff --git a/Daily/sql/get_cursor_usage.sql b/Daily/sql/25_get_cursor_usage.sql similarity index 100% rename from Daily/sql/get_cursor_usage.sql rename to Daily/sql/25_get_cursor_usage.sql diff --git a/Daily/sql/check_failed_cheduler_jobs.sql b/Daily/sql/26_check_failed_cheduler_jobs.sql similarity index 100% rename from Daily/sql/check_failed_cheduler_jobs.sql rename to Daily/sql/26_check_failed_cheduler_jobs.sql diff --git a/Daily/sql/get_tablespaces_ddl_ver_courte.sql b/Daily/sql/get_tablespaces_ddl_ver_courte.sql deleted file mode 100644 index 9d687b8..0000000 --- a/Daily/sql/get_tablespaces_ddl_ver_courte.sql +++ /dev/null @@ -1,59 +0,0 @@ -select '------- HOSTNAME : '||host_name||', DB_NAME : '||name||', VERSION : '||version || ' -------' from v$database,v$instance; -select '------- Datafiles -------' from dual; -SELECT 'CREATE ' - || DECODE (ts.bigfile, 'YES', 'BIGFILE ') --assuming smallfile is the default table space - || 'TABLESPACE "' || ts.tablespace_name || '" DATAFILE ' || CHR(13) || CHR(10) - || LISTAGG(decode(p.value, NULL, ' ''' || df.file_name || '''') || ' SIZE ' - || CASE - -- si la taille est nulle ou < 1M on retourne 1M - WHEN e.used_bytes is NULL or e.used_bytes < (1024*1024) - THEN '1M' - ELSE to_char(floor(e.used_bytes/(1024*1024))) || 'M' - END - || DECODE (df.autoextensible, 'YES', ' AUTOEXTEND ON'), - ',' || CHR (13) || CHR (10)) - WITHIN GROUP (ORDER BY df.file_id, df.file_name) - || ';' - ddl - FROM dba_tablespaces ts, - dba_data_files df, - (SELECT file_id, sum(decode(bytes,NULL,0,bytes)) used_bytes FROM dba_extents GROUP by file_id) e, - (select VALUE from v$parameter where name='db_create_file_dest') p - WHERE ts.tablespace_name not in ('SYSTEM','SYSAUX') - and ts.tablespace_name not like '%UNDO%' - and e.file_id (+) = df.file_id - and ts.tablespace_name = df.tablespace_name - GROUP BY ts.tablespace_name, - ts.bigfile, - ts.block_size - ORDER BY ts.tablespace_name; - -select '------- Tempfiles -------' from dual; - -SELECT 'CREATE TEMPORARY TABLESPACE "' || ts.tablespace_name || '" TEMPFILE ' || CHR (13) || CHR (10) - || LISTAGG(decode(p.value, NULL, ' ''' || df.file_name || '''') || ' SIZE ' - || CASE - -- si la taille est nulle ou < 1M on retourne 1M - WHEN e.used_bytes is NULL or e.used_bytes < (1024*1024) - THEN '1M' - ELSE to_char(floor(e.used_bytes/(1024*1024))) || 'M' - END - || DECODE (df.autoextensible, 'YES', ' AUTOEXTEND ON'), - ',' || CHR (13) || CHR (10)) - WITHIN GROUP (ORDER BY df.file_id, df.file_name) - || ';' - ddl - FROM dba_tablespaces ts, - dba_temp_files df, - (SELECT file_id, sum(decode(bytes,NULL,0,bytes)) used_bytes FROM dba_extents GROUP by file_id) e, - (select VALUE from v$parameter where name='db_create_file_dest') p - WHERE e.file_id (+) = df.file_id - and ts.tablespace_name = df.tablespace_name - GROUP BY ts.tablespace_name, - ts.bigfile, - ts.block_size - ORDER BY ts.tablespace_name; - - -EXIT -