Merge pull request 'feat: previas con sitema de reservas refs #6861' (!2176) from 6861-Pasar-modo-trabajo-de-previa-a-reservas into dev
gitea/salix/pipeline/head This commit looks good
Details
gitea/salix/pipeline/head This commit looks good
Details
Reviewed-on: #2176 Reviewed-by: Javi Gallego <jgallego@verdnatura.es>
This commit is contained in:
commit
ff1918ef06
|
@ -0,0 +1,29 @@
|
||||||
|
const UserError = require('vn-loopback/util/user-error');
|
||||||
|
module.exports = Self => {
|
||||||
|
Self.remoteMethodCtx('assignCollection', {
|
||||||
|
description: 'Assign a collection',
|
||||||
|
accessType: 'WRITE',
|
||||||
|
http: {
|
||||||
|
path: `/assignCollection`,
|
||||||
|
verb: 'POST'
|
||||||
|
},
|
||||||
|
returns: {
|
||||||
|
type: ['object'],
|
||||||
|
root: true
|
||||||
|
},
|
||||||
|
});
|
||||||
|
|
||||||
|
Self.assignCollection = async(ctx, options) => {
|
||||||
|
const userId = ctx.req.accessToken.userId;
|
||||||
|
const myOptions = {userId};
|
||||||
|
|
||||||
|
if (typeof options == 'object')
|
||||||
|
Object.assign(myOptions, options);
|
||||||
|
const [info, info2, [{'@vCollectionFk': collectionFk}]] = await Self.rawSql(
|
||||||
|
'CALL vn.collection_getAssigned(?, @vCollectionFk);SELECT @vCollectionFk', [userId], myOptions);
|
||||||
|
if (!collectionFk) throw new UserError('There are not picking tickets');
|
||||||
|
await Self.rawSql('CALL vn.collection_printSticker(?, NULL)', [collectionFk], myOptions);
|
||||||
|
|
||||||
|
return collectionFk;
|
||||||
|
};
|
||||||
|
};
|
|
@ -1,6 +1,6 @@
|
||||||
module.exports = Self => {
|
module.exports = Self => {
|
||||||
Self.remoteMethodCtx('getSales', {
|
Self.remoteMethodCtx('getSales', {
|
||||||
description: 'Get sales from ticket or collection',
|
description: 'Get sales from ticket, collection or sectorCollection',
|
||||||
accessType: 'READ',
|
accessType: 'READ',
|
||||||
accepts: [
|
accepts: [
|
||||||
{
|
{
|
||||||
|
|
|
@ -37,6 +37,7 @@ module.exports = Self => {
|
||||||
|
|
||||||
const promises = [];
|
const promises = [];
|
||||||
const [tickets] = await Self.rawSql(`CALL vn.collection_getTickets(?)`, [id], myOptions);
|
const [tickets] = await Self.rawSql(`CALL vn.collection_getTickets(?)`, [id], myOptions);
|
||||||
|
|
||||||
const sales = await Self.rawSql(`
|
const sales = await Self.rawSql(`
|
||||||
SELECT s.ticketFk,
|
SELECT s.ticketFk,
|
||||||
sgd.saleGroupFk,
|
sgd.saleGroupFk,
|
||||||
|
@ -68,7 +69,7 @@ module.exports = Self => {
|
||||||
LEFT JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
|
LEFT JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
|
||||||
LEFT JOIN parking p2 ON p2.id = sg.parkingFk
|
LEFT JOIN parking p2 ON p2.id = sg.parkingFk
|
||||||
JOIN item i ON i.id = s.itemFk
|
JOIN item i ON i.id = s.itemFk
|
||||||
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
||||||
LEFT JOIN parking p ON p.id = sh.parkingFk
|
LEFT JOIN parking p ON p.id = sh.parkingFk
|
||||||
|
@ -76,17 +77,56 @@ module.exports = Self => {
|
||||||
LEFT JOIN origin o ON o.id = i.originFk
|
LEFT JOIN origin o ON o.id = i.originFk
|
||||||
WHERE tc.collectionFk = ?
|
WHERE tc.collectionFk = ?
|
||||||
GROUP BY s.id, ish.id, p.code, p2.code
|
GROUP BY s.id, ish.id, p.code, p2.code
|
||||||
ORDER BY pickingOrder;`, [id], myOptions);
|
UNION ALL
|
||||||
|
SELECT s.ticketFk,
|
||||||
|
sgd.saleGroupFk,
|
||||||
|
s.id saleFk,
|
||||||
|
s.itemFk,
|
||||||
|
i.longName,
|
||||||
|
i.size,
|
||||||
|
ic.color,
|
||||||
|
o.code origin,
|
||||||
|
ish.packing,
|
||||||
|
ish.grouping,
|
||||||
|
s.isAdded,
|
||||||
|
s.originalQuantity,
|
||||||
|
s.quantity,
|
||||||
|
iss.quantity,
|
||||||
|
SUM(iss.quantity) OVER (PARTITION BY s.id ORDER BY ish.id),
|
||||||
|
ROW_NUMBER () OVER (PARTITION BY s.id ORDER BY p.pickingOrder),
|
||||||
|
COUNT(*) OVER (PARTITION BY s.id ORDER BY s.id) ,
|
||||||
|
sh.code,
|
||||||
|
IFNULL(p2.code, p.code),
|
||||||
|
IFNULL(p2.pickingOrder, p.pickingOrder),
|
||||||
|
iss.id itemShelvingSaleFk,
|
||||||
|
iss.isPicked
|
||||||
|
FROM sectorCollection sc
|
||||||
|
JOIN sectorCollectionSaleGroup ss ON ss.sectorCollectionFk = sc.id
|
||||||
|
JOIN saleGroup sg ON sg.id = ss.saleGroupFk
|
||||||
|
JOIN ticket t ON t.id = sg.ticketFk
|
||||||
|
JOIN sale s ON s.ticketFk = t.id
|
||||||
|
LEFT JOIN saleGroupDetail sgd ON sgd.saleFk = s.id
|
||||||
|
LEFT JOIN parking p2 ON p2.id = sg.parkingFk
|
||||||
|
JOIN item i ON i.id = s.itemFk
|
||||||
|
JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
|
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
|
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
||||||
|
LEFT JOIN parking p ON p.id = sh.parkingFk
|
||||||
|
LEFT JOIN itemColor ic ON ic.itemFk = s.itemFk
|
||||||
|
LEFT JOIN origin o ON o.id = i.originFk
|
||||||
|
WHERE sc.id = ?
|
||||||
|
AND sgd.saleGroupFk
|
||||||
|
GROUP BY s.id, ish.id, p.code, p2.code`, [id, id], myOptions);
|
||||||
if (print)
|
if (print)
|
||||||
await Self.rawSql(`CALL vn.collection_printSticker(?, ?)`, [id, null], myOptions);
|
await Self.rawSql(`CALL vn.collection_printSticker(?, ?)`, [id, null], myOptions);
|
||||||
|
|
||||||
const collection = {collectionFk: id, tickets: []};
|
const collection = {collectionFk: id, tickets: []};
|
||||||
|
|
||||||
if (tickets && tickets.length) {
|
if (tickets && tickets.length) {
|
||||||
for (const ticket of tickets) {
|
for (const ticket of tickets) {
|
||||||
const ticketId = ticket.ticketFk;
|
const ticketId = ticket.ticketFk;
|
||||||
if (ticket.observaciones != '') {
|
if (ticket.observation) {
|
||||||
for (observation of ticket.observaciones.split(' ')) {
|
for (observation of ticket.observation?.split(' ')) {
|
||||||
if (['#', '@'].includes(observation.charAt(0))) {
|
if (['#', '@'].includes(observation.charAt(0))) {
|
||||||
promises.push(Self.app.models.Chat.send(ctx, observation,
|
promises.push(Self.app.models.Chat.send(ctx, observation,
|
||||||
$t('The ticket is in preparation', {
|
$t('The ticket is in preparation', {
|
||||||
|
@ -100,11 +140,11 @@ module.exports = Self => {
|
||||||
if (sales && sales.length) {
|
if (sales && sales.length) {
|
||||||
const barcodes = await Self.rawSql(`
|
const barcodes = await Self.rawSql(`
|
||||||
SELECT s.id saleFk, b.code, c.id
|
SELECT s.id saleFk, b.code, c.id
|
||||||
FROM vn.sale s
|
FROM sale s
|
||||||
LEFT JOIN vn.itemBarcode b ON b.itemFk = s.itemFk
|
LEFT JOIN itemBarcode b ON b.itemFk = s.itemFk
|
||||||
LEFT JOIN vn.buy c ON c.itemFk = s.itemFk
|
LEFT JOIN buy c ON c.itemFk = s.itemFk
|
||||||
LEFT JOIN vn.entry e ON e.id = c.entryFk
|
LEFT JOIN entry e ON e.id = c.entryFk
|
||||||
LEFT JOIN vn.travel tr ON tr.id = e.travelFk
|
LEFT JOIN travel tr ON tr.id = e.travelFk
|
||||||
WHERE s.ticketFk = ?
|
WHERE s.ticketFk = ?
|
||||||
AND tr.landed >= util.VN_CURDATE() - INTERVAL 1 YEAR`,
|
AND tr.landed >= util.VN_CURDATE() - INTERVAL 1 YEAR`,
|
||||||
[ticketId], myOptions);
|
[ticketId], myOptions);
|
||||||
|
|
|
@ -0,0 +1,38 @@
|
||||||
|
const models = require('vn-loopback/server/server').models;
|
||||||
|
const LoopBackContext = require('loopback-context');
|
||||||
|
|
||||||
|
describe('ticket assignCollection()', () => {
|
||||||
|
let ctx;
|
||||||
|
let options;
|
||||||
|
let tx;
|
||||||
|
beforeEach(async() => {
|
||||||
|
ctx = {
|
||||||
|
req: {
|
||||||
|
accessToken: {userId: 1106},
|
||||||
|
headers: {origin: 'http://localhost'},
|
||||||
|
__: value => value
|
||||||
|
},
|
||||||
|
args: {}
|
||||||
|
};
|
||||||
|
|
||||||
|
spyOn(LoopBackContext, 'getCurrentContext').and.returnValue({
|
||||||
|
active: ctx.req
|
||||||
|
});
|
||||||
|
|
||||||
|
options = {transaction: tx};
|
||||||
|
tx = await models.Sale.beginTransaction({});
|
||||||
|
options.transaction = tx;
|
||||||
|
});
|
||||||
|
|
||||||
|
afterEach(async() => {
|
||||||
|
await tx.rollback();
|
||||||
|
});
|
||||||
|
|
||||||
|
it('should throw an error when there is not picking tickets', async() => {
|
||||||
|
try {
|
||||||
|
await models.Collection.assignCollection(ctx, options);
|
||||||
|
} catch (e) {
|
||||||
|
expect(e.message).toEqual('There are not picking tickets');
|
||||||
|
}
|
||||||
|
});
|
||||||
|
});
|
|
@ -26,8 +26,8 @@ describe('collection getTickets()', () => {
|
||||||
expect(collectionTickets.tickets[1].ticketFk).toEqual(2);
|
expect(collectionTickets.tickets[1].ticketFk).toEqual(2);
|
||||||
expect(collectionTickets.tickets[2].ticketFk).toEqual(23);
|
expect(collectionTickets.tickets[2].ticketFk).toEqual(23);
|
||||||
expect(collectionTickets.tickets[0].sales[0].ticketFk).toEqual(1);
|
expect(collectionTickets.tickets[0].sales[0].ticketFk).toEqual(1);
|
||||||
expect(collectionTickets.tickets[0].sales[1].ticketFk).toEqual(1);
|
expect(collectionTickets.tickets[1].sales.length).toEqual(0);
|
||||||
expect(collectionTickets.tickets[0].sales[2].ticketFk).toEqual(1);
|
expect(collectionTickets.tickets[2].sales.length).toEqual(0);
|
||||||
expect(collectionTickets.tickets[0].sales[0].Barcodes.length).toBeTruthy();
|
expect(collectionTickets.tickets[0].sales[0].Barcodes.length).toBeTruthy();
|
||||||
|
|
||||||
await tx.rollback();
|
await tx.rollback();
|
||||||
|
|
|
@ -22,7 +22,7 @@ module.exports = Self => {
|
||||||
const url = await Self.app.models.Url.findOne({
|
const url = await Self.app.models.Url.findOne({
|
||||||
where: {
|
where: {
|
||||||
appName,
|
appName,
|
||||||
environment: process.env.NODE_ENV || 'development'
|
environment: process.env.NODE_ENV || 'dev'
|
||||||
}
|
}
|
||||||
});
|
});
|
||||||
return url?.url;
|
return url?.url;
|
||||||
|
|
|
@ -3,6 +3,7 @@ module.exports = Self => {
|
||||||
require('../methods/collection/setSaleQuantity')(Self);
|
require('../methods/collection/setSaleQuantity')(Self);
|
||||||
require('../methods/collection/previousLabel')(Self);
|
require('../methods/collection/previousLabel')(Self);
|
||||||
require('../methods/collection/getTickets')(Self);
|
require('../methods/collection/getTickets')(Self);
|
||||||
|
require('../methods/collection/assignCollection')(Self);
|
||||||
require('../methods/collection/assign')(Self);
|
require('../methods/collection/assign')(Self);
|
||||||
require('../methods/collection/getSales')(Self);
|
require('../methods/collection/getSales')(Self);
|
||||||
};
|
};
|
||||||
|
|
|
@ -1,22 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE
|
|
||||||
DEFINER=`root`@`localhost`
|
|
||||||
EVENT `floranet`.`clean`
|
|
||||||
ON SCHEDULE EVERY 1 DAY
|
|
||||||
STARTS '2024-01-01 23:00:00.000'
|
|
||||||
ON COMPLETION PRESERVE
|
|
||||||
ENABLE
|
|
||||||
DO
|
|
||||||
BEGIN
|
|
||||||
DELETE
|
|
||||||
FROM `order`
|
|
||||||
WHERE created < CURDATE()
|
|
||||||
AND isPaid = FALSE;
|
|
||||||
|
|
||||||
DELETE c.*
|
|
||||||
FROM catalogue c
|
|
||||||
LEFT JOIN `order` o ON o.catalogueFk = c.id
|
|
||||||
WHERE c.created < CURDATE()
|
|
||||||
AND o.id IS NULL;
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -0,0 +1,8 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` EVENT `vn`.`itemShelvingSale_doReserve`
|
||||||
|
ON SCHEDULE EVERY 15 SECOND
|
||||||
|
STARTS '2023-10-16 00:00:00'
|
||||||
|
ON COMPLETION PRESERVE
|
||||||
|
ENABLE
|
||||||
|
DO CALL vn.itemShelvingSale_doReserve$$
|
||||||
|
DELIMITER ;
|
|
@ -1,64 +1,44 @@
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`ticket_get`(vParamFk INT)
|
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`ticket_get`(vParamFk INT)
|
||||||
RETURNS int(11)
|
RETURNS INT(11)
|
||||||
NOT DETERMINISTIC
|
NOT DETERMINISTIC
|
||||||
READS SQL DATA
|
READS SQL DATA
|
||||||
proc:BEGIN
|
BEGIN
|
||||||
|
/**
|
||||||
/* Devuelve el número de ticket o collection consultando en varias tablas posibles
|
* Devuelve el número de ticket / collection / sectorCollection consultando
|
||||||
*
|
* en que tabla se encuantra en la última semana
|
||||||
* @param vParamFk Número a validar
|
*
|
||||||
* @return vValidFk Identificador validado
|
* @param vParamFk Número a validar
|
||||||
*/
|
* @return vReturn Identificador validado
|
||||||
|
*/
|
||||||
DECLARE vValidFk INT;
|
DECLARE vReturn INT DEFAULT NULL;
|
||||||
|
DECLARE vDated DATE;
|
||||||
|
|
||||||
-- Tabla vn.saleGroup
|
SET vDated = util.VN_CURDATE() - INTERVAL 1 WEEK;
|
||||||
SELECT s.ticketFk INTO vValidFk
|
|
||||||
FROM vn.sale s
|
|
||||||
JOIN vn.saleGroupDetail sgd ON sgd.saleFk = s.id
|
|
||||||
JOIN vn.saleGroup sg ON sg.id = sgd.saleGroupFk
|
|
||||||
WHERE sg.id = vParamFk
|
|
||||||
AND sg.created > TIMESTAMPADD(WEEK,-1, util.VN_CURDATE())
|
|
||||||
LIMIT 1;
|
|
||||||
|
|
||||||
IF vValidFk THEN
|
|
||||||
|
|
||||||
RETURN vValidFk;
|
|
||||||
|
|
||||||
LEAVE proc;
|
|
||||||
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
-- Tabla vn.collection
|
SELECT COALESCE(
|
||||||
SELECT c.id INTO vValidFk
|
(SELECT s.ticketFk
|
||||||
FROM vn.collection c
|
FROM sale s
|
||||||
WHERE c.id = vParamFk
|
JOIN saleGroupDetail sgd ON sgd.saleFk = s.id
|
||||||
AND c.created > TIMESTAMPADD(WEEK,-1, util.VN_CURDATE());
|
JOIN saleGroup sg ON sg.id = sgd.saleGroupFk
|
||||||
|
WHERE sg.id = vParamFk
|
||||||
IF vValidFk THEN
|
AND sg.created > vDated
|
||||||
|
LIMIT 1),
|
||||||
RETURN vValidFk;
|
(SELECT c.id
|
||||||
|
FROM collection c
|
||||||
LEAVE proc;
|
WHERE c.id = vParamFk
|
||||||
|
AND c.created > vDated),
|
||||||
END IF;
|
(SELECT id
|
||||||
|
FROM ticket
|
||||||
|
WHERE id = vParamFk
|
||||||
|
AND shipped > vDated),
|
||||||
|
(SELECT id
|
||||||
|
FROM sectorCollection
|
||||||
|
WHERE id = vParamFk
|
||||||
|
AND created > vDated)
|
||||||
|
) INTO vReturn;
|
||||||
|
|
||||||
-- Tabla vn.ticket
|
RETURN vReturn;
|
||||||
SELECT t.id INTO vValidFk
|
|
||||||
FROM vn.ticket t
|
|
||||||
WHERE t.id = vParamFk
|
|
||||||
AND t.shipped > TIMESTAMPADD(WEEK,-1, util.VN_CURDATE());
|
|
||||||
|
|
||||||
IF vValidFk THEN
|
|
||||||
|
|
||||||
RETURN vValidFk;
|
|
||||||
|
|
||||||
LEAVE proc;
|
|
||||||
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
RETURN NULL;
|
|
||||||
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,89 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_addWithReservation`(
|
||||||
|
vItemFk INT,
|
||||||
|
vQuantity INT,
|
||||||
|
vTicketFk INT,
|
||||||
|
vSaleGroupFk INT
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* En el ámbito de las colecciones se añade una línea de sale a un ticket
|
||||||
|
* de una colección en caso de tener disponible y se realiza la reserva.
|
||||||
|
*
|
||||||
|
* @param vItemFk id of item
|
||||||
|
* @param vQuantity quantity to be added to the ticket
|
||||||
|
* @param vTicketFk ticket to which the sales line is added
|
||||||
|
* @param vSaleGroupFk saleGroupFk id to add saleGroupDetail
|
||||||
|
*/
|
||||||
|
|
||||||
|
DECLARE vWarehouseFk INT;
|
||||||
|
DECLARE vCacheAvailableFk INT;
|
||||||
|
DECLARE vAvailable INT;
|
||||||
|
DECLARE vSaleFk INT;
|
||||||
|
DECLARE vConcept VARCHAR(50);
|
||||||
|
DECLARE vItemName VARCHAR(50);
|
||||||
|
DECLARE vHasThrow BOOLEAN DEFAULT FALSE;
|
||||||
|
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
SELECT t.warehouseFk INTO vWarehouseFk
|
||||||
|
FROM ticket t
|
||||||
|
JOIN ticketCollection tc ON tc.ticketFk = t.id
|
||||||
|
WHERE t.id = vTicketFk;
|
||||||
|
|
||||||
|
CALL cache.available_refresh(
|
||||||
|
vCacheAvailableFk,
|
||||||
|
FALSE,
|
||||||
|
vWarehouseFk,
|
||||||
|
util.VN_CURDATE());
|
||||||
|
|
||||||
|
SELECT available INTO vAvailable
|
||||||
|
FROM cache.available
|
||||||
|
WHERE calc_id = vCacheAvailableFk
|
||||||
|
AND item_id = vItemFk;
|
||||||
|
|
||||||
|
IF vAvailable < vQuantity THEN
|
||||||
|
SET vHasThrow = TRUE;
|
||||||
|
ELSE
|
||||||
|
SELECT `name`,
|
||||||
|
CONCAT(getUser(), ' ', DATE_FORMAT(util.VN_NOW(), '%H:%i'), ' ', name)
|
||||||
|
INTO vItemName, vConcept
|
||||||
|
FROM item
|
||||||
|
WHERE id = vItemFk;
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
INSERT INTO sale
|
||||||
|
SET itemFk = vItemFk,
|
||||||
|
ticketFk = vTicketFk,
|
||||||
|
concept = vConcept,
|
||||||
|
quantity = vQuantity,
|
||||||
|
isAdded = TRUE;
|
||||||
|
|
||||||
|
SELECT LAST_INSERT_ID() INTO vSaleFk;
|
||||||
|
|
||||||
|
CALL sale_calculateComponent(vSaleFk, NULL);
|
||||||
|
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||||
|
|
||||||
|
IF NOT EXISTS (SELECT TRUE FROM itemShelvingSale WHERE saleFk = vSaleFk LIMIT 1) THEN
|
||||||
|
SET vHasThrow = TRUE;
|
||||||
|
END IF;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF vHasThrow THEN
|
||||||
|
CALL util.throw("There is no available for the selected item");
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF vSaleGroupFk THEN
|
||||||
|
INSERT INTO saleGroupDetail
|
||||||
|
SET saleFk = vSaleFk,
|
||||||
|
saleGroupFk = vSaleGroupFk;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
COMMIT;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,104 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getAssigned`(
|
||||||
|
vUserFk INT,
|
||||||
|
OUT vCollectionFk INT
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Comprueba si existen colecciones libres que se ajustan al perfil del usuario
|
||||||
|
* y le asigna la más antigua.
|
||||||
|
* Añade un registro al semillero de colecciones y hace la reserva para la colección
|
||||||
|
*
|
||||||
|
* @param vUserFk Id de usuario
|
||||||
|
* @param vCollectionFk Id de colección
|
||||||
|
*/
|
||||||
|
DECLARE vHasTooMuchCollections BOOL;
|
||||||
|
DECLARE vItemPackingTypeFk VARCHAR(1);
|
||||||
|
DECLARE vWarehouseFk INT;
|
||||||
|
DECLARE vLockName VARCHAR(215);
|
||||||
|
DECLARE vLockTime INT DEFAULT 30;
|
||||||
|
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
IF vLockName IS NOT NULL THEN
|
||||||
|
DO RELEASE_LOCK(vLockName);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
-- Si hay colecciones sin terminar, sale del proceso
|
||||||
|
CALL collection_get(vUserFk);
|
||||||
|
|
||||||
|
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0,
|
||||||
|
pc.collection_assign_lockname
|
||||||
|
INTO vHasTooMuchCollections,
|
||||||
|
vLockName
|
||||||
|
FROM tCollection tc
|
||||||
|
JOIN productionConfig pc;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE tCollection;
|
||||||
|
|
||||||
|
IF vHasTooMuchCollections THEN
|
||||||
|
CALL util.throw('There are pending collections');
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SELECT warehouseFk, itemPackingTypeFk
|
||||||
|
INTO vWarehouseFk, vItemPackingTypeFk
|
||||||
|
FROM operator
|
||||||
|
WHERE workerFk = vUserFk;
|
||||||
|
|
||||||
|
SET vLockName = CONCAT_WS('/',
|
||||||
|
vLockName,
|
||||||
|
vWarehouseFk,
|
||||||
|
vItemPackingTypeFk
|
||||||
|
);
|
||||||
|
|
||||||
|
IF NOT GET_LOCK(vLockName, vLockTime) THEN
|
||||||
|
CALL util.throw(CONCAT('Cannot get lock: ', vLockName));
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Se eliminan las colecciones sin asignar que estan obsoletas
|
||||||
|
INSERT INTO ticketTracking(stateFk, ticketFk)
|
||||||
|
SELECT s.id, tc.ticketFk
|
||||||
|
FROM collection c
|
||||||
|
JOIN ticketCollection tc ON tc.collectionFk = c.id
|
||||||
|
JOIN state s ON s.code = 'PRINTED_AUTO'
|
||||||
|
JOIN productionConfig pc
|
||||||
|
WHERE c.workerFk IS NULL
|
||||||
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
||||||
|
|
||||||
|
DELETE c
|
||||||
|
FROM collection c
|
||||||
|
JOIN productionConfig pc
|
||||||
|
WHERE c.workerFk IS NULL
|
||||||
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
||||||
|
|
||||||
|
-- Se añade registro al semillero
|
||||||
|
INSERT INTO collectionHotbed
|
||||||
|
SET userFk = vUserFk;
|
||||||
|
|
||||||
|
-- Comprueba si hay colecciones disponibles que se ajustan a su configuracion
|
||||||
|
SELECT MIN(c.id) INTO vCollectionFk
|
||||||
|
FROM collection c
|
||||||
|
JOIN operator o ON (o.itemPackingTypeFk = c.itemPackingTypeFk
|
||||||
|
OR c.itemPackingTypeFk IS NULL)
|
||||||
|
AND o.numberOfWagons = c.wagons
|
||||||
|
AND o.trainFk = c.trainFk
|
||||||
|
AND o.warehouseFk = c.warehouseFk
|
||||||
|
AND c.workerFk IS NULL
|
||||||
|
WHERE o.workerFk = vUserFk;
|
||||||
|
|
||||||
|
IF vCollectionFk IS NULL THEN
|
||||||
|
CALL collection_new(vUserFk, vCollectionFk);
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
UPDATE collection
|
||||||
|
SET workerFk = vUserFk
|
||||||
|
WHERE id = vCollectionFk;
|
||||||
|
|
||||||
|
CALL itemShelvingSale_addByCollection(vCollectionFk);
|
||||||
|
|
||||||
|
DO RELEASE_LOCK(vLockName);
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -2,61 +2,88 @@ DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getTickets`(vParamFk INT)
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getTickets`(vParamFk INT)
|
||||||
BEGIN
|
BEGIN
|
||||||
/**
|
/**
|
||||||
* Selecciona los tickets de una colección/ticket
|
* Selecciona los tickets de una colección/ticket/sectorCollection
|
||||||
* @param vParamFk ticketFk/collectionFk
|
* @param vParamFk ticketFk/collectionFk/sectorCollection
|
||||||
* @return Retorna ticketFk, level, agencyName, warehouseFk, salesPersonFk, observaciones
|
* @return Retorna ticketFk, level, agencyName, warehouseFk, salesPersonFk, observation
|
||||||
*/
|
*/
|
||||||
DECLARE vItemPackingTypeFk VARCHAR(1);
|
DECLARE vItemPackingTypeFk VARCHAR(1);
|
||||||
|
DECLARE vYesterday DATE;
|
||||||
|
|
||||||
-- Si los sacadores son los de pruebas, pinta los colores
|
-- Si los sacadores son los de pruebas, pinta los colores
|
||||||
SELECT itemPackingTypeFk INTO vItemPackingTypeFk
|
SELECT itemPackingTypeFk
|
||||||
FROM vn.collection
|
INTO vItemPackingTypeFk
|
||||||
|
FROM collection
|
||||||
WHERE id = vParamFk;
|
WHERE id = vParamFk;
|
||||||
|
|
||||||
|
SET vYesterday = util.yesterday();
|
||||||
|
|
||||||
SELECT t.id ticketFk,
|
WITH observation AS (
|
||||||
IF (!(vItemPackingTypeFk <=> 'V'), cc.code,CONCAT(SUBSTRING('ABCDEFGH',tc.wagon, 1),'-',tc.`level` )) `level`,
|
SELECT tob.ticketFk, tob.description
|
||||||
am.name agencyName,
|
FROM vn.ticketObservation tob
|
||||||
t.warehouseFk,
|
JOIN vn.ticketCollection tc ON tc.ticketFk = tob.ticketFk
|
||||||
w.id salesPersonFk,
|
LEFT JOIN vn.observationType ot ON ot.id = tob.observationTypeFk
|
||||||
IFNULL(tob.description,'') observaciones,
|
WHERE ot.`code` = 'itemPicker'
|
||||||
cc.rgb
|
AND tc.collectionFk = vParamFk
|
||||||
FROM vn.ticket t
|
)
|
||||||
LEFT JOIN vn.ticketCollection tc ON t.id = tc.ticketFk
|
|
||||||
LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk -- PAK 23/12/21
|
|
||||||
LEFT JOIN vn.collectionColors cc
|
|
||||||
ON cc.wagon = tc.wagon
|
|
||||||
AND cc.shelve = tc.`level`
|
|
||||||
AND cc.trainFk = c2.trainFk -- PAK 23/12/21
|
|
||||||
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
|
||||||
LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk
|
|
||||||
LEFT JOIN vn.client c ON c.id = t.clientFk
|
|
||||||
LEFT JOIN vn.worker w ON w.id = c.salesPersonFk
|
|
||||||
LEFT JOIN vn.ticketObservation tob ON tob.ticketFk = t.id
|
|
||||||
AND tob.observationTypeFk = 1
|
|
||||||
WHERE t.id = vParamFk
|
|
||||||
AND t.shipped >= util.yesterday()
|
|
||||||
UNION ALL
|
|
||||||
SELECT t.id ticketFk,
|
SELECT t.id ticketFk,
|
||||||
IF(!(vItemPackingTypeFk <=> 'V'), cc.code, CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`,
|
IF(!(vItemPackingTypeFk <=> 'V'), cc.code, CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`,
|
||||||
am.name agencyName,
|
am.name agencyName,
|
||||||
t.warehouseFk,
|
t.warehouseFk,
|
||||||
w.id salesPersonFk,
|
w.id salesPersonFk,
|
||||||
IFNULL(tob.description, '') observaciones,
|
IFNULL(ob.description,'') observaciones,
|
||||||
IF(!(vItemPackingTypeFk <=> 'V'), cc.rgb, NULL) `rgb`
|
cc.rgb
|
||||||
FROM vn.ticket t
|
FROM vn.ticket t
|
||||||
JOIN vn.ticketCollection tc ON t.id = tc.ticketFk
|
LEFT JOIN vn.ticketCollection tc ON t.id = tc.ticketFk
|
||||||
LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk -- PAK 23/12/21
|
LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk
|
||||||
LEFT JOIN vn.collectionColors cc
|
LEFT JOIN vn.collectionColors cc
|
||||||
ON cc.wagon = tc.wagon
|
ON cc.wagon = tc.wagon
|
||||||
AND cc.shelve = tc.`level`
|
AND cc.shelve = tc.`level`
|
||||||
AND cc.trainFk = c2.trainFk -- PAK 23/12/21
|
AND cc.trainFk = c2.trainFk
|
||||||
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk
|
LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk
|
||||||
LEFT JOIN vn.client c ON c.id = t.clientFk
|
LEFT JOIN vn.client c ON c.id = t.clientFk
|
||||||
LEFT JOIN vn.worker w ON w.id = c.salesPersonFk
|
LEFT JOIN vn.worker w ON w.id = c.salesPersonFk
|
||||||
LEFT JOIN vn.ticketObservation tob ON tob.ticketFk = t.id
|
LEFT JOIN observation ob ON ob.ticketFk = t.id
|
||||||
AND tob.observationTypeFk = 1
|
WHERE t.id = vParamFk
|
||||||
WHERE tc.collectionFk = vParamFk;
|
AND t.shipped >= vYesterday
|
||||||
|
UNION ALL
|
||||||
|
SELECT t.id ticketFk,
|
||||||
|
IF(NOT(vItemPackingTypeFk <=> 'V'), cc.code, CONCAT(SUBSTRING('ABCDEFGH', tc.wagon, 1), '-', tc.`level`)) `level`,
|
||||||
|
am.name agencyName,
|
||||||
|
t.warehouseFk,
|
||||||
|
w.id salesPersonFk,
|
||||||
|
ob.description,
|
||||||
|
IF(NOT (vItemPackingTypeFk <=> 'V'), cc.rgb, NULL) `rgb`
|
||||||
|
FROM vn.ticket t
|
||||||
|
JOIN vn.ticketCollection tc ON t.id = tc.ticketFk
|
||||||
|
LEFT JOIN vn.collection c2 ON c2.id = tc.collectionFk
|
||||||
|
LEFT JOIN vn.collectionColors cc
|
||||||
|
ON cc.wagon = tc.wagon
|
||||||
|
AND cc.shelve = tc.`level`
|
||||||
|
AND cc.trainFk = c2.trainFk
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk
|
||||||
|
LEFT JOIN vn.client c ON c.id = t.clientFk
|
||||||
|
LEFT JOIN vn.worker w ON w.id = c.salesPersonFk
|
||||||
|
LEFT JOIN observation ob ON ob.ticketFk = t.id
|
||||||
|
WHERE tc.collectionFk = vParamFk
|
||||||
|
UNION ALL
|
||||||
|
SELECT sg.ticketFk,
|
||||||
|
NULL `level`,
|
||||||
|
am.name agencyName,
|
||||||
|
t.warehouseFk,
|
||||||
|
c.salesPersonFk,
|
||||||
|
ob.description,
|
||||||
|
NULL `rgb`
|
||||||
|
FROM vn.sectorCollection sc
|
||||||
|
JOIN vn.sectorCollectionSaleGroup ss ON ss.sectorCollectionFk = sc.id
|
||||||
|
JOIN vn.saleGroup sg ON sg.id = ss.saleGroupFk
|
||||||
|
JOIN vn.ticket t ON t.id = sg.ticketFk
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
LEFT JOIN vn.agencyMode am ON am.id = z.agencyModeFk
|
||||||
|
LEFT JOIN observation ob ON ob.ticketFk = t.id
|
||||||
|
LEFT JOIN vn.client c ON c.id = t.clientFk
|
||||||
|
WHERE sc.id = vParamFk
|
||||||
|
AND t.shipped >= vYesterday;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,51 @@
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addByCollection`(
|
||||||
|
vCollectionFk INT(11)
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Reserva cantidades con ubicaciones para el contenido de una colección
|
||||||
|
*
|
||||||
|
* @param vCollectionFk Identificador de collection
|
||||||
|
*/
|
||||||
|
DECLARE vDone BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vSaleFk INT;
|
||||||
|
DECLARE vSales CURSOR FOR
|
||||||
|
WITH sales AS (
|
||||||
|
SELECT s.id saleFk, s.quantity, SUM(IFNULL(iss.quantity, 0)) quantityReserved
|
||||||
|
FROM vn.ticketCollection tc
|
||||||
|
JOIN vn.sale s ON s.ticketFk = tc.ticketFk
|
||||||
|
LEFT JOIN vn.itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
|
WHERE tc.collectionFk = vCollectionFk
|
||||||
|
GROUP BY s.id
|
||||||
|
HAVING quantity <> quantityReserved
|
||||||
|
), trackedSales AS (
|
||||||
|
SELECT sa.saleFk
|
||||||
|
FROM sales sa
|
||||||
|
JOIN vn.saleTracking st ON st.saleFk = sa.saleFk
|
||||||
|
JOIN vn.`state` s ON s.id = st.stateFk
|
||||||
|
WHERE st.isChecked
|
||||||
|
AND s.`code` IN ('PREVIOUS_PREPARATION', 'OK PREVIOUS', 'OK STOWAWAY')
|
||||||
|
GROUP BY sa.saleFk
|
||||||
|
) SELECT s.saleFk
|
||||||
|
FROM sales s
|
||||||
|
LEFT JOIN trackedSales ts ON ts.saleFk = s.saleFk
|
||||||
|
WHERE ts.saleFk IS NULL;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||||
|
|
||||||
|
OPEN vSales;
|
||||||
|
l: LOOP
|
||||||
|
SET vDone = FALSE;
|
||||||
|
FETCH vSales INTO vSaleFk;
|
||||||
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE l;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||||
|
END LOOP;
|
||||||
|
CLOSE vSales;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,102 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySale`(
|
||||||
|
vSaleFk INT
|
||||||
|
)
|
||||||
|
proc: BEGIN
|
||||||
|
/**
|
||||||
|
* Reserva una línea de venta en la ubicación más óptima
|
||||||
|
*
|
||||||
|
* @param vSaleFk Id de sale
|
||||||
|
* @param vItemShelvingSaleFk Id de reserva
|
||||||
|
*/
|
||||||
|
DECLARE vLastPickingOrder INT;
|
||||||
|
DECLARE vDone INT DEFAULT FALSE;
|
||||||
|
DECLARE vItemShelvingFk INT;
|
||||||
|
DECLARE vAvailable INT;
|
||||||
|
DECLARE vReservedQuantity INT;
|
||||||
|
DECLARE vOutStanding INT;
|
||||||
|
DECLARE vUserFk INT;
|
||||||
|
|
||||||
|
DECLARE vItemShelvingAvailable CURSOR FOR
|
||||||
|
SELECT ish.id itemShelvingFk,
|
||||||
|
ish.available
|
||||||
|
FROM sale s
|
||||||
|
JOIN itemShelving ish ON ish.itemFk = s.itemFk
|
||||||
|
JOIN shelving sh ON sh.code = ish.shelvingFk
|
||||||
|
JOIN parking p ON p.id = sh.parkingFk
|
||||||
|
JOIN sector sc ON sc.id = p.sectorFk
|
||||||
|
JOIN productionConfig pc
|
||||||
|
WHERE s.id = vSaleFk
|
||||||
|
AND NOT sc.isHideForPickers
|
||||||
|
ORDER BY s.id,
|
||||||
|
p.pickingOrder >= vLastPickingOrder,
|
||||||
|
sh.priority DESC,
|
||||||
|
ish.available >= s.quantity DESC,
|
||||||
|
s.quantity MOD ish.grouping = 0 DESC,
|
||||||
|
ish.grouping DESC,
|
||||||
|
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created);
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
SELECT MAX(p.pickingOrder), s.quantity - SUM(IFNULL(iss.quantity, 0))
|
||||||
|
INTO vLastPickingOrder, vOutStanding
|
||||||
|
FROM sale s
|
||||||
|
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
|
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
|
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
||||||
|
LEFT JOIN parking p ON p.id = sh.parkingFk
|
||||||
|
WHERE s.id = vSaleFk;
|
||||||
|
|
||||||
|
IF vOutStanding <= 0 THEN
|
||||||
|
LEAVE proc;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SELECT getUser() INTO vUserFk;
|
||||||
|
|
||||||
|
OPEN vItemShelvingAvailable;
|
||||||
|
l: LOOP
|
||||||
|
SET vDone = FALSE;
|
||||||
|
FETCH vItemShelvingAvailable INTO vItemShelvingFk, vAvailable;
|
||||||
|
|
||||||
|
IF vOutStanding <= 0 OR vDone THEN
|
||||||
|
LEAVE l;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
SELECT id INTO vItemShelvingFk
|
||||||
|
FROM itemShelving
|
||||||
|
WHERE id = vItemShelvingFk
|
||||||
|
FOR UPDATE;
|
||||||
|
|
||||||
|
SELECT LEAST(vOutStanding, vAvailable) INTO vReservedQuantity;
|
||||||
|
SET vOutStanding = vOutStanding - vReservedQuantity;
|
||||||
|
|
||||||
|
IF vReservedQuantity > 0 THEN
|
||||||
|
|
||||||
|
INSERT INTO itemShelvingSale(
|
||||||
|
itemShelvingFk,
|
||||||
|
saleFk,
|
||||||
|
quantity,
|
||||||
|
userFk)
|
||||||
|
SELECT vItemShelvingFk,
|
||||||
|
vSaleFk,
|
||||||
|
vReservedQuantity,
|
||||||
|
vUserFk;
|
||||||
|
|
||||||
|
UPDATE itemShelving
|
||||||
|
SET available = available - vReservedQuantity
|
||||||
|
WHERE id = vItemShelvingFk;
|
||||||
|
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
COMMIT;
|
||||||
|
END LOOP;
|
||||||
|
CLOSE vItemShelvingAvailable;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,41 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE
|
||||||
|
`vn`.`itemShelvingSale_addBySectorCollection`(vSectorCollectionFk INT(11))
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Reserva cantidades con ubicaciones para el contenido de una preparación previa
|
||||||
|
* de la cual ya tiene generada la asociación del saleGroup con sectorCollection
|
||||||
|
*
|
||||||
|
* @param vSectorCollectionFk Identificador de sectorCollection
|
||||||
|
*/
|
||||||
|
DECLARE vDone BOOL DEFAULT FALSE;
|
||||||
|
DECLARE vSaleFk INT;
|
||||||
|
DECLARE vSales CURSOR FOR
|
||||||
|
SELECT s.id
|
||||||
|
FROM sectorCollectionSaleGroup sc
|
||||||
|
JOIN saleGroupDetail sg ON sg.saleGroupFk = sc.saleGroupFk
|
||||||
|
JOIN sale s ON sg.saleFk = s.id
|
||||||
|
JOIN saleTracking str ON str.saleFk = s.id
|
||||||
|
JOIN `state` st ON st.id = str.stateFk
|
||||||
|
AND st.code = 'PREVIOUS_PREPARATION'
|
||||||
|
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
|
WHERE sc.sectorCollectionFk = vSectorCollectionFk
|
||||||
|
AND str.workerFk = account.myUser_getId()
|
||||||
|
AND iss.id IS NULL;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||||
|
|
||||||
|
OPEN vSales;
|
||||||
|
l: LOOP
|
||||||
|
SET vDone = FALSE;
|
||||||
|
FETCH vSales INTO vSaleFk;
|
||||||
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE l;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CALL itemShelvingSale_addBySale(vSaleFk);
|
||||||
|
END LOOP;
|
||||||
|
CLOSE vSales;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,52 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_doReserve`()
|
||||||
|
proc: BEGIN
|
||||||
|
/**
|
||||||
|
* Genera reservas de la tabla vn.itemShelvingSaleReserve
|
||||||
|
*/
|
||||||
|
DECLARE vDone BOOL;
|
||||||
|
DECLARE vSaleFk INT;
|
||||||
|
|
||||||
|
DECLARE vSales CURSOR FOR
|
||||||
|
SELECT DISTINCT saleFk FROM tSale;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
||||||
|
SET vDone = TRUE;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
DO RELEASE_LOCK('vn.itemShelvingSale_doReserve');
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF !GET_LOCK('vn.itemShelvingSale_doReserve', 0) THEN
|
||||||
|
LEAVE proc;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tSale
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT id, saleFk FROM itemShelvingSaleReserve;
|
||||||
|
|
||||||
|
OPEN vSales;
|
||||||
|
|
||||||
|
myLoop: LOOP
|
||||||
|
SET vDone = FALSE;
|
||||||
|
FETCH vSales INTO vSaleFk;
|
||||||
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE myLoop;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CALL itemShelvingSale_addBySale (vSaleFk);
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
CLOSE vSales;
|
||||||
|
|
||||||
|
DELETE iss FROM itemShelvingSaleReserve iss JOIN tSale s ON s.id = iss.id;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE tSale;
|
||||||
|
|
||||||
|
DO RELEASE_LOCK('vn.itemShelvingSale_doReserve');
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,49 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reallocate`(
|
||||||
|
vItemShelvingFk INT(10),
|
||||||
|
vItemFk INT(10)
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Elimina reservas de un itemShelving e intenta reservar en otra ubicación
|
||||||
|
*
|
||||||
|
* @param vItemShelvingFk Id itemShelving
|
||||||
|
*/
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
SELECT id INTO vItemShelvingFk
|
||||||
|
FROM itemShelving
|
||||||
|
WHERE id = vItemShelvingFk
|
||||||
|
FOR UPDATE;
|
||||||
|
|
||||||
|
UPDATE itemShelving
|
||||||
|
SET visible = 0,
|
||||||
|
available = 0
|
||||||
|
WHERE id = vItemShelvingFk
|
||||||
|
AND itemFk = vItemFk;
|
||||||
|
|
||||||
|
INSERT INTO itemShelvingSaleReserve (saleFk)
|
||||||
|
SELECT DISTINCT iss.saleFk
|
||||||
|
FROM itemShelvingSale iss
|
||||||
|
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
|
WHERE iss.itemShelvingFk = vItemShelvingFk
|
||||||
|
AND ish.itemFk = vItemFk
|
||||||
|
AND NOT iss.isPicked;
|
||||||
|
|
||||||
|
DELETE iss
|
||||||
|
FROM itemShelvingSale iss
|
||||||
|
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
|
WHERE iss.itemShelvingFk = vItemShelvingFk
|
||||||
|
AND ish.itemFk = vItemFk
|
||||||
|
AND NOT iss.isPicked;
|
||||||
|
COMMIT;
|
||||||
|
|
||||||
|
CALL itemShelvingSale_doReserve();
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -1,92 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserve`()
|
|
||||||
BEGIN
|
|
||||||
/**
|
|
||||||
* Reserva cantidades con ubicaciones para un conjunto de sales del mismo
|
|
||||||
* almacen.
|
|
||||||
*
|
|
||||||
* @table tmp.sale(saleFk, userFk)
|
|
||||||
*/
|
|
||||||
DECLARE vCalcFk INT;
|
|
||||||
DECLARE vWarehouseFk INT;
|
|
||||||
DECLARE vCurrentYear INT DEFAULT YEAR(util.VN_NOW());
|
|
||||||
DECLARE vLastPickingOrder INT;
|
|
||||||
|
|
||||||
SELECT t.warehouseFk, MAX(p.pickingOrder)
|
|
||||||
INTO vWarehouseFk, vLastPickingOrder
|
|
||||||
FROM ticket t
|
|
||||||
JOIN sale s ON s.ticketFk = t.id
|
|
||||||
JOIN tmp.sale ts ON ts.saleFk = s.id
|
|
||||||
LEFT JOIN itemShelvingSale iss ON iss.saleFk = ts.saleFk
|
|
||||||
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
|
||||||
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
|
|
||||||
LEFT JOIN parking p ON p.id = sh.parkingFk
|
|
||||||
WHERE t.warehouseFk IS NOT NULL;
|
|
||||||
|
|
||||||
IF vWarehouseFk IS NULL THEN
|
|
||||||
CALL util.throw('Warehouse not set');
|
|
||||||
END IF;
|
|
||||||
|
|
||||||
CALL cache.visible_refresh(vCalcFk, FALSE, vWarehouseFk);
|
|
||||||
|
|
||||||
SET @outstanding = 0;
|
|
||||||
SET @oldsaleFk = 0;
|
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tSalePlacementQuantity
|
|
||||||
(INDEX(saleFk))
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT saleFk, userFk, quantityToReserve, itemShelvingFk
|
|
||||||
FROM( SELECT saleFk,
|
|
||||||
sub.userFk,
|
|
||||||
itemShelvingFk ,
|
|
||||||
IF(saleFk <> @oldsaleFk, @outstanding := quantity, @outstanding),
|
|
||||||
@qtr := LEAST(@outstanding, available) quantityToReserve,
|
|
||||||
@outStanding := @outStanding - @qtr,
|
|
||||||
@oldsaleFk := saleFk
|
|
||||||
FROM(
|
|
||||||
SELECT ts.saleFk,
|
|
||||||
ts.userFk,
|
|
||||||
s.quantity,
|
|
||||||
ish.id itemShelvingFk,
|
|
||||||
ish.visible - IFNULL(ishr.reservedQuantity, 0) available
|
|
||||||
FROM tmp.sale ts
|
|
||||||
JOIN sale s ON s.id = ts.saleFk
|
|
||||||
JOIN itemShelving ish ON ish.itemFk = s.itemFk
|
|
||||||
LEFT JOIN (
|
|
||||||
SELECT itemShelvingFk, SUM(quantity) reservedQuantity
|
|
||||||
FROM itemShelvingSale
|
|
||||||
WHERE NOT isPicked
|
|
||||||
GROUP BY itemShelvingFk) ishr ON ishr.itemShelvingFk = ish.id
|
|
||||||
JOIN shelving sh ON sh.code = ish.shelvingFk
|
|
||||||
JOIN parking p ON p.id = sh.parkingFk
|
|
||||||
JOIN sector sc ON sc.id = p.sectorFk
|
|
||||||
JOIN warehouse w ON w.id = sc.warehouseFk
|
|
||||||
JOIN productionConfig pc
|
|
||||||
WHERE w.id = vWarehouseFk
|
|
||||||
AND NOT sc.isHideForPickers
|
|
||||||
ORDER BY
|
|
||||||
s.id,
|
|
||||||
p.pickingOrder >= vLastPickingOrder,
|
|
||||||
sh.priority DESC,
|
|
||||||
ish.visible >= s.quantity DESC,
|
|
||||||
s.quantity MOD ish.grouping = 0 DESC,
|
|
||||||
ish.grouping DESC,
|
|
||||||
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created)
|
|
||||||
)sub
|
|
||||||
)sub2
|
|
||||||
WHERE quantityToReserve > 0;
|
|
||||||
|
|
||||||
INSERT INTO itemShelvingSale(
|
|
||||||
itemShelvingFk,
|
|
||||||
saleFk,
|
|
||||||
quantity,
|
|
||||||
userFk)
|
|
||||||
SELECT itemShelvingFk,
|
|
||||||
saleFk,
|
|
||||||
quantityToReserve,
|
|
||||||
IFNULL(userFk, getUser())
|
|
||||||
FROM tSalePlacementQuantity spl;
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE tmp.sale;
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -1,29 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserveByCollection`(
|
|
||||||
vCollectionFk INT(11)
|
|
||||||
)
|
|
||||||
BEGIN
|
|
||||||
/**
|
|
||||||
* Reserva cantidades con ubicaciones para el contenido de una colección
|
|
||||||
*
|
|
||||||
* @param vCollectionFk Identificador de collection
|
|
||||||
*/
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
|
||||||
(INDEX(saleFk))
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT s.id saleFk, NULL userFk
|
|
||||||
FROM ticketCollection tc
|
|
||||||
JOIN sale s ON s.ticketFk = tc.ticketFk
|
|
||||||
LEFT JOIN (
|
|
||||||
SELECT DISTINCT saleFk
|
|
||||||
FROM saleTracking st
|
|
||||||
JOIN state s ON s.id = st.stateFk
|
|
||||||
WHERE st.isChecked
|
|
||||||
AND s.semaphore = 1)st ON st.saleFk = s.id
|
|
||||||
WHERE tc.collectionFk = vCollectionFk
|
|
||||||
AND st.saleFk IS NULL
|
|
||||||
AND NOT s.isPicked;
|
|
||||||
|
|
||||||
CALL itemShelvingSale_reserve();
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -1,21 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_reserveBySale`(
|
|
||||||
vSelf INT ,
|
|
||||||
vQuantity INT,
|
|
||||||
vUserFk INT
|
|
||||||
)
|
|
||||||
BEGIN
|
|
||||||
/**
|
|
||||||
* Reserva cantida y ubicación para una saleFk
|
|
||||||
*
|
|
||||||
* @param vSelf Identificador de la venta
|
|
||||||
* @param vQuantity Cantidad a reservar
|
|
||||||
* @param vUserFk Id de usuario que realiza la reserva
|
|
||||||
*/
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT vSelf saleFk, vUserFk userFk;
|
|
||||||
|
|
||||||
CALL itemShelvingSale_reserve();
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -0,0 +1,34 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setPicked`(
|
||||||
|
vSaleGroupFk INT(10)
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Gestiona la reserva de un vn.saleGroup actualizando vn.itemShelvingSale.isPicked
|
||||||
|
* y cambiando el estado de la vn.sale
|
||||||
|
*
|
||||||
|
* @param vSaleGroupFk Id saleGroupFk
|
||||||
|
*/
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF NOT (SELECT COUNT(*) FROM saleGroup WHERE id = vSaleGroupFk) THEN
|
||||||
|
CALL util.throw('Sale group not exists');
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
UPDATE itemShelvingSale iss
|
||||||
|
JOIN sale s ON s.id = iss.saleFk
|
||||||
|
JOIN saleGroupDetail sg ON sg.saleFk = s.id
|
||||||
|
SET iss.isPicked = TRUE
|
||||||
|
WHERE sg.saleGroupFk = vSaleGroupFk;
|
||||||
|
|
||||||
|
CALL saleTracking_addPreparedSaleGroup(vSaleGroupFk);
|
||||||
|
|
||||||
|
COMMIT;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -1,118 +1,94 @@
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setQuantity`(
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setQuantity`(
|
||||||
vItemShelvingSaleFk INT(10),
|
vItemShelvingSaleFk INT(10),
|
||||||
vQuantity DECIMAL(10,0),
|
vQuantity DECIMAL(10,0),
|
||||||
vIsItemShelvingSaleEmpty BOOLEAN
|
vIsItemShelvingSaleEmpty BOOLEAN
|
||||||
)
|
)
|
||||||
BEGIN
|
BEGIN
|
||||||
/**
|
/**
|
||||||
* Gestiona la reserva de un itemShelvingFk, actualizando isPicked y quantity
|
* Gestiona la reserva de un itemShelvingFk, actualizando isPicked y quantity
|
||||||
* en vn.itemShelvingSale y vn.sale.isPicked en caso necesario.
|
* en itemShelvingSale y sale.isPicked en caso necesario.
|
||||||
* Si la reserva de la ubicación es fallida, se regulariza la situación
|
* Si la reserva de la ubicación es fallida, se regulariza la situación
|
||||||
*
|
*
|
||||||
* @param vItemShelvingSaleFk Id itemShelvingSaleFK
|
* @param vItemShelvingSaleFk Id itemShelvingSaleFK
|
||||||
* @param vQuantity Cantidad real que se ha cogido de la ubicación
|
* @param vQuantity Cantidad real que se ha cogido de la ubicación
|
||||||
* @param vIsItemShelvingSaleEmpty determina si ka ubicación itemShelvingSale se ha
|
* @param vIsItemShelvingSaleEmpty determina si la ubicación itemShelvingSale se ha
|
||||||
* quedado vacio tras el movimiento
|
* quedado vacio tras el movimiento
|
||||||
*/
|
*/
|
||||||
DECLARE vSaleFk INT;
|
DECLARE vSaleFk INT;
|
||||||
DECLARE vCursorSaleFk INT;
|
DECLARE vItemShelvingFk INT;
|
||||||
DECLARE vItemShelvingFk INT;
|
DECLARE vReservedQuantity INT;
|
||||||
DECLARE vReservedQuantity INT;
|
DECLARE vRemainingQuantity INT;
|
||||||
DECLARE vRemainingQuantity INT;
|
DECLARE vItemFk INT;
|
||||||
DECLARE vItemFk INT;
|
DECLARE vTotalQuantity INT;
|
||||||
DECLARE vUserFk INT;
|
|
||||||
DECLARE vDone BOOLEAN DEFAULT FALSE;
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
DECLARE vSales CURSOR FOR
|
BEGIN
|
||||||
SELECT iss.saleFk, iss.userFk
|
ROLLBACK;
|
||||||
FROM itemShelvingSale iss
|
RESIGNAL;
|
||||||
JOIN sale s ON s.id = iss.saleFk
|
END;
|
||||||
WHERE iss.id = vItemShelvingSaleFk
|
|
||||||
AND s.itemFk = vItemFk
|
IF (SELECT isPicked FROM itemShelvingSale WHERE id = vItemShelvingSaleFk) THEN
|
||||||
AND NOT iss.isPicked;
|
CALL util.throw('Reservation completed');
|
||||||
|
END IF;
|
||||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
||||||
|
SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk, SUM(IFNULL(iss.quantity,0))
|
||||||
IF (SELECT isPicked FROM itemShelvingSale WHERE id = vItemShelvingSaleFk) THEN
|
INTO vItemFk, vSaleFk, vItemShelvingFk, vReservedQuantity
|
||||||
CALL util.throw('Booking completed');
|
FROM itemShelvingSale iss
|
||||||
END IF;
|
JOIN sale s ON s.id = iss.saleFk
|
||||||
|
WHERE iss.id = vItemShelvingSaleFk
|
||||||
SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk
|
AND NOT iss.isPicked;
|
||||||
INTO vItemFk, vSaleFk, vItemShelvingFk
|
|
||||||
FROM itemShelvingSale iss
|
IF vQuantity > vReservedQuantity
|
||||||
JOIN sale s ON s.id = iss.saleFk
|
OR (vQuantity < vReservedQuantity AND
|
||||||
WHERE iss.id = vItemShelvingSaleFk
|
(NOT vIsItemShelvingSaleEmpty OR vIsItemShelvingSaleEmpty IS NULL))
|
||||||
AND NOT iss.isPicked;
|
OR (vIsItemShelvingSaleEmpty IS NOT NULL AND vQuantity = vReservedQuantity) THEN
|
||||||
|
CALL util.throw('The quantity cannot be different from the reserved');
|
||||||
UPDATE itemShelvingSale
|
END IF;
|
||||||
SET isPicked = TRUE,
|
|
||||||
quantity = vQuantity
|
START TRANSACTION;
|
||||||
WHERE id = vItemShelvingSaleFk;
|
|
||||||
|
UPDATE itemShelvingSale
|
||||||
UPDATE itemShelving
|
SET isPicked = TRUE,
|
||||||
SET visible = IF(vIsItemShelvingSaleEmpty, 0, GREATEST(0,visible - vQuantity))
|
quantity = vQuantity
|
||||||
WHERE id = vItemShelvingFk;
|
WHERE id = vItemShelvingSaleFk;
|
||||||
|
|
||||||
IF vIsItemShelvingSaleEmpty THEN
|
SELECT id INTO vItemShelvingFk
|
||||||
OPEN vSales;
|
FROM itemShelving
|
||||||
l: LOOP
|
WHERE id = vItemShelvingFk
|
||||||
SET vDone = FALSE;
|
FOR UPDATE;
|
||||||
FETCH vSales INTO vCursorSaleFk, vUserFk;
|
|
||||||
IF vDone THEN
|
UPDATE itemShelving
|
||||||
LEAVE l;
|
SET visible = GREATEST(0, visible - vQuantity)
|
||||||
END IF;
|
WHERE id = vItemShelvingFk;
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
SELECT SUM(IF(isPicked, 0, quantity)), SUM(quantity)
|
||||||
(INDEX(saleFk, userFk))
|
INTO vRemainingQuantity, vTotalQuantity
|
||||||
ENGINE = MEMORY
|
FROM itemShelvingSale
|
||||||
SELECT vCursorSaleFk, vUserFk;
|
WHERE saleFk = vSaleFk;
|
||||||
|
|
||||||
CALL itemShelvingSale_reserveWhitUser();
|
IF vRemainingQuantity = 0 AND NOT vIsItemShelvingSaleEmpty THEN
|
||||||
DROP TEMPORARY TABLE tmp.sale;
|
CALL saleTracking_new(
|
||||||
|
vSaleFk,
|
||||||
END LOOP;
|
TRUE,
|
||||||
CLOSE vSales;
|
vTotalQuantity,
|
||||||
|
`account`.`myUser_getId`(),
|
||||||
DELETE iss
|
NULL,
|
||||||
FROM itemShelvingSale iss
|
'PREPARED',
|
||||||
JOIN sale s ON s.id = iss.saleFk
|
TRUE);
|
||||||
WHERE iss.id = vItemShelvingSaleFk
|
|
||||||
AND s.itemFk = vItemFk
|
UPDATE sale s
|
||||||
AND NOT iss.isPicked;
|
SET s.quantity = vTotalQuantity,
|
||||||
END IF;
|
isPicked = TRUE
|
||||||
|
WHERE s.id = vSaleFk;
|
||||||
SELECT SUM(quantity) INTO vRemainingQuantity
|
END IF;
|
||||||
FROM itemShelvingSale
|
|
||||||
WHERE saleFk = vSaleFk
|
COMMIT;
|
||||||
AND NOT isPicked;
|
|
||||||
|
IF vIsItemShelvingSaleEmpty AND vQuantity <> vReservedQuantity THEN
|
||||||
IF vRemainingQuantity THEN
|
INSERT INTO itemShelvingSaleReserve (saleFk)
|
||||||
CALL itemShelvingSale_reserveBySale (vSaleFk, vRemainingQuantity, NULL);
|
SELECT vSaleFk;
|
||||||
|
CALL itemShelvingSale_reallocate(vItemShelvingFk, vItemFk);
|
||||||
SELECT SUM(quantity) INTO vRemainingQuantity
|
END IF;
|
||||||
FROM itemShelvingSale
|
END$$
|
||||||
WHERE saleFk = vSaleFk
|
DELIMITER ;
|
||||||
AND NOT isPicked;
|
|
||||||
|
|
||||||
IF NOT vRemainingQuantity <=> 0 THEN
|
|
||||||
SELECT SUM(iss.quantity)
|
|
||||||
INTO vReservedQuantity
|
|
||||||
FROM itemShelvingSale iss
|
|
||||||
WHERE iss.saleFk = vSaleFk;
|
|
||||||
|
|
||||||
CALL saleTracking_new(
|
|
||||||
vSaleFk,
|
|
||||||
TRUE,
|
|
||||||
vReservedQuantity,
|
|
||||||
`account`.`myUser_getId`(),
|
|
||||||
NULL,
|
|
||||||
'PREPARED',
|
|
||||||
TRUE);
|
|
||||||
|
|
||||||
UPDATE sale s
|
|
||||||
SET s.quantity = vReservedQuantity
|
|
||||||
WHERE s.id = vSaleFk ;
|
|
||||||
END IF;
|
|
||||||
END IF;
|
|
||||||
END$$
|
|
||||||
DELIMITER ;
|
|
|
@ -0,0 +1,60 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_unpicked`(
|
||||||
|
vSelf INT(11)
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Desmarca una línea que ya estaba sacada, devolviendo la cantidad al itemShelving
|
||||||
|
*
|
||||||
|
* @param vSelf Identificador del itemShelvingSale
|
||||||
|
*/
|
||||||
|
DECLARE vSaleFk INT;
|
||||||
|
DECLARE vReservedQuantity INT;
|
||||||
|
DECLARE vIsSaleGroup BOOL;
|
||||||
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
|
BEGIN
|
||||||
|
ROLLBACK;
|
||||||
|
RESIGNAL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
IF (SELECT NOT isPicked FROM itemShelvingSale WHERE id = vSelf) THEN
|
||||||
|
CALL util.throw('Reserva no completada');
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
SELECT ish.saleFk, ish.quantity, IF(sg.id, TRUE, FALSE)
|
||||||
|
INTO vSaleFk, vReservedQuantity, vIsSaleGroup
|
||||||
|
FROM itemShelvingSale ish
|
||||||
|
LEFT JOIN saleGroupDetail sg ON sg.saleFk = ish.saleFk
|
||||||
|
WHERE ish.id = vSelf;
|
||||||
|
|
||||||
|
/*IF vIsSaleGroup THEN
|
||||||
|
CALL util.throw('Can not unpicked a sale group');
|
||||||
|
END IF;*/
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
UPDATE itemShelvingSale
|
||||||
|
SET isPicked = FALSE
|
||||||
|
WHERE id = vSelf;
|
||||||
|
|
||||||
|
UPDATE sale s
|
||||||
|
JOIN itemShelvingSale ish ON ish.saleFk = s.id
|
||||||
|
SET s.isPicked = FALSE
|
||||||
|
WHERE ish.id = vSelf;
|
||||||
|
|
||||||
|
UPDATE itemShelvingSale iss
|
||||||
|
JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
|
||||||
|
SET ish.visible = ish.visible + iss.quantity
|
||||||
|
WHERE iss.id = vSelf;
|
||||||
|
|
||||||
|
CALL saleTracking_new(
|
||||||
|
vSaleFk,
|
||||||
|
FALSE,
|
||||||
|
vReservedQuantity,
|
||||||
|
`account`.`myUser_getId`(),
|
||||||
|
NULL,
|
||||||
|
'ON_PREPARATION',
|
||||||
|
TRUE);
|
||||||
|
COMMIT;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -70,4 +70,4 @@ BEGIN
|
||||||
WHERE id = vBuyFk;
|
WHERE id = vBuyFk;
|
||||||
END IF;
|
END IF;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -1,5 +1,8 @@
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingTransfer`(vItemShelvingFk INT, vShelvingFk VARCHAR(3))
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelving_transfer`(
|
||||||
|
vItemShelvingFk INT,
|
||||||
|
vShelvingFk VARCHAR(10)
|
||||||
|
)
|
||||||
BEGIN
|
BEGIN
|
||||||
/**
|
/**
|
||||||
* Transfiere producto de una ubicación a otra, fusionando si coincide el
|
* Transfiere producto de una ubicación a otra, fusionando si coincide el
|
||||||
|
@ -21,8 +24,7 @@ BEGIN
|
||||||
buyFk
|
buyFk
|
||||||
FROM itemShelving
|
FROM itemShelving
|
||||||
WHERE id = vItemShelvingFk
|
WHERE id = vItemShelvingFk
|
||||||
) ish2
|
) ish2 ON ish2.itemFk = ish.itemFk
|
||||||
ON ish2.itemFk = ish.itemFk
|
|
||||||
AND ish2.packing = ish.packing
|
AND ish2.packing = ish.packing
|
||||||
AND date(ish2.created) = date(ish.created)
|
AND date(ish2.created) = date(ish.created)
|
||||||
AND ish2.buyFk = ish.buyFk
|
AND ish2.buyFk = ish.buyFk
|
||||||
|
@ -30,7 +32,7 @@ BEGIN
|
||||||
|
|
||||||
IF vNewItemShelvingFk THEN
|
IF vNewItemShelvingFk THEN
|
||||||
UPDATE itemShelving ish
|
UPDATE itemShelving ish
|
||||||
JOIN itemShelving ish2 ON ish2.id = vItemShelvingFk
|
JOIN itemShelving ish2 ON ish2.id = vItemShelvingFk
|
||||||
SET ish.visible = ish.visible + ish2.visible
|
SET ish.visible = ish.visible + ish2.visible
|
||||||
WHERE ish.id = vNewItemShelvingFk;
|
WHERE ish.id = vNewItemShelvingFk;
|
||||||
|
|
||||||
|
@ -41,7 +43,6 @@ BEGIN
|
||||||
SET shelvingFk = vShelvingFk
|
SET shelvingFk = vShelvingFk
|
||||||
WHERE id = vItemShelvingFk;
|
WHERE id = vItemShelvingFk;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
SELECT true;
|
SELECT true;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -0,0 +1,18 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sectorCollection_getMyPartial`()
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve las colecciones del sector que corresponden al usuario conectado, y que estan incompletas
|
||||||
|
*
|
||||||
|
*/
|
||||||
|
SELECT DISTINCT sc.id collectionFk, sc.created
|
||||||
|
FROM vn.sectorCollection sc
|
||||||
|
LEFT JOIN vn.sectorCollectionSaleGroup scsg ON scsg.sectorCollectionFk = sc.id
|
||||||
|
LEFT JOIN vn.saleGroupDetail sgd ON sgd.saleGroupFk = scsg.saleGroupFk
|
||||||
|
LEFT JOIN vn.sale sl ON sl.id = sgd.saleFk
|
||||||
|
LEFT JOIN itemShelvingSale iss ON iss.saleFk = sl.id
|
||||||
|
WHERE sc.userFk = account.myUser_getId()
|
||||||
|
AND (scsg.sectorCollectionFk IS NULL OR NOT iss.isPicked)
|
||||||
|
AND sc.created > util.VN_CURDATE() - INTERVAL 1 DAY;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,25 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION vn.sectorCollection_hasSalesReserved(vSelf INT) RETURNS tinyint(1)
|
||||||
|
DETERMINISTIC
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve si sectorCollection tiene reservas
|
||||||
|
* @param vSelf Id de sectorCollection
|
||||||
|
*
|
||||||
|
* returns BOOLEAN
|
||||||
|
*/
|
||||||
|
DECLARE vHasSalesReserved BOOLEAN;
|
||||||
|
|
||||||
|
SELECT DISTINCT COUNT(*) INTO vHasSalesReserved
|
||||||
|
FROM sectorCollection sc
|
||||||
|
JOIN sectorCollectionSaleGroup scsg ON sc.id = scsg.sectorCollectionFk
|
||||||
|
JOIN saleGroup sg ON sg.id = scsg.saleGroupFk
|
||||||
|
JOIN saleGroupDetail sgd ON sgd.saleGroupFk = sg.id
|
||||||
|
JOIN sale s ON s.id = sgd.saleFk
|
||||||
|
JOIN itemShelvingSale iss ON iss.saleFk = s.id
|
||||||
|
JOIN saleTracking st ON st.saleFk = s.id
|
||||||
|
WHERE sc.id = vSelf;
|
||||||
|
|
||||||
|
RETURN vHasSalesReserved;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
|
@ -2,11 +2,11 @@ DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelvingSale_afterInsert`
|
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelvingSale_afterInsert`
|
||||||
AFTER INSERT ON `itemShelvingSale`
|
AFTER INSERT ON `itemShelvingSale`
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
UPDATE vn.sale
|
UPDATE sale s
|
||||||
SET isPicked = TRUE
|
JOIN operator o ON o.workerFk = account.myUser_getId()
|
||||||
WHERE id = NEW.saleFk;
|
SET s.isPicked = IF(o.isOnReservationMode, s.isPicked, TRUE)
|
||||||
|
WHERE id = NEW.saleFk;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
|
@ -1,22 +0,0 @@
|
||||||
DELIMITER $$
|
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_afterInsert`
|
|
||||||
AFTER INSERT ON `itemShelving`
|
|
||||||
FOR EACH ROW
|
|
||||||
INSERT INTO vn.itemShelvingLog( itemShelvingFk,
|
|
||||||
workerFk,
|
|
||||||
accion,
|
|
||||||
itemFk,
|
|
||||||
shelvingFk,
|
|
||||||
visible,
|
|
||||||
`grouping`,
|
|
||||||
packing)
|
|
||||||
VALUES( NEW.id,
|
|
||||||
NEW.userFk,
|
|
||||||
'CREA REGISTRO',
|
|
||||||
NEW.itemFk,
|
|
||||||
NEW.shelvingFk,
|
|
||||||
NEW.visible,
|
|
||||||
NEW.`grouping`,
|
|
||||||
NEW.packing
|
|
||||||
)$$
|
|
||||||
DELIMITER ;
|
|
|
@ -2,7 +2,8 @@ DELIMITER $$
|
||||||
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_afterUpdate`
|
CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_afterUpdate`
|
||||||
AFTER UPDATE ON `itemShelving`
|
AFTER UPDATE ON `itemShelving`
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
INSERT INTO itemShelvingLog
|
BEGIN
|
||||||
|
INSERT INTO itemShelvingLog
|
||||||
SET itemShelvingFk = NEW.id,
|
SET itemShelvingFk = NEW.id,
|
||||||
workerFk = account.myUser_getId(),
|
workerFk = account.myUser_getId(),
|
||||||
accion = 'CAMBIO',
|
accion = 'CAMBIO',
|
||||||
|
@ -10,5 +11,8 @@ INSERT INTO itemShelvingLog
|
||||||
shelvingFk = NEW.shelvingFk,
|
shelvingFk = NEW.shelvingFk,
|
||||||
visible = NEW.visible,
|
visible = NEW.visible,
|
||||||
`grouping` = NEW.`grouping`,
|
`grouping` = NEW.`grouping`,
|
||||||
packing = NEW.packing$$
|
packing = NEW.packing,
|
||||||
|
available = NEW.available;
|
||||||
|
|
||||||
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -5,6 +5,7 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_beforeIn
|
||||||
BEGIN
|
BEGIN
|
||||||
SET NEW.editorFk = account.myUser_getId();
|
SET NEW.editorFk = account.myUser_getId();
|
||||||
SET NEW.userFk = account.myUser_getId();
|
SET NEW.userFk = account.myUser_getId();
|
||||||
|
SET NEW.available = NEW.visible;
|
||||||
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -3,9 +3,15 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` TRIGGER `vn`.`itemShelving_beforeUp
|
||||||
BEFORE UPDATE ON `itemShelving`
|
BEFORE UPDATE ON `itemShelving`
|
||||||
FOR EACH ROW
|
FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
SET NEW.editorFk = account.myUser_getId();
|
SET NEW.editorFk = account.myUser_getId();
|
||||||
IF NEW.userFk IS NULL THEN
|
IF NEW.userFk IS NULL THEN
|
||||||
SET NEW.userFk = account.myUser_getId();
|
SET NEW.userFk = account.myUser_getId();
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
|
IF (NEW.visible <> OLD.visible) THEN
|
||||||
|
SET NEW.available = GREATEST(NEW.available + NEW.visible - OLD.visible, 0);
|
||||||
|
END IF;
|
||||||
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,32 @@
|
||||||
|
ALTER TABLE vn.itemShelvingSale DROP COLUMN IF EXISTS isPicked;
|
||||||
|
|
||||||
|
ALTER TABLE vn.itemShelvingSale
|
||||||
|
ADD isPicked TINYINT(1) DEFAULT FALSE NOT NULL;
|
||||||
|
|
||||||
|
UPDATE vn.itemShelvingSale SET isPicked = TRUE;
|
||||||
|
|
||||||
|
ALTER TABLE vn.productionConfig DROP COLUMN IF EXISTS orderMode;
|
||||||
|
|
||||||
|
ALTER TABLE vn.productionConfig
|
||||||
|
ADD orderMode ENUM('Location', 'Age') NOT NULL DEFAULT 'Location';
|
||||||
|
|
||||||
|
ALTER TABLE vn.itemShelving DROP COLUMN IF EXISTS available;
|
||||||
|
|
||||||
|
ALTER TABLE vn.itemShelving ADD available INT NULL;
|
||||||
|
|
||||||
|
UPDATE vn.itemShelving SET available = visible;
|
||||||
|
|
||||||
|
CREATE TABLE vn.itemShelvingSaleReserve (
|
||||||
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
||||||
|
`saleFk` int(11) NOT NULL,
|
||||||
|
PRIMARY KEY (`id`),
|
||||||
|
KEY `itemShelvingSaleReserve_ibfk_1` (`saleFk`)
|
||||||
|
) ENGINE=InnoDB AUTO_INCREMENT=1 DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci
|
||||||
|
COMMENT='Queue of changed itemShelvingSale to reserve';
|
||||||
|
|
||||||
|
INSERT INTO `salix`.`ACL` (model, property, accessType, permission, principalType, principalId)
|
||||||
|
VALUES
|
||||||
|
|
||||||
|
('Collection', 'assignCollection', 'WRITE', 'ALLOW', 'ROLE', 'production');
|
||||||
|
|
||||||
|
ALTER TABLE vn.operator ADD IF NOT EXISTS isOnReservationMode TINYINT(1) NOT NULL DEFAULT FALSE;
|
|
@ -0,0 +1,5 @@
|
||||||
|
-- Place your SQL code here
|
||||||
|
USE vn;
|
||||||
|
|
||||||
|
DROP TRIGGER IF EXISTS itemShelving_AFTER_UPDATE;
|
||||||
|
DROP TRIGGER IF EXISTS itemShelving_AFTER_INSERT;
|
Loading…
Reference in New Issue