salix/db/routines/vn/procedures/agencyHourGetWarehouse.sql

79 lines
2.3 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`agencyHourGetWarehouse`(vAddress INT, vDate DATE, vWarehouse INT)
BEGIN
/**
* DEPRECATED usar zoneGetWarehouse
* Devuelve el listado de agencias disponibles para la fecha,
* dirección y warehouuse pasadas
*
* @param vAddress no puede ser NULL
* @param vWarehouse warehouse donde comprobaremos las agencias y fecha
* @param vDate Fecha de recogida
* @table agencyModeWarehouseList Listado de agencias disponibles
*/
DECLARE vAgency INT;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vCur CURSOR FOR
SELECT DISTINCT a.id
FROM agency a
JOIN agencyHour ah ON ah.agencyFk = a.id;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
IF vAddress IS NULL
THEN
CALL util.throw ('Address cannot be null');
END IF;
DROP TEMPORARY TABLE IF EXISTS tmp.agencyModeWarehouseList;
CREATE TEMPORARY TABLE tmp.agencyModeWarehouseList (
id INT NOT NULL,
agency VARCHAR(20),
description VARCHAR(45),
deliveryMethodFk VARCHAR(45),
shipped DATE,
warehouse VARCHAR(45),
PRIMARY KEY(id)
)
ENGINE = MEMORY;
OPEN vCur;
FETCH vCur INTO vAgency;
WHILE NOT vDone
DO
INSERT INTO tmp.agencyModeWarehouseList
SELECT am.id, am.name, am.description,am.deliveryMethodFk, TIMESTAMPADD(DAY, -ah.substractDay, vDate), w.name
FROM agencyHour ah
LEFT JOIN address a ON a.id = vAddress
JOIN agencyMode am ON am.agencyFk = vAgency
JOIN warehouse w on w.id = ah.warehouseFk
WHERE ah.warehouseFk = vWarehouse
AND (weekDay = WEEKDAY(vDate)
OR weekDay IS NULL)
AND (ah.agencyFk = vAgency
OR ah.agencyFk IS NULL)
AND (ah.provinceFk = a.provinceFk
OR ah.provinceFk IS NULL
OR vAddress IS NULL)
AND TIMESTAMPADD(DAY, -ah.substractDay, vDate) >= util.VN_CURDATE()
AND IF(TIMESTAMPADD(DAY, -ah.substractDay, vDate) = util.VN_CURDATE(), ah.maxHour > HOUR(util.VN_NOW()), TRUE)
ORDER BY (
(ah.weekDay IS NOT NULL) +
(ah.agencyFk IS NOT NULL) +
((ah.provinceFk IS NOT NULL) * 3)
) DESC
LIMIT 1;
FETCH vCur INTO vAgency;
END WHILE;
CLOSE vCur;
SELECT * FROM tmp.agencyModeWarehouseList;
DROP TEMPORARY TABLE tmp.agencyModeWarehouseList;
END$$
DELIMITER ;