122 lines
3.7 KiB
SQL
122 lines
3.7 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`packageInvoicing`(
|
|
IN vClient INT,
|
|
IN vDate DATE,
|
|
IN vCompany INT,
|
|
IN vIsAllInvoiceable BOOLEAN,
|
|
OUT vNewTicket INT(11)
|
|
)
|
|
BEGIN
|
|
|
|
DECLARE vGraceDays INT;
|
|
DECLARE vDateStart DATE DEFAULT '2017-11-21';
|
|
DECLARE vIsInvoiceable BOOLEAN;
|
|
DECLARE vWarehouse INT DEFAULT 13;
|
|
DECLARE vComponentCost INT DEFAULT 28;
|
|
DECLARE vGraceDate DATE;
|
|
DECLARE vDateEnd DATE;
|
|
|
|
SET vGraceDays = IF(vIsAllInvoiceable ,0, 30);
|
|
SET vGraceDate = TIMESTAMPADD(DAY, - vGraceDays, vDate);
|
|
|
|
/* Clientes especiales:
|
|
3240 MADEFLOR
|
|
992 JAVIER FELIU
|
|
4 TONI VENDRELL
|
|
*/
|
|
|
|
IF vClient IN (992, 3240, 4) THEN
|
|
|
|
SET vGraceDays = 365;
|
|
|
|
END IF;
|
|
/* Fin clientes especiales */
|
|
|
|
SET vDateEnd = DATE_ADD(vDate, INTERVAL 1 DAY);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.packageToInvoice;
|
|
|
|
CREATE TEMPORARY TABLE tmp.packageToInvoice
|
|
SELECT p.itemFk,
|
|
tp.packagingFk,
|
|
IF(tp.quantity < 0 OR t.shipped < vGraceDate, tp.quantity, 0) quantity,
|
|
tp.ticketFk,
|
|
p.price
|
|
FROM ticketPackaging tp
|
|
JOIN packaging p ON p.id = tp.packagingFk
|
|
JOIN ticket t ON t.id = tp.ticketFk
|
|
WHERE t.shipped BETWEEN vDateStart AND vDateEnd
|
|
AND t.clientFk = vClient;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.packageToInvoicePositives;
|
|
|
|
CREATE TEMPORARY TABLE tmp.packageToInvoicePositives
|
|
SELECT itemFk, sum(quantity) as totalQuantity
|
|
FROM tmp.packageToInvoice
|
|
GROUP BY itemFk
|
|
HAVING totalQuantity > 0;
|
|
|
|
SELECT COUNT(*)
|
|
INTO vIsInvoiceable
|
|
FROM tmp.packageToInvoicePositives;
|
|
|
|
IF vIsInvoiceable THEN
|
|
|
|
CALL ticket_add(vClient,
|
|
vDateEnd,
|
|
vWarehouse,
|
|
vCompany,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
vDateEnd,
|
|
account.myUser_getId(),
|
|
TRUE,
|
|
vNewTicket);
|
|
|
|
INSERT INTO ticketPackaging(
|
|
ticketFk,
|
|
packagingFk,
|
|
quantity,
|
|
pvp)
|
|
SELECT vNewTicket,
|
|
pti.packagingFk,
|
|
- SUM(pti.quantity) AS totalQuantity,
|
|
pti.price
|
|
FROM tmp.packageToInvoice pti
|
|
LEFT JOIN tmp.packageToInvoicePositives ptip ON pti.itemFk = ptip.itemFk
|
|
WHERE ptip.itemFK IS NOT NULL
|
|
OR vIsAllInvoiceable
|
|
GROUP BY packagingFk
|
|
HAVING totalQuantity;
|
|
|
|
INSERT INTO sale(
|
|
ticketFk,
|
|
itemFk,
|
|
concept,
|
|
quantity,
|
|
price
|
|
)
|
|
SELECT vNewTicket,
|
|
pti.itemFk,
|
|
i.name as concept,
|
|
sum(pti.quantity) as totalQuantity,
|
|
pti.price
|
|
FROM tmp.packageToInvoice pti
|
|
JOIN item i ON i.id = pti.itemFk
|
|
LEFT JOIN tmp.packageToInvoicePositives ptip ON pti.itemFk = ptip.itemFk
|
|
WHERE ptip.itemFK IS NOT NULL
|
|
OR vIsAllInvoiceable
|
|
GROUP BY pti.itemFk
|
|
HAVING totalQuantity;
|
|
|
|
INSERT INTO saleComponent(saleFk, componentFk, value)
|
|
SELECT id, vComponentCost, price
|
|
FROM sale
|
|
WHERE ticketFk = vNewTicket;
|
|
|
|
END IF;
|
|
|
|
END$$
|
|
DELIMITER ;
|