Pages

Monday, January 29, 2018

Monitor Database Processes and Sessions - Code Example

Log Database Processes - Code Example

A job to log processes in database to a table every 10 minutes



create table ADMIN_HIST_OPEN_CURSORS
(
  run_date             DATE,
  db_schema            VARCHAR2(30),
  machine              VARCHAR2(30),
  open_cursors_current NUMBER,
  open_cursors_max     NUMBER,
  open_cursors_total   NUMBER,
  rank                 NUMBER
)
tablespace SH_DBA_TBS_TB_01;

create table ADMIN_HIST_PROCESSES
(
  run_date  DATE,
  db_schema VARCHAR2(30),
  machine   VARCHAR2(30),
  os_user   VARCHAR2(30),
  processes NUMBER,
  rank      NUMBER
)
tablespace SH_DBA_TBS_TB_01;


--==============================================================
-- Manual Steps
--==============================================================
----------------------------------
-- As sysdba:
----------------------------------
-- CREATE TABLESPACE SH_DBA_TBS_TB_01 DATAFILE '/oracle_db/db1/db_igt/SH_DBA_TBS_TB_01.dbf' SIZE 10M AUTOEXTEND ON NEXT 10M MAXSIZE UNLIMITED EXTENT MANAGEMENT LOCAL AUTOALLOCATE;
-- CREATE TABLESPACE SH_DBA_TBS_IX_01 DATAFILE '/oracle_db/db1/db_igt/SH_DBA_TBS_IX_01.dbf' SIZE 10M AUTOEXTEND ON NEXT 10M MAXSIZE UNLIMITED EXTENT MANAGEMENT LOCAL AUTOALLOCATE;
-- CREATE USER SH_DBA IDENTIFIED BY SH_PASS DEFAULT TABLESPACE SH_DBA_TBS_TB_01;
-- GRANT CONNECT, RESOURCE TO SH_DBA;
-- GRANT SELECT ANY DICTIONARY TO SH_DBA;
-- GRANT UNLIMITED TABLESPACE TO SH_DBA;
-- GRANT CREATE PUBLIC SYNONYM TO SH_DBA;
-- GRANT DROP PUBLIC SYNONYM TO SH_DBA;
-- GRANT DEBUG CONNECT SESSION TO SH_DBA;
-- GRANT CREATE PROCEDURE, EXECUTE ANY PROCEDURE TO SH_DBA;
-- GRANT CREATE SNAPSHOT, CREATE TRIGGER, CREATE ANY INDEX TO SH_DBA;
-- GRANT CREATE SYNONYM TO SH_DBA;
-- GRANT UNLIMITED TABLESPACE TO SH_DBA;
-- GRANT QUERY REWRITE TO SH_DBA;
-- GRANT CREATE ANY DIRECTORY TO SH_DBA;
-- GRANT SELECT_CATALOG_ROLE TO SH_DBA;

-- GRANT DBA TO SH_DBA;
-- as system
-- GRANT SELECT ON SYS.V_$PROCESS TO MY_USER;
-- GRANT SELECT ON SYS.V_$SESSION TO MY_USER;

------------------------
-- Job
------------------------
DECLARE
   v_job_number NUMBER(10);
BEGIN
 DBMS_JOB.SUBMIT (JOB => v_job_number, 
                  WHAT => 'ADMIN_UTIL.monitor_oracle;', 
                  NEXT_DATE => TRUNC(SYSDATE,'mi') +10/1440, 
                  INTERVAL => 'TRUNC(SYSDATE,''mi'') +10/1440'
 );
 COMMIT;
END;
/

------------------------------------------------
CREATE OR REPLACE PACKAGE ADMIN_UTIL AS       
  PROCEDURE monitor_oracle;
END ADMIN_UTIL;
/

------------------------------------------------
CREATE OR REPLACE PACKAGE BODY MONITOR_UTIL AS
--==============================================================
-- Manual Steps
--==============================================================
-- CREATE TABLE ADMIN_HIST_PROCESSES
--      (run_date DATE,
--       db_schema VARCHAR2(30),
--       machine   VARCHAR2(30),
--       os_user   VARCHAR2(30),
--       processes  NUMBER,
--       rank       NUMBER) TABLESPACE IGT_TABLE;
--
-- As sysdba:
-- GRANT SELECT ON SYS.V_$PROCESS TO COLLECTOR;
-- GRANT SELECT ON SYS.V_$SESSION TO COLLECTOR;
--
-- Job
--DECLARE
--   v_job_number NUMBER(10);
--BEGIN
-- DBMS_JOB.SUBMIT (JOB => v_job_number,
--                  WHAT => 'ADMIN_UTIL.log_sessions;',
--                  NEXT_DATE => TRUNC(SYSDATE,'mi') +10/1440,
--                  INTERVAL => 'TRUNC(SYSDATE,''mi'') +10/1440'
-- );
-- COMMIT;
--END;
--/

  PROCEDURE log_open_cursors IS
  BEGIN  
      INSERT INTO ADMIN_HIST_OPEN_CURSORS (run_date, db_schema, machine, open_cursors_current, open_cursors_max, open_cursors_total, rank)
            SELECT TRUNC(SYSDATE,'mi') as run_date,
                   username AS db_schema ,
                   machine,
                   avg_cur AS open_cursors_current,
                   max_cur AS open_cursors_max,
                   total_cur AS open_cursors_total, 
                   rownum                   
            FROM   (
              SELECT SUM(a.value) total_cur, 
                     ROUND(avg(a.value)) avg_cur, 
                     MAX(a.value) max_cur, 
                     s.username   username,  
                     s.machine machine
               FROM V$SESSTAT A, 
                    V$STATNAME B, 
                    V$SESSION S 
              WHERE a.statistic# = b.statistic#  
                AND S.sid=a.sid
                AND b.name = 'opened cursors current' 
                AND S.username IS NOT NULL                
              GROUP BY s.username, s.machine
             HAVING SUM(a.value) > 99
              ORDER BY 1 desc
              );


  EXCEPTION

    WHEN OTHERS THEN
      NULL;
  END log_open_cursors;
------------------------------------------------------------------------
  PROCEDURE log_sessions IS
  BEGIN

    BEGIN
      INSERT INTO ADMIN_HIST_PROCESSES (run_date, db_schema, machine, os_user, processes, rank)
      SELECT run_date,
             db_schema ,
             machine,
             osuser,
             processes,
             rownum
      FROM(
            SELECT TRUNC(SYSDATE,'mi') as run_date,
                   schemaname AS db_schema ,
                   machine,
                   osuser,
                   COUNT(*) AS processes
            FROM   (
              SELECT  PROCESSES.*,
                      SESSIONS.*
                 FROM V$PROCESS PROCESSES,
                      V$SESSION SESSIONS
                WHERE PROCESSES.background IS NULL
                  AND PROCESSES.addr = SESSIONS.paddr
               )
            GROUP BY schemaname,machine, osuser
            HAVING COUNT(*) > 1
            ORDER BY COUNT(*) DESC
      );

      INSERT INTO ADMIN_HIST_PROCESSES (run_date, db_schema, machine, os_user, processes, rank)
      SELECT run_date,
             db_schema ,
             machine,
             osuser,
             processes,
             0
      FROM(
            SELECT TRUNC(SYSDATE,'mi') as run_date,
                   'Total' AS db_schema ,
                   NULL as machine,
                   NULL as osuser,
                   COUNT(*) AS processes
            FROM   (
              SELECT  PROCESSES.*,
                      SESSIONS.*
                 FROM V$PROCESS PROCESSES,
                      V$SESSION SESSIONS
                WHERE PROCESSES.background IS NULL
                  AND PROCESSES.addr = SESSIONS.paddr
               )
      );

      COMMIT;


     EXCEPTION
      WHEN OTHERS THEN
        NULL;
     END;

     BEGIN
       IF  TO_NUMBER(to_char(SYSDATE,'hh24')) = 14 THEN
         DELETE FROM ADMIN_HIST_PROCESSES WHERE run_date < SYSDATE - 200;
         COMMIT;
       END IF;
     EXCEPTION
      WHEN OTHERS THEN
        NULL;
     END;


  EXCEPTION

    WHEN OTHERS THEN
      NULL;
  END log_sessions;
------------------------------------------------------------------------
  PROCEDURE monitor_oracle IS  
  BEGIN  
    log_sessions;
    log_open_cursors;
  EXCEPTION  
    WHEN OTHERS THEN
      NULL;
  END monitor_oracle;  
------------------------------------------------------------------------

END MONITOR_UTIL;------------------------------------------------
--==============================================================  

CREATE OR REPLACE VIEW ADMIN_HIST_PROCESSES_SUM_VW AS 
SELECT * FROM 
(
SELECT 'SPARX' as service_name, run_date, SUM(processes) as processes FROM ADMIN_HIST_PROCESSES WHERE 1=1 and DB_SCHEMA like '%SPARX%' GROUP BY run_date 
UNION ALL
SELECT 'IPN' as service_name, run_date, SUM(processes) as processes FROM ADMIN_HIST_PROCESSES WHERE 1=1 and DB_SCHEMA like '%IP%' GROUP BY run_date 
UNION ALL
SELECT 'ORACLE and OGG' as service_name, run_date, SUM(processes)as processes  FROM ADMIN_HIST_PROCESSES WHERE 1=1 and DB_SCHEMA IN ('SYS','OGG') GROUP BY run_date
)
order by run_date desc , service_name asc;


------------------------------
-- Log Sessions and Processes
------------------------------
-- Create tables
CREATE TABLE ADMIN_HIST_SESSIONS_NUMBER
(
  run_date             DATE,
  all_sessions         NUMBER,
  app_sessions         NUMBER,
  all_processes        NUMBER,
  app_processes        NUMBER
)
TABLESPACE IGT_TABLE;

GRANT SELECT ON SYS.V_$PROCESS TO SH_DBA;
GRANT SELECT ON SYS.V_$SESSION TO SH_DBA;

CREATE OR REPLACE PACKAGE MONITOR_UTIL AS
  PROCEDURE log_open_sessions;
END MONITOR_UTIL;
/

CREATE OR REPLACE PACKAGE BODY MONITOR_UTIL AS

PROCEDURE log_open_sessions IS
BEGIN
    INSERT INTO ADMIN_HIST_SESSIONS_NUMBER (run_date, all_sessions, app_sessions, all_processes, app_processes)
    SELECT SYSDATE,
         (SELECT COUNT(*) FROM V$SESSION) as all_sessions,
         (SELECT COUNT(*) FROM V$SESSION WHERE user# <> 0) as app_sessions,
         (SELECT COUNT(*) FROM V$PROCESS) as all_processes,
         (SELECT COUNT(*) FROM V$PROCESS WHERE addr IN (SELECT paddr FROM V$SESSION WHERE user# <> 0)) as app_processes
    FROM DUAL;
    commit;
EXCEPTION
  WHEN OTHERS THEN
    NULL;
END log_open_sessions;

END MONITOR_UTIL;
/

BEGIN
  MONITOR_UTIL.log_open_sessions;
END;
/




DECLARE
  v_job_number NUMBER(10);
  v_job_exists NUMBER(10);
BEGIN
 SELECT COUNT(*) INTO v_job_exists FROM USER_JOBS WHERE UPPER(what) LIKE 'MONITOR_UTIL.LOG_OPEN_SESSIONS%';
 IF v_job_exists = 0 THEN
   DBMS_JOB.SUBMIT (JOB => v_job_number, 
                    WHAT => 'MONITOR_UTIL.log_open_sessions;', 
                    NEXT_DATE => TRUNC(SYSDATE,'HH24')+ 1/24,
                    INTERVAL => 'TRUNC(SYSDATE,''HH24'')+ 1/24'
                    );
   COMMIT;
 END IF;
END;
/

Sunday, January 21, 2018

Oracle GG Golden Gate Replicat Process is Abended in case of DELETE. What to check.

==========================
General
==========================
The issue: One of the Oracle GG (Golden Gate) REPLICAT processes is in ABENDED status

>%cd /software/ogg/1212
/software/ogg/1212/>% ./ggsci
info all

REPLICAT    RUNNING     REP_P_11    00:00:00      00:00:08    
REPLICAT    RUNNING     REP_P_12    00:00:00      00:00:05    
REPLICAT    RUNNING     REP_P_13    00:00:00      00:00:00    
REPLICAT    ABENDED     REP_P_14    00:00:50      1858:05:19  
REPLICAT    RUNNING     REP_P_15    00:00:00      00:00:04    
REPLICAT    RUNNING     REP_S_01    00:00:00      00:00:02    
REPLICAT    RUNNING     REP_S_02    00:00:00      00:00:03   

The REP_P_14 cannot be restarted.
What to check?

==========================
What to check
==========================
One can try these commands to restart REP_P_14

INFO REP_P_14
STATUS REP_P_14  
STOP REP_P_14 
START REP_P_14
CLEANUP REP_P_14
KILL REP_P_14

To see the real issues:
VIEW REPORT REP_P_14

In the output there is the actual error:
2018-01-21 10:16:58  ERROR   OGG-01296  Error mapping from MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP to MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP.

==========================
By Example
==========================

GGSCI (esp-tel-1-dbu-2) 3> info REPLICAT REP_P_14

REPLICAT   REP_P_14  Last Started 2018-01-21 09:54   Status ABENDED
Checkpoint Lag       00:00:50 (updated 1858:07:04 ago)
Log Read Checkpoint  File /software/ogg/1212/dirdat/14/in/ep000204
                     2017-11-04 23:50:37.060216  RBA 6086003

 
GGSCI (esp-tel-1-dbu-2) 7> STATUS REP_P_14  
REPLICAT REP_P_14: ABENDED

GGSCI (esp-tel-1-dbu-2) 8> STOP REP_P_14 
REPLICAT REP_P_14 is already stopped.

GGSCI (esp-tel-1-dbu-2) 9> START REP_P_14
Sending START request to MANAGER ...
REPLICAT REP_P_14 starting

GGSCI (esp-tel-1-dbu-2) 7> STATUS REP_P_14  
REPLICAT REP_P_14: ABENDED
 
GGSCI (esp-tel-1-dbu-2) 3> VIEW REPORT REP_P_14

********************************************************************
                 Oracle GoldenGate Delivery for Oracle
 Version 12.1.2.0.0 17185003 OGGCORE_12.1.2.0.0_PLATFORMS_130924.1316_FBO
   Linux, x64, 64bit (optimized), Oracle 11g on Sep 25 2013 00:50:41

Copyright (C) 1995, 2013, Oracle and/or its affiliates. All rights reserved.


                    Starting at 2018-01-21 10:09:04
********************************************************************

Operating System Version:
Linux
Version #1 SMP Sun Nov 10 22:19:54 EST 2013, Release 2.6.32-431.el6.x86_64
Node: esp-tel-1-dbu-2
Machine: x86_64
                         soft limit   hard limit
Address Space Size   :    unlimited    unlimited
Heap Size            :    unlimited    unlimited
File Size            :    unlimited    unlimited
CPU Time             :    unlimited    unlimited

Process id: 47121

Description: 

********************************************************************
**            Running with the following parameters                  **
********************************************************************

2018-01-21 10:09:04  INFO    OGG-03059  Operating system character set identified as UTF-8.

2018-01-21 10:09:04  INFO    OGG-02695  ANSI SQL parameter syntax is used for parameter parsing.
REPLICAT rep_p_14
setenv (ORACLE_SID="igt")

2018-01-21 10:09:04  INFO    OGG-02095  Successfully set environment variable ORACLE_SID=igt.
setenv (ORACLE_HOME="/software/oracle/112")

2018-01-21 10:09:04  INFO    OGG-02095  Successfully set environment variable ORACLE_HOME=/software/oracle/112.
setenv (NLS_LANG = "AMERICAN_AMERICA.AL32UTF8")

2018-01-21 10:09:04  INFO    OGG-02095  Successfully set environment variable NLS_LANG=AMERICAN_AMERICA.AL32UTF8.
ASSUMETARGETDEFS
USERID ogg, PASSWORD ******************************** ENCRYPTKEY DEFAULT
REPERROR (-1, IGNORE)
CACHEMGR CACHESIZE 256M
DISCARDFILE /software/ogg/1212/dirdat/14/in/disc14p.txt, append,
include ./dirprm/mapPROVtables_14.inc
MAP MEX_MOVQQ_IPNQQ.ADPE, TARGET MEX_MOVQQ_IPNQQ.ADPE;
MAP MEX_MOVQQ_IPNQQ.ADPE_FLOW_RULES, TARGET MEX_MOVQQ_IPNQQ.ADPE_FLOW_RULES;
MAP MEX_MOVQQ_IPNQQ.ADPE_IF, TARGET MEX_MOVQQ_IPNQQ.ADPE_IF;
MAP MEX_MOVQQ_IPNQQ.ALARMER, TARGET MEX_MOVQQ_IPNQQ.ALARMER;
MAP MEX_MOVQQ_IPNQQ.ALARM_EVENTS, TARGET MEX_MOVQQ_IPNQQ.ALARM_EVENTS;
MAP MEX_MOVQQ_IPNQQ.ALARM_FILE_CONFIG, TARGET MEX_MOVQQ_IPNQQ.ALARM_FILE_CONFIG;
MAP MEX_MOVQQ_IPNQQ.ALARM_MAP, TARGET MEX_MOVQQ_IPNQQ.ALARM_MAP;


opened trail file /software/ogg/1212/dirdat/14/in/ep000204 at 2018-01-21 10:09:05

2018-01-21 10:09:05  INFO    OGG-03522  Setting session time zone to source database time zone 'GMT'.

2018-01-21 10:09:05  INFO    OGG-03506  The source database character set, as determined from the trail file, is UTF-8.

MAP resolved (entry MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP):
  MAP "MEX_MOVQQ_IPNQQ"."DB_PROC_PURGE_HOMEBOUND_TEMP", TARGET MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP;

2018-01-21 10:09:05  WARNING OGG-06439  No unique key is defined for table DB_PROC_PURGE_HOMEBOUND_TEMP. All viable columns will be 
used to represent the key, but may not guarantee uniqueness. KEYCOLS may be used to define the key.
Using following columns in default map by name:
  NETWORK_ID, PROFILE_ID, PURGE_COUNT_GSM, PURGE_COUNT_LTE, 
  PURGE_COUNT_VOICE, PURGE_COUNT_DATA
Using the following key columns for target table MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP: NETWORK_ID, PROFILE_ID, PURGE_COUNT_G
SM, PURGE_COUNT_LTE, PURGE_COUNT_VOICE, PURGE_COUNT_DATA.



2018-01-21 10:09:05  WARNING OGG-01004  Aborted grouped transaction on 'MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP', Database erro
r 1403 (OCI Error ORA-01403: no data found, SQL <DELETE FROM "MEX_MOVQQ_IPNQQ"."DB_PROC_PURGE_HOMEBOUND_TEMP"  WHERE "NETWORK_ID" = 
:b0 AND "PROFILE_ID" = :b1 AND "PURGE_COUNT_GSM" = :b2 AND "PURGE_COUNT_LTE" is NULL AND "PURGE_COUNT_VOICE" is NULL AND "PURGE_COUN
T_DATA" is NULL AND ROWNUM = 1>).

2018-01-21 10:09:05  WARNING OGG-01003  Repositioning to rba 6086003 in seqno 204.

2018-01-21 10:09:05  WARNING OGG-01154  SQL error 1403 mapping MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP to MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP
 OCI Error ORA-01403: no data found, SQL <DELETE FROM "MEX_MOVQQ_IPNQQ"."DB_PROC_PURGE_HOMEBOUND_TEMP"  WHERE
 "NETWORK_ID" = :b0 AND "PROFILE_ID" = :b1 AND "PURGE_COUNT_GSM" = :b2 AND "PURGE_COUNT_LTE" is NULL AND "PURGE_COUNT_VOICE" is NULL
 AND "PURGE_COUNT_DATA" is NULL AND ROWNUM = 1>.

2018-01-21 10:09:05  WARNING OGG-01003  Repositioning to rba 6086003 in seqno 204.

==========================
Checking the Table in question
==========================
After checking the table DB_PROC_PURGE_HOMEBOUND_TEMP - it is not clear why this table failed in Replication

The table on both sites is identical and empty.

Table DB_PROC_PURGE_HOMEBOUND_TEMP got no Primary Key on both Instances.
Table DB_PROC_PURGE_HOMEBOUND_TEMP is identical on both Instances.

Even after running TRUNCATE TABLE DB_PROC_PURGE_HOMEBOUND_TEMP on both sites, the issue still remains.
As a workaround this table was excluded from the tables list for Replication.

A more general solution would have been to use ALLOWNOOPUPDATES parameter.
But since this was a production environment, and this table should not have been replicate in the first place, a more conservative solution was chosen.

==========================
REPLICAT Parameters File
==========================
Per VIEW REPORT REP_P_14 command output:

DISCARDFILE /software/ogg/1212/dirdat/14/in/disc14p.txt, append,
include ./dirprm/mapPROVtables_14.inc

Checking ./dirprm/mapPROVtables_14.inc file, it got such references:

MAP MEX_MOVQQ_IPNQQ.ADPE, TARGET MEX_MOVQQ_IPNQQ.ADPE;
MAP MEX_MOVQQ_IPNQQ.ADPE_FLOW_RULES, TARGET MEX_MOVQQ_IPNQQ.ADPE_FLOW_RULES;
MAP MEX_MOVQQ_IPNQQ.ADPE_IF, TARGET MEX_MOVQQ_IPNQQ.ADPE_IF;
MAP MEX_MOVQQ_IPNQQ.ALARMER, TARGET MEX_MOVQQ_IPNQQ.ALARMER;
MAP MEX_MOVQQ_IPNQQ.ALARM_EVENTS, TARGET MEX_MOVQQ_IPNQQ.ALARM_EVENTS;
MAP MEX_MOVQQ_IPNQQ.ALARM_FILE_CONFIG, TARGET MEX_MOVQQ_IPNQQ.ALARM_FILE_CONFIG;
MAP MEX_MOVQQ_IPNQQ.ALARM_MAP, TARGET MEX_MOVQQ_IPNQQ.ALARM_MAP;
...
...
MAP MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP, TARGET 
MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP;   

As a workaround, the reference to MEX_MOVQQ_IPNQQ.DB_PROC_PURGE_HOMEBOUND_TEMP was deleted from tables list, and REP_P_14 restarted.
Same was done on both instances.
And at this point the REP_P_14 was started without errors.

./ggsci 
GGSCI (esp-tel-2-dbu-1) 2> STOP REP_P_14
ending STOP request to REPLICAT REP_P_14 ...
Request processed.


GGSCI (esp-tel-2-dbu-1) 2> START REP_P_14

Sending START request to MANAGER ...
REPLICAT REP_P_14 starting

GGSCI (esp-tel-2-dbu-1) 3> STATUS REP_P_14  
REPLICAT REP_P_14: RUNNING


==========================
OGG-01296  Error mapping Error
==========================
Per Oracle Documentation:
Replicat Abends With Error "OGG-01296 Oracle GoldenGate Delivery for Oracle, repggt10.prm: Error mapping from CW.XYZ to CW.XYZ" (Doc ID 2295315.1)

APPLIES TO:
Oracle GoldenGate - Version 11.2.1.0.14 and later
Information in this document applies to any platform.

SYMPTOMS
Replicat process abends with following mapping errors

2017-07-16 19:52:12 WARNING OGG-00869 Oracle GoldenGate Delivery for Oracle, repggt10.prm: No unique key is defined for table 'XYZ'. All viable columns will be used to represent the key, but may not guarantee uniqueness. KEYCOLS may be used to define the key.
2017-07-16 19:52:12 ERROR OGG-01296 Oracle GoldenGate Delivery for Oracle, repggt10.prm: Error mapping from CW.XYZ to CW.XYZ.
2017-07-16 19:52:12 ERROR OGG-01668 Oracle GoldenGate Delivery for Oracle, repggt10.prm: PROCESS ABENDING.


CAUSE

Table doesn't have PK/UI and Replicat encounters a no-up update

SOLUTION
Add ALLOWNOOPUPDATES or APPLYNOOPUPDATES parameter to the Replicat

What are ALLOWNOOPUPDATES or APPLYNOOPUPDATES parameters?

ALLOWNOOPUPDATES and NOALLOWNOOPUPDATES

ALLOWNOOPUPDATES and NOALLOWNOOPUPDATES to control how Replicat responds to a no-op operation. 
A no-op operation is one in which there is no effect on the target table. 

NOALLOWNOOPUPDATES is the default value.

The following are some examples of how this can occur:

A. The source table has a column that does not exist in the target table, or it has a column that was excluded from replication (with a COLSEXCEPT clause). 
In either case, if that source column is updated, there will be no target column name to use in the SET clause within the Replicat SQL statement.

B. An update is made that sets a column to the same value as the current one. 
The database does not log the new value, because it did not change. However, Oracle GoldenGate captures the operation as a change record because the primary key was logged, but there is no column value for the SET clause in the Replicat SQL statement.

By default (NOALLOWNOOPUPDATES), Replicat abends with an error because these types of operations do not update the database. 

With ALLOWNOOPUPDATES, Replicat ignores the operation instead of abending. 

APPLYNOOPUPDATES 
You can use the internal parameter APPLYNOOPUPDATES to force the UPDATE to be applied. 
APPLYNOOPUPDATES overrides ALLOWNOOPUPDATES. 
If both are specified, Replicat applies updates for which there are key columns for the source and target tables. 

ALLOWNOOPUPDATES usage
The parameter ALLOWNOOPUPDATES should be added to the prm file and replicat process restarted.
For example:


/software/ogg/1212/dirprm>% less rep_p_14.prm
REPLICAT rep_p_14

setenv (ORACLE_SID="igt")
setenv (ORACLE_HOME="/software/oracle/112")
setenv (NLS_LANG = "AMERICAN_AMERICA.AL32UTF8")

ASSUMETARGETDEFS
ALLOWNOOPUPDATES
USERID ogg, PASSWORD AACAAAAAAAAAAAIAZEDCPHICXGPEQCED ENCRYPTKEY DEFAULT

REPERROR (-1, IGNORE)

CACHEMGR CACHESIZE 256M

DISCARDFILE /software/ogg/1212/dirdat/14/in/disc14p.txt, append,
include ./dirprm/mapPROVtables_14.inc