Files
article/oracle/oracle表占用分析.md

2.1 KiB

SELECT * FROM v$version;

表占用分析

WITH segment_mapping AS (
    -- 1. 基础表
    SELECT segment_name as table_name, segment_name, segment_type, bytes
    FROM user_segments
    WHERE segment_type LIKE 'TABLE%'
    UNION ALL
    -- 2. 索引对应的表
    SELECT i.table_name, s.segment_name, s.segment_type, s.bytes
    FROM user_segments s
    JOIN user_indexes i ON s.segment_name = i.index_name
    WHERE s.segment_type LIKE 'INDEX%'
    UNION ALL
    -- 3. LOB字段对应的表
    SELECT l.table_name, s.segment_name, s.segment_type, s.bytes
    FROM user_segments s
    JOIN user_lobs l ON s.segment_name = l.segment_name OR s.segment_name = l.index_name
    WHERE s.segment_type LIKE 'LOB%'
)
SELECT
    table_name AS "逻辑业务表名",
    ROUND(SUM(bytes)/1024/1024/1024, 2) AS "总占用(GB)",
    ROUND(SUM(CASE WHEN segment_type LIKE 'TABLE%' THEN bytes ELSE 0 END)/1024/1024/1024, 2) AS "数据(GB)",
    ROUND(SUM(CASE WHEN segment_type LIKE 'INDEX%' THEN bytes ELSE 0 END)/1024/1024/1024, 2) AS "索引(GB)",
    ROUND(SUM(CASE WHEN segment_type LIKE 'LOB%' THEN bytes ELSE 0 END)/1024/1024/1024, 2) AS "大字段(GB)"
FROM
    segment_mapping
GROUP BY
    table_name
ORDER BY
    2 DESC;

表空间释放


-- 1. 尝试开启行移动(如果报错,通常是因为权限不足或正在被锁定)
ALTER TABLE T_FOC_CREW_MQ_NEW ENABLE ROW MOVEMENT;

-- 2. 尝试收缩空间
-- 先执行压缩数据,不移动高水位线(对业务影响较小)
ALTER TABLE T_FOC_CREW_MQ_NEW SHRINK SPACE COMPACT;

-- 最终收缩并重置高水位线(释放空间给表空间)
ALTER TABLE T_FOC_CREW_MQ_NEW SHRINK SPACE;

回收站

SELECT
    original_name AS "原对象名",
    object_name AS "回收站对象名",
    type AS "类型",
    droptime AS "删除时间",
    can_undrop AS "是否可还原"
FROM user_recyclebin
ORDER BY droptime DESC;

--清空回收站
PURGE RECYCLEBIN;



-- 如果想看回收站总共占了多少 MB
SELECT ROUND(SUM(bytes)/1024/1024, 2) AS "回收站总占用(MB)"
FROM user_segments
WHERE segment_name LIKE 'BIN$%';