add sql scripts
This commit is contained in:
4
Daily/sql/check_db_restart.sql
Normal file
4
Daily/sql/check_db_restart.sql
Normal file
@@ -0,0 +1,4 @@
|
||||
alter session set nls_date_format='YYYY/MM/DD HH24:MI:SS';
|
||||
col host_name format a15
|
||||
SELECT instance_name, host_name, startup_time, status, logins FROM gv$instance ORDER BY 1;
|
||||
|
||||
4
Daily/sql/check_failed_cheduler_jobs.sql
Normal file
4
Daily/sql/check_failed_cheduler_jobs.sql
Normal file
@@ -0,0 +1,4 @@
|
||||
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;
|
||||
|
||||
13
Daily/sql/check_pga_use.sql
Normal file
13
Daily/sql/check_pga_use.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
col osuser format a15
|
||||
col pid format 9999
|
||||
col program format a20
|
||||
col sid format 99999
|
||||
col spid format a6
|
||||
col username format a12
|
||||
|
||||
SELECT p.spid,p.pid,s.sid,s.serial#,s.status,p.pga_alloc_mem,p.PGA_USED_MEM,s.username,s.osuser,s.program
|
||||
FROM v$process p,v$session s
|
||||
WHERE s.paddr ( + ) = p.addr
|
||||
-- AND p.background IS NULL -- comment if need to monitor background processes
|
||||
ORDER BY p.pga_alloc_mem DESC;
|
||||
|
||||
6
Daily/sql/check_sort_area.sql
Normal file
6
Daily/sql/check_sort_area.sql
Normal file
@@ -0,0 +1,6 @@
|
||||
SELECT a.value "Disk Sorts", b.value "Memory Sorts",
|
||||
ROUND((100*b.value)/DECODE((a.value+b.value), 0,1,(a.value+b.value)),2) "Pct Memory Sorts"
|
||||
FROM v$sysstat a, v$sysstat b
|
||||
WHERE a.name = 'sorts (disk)'
|
||||
AND b.name = 'sorts (memory)';
|
||||
|
||||
3
Daily/sql/check_supplemntal_logging.sql
Normal file
3
Daily/sql/check_supplemntal_logging.sql
Normal file
@@ -0,0 +1,3 @@
|
||||
SELECT supplemental_log_data_min, supplemental_log_data_pk, supplemental_log_data_ui, supplemental_log_data_fk, supplemental_log_data_all, supplemental_log_data_pl
|
||||
FROM v$database;
|
||||
|
||||
58
Daily/sql/disable_auto_tasks.sql
Normal file
58
Daily/sql/disable_auto_tasks.sql
Normal file
@@ -0,0 +1,58 @@
|
||||
--
|
||||
-- lorsqu'on vérifie les options utilisées par la base, "Automatic SQL Tuning Advisor" sort aussi
|
||||
-- même si la base n'est pas licenciée avec Tuning Pack
|
||||
-- Ce script permet de voir et désactiver les tâches automatiques
|
||||
-- pour ne pas avoir à licencier Tuning Pack
|
||||
--
|
||||
set lines 180 pages 1000
|
||||
col client_name for a40
|
||||
col attributes for a60
|
||||
col service_name for a20
|
||||
select client_name, status,attributes,service_name from dba_autotask_client
|
||||
/
|
||||
|
||||
BEGIN
|
||||
DBMS_AUTO_TASK_ADMIN.disable(
|
||||
client_name => 'auto space advisor',
|
||||
operation => NULL,
|
||||
window_name => NULL);
|
||||
END;
|
||||
/
|
||||
|
||||
BEGIN
|
||||
DBMS_AUTO_TASK_ADMIN.disable(
|
||||
client_name => 'sql tuning advisor',
|
||||
operation => NULL,
|
||||
window_name => NULL);
|
||||
END;
|
||||
/
|
||||
|
||||
-- BEGIN
|
||||
-- DBMS_AUTO_TASK_ADMIN.disable
|
||||
-- (
|
||||
-- client_name => 'auto optimizer stats collection',
|
||||
-- operation => NULL,
|
||||
-- window_name => NULL);
|
||||
-- END;
|
||||
-- /
|
||||
|
||||
select client_name, status,attributes,service_name from dba_autotask_client
|
||||
/
|
||||
|
||||
-- pour réactiver les auto task remplacer DBMS_AUTO_TASK_ADMIN.disable par DBMS_AUTO_TASK_ADMIN.enable
|
||||
|
||||
-- BEGIN
|
||||
-- dbms_auto_task_admin.enable(client_name => 'sql tuning advisor', operation => NULL, window_name => NULL);
|
||||
-- END;
|
||||
-- /
|
||||
|
||||
-- BEGIN
|
||||
-- DBMS_AUTO_TASK_ADMIN.enable(client_name => 'sql tuning advisor', operation => NULL, window_name => NULL);
|
||||
-- END;
|
||||
-- /
|
||||
|
||||
-- BEGIN
|
||||
-- DBMS_AUTO_TASK_ADMIN.enable(client_name => 'auto optimizer stats collection', operation => NULL, window_name => NULL);
|
||||
-- END;
|
||||
-- /
|
||||
|
||||
47
Daily/sql/get_cursor_usage.sql
Normal file
47
Daily/sql/get_cursor_usage.sql
Normal file
@@ -0,0 +1,47 @@
|
||||
-- SCRIPT - to Set the 'SESSION_CACHED_CURSORS' and 'OPEN_CURSORS' Parameters Based on Usage (Doc ID 208857.1)
|
||||
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'
|
||||
)
|
||||
/
|
||||
27
Daily/sql/get_grant_and_priv.sql
Normal file
27
Daily/sql/get_grant_and_priv.sql
Normal file
@@ -0,0 +1,27 @@
|
||||
--
|
||||
-- Le script prend en parametre un compte utilisateur
|
||||
-- ensuite il retourne les requetes pour creer les grants associe a ce compte
|
||||
-- un fichier grant_USER.lst est généré dans le répertoire courant
|
||||
--
|
||||
set heading off pages 0 feedback off echo off verify off
|
||||
ACCEPT v_user CHAR PROMPT 'compte utilisateur pour lequel on va extraire les GRANTS : '
|
||||
|
||||
SPOOL grant_&v_user
|
||||
SELECT 'REM Les roles :' FROM DUAL;
|
||||
SELECT DISTINCT 'CREATE ROLE '||GRANTED_ROLE||';' FROM DBA_ROLE_PRIVS WHERE GRANTEE IN &v_users;
|
||||
|
||||
SELECT 'REM Les GRANTs depuis DBA_ROLE_PRIVS :' FROM DUAL;
|
||||
SELECT DISTINCT 'GRANT '||GRANTED_ROLE||' TO '||GRANTEE|| CASE WHEN ADMIN_OPTION='YES' THEN ' WITH ADMIN OPTION;' ELSE ';' END "Granted Roles" FROM DBA_ROLE_PRIVS WHERE GRANTEE IN &v_users ORDER BY 1;
|
||||
|
||||
SELECT 'REM Les GRANTs depuis DBA_SYS_PRIVS :' FROM DUAL;
|
||||
SELECT DISTINCT 'GRANT '||PRIVILEGE||' TO '||GRANTEE|| CASE WHEN ADMIN_OPTION='YES' THEN ' WITH ADMIN OPTION;' ELSE ';' END "Granted System Privileges" FROM DBA_SYS_PRIVS WHERE GRANTEE IN &v_users;
|
||||
|
||||
SELECT 'REM Les GRANTs depuis DBA_TAB_PRIVS :' FROM DUAL;
|
||||
SELECT DISTINCT 'GRANT '||PRIVILEGE||' ON '||OWNER||'.'||TABLE_NAME||' TO '||GRANTEE||CASE WHEN GRANTABLE='YES' THEN ' WITH GRANT OPTION;' ELSE ';' END "Granted Object Privileges" FROM DBA_TAB_PRIVS WHERE GRANTEE IN &v_users;
|
||||
|
||||
SELECT 'REM Les GRANTs depuis DBA_TAB_PRIVS pour le compte PUBLIC sur les objets SYS.DBMS_XXX :' FROM DUAL;
|
||||
SELECT DISTINCT 'GRANT '||PRIVILEGE||' ON '||OWNER||'.'||TABLE_NAME||' TO '||GRANTEE||CASE WHEN GRANTABLE='YES' THEN ' WITH GRANT OPTION;' ELSE ';' END "Granted Object Privileges" FROM DBA_TAB_PRIVS WHERE GRANTEE IN ('PUBLIC') and OWNER='SYS' and TABLE_NAME like '%DBMS_%' order by 1;
|
||||
|
||||
SPOOL OFF
|
||||
EXIT
|
||||
|
||||
61
Daily/sql/get_tablespaces_ddl_ver_courte.sql
Normal file
61
Daily/sql/get_tablespaces_ddl_ver_courte.sql
Normal file
@@ -0,0 +1,61 @@
|
||||
set head off pages 0 feedback off lines 200
|
||||
|
||||
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
|
||||
|
||||
@@ -1,288 +0,0 @@
|
||||
set echo off
|
||||
set feedback off
|
||||
-- set serveroutput off
|
||||
-- set termout off
|
||||
-- set pagesize 1000
|
||||
-- set markup html on
|
||||
|
||||
|
||||
SET MARKUP HTML ON SPOOL ON PREFORMAT OFF ENTMAP OFF
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Current DATE</h2>
|
||||
-- ---------------------------------------------------
|
||||
set head off
|
||||
select to_char(sysdate,'DD/MM/YYYY HH24:MI:SS') "Current Date" from dual;
|
||||
set head on
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Database Size</h2>
|
||||
-- ---------------------------------------------------
|
||||
set head off
|
||||
col TOTAL_SIZE_GB format 99,999.99
|
||||
SELECT ROUND(SUM(TAILLE_BYTES)/1024/1024/1024,2) TOTAL_SIZE_GB 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#
|
||||
);
|
||||
set head on
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>INSTANCE STATUS</h2>
|
||||
-- ---------------------------------------------------
|
||||
select inst_id,
|
||||
instance_name,
|
||||
status,
|
||||
VERSION_FULL,
|
||||
EDITION,
|
||||
ARCHIVER,
|
||||
INSTANCE_ROLE,
|
||||
database_status,
|
||||
active_state,
|
||||
to_char(startup_time,'DD/MM/YYYY HH24:MI:SS') startup_time
|
||||
FROM gv$instance;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Database Status </h2>
|
||||
-- ---------------------------------------------------
|
||||
SELECT inst_id, name, to_char(CREATED ,'DD/MM/YYYY') CREATED , open_mode, DATABASE_ROLE, log_mode, FORCE_LOGGING, CURRENT_SCN FROM gv$database;
|
||||
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Database non default parameters</h2>
|
||||
-- ---------------------------------------------------
|
||||
set pages 999 lines 150
|
||||
col name for a50
|
||||
col value for a90
|
||||
col display_value for a90
|
||||
select NAME, DISPLAY_VALUE from v$parameter where ISDEFAULT='FALSE' order by name;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Users</h2>
|
||||
-- ---------------------------------------------------
|
||||
set pages 999 lines 150
|
||||
ALTER SESSION SET NLS_DATE_FORMAT ='YYYY/MM/DD HH24:MI';
|
||||
col USERNAME for a25
|
||||
col DEF_TBS for a15
|
||||
col TMP_TBS for a10
|
||||
col PROFILE for a10
|
||||
col ACCOUNT_STATUS for a20
|
||||
select USERNAME, ACCOUNT_STATUS, PROFILE, DEFAULT_TABLESPACE DEF_TBS, TEMPORARY_TABLESPACE TMP_TBS, CREATED, PASSWORD_VERSIONS from dba_users order by created;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>NLS Database parameters</h2>
|
||||
-- ---------------------------------------------------
|
||||
col parameter for a30
|
||||
col value for a30
|
||||
select * from nls_database_parameters ;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Fast Rrecovery Area</h2>
|
||||
-- ---------------------------------------------------
|
||||
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;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Invalid objects</h2>
|
||||
-- ---------------------------------------------------
|
||||
select owner,OBJECT_NAME, status FROM dba_objects WHERE status <> 'VALID';
|
||||
prompt
|
||||
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Tablespace Details</h2>
|
||||
-- ---------------------------------------------------
|
||||
|
||||
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;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>TEMP Tablespace</h2>
|
||||
-- ---------------------------------------------------
|
||||
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;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Last RMAN backup status</h2>
|
||||
-- ---------------------------------------------------
|
||||
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;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Last Alert Log Error</h2>
|
||||
-- ---------------------------------------------------
|
||||
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-)');
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Current sequence no in</h2>
|
||||
-- ---------------------------------------------------
|
||||
|
||||
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;
|
||||
|
||||
-- ---------------------------------------------------
|
||||
prompt <h2>Archive generated for the past 30 days</h2>
|
||||
-- ---------------------------------------------------
|
||||
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 <h2>Taille des redolog par jour </h2>
|
||||
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')
|
||||
;
|
||||
|
||||
prompt
|
||||
-- spool off
|
||||
set markup html off spool off
|
||||
exit
|
||||
|
||||
71
Daily/sql/redolog_freq_switch.sql
Normal file
71
Daily/sql/redolog_freq_switch.sql
Normal file
@@ -0,0 +1,71 @@
|
||||
--
|
||||
-- affichage de la rotation des redelog par jour et par 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')
|
||||
;
|
||||
|
||||
exit
|
||||
12
Daily/sql/redolog_size_per_days.sql
Normal file
12
Daily/sql/redolog_size_per_days.sql
Normal file
@@ -0,0 +1,12 @@
|
||||
REM
|
||||
REM Tailes des redoslog par jour
|
||||
REM
|
||||
|
||||
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')
|
||||
;
|
||||
8
Daily/sql/who_is_connected.sql
Normal file
8
Daily/sql/who_is_connected.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
-- Qui est connecté à la base :
|
||||
|
||||
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 from v$session order by LOGON_TIME asc;
|
||||
Reference in New Issue
Block a user