1789 lines
50 KiB
SQL
1789 lines
50 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`item_getVisible`(
|
|
vWarehouse TINYINT,
|
|
vDate DATE,
|
|
vType INT,
|
|
vPrefix VARCHAR(255))
|
|
BEGIN
|
|
|
|
/**
|
|
* Gets visible items of the specified type at specified date.
|
|
*
|
|
* @param vWarehouse The warehouse id
|
|
* @param vDate The visible date
|
|
* @param vType The type id
|
|
* @param vPrefix The article prefix to filter or %NULL for all
|
|
* @return tmp.itemVisible Visible items
|
|
*/
|
|
DECLARE vPrefixLen SMALLINT;
|
|
DECLARE vFilter VARCHAR(255) DEFAULT NULL;
|
|
DECLARE vDateInv DATE DEFAULT vn.getInventoryDate();
|
|
DECLARE EXIT HANDLER FOR 1114
|
|
BEGIN
|
|
GET DIAGNOSTICS CONDITION 1
|
|
@message = MESSAGE_TEXT;
|
|
CALL vn.mail_insert(
|
|
'cau@verdnatura.es',
|
|
NULL,
|
|
CONCAT('hedera.item_getVisible error: ', @message),
|
|
CONCAT(
|
|
'warehouse: ', IFNULL(vWarehouse, ''),
|
|
', Fecha:', IFNULL(vDate, ''),
|
|
', tipo: ', IFNULL(vType,''),
|
|
', prefijo: ', IFNULL(vPrefix,'')));
|
|
RESIGNAL;
|
|
END;
|
|
SET vPrefixLen = IFNULL(LENGTH(vPrefix), 0) + 1;
|
|
|
|
IF vPrefixLen > 1 THEN
|
|
SET vFilter = CONCAT(vPrefix, '%');
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS `filter`;
|
|
CREATE TEMPORARY TABLE `filter`
|
|
(INDEX (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT id itemFk FROM vn.item
|
|
WHERE typeFk = vType
|
|
AND (vFilter IS NULL OR `name` LIKE vFilter);
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS currentStock;
|
|
CREATE TEMPORARY TABLE currentStock
|
|
(INDEX (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT itemFk, SUM(quantity) quantity
|
|
FROM (
|
|
SELECT b.itemFk, b.quantity
|
|
FROM vn.buy b
|
|
JOIN vn.entry e ON e.id = b.entryFk
|
|
JOIN vn.travel t ON t.id = e.travelFk
|
|
WHERE t.landed BETWEEN vDateInv AND vDate
|
|
AND t.warehouseInFk = vWarehouse
|
|
AND NOT e.isRaid
|
|
UNION ALL
|
|
SELECT b.itemFk, -b.quantity
|
|
FROM vn.buy b
|
|
JOIN vn.entry e ON e.id = b.entryFk
|
|
JOIN vn.travel t ON t.id = e.travelFk
|
|
WHERE t.shipped BETWEEN vDateInv AND util.VN_CURDATE()
|
|
AND t.warehouseOutFk = vWarehouse
|
|
AND NOT e.isRaid
|
|
AND t.isDelivered
|
|
UNION ALL
|
|
SELECT m.itemFk, -m.quantity
|
|
FROM vn.sale m
|
|
JOIN vn.ticket t ON t.id = m.ticketFk
|
|
JOIN vn.ticketState s ON s.ticketFk = t.id
|
|
WHERE t.shipped BETWEEN vDateInv AND util.VN_CURDATE()
|
|
AND t.warehouseFk = vWarehouse
|
|
AND s.alertLevel = 3
|
|
) t
|
|
GROUP BY itemFk
|
|
HAVING quantity > 0;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp;
|
|
CREATE TEMPORARY TABLE tmp
|
|
(INDEX (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT *
|
|
FROM (
|
|
SELECT b.itemFk, b.packagingFk, b.packing
|
|
FROM vn.buy b
|
|
JOIN vn.entry e ON e.id = b.entryFk
|
|
JOIN vn.travel t ON t.id = e.travelFk
|
|
WHERE t.landed BETWEEN vDateInv AND vDate
|
|
AND NOT b.isIgnored
|
|
AND b.price2 >= 0
|
|
AND b.packagingFk IS NOT NULL
|
|
ORDER BY t.warehouseInFk = vWarehouse DESC, t.landed DESC
|
|
LIMIT 10000000000000000000
|
|
) t GROUP BY itemFk;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemVisible;
|
|
CREATE TEMPORARY TABLE tmp.itemVisible
|
|
ENGINE = MEMORY
|
|
SELECT i.id Id_Article,
|
|
SUBSTRING(i.`name`, vPrefixLen) Article,
|
|
t.packing, p.id Id_Cubo,
|
|
IF(p.depth > 0, p.depth, 0) depth, p.width, p.height,
|
|
CEIL(s.quantity / t.packing) etiquetas
|
|
FROM vn.item i
|
|
JOIN `filter` f ON f.itemFk = i.id
|
|
JOIN currentStock s ON s.itemFk = i.id
|
|
LEFT JOIN tmp t ON t.itemFk = i.id
|
|
LEFT JOIN vn.packaging p ON p.id = t.packagingFk
|
|
WHERE CEIL(s.quantity / t.packing) > 0
|
|
-- FIXME: Column Cubos.box not included in view vn.packaging
|
|
/* AND p.box */ ;
|
|
|
|
DROP TEMPORARY TABLE
|
|
`filter`,
|
|
currentStock,
|
|
tmp;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `hedera`.`order_confirmWithUser`(vSelf INT, vUserId INT)
|
|
BEGIN
|
|
/**
|
|
* Confirms an order, creating each of its tickets on the corresponding
|
|
* date, store and user.
|
|
*
|
|
* @param vSelf The order identifier
|
|
* @param vUser The user identifier
|
|
*/
|
|
DECLARE vOk BOOL;
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vWarehouse INT;
|
|
DECLARE vShipment DATE;
|
|
DECLARE vTicket INT;
|
|
DECLARE vNotes VARCHAR(255);
|
|
DECLARE vItem INT;
|
|
DECLARE vConcept VARCHAR(30);
|
|
DECLARE vAmount INT;
|
|
DECLARE vPrice DECIMAL(10,2);
|
|
DECLARE vSale INT;
|
|
DECLARE vRate INT;
|
|
DECLARE vRowId INT;
|
|
DECLARE vPriceFixed DECIMAL(10,2);
|
|
DECLARE vDelivery DATE;
|
|
DECLARE vAddress INT;
|
|
DECLARE vIsConfirmed BOOL;
|
|
DECLARE vClientId INT;
|
|
DECLARE vCompanyId INT;
|
|
DECLARE vAgencyModeId INT;
|
|
DECLARE TICKET_FREE INT DEFAULT 2;
|
|
DECLARE vCalc INT;
|
|
DECLARE vIsLogifloraItem BOOL;
|
|
DECLARE vOldQuantity INT;
|
|
DECLARE vNewQuantity INT;
|
|
DECLARE vIsTaxDataChecked BOOL;
|
|
|
|
DECLARE cDates CURSOR FOR
|
|
SELECT zgs.shipped, r.warehouse_id
|
|
FROM `order` o
|
|
JOIN order_row r ON r.order_id = o.id
|
|
LEFT JOIN tmp.zoneGetShipped zgs ON zgs.warehouseFk = r.warehouse_id
|
|
WHERE o.id = vSelf AND r.amount != 0
|
|
GROUP BY r.warehouse_id;
|
|
|
|
DECLARE cRows CURSOR FOR
|
|
SELECT r.id, r.item_id, i.name, r.amount, r.price, r.rate, i.isFloramondo
|
|
FROM order_row r
|
|
JOIN vn.item i ON i.id = r.item_id
|
|
WHERE r.amount != 0
|
|
AND r.warehouse_id = vWarehouse
|
|
AND r.order_id = vSelf
|
|
ORDER BY r.rate DESC;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
|
SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
-- Carga los datos del pedido
|
|
SELECT o.date_send, o.address_id, o.note, a.clientFk,
|
|
o.company_id, o.agency_id, c.isTaxDataChecked
|
|
INTO vDelivery, vAddress, vNotes, vClientId,
|
|
vCompanyId, vAgencyModeId, vIsTaxDataChecked
|
|
FROM hedera.`order` o
|
|
JOIN vn.address a ON a.id = o.address_id
|
|
JOIN vn.client c ON c.id = a.clientFk
|
|
WHERE o.id = vSelf;
|
|
|
|
-- Verifica si el cliente tiene los datos comprobados
|
|
IF NOT vIsTaxDataChecked THEN
|
|
CALL util.throw ('clientNotVerified');
|
|
END IF;
|
|
|
|
-- Carga las fechas de salida de cada almacen
|
|
CALL vn.zone_getShipped (vDelivery, vAddress, vAgencyModeId, FALSE);
|
|
|
|
-- Trabajador que realiza la accion
|
|
IF vUserId IS NULL THEN
|
|
SELECT employeeFk INTO vUserId FROM orderConfig;
|
|
END IF;
|
|
|
|
START TRANSACTION;
|
|
|
|
CALL order_checkEditable(vSelf);
|
|
|
|
-- Check order is not empty
|
|
|
|
SELECT COUNT(*) > 0 INTO vOk
|
|
FROM order_row WHERE order_id = vSelf AND amount > 0;
|
|
|
|
IF NOT vOk THEN
|
|
CALL util.throw ('ORDER_EMPTY');
|
|
END IF;
|
|
|
|
-- Crea los tickets del pedido
|
|
|
|
OPEN cDates;
|
|
|
|
lDates:
|
|
LOOP
|
|
SET vTicket = NULL;
|
|
SET vDone = FALSE;
|
|
FETCH cDates INTO vShipment, vWarehouse;
|
|
|
|
IF vDone THEN
|
|
LEAVE lDates;
|
|
END IF;
|
|
|
|
-- Busca un ticket existente que coincida con los parametros
|
|
WITH tPrevia AS
|
|
(SELECT DISTINCT s.ticketFk
|
|
FROM vn.sale s
|
|
JOIN vn.saleGroupDetail sgd ON sgd.saleFk = s.id
|
|
JOIN vn.ticket t ON t.id = s.ticketFk
|
|
WHERE t.shipped BETWEEN vShipment AND util.dayend(vShipment)
|
|
)
|
|
SELECT t.id INTO vTicket
|
|
FROM vn.ticket t
|
|
LEFT JOIN tPrevia tp ON tp.ticketFk = t.id
|
|
LEFT JOIN vn.ticketState tls on tls.ticketFk = t.id
|
|
JOIN hedera.`order` o
|
|
ON o.address_id = t.addressFk
|
|
AND vWarehouse = t.warehouseFk
|
|
AND o.date_send = t.landed
|
|
AND DATE(t.shipped) = vShipment
|
|
WHERE o.id = vSelf
|
|
AND t.refFk IS NULL
|
|
AND tp.ticketFk IS NULL
|
|
AND IFNULL(tls.alertLevel,0) = 0
|
|
LIMIT 1;
|
|
|
|
-- Crea el ticket en el caso de no existir uno adecuado
|
|
IF vTicket IS NULL
|
|
THEN
|
|
|
|
SET vShipment = IFNULL(vShipment, util.VN_CURDATE());
|
|
|
|
CALL vn.ticket_add(
|
|
vClientId,
|
|
vShipment,
|
|
vWarehouse,
|
|
vCompanyId,
|
|
vAddress,
|
|
vAgencyModeId,
|
|
NULL,
|
|
vDelivery,
|
|
vUserId,
|
|
TRUE,
|
|
vTicket
|
|
);
|
|
ELSE
|
|
INSERT INTO vn.ticketTracking
|
|
SET ticketFk = vTicket,
|
|
workerFk = vUserId,
|
|
stateFk = TICKET_FREE;
|
|
END IF;
|
|
|
|
INSERT IGNORE INTO vn.orderTicket
|
|
SET orderFk = vSelf,
|
|
ticketFk = vTicket;
|
|
|
|
-- Añade las notas
|
|
|
|
IF vNotes IS NOT NULL AND vNotes != ''
|
|
THEN
|
|
INSERT INTO vn.ticketObservation SET
|
|
ticketFk = vTicket,
|
|
observationTypeFk = 4 /* salesperson */,
|
|
`description` = vNotes
|
|
ON DUPLICATE KEY UPDATE
|
|
`description` = CONCAT(VALUES(`description`),'. ', `description`);
|
|
END IF;
|
|
|
|
-- Añade los movimientos y sus componentes
|
|
|
|
OPEN cRows;
|
|
|
|
lRows: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH cRows INTO vRowId, vItem, vConcept, vAmount, vPrice, vRate, vIsLogifloraItem;
|
|
|
|
IF vDone THEN
|
|
LEAVE lRows;
|
|
END IF;
|
|
|
|
SET vSale = NULL;
|
|
|
|
SELECT s.id, s.quantity INTO vSale, vOldQuantity
|
|
FROM vn.sale s
|
|
WHERE ticketFk = vTicket
|
|
AND price = vPrice
|
|
AND itemFk = vItem
|
|
AND discount = 0
|
|
LIMIT 1;
|
|
|
|
IF vSale THEN
|
|
UPDATE vn.sale
|
|
SET quantity = quantity + vAmount,
|
|
originalQuantity = quantity
|
|
WHERE id = vSale;
|
|
|
|
SELECT s.quantity INTO vNewQuantity
|
|
FROM vn.sale s
|
|
WHERE id = vSale;
|
|
ELSE
|
|
-- Obtiene el coste
|
|
SELECT SUM(rc.`price`) valueSum INTO vPriceFixed
|
|
FROM orderRowComponent rc
|
|
JOIN vn.component c ON c.id = rc.componentFk
|
|
JOIN vn.componentType ct ON ct.id = c.typeFk AND ct.isBase
|
|
WHERE rc.rowFk = vRowId;
|
|
|
|
INSERT INTO vn.sale
|
|
SET itemFk = vItem,
|
|
ticketFk = vTicket,
|
|
concept = vConcept,
|
|
quantity = vAmount,
|
|
price = vPrice,
|
|
priceFixed = vPriceFixed,
|
|
isPriceFixed = TRUE;
|
|
|
|
SET vSale = LAST_INSERT_ID();
|
|
|
|
INSERT INTO vn.saleComponent
|
|
(saleFk, componentFk, `value`)
|
|
SELECT vSale, rc.componentFk, rc.price
|
|
FROM orderRowComponent rc
|
|
JOIN vn.component c ON c.id = rc.componentFk
|
|
WHERE rc.rowFk = vRowId
|
|
GROUP BY vSale, rc.componentFk;
|
|
END IF;
|
|
|
|
UPDATE order_row SET Id_Movimiento = vSale
|
|
WHERE id = vRowId;
|
|
|
|
-- Inserta en putOrder si la compra es de Floramondo
|
|
IF vIsLogifloraItem THEN
|
|
CALL cache.availableNoRaids_refresh(vCalc,FALSE,vWarehouse,vShipment);
|
|
|
|
SET @available := 0;
|
|
|
|
SELECT GREATEST(0,available) INTO @available
|
|
FROM cache.availableNoRaids
|
|
WHERE calc_id = vCalc
|
|
AND item_id = vItem;
|
|
|
|
UPDATE cache.availableNoRaids
|
|
SET available = GREATEST(0,available - vAmount)
|
|
WHERE item_id = vItem
|
|
AND calc_id = vCalc;
|
|
|
|
INSERT INTO edi.putOrder (
|
|
deliveryInformationID,
|
|
supplyResponseId,
|
|
quantity ,
|
|
EndUserPartyId,
|
|
EndUserPartyGLN,
|
|
FHAdminNumber,
|
|
saleFk
|
|
)
|
|
SELECT di.ID,
|
|
i.supplyResponseFk,
|
|
CEIL((vAmount - @available)/ sr.NumberOfItemsPerCask),
|
|
o.address_id ,
|
|
vClientId,
|
|
IFNULL(ca.fhAdminNumber, fhc.defaultAdminNumber),
|
|
vSale
|
|
FROM edi.deliveryInformation di
|
|
JOIN vn.item i ON i.supplyResponseFk = di.supplyResponseID
|
|
JOIN edi.supplyResponse sr ON sr.ID = i.supplyResponseFk
|
|
LEFT JOIN edi.clientFHAdminNumber ca ON ca.clientFk = vClientId
|
|
JOIN edi.floraHollandConfig fhc
|
|
JOIN hedera.`order` o ON o.id = vSelf
|
|
WHERE i.id = vItem
|
|
AND di.LatestOrderDateTime > util.VN_NOW()
|
|
AND vAmount > @available
|
|
LIMIT 1;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
CLOSE cRows;
|
|
END LOOP;
|
|
|
|
CLOSE cDates;
|
|
|
|
UPDATE `order` SET confirmed = TRUE, confirm_date = util.VN_NOW()
|
|
WHERE id = vSelf;
|
|
|
|
COMMIT;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceOut_new`(
|
|
vSerial VARCHAR(255),
|
|
vInvoiceDate DATE,
|
|
vTaxArea VARCHAR(25),
|
|
OUT vNewInvoiceId INT)
|
|
BEGIN
|
|
/**
|
|
* Creación de facturas emitidas.
|
|
* requiere previamente tabla tmp.ticketToInvoice(id).
|
|
*
|
|
* @param vSerial serie a la cual se hace la factura
|
|
* @param vInvoiceDate fecha de la factura
|
|
* @param vTaxArea tipo de iva en relacion a la empresa y al cliente
|
|
* @param vNewInvoiceId id de la factura que se acaba de generar
|
|
* @return vNewInvoiceId
|
|
*/
|
|
DECLARE vIsAnySaleToInvoice BOOL;
|
|
DECLARE vIsAnyServiceToInvoice BOOL;
|
|
DECLARE vNewRef VARCHAR(255);
|
|
DECLARE vWorker INT DEFAULT account.myUser_getId();
|
|
DECLARE vCompanyFk INT;
|
|
DECLARE vInterCompanyFk INT;
|
|
DECLARE vClientFk INT;
|
|
DECLARE vCplusStandardInvoiceTypeFk INT DEFAULT 1;
|
|
DECLARE vCplusCorrectingInvoiceTypeFk INT DEFAULT 6;
|
|
DECLARE vCplusSimplifiedInvoiceTypeFk INT DEFAULT 2;
|
|
DECLARE vCorrectingSerial VARCHAR(1) DEFAULT 'R';
|
|
DECLARE vSimplifiedSerial VARCHAR(1) DEFAULT 'S';
|
|
DECLARE vNewInvoiceInFk INT;
|
|
DECLARE vIsInterCompany BOOL DEFAULT FALSE;
|
|
DECLARE vIsCEESerial BOOL DEFAULT FALSE;
|
|
DECLARE vIsCorrectInvoiceDate BOOL;
|
|
DECLARE vMaxShipped DATE;
|
|
DECLARE vDone BOOL;
|
|
DECLARE vTicketFk INT;
|
|
DECLARE vCursor CURSOR FOR
|
|
SELECT id
|
|
FROM tmp.ticketToInvoice;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
SET vInvoiceDate = IFNULL(vInvoiceDate, util.VN_CURDATE());
|
|
|
|
SELECT t.clientFk,
|
|
t.companyFk,
|
|
MAX(DATE(t.shipped)),
|
|
DATE(vInvoiceDate) >= invoiceOut_getMaxIssued(
|
|
vSerial,
|
|
t.companyFk,
|
|
YEAR(vInvoiceDate))
|
|
INTO vClientFk,
|
|
vCompanyFk,
|
|
vMaxShipped,
|
|
vIsCorrectInvoiceDate
|
|
FROM tmp.ticketToInvoice tt
|
|
JOIN ticket t ON t.id = tt.id;
|
|
|
|
IF(vMaxShipped > vInvoiceDate) THEN
|
|
CALL util.throw("Invoice date can't be less than max date");
|
|
END IF;
|
|
|
|
IF NOT vIsCorrectInvoiceDate THEN
|
|
CALL util.throw('Exists an invoice with a previous date');
|
|
END IF;
|
|
|
|
-- Eliminem de tmp.ticketToInvoice els tickets que no han de ser facturats
|
|
DELETE ti.*
|
|
FROM tmp.ticketToInvoice ti
|
|
JOIN ticket t ON t.id = ti.id
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
JOIN item i ON i.id = s.itemFk
|
|
JOIN supplier su ON su.id = t.companyFk
|
|
JOIN client c ON c.id = t.clientFk
|
|
LEFT JOIN itemTaxCountry itc ON itc.itemFk = i.id AND itc.countryFk = su.countryFk
|
|
WHERE (YEAR(t.shipped) < 2001 AND t.isDeleted)
|
|
OR c.isTaxDataChecked = FALSE
|
|
OR t.isDeleted
|
|
OR c.hasToInvoice = FALSE
|
|
OR itc.id IS NULL;
|
|
|
|
SELECT SUM(s.quantity * s.price * (100 - s.discount)/100) <> 0
|
|
INTO vIsAnySaleToInvoice
|
|
FROM tmp.ticketToInvoice t
|
|
JOIN sale s ON s.ticketFk = t.id;
|
|
|
|
SELECT COUNT(*) > 0 INTO vIsAnyServiceToInvoice
|
|
FROM tmp.ticketToInvoice t
|
|
JOIN ticketService ts ON ts.ticketFk = t.id;
|
|
|
|
IF (vIsAnySaleToInvoice OR vIsAnyServiceToInvoice)
|
|
AND (vCorrectingSerial = vSerial OR NOT hasAnyNegativeBase())
|
|
THEN
|
|
|
|
-- el trigger añade el siguiente Id_Factura correspondiente a la vSerial
|
|
INSERT INTO invoiceOut(
|
|
ref,
|
|
serial,
|
|
issued,
|
|
clientFk,
|
|
dued,
|
|
companyFk,
|
|
siiTypeInvoiceOutFk
|
|
)
|
|
SELECT
|
|
1,
|
|
vSerial,
|
|
vInvoiceDate,
|
|
vClientFk,
|
|
getDueDate(vInvoiceDate, dueDay),
|
|
vCompanyFk,
|
|
IF(vSerial = vCorrectingSerial,
|
|
vCplusCorrectingInvoiceTypeFk,
|
|
IF(vSerial = vSimplifiedSerial,
|
|
vCplusSimplifiedInvoiceTypeFk,
|
|
vCplusStandardInvoiceTypeFk))
|
|
FROM client
|
|
WHERE id = vClientFk;
|
|
|
|
SET vNewInvoiceId = LAST_INSERT_ID();
|
|
|
|
SELECT `ref`
|
|
INTO vNewRef
|
|
FROM invoiceOut
|
|
WHERE id = vNewInvoiceId;
|
|
|
|
OPEN vCursor;
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vCursor INTO vTicketFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
CALL ticket_recalc(vTicketFk, vTaxArea);
|
|
|
|
END LOOP;
|
|
CLOSE vCursor;
|
|
|
|
UPDATE ticket t
|
|
JOIN tmp.ticketToInvoice ti ON ti.id = t.id
|
|
SET t.refFk = vNewRef;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.updateInter;
|
|
CREATE TEMPORARY TABLE tmp.updateInter ENGINE = MEMORY
|
|
SELECT s.id,ti.id ticket_id,vWorker Id_Trabajador
|
|
FROM tmp.ticketToInvoice ti
|
|
LEFT JOIN ticketState ts ON ti.id = ts.ticketFk
|
|
JOIN state s
|
|
WHERE IFNULL(ts.alertLevel,0) < 3 and s.`code` = getAlert3State(ti.id);
|
|
|
|
INSERT INTO ticketTracking(stateFk,ticketFk,userFk)
|
|
SELECT * FROM tmp.updateInter;
|
|
|
|
CALL invoiceExpenseMake(vNewInvoiceId);
|
|
CALL invoiceTaxMake(vNewInvoiceId,vTaxArea);
|
|
|
|
UPDATE invoiceOut io
|
|
JOIN (
|
|
SELECT SUM(amount) total
|
|
FROM invoiceOutExpense
|
|
WHERE invoiceOutFk = vNewInvoiceId
|
|
) base
|
|
JOIN (
|
|
SELECT SUM(vat) total
|
|
FROM invoiceOutTax
|
|
WHERE invoiceOutFk = vNewInvoiceId
|
|
) vat
|
|
SET io.amount = base.total + vat.total
|
|
WHERE io.id = vNewInvoiceId;
|
|
|
|
DROP TEMPORARY TABLE tmp.updateInter;
|
|
|
|
SELECT COUNT(*), id
|
|
INTO vIsInterCompany, vInterCompanyFk
|
|
FROM company
|
|
WHERE clientFk = vClientFk;
|
|
|
|
IF (vIsInterCompany) THEN
|
|
|
|
INSERT INTO invoiceIn(supplierFk, supplierRef, issued, companyFk)
|
|
SELECT vCompanyFk, vNewRef, vInvoiceDate, vInterCompanyFk;
|
|
|
|
SET vNewInvoiceInFk = LAST_INSERT_ID();
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket;
|
|
CREATE TEMPORARY TABLE tmp.ticket
|
|
(KEY (ticketFk))
|
|
ENGINE = MEMORY
|
|
SELECT id ticketFk
|
|
FROM tmp.ticketToInvoice;
|
|
|
|
CALL `ticket_getTax`('NATIONAL');
|
|
|
|
SET @vTaxableBaseServices := 0.00;
|
|
SET @vTaxCodeGeneral := NULL;
|
|
|
|
INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk)
|
|
SELECT vNewInvoiceInFk,
|
|
@vTaxableBaseServices,
|
|
sub.expenseFk,
|
|
sub.taxTypeSageFk,
|
|
sub.transactionTypeSageFk
|
|
FROM (
|
|
SELECT @vTaxableBaseServices := SUM(tst.taxableBase) taxableBase,
|
|
i.expenseFk,
|
|
i.taxTypeSageFk,
|
|
i.transactionTypeSageFk,
|
|
@vTaxCodeGeneral := i.taxClassCodeFk
|
|
FROM tmp.ticketServiceTax tst
|
|
JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tst.code
|
|
WHERE i.isService
|
|
HAVING taxableBase
|
|
) sub;
|
|
|
|
INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk)
|
|
SELECT vNewInvoiceInFk,
|
|
SUM(tt.taxableBase) - IF(tt.code = @vTaxCodeGeneral,
|
|
@vTaxableBaseServices, 0) taxableBase,
|
|
i.expenseFk,
|
|
i.taxTypeSageFk ,
|
|
i.transactionTypeSageFk
|
|
FROM tmp.ticketTax tt
|
|
JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tt.code
|
|
WHERE !i.isService
|
|
GROUP BY tt.pgcFk
|
|
HAVING taxableBase
|
|
ORDER BY tt.priority;
|
|
|
|
CALL invoiceInDueDay_calculate(vNewInvoiceInFk);
|
|
|
|
SELECT COUNT(*) INTO vIsCEESerial
|
|
FROM invoiceOutSerial
|
|
WHERE code = vSerial;
|
|
|
|
IF vIsCEESerial THEN
|
|
|
|
INSERT INTO invoiceInIntrastat (
|
|
invoiceInFk,
|
|
intrastatFk,
|
|
amount,
|
|
stems,
|
|
countryFk,
|
|
net)
|
|
SELECT
|
|
vNewInvoiceInFk,
|
|
i.intrastatFk,
|
|
SUM(CAST((s.quantity * s.price * (100 - s.discount) / 100 ) AS DECIMAL(10, 2))),
|
|
SUM(CAST(IFNULL(i.stems, 1) * s.quantity AS DECIMAL(10, 2))),
|
|
su.countryFk,
|
|
CAST(SUM(IFNULL(i.stems, 1)
|
|
* s.quantity
|
|
* IF(ic.grams, ic.grams, IFNULL(i.weightByPiece, 0)) / 1000) AS DECIMAL(10, 2))
|
|
FROM sale s
|
|
JOIN ticket t ON s.ticketFk = t.id
|
|
JOIN supplier su ON su.id = t.companyFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
LEFT JOIN itemCost ic ON ic.itemFk = i.id AND ic.warehouseFk = t.warehouseFk
|
|
WHERE t.refFk = vNewRef
|
|
GROUP BY i.intrastatFk;
|
|
|
|
END IF;
|
|
DROP TEMPORARY TABLE tmp.ticket;
|
|
DROP TEMPORARY TABLE tmp.ticketAmount;
|
|
DROP TEMPORARY TABLE tmp.ticketTax;
|
|
DROP TEMPORARY TABLE tmp.ticketServiceTax;
|
|
END IF;
|
|
END IF;
|
|
DROP TEMPORARY TABLE `tmp`.`ticketToInvoice`;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingRadar`(vSectorFk INT)
|
|
proc:BEGIN
|
|
|
|
DECLARE vCalcVisibleFk INT;
|
|
DECLARE vCalcAvailableFk INT;
|
|
DECLARE hasFatherSector BOOLEAN;
|
|
DECLARE vBuyerFk INT DEFAULT 0;
|
|
DECLARE vWarehouseFk INT DEFAULT 0;
|
|
DECLARE vSonSectorFk INT;
|
|
DECLARE vWorkerFk INT;
|
|
|
|
SELECT s.workerFk
|
|
INTO vWorkerFk
|
|
FROM vn.sector s
|
|
WHERE s.id = vSectorFk;
|
|
|
|
SELECT w.id, s.warehouseFk INTO vBuyerFk, vWarehouseFk
|
|
FROM vn.worker w
|
|
JOIN vn.sector s ON s.code = w.code
|
|
WHERE s.id = vSectorFk;
|
|
|
|
SELECT s.id INTO vSectorFk
|
|
FROM vn.sector s
|
|
WHERE s.warehouseFk = vWarehouseFk
|
|
AND s.isMain;
|
|
|
|
SELECT COUNT(*) INTO hasFatherSector
|
|
FROM vn.sector
|
|
WHERE sonFk = vSectorFk;
|
|
|
|
SELECT warehouseFk, sonFk INTO vWarehouseFk, vSonSectorFk
|
|
FROM vn.sector
|
|
WHERE id = vSectorFk;
|
|
|
|
CALL cache.visible_refresh(vCalcVisibleFk, TRUE, vWarehouseFk);
|
|
CALL cache.available_refresh(vCalcAvailableFk, FALSE, vWarehouseFk, util.VN_CURDATE());
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemShelvingRadar;
|
|
|
|
IF hasFatherSector THEN
|
|
CREATE TEMPORARY TABLE tmp.itemShelvingRadar
|
|
(PRIMARY KEY (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT *
|
|
FROM (
|
|
SELECT iss.itemFk,
|
|
i.longName,
|
|
i.size,
|
|
i.subName producer,
|
|
IFNULL(a.available,0) available,
|
|
SUM(IF(s.sonFk = vSectorFk, IFNULL(iss.visible,0), 0)) upstairs,
|
|
SUM(IF(iss.sectorFk = vSectorFk, IFNULL(iss.visible,0), 0)) downstairs,
|
|
IF(it.isPackaging, NULL, IFNULL(v.visible,0)) as visible,
|
|
vSectorFk sectorFk
|
|
FROM vn.itemShelvingStock iss
|
|
JOIN vn.sector s ON s.id = iss.sectorFk
|
|
JOIN vn.item i on i.id = iss.itemFk
|
|
JOIN vn.itemType it ON it.id = i.typeFk AND vBuyerFk IN (0,it.workerFk)
|
|
LEFT JOIN cache.available a ON a.item_id = iss.itemFk AND a.calc_id = vCalcAvailableFk
|
|
LEFT JOIN cache.visible v ON v.item_id = iss.itemFk AND v.calc_id = vCalcVisibleFk
|
|
WHERE vSectorFk IN (iss.sectorFk, s.sonFk)
|
|
GROUP BY iss.itemFk
|
|
|
|
UNION ALL
|
|
|
|
SELECT v.item_id,
|
|
i.longName,
|
|
i.size,
|
|
i.subName producer,
|
|
IFNULL(a.available,0) as available,
|
|
0 upstairs,
|
|
0 downstairs,
|
|
IF(it.isPackaging, NULL, v.visible) visible,
|
|
vSectorFk as sectorFk
|
|
FROM cache.visible v
|
|
JOIN vn.item i on i.id = v.item_id
|
|
JOIN vn.itemType it ON it.id = i.typeFk AND vBuyerFk IN (0,it.workerFk)
|
|
LEFT JOIN vn.itemShelvingStock iss ON iss.itemFk = v.item_id AND iss.warehouseFk = vWarehouseFk
|
|
LEFT JOIN cache.available a ON a.item_id = v.item_id AND a.calc_id = vCalcAvailableFk
|
|
WHERE v.calc_id = vCalcVisibleFk
|
|
AND iss.itemFk IS NULL
|
|
AND it.isInventory
|
|
) sub GROUP BY itemFk;
|
|
|
|
SELECT ishr.*,
|
|
CAST(visible - upstairs - downstairs AS DECIMAL(10,0)) AS nicho,
|
|
CAST(downstairs - IFNULL(notPickedYed,0) AS DECIMAL(10,0)) as pendiente
|
|
FROM tmp.itemShelvingRadar ishr
|
|
JOIN vn.item i ON i.id = ishr.itemFk
|
|
LEFT JOIN (SELECT s.itemFk, sum(s.quantity) as notPickedYed
|
|
FROM vn.ticket t
|
|
JOIN vn.ticketStateToday tst ON tst.ticketFk = t.id
|
|
JOIN vn.sale s ON s.ticketFk = t.id
|
|
WHERE t.warehouseFk = vWarehouseFk
|
|
AND tst.alertLevel = 0
|
|
GROUP BY s.itemFk
|
|
) sub ON sub.itemFk = ishr.itemFk
|
|
ORDER BY i.typeFk, i.longName;
|
|
ELSE
|
|
CREATE TEMPORARY TABLE tmp.itemShelvingRadar
|
|
(PRIMARY KEY (itemFk))
|
|
ENGINE = MEMORY
|
|
SELECT iss.itemFk,
|
|
0 `hour`,
|
|
0 `minute`,
|
|
'--' itemPlacementCode,
|
|
i.longName,
|
|
i.size,
|
|
i.subName producer,
|
|
i.upToDown,
|
|
IFNULL(a.available,0) available,
|
|
IFNULL(v.visible - iss.visible,0) dayEndVisible,
|
|
IFNULL(v.visible - iss.visible,0) firstNegative,
|
|
IFNULL(v.visible - iss.visible,0) itemPlacementVisible,
|
|
IFNULL(i.minimum * b.packing,0) itemPlacementSize,
|
|
ips.onTheWay,
|
|
iss.visible itemShelvingStock,
|
|
IFNULL(v.visible,0) visible,
|
|
b.isPickedOff,
|
|
iss.sectorFk
|
|
FROM vn.itemShelvingStock iss
|
|
JOIN vn.item i on i.id = iss.itemFk
|
|
LEFT JOIN cache.last_buy lb ON lb.item_id = iss.itemFk AND lb.warehouse_id = vWarehouseFk
|
|
LEFT JOIN vn.buy b ON b.id = lb.buy_id
|
|
LEFT JOIN cache.available a ON a.item_id = iss.itemFk AND a.calc_id = vCalcAvailableFk
|
|
LEFT JOIN cache.visible v ON v.item_id = iss.itemFk AND v.calc_id = vCalcVisibleFk
|
|
LEFT JOIN (SELECT itemFk, sum(saldo) as onTheWay
|
|
FROM vn.itemPlacementSupplyList
|
|
WHERE saldo > 0
|
|
GROUP BY itemFk
|
|
) ips ON ips.itemFk = i.id
|
|
WHERE IFNULL(iss.sectorFk,0) IN (0, vSectorFk)
|
|
OR iss.sectorFk = vSectorFk;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.itemOutTime;
|
|
CREATE TEMPORARY TABLE tmp.itemOutTime
|
|
SELECT *,SUM(amount) quantity
|
|
FROM
|
|
(SELECT item_id itemFk,
|
|
amount,
|
|
IF(HOUR(t.shipped), HOUR(t.shipped), HOUR(z.`hour`)) as hours,
|
|
IF(MINUTE(t.shipped), MINUTE(t.shipped), MINUTE(z.`hour`)) as minutes
|
|
FROM vn2008.item_out io
|
|
JOIN tmp.itemShelvingRadar isr ON isr.itemFk = io.item_id
|
|
JOIN vn.ticket t on t.id= io.ticketFk
|
|
JOIN vn.ticketState ts on ts.ticketFk = io.ticketFk
|
|
JOIN vn.state s ON s.id = ts.stateFk
|
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
|
LEFT JOIN (SELECT DISTINCT saleFk
|
|
FROM vn.saleTracking st
|
|
WHERE st.created > util.VN_CURDATE()
|
|
AND st.isChecked
|
|
) stPrevious ON `stPrevious`.`saleFk` = io.saleFk
|
|
WHERE t.warehouseFk = vWarehouseFk
|
|
AND s.isPicked = 0
|
|
AND NOT io.Reservado
|
|
AND stPrevious.saleFk IS NULL
|
|
AND io.dat >= util.VN_CURDATE()
|
|
AND io.dat < util.VN_CURDATE() + INTERVAL 1 DAY
|
|
) sub
|
|
GROUP BY itemFk, hours, minutes;
|
|
|
|
INSERT INTO tmp.itemShelvingRadar (itemFk)
|
|
SELECT itemFk FROM tmp.itemOutTime
|
|
ON DUPLICATE KEY UPDATE dayEndVisible = dayEndVisible + quantity,
|
|
firstNegative = if (firstNegative < 0, firstNegative, firstNegative + quantity),
|
|
`hour` = ifnull(if (firstNegative > 0 , `hour`, hours),0),
|
|
`minute` = ifnull(if (firstNegative > 0, `minute`, minutes),0);
|
|
|
|
UPDATE tmp.itemShelvingRadar isr
|
|
JOIN (SELECT s.itemFk, sum(s.quantity) amount
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
JOIN ticketLastState tls ON tls.ticketFk = t.id
|
|
WHERE t.shipped BETWEEN util.VN_CURDATE() AND util.dayend(util.VN_CURDATE())
|
|
AND tls.name = 'Prep Camara'
|
|
GROUP BY s.itemFk) sub ON sub.itemFk = isr.itemFk
|
|
SET isr.dayEndVisible = dayEndVisible + sub.amount,
|
|
firstNegative = firstNegative + sub.amount;
|
|
|
|
SELECT * FROM tmp.itemShelvingRadar;
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE tmp.itemShelvingRadar;
|
|
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getBalance`(
|
|
vItemFk INT,
|
|
vWarehouseFk INT,
|
|
vDate DATETIME
|
|
)
|
|
BEGIN
|
|
/**
|
|
* @vItemFk item a buscar
|
|
* @vWarehouseFk almacen donde buscar
|
|
* @vDate Si la fecha es null, muestra el histórico desde el inventario.
|
|
* Si la fecha no es null, muestra histórico desde la fecha pasada.
|
|
*/
|
|
DECLARE vDateInventory DATETIME;
|
|
|
|
IF vDate IS NULL THEN
|
|
SELECT inventoried INTO vDateInventory
|
|
FROM config;
|
|
ELSE
|
|
SELECT mockUtcTime INTO vDateInventory
|
|
FROM util.config;
|
|
END IF;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tItemDiary(
|
|
shipped DATE,
|
|
`in` INT(11),
|
|
`out` INT(11),
|
|
alertLevel INT(11),
|
|
stateName VARCHAR(20),
|
|
`name` VARCHAR(50),
|
|
reference VARCHAR(50),
|
|
origin INT(11),
|
|
clientFk INT(11),
|
|
isPicked INT(11),
|
|
isTicket TINYINT(1),
|
|
lineFk INT(11),
|
|
`order` TINYINT(3) UNSIGNED,
|
|
clientType VARCHAR(20),
|
|
claimFk INT(10) UNSIGNED,
|
|
inventorySupplierFk INT(10)
|
|
);
|
|
|
|
INSERT INTO tItemDiary
|
|
SELECT tr.landed shipped,
|
|
b.quantity `in`,
|
|
NULL `out`,
|
|
st.alertLevel ,
|
|
st.name stateName,
|
|
s.name `name`,
|
|
e.invoiceNumber reference,
|
|
e.id origin,
|
|
s.id clientFk,
|
|
IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked,
|
|
FALSE isTicket,
|
|
b.id lineFk,
|
|
NULL `order`,
|
|
NULL clientType,
|
|
NULL claimFk,
|
|
ec.inventorySupplierFk
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN supplier s ON s.id = e.supplierFk
|
|
JOIN state st ON st.`code` = IF( tr.landed < util.VN_CURDATE()
|
|
OR (util.VN_CURDATE() AND tr.isReceived),
|
|
'DELIVERED',
|
|
'FREE')
|
|
JOIN entryConfig ec
|
|
WHERE tr.landed >= vDateInventory
|
|
AND vWarehouseFk = tr.warehouseInFk
|
|
AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL)
|
|
AND b.itemFk = vItemFk
|
|
AND e.isExcludedFromAvailable = FALSE
|
|
AND e.isRaid = FALSE
|
|
UNION ALL
|
|
SELECT tr.shipped,
|
|
NULL,
|
|
b.quantity,
|
|
st.alertLevel,
|
|
st.name,
|
|
s.name,
|
|
e.invoiceNumber,
|
|
e.id,
|
|
s.id,
|
|
IF(st.`code` = 'DELIVERED' , TRUE, FALSE),
|
|
FALSE,
|
|
b.id,
|
|
NULL,
|
|
NULL,
|
|
NULL,
|
|
ec.inventorySupplierFk
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel tr ON tr.id = e.travelFk
|
|
JOIN warehouse w ON w.id = tr.warehouseOutFk
|
|
JOIN supplier s ON s.id = e.supplierFk
|
|
JOIN state st ON st.`code` = IF(tr.shipped < util.VN_CURDATE()
|
|
OR (tr.shipped = util.VN_CURDATE() AND tr.isReceived),
|
|
'DELIVERED',
|
|
'FREE')
|
|
JOIN entryConfig ec
|
|
WHERE tr.shipped >= vDateInventory
|
|
AND vWarehouseFk = tr.warehouseOutFk
|
|
AND (s.id <> ec.inventorySupplierFk OR vDate IS NULL)
|
|
AND b.itemFk = vItemFk
|
|
AND e.isExcludedFromAvailable = FALSE
|
|
AND w.isFeedStock = FALSE
|
|
AND e.isRaid = FALSE
|
|
UNION ALL
|
|
SELECT DATE(t.shipped),
|
|
NULL,
|
|
s.quantity,
|
|
st2.alertLevel,
|
|
st2.name,
|
|
t.nickname,
|
|
t.refFk,
|
|
t.id,
|
|
t.clientFk,
|
|
stk.id,
|
|
TRUE,
|
|
s.id,
|
|
st.`order`,
|
|
ct.`code`,
|
|
cb.claimFk,
|
|
NULL
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
LEFT JOIN ticketState ts ON ts.ticketFk = t.id
|
|
LEFT JOIN state st ON st.`code` = ts.`code`
|
|
JOIN client c ON c.id = t.clientFk
|
|
JOIN clientType ct ON ct.id = c.clientTypeFk
|
|
JOIN state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(),
|
|
'DELIVERED',
|
|
IF (t.shipped > util.dayEnd(util.VN_CURDATE()),
|
|
'FREE',
|
|
IFNULL(ts.code, 'FREE')))
|
|
LEFT JOIN state stPrep ON stPrep.`code` = 'PREPARED'
|
|
LEFT JOIN saleTracking stk ON stk.saleFk = s.id
|
|
AND stk.stateFk = stPrep.id
|
|
LEFT JOIN claimBeginning cb ON s.id = cb.saleFk
|
|
WHERE t.shipped >= vDateInventory
|
|
AND s.itemFk = vItemFk
|
|
AND vWarehouseFk =t.warehouseFk
|
|
ORDER BY shipped,
|
|
(inventorySupplierFk = clientFk) DESC,
|
|
alertLevel DESC,
|
|
isTicket,
|
|
`order` DESC,
|
|
isPicked DESC,
|
|
`in` DESC,
|
|
`out` DESC;
|
|
|
|
IF vDate IS NULL THEN
|
|
|
|
SET @a := 0;
|
|
SET @currentLineFk := 0;
|
|
SET @shipped := '';
|
|
|
|
SELECT DATE(@shipped:= shipped) shipped,
|
|
alertLevel,
|
|
stateName,
|
|
origin,
|
|
reference,
|
|
clientFk,
|
|
name,
|
|
`in` invalue,
|
|
`out`,
|
|
@a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0) balance,
|
|
@currentLineFk := IF (@shipped < util.VN_CURDATE()
|
|
OR (@shipped = util.VN_CURDATE() AND (isPicked OR a.`code` >= 'ON_PREPARATION')),
|
|
lineFk,
|
|
@currentLineFk) lastPreparedLineFk,
|
|
isTicket,
|
|
lineFk,
|
|
isPicked,
|
|
clientType,
|
|
claimFk
|
|
FROM tItemDiary
|
|
LEFT JOIN alertLevel a ON a.id = tItemDiary.alertLevel;
|
|
|
|
ELSE
|
|
SELECT SUM(`in`) - SUM(`out`) INTO @a
|
|
FROM tItemDiary
|
|
WHERE shipped < vDate;
|
|
|
|
SELECT vDate shipped,
|
|
0 alertLevel,
|
|
0 stateName,
|
|
0 origin,
|
|
'' reference,
|
|
0 clientFk,
|
|
'Inventario calculado',
|
|
@a invalue,
|
|
NULL `out`,
|
|
@a balance,
|
|
0 lastPreparedLineFk,
|
|
0 isTicket,
|
|
0 lineFk,
|
|
0 isPicked,
|
|
0 clientType,
|
|
0 claimFk
|
|
UNION ALL
|
|
SELECT shipped,
|
|
alertlevel,
|
|
stateName,
|
|
origin,
|
|
reference,
|
|
clientFk,
|
|
name, `in`,
|
|
`out`,
|
|
@a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0),
|
|
0,
|
|
isTicket,
|
|
lineFk,
|
|
isPicked,
|
|
clientType,
|
|
claimFk
|
|
FROM tItemDiary
|
|
WHERE shipped >= vDate;
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE tItemDiary;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`productionControl`(
|
|
vWarehouseFk INT,
|
|
vScopeDays INT
|
|
)
|
|
proc: BEGIN
|
|
/**
|
|
* Devuelve un listado de tickets con parámetros relativos a la producción de los días en rango.
|
|
*
|
|
* @param vWarehouseFk Identificador de warehouse
|
|
* @param vScopeDays Número de días desde hoy en adelante que entran en el cálculo.
|
|
*
|
|
* @return Table tmp.productionBuffer
|
|
*/
|
|
DECLARE vEndingDate DATETIME;
|
|
DECLARE vIsTodayRelative BOOLEAN;
|
|
|
|
SELECT util.dayEnd(util.VN_CURDATE()) + INTERVAL LEAST(vScopeDays, maxProductionScopeDays) DAY
|
|
INTO vEndingDate
|
|
FROM productionConfig;
|
|
|
|
SELECT isTodayRelative INTO vIsTodayRelative
|
|
FROM worker
|
|
WHERE id = getUser(); -- Cambiar por account.myUser_getId(), falta dar permisos
|
|
|
|
CALL prepareTicketList(util.yesterday(), vEndingDate);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
|
SELECT * FROM tmp.productionTicket;
|
|
|
|
CALL prepareClientList();
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.sale_getProblems
|
|
(INDEX (ticketFk)) ENGINE = MEMORY
|
|
SELECT tt.ticketFk, tt.clientFk, t.warehouseFk, t.shipped
|
|
FROM tmp.productionTicket tt
|
|
JOIN ticket t ON t.id = tt.ticketFk;
|
|
|
|
CALL ticket_getProblems(vIsTodayRelative);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.productionBuffer
|
|
(PRIMARY KEY(ticketFk), previaParking VARCHAR(255))
|
|
ENGINE = MEMORY
|
|
SELECT tt.ticketFk,
|
|
tt.clientFk,
|
|
t.warehouseFk,
|
|
t.nickname,
|
|
t.packages,
|
|
IF(HOUR(t.shipped), HOUR(t.shipped), COALESCE(HOUR(zc.hour),HOUR(z.hour))) HH,
|
|
COALESCE(HOUR(zc.hour), HOUR(z.hour)) Departure,
|
|
COALESCE(MINUTE(t.shipped), MINUTE(zc.hour), MINUTE(z.hour)) mm,
|
|
t.routeFk,
|
|
IF(dm.code = 'DELIVERY', z.`id`, 0) zona,
|
|
t.nickname addressNickname,
|
|
a.postalCode,
|
|
a.city,
|
|
p.name province,
|
|
CONCAT(z.`name`,' ',IFNULL(RIGHT(t.routeFk,3),'')) agency,
|
|
am.id agencyModeFk,
|
|
0 `lines`,
|
|
CAST( 0 AS DECIMAL(5,2)) m3,
|
|
CAST( 0 AS DECIMAL(5,2)) preparationRate,
|
|
"" problem,
|
|
IFNULL(tls.state,2) state,
|
|
w.code workerCode,
|
|
DATE(t.shipped) shipped,
|
|
wk.code salesPersonCode,
|
|
p.id provinceFk,
|
|
tls.productionOrder,
|
|
IFNULL(tls.alertLevel, 0) alertLevel,
|
|
t.isBoxed palletized,
|
|
IF(rm.isPickingAllowed, rm.bufferFk, NULL) ubicacion,
|
|
tlu.lastUpdated,
|
|
IFNULL(st.graphCategory, 0) graphCategory,
|
|
pk.code parking,
|
|
0 H,
|
|
0 V,
|
|
0 N,
|
|
st.isOk,
|
|
ag.isOwn,
|
|
rm.bufferFk
|
|
FROM tmp.productionTicket tt
|
|
JOIN ticket t ON tt.ticketFk = t.id
|
|
LEFT JOIN ticketStateToday tst ON tst.ticket = t.id
|
|
LEFT JOIN state st ON st.id = tst.state
|
|
LEFT JOIN client c ON c.id = t.clientFk
|
|
LEFT JOIN worker wk ON wk.id = c.salesPersonFk
|
|
JOIN address a ON a.id = t.addressFk
|
|
LEFT JOIN province p ON p.id = a.provinceFk
|
|
JOIN agencyMode am ON am.id = t.agencyModeFk
|
|
JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk
|
|
JOIN agency ag ON ag.id = am.agencyFk
|
|
LEFT JOIN ticketState tls ON tls.ticketFk = tt.ticketFk
|
|
LEFT JOIN ticketLastUpdated tlu ON tlu.ticketFk = tt.ticketFk
|
|
LEFT JOIN worker w ON w.id = tls.userFk
|
|
LEFT JOIN routesMonitor rm ON rm.routeFk = t.routeFk
|
|
LEFT JOIN `zone` z ON z.id = t.zoneFk
|
|
LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk
|
|
AND DATE(t.shipped) = zc.dated
|
|
LEFT JOIN ticketParking tp ON tp.ticketFk = t.id
|
|
LEFT JOIN parking pk ON pk.id = tp.parkingFk
|
|
WHERE t.warehouseFk = vWarehouseFk
|
|
AND dm.code IN ('AGENCY', 'DELIVERY', 'PICKUP');
|
|
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN (
|
|
SELECT pb.ticketFk, GROUP_CONCAT(p.code) previaParking
|
|
FROM tmp.productionBuffer pb
|
|
JOIN sale s ON s.ticketFk = pb.ticketFk
|
|
JOIN saleGroupDetail sgd ON sgd.saleFk = s.id
|
|
JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
|
|
JOIN parking p ON p.id = sg.parkingFk
|
|
GROUP BY pb.ticketFk
|
|
) t ON t.ticketFk = pb.ticketFk
|
|
SET pb.previaParking = t.previaParking;
|
|
|
|
-- Problemas por ticket
|
|
ALTER TABLE tmp.productionBuffer
|
|
CHANGE COLUMN `problem` `problem` VARCHAR(255),
|
|
ADD COLUMN `collectionH` INT,
|
|
ADD COLUMN `collectionV` INT,
|
|
ADD COLUMN `collectionN` INT;
|
|
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN tmp.ticket_problems tp ON tp.ticketFk = pb.ticketFk
|
|
SET pb.problem = TRIM(CAST(CONCAT( IFNULL(tp.itemShortage, ''),
|
|
IFNULL(tp.itemDelay, ''),
|
|
IFNULL(tp.itemLost, ''),
|
|
IF(tp.isFreezed, ' CONGELADO',''),
|
|
IF(tp.hasHighRisk, ' RIESGO',''),
|
|
IF(tp.hasTicketRequest, ' COD 100',''),
|
|
IF(tp.isTaxDataChecked, '',' FICHA INCOMPLETA'),
|
|
IF(tp.hasComponentLack, ' COMPONENTES', ''),
|
|
IF(HOUR(util.VN_NOW()) < pb.HH AND tp.isTooLittle, ' PEQUEÑO', '')
|
|
) AS char(255)));
|
|
|
|
-- Clientes Nuevos o Recuperados
|
|
UPDATE tmp.productionBuffer pb
|
|
LEFT JOIN bs.clientNewBorn cnb ON cnb.clientFk = pb.clientFk
|
|
JOIN productionConfig pc
|
|
SET pb.problem = TRIM(CAST(CONCAT('NUEVO ', pb.problem) AS CHAR(255)))
|
|
WHERE (cnb.clientFk IS NULL OR cnb.isRookie)
|
|
AND pc.rookieDays;
|
|
|
|
-- Líneas y volumen por ticket
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN (
|
|
SELECT tt.ticketFk,
|
|
COUNT(*) `lines`,
|
|
SUM(sv.volume) m3,
|
|
IFNULL(SUM(IF(sv.isPicked, sv.volume, 0)) / SUM(sv.volume), 0) rate
|
|
FROM tmp.productionTicket tt
|
|
JOIN saleVolume sv ON sv.ticketFk = tt.ticketFk
|
|
GROUP BY tt.ticketFk
|
|
) m ON m.ticketFk = pb.ticketFk
|
|
SET pb.`lines` = m.`lines`,
|
|
pb.m3 = m.m3,
|
|
pb.preparationRate = m.rate;
|
|
|
|
DELETE FROM tmp.productionBuffer
|
|
WHERE NOT `lines`;
|
|
|
|
-- Lineas por linea de encajado
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN (
|
|
SELECT ticketFk,
|
|
SUM(sub.H) H,
|
|
SUM(sub.V) V,
|
|
SUM(sub.N) N
|
|
FROM (
|
|
SELECT t.ticketFk,
|
|
SUM(i.itemPackingTypeFk = 'H') H,
|
|
SUM(i.itemPackingTypeFk = 'V') V,
|
|
SUM(i.itemPackingTypeFk IS NULL) N
|
|
FROM tmp.productionTicket t
|
|
JOIN sale s ON s.ticketFk = t.ticketFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
GROUP BY t.ticketFk, i.itemPackingTypeFk
|
|
) sub
|
|
GROUP BY ticketFk
|
|
) sub2 ON sub2.ticketFk = pb.ticketFk
|
|
SET pb.H = sub2.H,
|
|
pb.V = sub2.V,
|
|
pb.N = sub2.N;
|
|
|
|
-- Colecciones segun tipo de encajado
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN ticketCollection tc ON pb.ticketFk = tc.ticketFk
|
|
SET pb.collectionH = IF(pb.H, tc.collectionFk, NULL),
|
|
pb.collectionV = IF(pb.V, tc.collectionFk, NULL),
|
|
pb.collectionN = IF(pb.N, tc.collectionFk, NULL);
|
|
|
|
-- Previa pendiente
|
|
ALTER TABLE tmp.productionBuffer
|
|
ADD previousWithoutParking BOOL DEFAULT FALSE;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketWithPrevia
|
|
(ticketFk INT PRIMARY KEY,
|
|
salesCount INT DEFAULT 0,
|
|
salesInParkingCount INT DEFAULT 0)
|
|
ENGINE = MEMORY;
|
|
|
|
-- Insertamos todos los tickets que tienen productos parkineados
|
|
-- en sectores de previa, segun el sector
|
|
CREATE OR REPLACE TEMPORARY TABLE tItemShelvingStock
|
|
(PRIMARY KEY(itemFk, sectorFk))
|
|
ENGINE = MEMORY
|
|
SELECT ish.itemFk,
|
|
p.sectorFk,
|
|
sc.isPreviousPrepared,
|
|
sc.itemPackingTypeFk
|
|
FROM itemShelving ish
|
|
JOIN shelving sh ON sh.code = ish.shelvingFk
|
|
JOIN parking p ON p.id = sh.parkingFk
|
|
JOIN sector sc ON sc.id = p.sectorFk
|
|
WHERE p.sectorFk
|
|
AND ish.visible
|
|
GROUP BY ish.itemFk, p.sectorFk;
|
|
|
|
INSERT INTO tmp.ticketWithPrevia(ticketFk, salesCount)
|
|
SELECT pb.ticketFk, COUNT(DISTINCT s.id)
|
|
FROM tmp.productionBuffer pb
|
|
JOIN sale s ON s.ticketFk = pb.ticketFk
|
|
JOIN tItemShelvingStock iss ON iss.itemFk = s.itemFk
|
|
JOIN sector sc ON sc.id = iss.sectorFk
|
|
JOIN item i ON i.id = iss.itemFk
|
|
WHERE iss.isPreviousPrepared
|
|
AND (sc.itemPackingTypeFk IS NULL
|
|
OR (i.itemPackingTypeFk IS NULL AND NOT pb.V)
|
|
OR sc.itemPackingTypeFk = i.itemPackingTypeFk)
|
|
AND s.quantity > 0
|
|
GROUP BY pb.ticketFk;
|
|
|
|
-- Se calcula la cantidad de productos que estan ya preparados porque su saleGroup está aparcado
|
|
UPDATE tmp.ticketWithPrevia twp
|
|
JOIN (
|
|
SELECT pb.ticketFk, COUNT(DISTINCT s.id) salesInParkingCount
|
|
FROM tmp.productionBuffer pb
|
|
JOIN sale s ON s.ticketFk = pb.ticketFk
|
|
JOIN saleGroupDetail sgd ON sgd.saleFk = s.id
|
|
JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
|
|
WHERE sg.parkingFk IS NOT NULL
|
|
AND s.quantity > 0
|
|
GROUP BY pb.ticketFk
|
|
) sub ON twp.ticketFk = sub.ticketFk
|
|
SET twp.salesInParkingCount = sub.salesInParkingCount;
|
|
|
|
-- Marcamos como pendientes aquellos que no coinciden las cantidades
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN tmp.ticketWithPrevia twp ON twp.ticketFk = pb.ticketFk
|
|
SET pb.previousWithoutParking = TRUE
|
|
WHERE twp.salesCount > twp.salesInParkingCount;
|
|
|
|
DROP TEMPORARY TABLE
|
|
tmp.productionTicket,
|
|
tmp.ticket,
|
|
tmp.risk,
|
|
tmp.ticket_problems,
|
|
tmp.ticketWithPrevia,
|
|
tItemShelvingStock;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`expedition_beforeInsert`
|
|
BEFORE INSERT ON `expedition`
|
|
FOR EACH ROW
|
|
BEGIN
|
|
DECLARE intcounter INT;
|
|
DECLARE vShipFk INT;
|
|
|
|
SET NEW.editorFk = account.myUser_getId();
|
|
|
|
IF NEW.freightItemFk IS NOT NULL THEN
|
|
|
|
UPDATE ticket SET packages = nz(packages) + 1 WHERE id = NEW.ticketFk;
|
|
|
|
SELECT IFNULL(MAX(counter),0) +1 INTO intcounter
|
|
FROM expedition e
|
|
INNER JOIN ticket t1 ON e.ticketFk = t1.id
|
|
LEFT JOIN ticketState ts ON ts.ticketFk = t1.id
|
|
INNER JOIN ticket t2 ON t2.addressFk = t1.addressFk AND DATE(t2.shipped) = DATE(t1.shipped)
|
|
AND t1.warehouseFk = t2.warehouseFk
|
|
WHERE t2.id = NEW.ticketFk AND ts.alertLevel < 3 AND t1.companyFk = t2.companyFk
|
|
AND t1.agencyModeFk = t2.agencyModeFk;
|
|
|
|
SET NEW.`counter` = intcounter;
|
|
END IF;
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_recalcComponent`(vOption INT)
|
|
proc: BEGIN
|
|
/**
|
|
* Este procedimiento recalcula los componentes de un conjunto de sales,
|
|
* eliminando los componentes existentes e insertandolos de nuevo
|
|
*
|
|
* @param vOption si no se quiere forzar llamar con NULL
|
|
* @table tmp.recalculateSales (id)
|
|
*/
|
|
DECLARE vShipped DATE;
|
|
DECLARE vWarehouseFk SMALLINT;
|
|
DECLARE vAgencyModeFk INT;
|
|
DECLARE vAddressFk INT;
|
|
DECLARE vTicketFk INT;
|
|
DECLARE vLanded DATE;
|
|
DECLARE vIsEditable BOOLEAN;
|
|
DECLARE vZoneFk INTEGER;
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
|
|
DECLARE vCur CURSOR FOR
|
|
SELECT DISTINCT s.ticketFk
|
|
FROM tmp.recalculateSales rs
|
|
JOIN vn.sale s ON s.id = rs.id;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
OPEN vCur;
|
|
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vCur INTO vTicketFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
SELECT (hasToRecalcPrice OR ts.alertLevel IS NULL) AND t.refFk IS NULL,
|
|
t.zoneFk,
|
|
t.warehouseFk,
|
|
t.shipped,
|
|
t.addressFk,
|
|
t.agencyModeFk,
|
|
t.landed
|
|
INTO vIsEditable,
|
|
vZoneFk,
|
|
vWarehouseFk,
|
|
vShipped,
|
|
vAddressFk,
|
|
vAgencyModeFk,
|
|
vLanded
|
|
FROM ticket t
|
|
LEFT JOIN ticketState ts ON t.id = ts.ticketFk
|
|
LEFT JOIN alertLevel al ON al.id = ts.alertLevel
|
|
WHERE t.id = vTicketFk;
|
|
|
|
CALL zone_getLanded(vShipped, vAddressFk, vAgencyModeFk, vWarehouseFk, TRUE);
|
|
|
|
IF NOT EXISTS (SELECT TRUE FROM tmp.zoneGetLanded LIMIT 1) THEN
|
|
CALL util.throw(CONCAT('There is no zone for these parameters ', vTicketFk));
|
|
END IF;
|
|
|
|
IF vLanded IS NULL OR vZoneFk IS NULL THEN
|
|
|
|
UPDATE ticket t
|
|
SET t.landed = (SELECT landed FROM tmp.zoneGetLanded LIMIT 1)
|
|
WHERE t.id = vTicketFk AND t.landed IS NULL;
|
|
|
|
IF vZoneFk IS NULL THEN
|
|
SELECT zoneFk INTO vZoneFk FROM tmp.zoneGetLanded LIMIT 1;
|
|
UPDATE ticket t
|
|
SET t.zoneFk = vZoneFk
|
|
WHERE t.id = vTicketFk AND t.zoneFk IS NULL;
|
|
END IF;
|
|
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE tmp.zoneGetLanded;
|
|
|
|
-- rellena la tabla buyUltimate con la ultima compra
|
|
CALL buyUltimate (vWarehouseFk, vShipped);
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
|
(PRIMARY KEY (saleFk)) ENGINE = MEMORY
|
|
SELECT s.id saleFk, vWarehouseFk warehouseFk
|
|
FROM sale s
|
|
JOIN tmp.recalculateSales rs ON s.id = rs.id
|
|
WHERE s.ticketFk = vTicketFk;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketLot
|
|
SELECT vWarehouseFk warehouseFk, NULL available, s.itemFk, bu.buyFk, vZoneFk zoneFk
|
|
FROM sale s
|
|
JOIN tmp.recalculateSales rs ON s.id = rs.id
|
|
LEFT JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
|
WHERE s.ticketFk = vTicketFk
|
|
GROUP BY s.itemFk;
|
|
|
|
CALL catalog_componentPrepare();
|
|
CALL catalog_componentCalculate(vZoneFk, vAddressFk, vShipped, vWarehouseFk);
|
|
|
|
IF vOption IS NULL THEN
|
|
SET vOption = IF(vIsEditable, 1, 6);
|
|
END IF;
|
|
|
|
CALL ticketComponentUpdateSale(vOption);
|
|
CALL catalog_componentPurge();
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
|
|
END LOOP;
|
|
CLOSE vCur;
|
|
|
|
END$$
|
|
DELIMITER ;
|
|
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`invoiceOut_new`(
|
|
vSerial VARCHAR(255),
|
|
vInvoiceDate DATE,
|
|
vTaxArea VARCHAR(25),
|
|
OUT vNewInvoiceId INT)
|
|
BEGIN
|
|
/**
|
|
* Creación de facturas emitidas.
|
|
* requiere previamente tabla tmp.ticketToInvoice(id).
|
|
*
|
|
* @param vSerial serie a la cual se hace la factura
|
|
* @param vInvoiceDate fecha de la factura
|
|
* @param vTaxArea tipo de iva en relacion a la empresa y al cliente
|
|
* @param vNewInvoiceId id de la factura que se acaba de generar
|
|
* @return vNewInvoiceId
|
|
*/
|
|
DECLARE vIsAnySaleToInvoice BOOL;
|
|
DECLARE vIsAnyServiceToInvoice BOOL;
|
|
DECLARE vNewRef VARCHAR(255);
|
|
DECLARE vWorker INT DEFAULT account.myUser_getId();
|
|
DECLARE vCompanyFk INT;
|
|
DECLARE vInterCompanyFk INT;
|
|
DECLARE vClientFk INT;
|
|
DECLARE vCplusStandardInvoiceTypeFk INT DEFAULT 1;
|
|
DECLARE vCplusCorrectingInvoiceTypeFk INT DEFAULT 6;
|
|
DECLARE vCplusSimplifiedInvoiceTypeFk INT DEFAULT 2;
|
|
DECLARE vCorrectingSerial VARCHAR(1) DEFAULT 'R';
|
|
DECLARE vSimplifiedSerial VARCHAR(1) DEFAULT 'S';
|
|
DECLARE vNewInvoiceInFk INT;
|
|
DECLARE vIsInterCompany BOOL DEFAULT FALSE;
|
|
DECLARE vIsCEESerial BOOL DEFAULT FALSE;
|
|
DECLARE vIsCorrectInvoiceDate BOOL;
|
|
DECLARE vMaxShipped DATE;
|
|
DECLARE vDone BOOL;
|
|
DECLARE vTicketFk INT;
|
|
DECLARE vCursor CURSOR FOR
|
|
SELECT id
|
|
FROM tmp.ticketToInvoice;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
SET vInvoiceDate = IFNULL(vInvoiceDate, util.VN_CURDATE());
|
|
|
|
SELECT t.clientFk,
|
|
t.companyFk,
|
|
MAX(DATE(t.shipped)),
|
|
DATE(vInvoiceDate) >= invoiceOut_getMaxIssued(
|
|
vSerial,
|
|
t.companyFk,
|
|
YEAR(vInvoiceDate))
|
|
INTO vClientFk,
|
|
vCompanyFk,
|
|
vMaxShipped,
|
|
vIsCorrectInvoiceDate
|
|
FROM tmp.ticketToInvoice tt
|
|
JOIN ticket t ON t.id = tt.id;
|
|
|
|
IF(vMaxShipped > vInvoiceDate) THEN
|
|
CALL util.throw("Invoice date can't be less than max date");
|
|
END IF;
|
|
|
|
IF NOT vIsCorrectInvoiceDate THEN
|
|
CALL util.throw('Exists an invoice with a previous date');
|
|
END IF;
|
|
|
|
-- Eliminem de tmp.ticketToInvoice els tickets que no han de ser facturats
|
|
DELETE ti.*
|
|
FROM tmp.ticketToInvoice ti
|
|
JOIN ticket t ON t.id = ti.id
|
|
JOIN sale s ON s.ticketFk = t.id
|
|
JOIN item i ON i.id = s.itemFk
|
|
JOIN supplier su ON su.id = t.companyFk
|
|
JOIN client c ON c.id = t.clientFk
|
|
LEFT JOIN itemTaxCountry itc ON itc.itemFk = i.id AND itc.countryFk = su.countryFk
|
|
WHERE (YEAR(t.shipped) < 2001 AND t.isDeleted)
|
|
OR c.isTaxDataChecked = FALSE
|
|
OR t.isDeleted
|
|
OR c.hasToInvoice = FALSE
|
|
OR itc.id IS NULL;
|
|
|
|
SELECT SUM(s.quantity * s.price * (100 - s.discount)/100) <> 0
|
|
INTO vIsAnySaleToInvoice
|
|
FROM tmp.ticketToInvoice t
|
|
JOIN sale s ON s.ticketFk = t.id;
|
|
|
|
SELECT COUNT(*) > 0 INTO vIsAnyServiceToInvoice
|
|
FROM tmp.ticketToInvoice t
|
|
JOIN ticketService ts ON ts.ticketFk = t.id;
|
|
|
|
IF (vIsAnySaleToInvoice OR vIsAnyServiceToInvoice)
|
|
AND (vCorrectingSerial = vSerial OR NOT hasAnyNegativeBase())
|
|
THEN
|
|
|
|
-- el trigger añade el siguiente Id_Factura correspondiente a la vSerial
|
|
INSERT INTO invoiceOut(
|
|
ref,
|
|
serial,
|
|
issued,
|
|
clientFk,
|
|
dued,
|
|
companyFk,
|
|
siiTypeInvoiceOutFk
|
|
)
|
|
SELECT
|
|
1,
|
|
vSerial,
|
|
vInvoiceDate,
|
|
vClientFk,
|
|
getDueDate(vInvoiceDate, dueDay),
|
|
vCompanyFk,
|
|
IF(vSerial = vCorrectingSerial,
|
|
vCplusCorrectingInvoiceTypeFk,
|
|
IF(vSerial = vSimplifiedSerial,
|
|
vCplusSimplifiedInvoiceTypeFk,
|
|
vCplusStandardInvoiceTypeFk))
|
|
FROM client
|
|
WHERE id = vClientFk;
|
|
|
|
SET vNewInvoiceId = LAST_INSERT_ID();
|
|
|
|
SELECT `ref`
|
|
INTO vNewRef
|
|
FROM invoiceOut
|
|
WHERE id = vNewInvoiceId;
|
|
|
|
OPEN vCursor;
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vCursor INTO vTicketFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
CALL ticket_recalc(vTicketFk, vTaxArea);
|
|
|
|
END LOOP;
|
|
CLOSE vCursor;
|
|
|
|
UPDATE ticket t
|
|
JOIN tmp.ticketToInvoice ti ON ti.id = t.id
|
|
SET t.refFk = vNewRef;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.updateInter;
|
|
CREATE TEMPORARY TABLE tmp.updateInter ENGINE = MEMORY
|
|
SELECT s.id,ti.id ticket_id,vWorker Id_Trabajador
|
|
FROM tmp.ticketToInvoice ti
|
|
LEFT JOIN ticketState ts ON ti.id = ts.ticketFk
|
|
JOIN state s
|
|
WHERE IFNULL(ts.alertLevel,0) < 3 and s.`code` = getAlert3State(ti.id);
|
|
|
|
INSERT INTO ticketTracking(stateFk,ticketFk,userFk)
|
|
SELECT * FROM tmp.updateInter;
|
|
|
|
CALL invoiceExpenseMake(vNewInvoiceId);
|
|
CALL invoiceTaxMake(vNewInvoiceId,vTaxArea);
|
|
|
|
UPDATE invoiceOut io
|
|
JOIN (
|
|
SELECT SUM(amount) total
|
|
FROM invoiceOutExpense
|
|
WHERE invoiceOutFk = vNewInvoiceId
|
|
) base
|
|
JOIN (
|
|
SELECT SUM(vat) total
|
|
FROM invoiceOutTax
|
|
WHERE invoiceOutFk = vNewInvoiceId
|
|
) vat
|
|
SET io.amount = base.total + vat.total
|
|
WHERE io.id = vNewInvoiceId;
|
|
|
|
DROP TEMPORARY TABLE tmp.updateInter;
|
|
|
|
SELECT COUNT(*), id
|
|
INTO vIsInterCompany, vInterCompanyFk
|
|
FROM company
|
|
WHERE clientFk = vClientFk;
|
|
|
|
IF (vIsInterCompany) THEN
|
|
|
|
INSERT INTO invoiceIn(supplierFk, supplierRef, issued, companyFk)
|
|
SELECT vCompanyFk, vNewRef, vInvoiceDate, vInterCompanyFk;
|
|
|
|
SET vNewInvoiceInFk = LAST_INSERT_ID();
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.ticket;
|
|
CREATE TEMPORARY TABLE tmp.ticket
|
|
(KEY (ticketFk))
|
|
ENGINE = MEMORY
|
|
SELECT id ticketFk
|
|
FROM tmp.ticketToInvoice;
|
|
|
|
CALL `ticket_getTax`('NATIONAL');
|
|
|
|
SET @vTaxableBaseServices := 0.00;
|
|
SET @vTaxCodeGeneral := NULL;
|
|
|
|
INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk)
|
|
SELECT vNewInvoiceInFk,
|
|
@vTaxableBaseServices,
|
|
sub.expenseFk,
|
|
sub.taxTypeSageFk,
|
|
sub.transactionTypeSageFk
|
|
FROM (
|
|
SELECT @vTaxableBaseServices := SUM(tst.taxableBase) taxableBase,
|
|
i.expenseFk,
|
|
i.taxTypeSageFk,
|
|
i.transactionTypeSageFk,
|
|
@vTaxCodeGeneral := i.taxClassCodeFk
|
|
FROM tmp.ticketServiceTax tst
|
|
JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tst.code
|
|
WHERE i.isService
|
|
HAVING taxableBase
|
|
) sub;
|
|
|
|
INSERT INTO invoiceInTax(invoiceInFk, taxableBase, expenseFk, taxTypeSageFk, transactionTypeSageFk)
|
|
SELECT vNewInvoiceInFk,
|
|
SUM(tt.taxableBase) - IF(tt.code = @vTaxCodeGeneral,
|
|
@vTaxableBaseServices, 0) taxableBase,
|
|
i.expenseFk,
|
|
i.taxTypeSageFk ,
|
|
i.transactionTypeSageFk
|
|
FROM tmp.ticketTax tt
|
|
JOIN invoiceOutTaxConfig i ON i.taxClassCodeFk = tt.code
|
|
WHERE !i.isService
|
|
GROUP BY tt.pgcFk
|
|
HAVING taxableBase
|
|
ORDER BY tt.priority;
|
|
|
|
CALL invoiceInDueDay_calculate(vNewInvoiceInFk);
|
|
|
|
SELECT COUNT(*) INTO vIsCEESerial
|
|
FROM invoiceOutSerial
|
|
WHERE code = vSerial;
|
|
|
|
IF vIsCEESerial THEN
|
|
|
|
INSERT INTO invoiceInIntrastat (
|
|
invoiceInFk,
|
|
intrastatFk,
|
|
amount,
|
|
stems,
|
|
countryFk,
|
|
net)
|
|
SELECT
|
|
vNewInvoiceInFk,
|
|
i.intrastatFk,
|
|
SUM(CAST((s.quantity * s.price * (100 - s.discount) / 100 ) AS DECIMAL(10, 2))),
|
|
SUM(CAST(IFNULL(i.stems, 1) * s.quantity AS DECIMAL(10, 2))),
|
|
su.countryFk,
|
|
CAST(SUM(IFNULL(i.stems, 1)
|
|
* s.quantity
|
|
* IF(ic.grams, ic.grams, IFNULL(i.weightByPiece, 0)) / 1000) AS DECIMAL(10, 2))
|
|
FROM sale s
|
|
JOIN ticket t ON s.ticketFk = t.id
|
|
JOIN supplier su ON su.id = t.companyFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
LEFT JOIN itemCost ic ON ic.itemFk = i.id AND ic.warehouseFk = t.warehouseFk
|
|
WHERE t.refFk = vNewRef
|
|
GROUP BY i.intrastatFk;
|
|
|
|
END IF;
|
|
DROP TEMPORARY TABLE tmp.ticket;
|
|
DROP TEMPORARY TABLE tmp.ticketAmount;
|
|
DROP TEMPORARY TABLE tmp.ticketTax;
|
|
DROP TEMPORARY TABLE tmp.ticketServiceTax;
|
|
END IF;
|
|
END IF;
|
|
DROP TEMPORARY TABLE `tmp`.`ticketToInvoice`;
|
|
END$$
|
|
DELIMITER ;
|