DROP function IF EXISTS `vn`.`clientGetSalesPerson`; DELIMITER $$ CREATE DEFINER=`root`@`%` FUNCTION `vn`.`clientGetSalesPerson`(vClientFk INT, vDated DATE) RETURNS int(11) DETERMINISTIC BEGIN /** * Dado un id cliente y una fecha, devuelve su comercial para ese dia, teniendo * en cuenta la jerarquía de las tablas: 1º la de sharingClient, 2º la de * sharingCart y tercero la de clientes. * * @param vClientFk El id del cliente * @param vDated Fecha a comprobar * @return El id del comercial para la fecha dada **/ DECLARE vSalesperson INT DEFAULT NULL; DECLARE vSubstitute INT DEFAULT NULL; DECLARE vLoop BOOLEAN; -- Obtiene el comercial original y el de sharingClient SELECT c.salesPersonFk, s.workerFk INTO vSalesperson, vSubstitute FROM client c LEFT JOIN sharingClient s ON c.id = s.clientFk AND vDated BETWEEN s.started AND s.ended WHERE c.id = vClientFk ORDER BY s.id LIMIT 1; -- Si no hay ninguno en sharingClient busca en sharingCart IF vSubstitute IS NOT NULL THEN SET vSalesperson = vSubstitute; ELSEIF vSalesperson IS NOT NULL THEN DROP TEMPORARY TABLE IF EXISTS tmp.stack; CREATE TEMPORARY TABLE tmp.stack (INDEX (substitute)) ENGINE = MEMORY SELECT vSalesperson substitute; l: LOOP SELECT workerSubstitute INTO vSubstitute FROM sharingCart WHERE vDated BETWEEN started AND ended AND workerFk = vSalesperson ORDER BY id LIMIT 1; IF vSubstitute IS NULL THEN LEAVE l; END IF; SELECT COUNT(*) > 0 INTO vLoop FROM tmp.stack WHERE substitute = vSubstitute; IF vLoop THEN LEAVE l; END IF; INSERT INTO tmp.stack SET substitute = vSubstitute; SET vSalesperson = vSubstitute; END LOOP; DROP TEMPORARY TABLE tmp.stack; END IF; RETURN vSalesperson; END$$ DELIMITER ;