141 lines
3.6 KiB
SQL
141 lines
3.6 KiB
SQL
DROP PROCEDURE IF EXISTS `vn`.`ticketPackaging_add`;
|
|
|
|
DELIMITER $$
|
|
$$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticketPackaging_add`(
|
|
vClientFk INT,
|
|
vDated DATE,
|
|
vCompanyFk INT,
|
|
vWithoutPeriodGrace BOOLEAN)
|
|
BEGIN
|
|
/**
|
|
* Genera nuevos tickets de embalajes para los clientes no han los han retornado
|
|
* y actualiza los valores para la tabla ticketPackaging
|
|
*
|
|
* @param vClientFk Cliente en caso de NULL todos los clientes
|
|
* @param vDated Fecha hasta la cual se revisan los embalajes
|
|
* @param vCompanyFk Empresa de la cual se comprobaran sus clientes
|
|
* @param vWithoutPeriodGrace si no se aplica el periodo de gracia de un mes
|
|
*/
|
|
DECLARE vNewTicket INT;
|
|
DECLARE vDateStart DATE;
|
|
DECLARE vDateEnd DATE;
|
|
DECLARE vGraceDate DATE DEFAULT vDated;
|
|
DECLARE vWarehouseInventory INT;
|
|
DECLARE vComponentCost INT;
|
|
DECLARE vDone INT DEFAULT FALSE;
|
|
DECLARE vClientId INT;
|
|
|
|
DECLARE vCursor CURSOR FOR
|
|
SELECT DISTINCT clientFk
|
|
FROM (
|
|
SELECT clientFk, SUM(quantity) totalQuantity
|
|
FROM tmp.packagingToInvoice
|
|
GROUP BY itemFk, clientFk
|
|
HAVING totalQuantity > 0)sub;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
SELECT id INTO vWarehouseInventory
|
|
FROM warehouse
|
|
WHERE `code`= 'inv';
|
|
|
|
SELECT id INTO vComponentCost
|
|
FROM component
|
|
WHERE `code`= 'purchaseValue';
|
|
|
|
SELECT packagingInvoicingDated INTO vDateStart
|
|
FROM ticketConfig;
|
|
|
|
IF vWarehouseInventory IS NULL THEN
|
|
CALL util.throw('Warehouse inventory not seted');
|
|
END IF;
|
|
|
|
IF vComponentCost IS NULL THEN
|
|
CALL util.throw('Component cost not seted');
|
|
END IF;
|
|
|
|
SET vDateEnd = vDated + INTERVAL 1 DAY;
|
|
|
|
IF NOT vWithoutPeriodGrace THEN
|
|
SET vGraceDate = vGraceDate -INTERVAL 1 MONTH;
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.packagingToInvoice;
|
|
CREATE TEMPORARY TABLE tmp.packagingToInvoice
|
|
(INDEX (clientFk))
|
|
ENGINE = MEMORY
|
|
SELECT p.itemFk,
|
|
tp.packagingFk,
|
|
tp.quantity,
|
|
tp.ticketFk,
|
|
p.price,
|
|
t.clientFk
|
|
FROM ticketPackaging tp
|
|
JOIN packaging p ON p.id = tp.packagingFk
|
|
JOIN ticket t ON t.id = tp.ticketFk
|
|
JOIN client c ON c.id = t.clientFk
|
|
WHERE c.isActive
|
|
AND (vClientFk IS NULL OR t.clientFk = vClientFk)
|
|
AND t.shipped BETWEEN vDateStart AND vDateEnd
|
|
AND (tp.quantity < 0 OR (tp.quantity > 0 AND t.shipped < vGraceDate))
|
|
AND tp.quantity
|
|
AND p.itemFk;
|
|
|
|
OPEN vCursor;
|
|
l: LOOP
|
|
|
|
FETCH vCursor INTO vClientId;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
START TRANSACTION;
|
|
|
|
CALL ticket_add(
|
|
vClientId,
|
|
vDateEnd,
|
|
vWarehouseInventory,
|
|
vCompanyFk,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
vDateEnd,
|
|
account.myUser_getId(),
|
|
TRUE,
|
|
vNewTicket);
|
|
|
|
INSERT INTO ticketPackaging(ticketFk, packagingFk, quantity, pvp)
|
|
SELECT vNewTicket, packagingFk, - SUM(quantity) totalQuantity, price
|
|
FROM tmp.packagingToInvoice
|
|
WHERE clientFk = vClientId
|
|
GROUP BY packagingFk
|
|
HAVING IF(vWithoutPeriodGrace, totalQuantity <> 0, totalQuantity < 0);
|
|
|
|
INSERT INTO sale(ticketFk, itemFk, concept, quantity, price)
|
|
SELECT vNewTicket, pti.itemFk, i.name, SUM(pti.quantity) totalQuantity, pti.price
|
|
FROM tmp.packagingToInvoice pti
|
|
JOIN item i ON i.id = pti.itemFk
|
|
WHERE pti.clientFk = vClientId
|
|
GROUP BY pti.itemFk
|
|
HAVING IF(vWithoutPeriodGrace, totalQuantity <> 0, totalQuantity > 0);
|
|
|
|
INSERT INTO saleComponent(saleFk, componentFk, value)
|
|
SELECT id, vComponentCost, price
|
|
FROM sale
|
|
WHERE ticketFk = vNewTicket;
|
|
|
|
COMMIT;
|
|
END LOOP;
|
|
CLOSE vCursor;
|
|
|
|
DROP TEMPORARY TABLE tmp.packagingToInvoice;
|
|
END$$
|
|
DELIMITER ; |