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: AFX Telemetry - Fulfillment Trending

RSA IGL Version: V 7.2.x

Modules: Governance

Product Area: Charts, Multiple Series (Applied to Home/AFX Telemetry Summary Dashboard)

Associated Dashboards:

Time to apply: ~30 minutes

 

Summary

This chart provides key information about the AFX fulfillment within your environment.  The chart uses data found in: avuser.PV_TELEMETRY_DATA. This means the data is always 1 day behind.

The goal of this chart is to understand how AFX is being used within your RSA IGL deployment. 

The chart can be used by admins to help understand if action is needed with AFX connectors and the amount of work that is automated with AFX.

 

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 chart displays the total fulfillment items completed. 

As this chart uses the telemetry data found within v7.2x, some of the historical data trends wont be available, if you have upgraded from an older RSA IGL version. 

 

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 'Monthly'
    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 'Monthly' then you might want to set "TotalDataPoints" = 6, showing you the results for the past 6 months. 
     For this chart, the recommendation is to use 12, 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 
    tFulfilmentRequestsCompleted.starttime,
    tFulfilmentRequestsCompleted.value as "Fulfilment Requests Completed",
    tFulfilmentRequestsFailed.value as "Fulfilment Requests Failed",
	tFulfilmentRequestsTotal.value as "Fulfilment Requests Total",
	tProvisioningCRNotCompleted.value as "Provisioning CR Not Completed"
from
    (
        SELECT
            TO_CHAR(Tdates.dates, DECODE(trim( :GROUPING ) , 'Daily', 'YYYY-Mon-DD', 'Weekly', 'YYYY - "Week "WW', :GROUPING , 'YYYY - Month', 'Quarterly', 'YYYY - "Q"Q', 'Yearly', 'YYYY')) StartTime,
            nvl(sum(td.value), 0) VALUE
        FROM
            (
            SELECT
            CASE
                    WHEN :GROUPING = 'Daily' THEN trunc(sysdate-1, 'DD') - (LEVEL-1)
                    WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
                    WHEN :GROUPING = :GROUPING THEN ADD_MONTHS(trunc(sysdate-1, 'MM'),-1 *(LEVEL-1))
                    WHEN :GROUPING = 'Quarterly' THEN ADD_MONTHS(trunc(sysdate-1, 'Q'),-3 *(LEVEL-1))
                    WHEN :GROUPING = 'Yearly' THEN ADD_MONTHS(trunc(sysdate-1, 'Y'),-:TotalDataPoints *(LEVEL-1))
                END dates
            FROM
                dual
            CONNECT BY
                LEVEL <= :TotalDataPoints 
            ) Tdates
           LEFT JOIN avuser.PV_TELEMETRY_DATA td 
                on td.CATEGORY = 'afx'
                 AND td.NAME =('fulfillmentrequests.completed.today')
                   AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D', :GROUPING ,'MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
        GROUP BY Tdates.dates
        ORDER BY Tdates.dates ASC
    ) tFulfilmentRequestsCompleted
left join 
    (
		SELECT
            TO_CHAR(Tdates.dates, DECODE(trim( :GROUPING ) , 'Daily', 'YYYY-Mon-DD', 'Weekly', 'YYYY - "Week "WW', :GROUPING , 'YYYY - Month', 'Quarterly', 'YYYY - "Q"Q', 'Yearly', 'YYYY')) StartTime,
            nvl(sum(td.value), 0) VALUE
        FROM
            (
            SELECT
            CASE
                    WHEN :GROUPING = 'Daily' THEN trunc(sysdate-1, 'DD') - (LEVEL-1)
                    WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
                    WHEN :GROUPING = :GROUPING THEN ADD_MONTHS(trunc(sysdate-1, 'MM'),-1 *(LEVEL-1))
                    WHEN :GROUPING = 'Quarterly' THEN ADD_MONTHS(trunc(sysdate-1, 'Q'),-3 *(LEVEL-1))
                    WHEN :GROUPING = 'Yearly' THEN ADD_MONTHS(trunc(sysdate-1, 'Y'),-12 *(LEVEL-1))
                END dates
            FROM
                dual
            CONNECT BY
                LEVEL <= :TotalDataPoints 
            ) Tdates
           LEFT JOIN avuser.PV_TELEMETRY_DATA td 
                on td.CATEGORY = 'afx'
                 AND td.NAME =('fulfillmentrequests.failed.today')
                AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D', :GROUPING ,'MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
        GROUP BY Tdates.dates
        ORDER BY Tdates.dates ASC
    ) tFulfilmentRequestsFailed
on tFulfilmentRequestsCompleted.StartTime = tFulfilmentRequestsFailed.starttime
left join 
    (
		SELECT
            TO_CHAR(Tdates.dates, DECODE(trim( :GROUPING ) , 'Daily', 'YYYY-Mon-DD', 'Weekly', 'YYYY - "Week "WW', :GROUPING , 'YYYY - Month', 'Quarterly', 'YYYY - "Q"Q', 'Yearly', 'YYYY')) StartTime,
            nvl(sum(td.value), 0) VALUE
        FROM
            (
            SELECT
            CASE
                    WHEN :GROUPING = 'Daily' THEN trunc(sysdate-1, 'DD') - (LEVEL-1)
                    WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
                    WHEN :GROUPING = :GROUPING THEN ADD_MONTHS(trunc(sysdate-1, 'MM'),-1 *(LEVEL-1))
                    WHEN :GROUPING = 'Quarterly' THEN ADD_MONTHS(trunc(sysdate-1, 'Q'),-3 *(LEVEL-1))
                    WHEN :GROUPING = 'Yearly' THEN ADD_MONTHS(trunc(sysdate-1, 'Y'),-12 *(LEVEL-1))
                END dates
            FROM
                dual
            CONNECT BY
                LEVEL <= :TotalDataPoints 
            ) Tdates
           LEFT JOIN avuser.PV_TELEMETRY_DATA td 
                on td.CATEGORY = 'afx'
                 AND td.NAME =('fulfillmentrequests.today')
                AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D', :GROUPING ,'MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
        GROUP BY Tdates.dates
        ORDER BY Tdates.dates ASC
    ) tFulfilmentRequestsTotal
on tFulfilmentRequestsCompleted.StartTime = tFulfilmentRequestsTotal.starttime
left join 
    (
		SELECT
            TO_CHAR(Tdates.dates, DECODE(trim( :GROUPING ) , 'Daily', 'YYYY-Mon-DD', 'Weekly', 'YYYY - "Week "WW', :GROUPING , 'YYYY - Month', 'Quarterly', 'YYYY - "Q"Q', 'Yearly', 'YYYY')) StartTime,
            nvl(sum(td.value), 0) VALUE
        FROM
            (
            SELECT
            CASE
                    WHEN :GROUPING = 'Daily' THEN trunc(sysdate-1, 'DD') - (LEVEL-1)
                    WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
                    WHEN :GROUPING = :GROUPING THEN ADD_MONTHS(trunc(sysdate-1, 'MM'),-1 *(LEVEL-1))
                    WHEN :GROUPING = 'Quarterly' THEN ADD_MONTHS(trunc(sysdate-1, 'Q'),-3 *(LEVEL-1))
                    WHEN :GROUPING = 'Yearly' THEN ADD_MONTHS(trunc(sysdate-1, 'Y'),-12 *(LEVEL-1))
                END dates
            FROM
                dual
            CONNECT BY
                LEVEL <= :TotalDataPoints 
            ) Tdates
           LEFT JOIN avuser.PV_TELEMETRY_DATA td 
                on td.CATEGORY = 'afx'
                 AND td.NAME =('provisioningcompleted.cractivitynotcompleted.today')
                AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D', :GROUPING ,'MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
        GROUP BY Tdates.dates
        ORDER BY Tdates.dates ASC
    ) tProvisioningCRNotCompleted
on tFulfilmentRequestsCompleted.StartTime = tProvisioningCRNotCompleted.starttime
 )

 

Example of the results:

pastedImage_2.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: AFX Telemetry - Fulfillment Trending
    • Description: From RSA IGL Link Community. This chart provides information on total AFX fulfillment. This chart uses data from avuser.PV_TELEMETRY_DATA which is collected nightly, so the data is always 1 day behind.
    • Type = Multiple Series Chart
      pastedImage_5.png

  5. Under the "Query" Tab, copy the SQL from above
  6. Update the 2 dynamic values as noted above, recommendation:
    Grouping: 'Monthly'
    TotalDataPoints: 12
  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_4.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
    - You can also manually specify a color for each value if you require
    pastedImage_6.png

  9. Under the "Display Attributes" tab, you should select "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: AFX Fulfillment Trending
      • Sub Caption: Total Items
      • X Axis Name: Date
      • Y Axis Name: Total
        pastedImage_8.png
    • Under "Functional attributes"
      • Select "Animation" = ticked
      • Select "Show Labels"  = ticked
      • Select "Show Values" = ticked
      • Select "Rotate Values" = ticked
      • Select "Slant 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_12.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_9.png

 

Next Steps

  • Please "hit reply" and share your feedback - we would love to see an image of this working in your environment!
  • Check out the other content found on the RSA IGL Recipes page: RSA Identity Governance &amp; Lifecycle Recipes 

     

    Thank you! 

 

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:
‎2022-08-05 04:12 PM
Updated by:
Article Dashboard