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 - Application - Application Account & Orphan Trending

RSA IGL Version: V 7.2.x

Modules: Governance

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

Associated Dashboard: RSA IGL Recipes : Dashboard - Application Summary 

Time to apply: ~30 minutes

 

Summary

This chart provides key information about the accounts for a selected application. 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 trending of total accounts and the total orphans, for applications. 

The chart can be used by application owners or the admin team to monitor accounts. This could be helpful for managing total orphans, to ensure that the potential risk of these orphan accounts managed. 

This chart will only work when it is applied dynamically to the Application 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 chart includes the following key information, you can click the chart legend to show/hide results: 

  • Total Accounts = The total number of accounts for this application. This includes orphan accounts. This does not include deleted accounts.
  • Total Orphans = The total number of all orphan accounts for this application

 

Chart Dynamic Values

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

  • TargetObjectID: This is used dynamically within the application itself, the value will automatically be updated, whenever you view an application. When viewing the chart, you need to give it some value, so it can work against something. Please go to an application 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 Resources/Applications
  • Select any application (pick one that has multiple accounts and some orphans)
  • Once the application 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 14
    pastedImage_4.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 'Monthly' or 'Quarterly'
    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 anything between 6 and 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 
    tTotalAcc.StartTime,
    tTotalAcc.Value as "Total Accounts",
    tTotalOrph.Value as "Total Orphans"
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,
                nvl(count(pA.ID), 0) VALUE
            FROM
                (
                SELECT
                CASE
                        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_ACCOUNT pA ON
                pA.application_id =:TargetObjectID
                AND pA.deletion_date IS NULL
                AND 
                trunc(pA.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 
            )
    ) tTotalAcc
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,
                nvl(count(pA.ID), 0) VALUE
            FROM
                (
                SELECT
                CASE
                        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_ACCOUNT pA ON
                pA.orphaned_date IS NOT NULL
                AND pA.application_id =:TargetObjectID
                AND pA.deletion_date IS NULL
                AND trunc(pA.orphaned_date, DECODE(:GROUPING , 'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) <= Tdates.dates
            GROUP BY
                Tdates.dates
            ORDER BY
                Tdates.dates ASC 
            )
    ) tTotalOrph
on tTotalOrph.StartTime = tTotalAcc.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: Application - Account & Orphan Trending
    • Description: From RSA IGL Link Community. This chart provides information on the total accounts and total orphan accounts for a selected application. The chart is dynamic and only works when applied within an "application" object dashboard.
    • Type = Multiple Series Chart
      pastedImage_3.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_5.png

  8. Under the "Columns" Tab, please use the configuration shown in the image below.
    Notes: 
    - You can update the display name if required.
    - 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 column 2D". Please also apply these settings, however you can update the wording with what is best for you.
    • Under "Title and Axis Names"
      • Caption: Account Trending
      • Sub Caption: Shows the trending of total accounts and total orphan accounts. Recommendation: Manage and monitor orphan accounts
      • X Axis Name: Date
      • Y Axis Name: Total
        pastedImage_7.png

    • Under "Functional attributes"
      • Select "Animation" = ticked
      • "Palette" = 1
      • Select "Show Labels"  = ticked
      • Select "Show Values" = ticked
      • Label Display = WRAP
      • Select "Rotate labels" = ticked
      • Select "Slant labels" = ticked
        pastedImage_11.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_13.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:
‎2022-08-03 09:22 AM
Updated by:
Article Dashboard