RSA IGL Recipes: User Summary - Joiners & Leavers

Document created by Jamie Pryer Employee on Dec 22, 2020Last modified by Jamie Pryer Employee on Jan 14, 2021
Version 2Show Document
  • View in full screen mode

RSA IGL Version: V 7.2.x

Modules: Governance

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

Associated Dashboard:

Time to apply: ~30 minutes

 

Summary

This chart provides key information about the total Joiners & Leavers within your company. 

The goal of this chart is to understand the volume of user changes. 

The chart can be used by admins to understand what is happening within the organisation and lead onto ROI, if automation (with AFX) is applied to help with these processes.

 

Other useful links

 

Example Image (Click to enlarge)

Key Notes

  • This chart/report/dashboard is supplied "as is" - any modification of this item is done at your own risk. 
  • This chart could also be updated to include "movers", if you have a way to flag when someone has "moved". 
  • 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 number of joiners and movers, for the grouping of time specified (eg. per week).

 

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 '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 '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
    tJoiners.starttime,
    tJoiners.value as "Joiners",
    tLeavers.value as "Leavers"
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(pU.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_users pU ON
               trunc(pU.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
     ) tJoiners
left join
     (
          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(pU.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_users pU ON
               trunc(pU.termination_date, DECODE(:GROUPING , 'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
          GROUP BY
               Tdates.dates
          ORDER BY
               Tdates.dates ASC
    ) tLeavers
on tJoiners.StartTime = tLeavers.starttime)

 

Example of the results:

 

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
  4. Under the "General Tab" add the following details:
    • Name: User Summary - Joiners & Leavers
    • Description: From RSA IGL Link Community. This chart provides information the total joiners and leavers. 
    • Type = Multiple Series Chart


  5. Under the "Query" Tab, copy the SQL from above
  6. Update the 2 dynamic values as noted above, recommendation:
    Grouping: 'Weekly'
    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 


  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 colour for each value if you require


  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: Joiners & Leavers
      • X Axis Name: Date
      • Y Axis Name: Total
    • Under "Functional attributes"
      • Select "Animation" = ticked
      • Select "Show Labels"  = ticked

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

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 & 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.

 

 

Attachments

    Outcomes