diff --git a/Daily/sql/rapport_html.sql b/Daily/rapport_html.sql
similarity index 100%
rename from Daily/sql/rapport_html.sql
rename to Daily/rapport_html.sql
diff --git a/Daily/sql/check_db_restart.sql b/Daily/sql/check_db_restart.sql
new file mode 100644
index 0000000..1e9fdb6
--- /dev/null
+++ b/Daily/sql/check_db_restart.sql
@@ -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;
+
diff --git a/Daily/sql/check_failed_cheduler_jobs.sql b/Daily/sql/check_failed_cheduler_jobs.sql
new file mode 100644
index 0000000..fe4ee38
--- /dev/null
+++ b/Daily/sql/check_failed_cheduler_jobs.sql
@@ -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;
+
diff --git a/Daily/sql/check_pga_use.sql b/Daily/sql/check_pga_use.sql
new file mode 100644
index 0000000..19400ff
--- /dev/null
+++ b/Daily/sql/check_pga_use.sql
@@ -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;
+
diff --git a/Daily/sql/check_sort_area.sql b/Daily/sql/check_sort_area.sql
new file mode 100644
index 0000000..c7c309d
--- /dev/null
+++ b/Daily/sql/check_sort_area.sql
@@ -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)';
+
diff --git a/Daily/sql/check_supplemntal_logging.sql b/Daily/sql/check_supplemntal_logging.sql
new file mode 100644
index 0000000..8b7889a
--- /dev/null
+++ b/Daily/sql/check_supplemntal_logging.sql
@@ -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;
+
diff --git a/Daily/sql/disable_auto_tasks.sql b/Daily/sql/disable_auto_tasks.sql
new file mode 100644
index 0000000..2f165d4
--- /dev/null
+++ b/Daily/sql/disable_auto_tasks.sql
@@ -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;
+-- /
+
diff --git a/Daily/sql/get_cursor_usage.sql b/Daily/sql/get_cursor_usage.sql
new file mode 100644
index 0000000..d4063c5
--- /dev/null
+++ b/Daily/sql/get_cursor_usage.sql
@@ -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'
+)
+/
\ No newline at end of file
diff --git a/Daily/sql/get_grant_and_priv.sql b/Daily/sql/get_grant_and_priv.sql
new file mode 100644
index 0000000..40037db
--- /dev/null
+++ b/Daily/sql/get_grant_and_priv.sql
@@ -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
+
diff --git a/Daily/sql/get_tablespaces_ddl_ver_courte.sql b/Daily/sql/get_tablespaces_ddl_ver_courte.sql
new file mode 100644
index 0000000..e276a50
--- /dev/null
+++ b/Daily/sql/get_tablespaces_ddl_ver_courte.sql
@@ -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
+
diff --git a/Daily/sql/redolog_freq_switch.sql b/Daily/sql/redolog_freq_switch.sql
new file mode 100644
index 0000000..c77080b
--- /dev/null
+++ b/Daily/sql/redolog_freq_switch.sql
@@ -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
diff --git a/Daily/sql/redolog_size_per_days.sql b/Daily/sql/redolog_size_per_days.sql
new file mode 100644
index 0000000..65159fe
--- /dev/null
+++ b/Daily/sql/redolog_size_per_days.sql
@@ -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')
+;
diff --git a/Daily/sql/who_is_connected.sql b/Daily/sql/who_is_connected.sql
new file mode 100644
index 0000000..dcc7854
--- /dev/null
+++ b/Daily/sql/who_is_connected.sql
@@ -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;