Update get_tablespaces_ddl_ver_courte.sql

This commit is contained in:
Yacine31
2021-11-26 07:36:32 +01:00
parent 0efd1ef987
commit 77431a12c5

View File

@@ -1,23 +1,61 @@
SET PAGES 999 LINES 150 set head off pages 0 feedback off lines 200
SELECT
'CREATE TABLESPACE "' || ts.tablespace_name || '" ' || CHR(13) || CHR(10) select '------- HOSTNAME : '||host_name||', DB_NAME : '||name||', VERSION : '||version || ' -------' from v$database,v$instance;
|| LISTAGG(' DATAFILE ' select '------- Datafiles -------' from dual;
|| decode(p.value, NULL, '''' || df.file_name || '''') -- si OMF pas de nom de fichier SELECT 'CREATE '
|| ' SIZE ' || DECODE (ts.bigfile, 'YES', 'BIGFILE ') --assuming smallfile is the default table space
|| nvl(e.used_bytes, 10 * 1024 * 1024) -- si taille nulle, on retourne 10M || 'TABLESPACE "' || ts.tablespace_name || '" DATAFILE ' || CHR(13) || CHR(10)
|| decode(df.autoextensible, 'YES', ' AUTOEXTEND ON'), || LISTAGG(decode(p.value, NULL, ' ''' || df.file_name || '''') || ' SIZE '
',' || CHR(13) || CHR(10)) || CASE
WITHIN GROUP(ORDER BY df.file_id, df.file_name) -- si la taille est nulle ou < 1M on retourne 1M
|| ';' ddl WHEN e.used_bytes is NULL or e.used_bytes < (1024*1024)
FROM dba_tablespaces ts, dba_data_files df, THEN '1M'
(SELECT file_id, SUM(decode(bytes, NULL, 0, bytes)) used_bytes FROM dba_extents GROUP BY file_id ) e, ELSE to_char(floor(e.used_bytes/(1024*1024))) || 'M'
(select VALUE from v$parameter where name='db_create_file_dest') p END
WHERE ts.tablespace_name NOT IN ( 'SYSTEM', 'SYSAUX' ) || DECODE (df.autoextensible, 'YES', ' AUTOEXTEND ON'),
AND ts.tablespace_name NOT LIKE '%UNDO%' ',' || CHR (13) || CHR (10))
AND e.file_id (+) = df.file_id WITHIN GROUP (ORDER BY df.file_id, df.file_name)
AND ts.tablespace_name = df.tablespace_name || ';'
GROUP BY ts.tablespace_name, ts.bigfile, ts.block_size ddl
ORDER BY ts.tablespace_name; 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 NEXT '),
',' || 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 EXIT