RSA IGL Version: V 7.2.x
Modules: Governance
Product Area: Tabular Reports - Dynamic (Applied to Review Results Object Dashboard)
Time to apply: ~20 minutes
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.
This report includes various key data points about the review, to provide a high-level review summary.
The following value needs to be used when creating the report, however the value will update dyncamilly when used within the dashboard.
How to find an Example Target Object ID:
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:
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
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.