DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`workerTimeControl_sendMailByDepartment`(IN vDatedFrom DATETIME, IN vDatedTo DATETIME, IN vWorkerFk INT)
BEGIN
/**
 * Inserta el registro de horario semanalmente de PRODUCCION, CAMARA, REPARTO, TALLER NATURAL y TALLER ARTIFICIAL en vn.mail.
 *
 * @param vDatedFrom
 * @param vDatedTo
 * @param vWorkerFk -> En el caso de querer generarlo para todos los empleados deberá de pasarse = NULL
 */
	SET session group_concat_max_len = 15000;

	DROP TEMPORARY TABLE IF EXISTS tmp.timeControlCalculate;
	DROP TEMPORARY TABLE IF EXISTS tmp.timeBusinessCalculate;
	DROP TEMPORARY TABLE IF EXISTS tmp.reportHours;

	IF vWorkerFk IS NULL THEN
		CALL timeControl_calculateAll(vDatedFrom,vDatedTo);
		CALL timeBusiness_calculateAll(vDatedFrom,vDatedTo);
	ELSE
		CALL timeControl_calculateByUser(vWorkerFk,vDatedFrom,vDatedTo);
		CALL timeBusiness_calculateByUser(vWorkerFk,vDatedFrom,vDatedTo);
	END IF;

	CREATE TEMPORARY TABLE tmp.reportHours
		SELECT  t.dated,
				IF (tm.hoursWeek IS NULL,'', GROUP_CONCAT(DATE_FORMAT(wtc.timed,'%H:%i') ORDER BY wtc.timed ASC SEPARATOR ' ') ) timeWorkDay,
				SEC_TO_TIME(IFNULL(tm.timeWorkSeconds, 0)) tm,
				SEC_TO_TIME(IFNULL(tc.timeWorkSeconds, 0)) tc,
				SEC_TO_TIME(IFNULL(tc.timeWorkSeconds, 0) - IFNULL(tm.timeWorkSeconds, 0)) balance,
				w.lastName,
				w.firstname,
				c.fi,
				w.id userFk,
				MONTHNAME(t.dated) mes,
				YEAR(t.dated) año,
				w.id,
				tm.hoursWeek,
				tm.type,
				b.started,
				b.ended,
				d.name,
				tm.businessFk
			FROM time t
				LEFT JOIN tmp.timeBusinessCalculate tm ON tm.dated = t.dated
				LEFT JOIN tmp.timeControlCalculate tc ON tc.dated = tm.dated AND tc.userFk = tm.userFk
				LEFT JOIN vn.workerTimeControl wtc ON wtc.userFk = tm.userFk AND DATE(wtc.timed) = t.dated
				LEFT JOIN business b ON  b.workerFk = tm.userFk AND b.id = tm.businessFk
				LEFT JOIN workCenter wc ON wc.id  = b.workcenterFk
				LEFT JOIN department d ON d.id = b.departmentFk
				LEFT JOIN worker w ON w.id = tm.userFk
				LEFT JOIN client c ON c.id = w.id
				WHERE wc.name NOT IN ('VNH')
					AND d.hasToSendMail
					AND w.businessFk
				GROUP BY tm.userFk,t.dated
				ORDER BY tm.userFk,t.dated;
	
	INSERT INTO vn.mail (receiver, replyTo, subject, body)
		SELECT eu.email, 'laboral@verdnatura.es', CONCAT('Registro de horas semana ', WEEK(vDatedFrom), ' año ', YEAR(vDatedFrom)) ,
				CONCAT('
				<!DOCTYPE html>
				<html>

				<head>
					<style>
						hr { margin-left: 50px;
							margin-right: 50px;}

						.result {font-weight:bold;
								padding-top: 25px;}
					</style>
				<body>
					<div align="center">
					<h2>REGISTRO DE LA JORNADA DE LOS TRABAJADORES</h2>
					<table cellpadding="5" cellspacing="2" width="60%" style="color: #153643; font-family: " Trebuchet MS"; font-size:18px; line-height: 18px;">
						<tr>
							<td align="center" colspan="5">
								Según la información recogida en el sistema, adjuntamos la tabla con los registros. Cualquier incidencia rogamos la comunique a <b>laboral@verdnatura.es</b>.
								<br> De no recibir incidencia por su parte, se entenderá que el registro es correcto. <br>
							</td>
						</tr>
						<tr>
							<td> <b>Empresa: </b> Verdnatura Levante SL</td>
						</tr>
						<tr>
							<td> <b>Trabajador: </b> ',rh.firstname,' ',rh.lastName, '</td>
							<td> <b> NIF: </b> ',rh.fi, '</td>
						</tr>
						<tr>
							<td> <b> AÑO: </b> ',rh.año, '</td>
							<td> <b> MES: </b> ',UPPER(rh.mes), '</td>
							<td> <b> Calendario Laboral: </b>',rh.hoursWeek,' horas semanales </td>
						</tr>
					</table>
					<hr>
					<table cellpadding="5" cellspacing="2" width="60%" style="color: #153643; font-family: " Trebuchet MS"; font-size:18px; line-height: 18px;">
						<tr>
							<td bgcolor="#8ebb27" align="center">Fecha:</td>
							<td bgcolor="#8ebb27" align="center">Día:</td>
							<td bgcolor="#8ebb27" align="center">Fichadas:</td>
							<td bgcolor="#8ebb27" align="center">Horas a trabajar:</td>
							<td bgcolor="#8ebb27" align="center">Horas trabajadas:</td>
							<td bgcolor="#8ebb27" align="center">Balance:</td>
						</tr>',
						GROUP_CONCAT(DISTINCT '<tr> <td bgcolor="#8ebb27" align="center">', DATE_FORMAT( rh.dated, '%d-%m-%y'),
								 '</td> <td align="center">', CONCAT(UCASE(LEFT(DAYNAME(rh.dated), 1)), SUBSTRING(DAYNAME(rh.dated), 2)),
		                         '</td> <td align="center"> ', IFNULL(rh.timeWorkDay,' '),' ', IFNULL(rh.type,' '),
		                         '</td> <td align="center">', rh.tm,
		                         '</td> <td align="center">', SUBSTRING_INDEX(rh.tc, '.', 1),
		                         '</td> <td align="center">', SUBSTRING_INDEX(rh.balance, '.', 1), '</td></tr>' ORDER BY rh.dated SEPARATOR ''),
							'<td align="center"></td>
							<td align="center"></td>
							<td align="center"></td>
							<td class="result" align="right"><b>Total horas trabajadas: </b></td>
							<td class="result" align="center"><b>', SUBSTRING_INDEX(SEC_TO_TIME(SUM(TIME_TO_SEC(rh.tc))), '.', 1),'</b></td>
							<td class="result" align="center"><b>', SUBSTRING_INDEX(SEC_TO_TIME(SUM(TIME_TO_SEC(rh.balance))), '.', 1),'</b></td>
						</tr>
					</table>
				</body>')
			FROM tmp.reportHours rh
			JOIN account.emailUser eu ON rh.id = eu.userFk
		    GROUP BY rh.id;

	DROP TEMPORARY TABLE tmp.timeControlCalculate;
	DROP TEMPORARY TABLE tmp.timeBusinessCalculate;
	DROP TEMPORARY TABLE tmp.reportHours;
END$$
DELIMITER ;