#7709 -supplierPackaging_ReportSource_2 #3107

Open
robert wants to merge 29 commits from 7709-supplierPackaging_ReportSource_2 into dev
1 changed files with 101 additions and 89 deletions

View File

@ -1,94 +1,53 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`supplierPackaging_ReportSource`(
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`supplierPackaging_reportSource`(
vFromDated DATE,
vSupplierFk INT
vNif VARCHAR(50)
)
BEGIN
/**
* Create a report with packaging balance
*
* @param vFromDated Starting date
* @param vSupplierFk Supplier ID
*/
SET @vBalance = 0;
SET @vItemFk = NULL;
* Create a report with packaging balance
*
* @param vFromDated Starting date
robert marked this conversation as resolved Outdated

espacios en los comentarios *

espacios en los comentarios _*_
* @param vNif number of nif/fi of supplier or client
*/
DECLARE vEntityId INT;
robert marked this conversation as resolved Outdated

vPerson no és correcte, les empreses no son persones

vClientOrSupplierId
vEntityId

vPerson no és correcte, les empreses no son persones vClientOrSupplierId vEntityId
CREATE OR REPLACE TEMPORARY TABLE tSupplierPackaging
SELECT supplierFk,
itemFk,
CREATE OR REPLACE TEMPORARY TABLE tPackaging
robert marked this conversation as resolved Outdated

los supplier no son users

los supplier no son users
SELECT itemFk,
longName,
supplier,
`name`,
entryFk,
landed,
`in`,
`out`,
sref,
buyingValue,
IF (
NOT (@vItemFk <=> sub.itemFk),
@vBalance := (`in` - `out`),
@vBalance := (`in` - `out` + @vBalance)
) balance,
@vItemFk := sub.itemFk previousItemFk
CAST(cmrFk AS CHAR) sref,
buyingValue
FROM (
SELECT sp.supplierFk,
sp.itemFk,
sp.longName,
sp.supplier,
CONCAT('E',sp.entryFk) entryFk,
sp.landed,
sp.`in`,
sp.`out`,
e.invoiceNumber sref,
sp.buyingValue
FROM supplierPackaging sp
JOIN entry e ON e.id = sp.entryFk
WHERE sp.supplierFk = vSupplierFk
AND sp.landed >= vFromDated
UNION ALL
SELECT vSupplierFk,
itemFk,
longName,
supplier,
'E previous',
vFromDated,
SUM(`in`),
SUM(`out`),
NULL,
AVG(buyingValue)
FROM supplierPackaging
WHERE supplierFk = vSupplierFk
AND landed < vFromDated
GROUP BY itemFk
UNION ALL
SELECT vSupplierFk,
s.itemFk,
SELECT s.itemFk,
i.longName,
c.name,
CONCAT('T',s.ticketFk),
DATE(t.shipped),
-LEAST(s.quantity,0) `in`,
GREATEST(s.quantity,0) `out`,
CONCAT('T', s.ticketFk) entryFk,
DATE(t.shipped) landed,
-LEAST(s.quantity, 0) `in`,
GREATEST(s.quantity, 0) `out`,
t.cmrFk,
s.price * (100 - s.discount) / 100
s.price * (100 - s.discount) / 100 buyingValue
FROM sale s
JOIN item i ON i.id = s.itemFk
JOIN packaging p ON p.itemFk = i.id
JOIN ticket t ON t.id = s.ticketFk
carlosap marked this conversation as resolved Outdated

hay una columna virtual para este valor, es sale

hay una columna virtual para este valor, es sale

la columna total de sale el calculo que hace es el siguiente :
(price * quantity * (100 - discount) / 100)

la columna total de sale el calculo que hace es el siguiente : (`price` * `quantity` * (100 - `discount`) / 100)
JOIN client c ON c.id = t.clientFk
JOIN supplier su ON su.nif = c.fi
WHERE su.id = vSupplierFk
WHERE c.fi = vNif
AND t.shipped >= vFromDated
AND p.isPackageReturnable
UNION ALL
SELECT vSupplierFk,
s.itemFk,
SELECT s.itemFk,
i.longName,
c.name,
'T previous',
vFromDated,
SUM(-LEAST(s.quantity,0)) `in`,
SUM(GREATEST(s.quantity,0)) `out`,
SUM(-LEAST(s.quantity, 0)),
SUM(GREATEST(s.quantity, 0)),
NULL,
AVG(s.price * (100 - s.discount) / 100)
FROM sale s
@ -96,21 +55,19 @@ BEGIN
JOIN packaging p ON p.itemFk = i.id
JOIN ticket t ON t.id = s.ticketFk
JOIN client c ON c.id = t.clientFk
JOIN supplier su ON su.nif = c.fi
WHERE su.id = vSupplierFk
WHERE c.fi = vNif
AND t.shipped < vFromDated
AND p.isPackageReturnable
AND NOT t.isDeleted
GROUP BY s.itemFk
UNION ALL
SELECT vSupplierFk,
p.itemFk,
SELECT p.itemFk,
i.longName,
c.name,
CONCAT('TP',tp.ticketFk),
CONCAT('TP', tp.ticketFk),
DATE(t.shipped),
-LEAST(tp.quantity,0) `in`,
GREATEST(tp.quantity,0) `out`,
-LEAST(tp.quantity, 0),
GREATEST(tp.quantity, 0),
t.cmrFk,
0
FROM ticketPackaging tp
@ -118,19 +75,17 @@ BEGIN
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
JOIN supplier su ON su.nif = c.fi
WHERE su.id = vSupplierFk
WHERE c.fi = vNif
AND t.shipped >= vFromDated
AND p.isPackageReturnable
UNION ALL
SELECT vSupplierFk,
p.itemFk,
SELECT p.itemFk,
i.longName,
c.name,
'TP previous',
vFromDated,
SUM(-LEAST(tp.quantity,0)) `in`,
SUM(GREATEST(tp.quantity,0)) `out`,
SUM(-LEAST(tp.quantity, 0)) `in`,
SUM(GREATEST(tp.quantity, 0)) `out`,
NULL,
0
FROM ticketPackaging tp
@ -138,30 +93,87 @@ BEGIN
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
JOIN supplier su ON su.nif = c.fi
WHERE su.id = vSupplierFk
WHERE c.fi = vNif
AND t.shipped < vFromDated
AND p.isPackageReturnable
AND NOT t.isDeleted
GROUP BY p.itemFk
ORDER BY itemFk, landed, entryFk
) sub
ORDER BY itemFk , landed, entryFk
)sub
WHERE `out` OR `in`;
SELECT supplierFk,
SELECT id INTO vEntityId
FROM supplier
WHERE nif = vNif;
IF vEntityId IS NULL THEN
SELECT id INTO vEntityId
FROM client
WHERE fi = vNif;
INSERT INTO tPackaging
SELECT itemFk,
longName,
`name`,
entryFk,
landed,
`in`,
`out`,
sref,
buyingValue
FROM (
SELECT sp.itemFk,
sp.longName,
sp.supplier name,
CONCAT('E', sp.entryFk) entryFk,
sp.landed,
sp.`in`,
sp.`out`,
e.invoiceNumber sref,
sp.buyingValue
FROM supplierPackaging sp
JOIN entry e ON e.id = sp.entryFk
JOIN supplier s ON s.id = sp.supplierFk
WHERE s.nif = vNif
AND sp.landed >= vFromDated
UNION ALL
SELECT itemFk,
longName,
supplier,
'E previous',
vFromDated,
GREATEST(SUM(`in`) - SUM(`out`), 0) AS `in`,
robert marked this conversation as resolved Outdated

es molt confús un + y el - "amagat" gasta GREATEST(SUM(in) - SUM(out), 0) i queda mes compacte

es molt confús un + y el - "amagat" gasta GREATEST(SUM(in) - SUM(out), 0) i queda mes compacte
LEAST(SUM(`in`) - SUM(`out`), 0) AS `out`,
NULL,
AVG(buyingValue)
FROM supplierPackaging sp
JOIN supplier s ON s.id = sp.supplierFk
WHERE s.nif = vNif
AND landed < vFromDated
GROUP BY itemFk
ORDER BY itemFk , landed, entryFk
) sub
WHERE `out` OR `in`;
END IF;
robert marked this conversation as resolved Outdated

paréntesis innecesarios

paréntesis innecesarios
SELECT vEntityId,
itemFk,
longName,
supplier,
name,
entryFk,
landed,
CAST(`in` AS DECIMAL(10,0)) `in`,
CAST(`out` AS DECIMAL(10,0)) `out`,
CAST(`in` AS DECIMAL(10, 0)) `in`,
CAST(`out` AS DECIMAL(10, 0)) `out`,
sref,
buyingValue,
balance
FROM tSupplierPackaging
WHERE NOT (NOT balance AND landed < CURDATE() - INTERVAL 1 YEAR);
CAST(SUM(IF(`in` = 0, -`out`, `in`)) OVER (
PARTITION BY itemFk
ORDER BY itemFk , landed, entryFk
) AS DECIMAL(10,2)) balance
FROM tPackaging
robert marked this conversation as resolved Outdated

no hacer uso de curdate

no hacer uso de curdate
WHERE landed >= util.VN_CURDATE() - INTERVAL 1 YEAR
ORDER BY itemFk, landed, entryFk;
DROP TEMPORARY TABLE tSupplierPackaging;
DROP TEMPORARY TABLE tPackaging;
END$$
DELIMITER ;