84 lines
2.4 KiB
SQL
84 lines
2.4 KiB
SQL
CREATE TABLE `vn`.`dmsRecover` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`ticketFk` int(11) DEFAULT NULL,
|
|
`sign` text DEFAULT NULL,
|
|
`created` timestamp NULL DEFAULT current_timestamp(),
|
|
PRIMARY KEY (`id`),
|
|
KEY `ticketFk_idx` (`ticketFk`),
|
|
CONSTRAINT `ticketFk` FOREIGN KEY (`ticketFk`) REFERENCES `ticket` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
|
|
) ENGINE=InnoDB AUTO_INCREMENT=31917 DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci;
|
|
|
|
ALTER TABLE `vn`.`delivery` ADD addressFk INT;
|
|
|
|
DROP PROCEDURE IF EXISTS `vn`.`route_getTickets`;
|
|
|
|
DELIMITER $$
|
|
$$
|
|
CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`route_getTickets`(vRouteFk INT)
|
|
BEGIN
|
|
/**
|
|
* Pasado un RouteFk devuelve la información
|
|
* de sus tickets.
|
|
*
|
|
* @param vRouteFk
|
|
* @select Información de los tickets
|
|
*/
|
|
SELECT *
|
|
FROM (
|
|
SELECT t.id Id,
|
|
t.clientFk Client,
|
|
a.id Address,
|
|
a.nickname ClientName,
|
|
t.packages Packages,
|
|
a.street AddressName,
|
|
a.postalCode PostalCode,
|
|
a.city City,
|
|
sub2.itemPackingTypeFk PackingType,
|
|
c.phone ClientPhone,
|
|
c.mobile ClientMobile,
|
|
a.phone AddressPhone,
|
|
a.mobile AddressMobile,
|
|
d.longitude Longitude,
|
|
d.latitude Latitude,
|
|
wm.mediaValue SalePersonPhone,
|
|
tob.description Note,
|
|
t.isSigned Signed,
|
|
t.priority
|
|
FROM ticket t
|
|
JOIN client c ON t.clientFk = c.id
|
|
JOIN address a ON t.addressFk = a.id
|
|
LEFT JOIN delivery d ON d.addressFk = a.id
|
|
LEFT JOIN workerMedia wm ON wm.workerFk = c.salesPersonFk
|
|
LEFT JOIN(
|
|
SELECT tob.description, t.id
|
|
FROM ticketObservation tob
|
|
JOIN ticket t ON tob.ticketFk = t.id
|
|
JOIN observationType ot ON ot.id = tob.observationTypeFk
|
|
WHERE t.routeFk = vRouteFk
|
|
AND ot.code = 'delivery'
|
|
)tob ON tob.id = t.id
|
|
LEFT JOIN(
|
|
SELECT sub.ticketFk,
|
|
CONCAT('(',
|
|
GROUP_CONCAT(DISTINCT sub.itemPackingTypeFk
|
|
ORDER BY sub.items DESC SEPARATOR ','),
|
|
') ') itemPackingTypeFk
|
|
FROM (
|
|
SELECT s.ticketFk, i.itemPackingTypeFk, COUNT(*) items
|
|
FROM ticket t
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
JOIN item i ON i.id = s.itemFk
|
|
WHERE t.routeFk = vRouteFk
|
|
GROUP BY t.id, i.itemPackingTypeFk
|
|
)sub
|
|
GROUP BY sub.ticketFk
|
|
)sub2 ON sub2.ticketFk = t.id
|
|
WHERE t.routeFk = vRouteFk
|
|
ORDER BY d.id DESC
|
|
LIMIT 10000000000000000000
|
|
)sub3
|
|
GROUP BY sub3.id
|
|
ORDER BY sub3.priority;
|
|
END$$
|
|
DELIMITER ;
|