Files
db_report/sql/20c_datafile.sql
Yacine31 4e7683aee2 mise à jour v2
Grosse mise à jour :
- style moderne des tableaux et code
- code structuré et factorisé
- sql et sh affinés
2025-11-19 15:55:11 +01:00

97 lines
3.2 KiB
SQL

prompt <h2>CDB/PDB - Détail des datafiles : </h2>
COL con_id HEAD "CON ID"
COL pdb_name HEAD "PDB Name"
COL file_id HEAD "File ID"
COL file_name HEAD "Datafile"
COL tablespace_name FORMAT A20 HEAD "Tablespace"
COL file_size_mb FORMAT 999999999.00 HEAD "File Size MB"
COL space_used_mb FORMAT 999999999.00 HEAD "Space Used MB"
COL space_free_mb FORMAT 999999999.00 HEAD "Space Free MB"
COL maxsize_mb FORMAT 999999999.00 HEAD "Max Size MB"
COL percent_used FORMAT 999.00 HEAD "% Used"
COL autoextensible FORMAT A15 HEAD "Auto Extensible"
COL status head "Status"
COL online_status format a15 head "Online Status"
WITH
-- Sous-requête pour les fichiers de données dans une CDB
cdb_files AS (
-- cdb_files.sql
select /* db-html-report */
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
RIGHT JOIN cdb_pdbs p ON d.con_id = p.pdb_id
WHERE
(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 (
-- 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 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
UNION ALL
SELECT * FROM non_cdb_files;