From 77431a12c52a36ffe822270c4c29463092c34cdd Mon Sep 17 00:00:00 2001 From: Yacine31 Date: Fri, 26 Nov 2021 07:36:32 +0100 Subject: [PATCH] Update get_tablespaces_ddl_ver_courte.sql --- get_tablespaces_ddl_ver_courte.sql | 78 ++++++++++++++++++++++-------- 1 file changed, 58 insertions(+), 20 deletions(-) diff --git a/get_tablespaces_ddl_ver_courte.sql b/get_tablespaces_ddl_ver_courte.sql index bca3d3a..c5bbe25 100644 --- a/get_tablespaces_ddl_ver_courte.sql +++ b/get_tablespaces_ddl_ver_courte.sql @@ -1,23 +1,61 @@ -SET PAGES 999 LINES 150 -SELECT - 'CREATE TABLESPACE "' || ts.tablespace_name || '" ' || CHR(13) || CHR(10) - || LISTAGG(' DATAFILE ' - || decode(p.value, NULL, '''' || df.file_name || '''') -- si OMF pas de nom de fichier - || ' SIZE ' - || nvl(e.used_bytes, 10 * 1024 * 1024) -- si taille nulle, on retourne 10M - || 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; +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 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