MGMTDB is new database instance which is used for storing Cluster Health Monitor (CHM) data.
In Oracle 11g this information was stored in Berkley database (.bdb files), in $GRID_HOME/crf/db/hostname, but starting from Oracle database 12c it is configured as an Oracle Single Instance.
In Oracle 12.1.0.1 the Grid Infrastructure Management Repository (GIMR) is optional.
In Oracle 12.1.0.2 it’s mandatory and it’s not supported to be turned off with the exception of Exadata.
# ps -ef |grep mdb_pmon oracle 4961 4124 0 11:05 pts/2 00:00:00 grep --color=auto mdb_pmon grid 40414 1 0 2018 ? 01:04:31 mdb_pmon_-MGMTDB
Below alert warning received from the Grid Control of the SYSMGMTDATA tablespace with 91% occupied:
The variables included in the oraEMNGAlert trap.
oraEMNGEventTargetName = -MGMTDB_exadb015.PDB_CLUSTER
oraEMNGEventMessage = The SYSMGMTDATA tablespace has 91.314453125 occupied.
oraEMNGEventSeverityCode = CRITICAL
oraEMNGEventReportedTime = May 31, 2020 7:31:27 PM BRT
oraEMNGEventCategories = Capacity
oraEMNGEventType = Metric Alert
oraEMNGEventTargetType = Pluggable Database
oraEMNGEventHostName = exadb015
oraEMNGEventTargetVersion = 12.1.0.2.0
oraEMNGEventUserDefinedTgtProp = Operating System=Linux, Platform=x86_64,
oraEMNGEventRuleName = Tablespace, Tablespace
Check the current CHM repository:
# oclumon manage -get reppath CRS-9001-internal error CRS-9010-Error manage: mandatory data not supplied
The error occurs because the resource is offline:
# crsctl stat res ora.crf -init NAME=ora.crf TYPE=ora.crf.type TARGET=ONLINE STATE=OFFLINE
Enable the ora.crf resource:
# cd /u01/app/12.1.0.2/grid/bin/ # ./crsctl modify res ora.crf -attr ENABLED=1 -init
Start the ora.crf resource manually using below command:
# crsctl start res ora.crf -init CRS-2672: Attempting to start 'ora.crf' on 'exadb015' CRS-2676: Start of 'ora.crf' on 'exadb015' succeeded
Resource is online:
# crsctl stat res ora.crf -init NAME=ora.crf TYPE=ora.crf.type TARGET=ONLINE STATE=ONLINE on exadb015 # crsctl stat res ora.mgmtdb -t -------------------------------------------------------------------------------- Name Target State Server State details -------------------------------------------------------------------------------- Cluster Resources -------------------------------------------------------------------------------- ora.mgmtdb 1 ONLINE ONLINE exadb015 Open,STABLE --------------------------------------------------------------------------------
Displays the status of the current configuration:
# srvctl config mgmtdb Database unique name: _mgmtdb Database name: Oracle home: <CRS home> Oracle user: grid Spfile: +DG_OCRVOTING/_MGMTDB/PARAMETERFILE/spfile.268.886174866 Password file: Domain: Start options: open Stop options: immediate Database role: PRIMARY Management policy: AUTOMATIC Type: Management PDB name: pdb_cluster PDB service: pdb_cluster Cluster name: pdb-cluster Database instance: -MGMTDB
Check the current CHM repository:
# oclumon manage -get reppath CHM Repository Path = +DG_OCRVOTING/_MGMTDB/FD9B43BF6A646F8CE043B6A9E80A2815/DATAFILE/SYSMGMTDATA.269.886174975 # asmcmd ls -ls +DG_OCRVOTING/_MGMTDB/FD9B43BF6A646F8CE043B6A9E80A2815/DATAFILE/SYSMGMTDATA.269.886174975 Type Redund Striped Time Sys Block_Size Blocks Bytes Space Name DATAFILE HIGH COARSE JUN 01 12:00:00 Y 8192 262145 2147491840 6467616768 SYSMGMTDATA.269.886174975
Resize the datafile. I increased the size from 2048M to 3072M:
$ export ORACLE_SID=-MGMTDB $ sqlplus / as sysdba SQL*Plus: Release 12.1.0.2.0 Production on Mon Jun 1 13:32:46 2020 Copyright (c) 1982, 2014, Oracle. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, Automatic Storage Management and Advanced Analytics options sql> show pdbs; CON_ID CON_NAME OPEN MODE RESTRICTED ---------- ------------------------------ ---------- ---------- 2 PDB$SEED READ ONLY NO 3 PDB_CLUSTER READ WRITE NO sql> alter session set container=PDB_CLUSTER; Session altered. sql> select TABLESPACE_NAME,FILE_NAME,AUTOEXTENSIBLE,BYTES/1024/1024 MB, MAXBLOCKS/1024/1024 from dba_data_files where TABLESPACE_NAME='SYSMGMTDATA'; TABLESPACE_NAME FILE_NAME AUT MB MAXBLOCKS/1024/1024 --------------- --------- ---- ------ -------------------- SYSMGMTDATA +DG_OCRVOTING/_MGMTDB/FD9B43BF6A646F8CE043B6A9E80A2815/DATAFILE/sysmgmtdata.269.886174975 NO 2048 0 sql> alter database datafile '+DG_OCRVOTING/_MGMTDB/FD9B43BF6A646F8CE043B6A9E80A2815/DATAFILE/sysmgmtdata.269.886174975' resize 3072m; Database altered.
Other ways to solve the space problem in tablespace SYSMGMTDATA in GIMR Database:
– Move GIMR Repository to Different Shared Storage (Diskgroup, CFS or NFS etc) as per Doc ID 1589394.1.
– Truncate the big tables owned by CHM as per Doc ID 2177879.1.
Normally the below two tables can be truncated:
sql> truncate table CHM.CHMOS_PROCESS_INT_TBL; sql> truncate table CHM.CHMOS_DEVICE_INT_TBL;
The trace files the instance MGMTDB can be found by default in:
$DIAG_HOME/_mgmtdb/-MGMTDB/trace