Oracle – Monitor TEMP Tablespace

Monitor TEMP Tablespace with a DBMS_SCHEDULER job

I was faced with a situation in which a process (Oracle pl/sql procedure within a package, scheduled outside Oracle in the evenings) was exhausting the TEMP tablespace. In order to investigate, the following procedure was used to monitor TEMP tablespace usage during the period of time the job was executed. This allowed quick identification of the offending user and SQL that was causing TEMP tablesace exhaustion.

Code is quick and dirty, no exception handling. I’m assuming the executing user has all the required privileges. There are other ways to investigate this, but this works.

Create a table to store data

CREATE TABLE TEMPDATA
(
  CTIME       TIMESTAMP(6) WITH TIME ZONE,
  TABLESPACE  VARCHAR2(30),
  TEMP_SIZE   VARCHAR2(41),
  INSTANCE    NUMBER,
  SID_SERIAL  VARCHAR2(81),
  USERNAME    VARCHAR2(30),
  PROGRAM     VARCHAR2(48),
  STATUS      VARCHAR2(8),
  SQL_ID      VARCHAR2(13)
)

Create the procedure

CREATE OR REPLACE procedure colltempdata as
begin

begin
    insert into tempdata
    SELECT systimestamp ctime,
           b.tablespace,
           ROUND(((b.blocks*p.value)/1024/1024),2)||'M' AS temp_size,
           a.inst_id as Instance,
           a.sid||','||a.serial# AS sid_serial,
           NVL(a.username, '(oracle)') AS username,
           a.program,
           a.status,
           a.sql_id
    FROM   sys.gv$session a,
           sys.gv$sort_usage b,
           sys.gv$parameter p
    WHERE  p.name  = 'db_block_size'
    AND    a.saddr = b.session_addr
    AND    a.inst_id=b.inst_id
    AND    a.inst_id=p.inst_id;
end;

end;
/

Create a job to execute the procedure

In this example, execute every minute for a specfied time period

begin
    DBMS_SCHEDULER.CREATE_JOB (
         job_name             => 'colltempdatajob6',
         job_type             => 'PLSQL_BLOCK',
         job_action           => 'begin colltempdata;commit;end;',
         start_date           => timestamp '2018-07-04 21:30:00',
         repeat_interval      => 'FREQ=MINUTELY;INTERVAL=1;',
         end_date             => timestamp '2018-07-04 22:45:00',
         enabled              => TRUE);
end;

SQL to display jobs, check size of data, and query the collected data

-- display job details
select job_name, start_date, run_count, last_start_date, next_run_date  from dba_scheduler_jobs where job_name like 'COLLTEMPDATAJOB%' order by start_date

-- check size of data
select sum(bytes)/1024/1024/1024 from dba_segments where segment_name = 'TEMPDATA'

-- Query data collected
select * from tempdata order by ctime desc

Oracle – Automatic Workload Respository AWR

AWR, Automatic Workload Respository

The Oracle AWR, Automatic Workload Respository, is tored in the SYSAUX tablespace. This post conatians information useful for purging/cleaning the AWR when it becomes large due to failure of cleanup jobs to remove partitions in the large AWR table, e.g. WRH$_ACTIVE_SESSION_HISTORY. Mainly Oracle 12c release 1.

-- check ASH history compared to retention period
select sysdate - a.sample_time ash,
sysdate - s.begin_interval_time snap,
c.RETENTION
from sys.wrm$_wr_control c,
(
select db.dbid,
min(w.sample_time) sample_time
from sys.v_$database db,
sys.Wrh$_active_session_history w
where w.dbid = db.dbid group by db.dbid
) a,
(
select db.dbid,
min(r.begin_interval_time) begin_interval_time
from sys.v_$database db,
sys.wrm$_snapshot r
where r.dbid = db.dbid
group by db.dbid
) s
where a.dbid = s.dbid
and c.dbid = a.dbid;
-- How much space is being used?
SELECT  occupant_name "Item",
space_usage_kbytes/1048576 "Space Used (GB)",
schema_name "Schema",
move_procedure "Move Procedure"
FROM v$sysaux_occupants
WHERE occupant_name in  ('SM/AWR','SM/OPTSTAT')
ORDER BY 1
-- Get orphaned ASH rows
SELECT COUNT(1) Orphaned_ASH_Rows FROM wrh$_active_session_history a
  WHERE NOT EXISTS
  (SELECT 1
  FROM wrm$_snapshot
  WHERE snap_id       = a.snap_id
  AND dbid            = a.dbid
  AND instance_number = a.instance_number
  );
-- check ASH history compared to retention period
select sysdate - a.sample_time ash,
sysdate - s.begin_interval_time snap,
c.RETENTION
from sys.wrm$_wr_control c,
(
select db.dbid,
min(w.sample_time) sample_time
from sys.v_$database db,
sys.Wrh$_active_session_history w
where w.dbid = db.dbid group by db.dbid
) a,
(
select db.dbid,
min(r.begin_interval_time) begin_interval_time
from sys.v_$database db,
sys.wrm$_snapshot r
where r.dbid = db.dbid
group by db.dbid
) s
where a.dbid = s.dbid
and c.dbid = a.dbid;
-- Get current settings
select DBID, SNAP_INTERVAL,  RETENTION, TOPNSQL from DBA_HIST_WR_CONTROL;

select
       extract( day from snap_interval) *24*60+
       extract( hour from snap_interval) *60+
       extract( minute from snap_interval ) "Snapshot Interval (minutes)",
       extract( day from retention) *24*60+
       extract( hour from retention) *60+
       extract( minute from retention ) "Retention Interval (minutes)"
from dba_hist_wr_control

-- Check snapshoits are being created properly
SELECT (CASE WHEN NUMTODSINTERVAL((SYSDATE - MAX(CAST(END_INTERVAL_TIME AS DATE))), 'DAY') 
< SNAP_INTERVAL THEN 'OK AWR Snapshots are being collected' ELSE 'NOK Problems with Snapshot collection' END) "RESULT"
FROM DBA_HIST_SNAPSHOT, DBA_HIST_WR_CONTROL
GROUP BY SNAP_INTERVAL

-- Disable snapshots
BEGIN
  DBMS_WORKLOAD_REPOSITORY.modify_snapshot_settings(
    retention => 11520,    -- Mins (43200 = 30 Days). Current value retained if NULL.(11520 is 8 days)
    interval  => 0);              -- Mins. Current value retained if NULL. If zero --> snapshots are stopped
END;
/

-- Enable snapshots
BEGIN
  DBMS_WORKLOAD_REPOSITORY.modify_snapshot_settings(
    retention => 43200,        -- Minutes (= 30 Days). Current value retained if NULL. (11520 is 8 days)
    interval  => 30);          -- Minutes. Current value retained if NULL. If zero --> snapshots are stopped
END;
/

-- Get Objects at high end of tablespace
select * from (
select
owner,segment_name, partition_name, segment_type, max((block_id + blocks-1)*8192)/1024/1024 "HWM_MB"
from dba_extents  where file_id=<file id for SYSAUX (2)>
group by owner,segment_name, partition_name, segment_type)
where HWM_MB > <Put size here e.g. 10000 for 10G>
order by 5 DESC

Move Segments to a temp SYSAUX to reorganize SYSAUX objects

• Move CTXSYS
• Move LogMiner
• Move DBAudit Tables
• Move LOB segments (BLOB and CLOB columns)
• Move Normal tables and rebuild indexes
• Move partitioned tables and rebuild partitioned indexes
• Move tables with LONG columns
• Move nested tables
• Move IOTs
• 12c – HEATMAP
• AQ datapump tables

exec ctxsys.DRI_MOVE_CTXSYS(TBS_NAME=>'SYSAUX_TEMP', PRINT_ONLY=>false)

select count(*), segment_type from dba_segments where tablespace_name = 'SYSAUX'
and owner = 'CTXSYS'
group by segment_type

exec SYS.DBMS_LOGMNR_D.SET_TABLESPACE('SYSAUX_TEMP')

exec DBMS_AUDIT_MGMT.move_dbaudit_tables('SYSAUX_TEMP')


BEGIN
dbms_audit_mgmt.set_audit_trail_location(
audit_trail_type => dbms_audit_mgmt.audit_trail_unified,
audit_trail_location_value => 'SYSAUX_TEMP');
END;
/

BEGIN
DBMS_AUDIT_MGMT.set_audit_trail_location(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_AUD_STD,--this moves table AUD$
audit_trail_location_value => 'SYSAUX_TEMP');
END;
/

BEGIN
DBMS_AUDIT_MGMT.set_audit_trail_location(
audit_trail_type => DBMS_AUDIT_MGMT.AUDIT_TRAIL_FGA_STD,--this moves table FGA_LOG$
audit_trail_location_value => 'SYSAUX_TEMP');
END;
/

None of these move the CLI_ objects

PROCEDURE MOVE_DBAUDIT_TABLES
 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 AUDIT_TRAIL_TBS                VARCHAR2                IN     DEFAULT


12c

--THIS ONE removed CLI_SWP* (very quickly!) – when the AUDIT objects are moved
-- they are recreated in the new tablespace
SQL> exec dbms_audit_mgmt.clean_audit_trail(audit_trail_type=>dbms_audit_mgmt.audit_trail_unified,use_last_arch_timestamp=>FALSE);

BLOB and CLOB Segments
General
alter table <owner>.<table_name> move lob(<column name>) store as ( tablespace sysaux_temp );



Find Generate Move LOB Commands

SELECT 'alter table '||owner||'.'||TABLE_NAME||
' move lob('||COLUMN_NAME||') store as (tablespace SYSAUX_TEMP);' "move lob script",
DATA_TYPE
FROM dba_tab_columns
WHERE DATA_TYPE IN ('CLOB','BLOB')
AND table_name IN (SELECT table_name
FROM dba_tables
WHERE tablespace_name='SYSAUX'
and       partitioned = 'NO'
and       NESTED = 'NO') 
and       owner = 'SYS'

This will generate commands that will work for normal (non-partitioned and non-nested) tables. 

Partitioned table commands are different

Move to SYSAUX_TEMP
alter table  WRH$_SQL_PLAN move lob(other_xml) store as ( tablespace sysaux_temp )

12c
alter table  WRH$_SQLTEXT move lob(SQL_TEXT) store as ( tablespace sysaux_temp )
Move back to SYSAUX
alter table  WRH$_SQL_PLAN move lob(other_xml) store as ( tablespace sysaux )

12c
alter table  WRH$_SQLTEXT move lob(SQL_TEXT) store as ( tablespace sysaux )

alter table  WRI$_ADV_RATIONALE move lob(ATTR5) store as ( tablespace sysaux_temp )

alter table  WRI$_DBU_FEATURE_USAGE move lob(FEATURE_INFO) store as ( tablespace sysaux_temp )


And for partitioned tables, example:

Find the LOB PARTITION name
Find the table name from dba_lobs
Find the column name by DESC’ing the table
select 'alter table <table name> move partition '
||partition_name||' lob(<column name>) '||' store as (tablespace SYSAUX_TEMP);'
from dba_tab_partitions where table_name = '<table name>'


select 'alter table WRI$_OPTSTAT_HISTHEAD_HISTORY move partition '
||partition_name||' lob(EXPRESSION) '||' store as (tablespace SYSAUX_TEMP);'
from dba_tab_partitions where table_name = 'WRI$_OPTSTAT_HISTHEAD_HISTORY'


Normal Tables and Indexes

Generate Table Move (to SYSAUX_TEMP) Scripts

select 'alter table '||owner||'.'||segment_name||' move tablespace sysaux_temp;'
from dba_segments where  segment_type = 'TABLE' and tablespace_name = 'SYSAUX'and owner = 'SYS'


Generate Index Rebuild (to SYSAUX_TEMP) Scripts

select 'alter index '||owner||'.'||index_name||' rebuild tablespace SYSAUX_TEMP;'
from dba_indexes where status = 'UNUSABLE'
and tablespace_name = 'SYSAUX'

Partitioned tables and Indexes

Move table partitions to SYSAUX_TEMP

select 'alter table '||owner||'.'||segment_name||' move partition '||partition_name||' tablespace sysaux_temp;'
from dba_segments where segment_type = 'TABLE PARTITION' and tablespace_name = 'SYSAUX'
order by segment_name


Rebuild Index Partitions in SYSAUX_TEMP
They become USABLE again and are rebuilt in SYSAUX_TEMP

select 'alter index '||index_name|| ' rebuild partition '||
partition_name||' tablespace SYSAUX_TEMP;' from dba_ind_partitions
where status = 'UNUSABLE'
and tablespace_name = 'SYSAUX'

Move to SYSAUX_TEMP

select 'alter table '||owner||'.'||segment_name ||' move tablespace SYSAUX_TEMP;'
from dba_segments where segment_name like '%==' and tablespace_name = 'SYSAUX'
and segment_type  = 'NESTED TABLE'


Index-Organized Tables
IOT

Find the table concerned and shrink it
Enable row movement on the table first (if not already enabled)

Display row_movement


select owner,table_name, row_movement from dba_tables where table_name in 
(select table_name from dba_indexes where index_name like '%IOT%' and tablespace_name = 'SYSAUX')


GSMADMIN_INTERNAL – may not be required to move this – see 

WMSYS 

CTXSYS – these should have been moved with the move proc  but may not have been

IOT Indexes

alter table AQ$_ALERT_QT_H shrink space cascade;

12c - HEATMAP

See MOS
Doc ID 2024036.1
HEATMAP Segment Size Is Large In SYSAUX Even When Heatmap=Off (Doc ID 2024036.1)
This is not the same as my problem – but the solution to my HEATMAP problem is in this document


SQL> show parameter HEAT_MAP;

NAME                                 TYPE                                         VALUE
------------------------------------ -------------------------------------------- ------------------------------
heat_map                             string                                       OFF

ALTER SYSTEM SET "_drop_stat_segment"=1 scope=memory;

Heatmap is dropped

AQ DATAPUMP Tables

Examples
alter table "AQ$_KUPC$DATAPUMP_QUETAB_2_P" move tablespace sysaux_temp;

alter table "AQ$_KUPC$DATAPUMP_QUETAB_2_S" move tablespace sysaux_temp;

Tables with LONG columns

Display Tables with LONG Columns


SELECT TABLE_NAME,COLUMN_NAME,DATA_TYPE
     FROM dba_tab_columns
     WHERE DATA_TYPE IN ('LONG','LONG RAW')
     AND table_name IN (SELECT table_name
                        FROM dba_tables
                        WHERE tablespace_name='SYSAUX')


Some tables with long columns do not contain data- these can be truncated directly. 

For tables with LONG columns that contain data AND there is no data in the LONG column:
•	create a temporary table with the data without the LONG column(s)
•	truncate the table
•	insert the rows back into the table

WRI$_ADV_SQLT_PLAN
Doc ID 2205210.1


create table SQLT_PLANS_TEMP as select
TASK_ID, OBJECT_ID, ATTRIBUTE, PLAN_HASH_VALUE, PLAN_ID,STATEMENT_ID, TIMESTAMP,
REMARKS, OPERATION, OPTIONS, OBJECT_NODE, OBJECT_OWNER, OBJECT_NAME, OBJECT_ALIAS,
OBJECT_INSTANCE,OBJECT_TYPE,OPTIMIZER,SEARCH_COLUMNS,ID,PARENT_ID,DEPTH,POSITION,
COST,CARDINALITY,BYTES,OTHER_TAG,PARTITION_START,PARTITION_STOP,PARTITION_ID,
DISTRIBUTION,CPU_COST,IO_COST,TEMP_SPACE,ACCESS_PREDICATES,FILTER_PREDICATES,
PROJECTION,TIME,QBLOCK_NAME,OTHER_XML         from WRI$_ADV_SQLT_PLANS

select count(*) from WRI$_ADV_SQLT_PLANS where other is not null

select count(*) from SQLT_PLANS_TEMP

select * from SQLT_PLANS_TEMP

truncate table WRI$_ADV_SQLT_PLANS

insert into WRI$_ADV_SQLT_PLANS
select
TASK_ID,OBJECT_ID,ATTRIBUTE, PLAN_HASH_VALUE, PLAN_ID,STATEMENT_ID, TIMESTAMP,
REMARKS, OPERATION, OPTIONS, OBJECT_NODE, OBJECT_OWNER, OBJECT_NAME, OBJECT_ALIAS,
OBJECT_INSTANCE, OBJECT_TYPE,OPTIMIZER, SEARCH_COLUMNS, ID, PARENT_ID, DEPTH,POSITION,
COST, CARDINALITY, BYTES,  OTHER_TAG,PARTITION_START,PARTITION_STOP,PARTITION_ID,
NULL,DISTRIBUTION,CPU_COST, IO_COST,TEMP_SPACE,ACCESS_PREDICATES,FILTER_PREDICATES,
PROJECTION,TIME,QBLOCK_NAME, OTHER_XML  from SQLT_PLANS_TEMP





create table PLAN_temp as select
SIGNATURE, CATEGORY, OBJ_TYPE, PLAN_ID, STATEMENT_ID, XPL_PLAN_ID, TIMESTAMP,
REMARKS, OPERATION, OPTIONS, OBJECT_NODE, OBJECT_OWNER, OBJECT_NAME,
OBJECT_ALIAS, OBJECT_INSTANCE, OBJECT_TYPE, OPTIMIZER, SEARCH_COLUMNS, ID,
PARENT_ID, DEPTH, POSITION, COST,CARDINALITY,BYTES,OTHER_TAG,PARTITION_START,
PARTITION_STOP,PARTITION_ID,DISTRIBUTION,CPU_COST,IO_COST,TEMP_SPACE,
ACCESS_PREDICATES,FILTER_PREDICATES,PROJECTION,TIME,QBLOCK_NAME,OTHER_XML
from SQLOBJ$PLAN

truncate table SQLOBJ$PLAN

insert into SQLOBJ$PLAN select
SIGNATURE, CATEGORY, OBJ_TYPE, PLAN_ID, STATEMENT_ID, XPL_PLAN_ID, TIMESTAMP, REMARKS, OPERATION,
OPTIONS, OBJECT_NODE,OBJECT_OWNER,OBJECT_NAME,OBJECT_ALIAS,OBJECT_INSTANCE,OBJECT_TYPE,
OPTIMIZER,SEARCH_COLUMNS,ID,PARENT_ID,DEPTH,POSITION,COST,CARDINALITY,BYTES,OTHER_TAG,
PARTITION_START,PARTITION_STOP,PARTITION_ID,NULL,DISTRIBUTION,CPU_COST,IO_COST,TEMP_SPACE,
ACCESS_PREDICATES,FILTER_PREDICATES,PROJECTION,TIME,QBLOCK_NAME,OTHER_XML  from PLAN_TEMP;

commit

select count(*) from SQLOBJ$PLAN

Check ADDM Jobs – Shows AWR is Working

If there are unusable indexes or other problems, ADDM tasks may not have a status of ‘COMPLETED’

This query shows ADDM tasks

select owner || '/' || advisor_name as owner_adv
        , task_id || '/' || task_name as task_id_name
        , created
        , (execution_end - execution_start)*86400 as exe_duratn
        , (execution_end - created) * 86400 as exe_creatn
        , how_created
        , status
        , 'Description: ' || description as task_desc
        , 'Error Msg  : ' || error_message as error_msg
from   (select t.*, rank() over (order by execution_end desc) rnk
        from   dba_advisor_tasks t) dat
where  dat.rnk <= 50
  and  1 = 1
order by created desc;



Check Object Validity and Recompile

Select count(*) from dba_objects where status <> 'VALID'

@?/rdbms/admin/utlrp.sql

Linux – Oracle – Display Environment Variables Associated to a Process

Find the process id – Example : Oracle Listener

[grid@server01 admin]$ ps -ef|grep -i listen
grid     21687     1  0 Apr21 ?        00:20:28 /oracle/grid/12.2/bin/tnslsnr LISTENER_SCAN1 -no_crs_notify -inherit
grid     21938     1  0 Apr21 ?        00:32:52 /oracle/grid/12.2/bin/tnslsnr LISTENER -no_crs_notify -inherit
root     31840 31805  0 Apr21 ?        00:00:00 hald-addon-input: Listening on /dev/input/event3 /dev/input/event0 /dev/input/event1
68       32017 31805  0 Apr21 ?        00:00:00 hald-addon-acpi: listening on acpid socket /var/run/acpid.socket
grid     32608 13797  0 14:21 pts/5    00:00:00 grep -i listen

Display the Environment Variables

[grid@server01 admin]$ strings /proc/21938/environ
__CRS_ACTIVE_VERSION=12.2.0.1.0
__CLSAGFW_TYPE_NAME=ora.mgmtlsnr.type
CHECK_WRAP_TRACE=/oracle/gridbase/crsdata/debug/oraagent_trace_needed.txt
ORA_CRS_HOME=/oracle/grid/12.2
TERM=linux
__CRSD_CONNECT_STR=(ADDRESS=(PROTOCOL=IPC)(KEY=CRSD_IPC_SOCKET_11))
NLS_LANG=AMERICAN_AMERICA.AL32UTF8
CRF_HOME=/oracle/grid/12.2
GIPCD_PASSTHROUGH=false
ENVCMD=/bin/env
__CRSD_AGENT_NAME=/oracle/grid/12.2/bin/oraagent_grid
_ORA_AGENT_ACTION=TRUE
__CRSD_MSG_FRAME_VERSION=2
LD_LIBRARY_PATH=/oracle/grid/12.2/lib:/etc/ORCLcluster/lib
WRAP_ENVFILE=/oracle/gridbase/crsdata/debug/oraagent_env_20066.log
START_MODE=
FILEOWNER=
__CLSAGENT_INCARNATION=2
CRS_LIMIT_MEMLOCK=unlimited
FILEOWNER_ID=
__CRS_START_MODE=normal
ORACLE_BASE=/oracle/gbase
.......

Oracle – listener.log file

Rename and compress listener.log file

[grid@server]$ lsnrctl
LSNRCTL> set current_listener listener
LSNRCTL> set log_status off
 
[grid@server]$ mv listener.log listener.log.temp
 
[grid@server]$ lsnrctl
LSNRCTL> set current_listener listener
LSNRCTL> set log_status on

-- compress (or delete) 
[grid@server]$ gzip listener.log.temp
[grid@server]$ lsnrctl
LSNRCTL> set current_listener ASMNET1LSNR_ASM
LSNRCTL> set log_status off
 
[grid@server]$ mv asmnet1lsnr_asm.log asmnet1lsnr_asm.log.temp
 
[grid@server]$ lsnrctl
LSNRCTL> set current_listener ASMNET1LSNR_ASM
LSNRCTL> set log_status on

-- compress (or delete) 
[grid@server]$ gzip asmnet1lsnr_asm.log.temp

Oracle – Query locking

Display locks in Oracle database

select * from gv$lock where block = 1

select * from gv$session where sid in (1998)

select sid, serial#, lockwait,
blocking_instance, blocking_session,
final_blocking_instance, final_blocking_session
from gv$session where program not like 'oracle%'
and blocking_session is not null

--ALTER SYSTEM KILL SESSION 'sid,serial#,inst_id';

select * from gv$session where status = 'KILLED'

-- non-RAC environment
SELECT Decode(request, 0, 'Holder: ',
  'Waiter: ')
  ||vl.sid sess,
  status,id1,id2,lmode,request,vl.TYPE
FROM v$lock vl,v$session vs
WHERE ( id1, id2, vl.TYPE ) IN 
(SELECT id1, id2, TYPE FROM v$lock
  WHERE request > 0)
  AND vl.sid = vs.sid
ORDER BY id1, request

[Look for UBABLK in gv$transaction – if value remains static for a while, the transaction is potentially blocked

select * from gv$transaction

Oracle – Clusterware Installation and Configuration

Installing and Configuring Oracle Clusterware

The installation procedure for Oracle clusterware (Grid Infrastructure) is well documented in Oracle documentation. This post contains the titles of MOS documents that will be useful before, during, or after Oracle clusterware installation.

MOS Oracle Account is required to access the documents listed in this post.

Network and Network Interfaces Validation

How to Validate Network and Name Resolution Setup for the Clusterware and RAC (Doc ID 1054902.1)

Configure/Reconfigure

Attention – GridSetup.sh for 12.2

How to Configure or Re-configure Grid Infrastructure With config.sh/config.bat (Doc ID 1354258.1)

Multicast Test Script

Look for mcasttest.pl-tool in the MOS document:

Grid Infrastructure Startup During Patching, Install or Upgrade May Fail Due to Multicasting Requirement (Doc ID 1212703.1)

Create/Recreate GIMR database (MGMTDB)

MDBUtil: GI Management Repository configuration tool (Doc ID 2065175.1)

 

Install OS Packages

For convenience

yum -y install xorg-x11-utils  (xdpyinfo (DISPLAY issue with mobaxterm)

yum -y install psmisc (for opatching if required)

 

Add First Node

Unizip Oracle sw or gold image in $GRID_HOME (owned by and permissions set for grid user)

(as grid user)

$GRID_HOME/GridSetup.sh

Add second node

After install of first node:
(as grid user)
$GRID_HOME/bin/cluvfy stage -pre nodeadd -n <node2> -fixup -fixupnoexec -verbose

 

Trace/Log Files

$GRID_BASE/diag/crs/<host>/crs/trace

alert.log
gipcd.trc
ocssd.trc
evmd.trc
gpnpd.trc
mdnsd.trc

$GRID_BASE/crsdata/<host>/crsconfig/

Useful Commands

/oracle/grid/12.2.0/bin/crsctl stat res -t -init -w "((TARGET != ONLINE) or (STATE != ONLINE))"

Oracle – RMAN – Display RMAN Backups

RMAN -Display RMAN Backups

-- display rman backups
select
  j.session_recid, j.session_stamp,
  to_char(j.start_time, 'dd.mm.yyyy hh24:mi:ss') start_time,
  to_char(j.end_time, 'dd.mm.yyyy hh24:mi:ss') end_time,
  (j.output_bytes/1024/1024) output_mbytes, j.status, j.input_type,
  decode(to_char(j.start_time, 'd'), 1, 'Sunday', 2, 'Monday',
                                     3, 'Tuesday', 4, 'Wednesday',
                                     5, 'Thursday', 6, 'Friday',
                                     7, 'Saturday') dow,
  j.elapsed_seconds, j.time_taken_display,
  x.cf, x.df, x.i0, x.i1, x.l,
  ro.inst_id output_instance
from V$RMAN_BACKUP_JOB_DETAILS j
  left outer join
  (select
     d.session_recid, d.session_stamp,
     sum(case when d.controlfile_included = 'YES' then d.pieces else 0 end) CF,
     sum(case when d.controlfile_included = 'NO'
               and d.backup_type||d.incremental_level = 'D' then d.pieces else 0 end) DF,
     sum(case when d.backup_type||d.incremental_level = 'D0' then d.pieces else 0 end) I0,
     sum(case when d.backup_type||d.incremental_level = 'I1' then d.pieces else 0 end) I1,
     sum(case when d.backup_type = 'L' then d.pieces else 0 end) L
    from
     V$BACKUP_SET_DETAILS d
     join V$BACKUP_SET s on s.set_stamp = d.set_stamp and s.set_count = d.set_count
    where s.input_file_scan_only = 'NO'
    group by d.session_recid, d.session_stamp) x
    on x.session_recid = j.session_recid and x.session_stamp = j.session_stamp
  left outer join (select o.session_recid, o.session_stamp, min(inst_id) inst_id
                   from GV$RMAN_OUTPUT o
                   group by o.session_recid, o.session_stamp)
    ro on ro.session_recid = j.session_recid and ro.session_stamp = j.session_stamp
where j.start_time > trunc(sysdate)-2
order by j.start_time desc;

Oracle – Direct NFS with a Windows NFS Server

Scenario : Oracle Direct NFS, NFS on Windows Server

you are using Oracle Direct NFS, and the NFS is running on Windows, there is a potential issue with permissions and ownership changes required.

Example

An example of issues with Oracle Direct NFS using datapump with the DATA_PUMP_DIR located on an NFS share server by NFS on Windows:

Estimate in progress using BLOCKS method...
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 2.625 MB
Processing object type SCHEMA_EXPORT/USER
ORA-39126: Worker unexpected fatal error in KUPW$WORKER.CREATE_OBJECT_ROWS [USER:"XYZ"]
ORA-19505: failed to identify file "/u01/ORCL/ORCL_testexp.dp"
ORA-17503: ksfdopn:4 Failed to open file /u01/ORCL/ORCL_testexp.dp
ORA-17500: ODM err:File does not exist
ORA-06512: at "SYS.DBMS_SYS_ERROR", line 95
ORA-06512: at "SYS.KUPW$WORKER", line 11014
----- PL/SQL Call Stack -----
  object      line  object
  handle    number  name

Relevant MOS Documents

RMAN Backup Fail to NFS Shares From a Windows Server When DNFS is Enabled (Doc ID 2171297.1)
Datapump Dump File Permission In DNFS Environment (Doc ID 2049012.1)

Solution

Change the value of the following registry key (on the Windows Server providing NFS) to 0 and restart Server for NFS:

HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\ServerForNfs\CurrentVersion\Exports\0\RestrictChown = 0 (DWORD)

Workaround

You could also disable Direct NFS:
set ORACLE environment.
cd $ORACLE_HOME/rdbms/lib/
make -f ins_rdbms.mk dnfs_off

— restart the instance