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.ticket = 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, userFk = 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.ticket 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 invoiceExpenceMake(vNewInvoiceId); CALL invoiceTaxMake(vNewInvoiceId, vTaxArea); UPDATE invoiceOut io JOIN ( SELECT SUM(amount) total FROM invoiceOutExpence 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, expenceFk, taxTypeSageFk, transactionTypeSageFk) SELECT vNewInvoiceInFk, @vTaxableBaseServices, sub.expenceFk, sub.taxTypeSageFk, sub.transactionTypeSageFk FROM ( SELECT @vTaxableBaseServices := SUM(tst.taxableBase) taxableBase, i.expenceFk, 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, expenceFk, taxTypeSageFk, transactionTypeSageFk) SELECT vNewInvoiceInFk, SUM(tt.taxableBase) - IF(tt.code = @vTaxCodeGeneral, @vTaxableBaseServices, 0) taxableBase, i.expenceFk, 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`.`productionError_add`() BEGIN DECLARE vDatedFrom DATETIME; DECLARE vDatedTo DATETIME; /** * Rellena la tabla vn.productionError con estadisticas de encajadores, revisores y sacadores. Se ejecuta en el nightTask */ SELECT util.VN_CURDATE() - INTERVAL 1 DAY, util.dayend(util.VN_CURDATE() - INTERVAL 1 DAY) INTO vDatedFrom, vDatedTo; CALL timeControl_calculateAll(vDatedFrom, vDatedTo); -- Rellena la tabla tmp.errorsByClaim con encajadores, revisores y sacadores CREATE OR REPLACE TEMPORARY TABLE tmp.errorsByClaim ENGINE = MEMORY SELECT COUNT(c.ticketFk) errors, cd.workerFk FROM claimDevelopment cd JOIN claim c ON cd.claimFk = c.id JOIN ticket t ON c.ticketFk = t.id JOIN claimResponsible cr ON cd.claimResponsibleFk = cr.id WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo AND cr.code IN ('pic', 'chk', 'pck') GROUP BY cd.workerFk; -- Genera la tabla tmp.volume con encajadores, sacadores y revisores CREATE OR REPLACE TEMPORARY TABLE tmp.volume ENGINE = MEMORY SELECT SUM(w.volume) volume, w.workerFk FROM bs.workerProductivity w WHERE w.dated BETWEEN vDatedFrom AND vDatedTo GROUP BY w.workerFk; -- Rellena la tabla tmp.errorsByChecker con fallos de revisores CREATE OR REPLACE TEMPORARY TABLE tmp.errorsByChecker ENGINE = MEMORY SELECT st.workerFk, COUNT(t.id) errors FROM saleMistake sm JOIN saleTracking st ON sm.saleFk = st.saleFk JOIN `state` s2 ON s2.id = st.stateFk JOIN sale s ON s.id = sm.saleFk JOIN ticket t on t.id = s.ticketFk WHERE (t.shipped BETWEEN vDatedFrom AND vDatedTo) AND s2.code IN ('OK','PREVIOUS_PREPARATION','PREPARED','CHECKED') GROUP BY st.workerFk; -- Rellena la tabla tmp.expeditionErrors con fallos de expediciones CREATE OR REPLACE TEMPORARY TABLE tmp.expeditionErrors ENGINE = MEMORY SELECT COUNT(t.id) errors, e.workerFk FROM vn.expeditionMistake pm JOIN vn.expedition e ON e.id = pm.expeditionFk JOIN vn.ticket t ON t.id = e.ticketFk WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo GROUP BY e.workerFk; -- Genera la tabla tmp.total para sacadores y revisores CREATE OR REPLACE TEMPORARY TABLE tmp.total ENGINE = MEMORY SELECT st.workerFk, COUNT(DISTINCT t.id) ticketCount, COUNT(s.id) lineCount FROM saleTracking st JOIN `state` s2 ON s2.id = st.stateFk JOIN sale s ON s.id = st.saleFk JOIN ticket t ON s.ticketFk = t.id WHERE (t.shipped BETWEEN vDatedFrom AND vDatedTo) AND s2.code IN ('OK','PREVIOUS_PREPARATION','PREPARED','CHECKED') GROUP BY st.workerFk; -- Rellena la tabla vn.productionError con sacadores INSERT INTO productionError(userFk, firstname, lastname, rol, ticketNumber, lineNumber, error, volume, hourStart, hourEnd, hourWorked, dated) SELECT w.id, w.firstName, w.lastName, "Sacadores", t.ticketCount totalTickets, t.lineCount, IFNULL(ec.errors,0) + IFNULL(ec2.errors,0) errors, v.volume volume, SUBSTRING(tc.tableTimed, 1, 5) hourStart, SUBSTRING(tc.tableTimed, LENGTH(tc.tableTimed)-4, 5) hourEnd, IFNULL(CAST(tc.timeWorkDecimal AS DECIMAL (10,2)) , 0) hourWorked, vDatedFrom dated FROM tmp.total t LEFT JOIN worker w ON w.id = t.workerFk LEFT JOIN tmp.timeControlCalculate tc ON tc.userFk = t.workerFk LEFT JOIN tmp.errorsByClaim ec ON ec.workerFk = t.workerFk LEFT JOIN tmp.volume v ON v.workerFk = t.workerFk LEFT JOIN tmp.errorsByChecker ec2 ON ec2.workerFk = t.workerFk JOIN (SELECT DISTINCT w.id -- Verificamos que son sacadores FROM vn.collection c JOIN vn.state s ON s.id = c.stateFk JOIN vn.train tn ON tn.id = c.trainFk JOIN vn.worker w ON w.id = c.workerFk WHERE c.created BETWEEN vDatedFrom AND vDatedTo) sub ON sub.id = w.id GROUP BY w.id; CREATE OR REPLACE TEMPORARY TABLE itemPickerErrors -- Errores de los sacadores, derivadores de los revisadores ENGINE = MEMORY SELECT COUNT(c.ticketFk) errors, tt.userFk FROM claimDevelopment cd JOIN claim c ON cd.claimFk = c.id JOIN ticket t ON c.ticketFk = t.id JOIN claimResponsible cr ON cd.claimResponsibleFk = cr.id JOIN ticketTracking tt ON tt.ticketFk = t.id JOIN `state` s ON s.id = tt.stateFk WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo AND cr.code = 'chk' AND s.code = 'ON_PREPARATION' GROUP BY tt.userFk; UPDATE productionError ep JOIN itemPickerErrors ipe ON ipe.workerFk = ep.userFk SET ep.error = ep.error + ipe.errors WHERE vDatedFrom = ep.dated AND ep.rol = 'Sacadores'; DROP TEMPORARY TABLE itemPickerErrors; -- Rellena la tabla vn.productionError con revisores CALL productionError_addCheckerPackager(vDatedFrom, vDatedTo, "Revisadores"); -- Genera la tabla tmp.total para encajadores CREATE OR REPLACE TEMPORARY TABLE tmp.total ENGINE = MEMORY SELECT e.workerFk, COUNT(DISTINCT t.id) ticketCount, COUNT(s.id) lineCount FROM expedition e JOIN ticket t ON e.ticketFk = t.id JOIN sale s ON s.ticketFk = t.id WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo GROUP BY e.workerFk; -- Rellena la tabla vn.productionError con encajadores CALL productionError_addCheckerPackager(vDatedFrom, vDatedTo, "Encajadores"); DROP TEMPORARY TABLE tmp.errorsByClaim, tmp.volume, tmp.errorsByChecker, tmp.expeditionErrors, tmp.total; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sectorProductivity_add`() BEGIN DECLARE vDatedFrom DATETIME; DECLARE vDatedTo DATETIME; SELECT DATE_SUB(util.VN_CURDATE(),INTERVAL 1 DAY), CONCAT(DATE_SUB(util.VN_CURDATE(),INTERVAL 1 DAY),' 23:59:59') INTO vDatedFrom, vDatedTo; DROP TEMPORARY TABLE IF EXISTS tmp.timeControlCalculate; DROP TEMPORARY TABLE IF EXISTS tmp.errorsByChecker; DROP TEMPORARY TABLE IF EXISTS tmp.previousErrors; CALL timeControl_calculateAll(vDatedFrom, vDatedTo); CREATE TEMPORARY TABLE tmp.errorsByChecker ENGINE = MEMORY SELECT sc.userFk workerFk, COUNT(DISTINCT s.ticketFk) errorsByChecker FROM saleMistake sm JOIN vn.saleGroupDetail sgd on sgd.saleFk = sm.saleFk JOIN vn.sectorCollectionSaleGroup scsg on scsg.saleGroupFk = sgd.saleGroupFk JOIN vn.sectorCollection sc on sc.id = scsg.sectorCollectionFk JOIN sale s ON s.id = sm.saleFk JOIN ticket t on t.id = s.ticketFk WHERE (t.shipped BETWEEN vDatedFrom AND vDatedTo) GROUP BY sc.userFk ; CREATE TEMPORARY TABLE tmp.previousErrors -- Errores de previa, derivadores de los revisadores (por reclamación) ENGINE = MEMORY SELECT tt.userFk, COUNT(c.ticketFk) errorsByClaim FROM claimDevelopment cd JOIN claim c ON cd.claimFk = c.id JOIN ticket t ON c.ticketFk = t.id JOIN claimResponsible cr ON cd.claimResponsibleFk = cr.id JOIN ticketTracking tt ON tt.ticketFk = t.id JOIN `state` s ON s.id = tt.stateFk WHERE t.shipped BETWEEN vDatedFrom AND vDatedTo AND cr.description = 'Revisadores' AND s.code = 'OK PREVIOUS' GROUP BY cd.workerFk; DELETE FROM sectorProductivity WHERE dated = vDatedFrom AND sector IN ('Algemesi Artificial','Algemesi Complementos'); INSERT INTO sectorProductivity(workerFk, firstName, lastName, sector, ticketCount, saleCount, error, volume, hourWorked, dated) SELECT w.id workerFk, w.firstName, w.lastName, se.description sector, COUNT(DISTINCT s.ticketFk) ticketCount, COUNT(sgd.id) saleCount, IFNULL(ec2.errorsByChecker,0) + IFNULL(pe.errorsByClaim, 0) errors, wp.volume, IFNULL(CAST(tc.timeWorkDecimal AS DECIMAL (10,2)) , 0) AS hourWorked, DATE(vDatedFrom) dated FROM vn.saleGroupDetail sgd JOIN vn.saleGroup sg on sg.id = sgd.saleGroupFk JOIN vn.sectorCollectionSaleGroup scsg on scsg.saleGroupFk = sgd.saleGroupFk JOIN vn.sectorCollection sc on sc.id = scsg.sectorCollectionFk join vn.sector se on se.id = sc.sectorFk JOIN vn.worker w ON w.id = sc.userFk LEFT JOIN vn.sale s ON s.id = sgd.saleFk LEFT JOIN tmp.timeControlCalculate tc ON tc.userFk = w.id LEFT JOIN bs.workerProductivity wp ON wp.workerFk = w.id LEFT JOIN `state` s2 ON s2.id = wp.stateFk AND s2.code = 'OK PREVIOUS' LEFT JOIN tmp.errorsByChecker ec2 ON ec2.workerFk = w.id LEFT JOIN tmp.previousErrors pe ON pe.workerFk = w.id WHERE DATE(sc.created) = vDatedFrom AND wp.dated = vDatedFrom GROUP BY w.id; DROP TEMPORARY TABLE tmp.timeControlCalculate; DROP TEMPORARY TABLE tmp.errorsByChecker; DROP TEMPORARY TABLE tmp.previousErrors; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticketStateUpdate`(vTicketFk INT, vStateCode VARCHAR(45)) BEGIN /* * @deprecated:utilizar ticket_setState */ DECLARE vAlertLevel INT; SELECT s.alertLevel INTO vAlertLevel FROM vn.state s JOIN vn.ticketState ts ON ts.stateFk = s.id WHERE ts.ticketFk = vTicketFk; IF !(vStateCode = 'ON_CHECKING' AND vAlertLevel > 1) THEN INSERT INTO ticketTracking(stateFk, ticketFk, userFk) SELECT id, vTicketFk, account.myUser_getId() FROM vn.state WHERE `code` = vStateCode collate utf8_unicode_ci; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_Clone`(vOriginalTicket INT, OUT vNewTicket INT) BEGIN /** * Clona el contenido de un ticket en otro * * @param vOriginalTicket ticket Original * @param vNewTicket ticket creado */ DECLARE vStateFk INT; INSERT INTO ticket ( clientFk, shipped, addressFk, agencyModeFk, nickname, warehouseFk, companyFk, landed, zoneFk, zonePrice, zoneBonus, routeFk, priority, hasPriority, clonedFrom ) SELECT clientFk, shipped, addressFk, agencyModeFk, nickname, warehouseFk, companyFk, landed, zoneFk, zonePrice, zoneBonus, routeFk, priority, hasPriority, vOriginalTicket FROM ticket WHERE id = vOriginalTicket; SET vNewTicket = LAST_INSERT_ID(); INSERT INTO ticketObservation(ticketFk, observationTypeFk, description) SELECT vNewTicket, observationTypeFk, description FROM ticketObservation WHERE ticketFk = vOriginalTicket; INSERT INTO ticketTracking(ticketFk, stateFk, userFk, created) SELECT vNewTicket, stateFk, userFk, created FROM ticketTracking WHERE ticketFk = vOriginalTicket ORDER BY created; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_add`( vClientId INT ,vShipped DATE ,vWarehouseFk INT ,vCompanyFk INT ,vAddressFk INT ,vAgencyModeFk INT ,vRouteFk INT ,vlanded DATE ,vUserId INT ,vIsRequiredZone INT ,OUT vNewTicket INT) BEGIN /** * Crea un ticket, * ¡¡NO se debe llamar directamente, llamar a salix que hace comprobaciones previas!! * * @param vClientId id del cliente * @param vShipped dia preparacion * @param vWarehouseFk id del warehouse * @param vCompanyFk id la empresa * @param vAddressFk id del consignatario * @param vAgencyModeFk id de la agencia * @param vRouteFk id de la ruta | NULL * @param vlanded dia llegada * @param vUserId que crea el ticket * @param vIsRequiredZone Indica si tiene que tener zona valida para ser creado * @return vNewTicket id del ticket creado */ DECLARE vZoneFk INT; DECLARE vPrice DECIMAL(10,2); DECLARE vBonus DECIMAL(10,2); DECLARE vIsActive BOOL; IF vClientId IS NULL THEN CALL util.throw ('CLIENT_NOT_ESPECIFIED'); END IF; SELECT isActive INTO vIsActive FROM vn.client WHERE id = vClientId; IF NOT vIsActive THEN CALL util.throw ('CLIENT_NOT_ACTIVE'); END IF; IF NOT vAddressFk OR vAddressFk IS NULL THEN SELECT id INTO vAddressFk FROM address WHERE clientFk = vClientId AND isDefaultAddress; END IF; IF vAgencyModeFk IS NOT NULL THEN CALL vn.zone_getShipped (vlanded, vAddressFk, vAgencyModeFk, TRUE); SELECT zoneFk, price, bonus INTO vZoneFk, vPrice, vBonus FROM tmp.zoneGetShipped WHERE shipped = vShipped AND warehouseFk = vWarehouseFk LIMIT 1; IF (vZoneFk IS NULL OR vZoneFk = 0) AND vIsRequiredZone THEN CALL util.throw ('NOT_ZONE_WITH_THIS_PARAMETERS'); END IF; END IF; INSERT INTO ticket ( clientFk, shipped, addressFk, agencyModeFk, nickname, warehouseFk, routeFk, companyFk, landed, zoneFk, zonePrice, zoneBonus ) SELECT vClientId, vShipped, a.id, vAgencyModeFk, a.nickname, vWarehouseFk, IF(vRouteFk,vRouteFk,NULL), vCompanyFk, vlanded, vZoneFk, vPrice, vBonus FROM address a JOIN agencyMode am ON am.id = a.agencyModeFk WHERE a.id = vAddressFk; SET vNewTicket = LAST_INSERT_ID(); INSERT INTO ticketObservation(ticketFk, observationTypeFk, description) SELECT vNewTicket, ao.observationTypeFk, ao.description FROM addressObservation ao JOIN address a ON a.id = ao.addressFk WHERE a.id = vAddressFk; IF (SELECT COUNT(*) FROM bs.clientNewBorn cnb WHERE cnb.clientFk = vClientId AND NOT cnb.isRookie) = 0 THEN CALL vn.ticketObservation_addNewBorn(vNewTicket); END IF; IF (SELECT ct.isCreatedAsServed FROM vn.clientType ct JOIN vn.client c ON c.typeFk = ct.code WHERE c.id = vClientId ) <> FALSE THEN INSERT INTO ticketTracking(stateFk, ticketFk, userFk) SELECT id, vNewTicket, account.myUser_getId() FROM state WHERE `code` = 'DELIVERED'; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setNextState`(vSelf INT) BEGIN /** * Cambia el estado del ticket al siguiente estado según la tabla state * * @param vSelf id dle ticket */ DECLARE vStateFk INT; DECLARE vNewStateFk INT; SELECT stateFk INTO vStateFk FROM ticketState WHERE ticketFk = vSelf; SELECT nextStateFk INTO vNewStateFk FROM state WHERE id = vStateFk; INSERT INTO ticketTracking(stateFk, ticketFk, userFk) VALUES (vNewStateFk, vSelf, account.myUser_getId()); END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setPreviousState`(vTicketFk INT) BEGIN DECLARE vControlFk INT; SELECT MAX(id) INTO vControlFk FROM ticketTracking WHERE ticketFk = vTicketFk; IF (SELECT s.code FROM vn.state s JOIN ticketTracking tt ON tt.stateFk = s.id WHERE tt.id = vControlFk) = 'PREVIOUS_PREPARATION' THEN SELECT id INTO vControlFk FROM ticketTracking tt JOIN vn.state s ON tt.stateFk = s.id WHERE ticketFk = vTicketFk AND id < vControlFk AND s.code != 'PREVIOUS_PREPARATION' ORDER BY id DESC LIMIT 1; INSERT INTO ticketTracking(stateFk, ticketFk, userFk) SELECT s.nextStateFk, tt.ticketFk, account.myUser_getId() FROM ticketTracking tt JOIN vn.state s ON tt.stateFk = s.id WHERE id = vControlFk; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setState`( vSelf INT, vStateCode VARCHAR(255) COLLATE utf8_general_ci ) BEGIN /** * Modifica el estado de un ticket si se cumplen las condiciones necesarias. * * @param vSelf el id del ticket * @param vStateCode estado a modificar del ticket */ DECLARE vticketAlertLevel INT; DECLARE vTicketStateCode VARCHAR(255); DECLARE vCanChangeState BOOL; DECLARE vPackedAlertLevel INT; DECLARE vZoneFk INT; SELECT s.alertLevel, s.`code`, t.zoneFk INTO vticketAlertLevel, vTicketStateCode, vZoneFk FROM state s JOIN ticketTracking tt ON tt.stateFk = s.id JOIN ticket t ON t.id = tt.ticketFk WHERE tt.ticketFk = vSelf ORDER BY tt.created DESC LIMIT 1; SELECT id INTO vPackedAlertLevel FROM alertLevel WHERE code = 'PACKED'; IF vStateCode = 'OK' AND vZoneFk IS NULL THEN CALL util.throw('ASSIGN_ZONE_FIRST'); END IF; SET vCanChangeState = ( vStateCode <> 'ON_CHECKING' OR vticketAlertLevel < vPackedAlertLevel )AND NOT ( vTicketStateCode IN ('CHECKED', 'CHECKING') AND vStateCode IN ('PREPARED', 'ON_PREPARATION') ); IF vCanChangeState THEN INSERT INTO ticketTracking (stateFk, ticketFk, userFk) SELECT id, vSelf, account.myUser_getId() FROM state WHERE `code` = vStateCode COLLATE utf8_unicode_ci; IF vStateCode = 'PACKED' THEN CALL ticket_doCmr(vSelf); END IF; ELSE CALL util.throw('INCORRECT_TICKET_STATE'); END IF; END$$ DELIMITER ;