RSA IGL Version: V 7.2.x
Modules: Governance
Product Area: Charts, Multiple Series (Applied to Topic/Access Request Dashboard)
Associated Dashboard:
Time to apply: ~30 minutes
This chart provides key information about Workflow (WF) Forms 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 the different types of forms within the environment.
The chart can be used by admins to understand the status of different forms overall.
This chart displays info on the total number of each different Workflow Form Type.
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
tProvOOO.starttime,
tProvOOO.value as "Provisioning Out Of Office",
tProv.value as "Provisioning",
tDRS.value as "Data Resouce Set",
tRP.value as "Password Reset",
tApp.value as "Application",
tProvAb.Value as "Provisioning Absence",
tRS.value as "Role Set",
tEV.value as "Entitlement View",
tGlobal.Value as "Global",
tProvTerm.value as "Provisioning Termination",
tDir.Value as "Directory",
tCA.value as "Create Account"
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(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.ProvisioningOutOfOffice')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tProvOOO
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.Provisioning')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tProv
on tProvOOO.StartTime = tProv.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.DataResourceSet')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tDRS
on tProvOOO.StartTime = tDRS.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.ResetPassword')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tRP
on tProvOOO.StartTime = tRP.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.Application')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tApp
on tProvOOO.StartTime = tApp.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.ProvisioningAbsence')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tProvAb
on tProvOOO.StartTime = tProvAb.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.RoleSet')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tRS
on tProvOOO.StartTime = tRS.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.EntitlementView')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tEV
on tProvOOO.StartTime = tEV.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.Global')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tGlobal
on tProvOOO.StartTime = tGlobal.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.ProvisioningTermination')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tProvTerm
on tProvOOO.StartTime = tProvTerm.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.Directory')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tDir
on tProvOOO.StartTime = tDir.starttime
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,
/*
Use count(t1.value) to count the number of rows based on your filters
Use max(t1.value) to getAR the maximum value on the specific date
Use sum(t1.value) to get the collective total of values on the specific date
*/
nvl(max(td.value), 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-1, 'DD') - (LEVEL-1)
WHEN :GROUPING = 'Weekly' THEN trunc(sysdate-1, 'D') - (7 * (LEVEL-1))
WHEN :GROUPING = 'Monthly' 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 = 'accessrequest'
AND td.NAME =('formbytype.type.CreateAccount')
/*
Use = to get values at the exact dates.
Use <= to get values on or before the exact date
*/
AND trunc(td."DAY", DECODE(:GROUPING ,'Daily','DD','Weekly','D','Monthly','MM','Quarterly','Q','Yearly','Y')) = Tdates.dates
GROUP BY Tdates.dates
ORDER BY Tdates.dates ASC
) tCA
on tProvOOO.StartTime = tCA.starttime
)
Example of the results:
Note: for some reason, results do not show in the UI for my demo enviroment, however everything works on the other screens and gives the expected results we need. The results do show in SQL Developer.
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.