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

69 lines
2.2 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getTickets`(
vParamFk INT
)
BEGIN
/**
* Selecciona los tickets de una colección/ticket
* @param vParamFk ticketFk/collectionFk
* @return Retorna (ticketFk, level, agencyName, warehouseFk, salesPersonFk,
* observaciones, rgb, salesDepartmentFk)
*/
DECLARE vItemPackingTypeFk VARCHAR(1);
-- Si los sacadores son los de pruebas, pinta los colores
SELECT itemPackingTypeFk INTO vItemPackingTypeFk
FROM collection
WHERE id = vParamFk;
SELECT t.id ticketFk,
IF (NOT(vItemPackingTypeFk <=> 'V'),
cc.code,
CONCAT(SUBSTRING('ABCDEFGH',tc.wagon, 1),'-',tc.`level` )) `level`,
am.name agencyName,
t.warehouseFk,
c.salesPersonFk,
IFNULL(tob.description,'') observaciones,
cc.rgb,
c.salesDepartmentFk
FROM ticket t
LEFT JOIN ticketCollection tc ON t.id = tc.ticketFk
LEFT JOIN collection c2 ON c2.id = tc.collectionFk
LEFT JOIN collectionColors cc
ON cc.wagon = tc.wagon
AND cc.shelve = tc.`level`
AND cc.trainFk = c2.trainFk
LEFT JOIN zone z ON z.id = t.zoneFk
LEFT JOIN agencyMode am ON am.id = z.agencyModeFk
LEFT JOIN client c ON c.id = t.clientFk
LEFT JOIN ticketObservation tob ON tob.ticketFk = t.id
AND tob.observationTypeFk = 1
WHERE t.id = vParamFk
AND t.shipped >= util.yesterday()
UNION ALL
SELECT t.id ticketFk,
IF(NOT(vItemPackingTypeFk <=> 'V'),
cc.code,
CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`,
am.name agencyName,
t.warehouseFk,
c.salesPersonFk,
IFNULL(tob.description, '') observaciones,
IF(NOT(vItemPackingTypeFk <=> 'V'), cc.rgb, NULL) `rgb`,
c.salesDepartmentFk
FROM ticket t
JOIN ticketCollection tc ON t.id = tc.ticketFk
LEFT JOIN collection c2 ON c2.id = tc.collectionFk
LEFT JOIN collectionColors cc
ON cc.wagon = tc.wagon
AND cc.shelve = tc.`level`
AND cc.trainFk = c2.trainFk
LEFT JOIN zone z ON z.id = t.zoneFk
LEFT JOIN agencyMode am ON am.id = z.agencyModeFk
LEFT JOIN client c ON c.id = t.clientFk
LEFT JOIN ticketObservation tob ON tob.ticketFk = t.id
AND tob.observationTypeFk = 1
WHERE tc.collectionFk = vParamFk;
END$$
DELIMITER ;