#7709 -supplierPackaging_ReportSource_2 #3107

Open
robert wants to merge 19 commits from 7709-supplierPackaging_ReportSource_2 into dev
1 changed files with 128 additions and 127 deletions
Showing only changes of commit a99fed2690 - Show all commits

View File

@ -12,79 +12,30 @@ BEGIN
*/
DECLARE vUser INT;
SET @vBalance = 0;
SET @vItemFk = NULL;
SELECT id INTO vUser
FROM supplier
WHERE nif = vNif;
IF vUser IS NULL THEN
SELECT id INTO vUser
FROM client
WHERE fi = vNif;
END IF;
CREATE OR REPLACE TEMPORARY TABLE tSupplierPackaging
SELECT vUser supplierFk,
itemFk,
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(sref AS CHAR) sref,
buyingValue
FROM (
SELECT vUser,
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
JOIN supplier s ON s.id = sp.supplierFk
WHERE s.nif = vNif
AND sp.landed >= vFromDated
UNION ALL
SELECT vUser,
itemFk,
longName,
supplier,
'E previous',
vFromDated,
SUM(`in`),
SUM(`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
UNION ALL
SELECT vUser,
s.itemFk,
SELECT s.itemFk,
i.longName,
c.name,
CONCAT('T',s.ticketFk),
DATE(t.shipped),
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
t.cmrFk sref,
s.price * (100 - s.discount) / 100 buyingValue
carlosap marked this conversation as resolved
Review

hay una columna virtual para este valor, es sale

hay una columna virtual para este valor, es sale
Review

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)
FROM sale s
JOIN item i ON i.id = s.itemFk
JOIN packaging p ON p.itemFk = i.id
@ -93,84 +44,134 @@ BEGIN
WHERE c.fi = vNif
AND t.shipped >= vFromDated
AND p.isPackageReturnable
UNION ALL
SELECT vUser,
s.itemFk,
i.longName,
c.name,
'T previous',
vFromDated,
SUM(-LEAST(s.quantity,0)) `in`,
SUM(GREATEST(s.quantity,0)) `out`,
NULL,
AVG(s.price * (100 - s.discount) / 100)
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
JOIN client c ON c.id = t.clientFk
WHERE c.fi = vNif
AND t.shipped < vFromDated
AND p.isPackageReturnable
AND NOT t.isDeleted
GROUP BY s.itemFk
UNION ALL
SELECT vUser,
p.itemFk,
i.longName,
c.name,
CONCAT('TP',tp.ticketFk),
DATE(t.shipped),
-LEAST(tp.quantity,0) `in`,
GREATEST(tp.quantity,0) `out`,
t.cmrFk,
0
FROM ticketPackaging tp
JOIN packaging p ON p.id = tp.packagingFk
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
WHERE c.fi = vNif
AND t.shipped >= vFromDated
AND p.isPackageReturnable
UNION ALL
SELECT vUser,
p.itemFk,
i.longName,
c.name,
'TP previous',
vFromDated,
SUM(-LEAST(tp.quantity,0)) `in`,
SUM(GREATEST(tp.quantity,0)) `out`,
NULL,
0
FROM ticketPackaging tp
JOIN packaging p ON p.id = tp.packagingFk
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
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
WHERE `out` OR `in`;
UNION ALL
SELECT s.itemFk,
i.longName,
c.name,
'T previous',
vFromDated,
SUM(-LEAST(s.quantity,0)) `in`,
SUM(GREATEST(s.quantity,0)) `out`,
NULL,
AVG(s.price * (100 - s.discount) / 100)
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
JOIN client c ON c.id = t.clientFk
WHERE c.fi = vNif
AND t.shipped < vFromDated
AND p.isPackageReturnable
AND NOT t.isDeleted
GROUP BY s.itemFk
UNION ALL
SELECT p.itemFk,
i.longName,
c.name,
CONCAT('TP',tp.ticketFk) entryFk,
DATE(t.shipped),
-LEAST(tp.quantity,0) `in`,
GREATEST(tp.quantity,0) `out`,
t.cmrFk,
0
FROM ticketPackaging tp
JOIN packaging p ON p.id = tp.packagingFk
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
WHERE c.fi = vNif
AND t.shipped >= vFromDated
AND p.isPackageReturnable
UNION ALL
SELECT p.itemFk,
i.longName,
c.name,
'TP previous',
vFromDated,
SUM(-LEAST(tp.quantity,0)) `in`,
SUM(GREATEST(tp.quantity,0)) `out`,
NULL,
0
FROM ticketPackaging tp
JOIN packaging p ON p.id = tp.packagingFk
JOIN item i ON i.id = p.itemFk
JOIN ticket t ON t.id = tp.ticketFk
JOIN client c ON c.id = t.clientFk
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
WHERE (`out` OR `in`);
SELECT supplierFk,
IF vUser IS NULL THEN
SELECT id INTO vUser
FROM client
WHERE fi = vNif;
INSERT INTO tSupplierPackaging
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,
IF(SUM(`in`) + SUM(-`out`)>0, SUM(`in`) + SUM(-`out`), 0) `in`,
-IF(SUM(`in`) + SUM(-`out`)<0, SUM(`in`) + SUM(-`out`), 0) `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;
SELECT vUser,
itemFk,
longName,
supplier,
name,
entryFk,
landed,
CAST(`in` AS DECIMAL(10,0)) `in`,
CAST(`out` AS DECIMAL(10,0)) `out`,
sref,
buyingValue,
balance
CAST(SUM(IF(`in`=0, -`out`, `in`)) OVER (PARTITION BY itemFk ORDER BY itemFk , landed, entryFk) AS DECIMAL(10,2)) balance
FROM tSupplierPackaging
WHERE NOT (NOT balance AND landed < CURDATE() - INTERVAL 1 YEAR);
WHERE NOT (landed < CURDATE() - INTERVAL 1 YEAR)
ORDER BY itemFk, landed, entryFk;
DROP TEMPORARY TABLE tSupplierPackaging;
END$$