From 00c8ad528ec0da6d6361e133c973af1b17dae15e Mon Sep 17 00:00:00 2001 From: Yacine31 Date: Thu, 6 Jun 2024 06:35:47 +0200 Subject: [PATCH] Update 20c_datafile.sql --- sql/20c_datafile.sql | 138 +++++++++++++++++++++---------------------- 1 file changed, 67 insertions(+), 71 deletions(-) diff --git a/sql/20c_datafile.sql b/sql/20c_datafile.sql index c87723a..d2392d7 100644 --- a/sql/20c_datafile.sql +++ b/sql/20c_datafile.sql @@ -4,83 +4,79 @@ WITH -- Sous-requête pour les fichiers de données dans une CDB cdb_files AS ( ( - select - p.con_id AS pdb_id, - p.pdb_name AS pdb_name, - d.file_id, - d.file_name, - d.tablespace_name, - a.bytes_alloc/1024/1024 file_size_mb, - (a.bytes_alloc - nvl(b.bytes_free, 0))/1024/1024 space_used_mb, - nvl(b.bytes_free, 0)/1024/1024 space_free_mb, - a.maxbytes/1024/1024 maxsize_mb, - round((a.bytes_alloc - nvl(b.bytes_free, 0)) / a.maxbytes * 100,2) percent_used, - d.autoextensible, - d.status, - d.online_status - from - ( - select - f.file_id, - sum(f.bytes) bytes_alloc, - sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes - from dba_data_files f group by file_id - ) a, - ( - select - f.file_id, - sum(f.bytes) bytes_free - from dba_free_space f group by file_id - ) b, - dba_data_files d, - cdb_pdbs p - where - a.file_id = b.file_id (+) and d.file_id=a.file_id and d.pdb_id=p.con_id - -- order by - -- p.con_id, p.pdb_name, d.file_name - ) + -- cdb_files.sql + SELECT + p.con_id AS pdb_id, + p.pdb_name AS pdb_name, + d.file_id, + d.tablespace_name, + d.file_name, + a.bytes_alloc/1024/1024 AS file_size_mb, + (a.bytes_alloc - NVL(b.bytes_free, 0))/1024/1024 AS space_used_mb, + NVL(b.bytes_free, 0)/1024/1024 AS space_free_mb, + a.maxbytes/1024/1024 AS maxsize_mb, + ROUND((a.bytes_alloc - NVL(b.bytes_free, 0)) / a.maxbytes * 100, 2) AS percent_used, + d.autoextensible, + d.status, + d.online_status + FROM + ( + SELECT + f.file_id, + SUM(f.bytes) AS bytes_alloc, + SUM(DECODE(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) AS maxbytes + FROM cdb_data_files f GROUP BY file_id + ) a + LEFT JOIN ( + SELECT + f.file_id, + SUM(f.bytes) AS bytes_free + FROM cdb_free_space f GROUP BY file_id + ) b ON a.file_id = b.file_id + JOIN cdb_data_files d ON a.file_id = d.file_id + JOIN cdb_pdbs p ON d.con_id = p.pdb_id WHERE - (SELECT cdb AS is_cdb FROM v$database) = 'YES' + (SELECT cdb FROM v$database) = 'YES' + ORDER BY + p.pdb_id, d.tablespace_name, d.file_name; ), -- Sous-requête pour les fichiers de données dans une non-CDB non_cdb_files AS ( ( - select - NULL AS pdb_id, - NULL AS pdb_name, - d.file_id, - d.file_name, - d.tablespace_name, - a.bytes_alloc/1024/1024 file_size_mb, - (a.bytes_alloc - nvl(b.bytes_free, 0))/1024/1024 space_used_mb, - nvl(b.bytes_free, 0)/1024/1024 space_free_mb, - a.maxbytes/1024/1024 maxsize_mb, - round((a.bytes_alloc - nvl(b.bytes_free, 0)) / a.maxbytes * 100,2) percent_used, - d.autoextensible, - d.status, - d.online_status - from - ( - select - f.file_id, - sum(f.bytes) bytes_alloc, - sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes - from dba_data_files f group by file_id - ) a, - ( - select - f.file_id, - sum(f.bytes) bytes_free - from dba_free_space f group by file_id - ) b, - dba_data_files d - where - a.file_id = b.file_id (+) and d.file_id=a.file_id - order by - d.file_name - ) + -- non_cdb_files.sql + SELECT + NULL AS pdb_id, + NULL AS pdb_name, + d.file_id, + d.tablespace_name, + d.file_name, + a.bytes_alloc/1024/1024 AS file_size_mb, + (a.bytes_alloc - NVL(b.bytes_free, 0))/1024/1024 AS space_used_mb, + NVL(b.bytes_free, 0)/1024/1024 AS space_free_mb, + a.maxbytes/1024/1024 AS maxsize_mb, + ROUND((a.bytes_alloc - NVL(b.bytes_free, 0)) / a.maxbytes * 100, 2) AS percent_used, + d.autoextensible, + d.status, + d.online_status + FROM + ( + SELECT + f.file_id, + SUM(f.bytes) AS bytes_alloc, + SUM(DECODE(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) AS maxbytes + FROM dba_data_files f GROUP BY file_id + ) a + LEFT JOIN ( + SELECT + f.file_id, + SUM(f.bytes) AS bytes_free + FROM dba_free_space f GROUP BY file_id + ) b ON a.file_id = b.file_id + JOIN dba_data_files d ON a.file_id = d.file_id WHERE - (SELECT cdb AS is_cdb FROM v$database) = 'NO' + (SELECT cdb FROM v$database) = 'NO' + ORDER BY + d.tablespace_name, d.file_name; ) -- Requête finale combinant les résultats des sous-requêtes SELECT * FROM cdb_files