From 0d0b0d8de4470a9b20c1ed912313b31eb3dffb78 Mon Sep 17 00:00:00 2001 From: Yacine31 Date: Thu, 6 Jun 2024 06:08:28 +0200 Subject: [PATCH] Update 20c_datafile.sql --- sql/20c_datafile.sql | 118 ++++++++++++++++++++++++++++++------------- 1 file changed, 84 insertions(+), 34 deletions(-) diff --git a/sql/20c_datafile.sql b/sql/20c_datafile.sql index e531408..baaa9ad 100644 --- a/sql/20c_datafile.sql +++ b/sql/20c_datafile.sql @@ -1,37 +1,87 @@ -SET SERVEROUT OFF -COLUMN is_cdb NEW_VALUE is_cdb_var -SELECT cdb AS is_cdb FROM v$database; - -SET SERVEROUT ON prompt

CDB/PDB - Détail des datafiles :

-SELECT - CASE - WHEN '&is_cdb_var' = 'YES' THEN p.con_id - ELSE NULL - END AS pdb_id, - CASE - WHEN '&is_cdb_var' = 'YES' THEN p.pdb_name - ELSE NULL - END AS pdb_name, - df.tablespace_name, - df.file_name, - df.bytes/1024/1024 AS Size_Mo, - df.maxbytes/1024/1024 AS Maxsize_Mo, - df.autoextensible -FROM - cdb_data_files df - LEFT JOIN cdb_pdbs p ON df.con_id = p.con_id -WHERE '&is_cdb_var' = 'YES' +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 + ) + WHERE + (SELECT cdb AS is_cdb FROM v$database) = 'YES' +), +-- 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 + ) + WHERE + (SELECT cdb AS is_cdb FROM v$database) = 'NO' +) +-- Requête finale combinant les résultats des sous-requêtes +SELECT * FROM cdb_files UNION ALL -SELECT - NULL AS pdb_id, - NULL AS pdb_name, - df.tablespace_name, - df.file_name, - df.bytes/1024/1024 AS Size_Mo, - df.maxbytes/1024/1024 AS Maxsize_Mo, - df.autoextensible -FROM - dba_data_files df -WHERE '&is_cdb_var' = 'NO'; +SELECT * FROM non_cdb_files; \ No newline at end of file