SecurID® Governance & Lifecycle Recipes

SecurID Governance & Lifecycle recipes is a collection of items, to help you get the most out of your product deployment. For example, a useful report with the SQL to implement or a way to achieve some advanced rule processing.

RSA IGL Recipes: Report - Review Results - Review Summary Info

RSA IGL Version: V 7.2.x

Modules: Governance

Product Area: Tabular Reports - Dynamic (Applied to Review Results Object Dashboard)

Associated Dashboard:   

Time to apply: ~20 minutes

Summary

This report provides key information about the review and overall stats/metrics that may be useful to know at a highlevel. 

The goal of this report is to provide quick access to key information. 

The report can be used by Review owners or the admin team to better understand the review overall and share key metrics to other stakeholders.

This report will only work when it is applied dynamically to the Review Results object dashboard.

Other useful links

 

Example Image (Click to enlarge)

pastedImage_2.png

 

Key Notes

  • This chart/report/dashboard is supplied "as is" - any modification of this item is done at your own risk. 
  • If you have issues applying this chart/report/dashboard, please comment below for help, DO NOT contact the RSA Support team.
  • If you would like more assistance with this chart/report/dashboard or for help in creating other chart/report/dashboards, then RSA Professional Services (RSA PS) is available to help.
    • Please contact your RSA Account Manager or local RSA Sales Rep or reply below for further assistance.

 

Details

This report includes various key data points about the review, to provide a high-level review summary.

 

Report Dynamic Values

The following value needs to be used when creating the report, however the value will update dyncamilly when used within the dashboard.

  • TargetObjectID: This is used dynamically within the review itself, the value will automatically be updated, whenever you view a new review result. When viewing the report, you need to give it some value, so it can work against something. Please go to a review you have and find its "OID". Use this value in the TargetObjectID, so the report has something to use. 

How to find an Example Target Object ID:

  • Go to Review/Results
  • Select any review (pick one that has been worked on, so there are some results)
  • Once the review is open, look at the URL.
  • The value you want is found just after "OID=" and then before the "&"
  • In this example, the value we want is 25
    pastedImage_12.png

 

Report SQL

First test this in your query tool (SQLDeveloper, Toad etc..)

(select
'Review Status' as Status,
State as Total
from avuser.pv_review
where id=:TargetObjectId
UNION ALL
select
'Review Type' as Status,
CASE review_type
when 'User' then 'User Access'
when 'Account' then 'Account Access'
when 'GlobalRole' then 'Role Definition'
when 'UserGroup' then 'Group Definition'
when 'dataresource' then 'Data Resource Ownership' -- to be validated
End as Total
from avuser.pv_review
where id=:TargetObjectId
UNION ALL
select
'Start Date' as Status,
to_char(creation_date) as total
from avuser.pv_review
where id=:TargetObjectId
UNION ALL
select
'End Date' as Status,
CASE
when end_date is null then 'Not Specified'
else to_char(end_date)
end as Total
from avuser.pv_review
where id=:TargetObjectId
UNION ALL
select distinct
'' as Status,
'' as Total
From avuser.pv_review
UNION ALL
SELECT -- Gives you the total distinct reviewees
'Total ' || DECODE(pR.review_type,'User','Users','Account','Accounts','GlobalRole','Roles','UserGroup','Groups','dataresource','Data Resources') as Status,
to_char(Count(distinct tRC.Reviewee_ID)) as total
FROM avuser.pv_review pR
JOIN avuser.pv_review_component tRC
ON pR.id=:TargetObjectId
AND pR.id = tRC.review_id
GROUP BY pR.review_type
UNION ALL
SELECT -- Gives you the total applications overall
'Total Applications' as Status,
to_char(Count(distinct tRC.ASSOC_APP_ID)) as total
FROM Avuser.pv_review_component tRC
WHERE tRC.Review_ID =:TargetObjectId
UNION ALL
select -- Gives you the total reviewers overall
'Total Reviewers' as Status,
to_char(Count(distinct tRC.Covering_User_ID)) as total
from avuser.pv_REVIEW_COVERAGE tRC
WHERE tRC.Rev_ID =:TargetObjectId
and lower(tRC.role_type) <> 'monitor'
UNION ALL
SELECT -- Gives you the total entitlments overall
'Total Items' as Status,
to_char(Count(1)) as total
FROM Avuser.pv_review_component tRC
WHERE tRC.Review_ID =:TargetObjectId
UNION ALL
SELECT -- Gives you the total entitlments with state = maintain
'Total Maintain' as Status,
to_char(Count(1)) as total
FROM Avuser.pv_review_component tRC
WHERE lower(tRC.State) = 'maintain'
AND tRC.Review_ID =:TargetObjectId
UNION ALL
SELECT -- Gives you the total entitlments with state = revoke
'Total Revoke' as Status,
to_char(Count(1)) as total
FROM Avuser.pv_review_component tRC
WHERE lower(tRC.State) = 'revoke'
AND tRC.Review_ID =:TargetObjectId
UNION ALL
SELECT -- Gives you the total entitlments that are NOT reviewed
'Total None' as Status,
to_char(Count(1)) as total
FROM Avuser.pv_review_component tRC
WHERE lower(tRC.State) = 'none'
AND tRC.Review_ID =:TargetObjectId
UNION ALL
SELECT -- Gives you the total entitlments that with violations
'Violation Count' as Status,
to_char(Count(1)) as total
FROM Avuser.pv_review_component tRC
WHERE tRC.Review_ID =:TargetObjectId
AND tRC.Violation_Count > 0
UNION ALL
select
'Total Reassigns' as Total,
to_char(count(1)) as total
FROM avuser.pv_REVIEW_DELEGATION tRD
JOIN Avuser.pv_review_component tRC
ON tRD.review_component_id = tRC.ID
WHERE tRC.Review_ID =:TargetObjectId)‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍‍

 

Example of the results:

pastedImage_4.png

 

Report Implementation

  1. Log into RSA IGL as a user who can create reports. In my example, im using AveksaAdmin
  2. Go to "Reports" / "Tabular"
  3. Select "+ Create Report" button
    pastedImage_5.png
  4. Under the "General Tab" add the following details:
    • Name: Review Results - Review Summary Info
    • Title: Review Summary Info
    • Description: From RSA IGL Link Community. This report provide key information on the review. The report is dynamic and only works when applied within a "review results" object dashboard.
    • Scope: System
    • Page Size: Note
    • Orientation: Portrait
      pastedImage_6.png

  5. Under the "Query" Tab, copy the SQL from above
  6. Update the TargetObjectID as noted above
  7. In the bottom bar, press the "Style" button. "Slate" is a good recommendation for reports
    pastedImage_14.png
  8. Press the "Preview" button, you should see some results, as per the example image below.
    If you get an error at this stage, please test your SQL in a Query tool, like "SQL Developer" or "SQL Squirrel" to ensure it works first. 
    If it still doesn't work, please share your SQL and a screen shot of the issue below. DO NOT contact RSA Support 
    pastedImage_4.png
  9. Under the "Columns" Tab, please use the configuration shown in the image below
    pastedImage_11.png

  10. Under the "Display Attributes" tab, please use the configuration shown in the image below
    pastedImage_13.png
  11. Nothing has been set on the "Filter", "Grouping & Sorting" or "Schedule and Email" tabs

 

Next Steps

 

Dont forget:

Please login, then "Like"  and "Actions/Follow" this page (Top Right), so as to receive updates and be notified if we modify/change items found here, in future.

pastedImage_4.png

Labels (1)
No ratings
Version history
Last update:
‎2020-11-27 12:41 PM
Updated by:
Contributors
Article Dashboard