--表空间查询
SELECT CON_ID,
PDBNAME,
TS#,
TS_NAME,
TS_SIZE_M,
FREE_SIZE_M,
USED_SIZE_M,
USED_PER,
MAX_SIZE_G,
USED_PER_MAX,
BLOCK_SIZE,
LOGGING,
TS_DF_COUNT
FROM (WITH wt1 AS (SELECT ts.CON_ID,
(SELECT np.NAME
FROM V$CONTAINERS np
WHERE np.CON_ID = tS.con_id) PDBNAME,
(SELECT A.TS#
FROM V$TABLESPACE A
WHERE A.NAME = UPPER(tS.TABLESPACE_NAME)
AND a.CON_ID = tS.con_id) TS#,
ts.TABLESPACE_NAME,
df.all_bytes,
decode(df.TYPE,
'D',
nvl(fs.FREESIZ, 0),
'T',
df.all_bytes - nvl(fs.FREESIZ, 0)) FREESIZ,
df.MAXSIZ,
ts.BLOCK_SIZE,
ts.LOGGING,
ts.FORCE_LOGGING,
ts.CONTENTS,
ts.EXTENT_MANAGEMENT,
ts.SEGMENT_SPACE_MANAGEMENT,
ts.RETENTION,
ts.DEF_TAB_COMPRESSION,
df.ts_df_count
FROM cdb_tablespaces ts,
(SELECT d.CON_ID,
'D' TYPE,
TABLESPACE_NAME,
COUNT(*) ts_df_count,
SUM(BYTES) all_bytes,
SUM(decode(MAXBYTES, 0, BYTES, MAXBYTES)) MAXSIZ
FROM cdb_data_files d
GROUP BY d.CON_ID,
TABLESPACE_NAME
UNION ALL
SELECT d.CON_ID,
'T',
TABLESPACE_NAME,
COUNT(*) ts_df_count,
SUM(BYTES) all_bytes,
SUM(decode(MAXBYTES, 0, BYTES, MAXBYTES))
FROM cdb_temp_files d
GROUP BY d.CON_ID,
TABLESPACE_NAME) df,
(SELECT d.CON_ID,
TABLESPACE_NAME,
SUM(BYTES) FREESIZ
FROM cdb_free_space d
GROUP BY d.CON_ID,
TABLESPACE_NAME
UNION ALL
SELECT d.CON_ID,
tablespace_name,
SUM(d.BLOCK_SIZE * a.BLOCKS) bytes
FROM gv$sort_usage a,
cdb_tablespaces d
WHERE a.tablespace = d.tablespace_name
AND a.CON_ID = d.CON_ID
GROUP BY d.CON_ID,
tablespace_name) fs
WHERE ts.TABLESPACE_NAME = df.TABLESPACE_NAME
AND ts.CON_ID = df.CON_ID
AND ts.TABLESPACE_NAME = fs.TABLESPACE_NAME(+)
AND ts.CON_ID = fs.CON_ID(+))
SELECT T.CON_ID,
(CASE
WHEN T.PDBNAME = LAG(T.PDBNAME, 1)
OVER(PARTITION BY T.PDBNAME ORDER BY TS#) THEN
NULL
ELSE
T.PDBNAME
END) PDBNAME,
TS#,
t.TABLESPACE_NAME TS_Name,
round(t.all_bytes / 1024 / 1024) ts_size_M,
round(t.freesiz / 1024 / 1024) Free_Size_M,
round((t.all_bytes - t.FREESIZ) / 1024 / 1024) Used_Size_M,
round((t.all_bytes - t.FREESIZ) * 100 / t.all_bytes, 3) Used_per,
round(MAXSIZ / 1024 / 1024 / 1024, 3) MAX_Size_g,
round(decode(MAXSIZ,
0,
to_number(NULL),
(t.all_bytes - FREESIZ)) * 100 / MAXSIZ,
3) USED_per_MAX,
round(t.BLOCK_SIZE) BLOCK_SIZE,
t.LOGGING,
t.ts_df_count
FROM wt1 t
UNION ALL
SELECT DISTINCT T.CON_ID,
'' PDBNAME,
to_number('') TS#,
'ALL TS:' TS_Name,
round(SUM(t.all_bytes) / 1024 / 1024, 3) ts_size_M,
round(SUM(t.freesiz) / 1024 / 1024) Free_Size_m,
round(SUM(t.all_bytes - t.FREESIZ) / 1024 / 1024) Used_Size_M,
round(SUM(t.all_bytes - t.FREESIZ) * 100 /
SUM(t.all_bytes),
3) Used_per,
round(SUM(MAXSIZ) / 1024 / 1024 / 1024) MAX_Size,
to_number('') "USED,% of MAX Size",
to_number('') BLOCK_SIZE,
'' LOGGING,
to_number('') ts_df_count
FROM wt1 t
GROUP BY rollup(CON_ID,PDBNAME)
)
ORDER BY CON_ID,TS# ;
复制
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。
评论
相关阅读
Oracle数据库调整内存应该注意的几个问题
听见风的声音
309次阅读
2025-03-18 09:43:11
记一次ORA600内部错误故障分析与修复实录
Digital Observer
283次阅读
2025-03-05 09:33:15
数据库的易用性是多维度的
白鳝的洞穴
121次阅读
2025-03-06 09:26:58
Oracle 物理 DataGuard 机制全面解析(最佳参考)
Albert Tan DBA 之路
95次阅读
2025-03-10 17:28:06
Oracle 10G DG 修复从库-磁盘空间爆满导致从库无法工作
Albert Tan DBA 之路
59次阅读
2025-03-27 16:52:57
Oracle 10.2.0.5 DataGuard主从搭建-呆瓜式
Albert Tan DBA 之路
56次阅读
2025-03-12 10:05:53
Oracle大表数据导出指南
yuki
47次阅读
2025-03-20 16:27:24
紧急救援!SCN调整秘籍(二)
呆呆的私房菜
42次阅读
2025-03-25 10:37:52
oracle 补丁包
凉冰
38次阅读
2025-03-19 15:20:17
Oracle数据库,误删除数据文件,无任何备份情况下,完全恢复只需3步?
青年数据库学习互助会
36次阅读
2025-03-07 10:29:28
TA的专栏
exadata官方培训教材
收录6篇内容
达梦数据库官方文档
收录11篇内容
热门文章
04.达梦DCA认证课程-DM用户和权限管理
2024-10-10 352浏览
01.达梦DCA认证课程-DM数据库安装和实例管理
2024-06-28 226浏览
09.达梦DCP认证课程-统计信息和索引管理
2024-10-24 215浏览
05.达梦DCA认证课程-DM模式对象管理
2024-10-16 171浏览
02.达梦DCA认证课程-达梦客户端工具使用
2024-06-28 170浏览
最新文章
Statistics (Cardinality) Feedback - Frequently Asked Questions (文档 ID 1344937.1)
2025-03-08 33浏览
如何以最快方式干净的关闭数据库? (文档 ID 1577321.1)
2025-03-07 36浏览
自适应执行计划 (文档 ID 2226580.1)
2025-03-06 39浏览
如何收集用来诊断性能问题的10046 Trace(SQL_TRACE)
2025-03-05 31浏览
故障排除:Shared Pool优化和Library Cache Latch冲突优化
2025-03-04 22浏览