93 lines
2.9 KiB
SQL
93 lines
2.9 KiB
SQL
SET @INIT_DATE = '{init_date}';
|
|
SET @FINISH_DATE = '{finish_date}';
|
|
|
|
DELETE FROM USR_REPORTING WHERE `YEAR` >= DATE_FORMAT(CAST(@INIT_DATE AS DATE), '%Y')
|
|
AND `MONTH` >= DATE_FORMAT(CAST(@INIT_DATE AS DATE), '%m')
|
|
AND `YEAR` <= DATE_FORMAT(CAST(@FINISH_DATE AS DATE), '%Y')
|
|
AND `MONTH` <= DATE_FORMAT(CAST(@FINISH_DATE AS DATE), '%m');
|
|
|
|
INSERT INTO USR_REPORTING (
|
|
USR_UID,
|
|
TAS_UID,
|
|
PRO_UID,
|
|
MONTH,
|
|
YEAR,
|
|
TOTAL_QUEUE_TIME_BY_TASK,
|
|
TOTAL_TIME_BY_TASK,
|
|
TOTAL_CASES_IN,
|
|
TOTAL_CASES_OUT,
|
|
USER_HOUR_COST,
|
|
AVG_TIME,
|
|
SDV_TIME,
|
|
CONFIGURED_TASK_TIME,
|
|
TOTAL_CASES_OVERDUE,
|
|
TOTAL_CASES_ON_TIME,
|
|
PRO_COST,
|
|
PRO_UNIT_COST
|
|
)
|
|
|
|
SELECT
|
|
ACV.USR_UID,
|
|
ACV.TAS_UID,
|
|
ACV.PRO_UID,
|
|
DATE_FORMAT(ACV.DEL_DELEGATE_DATE, '%m') AS `MONTH`,
|
|
DATE_FORMAT(ACV.DEL_DELEGATE_DATE, '%Y') AS `YEAR`,
|
|
SUM(ACV.DEL_QUEUE_DURATION*24) AS TOTAL_QUEUE_TIME_BY_TASK,
|
|
SUM(ACV.DEL_DURATION*24) AS TOT_TIME_BY_TASK,
|
|
COUNT(ACV.DEL_DELEGATE_DATE) AS TOT_CASES_IN,
|
|
COUNT(ACV.DEL_FINISH_DATE) AS TOT_CASES_OUT,
|
|
NULL,
|
|
AVG(DEL_DURATION*24) AS `AVG_TIME`,
|
|
STD(DEL_DURATION*24) AS `STD_TIME`,
|
|
NULL,
|
|
count(if(ACV.DEL_DELAY_DURATION > 0, 1, NULL)) AS TOTAL_CASES_OVERDUE,
|
|
count(if(ACV.DEL_DELAY_DURATION <= 0, 1, NULL)) AS TOTAL_CASES_ON_TIME,
|
|
0,
|
|
NULL
|
|
FROM
|
|
APPLICATION
|
|
INNER JOIN APP_DELEGATION AS ACV ON
|
|
APPLICATION.APP_NUMBER=ACV.APP_NUMBER AND
|
|
APPLICATION.PRO_UID=ACV.PRO_UID
|
|
WHERE
|
|
(ACV.DEL_DELEGATE_DATE BETWEEN CAST(@INIT_DATE AS DATETIME) AND CAST(@FINISH_DATE AS DATETIME))
|
|
AND ACV.DEL_DELEGATE_DATE IS NOT NULL
|
|
GROUP BY ACV.USR_UID , ACV.TAS_UID, DATE_FORMAT( ACV.DEL_DELEGATE_DATE, '%m' ) , DATE_FORMAT( ACV.DEL_DELEGATE_DATE, '%Y' ) ;
|
|
|
|
DELETE USR_REPORTING
|
|
FROM USR_REPORTING
|
|
INNER JOIN TASK ON TASK.TAS_UID = USR_REPORTING.TAS_UID
|
|
WHERE TASK.TAS_TYPE NOT IN ('NORMAL', 'ADHOC');
|
|
|
|
UPDATE USR_REPORTING
|
|
INNER JOIN
|
|
USERS
|
|
ON USR_REPORTING.USR_UID = USERS.USR_UID
|
|
SET USR_REPORTING.USER_HOUR_COST = USERS.USR_COST_BY_HOUR;
|
|
|
|
UPDATE USR_REPORTING
|
|
INNER JOIN
|
|
PROCESS
|
|
ON USR_REPORTING.PRO_UID = PROCESS.PRO_UID
|
|
SET USR_REPORTING.PRO_COST = PROCESS.PRO_COST,
|
|
USR_REPORTING.PRO_UNIT_COST = PROCESS.PRO_UNIT_COST;
|
|
|
|
UPDATE USR_REPORTING
|
|
INNER JOIN TASK ON USR_REPORTING.TAS_UID = TASK.TAS_UID
|
|
SET USR_REPORTING.CONFIGURED_TASK_TIME =
|
|
IF(TASK.TAS_TIMEUNIT = "DAYS",
|
|
(TASK.TAS_DURATION *
|
|
(IF ((SELECT CA.CALENDAR_UID FROM CALENDAR_ASSIGNMENTS AS CA WHERE CA.OBJECT_UID = TASK.TAS_UID limit 1) IS NOT NULL,
|
|
(SELECT AVG(TIMEDIFF(STR_TO_DATE(CBH.CALENDAR_BUSINESS_END, '%H:%i'), STR_TO_DATE(CBH.CALENDAR_BUSINESS_START, '%H:%i')))/10000
|
|
FROM CALENDAR_ASSIGNMENTS AS CA, CALENDAR_BUSINESS_HOURS AS CBH
|
|
WHERE CA.OBJECT_UID = TASK.TAS_UID
|
|
AND CA.CALENDAR_UID = CBH.CALENDAR_UID
|
|
GROUP BY CA.CALENDAR_UID LIMIT 1) ,24)))
|
|
,
|
|
(IF(TASK.TAS_TIMEUNIT = "MINUTES",
|
|
(TASK.TAS_DURATION /60)
|
|
,TASK.TAS_DURATION))
|
|
)
|
|
|
|
|