salix/services/db/install/changes/1.1.0/07-agencyHourGetLanded.sql

43 lines
1.7 KiB
SQL

USE `vn`;
DROP procedure IF EXISTS `agencyHourGetLanded`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `agencyHourGetLanded`(vDated DATE, vAddress INT, vAgency INT, vWarehouse INT)
BEGIN
/**
* Devuelve una tabla temporal con el dia de recepcion para vDated.
*
* @param vDated Fecha de preparacion de mercancia
* @param vAddress Id de consignatario, %NULL para recogida
* @param vAgency Id agencia
* @table tmp.agencyHourGetLanded Datos de recepción
*/
DROP TEMPORARY TABLE IF EXISTS tmp.agencyHourGetLanded;
CREATE TEMPORARY TABLE tmp.agencyHourGetLanded
ENGINE = MEMORY
SELECT vWarehouse warehouseFk, landed FROM (
SELECT * FROM (
SELECT vWarehouse, TIMESTAMPADD(DAY, ah.substractDay, vDated) landed, ah.substractDay, ah.maxHour
FROM agencyHour ah
LEFT JOIN address a ON a.id = vAddress
WHERE (ah.weekDay = WEEKDAY(TIMESTAMPADD(DAY, ah.substractDay, vDated)) OR ah.weekDay IS NULL)
AND (ah.agencyFk = vAgency OR ah.agencyFk IS NULL)
AND ah.warehouseFk = vWarehouse
AND (ah.provinceFk = a.provinceFk OR ah.provinceFk IS NULL OR vAddress IS NULL)
ORDER BY (
(ah.weekDay IS NOT NULL) +
(ah.agencyFk IS NOT NULL) +
(- ah.substractDay) +
((ah.provinceFk IS NOT NULL)*3)
) DESC
) t
LIMIT 1
) t
WHERE IF(vDated = CURDATE(), t.maxHour > HOUR(NOW()), TRUE) AND t.substractDay < 225;
END$$
DELIMITER ;