Flight plan queries
You can use the queries in this article to create data visualizations similar to those in Enhanced Analytics.
IMPORTANT
Queries will produce similar results to those shown in Enhanced Analytics, but they may not match exactly.
Prerequisites
Before you begin, you must
-
Establish a connection with your Business Intelligence (BI) tool:
Once you establish a connection, you can use the queries in this article to extract and visualize data.
Project planned hours adjustments (within date range)
WITH VALID_PROJECTS AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽 plannedstartdate as projectplannedstartdate,
聽聽聽聽聽聽聽 plannedcompletiondate as projectplannedcompletiondate,
聽聽聽聽聽聽聽 actualstartdate as projectactualstartdate,
聽聽聽聽聽聽聽 actualcompletiondate as projectactualcompletiondate,
聽聽聽聽聽聽聽 condition as projectcondition,
聽聽聽聽聽聽聽 name as projectname,
聽聽聽聽聽聽聽 status,
聽聽聽聽聽聽聽 groupid,
聽聽聽聽聽聽聽 conditiontype,
聽聽聽聽聽聽聽 calendardate as snapshotdate
聽聽聽 FROM PROJECTS_DAILY_HISTORY
聽聽聽 WHERE nvl(trim(deleted),'-1') != '1'
聽聽聽聽聽聽聽 AND (
聽聽聽聽聽聽聽聽聽聽聽 to_date(actualcompletiondate) > '2021-01-01'
聽聽聽聽聽聽聽聽聽聽聽 OR actualcompletiondate is NULL
聽聽聽聽聽聽聽 )
), VALID_CUSTOMENUMS AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 distinct valueasstring,
聽聽聽聽聽聽聽 groupid,
聽聽聽聽聽聽聽 enumclass,
聽聽聽聽聽聽聽 equateswith,
聽聽聽聽聽聽聽 label,
聽聽聽聽聽聽聽 calendardate
聽聽聽 FROM CUSTOMENUMS_DAILY_HISTORY
), VALID_TASKS AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽 taskid,
聽聽聽聽聽聽聽 plannedminutes,
聽聽聽聽聽聽聽 planneddurationminutes,
聽聽聽聽聽聽聽 completedminutes,
聽聽聽聽聽聽聽 completedplannedminutes,
聽聽聽聽聽聽聽 completedplanneddurationminutes,
聽聽聽聽聽聽聽 taskcompleted,
聽聽聽聽聽聽聽 numberofchildren,
聽聽聽聽聽聽聽 snapshotdate,
聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽 WHEN actualcompletiondate is not NULL or percentcomplete = '100' or status='CPL' THEN 0
聽聽聽聽聽聽聽聽聽聽聽 ELSE plannedminutes - completedplannedminutes
聽聽聽聽聽聽聽 END as remainingminutes,
聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽 WHEN actualcompletiondate is not NULL or percentcomplete = '100' or status='CPL' THEN 0
聽聽聽聽聽聽聽聽聽聽聽 ELSE planneddurationminutes - completedplanneddurationminutes
聽聽聽聽聽聽聽 END as remainingdurationminutes
聽聽聽 FROM (
聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽 a.projectid,a.taskid,
聽聽聽聽聽聽聽聽聽聽聽 a.actualcompletiondate,
聽聽聽聽聽聽聽聽聽聽聽 a.percentcomplete,
聽聽聽聽聽聽聽聽聽聽聽 a.numberofchildren,
聽聽聽聽聽聽聽聽聽聽聽 a.plannedminutes,
聽聽聽聽聽聽聽聽聽聽聽 a.planneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽 a.completedminutes,
聽聽聽聽聽聽聽聽聽聽聽 a.completedplannedminutes,
聽聽聽聽聽聽聽聽聽聽聽 a.completedplanneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽 a.snapshotdate,
聽聽聽聽聽聽聽聽聽聽聽 a.status,
聽聽聽聽聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 WHEN a.actualcompletiondate is not NULL or a.percentcomplete = '100' or a.status='CPL' THEN 1
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 ELSE 0
聽聽聽聽聽聽聽聽聽聽聽 END as taskcompleted
聽聽聽聽聽聽聽 FROM (
聽聽聽聽聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 distinct
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.projectid,t.taskid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.actualcompletiondate,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.percentcomplete,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.numberofchildren,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.workrequired as plannedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.plannedDurationMinutes as planneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.actualwork as completedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 round((t.workrequired * t.percentcomplete)/100) as completedplannedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 round((t.plannedDurationMinutes * t.percentcomplete)/100) as completedplanneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.groupid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.status,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.calendardate as snapshotdate
聽聽聽聽聽聽聽聽聽聽聽 FROM TASKS_DAILY_HISTORY t
聽聽聽聽聽聽聽聽聽聽聽 WHERE nvl(trim(t.deleted),'-1') != '1'
聽聽聽聽聽聽聽 ) a
聽聽聽聽聽聽聽 INNER JOIN valid_projects v ON (a.projectid = v.projectid AND a.snapshotdate = v.snapshotdate)
聽聽聽 )
), VALID_ISSUES AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽 optaskid,
聽聽聽聽聽聽聽 plannedminutes,
聽聽聽聽聽聽聽 planneddurationminutes,
聽聽聽聽聽聽聽 completedminutes,
聽聽聽聽聽聽聽 completedplannedminutes,
聽聽聽聽聽聽聽 completedplanneddurationminutes,
聽聽聽聽聽聽聽 issueresolved,
聽聽聽聽聽聽聽 calendardate as snapshotdate,
聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽 WHEN actualcompletiondate is not NULL or percentcomplete = '100' or equateswith='CLS' or (equateswith='CLS' and status='CLS') THEN 0
聽聽聽聽聽聽聽聽聽聽聽 ELSE plannedminutes - completedplannedminutes
聽聽聽聽聽聽聽 END as remainingminutes,
聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽 WHEN actualcompletiondate is not NULL or percentcomplete = '100' or equateswith='CLS' or (equateswith='CLS' and status='CLS') THEN 0
聽聽聽聽聽聽聽聽聽聽聽 ELSE planneddurationminutes - completedplanneddurationminutes END as remainingdurationminutes
聽聽聽 FROM (
聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽聽聽聽聽 optaskid,
聽聽聽聽聽聽聽聽聽聽聽 actualcompletiondate,
聽聽聽聽聽聽聽聽聽聽聽 equateswith,
聽聽聽聽聽聽聽聽聽聽聽 plannedminutes,
聽聽聽聽聽聽聽聽聽聽聽 planneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽 percentcomplete,
聽聽聽聽聽聽聽聽聽聽聽 completedminutes,
聽聽聽聽聽聽聽聽聽聽聽 status,
聽聽聽聽聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 WHEN actualcompletiondate is not NULL or percentcomplete = '100' or equateswith = 'CLS' or (equateswith='CLS' and status='CLS') THEN 1
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 ELSE 0
聽聽聽聽聽聽聽聽聽聽聽 END as issueresolved,
聽聽聽聽聽聽聽聽聽聽聽 round((plannedminutes * percentcomplete)/100) as completedplannedminutes,
聽聽聽聽聽聽聽聽聽聽聽 round((planneddurationminutes * percentcomplete)/100) as completedplanneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽 calendardate
聽聽聽聽聽聽聽 FROM (
聽聽聽聽聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.projectid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.optaskid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.actualcompletiondate,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 ce.equateswith,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.plannedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.planneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.completedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.calendardate,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 a.status,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 CASE
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 WHEN a.percentcomplete is not null THEN a.percentcomplete
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 WHEN a.actualcompletiondate is not NULL or a.percentcomplete = '100' or ce.equateswith='CLS' or (ce.equateswith='CLS' and a.status='CLS') THEN 100
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 ELSE 0
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 END as percentcomplete
聽聽聽聽聽聽聽聽聽聽聽 FROM (
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 distinct t.projectid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.optaskid,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.actualcompletiondate,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.workrequired as plannedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.planneddurationminutes as planneddurationminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.actualworkrequired as completedminutes,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.calendardate as calendardate,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.percentcomplete,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 t.status,
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 FROM OPTASKS_DAILY_HISTORY t
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 WHERE nvl(trim(t.deleted),'-1') != '1'
聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽聽 AND t.optasktype in ('ISU','BUG')
聽聽聽聽聽聽聽聽聽聽聽 ) a
聽聽聽聽聽聽聽聽聽聽聽 INNER JOIN VALID_PROJECTS v ON (a.projectid=v.projectid AND a.calendardate = v.snapshotdate)
聽聽聽聽聽聽聽聽聽聽聽 LEFT JOIN VALID_CUSTOMENUMS ce ON (ce.valueasstring = a.status AND ce.groupid = v.groupid AND a.projectid = v.projectid AND ce.enumclass='STATUS_OPTASK' AND a.calendardate = ce.calendardate)
聽聽聽聽聽聽聽 )
聽聽聽 )
), AGGREGATE_TASKS AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽 snapshotdate,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN plannedminutes ELSE 0 END) as plannedminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN planneddurationminutes ELSE 0 END) as planneddurationminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN completedminutes ELSE 0 END) as completedminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN completedplannedminutes ELSE 0 END) as completedplannedminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN completedplanneddurationminutes ELSE 0 END) as completedplanneddurationminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN remainingminutes ELSE 0 END) as remainingminutes,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN remainingdurationminutes ELSE 0 END) as remainingdurationminutes,
聽聽聽聽聽聽聽 count(CASE WHEN numberofchildren=0 THEN taskid ELSE NULL END) as totaltaskcount,
聽聽聽聽聽聽聽 SUM(CASE WHEN numberofchildren=0 THEN taskcompleted ELSE 0 END) as totalcompletedtaskcount
聽聽聽 FROM valid_tasks
聽聽聽 GROUP BY projectid, snapshotdate
), AGGREGATE_ISSUES AS (
聽聽聽 SELECT
聽聽聽聽聽聽聽 projectid,
聽聽聽聽聽聽聽 snapshotdate,
聽聽聽聽聽聽聽 SUM(plannedminutes) as issueplannedminutes,
聽聽聽聽聽聽聽 SUM(planneddurationminutes) as issueplanneddurationminutes,
聽聽聽聽聽聽聽 SUM(completedminutes) as issuecompletedminutes,
聽聽聽聽聽聽聽 SUM(completedplannedminutes) as issuecompletedplannedminutes,
聽聽聽聽聽聽聽 SUM(completedplanneddurationminutes) as issuecompletedplanneddurationminutes,
聽聽聽聽聽聽聽 SUM(remainingminutes) as issueremainingminutes,
聽聽聽聽聽聽聽 SUM(remainingdurationminutes) as issueremainingdurationminutes,
聽聽聽聽聽聽聽 count(optaskid) as totalissuecount,
聽聽聽聽聽聽聽 SUM(issueresolved) as totalresolvedissue
聽聽聽 FROM valid_issues
聽聽聽 GROUP BY projectid, snapshotdate
)
SELECT
聽聽聽 p.projectid as projectguid,
聽聽聽 p.projectname,
聽聽聽 p.projectplannedstartdate as projectplannedstartdate,
聽聽聽 p.projectplannedcompletiondate as projectplannedcompletiondate,
聽聽聽 p.projectactualstartdate as projectactualstartdate,
聽聽聽 p.projectactualcompletiondate as projectactualcompletiondate,
聽聽聽 p.projectcondition as projectcond,
聽聽聽 coalesce(t.plannedminutes, 0) as plannedminutes,
聽聽聽 coalesce(t.planneddurationminutes, 0) as planneddurationminutes,
聽聽聽 coalesce(t.completedminutes, 0) as completedminutes,
聽聽聽 coalesce(t.completedplannedminutes, 0) as completedplannedminutes,
聽聽聽 coalesce(t.completedplanneddurationminutes,0) as completedplanneddurationminutes,
聽聽聽 coalesce(t.remainingminutes,0) as remainingminutes,
聽聽聽 coalesce(t.remainingdurationminutes, 0) as remainingdurationminutes,
聽聽聽 coalesce(cast(t.totaltaskcount as Integer),0) - coalesce(cast(pt.totaltaskcount as Integer),0) as taskaddeddaily,
聽聽聽 coalesce(cast(t.totalcompletedtaskcount as Integer),0) - coalesce(cast(pt.totalcompletedtaskcount as Integer),0) as taskcompleteddaily,
聽聽聽 coalesce(t.plannedminutes,0) - coalesce(pt.plannedminutes,0) as plannedminutesdaily,
聽聽聽 coalesce(t.planneddurationminutes,0) - coalesce(pt.planneddurationminutes,0) as planneddurationminutesdaily,
聽聽聽 coalesce(t.completedminutes,0) - coalesce(pt.completedminutes,0) as completedminutesdaily,
聽聽聽 coalesce(t.completedplannedminutes,0) - coalesce(pt.completedplannedminutes,0) as completedplannedminutesdaily,
聽聽聽 coalesce(t.completedplanneddurationminutes,0) - coalesce(pt.completedplanneddurationminutes,0) as completedplanneddurationminutesdaily,
聽聽聽 CASE
聽聽聽聽聽聽聽 WHEN ce.equateswith='CPL' THEN TRUE
聽聽聽聽聽聽聽 WHEN ce.equateswith is NULL and p.status='CPL' THEN TRUE
聽聽聽聽聽聽聽 ELSE FALSE
聽聽聽 END as iscompleted,
聽聽聽 coalesce(cast(t.totaltaskcount as Integer),0) as totaltaskcount,
聽聽聽 coalesce(cast(t.totalcompletedtaskcount as Integer),0) as totalcompletedtaskcount,
聽聽聽 coalesce(i.issueplannedminutes, 0) as issueplannedminutes,
聽聽聽 coalesce(i.issueplanneddurationminutes, 0) as issueplanneddurationminutes,
聽聽聽 coalesce(i.issuecompletedminutes, 0) as issuecompletedminutes,
聽聽聽 coalesce(i.issuecompletedplannedminutes, 0) as issuecompletedplannedminutes,
聽聽聽 coalesce(i.issuecompletedplanneddurationminutes,0) as issuecompletedplanneddurationminutes,
聽聽聽 coalesce(i.issueremainingminutes,0) as issueremainingminutes,
聽聽聽 coalesce(i.issueremainingdurationminutes, 0) as issueremainingdurationpminutes,
聽聽聽 coalesce(cast(i.totalissuecount as Integer),0) - coalesce(cast(pi.totalissuecount as Integer),0) as issueaddeddaily,
聽聽聽 coalesce(cast(i.totalresolvedissue as Integer),0) - coalesce(cast(pi.totalresolvedissue as Integer),0) as issueresolveddaily,
聽聽聽 coalesce(i.issueplannedminutes,0) - coalesce(pi.issueplannedminutes,0) as issueplannedminutesdaily,
聽聽聽 coalesce(i.issueplanneddurationminutes,0) - coalesce(pi.issueplanneddurationminutes,0) as issueplanneddurationminutesdaily,
聽聽聽 coalesce(i.issuecompletedminutes,0) - coalesce(pi.issuecompletedminutes,0) as issuecompletedminutesdaily,
聽聽聽 coalesce(i.issuecompletedplannedminutes,0) - coalesce(pi.issuecompletedplannedminutes,0) as issuecompletedplannedminutesdaily,
聽聽聽 coalesce(i.issuecompletedplanneddurationminutes,0) - coalesce(pi.issuecompletedplanneddurationminutes,0) as issuecompletedplanneddurationminutesdaily,
聽聽聽 coalesce(cast(i.totalissuecount as Integer),0) as totalissuecount,
聽聽聽 coalesce(cast(i.totalresolvedissue as Integer),0) as totalresolvedissue,
聽聽聽 convert_timezone('UTC',current_timestamp)::timestamp_ntz as dl_load_ts,
聽聽聽 ce2.equateswith as conditionequateswith,
聽聽聽 ce2.label as conditionlabel,
聽聽聽 p.status as status,
聽聽聽 ce.equateswith as statusequateswith,
聽聽聽 ce.label as statuslabel,
聽聽聽 split_part(p.status, ':', 2) as statuspending,
聽聽聽 p.conditiontype as projectconditiontype,
聽聽聽 CASE
聽聽聽聽聽聽聽 WHEN p.conditiontype = 'PG' THEN 'PROGRESS STATUS'
聽聽聽聽聽聽聽 WHEN p.conditiontype = 'MN' THEN 'MANUAL'
聽聽聽 END as projectconditiontypename
FROM valid_projects p
聽聽聽 LEFT JOIN (
聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽 customenumid,
聽聽聽聽聽聽聽聽聽聽聽 enumclass,
聽聽聽聽聽聽聽聽聽聽聽 calendardate,
聽聽聽聽聽聽聽聽聽聽聽 label,
聽聽聽聽聽聽聽聽聽聽聽 equateswith
聽聽聽聽聽聽聽 FROM CUSTOMENUMS_DAILY_HISTORY) ce ON (ce.enumclass = 'STATUS_PROJ' AND p.status = ce.label AND ce.calendardate = p.snapshotdate)
聽聽聽 LEFT JOIN aggregate_tasks t ON (p.snapshotdate = t.snapshotdate AND t.projectid = p.projectid)
聽聽聽 LEFT JOIN aggregate_issues i ON (p.snapshotdate = i.snapshotdate AND i.projectid = p.projectid)
聽聽聽 LEFT JOIN aggregate_tasks pt ON (p.snapshotdate = dateadd(days,1,pt.snapshotdate) AND p.projectid = pt.projectid)
聽聽聽 LEFT JOIN aggregate_issues pi ON (p.snapshotdate = dateadd(days,1,pi.snapshotdate) AND p.projectid = pi.projectid)
聽聽聽 LEFT JOIN (
聽聽聽聽聽聽聽 SELECT
聽聽聽聽聽聽聽聽聽聽聽 customenumid,
聽聽聽聽聽聽聽聽聽聽聽 enumclass,
聽聽聽聽聽聽聽聽聽聽聽 calendardate,
聽聽聽聽聽聽聽聽聽聽聽 label,
聽聽聽聽聽聽聽聽聽聽聽 equateswith
聽聽聽聽聽聽聽 FROM CUSTOMENUMS_DAILY_HISTORY) ce2 ON (ce2.enumclass = 'CONDITION_PROJ' AND p.projectcondition = ce2.label AND ce2.calendardate = p.snapshotdate)
recommendation-more-help
5f00cc6b-2202-40d6-bcd0-3ee0c2316b43