86 lines
3.4 KiB
SQL
86 lines
3.4 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`timeBusiness_calculate`(vDatedFrom DATETIME, vDatedTo DATETIME)
|
|
BEGIN
|
|
/**
|
|
* Horas que debe trabajar un empleado según contrato y día.
|
|
* @param vDatedFrom workerTimeControl
|
|
* @param vDatedTo workerTimeControl
|
|
* @table tmp.user(userFk)
|
|
* @return tmp.timeBusinessCalculate
|
|
*/
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.timeBusinessCalculate;
|
|
CREATE TEMPORARY TABLE tmp.timeBusinessCalculate
|
|
(INDEX (departmentFk))
|
|
SELECT dated,
|
|
businessFk,
|
|
sub.id userFk,
|
|
departmentFk,
|
|
hourStart,
|
|
hourEnd,
|
|
timeTable,
|
|
timeWorkSeconds,
|
|
SEC_TO_TIME(timeWorkSeconds) timeWorkSexagesimal,
|
|
timeWorkSeconds / 3600 timeWorkDecimal,
|
|
timeWorkSeconds timeBusinessSeconds,
|
|
SEC_TO_TIME(timeWorkSeconds) timeBusinessSexagesimal,
|
|
timeWorkSeconds / 3600 timeBusinessDecimal,
|
|
name type,
|
|
permissionRate,
|
|
hoursWeek,
|
|
discountRate,
|
|
isAllowedToWork
|
|
FROM(SELECT t.dated,
|
|
b.id businessFk,
|
|
w.id,
|
|
b.departmentFk,
|
|
IF(bs.started = NULL, NULL, GROUP_CONCAT(DISTINCT LEFT(bs.started,5) ORDER BY bs.started ASC SEPARATOR ' - ')) hourStart ,
|
|
IF(bs.started = NULL, NULL, GROUP_CONCAT(DISTINCT LEFT(bs.ended,5) ORDER BY bs.ended ASC SEPARATOR ' - ')) hourEnd,
|
|
IF(bs.started = NULL, NULL, GROUP_CONCAT(DISTINCT LEFT(bs.started,5), " - ", LEFT(bs.ended,5) ORDER BY bs.ended ASC SEPARATOR ' - ')) timeTable,
|
|
IF(bs.started = NULL, 0, IFNULL(SUM(TIME_TO_SEC(bs.ended)) - SUM(TIME_TO_SEC(bs.started)), 0)) timeWorkSeconds,
|
|
at2.name,
|
|
at2.permissionRate,
|
|
at2.discountRate,
|
|
ct.hoursWeek hoursWeek,
|
|
at2.isAllowedToWork
|
|
FROM time t
|
|
LEFT JOIN business b ON t.dated BETWEEN b.started AND IFNULL(b.ended, vDatedTo)
|
|
LEFT JOIN worker w ON w.id = b.workerFk
|
|
JOIN tmp.`user` u ON u.userFK = w.id
|
|
LEFT JOIN workCenter wc ON wc.id = b.workcenterFK
|
|
LEFT JOIN calendarType ct ON ct.id = b.calendarTypeFk
|
|
LEFT JOIN businessSchedule bs ON bs.businessFk = b.id AND bs.weekday = WEEKDAY(t.dated) + 1
|
|
LEFT JOIN calendar c ON c.businessFk = b.id AND c.dated = t.dated
|
|
LEFT JOIN absenceType at2 ON at2.id = c.dayOffTypeFk
|
|
WHERE t.dated BETWEEN vDatedFrom AND vDatedTo
|
|
GROUP BY w.id, t.dated
|
|
)sub;
|
|
|
|
UPDATE tmp.timeBusinessCalculate t
|
|
LEFT JOIN businessSchedule bs ON bs.businessFk = t.businessFk
|
|
SET t.timeWorkSeconds = t.hoursWeek / 5 * 3600,
|
|
t.timeWorkSexagesimal = SEC_TO_TIME( t.hoursWeek / 5 * 3600),
|
|
t.timeWorkDecimal = t.hoursWeek / 5,
|
|
t.timeBusinessSeconds = t.hoursWeek / 5 * 3600,
|
|
t.timeBusinessSexagesimal = SEC_TO_TIME( t.hoursWeek / 5 * 3600),
|
|
t.timeBusinessDecimal = t.hoursWeek / 5
|
|
WHERE DAYOFWEEK(t.dated) IN(2,3,4,5,6) AND bs.id IS NULL ;
|
|
|
|
UPDATE tmp.timeBusinessCalculate t
|
|
SET t.timeWorkSeconds = t.timeWorkSeconds - (t.timeWorkSeconds * permissionRate) ,
|
|
t.timeWorkSexagesimal = SEC_TO_TIME ((t.timeWorkDecimal - (t.timeWorkDecimal * permissionRate)) * 3600),
|
|
t.timeWorkDecimal = t.timeWorkDecimal - (t.timeWorkDecimal * permissionRate)
|
|
WHERE permissionRate <> 0;
|
|
|
|
UPDATE tmp.timeBusinessCalculate t
|
|
JOIN calendarHolidays ch ON ch.dated = t.dated
|
|
JOIN business b ON b.id = t.businessFk
|
|
AND b.workcenterFk = ch.workcenterFk
|
|
SET t.timeWorkSeconds = 0,
|
|
t.timeWorkSexagesimal = 0,
|
|
t.timeWorkDecimal = 0,
|
|
t.permissionrate = 1,
|
|
t.type = 'Festivo'
|
|
WHERE t.type IS NULL;
|
|
END$$
|
|
DELIMITER ;
|