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: Chart - Review Results - Review Progress Trending

RSA IGL Version: V 7.2.x

Modules: Governance

Product Area: Charts, Multiple Series - Dynamic (Applied to Review Results Object Dashboard)

Associated Dashboard:   

Time to apply: ~30 minutes

 

Summary

This chart provides key information about a review. It is a dynamic chart, that has flexible configuration options, allowing you to decide how you want to show and group the data displayed. 

The goal of this chart is to understand the activity of your review and what has been happening. 

The chart can be used by Review owners or the admin team to track and monitor the progress of the review. It could help with showing how useful sending review reminders were, e.g.. If you sent an email and didn't see a spike in activity, this could indicate an issue with the communication. 

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

 

Other useful links

 

Example Image (Click to enlarge)

pastedImage_4.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 chart includes the following key information, you can click the chart legend to show/hide results: 

  • Maintain (Count) = The total number of items that were set to be "maintain" for the date range specified. eg. 8 items this week have been set to maintain.
  • Maintain (Total) = The total number of items that are set to be "maintain" for the whole review so far. eg 340 items for this review are set to maintain.
  • Revoke (Count) =The total number of items that were set to be "revoke" for the date range specified. eg. 30 items this day have been set to maintain.
  • Revoke (Total) = The total number of items that are set to be "revoke" for the whole review so far. eg 340 items for this review are set to revoke.
  • Reassign/Delegation (Count) = The total number of items that were set to be either "unassigned/reassigned/delegated" for the date range specified. eg. 24 items for this week have been unassigned and reassigned.

 

Chart Dynamic Values

The following value needs to be used when creating the chart, 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 chart, 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 chart 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

 

Optional Changes to Dynamic Chart Values

This is how you can configure the chart, so it is useful for how you wish to view the data 

  • GROUPING: This allows you to group the data and display it based on the following date ranges. For example, you might want to show the data grouped per week, per quarter or per day. This will be up to you and your business needs. For this chart, the recommendation is to use 'Daily' or 'Weekly'
    You MUST ensure you use a single quote ', either side of the value, for this to work properly in the RSA IGL Chart UI.
    However, when testing this in SQL Developer, the single quote ' is NOT required.
    Please copy and paste these values exactly as shown below to change the chart:
    • 'Daily'
    • 'Weekly'
    • 'Monthly'
    • 'Quarterly'
    • 'Yearly'

 

  • TotalDataPoints: This is how many results you want to display. It is a number and doesn't need any quotes. If you set this value to be 7, it would show 7 results. For example if you set "Grouping" to be 'Daily' then you might want to set "TotalDataPoints" = 14, showing you the results for the past 14 days.
    However if you set this to be 'Weekly', then maybe setting "TotalDataPoints" to just 6 is better, showing you the past 6 weeks of data.For this chart, the recommendation is to use 10, however it will depending on the screen size you have and how this looks.

We strongly recommend you do not specify too many values for "TotalDataPoints" otherwise it will not display well

 

Chart SQL

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

(
  Select 
    tMaintain.Starttime as "Date", 
    tMaintain.Value as "Maintain (Count)", 
    tRevoke.Value as "Revoke (Count)", 
    tRevokeTotal.Value as "Revoke (Total)", 
    tMaintainTotal.Value as "Maintain (Total)", 
    tReassign.Value as "Reassign/Delegation (Count)" 
  From 
    (
      SELECT 
        * 
      FROM 
        (
          SELECT 
            TO_CHAR(
              Tdates.dates, 
              DECODE(
                trim(: GROUPING), 
                'Daily', 
                'YYYY-Mon-DD', 
                'Weekly', 
                'YYYY - "Week "WW', 
                'Monthly', 
                'YYYY - Month', 
                'Quarterly', 
                'YYYY - "Q"Q', 
                'Yearly', 
                'YYYY'
              )
            ) StartTime, 
            
            /* 
                        Use count(t1.value) to count the number of rows based on your filters
                        Use max(t1.value) to get the maximum value on the specific date
                        Use sum(t1.value) to get the collective total of values on the specific date
                        */
            nvl(
              count(pRC.ID), 
              0
            ) VALUE 
          FROM 
            (
              SELECT 
                CASE 
                /* if using avuser.PV_TELEMETRY_DATA then change sysdate to be sysdate-1. This is beacuse telemetry is calculated 1 day later */
                WHEN : GROUPING = 'Daily' THEN trunc(sysdate, 'DD') - (LEVEL -1) WHEN : GROUPING = 'Weekly' THEN trunc(sysdate, 'D') - (
                  7 * (LEVEL -1)
                ) WHEN : GROUPING = 'Monthly' THEN ADD_MONTHS(
                  trunc(sysdate, 'MM'), 
                  -1 *(LEVEL -1)
                ) WHEN : GROUPING = 'Quarterly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Q'), 
                  -3 *(LEVEL -1)
                ) WHEN : GROUPING = 'Yearly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Y'), 
                  -12 *(LEVEL -1)
                ) END dates 
              FROM 
                dual CONNECT BY LEVEL <= : TotalDataPoints
            ) Tdates 
            LEFT JOIN avuser.PV_REVIEW_COMPONENT pRC ON pRC.last_reviewed_date IS NOT NULL 
            AND pRC.review_id =: TargetObjectID 
            AND lower(pRC.state) = 'maintain' 
            /* 
                            Use = to get values at the exact dates. 
                            Use <= to get values on or before the exact date 
                            */
            AND trunc(
              pRC.last_reviewed_date, 
              DECODE(
                : GROUPING, 'Daily', 'DD', 'Weekly', 
                'D', 'Monthly', 'MM', 'Quarterly', 
                'Q', 'Yearly', 'Y'
              )
            ) = Tdates.dates 
          GROUP BY 
            Tdates.dates 
          ORDER BY 
            Tdates.dates ASC
        )
    ) tMaintain 
    left join (
      SELECT 
        * 
      FROM 
        (
          SELECT 
            TO_CHAR(
              Tdates.dates, 
              DECODE(
                trim(: GROUPING), 
                'Daily', 
                'YYYY-Mon-DD', 
                'Weekly', 
                'YYYY - "Week "WW', 
                'Monthly', 
                'YYYY - Month', 
                'Quarterly', 
                'YYYY - "Q"Q', 
                'Yearly', 
                'YYYY'
              )
            ) StartTime, 
            
            /* 
                        Use count(t1.value) to count the number of rows based on your filters
                        Use max(t1.value) to get the maximum value on the specific date
                        Use sum(t1.value) to get the collective total of values on the specific date
                        */
            nvl(
              count(pRC.ID), 
              0
            ) VALUE 
          FROM 
            (
              SELECT 
                CASE 
                /* if using avuser.PV_TELEMETRY_DATA then change sysdate to be sysdate-1. This is beacuse telemetry is calculated 1 day later */
                WHEN : GROUPING = 'Daily' THEN trunc(sysdate, 'DD') - (LEVEL -1) WHEN : GROUPING = 'Weekly' THEN trunc(sysdate, 'D') - (
                  7 * (LEVEL -1)
                ) WHEN : GROUPING = 'Monthly' THEN ADD_MONTHS(
                  trunc(sysdate, 'MM'), 
                  -1 *(LEVEL -1)
                ) WHEN : GROUPING = 'Quarterly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Q'), 
                  -3 *(LEVEL -1)
                ) WHEN : GROUPING = 'Yearly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Y'), 
                  -12 *(LEVEL -1)
                ) END dates 
              FROM 
                dual CONNECT BY LEVEL <= : TotalDataPoints
            ) Tdates 
            LEFT JOIN avuser.PV_REVIEW_COMPONENT pRC ON pRC.last_reviewed_date IS NOT NULL 
            AND pRC.review_id =: TargetObjectID 
            AND lower(pRC.state) = 'revoke' 
            /* 
                            Use = to get values at the exact dates. 
                            Use <= to get values on or before the exact date 
                            */
            AND trunc(
              pRC.last_reviewed_date, 
              DECODE(
                : GROUPING, 'Daily', 'DD', 'Weekly', 
                'D', 'Monthly', 'MM', 'Quarterly', 
                'Q', 'Yearly', 'Y'
              )
            ) = Tdates.dates 
          GROUP BY 
            Tdates.dates 
          ORDER BY 
            Tdates.dates ASC
        )
    ) tRevoke on tRevoke.starttime = tMaintain.Starttime 
    left join (
      SELECT 
        * 
      FROM 
        (
          SELECT 
            TO_CHAR(
              Tdates.dates, 
              DECODE(
                trim(: GROUPING), 
                'Daily', 
                'YYYY-Mon-DD', 
                'Weekly', 
                'YYYY - "Week "WW', 
                'Monthly', 
                'YYYY - Month', 
                'Quarterly', 
                'YYYY - "Q"Q', 
                'Yearly', 
                'YYYY'
              )
            ) StartTime, 
            
            /* 
                        Use count(t1.value) to count the number of rows based on your filters
                        Use max(t1.value) to get the maximum value on the specific date
                        Use sum(t1.value) to get the collective total of values on the specific date
                        */
            nvl(
              count(pRC.ID), 
              0
            ) VALUE 
          FROM 
            (
              SELECT 
                CASE 
                /* if using avuser.PV_TELEMETRY_DATA then change sysdate to be sysdate-1. This is beacuse telemetry is calculated 1 day later */
                WHEN : GROUPING = 'Daily' THEN trunc(sysdate, 'DD') - (LEVEL -1) WHEN : GROUPING = 'Weekly' THEN trunc(sysdate, 'D') - (
                  7 * (LEVEL -1)
                ) WHEN : GROUPING = 'Monthly' THEN ADD_MONTHS(
                  trunc(sysdate, 'MM'), 
                  -1 *(LEVEL -1)
                ) WHEN : GROUPING = 'Quarterly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Q'), 
                  -3 *(LEVEL -1)
                ) WHEN : GROUPING = 'Yearly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Y'), 
                  -12 *(LEVEL -1)
                ) END dates 
              FROM 
                dual CONNECT BY LEVEL <= : TotalDataPoints
            ) Tdates 
            LEFT JOIN avuser.PV_REVIEW_COMPONENT pRC ON pRC.last_reviewed_date IS NOT NULL 
            AND pRC.review_id =: TargetObjectID 
            AND lower(pRC.state) = 'revoke' 
            /* 
                            Use = to get values at the exact dates. 
                            Use <= to get values on or before the exact date 
                            */
            AND trunc(
              pRC.last_reviewed_date, 
              DECODE(
                : GROUPING, 'Daily', 'DD', 'Weekly', 
                'D', 'Monthly', 'MM', 'Quarterly', 
                'Q', 'Yearly', 'Y'
              )
            ) <= Tdates.dates 
          GROUP BY 
            Tdates.dates 
          ORDER BY 
            Tdates.dates ASC
        )
    ) tRevokeTotal on tRevokeTotal.starttime = tMaintain.Starttime 
    left join (
      SELECT 
        * 
      FROM 
        (
          SELECT 
            TO_CHAR(
              Tdates.dates, 
              DECODE(
                trim(: GROUPING), 
                'Daily', 
                'YYYY-Mon-DD', 
                'Weekly', 
                'YYYY - "Week "WW', 
                'Monthly', 
                'YYYY - Month', 
                'Quarterly', 
                'YYYY - "Q"Q', 
                'Yearly', 
                'YYYY'
              )
            ) StartTime, 
            
            /* 
                        Use count(t1.value) to count the number of rows based on your filters
                        Use max(t1.value) to get the maximum value on the specific date
                        Use sum(t1.value) to get the collective total of values on the specific date
                        */
            nvl(
              count(pRC.ID), 
              0
            ) VALUE 
          FROM 
            (
              SELECT 
                CASE 
                /* if using avuser.PV_TELEMETRY_DATA then change sysdate to be sysdate-1. This is beacuse telemetry is calculated 1 day later */
                WHEN : GROUPING = 'Daily' THEN trunc(sysdate, 'DD') - (LEVEL -1) WHEN : GROUPING = 'Weekly' THEN trunc(sysdate, 'D') - (
                  7 * (LEVEL -1)
                ) WHEN : GROUPING = 'Monthly' THEN ADD_MONTHS(
                  trunc(sysdate, 'MM'), 
                  -1 *(LEVEL -1)
                ) WHEN : GROUPING = 'Quarterly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Q'), 
                  -3 *(LEVEL -1)
                ) WHEN : GROUPING = 'Yearly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Y'), 
                  -12 *(LEVEL -1)
                ) END dates 
              FROM 
                dual CONNECT BY LEVEL <= : TotalDataPoints
            ) Tdates 
            LEFT JOIN avuser.PV_REVIEW_COMPONENT pRC ON pRC.last_reviewed_date IS NOT NULL 
            AND pRC.review_id =: TargetObjectID 
            AND lower(pRC.state) = 'maintain' 
            /* 
                            Use = to get values at the exact dates. 
                            Use <= to get values on or before the exact date 
                            */
            AND trunc(
              pRC.last_reviewed_date, 
              DECODE(
                : GROUPING, 'Daily', 'DD', 'Weekly', 
                'D', 'Monthly', 'MM', 'Quarterly', 
                'Q', 'Yearly', 'Y'
              )
            ) <= Tdates.dates 
          GROUP BY 
            Tdates.dates 
          ORDER BY 
            Tdates.dates ASC
        )
    ) tMaintainTotal on tMaintainTotal.starttime = tMaintain.Starttime 
    left join (
      SELECT 
        * 
      FROM 
        (
          SELECT 
            TO_CHAR(
              Tdates.dates, 
              DECODE(
                trim(: GROUPING), 
                'Daily', 
                'YYYY-Mon-DD', 
                'Weekly', 
                'YYYY - "Week "WW', 
                'Monthly', 
                'YYYY - Month', 
                'Quarterly', 
                'YYYY - "Q"Q', 
                'Yearly', 
                'YYYY'
              )
            ) StartTime, 
            
            /* 
                        Use count(t1.value) to count the number of rows based on your filters
                        Use max(t1.value) to get the maximum value on the specific date
                        Use sum(t1.value) to get the collective total of values on the specific date
                        */
            nvl(
              count(pRCC.ID), 
              0
            ) VALUE 
          FROM 
            (
              SELECT 
                CASE 
                /* if using avuser.PV_TELEMETRY_DATA then change sysdate to be sysdate-1. This is beacuse telemetry is calculated 1 day later */
                WHEN : GROUPING = 'Daily' THEN trunc(sysdate, 'DD') - (LEVEL -1) WHEN : GROUPING = 'Weekly' THEN trunc(sysdate, 'D') - (
                  7 * (LEVEL -1)
                ) WHEN : GROUPING = 'Monthly' THEN ADD_MONTHS(
                  trunc(sysdate, 'MM'), 
                  -1 *(LEVEL -1)
                ) WHEN : GROUPING = 'Quarterly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Q'), 
                  -3 *(LEVEL -1)
                ) WHEN : GROUPING = 'Yearly' THEN ADD_MONTHS(
                  trunc(sysdate, 'Y'), 
                  -12 *(LEVEL -1)
                ) END dates 
              FROM 
                dual CONNECT BY LEVEL <= : TotalDataPoints
            ) Tdates 
            LEFT JOIN avuser.PV_REVIEW_COMPONENT pRC ON pRC.review_id =: TargetObjectID 
            left join avuser.PV_REVIEW_COMPONENT_CHANGE pRCC on pRCC.Review_component_id = pRC.ID 
            AND pRC.review_id =: TargetObjectID 
            AND Operation_type in (
              'Reassign', 'Delegation', 'Remove'
            ) 
            AND trunc(
              pRCC.creation_date, 
              DECODE(
                : GROUPING, 'Daily', 'DD', 'Weekly', 
                'D', 'Monthly', 'MM', 'Quarterly', 
                'Q', 'Yearly', 'Y'
              )
            ) = Tdates.dates 
          GROUP BY 
            Tdates.dates 
          ORDER BY 
            Tdates.dates ASC
        )
    ) tReassign on tReassign.starttime = tMaintain.Starttime
)

 

Example of the results:

pastedImage_21.png

 

 

Chart Implementation

  1. Log into RSA IGL as a user who can create charts. In my example, im using AveksaAdmin
  2. Go to "Reports" / "Charts"
  3. Select "+ Create Chart" button
    pastedImage_4.png
  4. Under the "General Tab" add the following details:
    • Name: Review Results - Review Progress Trending
    • Description: From RSA IGL Link Community. This chart provides information on a review and its progress. The chart is dynamic and only works when applied within a "review results" object dashboard.
    • Type = Multiple Series Chart
      pastedImage_21.png

  5. Under the "Query" Tab, copy the SQL from above
  6. Update the 3 dynamic values as noted above, recommendation:
    Grouping: 'Daily'
    TotalDataPoints: 10
  7. 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_21.png
  8. Under the "Columns" Tab, please use the configuration shown in the image below.
    Notes:
    - You can update the display name if you need, eg. you can change "Maintain (Count)" to be "Keep (Count)".
    - You can also manually specify a color for each value if you require. 
    - You can remove any data from the chart if you need, just hit the "x" at the end of the row for each item in the series
    pastedImage_25.png

  9. Under the "Display Attributes" tab, you should select "Style = MS Line". Please also apply these settings, however you can update the wording with what is best for you.
    • Under "Title and Axis Names"
      • Caption: Review Activity
      • Sub Caption: Shows the trending of activity for the review  Count = The total for that date shown, Total = The sum total to date
      • X Axis Name: Date
      • Y Axis Name: Total
        pastedImage_27.png
    • Under "Functional attributes"
      • Select "Animation" = ticked
      • Select "Show Labels"  = ticked
      • Select "Show Values" = ticked
      • Label Display = WRAP
      • Label Step: 2 (Note: this just skips each value in the X axis display, remove this if you want to show all results, but this might not look great if you do)
        pastedImage_35.png
    • Under "Data Dataset Element
      • Select "Show Values" = Ticked
        pastedImage_26.png

There are MANY other "display attributes" you can play with on this screen, so please update and make changes as you see fit. 

pastedImage_36.png

 

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:
‎2021-11-11 04:00 PM
Updated by:
Article Dashboard