Oracle 中的高水位(High Water Mark)指的是表或段中曾经使用过的最高数据块位置。哪怕后来数据被删除了,Oracle 仍然认为这些块“已被使用”,不会自动回收,导致:
1、表空间看起来很大(占了磁盘);
2、实际数据却不多;
3、新数据插入时,可能会跳过这些空闲但“不可用”的块。
表空间高水位收缩通常是因操作系统磁盘空间压力所引发,主要是被了腾空间。出于对生产环境稳定性的考量,我们一般仅在迫不得已的情况下才实施此类高风险调整。
本文档是针对某个特定用户表空间收缩的文档,实际操作要结合生产库具体情况。主要包括以下几个流程:
收集当前数据库相关信息
降低数据库表高水位线
Resize 收缩数据文件
SQL> SELECT total.tablespace_name,
Round(total.MB, 2) AS Total_MB,
Round(total.MB - free.MB, 2) AS Used_MB,
Round(( 1 - free.MB / total.MB ) * 100, 2)
|| '%' AS Used_Pct
FROM (SELECT tablespace_name,
Sum(bytes) / 1024 / 1024 AS MB
FROM dba_free_space
GROUP BY tablespace_name) free,
(SELECT tablespace_name,
Sum(bytes) / 1024 / 1024 AS MB
FROM dba_data_files
GROUP BY tablespace_name) total
WHERE free.tablespace_name = total.tablespace_name;
TABLESPACE_NAME TOTAL_MB USED_MB USED_PCT
------------------------------ ---------- ---------- -----------------------------------------
SYSAUX 5000 1359.19 27.18%
SYSTEM 1024 625.13 61.05%
TS_AUD 4000 1483.19 37.08%
TS_BJCA 512 118.63 23.17%
TS_BT 512 .06 .01%
TS_CHDD 2000 864.06 43.2%
TS_DATA 2167482 496135.81 22.89%
TS_FCCH 512 1.94 .38%
TS_FDC 50000 36266.88 72.53%
TS_INDEX 390000 294789.81 75.59%
TS_LOG 30000 23551.81 78.51%
TS_RMAN 512 266.06 51.97%
TS_SB 6000 4594 76.57%
TS_SCJY 10000 5618.5 56.19%
TS_WHMS 512 310.38 60.62%
TS_ZLPT 2048 484.06 23.64%
UNDOTBS1 60000 59999.63 100%
USERS 5000 1060.06 21.2%
# 与客户描述的一致,TS_DATA表空间量大,但实际使用量小。2、查看表空间上的用户 SQL> select owner,tablespace_name ,sum(bytes)/1024/1024/1024 G from dba_segments where tablespace_name = 'TS_DATA' group by owner,tablespace_name; OWNER TABLESPACE_NAME G ------------------------------ ------------------------------ ---------- TMC TS_DATA 454.085266 IBMS_SEC TS_DATA .005004883 PLATFORM TS_DATA .290893555 SZFDC TS_DATA .661071777 GTB_APP TS_DATA .20111084 FDC_ZJJYJZX TS_DATA 7.76208496 SZFDCOA TS_DATA 1.01373291 BWPLATFORM TS_DATA 16.6900024 SZFDC_CA TS_DATA 2.73272705 FDC_YJZX TS_DATA 1.35357666 FLOOR TS_DATA 108.474243 SHENBAO TS_DATA .002502441 IBMS TS_DATA 1.8303833 FCCH TS_DATA .26361084 PUCHA TS_DATA .19140625 FDCYS TS_DATA 7.56640625 RIS_ACCESS TS_DATA 1.08044434 17 rows selected.3、查看表空间TOP 10大表 SQL> select * from ( 2 select owner, segment_name, segment_type, tablespace_name, bytes/1024/1024/1024 "G" 3 from dba_segments where segment_type = 'TABLE' and tablespace_name = 'TS_DATA' order by bytes desc) 4 where rownum <= 10; OWNER SEGMENT_NAME SEGMENT_TYPE TABLESPACE_NAME G ------------------- ------------------------------------ ------------------ ------------------- ---------- TMC FDC_INFO_QRY_LOG_2020 TABLE TS_DATA 144.490234 TMC TMC_LOG TABLE TS_DATA 86.6728516 TMC BIN$tvmjhUBAC37gVAALXeBfRg==$0 TABLE TS_DATA 50.9677734 TMC BIN$tvSoznk+ICjgVAALXeBfRg==$0 TABLE TS_DATA 30.59375 TMC REMC_WS_LOG_REQUEST TABLE TS_DATA 9.87109375 FDCYS SYS_20191171126389483_TEMP TABLE TS_DATA 3.4375 BWPLATFORM SOA_SYSTEM_LOG TABLE TS_DATA 3.125 FDCYS TRADE_RECORD TABLE TS_DATA 2.90625 TMC JG_TBL_FDC_EST_REGISTE TABLE TS_DATA 2.87890625 TMC MLOG$_FDC_TMC_CONTRACT TABLE TS_DATA 1.444335944、查看表空间TOP 10大索引 SQL> select * from ( 2 select owner, segment_name, segment_type, tablespace_name, bytes/1024/1024/1024 "G" 3 from dba_segments where segment_type = 'INDEX' and tablespace_name = 'TS_DATA' order by bytes desc) 4 where rownum <= 10; OWNER SEGMENT_NAME SEGMENT_TYPE TABLESPACE_NAME G ----------------- ---------------------------- ------------------ ------------------ ---------- TMC TMC_LOG_PK INDEX TS_DATA 13.03125 BWPLATFORM SOA_SYSTEM_LOG INDEX TS_DATA .433837891 TMC INDEX_USER INDEX TS_DATA .419921875 TMC INDEX_ORGAN INDEX TS_DATA .390625 BWPLATFORM PK_PLAT_USER_LOGIN_LOG INDEX TS_DATA .267150879 TMC SEI_IX_NAME INDEX TS_DATA .216796875 TMC FTVC_IX_EXPIRE_DATE INDEX TS_DATA .1953125 FDCYS I_TR_YWBJSJ INDEX TS_DATA .1953125 BWPLATFORM SYS_C0066879 INDEX TS_DATA .1484375 TMC FTVC_UK_CERT_NO_FO_ID INDEX TS_DATA .1328125 10 rows selected.5、查看表空间管理方式 SQL> select tablespace_name, block_size,contents, extent_management, segment_space_management, allocation_type, segment_space_management from dba_tablespaces where tablespace_name='TS_DATA'; TABLESPACE_NAME BLOCK_SIZE CONTENTS EXTENT_MAN SEGMEN ALLOCATIO SEGMEN ------------------------------ ---------- --------- ---------- ------ --------- ------ TS_DATA 8192 PERMANENT LOCAL AUTO SYSTEM AUTO6、查看数据文件使用情况 SQL> col file_name for a50 SQL> select file_name, tablespace_name, bytes/1024/1024/1024 "used G", maxbytes/1024/1024/1024 "total G" from dba_data_files where tablespace_name = 'TS_DATA' order by bytes; FILE_NAME TABLESPACE_NAME used G total G -------------------------------------------------- ------------------------------ ---------- ---------- /Oradata/2nd_fdc/TS_DATA74.dbf TS_DATA 5 0 /Oradata/2nd_fdc/TS_DATA76.dbf TS_DATA 5 0 /Oradata/2nd_fdc/TS_DATA75.dbf TS_DATA 5 0 ................... /Oradata/2nd_fdc/TS_DATA18.dbf TS_DATA 31.9921875 31.9999847 /Oradata/2nd_fdc/TS_DATA19.dbf TS_DATA 31.9921875 31.9999847 /Oradata/2nd_fdc/TS_DATA11.dbf TS_DATA 31.9921875 31.9999847 /Oradata/2nd_fdc/TS_DATA14.dbf TS_DATA 31.9921875 31.9999847 76 rows selected.7、查看表空间高水位情况 SQL> select max(block_id)*8/1024/1024 "G size" from dba_extents where tablespace_name='TS_DATA'; G size ---------- 31.9920731降低高水位1、检查失效索引 (建议处理高水位前和后都要检查。并及时处理失效索引)--检查分区索引(包括分区表的分区本地索引,分区表的分区全局索引),如果存在重建,并修改并行度 select 'alter index '||a.index_owner||'.'||a.index_name||' rebuild partition '||a.partition_name ||' parallel 10;' from dba_ind_partitions a where a.status='UNUSABLE'; select 'alter index '||a.index_owner||'.'||a.index_name||' parallel 1;' from dba_ind_partitions a where a.status='UNUSABLE’; --检查普通索引(包括普通表的索引,分区表的普通全局索引),如果存在重建,并修改并行度 select 'alter index '||a.owner||'.'||a.index_name||' rebuild parallel 10;' from dba_indexes a where a.status='UNUSABLE'; select 'alter index '||a.owner||'.'||a.index_name||' parallel 1;' from dba_indexes a where a.status='UNUSABLE’;2、查询指定用户中的高水位 # 比较表的行数和表的大小关系。如果行数为0,而表的当前占用大小减去初始化时的大小(INITIAL_EXTENT)后依然很大,那么说明该表有高水位。=====为了保证结果准确,建议先对表进行统计信息收集。 # 查看TMC用户高水位 SQL> SELECT D.OWNER, 2 ROUND(D.NUM_ROWS / D.BLOCKS, 2), 3 D.NUM_ROWS, 4 D.BLOCKS, 5 D.TABLE_NAME, 6 ROUND((d.BLOCKS*8-D.INITIAL_EXTENT/1024)/1024) t_size 7 FROM DBA_TABLES D 8 WHERE D.BLOCKS > 10 9 AND ROUND(D.NUM_ROWS / D.BLOCKS, 2) < 5 10 AND d.OWNER = 'TMC' ; OWNER ROUND(D.NUM_ROWS/D.BLOCKS,2) NUM_ROWS BLOCKS TABLE_NAME T_SIZE -------- ---------------------------- ---------- ---------- ------------------------------ ---------- TMC 2.6 2597 1000 EX_ZQ_MIDDLE_ACCESS 8 TMC 2.31 30 13 EX_ZW_SRV_CONFIG 0 TMC 1.1 66 60 FDC_ROLES_CATALOG -1 TMC .35 21 60 FDC_ORGANTYPE_SUBSYSTEM -1 TMC .1 6 58 FDC_USER_DEV_UPLOAD 0 TMC 3.05 1149260 377166 JG_TBL_FDC_EST_REGISTE 2947 TMC 0 0 1522 JG_TBL_JSYDGH 12 TMC 0 0 2410 JG_TBL_LAND_CONTRACT 19 TMC 4.83 713497 147670 FDC_YS_CONTRACT_APPENDIX 1154 TMC 1.94 3646 1882 SIREA_REPORT_3 15 TMC 2.56 625 244 DZZZ_FDC_YS_PREPROJECT 2 TMC .22 9703 44390 FDC_ORGAN_REPORT_DEV_USER 347 TMC 0 0 13 SYS_20185311110401376_TEMP 0 TMC 1.57 1902326 1210229 REMC_WS_LOG_REQUEST 9455 # 查看表上边的索引 SQL> select index_name, status from dba_indexes where owner = 'TMC' and table_name = 'JG_TBL_FDC_EST_REGISTE'; INDEX_NAME STATUS ------------------------------ -------- EST_REGISTE_PARCEL_NO VALID EST_REGISTE_PROJ_NO VALID SQL> select index_name, status from dba_indexes where owner = 'TMC' and table_name = 'FDC_YS_CONTRACT_APPENDIX'; INDEX_NAME STATUS ------------------------------ -------- SYS_IL0000060570C00006$$ VALID SYS_IL0000060570C00020$$ VALID FYCA_IX_FYC_ID VALID FYCA_IX_YS_FYB_ID VALID SYS_IL0000060570C00026$$ VALID FYCA_PK VALID 6 rows selected. SQL> select index_name, status from dba_indexes where owner = 'TMC' and table_name = 'REMC_WS_LOG_REQUEST'; INDEX_NAME STATUS ------------------------------ -------- SYS_IL0000142741C00026$$ VALID SYS_IL0000142741C00027$$ VALID SYS_IL0000142741C00028$$ VALID # 查看FDCYS用户高水位线 SELECT D.OWNER, ROUND(D.NUM_ROWS / D.BLOCKS, 2), D.NUM_ROWS, D.BLOCKS, D.TABLE_NAME, ROUND((d.BLOCKS*8-D.INITIAL_EXTENT/1024)/1024) t_size FROM DBA_TABLES D WHERE D.BLOCKS > 10 AND ROUND(D.NUM_ROWS / D.BLOCKS, 2) < 5 AND d.OWNER = 'FDCYS' ; OWNER ROUND(D.NUM_ROWS/D.BLOCKS,2) NUM_ROWS BLOCKS TABLE_NAME T_SIZE ------------------------------ ---------------------------- ---------- ---------- ------------------------------ ---------- FDCYS 0 0 449636 SYS_20191171126389483_TEMP 3513 # 查看表上的索引 SQL> select index_name,status from dba_indexes where owner = 'FDCYS' and table_name = 'SYS_20191171126389483_TEMP'; INDEX_NAME STATUS ------------------------------ -------- SYS_C0060562 VALID3、收缩指定表的高水位 # TMC用户收缩高水位线 alter table TMC.JG_TBL_FDC_EST_REGISTE enable row movement; alter table TMC.JG_TBL_FDC_EST_REGISTE shrink space; alter index TMC.EST_REGISTE_PARCEL_NO rebuild; alter index TMC.EST_REGISTE_PROJ_NO rebuild; alter table TMC.JG_TBL_FDC_EST_REGISTE disable row movement; alter table TMC.FDC_YS_CONTRACT_APPENDIX enable row movement; alter table TMC.FDC_YS_CONTRACT_APPENDIX shrink space; alter index TMC.FYCA_IX_FYC_ID rebuild parallel 4 nologging; alter index TMC.FYCA_IX_YS_FYB_ID rebuild parallel 4 nologging; alter index TMC.FYCA_PK rebuild parallel 4 nologging; alter index TMC.FYCA_IX_FYC_ID parallel 1 ; alter index TMC.FYCA_IX_YS_FYB_ID parallel 1 ; alter index TMC.FYCA_PK parallel 1 ; alter index TMC.FDC_YS_CONTRACT_APPENDIX disable row movement; alter table TMC.REMC_WS_LOG_REQUEST enable row movement; alter table TMC. REMC_WS_LOG_REQUEST shrink space; alter table TMC.REMC_WS_LOG_REQUEST disable row movement; # FDCYS用户收缩高水位线 alter table FDCYS.SYS_20191171126389483_TEMP enable row movement; alter table FDCYS.SYS_20191171126389483_TEMP shrink space; alter index SYS_C0060562 rebuild; alter table FDCYS.SYS_20191171126389483_TEMP disable row movement;4、重新收集表的统计信息 exec dbms_stats.gather_table_stats('TMC','JG_TBL_FDC_EST_REGISTE',cascade=>true); exec dbms_stats.gather_table_stats('TMC','FDC_YS_CONTRACT_APPENDIX',cascade=>true); exec dbms_stats.gather_table_stats('TMC','REMC_WS_LOG_REQUEST',cascade=>true); exec dbms_stats.gather_table_stats('FDCYS','SYS_20191171126389483_TEMP',cascade=>true); 如果是大表,建议使用如下语句进行统计信息收集 说明:需要替换用户名、表名、及分区名(如果是分区表) 如果要单独分析表的某个分区,将 --granularity和-- partname=>'p200902', 这句注释去掉,并替换分区名 begin DBMS_STATS.GATHER_TABLE_STATS(ownname=>'NETFORCE', tabname=>'TBL_PROCESS_DRAFT', --granularity => 'PARTITION', --partname=>'POPERATIONPROCESS0102', estimate_percent=>1, method_opt=>'FOR ALL COLUMNS SIZE 1', no_invalidate=>false, cascade=>true, degree => 10); end ;Resize数据库文件# 查看最大可resize的数据文件大小 col name for a50 col resizecmd for a90 select a.file#, a.name, a.bytes / 1024 / 1024 CurrentMB, ceil(HWM * a.block_size / 1024 / 1024) Resizeto, (a.bytes - HWM * a.block_size) / 1024 / 1024 releaseMB, 'alter database datafile ''' || a.name || ''' resize ' || ceil(HWM * a.block_size / 1024 / 1024) || 'M;' ResizeCmd from v$datafile a, (select file_id, max(block_id + blocks - 1) HWM from dba_extents where tablespace_name = 'TS_DATA' group by file_id) b where a.file# = b.file_id(+) and (a.bytes - HWM * a.block_size) > 0 order by 5; FILE# NAME CURRENTMB RESIZETO RELEASEMB RESIZECMD ----- -------------------------------- ---------- ---------- ---------- ------------------------------------------------------------------------- 7 /Oradata/2nd_fdc/TS_DATA02.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA02.dbf' resize 30000M; 9 /Oradata/2nd_fdc/TS_DATA04.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA04.dbf' resize 30000M; 6 /Oradata/2nd_fdc/TS_DATA01.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA01.dbf' resize 30000M; 41 /Oradata/2nd_fdc/TS_DATA29.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA29.dbf' resize 30000M; 12 /Oradata/2nd_fdc/TS_DATA07.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA07.dbf' resize 30000M; 61 /Oradata/2nd_fdc/TS_DATA45.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA45.dbf' resize 30000M; 26 /Oradata/2nd_fdc/TS_DATA17.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA17.dbf' resize 30000M; 31 /Oradata/2nd_fdc/TS_DATA22.dbf 30000 30000 .0625 alter database datafile '/Oradata/2nd_fdc/TS_DATA22.dbf' resize 30000M; ................ 88 /Oradata/2nd_fdc/TS_DATA69.dbf 29980 22035 7945.9375 alter database datafile '/Oradata/2nd_fdc/TS_DATA69.dbf' resize 22035M; 86 /Oradata/2nd_fdc/TS_DATA68.dbf 29980 21958 8022.9375 alter database datafile '/Oradata/2nd_fdc/TS_DATA68.dbf' resize 21958M; 92 /Oradata/2nd_fdc/TS_DATA72.dbf 30720 21246 9474.875 alter database datafile '/Oradata/2nd_fdc/TS_DATA72.dbf' resize 21246M; 93 /Oradata/2nd_fdc/TS_DATA73.dbf 30720 20626 10094.875 alter database datafile '/Oradata/2nd_fdc/TS_DATA73.dbf' resize 20626M;
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




