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
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.
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.
This is how you can configure the chart, so it is useful for how you wish to view the data
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:
We strongly recommend you do not specify too many values for "TotalDataPoints" otherwise it will not display well
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:
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
There are MANY other "display attributes" you can play with on this screen, so please update and make changes as you see fit.
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.