refactor: refs #6495 Migrated procs to vn
gitea/salix/pipeline/pr-dev This commit looks good Details

This commit is contained in:
Guillermo Bonet 2024-02-28 12:32:28 +01:00
parent 89ebd36b9b
commit f5f2179ac6
9 changed files with 237 additions and 256 deletions

View File

@ -0,0 +1,91 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`client_sendMailPurchases`(
vSelf INT,
vDated DATE
)
BEGIN
/**
* Envia un correo electrónico con un resumen de los pedidos
* preparados para un cliente.
*
* @param vSelf Id del cliente
* @param vDated Fecha de preparación
*/
DECLARE vTicketFk INT;
DECLARE vAlias VARCHAR(50);
DECLARE vStreet VARCHAR(255);
DECLARE vCity VARCHAR(25);
DECLARE vAmount DOUBLE;
DECLARE vMailTo VARCHAR(250);
DECLARE vString TEXT;
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vTickets CURSOR FOR
SELECT t.id,
t.nickname,
CAST(sub.amount AS DECIMAL(10,2)) amount,
a.street,
a.city
FROM ticket t
JOIN `address` a ON t.addressFk = a.id
JOIN (
SELECT s.ticketFk,
SUM(
s.quantity * s.price * (100 - s.discount) / 100
) amount
FROM sale s
JOIN ticket t ON t.id = s.ticketFk
WHERE t.shipped >= util.VN_CURDATE() - INTERVAL 6 MONTH
GROUP BY s.ticketFk
) sub ON sub.ticketFk = t.id
WHERE t.shipped BETWEEN vDated AND util.dayEnd(vDated)
AND t.clientFk = vSelf;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
SET vDated = IFNULL(vDated, util.yesterday());
OPEN vTickets;
FETCH vTickets INTO vTicketFk, vAlias, vAmount, vStreet, vCity;
SET vString = CONCAT('<p><font face="verdana" >',
'<h2> Relación de envíos.</h2>',
'<h3><font color="green">Dia: ', vDated, '</font></h3>');
WHILE NOT vDone DO
SET vString = CONCAT(vString, '<br><br>',
'<table>
<tr>
<th> <a href = "https://shop.verdnatura.es/#!form=ecomerce/ticket&ticket=',vTicketFk,'">
<font color="green"> Ticket ', vTicketFk,'</font></th>
<th></th><th></th><th></th><th></th>
<th></th><th></th><th></th><th></th>
<th> <font color="orange"> ', vAmount, ' </a></font></th>
</tr>
</table>',
' ', vAlias, '<br>',
' ', vStreet, '(', vCity, ')');
FETCH vTickets INTO vTicketFk, vAlias, vAmount, vStreet, vCity;
END WHILE;
SET vString = CONCAT(
vString,
'<table>',
'<tr><th></th></tr>',
'</table>',
'<br><br>Puede acceder al detalle de los albaranes haciendo click sobre el número de Ticket',
'<br><h3> Muchas gracias por su confianza</h3>',
'</font></p>');
-- Envío del email
SELECT CONCAT(email,', pako@verdnatura.es') INTO vMailTo
FROM client
WHERE id = vSelf
AND email <> '';
CALL mail_insert(
IFNULL(vMailTo, 'pako.natek@gmail.com'),
'pako@verdnatura.es',
'Resumen de pedidos preparados',
vString
);
END$$
DELIMITER ;

View File

@ -0,0 +1,27 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`client_sendMailPurchasesLauncher`()
BEGIN
/**
* Lanza el envío de correos electrónicos con el resumen de pedidos
* preparados para todos los clientes con el campo eypbc a TRUE.
*
* @param vSelf Id del cliente
* @param vDated Fecha de preparación
*/
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vClientFk INT;
DECLARE vClients CURSOR FOR
SELECT id
FROM client
WHERE eypbc;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
OPEN vClients;
FETCH vClients INTO vClientFk;
WHILE NOT vDone DO
CALL client_sendMailPurchases(util.yesterday(), vClientFk);
FETCH vClients INTO vClientFk;
END WHILE;
END$$
DELIMITER ;

View File

@ -0,0 +1,50 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`supplier_getPackagingStock`(
vSelf INT
)
BEGIN
/**
* Obtiene el stock de los embalajes de un proveedor.
*
* @param vSelf Id del proveedor
*/
DECLARE vItemCategoryFk INT;
SELECT id INTO vItemCategoryFk
FROM itemCategory
WHERE code = 'others';
SELECT sub.itemFk,
i.name,
SUM(sub.quantity) quantity
FROM (
SELECT b.itemFk, b.quantity
FROM buy b
JOIN item i ON i.id = b.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN `entry` e ON e.id = b.entryFk
JOIN travel t ON t.id = e.travelFk
WHERE e.supplierFk = vSelf
AND t.landed >= '2010-01-01'
AND it.categoryFk = vItemCategoryFk
UNION ALL
SELECT s.itemFk, - s.quantity
FROM sale s
JOIN item i ON i.id = s.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN ticket t ON t.id = s.ticketFk
JOIN `address` a ON a.id = t.addressFk
JOIN (
SELECT c.id,
s.id supplierFk
FROM supplier s
JOIN client c ON c.fi = s.nif
) sub ON sub.id = a.clientFk
WHERE sub.supplierFk = vSelf
AND it.categoryFk = vItemCategoryFk
AND t.shipped > '2010-01-01'
) sub
JOIN item i ON i.id = sub.itemFk
GROUP BY i.id;
END$$
DELIMITER ;

View File

@ -0,0 +1,65 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`supplier_getPackagingStockDetail`(
vSelf INT,
vItemFk INT
)
BEGIN
/**
* Obtiene el detalle del embalaje de un proveedor.
*
* @param vSelf Id del proveedor
* @param vItemFk Id del artículo
*/
SELECT sub.itemFk,
sub.`table`,
sub.registry,
sub.dated,
i.name item,
w.name warehouse,
sub.`in`,
sub.`out`,
s.name supplier,
CAST(sub.buyingValue AS DECIMAL(5,2)) price
FROM (
SELECT b.itemFk,
IF(b.quantity > 0, b.quantity, NULL) `in`,
IF(b.quantity > 0, NULL, - b.quantity) `out`,
'E' `table`,
b.entryFk registry,
t.landed dated,
t.warehouseInFk,
b.buyingValue
FROM buy b
JOIN `entry` e ON e.id = b.entryFk
JOIN travel t ON t.id = e.travelFk
WHERE e.supplierFk = vSelf
AND b.itemFk = vItemFk
AND t.landed >= '2010-01-01'
UNION ALL
SELECT s.itemFk,
IF(s.quantity < 0, - s.quantity, NULL),
IF(s.quantity < 0, NULL, s.quantity),
'T',
s.ticketFk,
t.shipped,
t.warehouseFk,
s.price
FROM sale s
JOIN ticket t ON t.id = s.ticketFk
JOIN address a ON a.id = t.addressFk
JOIN (
SELECT c.id,
s.id supplierFk
FROM supplier s
JOIN client c ON c.fi = s.nif
) sub ON sub.id = a.clientFk
WHERE sub.supplierFk = vSelf
AND s.itemFk = vItemFk
AND t.shipped > '2010-01-01'
) sub
JOIN item i ON i.id = sub.itemFk
JOIN supplier s ON s.id = vSelf
JOIN warehouse w on w.id = sub.warehouseInFk;
END$$
DELIMITER ;

View File

@ -1,100 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`emailYesterdayPurchasesByConsigna`(IN v_Date DATE, IN v_Client_Id INT)
BEGIN
DECLARE MyIdTicket BIGINT;
DECLARE MyAlias VARCHAR(50);
DECLARE MyDomicilio VARCHAR(255);
DECLARE MyPoblacion VARCHAR(25);
DECLARE MyImporte DOUBLE;
DECLARE MyMailTo VARCHAR(250);
DECLARE MyMailReplyTo VARCHAR(250);
DECLARE done INT DEFAULT FALSE;
DECLARE emptyList INT DEFAULT 0;
DECLARE txt TEXT;
DECLARE rs CURSOR FOR
SELECT t.Id_Ticket, Alias, cast(amount as decimal(10,2)) Importe, Domicilio, POBLACION
FROM Tickets t
JOIN Consignatarios cs ON t.Id_Consigna = cs.Id_Consigna
JOIN (
SELECT `Movimientos`.`Id_Ticket` AS `Id_Ticket`,
sum(
`Movimientos`.`Cantidad` * `Movimientos`.`Preu` * (100 - `Movimientos`.`Descuento`) / 100
) AS `amount`
FROM (
`vn2008`.`Movimientos`
JOIN `vn2008`.`Tickets` ON(
`Movimientos`.`Id_Ticket` = `Tickets`.`Id_Ticket`
)
)
WHERE `Tickets`.`Fecha` >= `util`.`VN_CURDATE`() + INTERVAL -6 MONTH
GROUP BY `Movimientos`.`Id_Ticket`
) v ON v.Id_Ticket = t.Id_Ticket
WHERE t.Fecha BETWEEN v_Date AND util.dayEnd(v_Date)
AND t.Id_Cliente = v_Client_Id;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;
SET v_Date = IFNULL(v_Date, util.yesterday());
OPEN rs;
FETCH rs INTO MyIdTicket, MyAlias, MyImporte, MyDomicilio, MyPoblacion;
SET emptyList = done;
SET txt = CONCAT('<p><font face="verdana" >',
'<h2> Relación de envíos.</h2>',
'<h3><font color="green">Dia: ', v_Date, '</font></h3>');
WHILE NOT done DO
SET txt = CONCAT(txt, '<br><br>',
'<table>
<tr>
<th> <a href = "https://shop.verdnatura.es/#!form=ecomerce/ticket&ticket=',MyIdTicket,'">
<font color="green"> Ticket ', MyIdTicket,'</font></th>
<th></th><th></th><th></th><th></th>
<th></th><th></th><th></th><th></th>
<th> <font color="orange"> ', MyImporte, ' </a></font></th>
</tr>
</table>'
, ' ', MyAlias, '<br>'
, ' ', MyDomicilio, '(', MyPoblacion, ')');
FETCH rs INTO MyIdTicket, MyAlias, MyImporte, MyDomicilio, MyPoblacion;
END WHILE;
SET txt = CONCAT(
txt,
'<table>',
'<tr><th></th></tr>',
'</table>',
'<br><br>Puede acceder al detalle de los albaranes haciendo click sobre el número de Ticket',
'<br><h3> Muchas gracias por su confianza</h3>',
'</font></p>');
-- Envío del email
IF emptyList = 0 THEN
SELECT CONCAT(`e-mail`,',pako@verdnatura.es') INTO MyMailTo
FROM Clientes
WHERE Id_Cliente = v_Client_Id AND `e-mail`>'';
IF v_Client_Id = 7818 THEN -- LOEWE
SET MyMailTo = 'isabel@elisabethblumen.com,emunozca@loewe.es,pako@verdnatura.es';
END IF;
CALL vn.mail_insert(
IFNULL(MyMailTo,'pako.natek@gmail.com'),
'pako@verdnatura.es',
'Resumen de pedidos preparados',
txt
);
END IF;
END$$
DELIMITER ;

View File

@ -1,27 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`emailYesterdayPurchasesLauncher`()
BEGIN
DECLARE done INT DEFAULT 0;
DECLARE vMyClientId INT;
DECLARE rs CURSOR FOR
SELECT Id_Cliente
FROM Clientes
WHERE EYPBC != 0;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;
OPEN rs;
FETCH rs INTO vMyClientId;
WHILE NOT done DO
CALL emailYesterdayPurchasesByConsigna(util.yesterday(), vMyClientId);
FETCH rs INTO vMyClientId;
END WHILE;
END$$
DELIMITER ;

View File

@ -1,51 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`embalajes_stocks`(IN idPEOPLE INT, IN bolCLIENT BOOLEAN)
BEGIN
if bolCLIENT then
select m.Id_Article, Article, - cast(sum(m.Cantidad) as decimal) as Saldo
from Movimientos m
join Articles a on m.Id_Article = a.Id_Article
join Tipos tp on tp.tipo_id = a.tipo_id
join Tickets t using(Id_Ticket)
join Consignatarios cs using(Id_Consigna)
where cs.Id_Cliente = idPEOPLE
and Tipo = 'Contenedores'
and t.Fecha > '2010-01-01'
group by m.Id_Article;
else
select Id_Article, Article, sum(Cantidad) as Saldo
from
(select Id_Article, Cantidad
from Compres c
join Articles a using(Id_Article)
join Tipos tp using(tipo_id)
join Entradas e using(Id_Entrada)
join travel tr on tr.id = travel_id
where Id_Proveedor = idPEOPLE
and landing >= '2010-01-01'
and reino_id = 6
union all
select Id_Article, - Cantidad
from Movimientos m
join Articles a using(Id_Article)
join Tipos tp using(tipo_id)
join Tickets t using(Id_Ticket)
join Consignatarios cs using(Id_Consigna)
join proveedores_clientes pc on pc.Id_Cliente = cs.Id_Cliente
where Id_Proveedor = idPEOPLE
and reino_id = 6
and t.Fecha > '2010-01-01') mov
join Articles a using(Id_Article)
group by Id_Article;
end if;
END$$
DELIMITER ;

View File

@ -1,78 +0,0 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn2008`.`embalajes_stocks_detalle`(IN idPEOPLE INT, IN idARTICLE INT, IN bolCLIENT BOOLEAN)
BEGIN
if bolCLIENT then
select m.Id_Article
, Article
, IF(Cantidad < 0, - Cantidad, NULL) as Entrada
, IF(Cantidad < 0, NULL, Cantidad) as Salida
, 'T' as Tabla
, t.Id_Ticket as Registro
, t.Fecha
, w.name as Almacen
, cast(Preu as Decimal(5,2)) Precio
, c.Cliente as Proveedor
, abbreviation as Empresa
from Movimientos m
join Articles a using(Id_Article)
join Tickets t using(Id_Ticket)
join empresa e on e.id = t.empresa_id
join warehouse w on w.id = t.warehouse_id
join Consignatarios cs using(Id_Consigna)
join Clientes c on c.Id_Cliente = cs.Id_Cliente
where cs.Id_Cliente = idPEOPLE
and m.Id_Article = idARTICLE
and t.Fecha > '2010-01-01';
else
select Id_Article, Tabla, Registro, Fecha, Article
, w.name as Almacen, Entrada, Salida, Proveedor, cast(Precio as Decimal(5,2)) Precio
from
(select Id_Article
, IF(Cantidad > 0, Cantidad, NULL) as Entrada
, IF(Cantidad > 0, NULL,- Cantidad) as Salida
, 'E' as Tabla
, Id_Entrada as Registro
, landing as Fecha
, tr.warehouse_id
, Costefijo as Precio
from Compres c
join Entradas e using(Id_Entrada)
join travel tr on tr.id = travel_id
where Id_Proveedor = idPEOPLE
and Id_Article = idARTICLE
and landing >= '2010-01-01'
union all
select Id_Article
, IF(Cantidad < 0, - Cantidad, NULL) as Entrada
, IF(Cantidad < 0, NULL, Cantidad) as Salida
, 'T'
, Id_Ticket
, Fecha
, t.warehouse_id
, Preu
from Movimientos m
join Tickets t using(Id_Ticket)
join Consignatarios cs using(Id_Consigna)
join proveedores_clientes pc on pc.Id_Cliente = cs.Id_Cliente
where Id_Proveedor = idPEOPLE
and Id_Article = idARTICLE
and t.Fecha > '2010-01-01') mov
join Articles a using(Id_Article)
join Proveedores p on Id_Proveedor = idPEOPLE
join warehouse w on w.id = mov.warehouse_id
;
end if;
END$$
DELIMITER ;

View File

@ -0,0 +1,4 @@
UPDATE IGNORE bs.nightTask
SET `procedure` = 'client_sendMailPurchasesLauncher',
`schema` = 'vn'
WHERE `procedure` = 'emailYesterdayPurchasesLauncher';