60 lines
1.8 KiB
SQL
60 lines
1.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_priceDifference`(
|
|
vTicketFk INT,
|
|
vLanded DATE,
|
|
vAddressFk INT,
|
|
vZoneFk INT,
|
|
vWarehouseFk INT,
|
|
vCurrencyFk SMALLINT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Devuelve las diferencias de precio de los movimientos de un ticket.
|
|
*
|
|
* @param vTicketFk Id del ticket
|
|
* @param vLanded Fecha de recepcion
|
|
* @param vAddressFk Id del consignatario
|
|
* @param vZoneFk Id de la zona
|
|
* @param vWarehouseFk Id del almacén
|
|
*/
|
|
CALL vn.ticket_componentPreview(vTicketFk, vLanded, vAddressFk, vZoneFk, vWarehouseFk, vCurrencyFk);
|
|
|
|
WITH ticketPriceDifference AS (
|
|
SELECT s.itemFk,
|
|
i.name,
|
|
i.size,
|
|
i.category,
|
|
IFNULL(s.quantity, 0) quantity,
|
|
IFNULL(s.price, 0) price,
|
|
ROUND(IFNULL(
|
|
IFNULL(
|
|
s.foreignPrice,
|
|
s.price * ticket_getCurrencyRate(vTicketFk, vCurrencyFk)
|
|
) , 0
|
|
), 2) foreignPrice,
|
|
ROUND(SUM(tc.cost), 2) newPrice,
|
|
s.id saleFk,
|
|
ticket_getCurrencyRate(vTicketFk, vCurrencyFk) currencyRate
|
|
FROM vn.sale s
|
|
JOIN vn.item i ON i.id = s.itemFk
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
LEFT JOIN tmp.ticketComponentPreview tc ON tc.itemFk = s.itemFk
|
|
AND tc.warehouseFk = vWarehouseFk
|
|
LEFT JOIN vn.saleComponent sc ON sc.saleFk = s.id
|
|
AND sc.componentFk = tc.componentFk
|
|
LEFT JOIN vn.`component` c ON c.id = tc.componentFk
|
|
WHERE t.id = vTicketFk
|
|
AND IF(sc.componentFk IS NULL
|
|
AND c.classRate IS NOT NULL, FALSE, TRUE)
|
|
GROUP BY s.id ORDER BY s.id
|
|
) SELECT
|
|
*,
|
|
ROUND(currencyRate * newPrice, 2) newForeignPrice,
|
|
quantity * (newPrice - price) difference,
|
|
quantity * (ROUND(currencyRate * newPrice, 2) - foreignPrice ) foreignDifference
|
|
FROM ticketPriceDifference;
|
|
|
|
DROP TEMPORARY TABLE tmp.ticketComponentPreview;
|
|
END$$
|
|
DELIMITER ;
|