update structure db #9480

This commit is contained in:
Bernat 2019-01-21 09:25:02 +01:00
parent 1989232949
commit 6e84a43e99
7 changed files with 409 additions and 12 deletions

View File

@ -1,12 +0,0 @@
ALTER TABLE `vn`.`ticketService`
ADD COLUMN `ticketFk` INT(11) NOT NULL AFTER `taxClassFk`;
ALTER TABLE `vn`.`ticketService`
ADD INDEX `fgn_ticketFk_idx` (`ticketFk` ASC);
ALTER TABLE `vn`.`ticketService`
ADD CONSTRAINT `fgn_ticketFk`
FOREIGN KEY (`ticketFk`)
REFERENCES `vn2008`.`Tickets` (`Id_Ticket`)
ON DELETE CASCADE
ON UPDATE CASCADE;

View File

@ -0,0 +1,34 @@
USE `vn`;
DROP procedure IF EXISTS `logAddWithUser`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `logAddWithUser`(vOriginFk INT, vUserId INT, vActionCode VARCHAR(45), vEntity VARCHAR(45), vDescription TEXT)
BEGIN
/**
* Guarda las acciones realizadas por el usuario
*
* @param vOriginFk Id del registro de origen
* @param vActionCode Código de la acción {insert | delete | update}
* @param vEntity Nombre que hace referencia a la tabla.
* @param descripcion Descripción de la acción realizada por el usuario
*/
DECLARE vTableName VARCHAR(255) DEFAULT CONCAT(IFNULL(vEntity, ''), 'Log');
SET @sqlQuery = CONCAT(
'INSERT INTO vn.', vTableName, ' SET originFk = ?, userFk = ?, action = ?, description = ?'
);
SET @originFk = vOriginFk;
SET @userFk = vUserId;
SET @action = vActionCode;
SET @description = vDescription;
PREPARE stmt FROM @sqlQuery;
EXECUTE stmt USING @originFk, @userFk, @action, @description;
DEALLOCATE PREPARE stmt;
SET @sqlQuery = NULL;
END$$
DELIMITER ;

View File

@ -0,0 +1,21 @@
USE `vn`;
DROP procedure IF EXISTS `logAdd`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `logAdd`(vOriginFk INT, vActionCode VARCHAR(45), vEntity VARCHAR(45), vDescription TEXT)
BEGIN
/**
* Guarda las acciones realizadas por el usuario
*
* @param vOriginFk Id del registro de origen
* @param vActionCode Código de la acción {insert | delete | update}
* @param vEntity Nombre que hace referencia a la tabla.
* @param descripcion Descripción de la acción realizada por el usuario
*/
CALL logAddWithUser(vOriginFk, account.userGetId(), vActionCode, vEntity, vDescription);
END$$
DELIMITER ;

View File

@ -0,0 +1,21 @@
USE `vn`;
DROP procedure IF EXISTS `ticketCreate`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCreate`(
vClientId INT
,vShipped DATE
,vWarehouseId INT
,vCompanyFk INT
,vAddressFk INT
,vAgencyType INT
,vRouteFk INT
,vlanded DATE
,OUT vNewTicket INT)
BEGIN
CALL `ticketCreateWithUser`(vClientId, vShipped, vWarehouseId, vCompanyFk, vAddressFk, vAgencyType, vRouteFk, vlanded, account.userGetId(), vNewTicket);
END$$
DELIMITER ;

View File

@ -0,0 +1,82 @@
USE `vn`;
DROP procedure IF EXISTS `ticketCreateWithUser`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `ticketCreateWithUser`(
vClientId INT
,vShipped DATE
,vWarehouseId INT
,vCompanyFk INT
,vAddressFk INT
,vAgencyType INT
,vRouteFk INT
,vlanded DATE
,vUserId INT
,OUT vNewTicket INT)
BEGIN
DECLARE vClientOrnamentales INT DEFAULT 5270;
DECLARE vCompanyOrn INT DEFAULT 1381;
DECLARE vProvinceName VARCHAR(255);
SELECT p.name INTO vProvinceName
FROM vn.client c
JOIN province p ON p.id = c.provinceFk
WHERE c.id = vClientId;
IF vProvinceName IN ('SANTA CRUZ DE TENERIFE', 'LAS PALMAS DE GRAN CANARIA') AND vClientId <> vClientOrnamentales THEN
SET vCompanyFk = vCompanyOrn;
END IF;
IF NOT vAddressFk OR vAddressFk IS NULL THEN
SELECT id INTO vAddressFk
FROM address
WHERE clientFk = vClientId AND isDefaultAddress;
END IF;
INSERT INTO vn2008.Tickets (
Id_Cliente,
Fecha,
Id_Consigna,
Id_Agencia,
Alias,
warehouse_id,
Id_Ruta,
empresa_id,
landing
)
SELECT
vClientId,
vShipped,
a.id,
IF(vAgencyType, vAgencyType, a.agencyModeFk),
a.nickname,
vWarehouseId,
IF(vRouteFk,vRouteFk,NULL),
vCompanyFk,
vlanded
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;
CALL logAddWithUser(vNewTicket, vUserId, 'insert', 'ticket', CONCAT('Ha creado el ticket', ' ', vNewTicket));
IF (SELECT isCreatedAsServed FROM vn.client WHERE id = vClientId ) <> FALSE THEN
INSERT INTO vncontrol.inter(state_id, Id_Ticket, Id_Trabajador)
SELECT id, vNewTicket, getWorker()
FROM state
WHERE `code` = 'DELIVERED';
END IF;
END$$
DELIMITER ;

View File

@ -0,0 +1,18 @@
USE `hedera`;
DROP procedure IF EXISTS `orderConfirm`;
DELIMITER $$
USE `hedera`$$
CREATE DEFINER=`root`@`%` PROCEDURE `orderConfirm`(vOrder INT)
BEGIN
/**
* Confirms an order, creating each of its tickets on
* the corresponding date and store.
*
* @param vOrder The order identifier
*/
CALL orderConfirmWithUser(vOrder, account.userGetId());
END$$
DELIMITER ;

View File

@ -0,0 +1,233 @@
USE `hedera`;
DROP procedure IF EXISTS `orderConfirmWithUser`;
DELIMITER $$
USE `hedera`$$
CREATE DEFINER=`root`@`%` PROCEDURE `orderConfirmWithUser`(vOrder INT, vUserId INT)
BEGIN
/**
* Confirms an order, creating each of its tickets on
* the corresponding date, store and user
*
* @param vOrder The order identifier
*@param vUser The user identifier
*/
DECLARE vOk BOOL;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vWarehouse INT;
DECLARE vShipment DATETIME;
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 vDelivery DATE;
DECLARE vAddress INT;
DECLARE vAgency INT;
DECLARE vIsConfirmed BOOL;
DECLARE vClientId INT;
DECLARE vCompanyId INT;
DECLARE vAgencyModeId INT;
DECLARE TICKET_FREE INT DEFAULT 2;
DECLARE SYSTEM_WORKER INT DEFAULT 20;
DECLARE cDates CURSOR FOR
SELECT ah.shipped, r.warehouse_id
FROM `order` o
JOIN order_row r ON r.order_id = o.id
LEFT JOIN tmp.agencyHourGetShipped ah ON ah.warehouseFk = r.warehouse_id
WHERE o.id = vOrder AND r.amount != 0
GROUP BY warehouse_id;
DECLARE cRows CURSOR FOR
SELECT r.id, r.item_id, a.Article, r.amount, r.price, r.rate
FROM order_row r
JOIN vn2008.Articles a ON a.Id_Article = r.item_id
WHERE r.amount != 0
AND r.warehouse_id = vWarehouse
AND r.order_id = vOrder
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.agency_id,
o.confirmed, cs.Id_Cliente, o.company_id, o.agency_id
INTO vDelivery, vAddress, vNotes, vAgency,
vIsConfirmed, vClientId, vCompanyId, vAgencyModeId
FROM hedera.`order` o
JOIN vn2008.Agencias a ON a.Id_Agencia = o.agency_id
JOIN vn2008.Consignatarios cs ON cs.Id_Consigna = o.address_id
WHERE id = vOrder;
-- Comprueba que el pedido no está confirmado
IF vIsConfirmed THEN
CALL util.throw ('ORDER_ALREADY_CONFIRMED');
END IF;
-- Comprueba que el pedido no está vacío
SELECT COUNT(*) > 0 INTO vOk
FROM order_row WHERE order_id = vOrder AND amount > 0;
IF !vOk THEN
CALL util.throw ('ORDER_EMPTY');
END IF;
-- Carga las fechas de salida de cada almacén
CALL vn.agencyHourGetShipped (vDelivery, vAddress, vAgency);
-- Trabajador que realiza la acción
IF vUserId IS NULL THEN
SELECT employeeFk INTO vUserId FROM orderConfig;
END IF;
-- Crea los tickets del pedido
START TRANSACTION;
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 del nuevo pedido
SELECT Id_Ticket INTO vTicket
FROM vn2008.Tickets t
LEFT JOIN vn.ticketState tls on tls.ticket = t.Id_Ticket
JOIN `order` o
ON o.address_id = t.Id_Consigna
AND vWarehouse = t.warehouse_id
AND o.agency_id = t.Id_Agencia
AND t.landing = o.date_send
AND vShipment = DATE(t.Fecha)
WHERE o.id = vOrder
AND t.Factura IS NULL
AND IFNULL(tls.alertLevel,0) = 0
AND t.Id_Cliente <> 1118
LIMIT 1;
-- Crea el ticket en el caso de no existir uno adecuado
IF vTicket IS NULL
THEN
CALL vn.ticketCreateWithUser(
vClientId,
IFNULL(vShipment, CURDATE()),
vWarehouse,
vCompanyId,
vAddress,
vAgencyModeId,
NULL,
vDelivery,
vUserId,
vTicket
);
ELSE
INSERT INTO vncontrol.inter
SET Id_Ticket = vTicket,
Id_Trabajador = SYSTEM_WORKER,
state_id = TICKET_FREE;
END IF;
INSERT IGNORE INTO vn2008.order_Tickets
SET order_id = vOrder,
Id_Ticket = vTicket;
-- Añade las notas
IF vNotes IS NOT NULL AND vNotes != ''
THEN
INSERT INTO vn2008.ticket_observation (Id_Ticket, observation_type_id, text)
VALUES (vTicket, 4/*comercial*/ , vNotes)
ON DUPLICATE KEY UPDATE text = CONCAT(VALUES(text),'. ', text);
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;
IF vDone THEN
LEAVE lRows;
END IF;
INSERT INTO vn2008.Movimientos
SET
Id_Article = vItem,
Id_Ticket = vTicket,
Concepte = vConcept,
Cantidad = vAmount,
Preu = vPrice,
CostFixat = 0,
PrecioFijado = TRUE;
SET vSale = LAST_INSERT_ID();
INSERT INTO vn2008.Movimientos_componentes (Id_Movimiento, Id_Componente, Valor)
SELECT vSale, cm.component_id, cm.price
FROM order_component cm
JOIN bi.tarifa_componentes tc ON tc.Id_Componente = cm.component_id
WHERE cm.order_row_id = vRowId
GROUP BY vSale, cm.component_id;
UPDATE order_row SET Id_Movimiento = vSale
WHERE id = vRowId;
END LOOP;
CLOSE cRows;
-- Fija el Costfixat
UPDATE vn2008.Movimientos m
JOIN (SELECT SUM(mc.Valor) sum_valor,mc.Id_Movimiento
FROM vn2008.Movimientos_componentes mc
JOIN bi.tarifa_componentes tc USING(Id_Componente)
JOIN bi.tarifa_componentes_series tcs on tcs.tarifa_componentes_series_id = tc.tarifa_componentes_series_id AND tcs.base
JOIN vn2008.Movimientos m ON m.Id_Movimiento = mc.Id_Movimiento
WHERE m.Id_Ticket = vTicket
GROUP BY mc.Id_Movimiento) mc ON mc.Id_Movimiento = m.Id_Movimiento
SET m.CostFixat = sum_valor;
END LOOP;
CLOSE cDates;
DELETE FROM basketOrder WHERE orderFk = vOrder;
UPDATE `order` SET confirmed = TRUE, confirm_date = NOW()
WHERE id = vOrder;
COMMIT;
END$$
DELIMITER ;