Oracle Enterprise Manager Security– Disable SYSMAN access

In Enterprise Manager 12c SYSMAN user is the schema owner and as a best practice all the users should log in using their own individual accounts. To enforce this you can prevent SYSMAN from login into the console and/or emcli by setting SYSTEM_USER to -1 in the MGMT_CREATED_USERS table:
UPDATE MGMT_CREATED_USERS
SET SYSTEM_USER=’-1’
WHERE user_name=’SYSMAN’
To re-enable the access just set it to 1.
UPDATE MGMT_CREATED_USERS
SET SYSTEM_USER=’1’
WHERE user_name=’SYSMAN’
Refer to Oracle Support’s note:
How To Disable SYSMAN & SYSTEM Users from Logging into Grid Console? (Doc ID 867360.1)
Thanks,

Alfredo

Oracle Enterprise Manager – Reducing the noise, Part 1

Enterprise Manager 12c is a great monitoring tool, with it you can monitor a wide range of target types from databases to middleware; although out-of-the-box metrics can suit your monitoring requirements they can generate a considerable amount of white noise. In order to reduce this noise first you have to identify which are the top alerts in your system; Cloud Control comes with several predefined reports that help you to dig into multiple areas of your system, there’s a report “20 Most Common Alerts” which shows you the incidence of common alerts.


In the picture above, you can clearly see that metric “Database Time Spent Waiting (%)” appears twice in my Top 3, let’s find out our metric setting for my DB targets; in order to do this we must go to a DB home page then Oracle Database -> Monitoring -> Metrics and Collection Settings.  

 
Wait a minute! Why I’m receiving alerts if there are no thresholds setup for any of those metrics?, this behavior is clearly explained in MOS note 1500074.1 about a default warning threshold of 30% inside the database configuration. Let’s take a look to dba_threshold to confirm.
set lines 300
column METRICS_NAME format a30
column WARNING_OPERATOR format a30
column WARNING_VALUE format a30
column CRITICAL_OPERATOR format a30
column CRITICAL_VALUE format a30
SELECT METRICS_NAME,WARNING_OPERATOR ,WARNING_VALUE,CRITICAL_OPERATOR ,CRITICAL_VALUE FROM DBA_THRESHOLDS;
METRICS_NAME                        WARNING_OPERATOR               WARNING_VALUE                  CRITICAL_OPERATOR              CRITICAL_VALUE
———————————– —————————— —————————— —————————— ——————————
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Blocked User Session Count          GT                             0                              NONE
Current Open Cursors Count          GT                             1200                           NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             30                             NONE
Database Time Spent Waiting (%)     GT                             50                             NONE
Database Time Spent Waiting (%)     GT                             50                             NONE
Logons Per Sec                      GE                             100                            NONE
Session Limit %                     GT                             90                             GT                             97
Tablespace Bytes Space Usage        DO NOT CHECK                   0                              DO_NOT_CHECK                   0
Tablespace Space Usage              GE                             85                             GE                             97
22 rows selected.
There you go!, all metrics for “Database Time Spent Waiting (%)” are set to 30% or 50% values, now the trick to disable these metrics is to set them to a different value like 99%; this will override the default value as follows:

  
Let’s look at the database setting again:
set lines 300
column METRICS_NAME format a30
column WARNING_OPERATOR format a30
column WARNING_VALUE format a30
column CRITICAL_OPERATOR format a30
column CRITICAL_VALUE format a30
METRICS_NAME                        WARNING_OPERATOR               WARNING_VALUE                  CRITICAL_OPERATOR              CRITICAL_VALUE
———————————– —————————— —————————— —————————— ——————————
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Blocked User Session Count          GT                             0                              NONE
Current Open Cursors Count          GT                             1200                           NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Database Time Spent Waiting (%)     GT                             99                             NONE
Logons Per Sec                      GE                             100                            NONE
Session Limit %                     GT                             90                             GT                             97
Tablespace Bytes Space Usage        DO NOT CHECK                   0                              DO_NOT_CHECK                   0
Tablespace Space Usage              GE                             85                             GE                             97
25 rows selected.
We successfully modified these metrics to a very high value; at this point you can decide to stay at 99% or you can remove that threshold in order to completely disable them.

Now let’s confirm those settings in the database:
set lines 300
column METRICS_NAME format a30
column WARNING_OPERATOR format a30
column WARNING_VALUE format a30
column CRITICAL_OPERATOR format a30
column CRITICAL_VALUE format a30
METRICS_NAME                        WARNING_OPERATOR               WARNING_VALUE                  CRITICAL_OPERATOR              CRITICAL_VALUE
———————————– —————————— —————————— —————————— ——————————
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             10                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Average Users Waiting Counts        GT                             30                             NONE
Blocked User Session Count          GT                             0                              NONE
Current Open Cursors Count          GT                             1200                           NONE
Logons Per Sec                      GE                             100                            NONE
Session Limit %                     GT                             90                             GT                             97
Tablespace Bytes Space Usage        DO NOT CHECK                   0                              DO_NOT_CHECK                   0
Tablespace Space Usage              GE                             85                             GE                             97
14 rows selected.
The metrics are not there anymore and hopefully the alerts neither. This behavior is also noted for “Average Users Waiting Counts” metric, if you are receiving considerable white noise for this metric you can disable as well following the same procedure. A good practice is to create a Monitoring template to help you modify these thresholds for multiple targets at once.
Stay tuned for my next post about reducing OEM 12c noise.
Thanks,

Alfredo

Upgrade Oracle Enterprise Manager to 12.1.0.4

Enterprise Manager 12.1.0.4 was just released and now is time to test and document the process. The official documentation can be obtained from here (http://docs.oracle.com/cd/E24628_01/upgrade.121/e22625/upgrading_12101_PS1_gtgstrtd.htm) and this document cover the steps I followed and may not work on yours (I’m not responsible of any issues/problems caused to your system).
This document covers Oracle Enterprise Manager upgrade from 12.1.0.3 to 12.1.0.4 version in a Single-OMS configuration using one system upgrade method and is divided in 3 sections describing prerequisites, upgrade and post upgrade tasks.


Prerequisites


  • Download the software from (http://www.oracle.com/technetwork/oem/enterprise-manager/downloads/index.html) on your server and extract it to a stage directory.


mkdir /stage
unzip em12104_linux64_disk1.zip -d /stage
unzip em12104_linux64_disk2.zip -d /stage
unzip em12104_linux64_disk3.zip -d /stage


  • Ensure that you have a valid OMS (middleware home & inventory), Repository and Software Library backup.
  • If you have BI Publisher installed, then stop BIP server through WebLogic Admin Console.
  • Drop any snapshot created against Repository tables.


SQL> select master , log_table from all_mview_logs where log_owner=’SYSMAN’


no rows selected


  • Check and compile invalid objects in the Repository schema.


SQL> select ‘alter ‘||object_type||’ ‘||owner||’.’||object_name||’ compile;’ from all_objects
 2  where status=’INVALID’;


no rows selected


  • Execute privileges on DBMS_RANDOM are required during the upgrade, run the below commands to set them.


SQL> grant execute on DBMS_RANDOM to DBSNMP;
SQL> grant execute on DBMS_RANDOM to SYSMAN;
SQL> revoke execute on DBMS_RANDOM from PUBLIC;


  • Copy the emkey from OMS to the Management Repository.


$ emctl config emkey -copy_to_repos
Oracle Enterprise Manager Cloud Control 12c Release 3
Copyright (c) 1996, 2013 Oracle Corporation.  All rights reserved.
Enter Enterprise Manager Root (SYSMAN) Password :
The EMKey has been copied to the Management Repository. This operation will cause the EMKey to become unsecure.
After the required operation has been completed, secure the EMKey by running “emctl config emkey -remove_from_repos”.



  • Stop OMS, extended instances and both OMS and Repository agents.


$ emctl extended oms jvmd stop -all
Oracle Enterprise Manager Cloud Control 12c Release 3
Copyright (c) 1996, 2013 Oracle Corporation.  All rights reserved.
Please enter the SYSMAN password:
Stopping all Engines
{}
No engines found for this operation
Emctl Extended verb failed. Please check /u01/app/oracle/gc_inst/em/EMGC_OMS1/sysman/log/emctl.log for more details


$ emctl extended oms adp stop -all
Oracle Enterprise Manager Cloud Control 12c Release 3
Copyright (c) 1996, 2013 Oracle Corporation.  All rights reserved.
Please enter the SYSMAN password:
Stopping all Engines
{}
No engines found for this operation
Emctl Extended verb failed. Please check /u01/app/oracle/gc_inst/em/EMGC_OMS1/sysman/log/emctl.log for more details


$ emctl stop oms -all
Oracle Enterprise Manager Cloud Control 12c Release 3
Copyright (c) 1996, 2013 Oracle Corporation.  All rights reserved.
Stopping WebTier…
WebTier Successfully Stopped
Stopping Oracle Management Server…
Oracle Management Server Successfully Stopped
AdminServer Successfully Stopped
Oracle Management Server is Down


$ ./emctl stop agent
Oracle Enterprise Manager Cloud Control 12c Release 3
Copyright (c) 1996, 2013 Oracle Corporation.  All rights reserved.
Stopping agent ….. stopped.


Upgrade

  • Run the runInstaller executable from the folder where the software was extracted.


$ cd /stage
$ ./runInstaller



  • Type My Oracle Support account details.


  • Choose if you want to search for any software updates.


  • Review and fix any prerequisite failure.


  • Choose the upgrade method, in my case One system Upgrade then select the Oracle Home.


  • Type the “NEW” Middleware Home location.


  • Type the required Repository credentials.


  • Some prerequisites failed, click Yes to let the installer fix them automatically.


  • Review the list of plug-ins that are going to be automatically upgraded.


  • Select any additional plug-ins to be deployed after the upgrade.


  • Type the required WebLogic Domain credentials.


  • Review the all the information provided and click Install.


  • Review the progress.


  • Run the required allroot.sh script as root.


  • Review the final information about the upgrade process.



  • Login to Cloud Control and verify the version. Note that some targets are marked as down, we are going to fix them in the post upgrade tasks.


  • Upgrade Oracle Management Agents (at least OMS and Repository). Go to Setup -> Manage Cloud Control -> Upgrade Agents.



  • Type a Job Name (or use the default name) and click Add to select the agents you want to upgrade to 12.1.0.4.
  • Select the agents from the list and click OK.


  • Choose credentials and click Submit. There’s the option to schedule the upgrade for later under Additional Inputs.



  • You must run the root.sh script after the upgrade, click OK.


  • Review the agent upgrade process.



  • Agent upgrade was successful.


Post Upgrade

Deleting the Old OMS Home is an optional task, however I have decided to perform it in order to save space and have a clean Inventory.


  • Invoke the installer from the old OMS home


$ export ORACLE_HOME=/u01/app/oracle/oms12cr3/oms
$ /oui/bin/runInstaller -deinstall



  • Select only the OMS-related plug-ins homes (from the Old Home only!!) and click Remove.


  • Select the Java Development Kit JDK home and click Remove.


  • Select the Oracle WebTier home and click Remove. After finishing the deinstall click Close.


  • Finally select the OMS home & the Oracle Common directories and click Remove.


All targets marked up.

Thanks,
Alfredo

Oracle Recursive Sessions ORA-00018

Today I want to talk about Oracle Database session usage; last week there was a problem with a database reporting ORA-00018: maximum number of sessions exceeded, but the number of sessions from v$session was much less than the one specified in SESSIONS parameter.
So, what was going on?
Turns out this is explained by internal recursive sessions that also account but they are not seen in the dictionary views. Note ID 419130.1 explains this in detail but I wanted to see this behavior in my 12c test database.
SQL> select count(*) from v$session;
  COUNT(*)
———-
       104
SQL> select count(*) from x$ksuse where bitand(ksspaflg,1) !=0 ;
  COUNT(*)
———-
       132
Also wanted to know what sessions were recursive and seems like all of them are performing DDL operations.
SQL> select INDX,decode(bitand(ksuseflg,19),17,’BACKGROUND’,1,’USER’,2,’RECURSIVE’,’?’),ksuudsna from x$ksuse s WHERE decode(bitand(ksuseflg,19),17,’BACKGROUND’,1,’USER’,2,’RECURSIVE’,’?’)=’RECURSIVE’;
      INDX DECODE(BIT KSUUDSNA
———- ———- ——————————
         8 RECURSIVE  SYS
        11 RECURSIVE  SYS
        14 RECURSIVE  SYS
        15 RECURSIVE  SYS
        17 RECURSIVE  SYS
        19 RECURSIVE  SYS
        20 RECURSIVE  SYS
        21 RECURSIVE  SYS
        29 RECURSIVE  SYS
        32 RECURSIVE  SYS
        38 RECURSIVE  SYS
        39 RECURSIVE  SYS
        40 RECURSIVE  SYS
        42 RECURSIVE  SYS
       123 RECURSIVE  SYS
       126 RECURSIVE  SYS
       129 RECURSIVE  SYS
       134 RECURSIVE  SYS
       136 RECURSIVE  SYS
       137 RECURSIVE  SYS
       138 RECURSIVE  SYS
       139 RECURSIVE  SYS
       142 RECURSIVE  SYS
       144 RECURSIVE  SYS
       145 RECURSIVE  SYS
       148 RECURSIVE  SYS
       154 RECURSIVE  SYS
       155 RECURSIVE  SYS
       156 RECURSIVE  SYS
       157 RECURSIVE  SYS
       242 RECURSIVE  SYS
       247 RECURSIVE  SYS
       249 RECURSIVE  SYS
       250 RECURSIVE  SYS
       252 RECURSIVE  SYS
       253 RECURSIVE  SYS
       255 RECURSIVE  SYS
       257 RECURSIVE  SYS
       259 RECURSIVE  SYS
       264 RECURSIVE  SYS
       265 RECURSIVE  SYS
       269 RECURSIVE  SYS
       272 RECURSIVE  SYS
       273 RECURSIVE  SYS
       275 RECURSIVE  SYS
       276 RECURSIVE  SYS
       278 RECURSIVE  SYS
       367 RECURSIVE  SYS
       369 RECURSIVE  SYS
       371 RECURSIVE  SYS
       375 RECURSIVE  SYS
       376 RECURSIVE  SYS
       379 RECURSIVE  SYS
       381 RECURSIVE  SYS
       383 RECURSIVE  SYS
       384 RECURSIVE  SYS
       388 RECURSIVE  SYS
       389 RECURSIVE  SYS
       391 RECURSIVE  SYS
       392 RECURSIVE  SYS
60 rows selected.
This is something to keep in mind when setting SESSIONS parameter in future.
Thanks,

Alfredo

Extract AWR data to build Response Time graphs (awrrtsys.sql)

This SQL script extract AWR data required to perform Response Time analysis for Oracle Databases. All information about it will be presented in the IOUG Collaborate 2014 session “553: Oracle Database Performance: Are Database Users Telling Me The Truth?”
–#********************************************************************
–#– Filename           : awrrtsys.sql
–#– Author             : Alfredo Krieg
–#– Original           : 17-Oct-12
–#– Last Update        : 21-Ago-13
–#– Description        : awrrtsys.sql- System Response time per snapshot in the last x days
–#                        per desired unit of work –
–#– Usage              : start awrrtsys.sql
–#– This script use AWR data (licensing is required)
–#********************************************************************
set termout on
set feedback off
set heading on
set linesize 150
set pagesize 100
set feedback off verify off
col snap_id           format  999999     heading “Snapshot Id”
col instance_number   format  99         heading “Instance Number”
col snap_time         format  a25        heading “Snap Begin Time”
col non_idle_wait     format  9999999.99 heading “Qt (s)”
col cpu_time          format  9999999.99 heading “St (s)”
col lio               format  9999999.99 heading “LIO”
col pio               format  9999999.99 heading “PIO”
col uw_variable       format  9999999.99 heading “UC”
col rt_ms_per_lio     format  9999999.99 heading “RT (ms/lio)”
col rt_ms_per_pio     format  9999999.99 heading “RT (ms/pio)”
col rt_ms_per_uw      format  9999999.99 heading “RT (ms/uc)”
SELECT a.SNAP_ID,
         b.instance_number,
         TO_CHAR (END_INTERVAL_TIME, ‘mon/dd/yyyy HH24:mi’) AS snap_time,
         non_idle_wait,
         background_cpu+
         db_cpu as cpu_time,
         lio,
         pio,
         uwvariable AS UW_VARIABLE,
         ROUND (
            ( ( (background_cpu + db_cpu) / lio) + (non_idle_wait / lio))
            * 1000,
            4)
            AS RT_ms_per_lio,
         ROUND (
            ( ( (background_cpu + db_cpu) / pio) + (non_idle_wait / pio))
            * 1000,
            4)
            AS RT_ms_per_pio,
         ROUND (
            ( ( (background_cpu + db_cpu) / (uwvariable))
             + (non_idle_wait / (uwvariable)))
            * 1000,
            4)
            AS RT_ms_per_uw
    FROM ( 
    SELECT SNAP_ID,
                   SUM (non_idle_wait) AS non_idle_wait,
                   ROUND (SUM (background_cpu), 0) AS background_cpu,
                   ROUND (SUM (db_cpu), 0) AS db_cpu,
                   SUM (lio) AS lio,
                   SUM (pio) AS pio,
                   SUM (uwvariable) AS uwvariable
              FROM (
              SELECT SNAP_ID,
                           ROUND (time_secs, 0) non_idle_wait,
                           0 AS background_cpu,
                           0 AS db_cpu,
                           0 AS lio,
                           0 AS pio,
                           0 AS uwvariable
                      FROM (  SELECT snap_id,
                                     ‘WAIT’ AS wait_class,
                                     ‘Non Idle’ AS name,
                                     (SUM (VALUE) – SUM (value1)) / 1000000
                                        AS time_secs
                                FROM (  SELECT snap_id,
                                               0 AS snap2,
                                               SUM (time_waited_micro) AS VALUE,
                                               0 AS value1
                                          FROM dba_hist_system_event
                                         WHERE wait_class ‘Idle’
                                      GROUP BY snap_id
                                      UNION
                                        SELECT snap_id + 1,
                                               snap_id,
                                               0,
                                               SUM (time_waited_micro) AS value1
                                          FROM dba_hist_system_event
                                         WHERE wait_class ‘Idle’
                                      GROUP BY snap_id)
                            GROUP BY snap_id)
                    UNION
                      SELECT snap_id,
                             0,
                             (SUM (VALUE) – SUM (value1)) / 1000000
                                AS background_cpu,
                             0,
                             0,
                             0,
                             0                       
                        FROM (SELECT snap_id,
                                     0 AS snap2,
                                     stat_name,
                                     VALUE,
                                     0 AS value1
                                FROM dba_hist_sys_time_model
                               WHERE stat_name IN (‘background cpu time’)
                              UNION
                              SELECT snap_id + 1,
                                     snap_id,
                                     stat_name,
                                     0,
                                     VALUE AS value1
                                FROM dba_hist_sys_time_model
                               WHERE stat_name IN (‘background cpu time’))
                    GROUP BY snap_id, stat_name
                    UNION
                      SELECT snap_id,
                             0,
                             0,
                             (SUM (VALUE) – SUM (value1)) / 1000000 AS db_cpu,
                             0,
                             0,
                             0                          
                        FROM (SELECT snap_id,
                                     0 AS snap2,
                                     stat_name,
                                     VALUE,
                                     0 AS value1
                                FROM dba_hist_sys_time_model
                               WHERE stat_name IN (‘DB CPU’)
                              UNION
                              SELECT snap_id + 1,
                                     snap_id,
                                     stat_name,
                                     0,
                                     VALUE AS value1
                                FROM dba_hist_sys_time_model
                               WHERE stat_name IN (‘DB CPU’))
                    GROUP BY snap_id, stat_name
                    UNION
                      SELECT snap_id,
                             0,
                             0,
                             0,
                             SUM (VALUE) – SUM (value1) AS lio,
                             0,
                             0                           
                        FROM (SELECT snap_id,
                                     0 AS snap2,
                                     stat_name,
                                     VALUE,
                                     0 AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘session logical reads’)
                              UNION
                              SELECT snap_id + 1,
                                     snap_id,
                                     stat_name,
                                     0,
                                     VALUE AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘session logical reads’))
                    GROUP BY snap_id, stat_name
                    UNION
                      SELECT snap_id,
                             0,
                             0,
                             0,
                             0,
                             SUM (VALUE) – SUM (value1) AS pio,
                             0                           
                        FROM (SELECT snap_id,
                                     0 AS snap2,
                                     stat_name,
                                     VALUE,
                                     0 AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘physical reads’)
                              UNION
                              SELECT snap_id + 1,
                                     snap_id,
                                     stat_name,
                                     0,
                                     VALUE AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘physical reads’))
                    GROUP BY snap_id, stat_name
                    UNION
                      SELECT snap_id,
                             0,
                             0,
                             0,
                             0,
                             0,
                             SUM (VALUE) – SUM (value1) AS uwvariable                          
                        FROM (SELECT snap_id,
                                     0 AS snap2,
                                     stat_name,
                                     VALUE,
                                     0 AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘&1’)
                              UNION
                              SELECT snap_id + 1,
                                     snap_id,
                                     stat_name,
                                     0,
                                     VALUE AS value1
                                FROM DBA_HIST_SYSSTAT
                               WHERE stat_name IN (‘&1’))
                    GROUP BY snap_id, stat_name
                    )
          GROUP BY snap_id
            HAVING SUM (background_cpu) >= 0
          ORDER BY snap_id DESC) a, DBA_HIST_SNAPSHOT B
   WHERE a.SNAP_ID = b.SNAP_ID AND BEGIN_INTERVAL_TIME > SYSDATE – &2

ORDER BY 1;