Wednesday, June 18, 2008

Oracle EM Grid Control - Custom Reports

Creating Custom Grid Report for database availability

Oracle Enterprise Manager GRID Server contains built in reports to support Database Administrators to generate sightly reports. However, in my company, we need some reports that cannot be find in GRID and needs custom development. Here is how i did it.

First Thing is to click to "Reports" tab on the top, right hand side of the GRID Management Console (figure_grid_management_console). This page is where all the predefined and custom reports can be find. Now click on the "Create" Button on top of the page to create a new custom report. "Create Report Definition" page comes to the screen. There are four tabs for the definition of the report.

General
After specifiying title of the report then select category and subcategory from the comboboxes. Category and subcategory defines our newly custom report's group and standing place in the reports list of the GRID reports page. You can also create new categories by clicking the buttons between the comboboxes.

Targets section enables you to limit the available list of target selection while generating the report or you can select a specified target to be used. I used "Specified Target" and left the textbox blank because this report will apply to all database and rac targets and is not allowed to be changed.

You can enable to select time periods by end user or you can preset the time period from the "Time Period" section (figure_create_report_general_tab). This custom report always displays the last known and most updated state of the databases uptimes and downtimes.

Elements
In the Elements tab, you can define the report elements and their positions in the report page (figure_add_elements_1). Report elements are structures that displays selected data from the GRID Servers repository. Click "Add" Button to add elements. I used IPMSG_USER_CHART_FROM_SQL and IPMSG_USER_TABLE_FROM_SQL elements (figure_add_elements_2). Click on the "Set Parameters" icon on the right hand side of the listed items to obtain a statement for the elements (figure_add_elements_2). Here you can enter the sql statement that brings data into the element from Management Servers repository. Following you can find the sql statements for the elements.

IPMSG_USER_TABLE_FROM_SQL

select
target_name,
target_type,
sum(up_time) up_time,
sum(down_time) down_time,
sum(blackout_time) blackout_time,
trunc(sum(up_time)/(sum(nvl(up_time,1))+sum(nvl(down_time,1)))*100) availability_pct
from
(
select
target_name,
target_type,
sum(trunc((nvl(end_timestamp,sysdate)-start_timestamp)*24)) total_hours,
case availability_status
when 'Target Down' then
0
when 'Target Up' then
0
when 'Blackout' then
sum(trunc((nvl(end_timestamp,sysdate)-start_timestamp)*24))
end blackout_time,
case availability_status
when 'Target Down' then
0
when 'Target Up' then
sum(trunc((nvl(end_timestamp,sysdate)-start_timestamp)*24))
when 'Blackout' then
0
end up_time,
case availability_status
when 'Target Down' then
sum(trunc((nvl(end_timestamp,sysdate)-start_timestamp)*24))
when 'Target Up' then
0
when 'Blackout' then
0
end down_time,
availability_status
from
MGMT$AVAILABILITY_HISTORY
where
target_type in ('oracle_database','rac_database') and
availability_status in ('Target Down','Target Up','Blackout')
group by
target_name, target_type, availability_status
order by target_name, availability_status
)
group by target_name, target_type
order by target_name

--sample output:

TARGET_NAME TARGET_TYPE UP_TIME DOWN_TIME BLACKOUT_TIME AVAILABILITY_PCT
----------- ----------- ------- --------- ------------- ----------------
ACTV rac_database 4823 0 1 100
ACTV_ACTV1 oracle_database 4823 0 1 100
ACTV_ACTV2 oracle_database 3964 0 1 100
ARCH.AVEA.COM oracle_database 3334 0 0 100
ARCHCM oracle_database 2210 1126 0 66
ARCHDB rac_database 3858 0 653 100
ARCHDB_ARCHDB1 oracle_database 3514 31 652 99
ARCHDB_ARCHDB2 oracle_database 3725 0 652 100
ASPDB oracle_database 1750 2 0 99
...


IPMSG_USER_CHART_FROM_SQL

select
availability_status,
sum(trunc((end_timestamp-start_timestamp)*24)) total_hours
from
MGMT$AVAILABILITY_HISTORY
where
target_type in ('oracle_database','rac_database') and
availability_status in ('Target Down','Target Up','Blackout')
group by
availability_status

--sample output:

AVAILABILITY_STATUS TOTAL_HOURS
------------------- -----------
Target Up 130008
Target Down 2086
Blackout 2405


Schedule
You can schedule a report to be emailed to an email by setting schedules (figure_schedule_tab).

Access
Report creator can define user groups or users who will be allowed to access this report. Here i used user groups (figure_access_tab).

Database availability report is now ready for managers

10 comments:

  1. Thanks a lot ... its very userful.

    However, the report period is not specified in the query. How do we specify the period.

    eg: If manaement wants only monthly report (30 days)

    ReplyDelete
  2. Hello.... THanks for the post is very useful... I need to know what version of grid control that are you using... because I don´t have the type port element in the picture... (picture 2)...


    Thanks

    ReplyDelete
  3. Hi juanjo,

    Current grid control version is 10.2.0.5 But as far as i remember, Element tab is also available in version 10.2.0.4.

    ReplyDelete
  4. Reddy,

    There should be "this reports has time period" option in the first step of job creation. Check this image

    There is a small sample report sql that uses this time period (??EMIP_BIND_START_DATE?? and ??EMIP_BIND_END_DATE??)

    Maybe I should write an individual post for this subject.

    select

    t2.AGGREGATE_TARGET_NAME AGGREGATE_TARGET_NAME,

    sum(trunc((nvl(t1.end_timestamp,sysdate)-t1.start_timestamp)*24)) total_time

    from

    MGMT$AVAILABILITY_HISTORY t1 LEFT JOIN MGMT$TARGET_FLAT_MEMBERS t2 ON (t1.TARGET_GUID = t2.MEMBER_TARGET_GUID)

    where

    member_target_type in ('oracle_database','rac_database') and

    member_target_name not in (

    select member_target_name from MGMT$TARGET_FLAT_MEMBERS

    where aggregate_target_type='rac_database' ) and

    availability_status in ('Target Up','Target Down','Blackout') and

    t2.AGGREGATE_TARGET_NAME like '%_PRIMARY' and

    ((t1.start_timestamp >= ??EMIP_BIND_START_DATE?? and

    t1.start_timestamp <= ??EMIP_BIND_END_DATE??) OR end_timestamp is null)

    group by

    t2.AGGREGATE_TARGET_NAME ;

    ReplyDelete
  5. I want a report which should list all database targets alongwith the version of database, listening port , oracle_home etc. Actually I want the output of "databases" tab in the OEM console in the form of report. is it possible? can you table which tables can I join to mgmt$target?

    ReplyDelete
  6. Nice work. I'm delving into the Enterprise Manager Repository mself. Check out http://wp.me/p1RG2x-1N

    regards,

    Seamus

    ReplyDelete
  7. Here's how to import or view that data in Excel or some other Microsoft Office application for that matter.

    http://www.bearsbreeches.com/bearpress/2012/03/06/how-to-import-enterprise-manager-data-into-excel-and-create-attractive-looking-graphs-and-charts/

    ReplyDelete
  8. I found this blog very helpful.Is there a way to create customized time series graph with multiple nodes for avg cpu utilization because the metric detail element gives the graph with max cpu utilization.
    Please see the below query that i am using:

    select target_name HOSTNAME,to_char(rollup_timestamp,'dd-mon-yy HH24:MI') TIMESTAMP,
    round(avg(MINIMUM),2) MINIMUM,round(avg(MAXIMUM),2) MAXIMUM,round(avg(AVERAGE),2) AVERAGE
    from sysman.mgmt$metric_hourly where TARGET_NAME like 'bde7db%' and METRIC_COLUMN like'cpuUtil'
    and rollup_timestamp between sysdate-1 and sysdate
    group by target_name,rollup_timestamp order by 2,1

    ReplyDelete
  9. I am getting a error message that divisor is equal to zero

    ReplyDelete
  10. Thanks a million + 1,
    Your query helped me a lot :)

    ReplyDelete