This commit is contained in:
parent
2d6c56cd26
commit
dbe63ad11b
|
@ -1,4 +1,497 @@
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`supplier_statement`(
|
||||||
|
vSupplierFk INT,
|
||||||
|
vCurrencyFk INT,
|
||||||
|
vCompanyFk INT,
|
||||||
|
vOrderBy VARCHAR(15),
|
||||||
|
vIsConciliated BOOL
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Crea un estado de cuenta de proveedores calculando
|
||||||
|
* los saldos en euros y en la moneda especificada.
|
||||||
|
*
|
||||||
|
* @param vSupplierFk Id del proveedor
|
||||||
|
* @param vCurrencyFk Id de la moneda
|
||||||
|
* @param vCompanyFk Id de la empresa
|
||||||
|
* @param vOrderBy Criterio de ordenación
|
||||||
|
* @param vIsConciliated Indica si está conciliado o no
|
||||||
|
* @return tmp.supplierStatement
|
||||||
|
*/
|
||||||
|
SET @euroBalance:= 0;
|
||||||
|
SET @currencyBalance:= 0;
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tmp.supplierStatement
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT *,
|
||||||
|
@euroBalance:= ROUND(
|
||||||
|
@euroBalance + IFNULL(paymentEuros, 0) -
|
||||||
|
IFNULL(invoiceEuros, 0), 2
|
||||||
|
) euroBalance,
|
||||||
|
@currencyBalance:= ROUND(
|
||||||
|
@currencyBalance + IFNULL(paymentCurrency, 0) -
|
||||||
|
IFNULL(invoiceCurrency, 0), 2
|
||||||
|
) currencyBalance
|
||||||
|
FROM (
|
||||||
|
SELECT * FROM
|
||||||
|
(
|
||||||
|
SELECT NULL bankFk,
|
||||||
|
ii.companyFk,
|
||||||
|
ii.serial,
|
||||||
|
ii.id,
|
||||||
|
CASE
|
||||||
|
WHEN vOrderBy = 'issued' THEN ii.issued
|
||||||
|
WHEN vOrderBy = 'bookEntried' THEN ii.bookEntried
|
||||||
|
WHEN vOrderBy = 'booked' THEN ii.booked
|
||||||
|
WHEN vOrderBy = 'dueDate' THEN iid.dueDated
|
||||||
|
END dated,
|
||||||
|
CONCAT('S/Fra ', ii.supplierRef) sref,
|
||||||
|
IF(ii.currencyFk > 1,
|
||||||
|
ROUND(SUM(iid.foreignValue) / SUM(iid.amount), 3),
|
||||||
|
NULL
|
||||||
|
) changeValue,
|
||||||
|
CAST(SUM(iid.amount) AS DECIMAL(10,2)) invoiceEuros,
|
||||||
|
CAST(SUM(iid.foreignValue) AS DECIMAL(10,2)) invoiceCurrency,
|
||||||
|
NULL paymentEuros,
|
||||||
|
NULL paymentCurrency,
|
||||||
|
ii.currencyFk,
|
||||||
|
ii.isBooked,
|
||||||
|
c.code,
|
||||||
|
'invoiceIn' statementType
|
||||||
|
FROM invoiceIn ii
|
||||||
|
JOIN invoiceInDueDay iid ON iid.invoiceInFk = ii.id
|
||||||
|
JOIN currency c ON c.id = ii.currencyFk
|
||||||
|
WHERE ii.issued > '2014-12-31'
|
||||||
|
AND ii.supplierFk = vSupplierFk
|
||||||
|
AND vCurrencyFk IN (ii.currencyFk, 0)
|
||||||
|
AND vCompanyFk IN (ii.companyFk, 0)
|
||||||
|
AND (vIsConciliated = ii.isBooked OR NOT vIsConciliated)
|
||||||
|
GROUP BY iid.id
|
||||||
|
UNION ALL
|
||||||
|
SELECT p.bankFk,
|
||||||
|
p.companyFk,
|
||||||
|
NULL,
|
||||||
|
p.id,
|
||||||
|
CASE
|
||||||
|
WHEN vOrderBy = 'issued' THEN p.received
|
||||||
|
WHEN vOrderBy = 'bookEntried' THEN p.received
|
||||||
|
WHEN vOrderBy = 'booked' THEN p.received
|
||||||
|
WHEN vOrderBy = 'dueDate' THEN p.dueDated
|
||||||
|
END,
|
||||||
|
CONCAT(IFNULL(pm.name, ''),
|
||||||
|
IF(pn.concept <> '',
|
||||||
|
CONCAT(' : ', pn.concept),
|
||||||
|
'')
|
||||||
|
),
|
||||||
|
IF(p.currencyFk > 1, p.divisa / p.amount, NULL),
|
||||||
|
NULL,
|
||||||
|
NULL,
|
||||||
|
p.amount,
|
||||||
|
p.divisa,
|
||||||
|
p.currencyFk,
|
||||||
|
p.isConciliated,
|
||||||
|
c.code,
|
||||||
|
'payment'
|
||||||
|
FROM payment p
|
||||||
|
LEFT JOIN currency c ON c.id = p.currencyFk
|
||||||
|
LEFT JOIN bank b ON b.id = p.bankFk
|
||||||
|
LEFT JOIN payMethod pm ON pm.id = p.payMethodFk
|
||||||
|
LEFT JOIN promissoryNote pn ON pn.paymentFk = p.id
|
||||||
|
WHERE p.received > '2014-12-31'
|
||||||
|
AND p.supplierFk = vSupplierFk
|
||||||
|
AND vCurrencyFk IN (p.currencyFk, 0)
|
||||||
|
AND vCompanyFk IN (p.companyFk, 0)
|
||||||
|
AND (vIsConciliated = p.isConciliated OR NOT vIsConciliated)
|
||||||
|
UNION ALL
|
||||||
|
SELECT NULL,
|
||||||
|
companyFk,
|
||||||
|
NULL,
|
||||||
|
se.id,
|
||||||
|
CASE
|
||||||
|
WHEN vOrderBy = 'issued' THEN se.dated
|
||||||
|
WHEN vOrderBy = 'bookEntried' THEN se.dated
|
||||||
|
WHEN vOrderBy = 'booked' THEN se.dated
|
||||||
|
WHEN vOrderBy = 'dueDate' THEN se.dueDated
|
||||||
|
END,
|
||||||
|
se.description,
|
||||||
|
1,
|
||||||
|
amount,
|
||||||
|
NULL,
|
||||||
|
NULL,
|
||||||
|
NULL,
|
||||||
|
currencyFk,
|
||||||
|
isConciliated,
|
||||||
|
c.`code`,
|
||||||
|
'expense'
|
||||||
|
FROM supplierExpense se
|
||||||
|
JOIN currency c ON c.id = se.currencyFk
|
||||||
|
WHERE se.supplierFk = vSupplierFk
|
||||||
|
AND vCurrencyFk IN (se.currencyFk,0)
|
||||||
|
AND vCompanyFk IN (se.companyFk,0)
|
||||||
|
AND (vIsConciliated = se.isConciliated OR NOT vIsConciliated)
|
||||||
|
) sub
|
||||||
|
ORDER BY (dated IS NULL AND NOT isBooked),
|
||||||
|
dated,
|
||||||
|
IF(vOrderBy = 'dueDate', id, NULL)
|
||||||
|
LIMIT 10000000000000000000
|
||||||
|
) t;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
||||||
|
|
||||||
GRANT EXECUTE ON PROCEDURE vn.supplier_statement TO administrative, buyer, hrBoss;
|
GRANT EXECUTE ON PROCEDURE vn.supplier_statement TO administrative, buyer, hrBoss;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`XDiario_reconciliation`()
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Realiza la conciliación diaria de los asientos contables,
|
||||||
|
* identificando y notificando los asientos descuadrados
|
||||||
|
* y ajustando los saldos en caso necesario.
|
||||||
|
*/
|
||||||
|
INSERT INTO mail (receiver, subject, body)
|
||||||
|
SELECT 'cau@verdnatura.es',
|
||||||
|
'Asientos descuadrados',
|
||||||
|
GROUP_CONCAT(CONCAT(' Asiento: ', ASIEN, ' - Importe:', recon) SEPARATOR ' | \n')
|
||||||
|
FROM (
|
||||||
|
SELECT ASIEN,
|
||||||
|
SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0)) recon
|
||||||
|
FROM XDiario
|
||||||
|
WHERE NOT enlazado
|
||||||
|
GROUP BY ASIEN
|
||||||
|
HAVING ABS(SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0))) > 0.01
|
||||||
|
) sub
|
||||||
|
HAVING COUNT(*);
|
||||||
|
|
||||||
|
UPDATE XDiario xd
|
||||||
|
JOIN (
|
||||||
|
SELECT xd.id, SUBCTA, recon
|
||||||
|
FROM XDiario xd
|
||||||
|
JOIN (
|
||||||
|
SELECT ASIEN,
|
||||||
|
SUM(IFNULL(ROUND(Eurodebe, 2), 0)) - SUM(IFNULL(ROUND(EUROHABER, 2), 0)) recon
|
||||||
|
FROM XDiario
|
||||||
|
WHERE NOT enlazado
|
||||||
|
GROUP BY ASIEN
|
||||||
|
HAVING recon
|
||||||
|
) sub ON sub.ASIEN = xd.ASIEN
|
||||||
|
WHERE xd.SUBCTA > '5999999999'
|
||||||
|
GROUP BY xd.ASIEN
|
||||||
|
) sub ON sub.id = xd.id
|
||||||
|
SET xd.Eurohaber = IF(IFNULL(xd.Eurohaber, 0) = 0, xd.Eurohaber, xd.Eurohaber + sub.recon),
|
||||||
|
xd.Eurodebe = IF(IFNULL(xd.Eurodebe, 0) = 0, xd.Eurodebe, xd.Eurodebe - sub.recon);
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
||||||
|
|
||||||
GRANT EXECUTE ON PROCEDURE vn.XDiario_reconciliation TO adminBoss;
|
GRANT EXECUTE ON PROCEDURE vn.XDiario_reconciliation TO adminBoss;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`travel_detail`()
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve los detalles de los vuelos que tienen
|
||||||
|
* un almacén de salida en Ecuador o Colombia.
|
||||||
|
*/
|
||||||
|
DECLARE vDateFrom DATE DEFAULT util.VN_CURDATE() - INTERVAL 12 WEEK;
|
||||||
|
SELECT IFNULL(CONCAT(" ", entryFk), travelFk) travelAndEntry,
|
||||||
|
sub.*
|
||||||
|
FROM (
|
||||||
|
SELECT tr.id travelFk,
|
||||||
|
NULL entryFk,
|
||||||
|
TRUE isTravel,
|
||||||
|
am.name agency,
|
||||||
|
tr.ref,
|
||||||
|
tr.shipped,
|
||||||
|
wOut.name originBoxes,
|
||||||
|
tr.landed,
|
||||||
|
wIn.name destination,
|
||||||
|
SUM(b.stickers) stickers,
|
||||||
|
NULL evaNotes,
|
||||||
|
tr.kg,
|
||||||
|
CAST(SUM(b.weight * b.stickers) AS INT) loadedkg,
|
||||||
|
CAST(
|
||||||
|
SUM(vc.aerealVolumetricDensity *
|
||||||
|
b.stickers *
|
||||||
|
IF(p.volume,
|
||||||
|
p.volume,
|
||||||
|
p.width * p.depth * p.height
|
||||||
|
) / 1000000
|
||||||
|
) AS INT
|
||||||
|
) volumeKg,
|
||||||
|
NULL loadPriority,
|
||||||
|
NULL invoiceAmount,
|
||||||
|
s.nickname freighter,
|
||||||
|
NULL reference
|
||||||
|
FROM travel tr
|
||||||
|
LEFT JOIN supplier s ON s.id = tr.cargoSupplierFk
|
||||||
|
LEFT JOIN entry e ON e.travelFk = tr.id
|
||||||
|
LEFT JOIN buy b ON b.entryFk = e.id
|
||||||
|
LEFT JOIN packaging p ON p.id = b.packagingFk
|
||||||
|
LEFT JOIN item i ON i.id = b.itemFk
|
||||||
|
LEFT JOIN itemType it ON it.id = i.typeFk
|
||||||
|
JOIN warehouse wIn ON wIn.id = tr.warehouseInFk
|
||||||
|
JOIN warehouse wOut ON wOut.id = tr.warehouseOutFk
|
||||||
|
JOIN agencyMode am ON am.id = tr.agencyModeFk
|
||||||
|
JOIN volumeConfig vc
|
||||||
|
WHERE tr.landed >= vDateFrom
|
||||||
|
AND (wOut.code = "col" OR wOut.code = "ecu")
|
||||||
|
GROUP BY tr.id
|
||||||
|
UNION ALL
|
||||||
|
SELECT e.travelFk,
|
||||||
|
e.id,
|
||||||
|
FALSE,
|
||||||
|
s.name,
|
||||||
|
e.invoiceNumber,
|
||||||
|
tr.shipped,
|
||||||
|
wOut.name,
|
||||||
|
tr.landed,
|
||||||
|
wIn.name,
|
||||||
|
SUM(b.stickers),
|
||||||
|
e.evaNotes,
|
||||||
|
NULL,
|
||||||
|
CAST(SUM(b.weight * b.stickers) AS INT),
|
||||||
|
CAST(
|
||||||
|
SUM(vc.aerealVolumetricDensity *
|
||||||
|
b.stickers *
|
||||||
|
IF(p.volume,
|
||||||
|
p.volume,
|
||||||
|
p.width * p.depth * p.height
|
||||||
|
) / 1000000
|
||||||
|
) AS INT
|
||||||
|
),
|
||||||
|
loadPriority,
|
||||||
|
e.invoiceAmount,
|
||||||
|
s2.nickname,
|
||||||
|
e.reference
|
||||||
|
FROM entry e
|
||||||
|
JOIN buy b ON b.entryFk = e.id
|
||||||
|
JOIN packaging p ON p.id = b.packagingFk
|
||||||
|
JOIN item i ON i.id = b.itemFk
|
||||||
|
JOIN itemType it ON it.id = i.typeFk
|
||||||
|
JOIN supplier s ON s.id = e.supplierFk
|
||||||
|
JOIN travel tr ON tr.id = e.travelFk
|
||||||
|
LEFT JOIN supplier s2 ON s2.id = tr.cargoSupplierFk
|
||||||
|
JOIN warehouse wIn ON wIn.id = tr.warehouseInFk
|
||||||
|
JOIN warehouse wOut ON wOut.id = tr.warehouseOutFk
|
||||||
|
JOIN volumeConfig vc
|
||||||
|
WHERE tr.landed >= vDateFrom
|
||||||
|
AND (wOut.code = "col" OR wOut.code = "ecu")
|
||||||
|
GROUP BY e.id
|
||||||
|
) sub
|
||||||
|
ORDER BY landed ASC,
|
||||||
|
shipped ASC,
|
||||||
|
travelFk,
|
||||||
|
isTravel DESC,
|
||||||
|
(loadPriority > 0) DESC,
|
||||||
|
loadPriority,
|
||||||
|
agency,
|
||||||
|
evaNotes;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
||||||
|
|
||||||
GRANT EXECUTE ON PROCEDURE vn.travel_detail TO buyer;
|
GRANT EXECUTE ON PROCEDURE vn.travel_detail TO buyer;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`entry_getTransfer`(
|
||||||
|
vSelf INT
|
||||||
|
)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Gestiona el traslado de productos a partir de una entrada específica.
|
||||||
|
*
|
||||||
|
* @param vSelf Id de entrada
|
||||||
|
*/
|
||||||
|
DECLARE vDateShipped DATE;
|
||||||
|
DECLARE vDateLanded DATE;
|
||||||
|
DECLARE vWarehouseIn INT;
|
||||||
|
DECLARE vWarehouseOut INT;
|
||||||
|
DECLARE vCalcVisible INT;
|
||||||
|
DECLARE vInventoryDate DATE DEFAULT vn.getInventoryDate();
|
||||||
|
|
||||||
|
SELECT shipped, landed, warehouseInFk, warehouseOutFk
|
||||||
|
INTO vDateShipped, vDateLanded, vWarehouseIn, vWarehouseOut
|
||||||
|
FROM vn.travel t
|
||||||
|
JOIN vn.entry e ON e.travelFk = t.id
|
||||||
|
WHERE e.id = vSelf;
|
||||||
|
|
||||||
|
CALL vn.rate_getPrices(vDateShipped, vWarehouseIn);
|
||||||
|
|
||||||
|
-- Traslado en almacen origen
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tBuy
|
||||||
|
(PRIMARY KEY (itemFk), INDEX(buyFk))
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT *
|
||||||
|
FROM (
|
||||||
|
SELECT b.itemFk, b.id buyFk
|
||||||
|
FROM buy b
|
||||||
|
JOIN entry e ON e.id = b.entryFk
|
||||||
|
JOIN travel t ON t.id = e.travelFk
|
||||||
|
WHERE t.landed BETWEEN vInventoryDate AND vDateShipped
|
||||||
|
AND NOT b.isIgnored
|
||||||
|
AND b.price2 >= 0
|
||||||
|
ORDER BY (vWarehouseOut = t.warehouseInFk) DESC, t.landed DESC
|
||||||
|
LIMIT 10000000000000000000
|
||||||
|
) sub
|
||||||
|
GROUP BY itemFk;
|
||||||
|
|
||||||
|
IF vDateShipped >= util.VN_CURDATE() THEN
|
||||||
|
CALL `cache`.visible_refresh(vCalcVisible, TRUE, vWarehouseOut);
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tItem (
|
||||||
|
`itemFk` int(10) unsigned NOT NULL,
|
||||||
|
`visible` int(11) NOT NULL DEFAULT 0,
|
||||||
|
`available` int(11) NOT NULL DEFAULT 0,
|
||||||
|
`visibleLanding` int(11) NOT NULL DEFAULT 0,
|
||||||
|
`availableLanding` int(11) NOT NULL DEFAULT 0,
|
||||||
|
UNIQUE INDEX i USING HASH (itemFk)
|
||||||
|
) ENGINE = MEMORY;
|
||||||
|
|
||||||
|
INSERT INTO tItem(itemFk, visible)
|
||||||
|
SELECT item_id itemFk, visible
|
||||||
|
FROM `cache`.visible
|
||||||
|
WHERE calc_id = vCalcVisible
|
||||||
|
AND visible;
|
||||||
|
|
||||||
|
CALL `cache`.visible_refresh(vCalcVisible, TRUE, vWarehouseIn);
|
||||||
|
|
||||||
|
INSERT INTO tItem(itemFk, visibleLanding)
|
||||||
|
SELECT item_id, `visible`
|
||||||
|
FROM `cache`.`visible` v
|
||||||
|
WHERE v.calc_id = vCalcVisible
|
||||||
|
AND v.`visible`
|
||||||
|
ON DUPLICATE KEY UPDATE visibleLanding = v.`visible`;
|
||||||
|
|
||||||
|
CALL vn2008.availableTraslate(vWarehouseOut, vDateShipped, NULL);
|
||||||
|
|
||||||
|
INSERT INTO tItem(itemFk, available)
|
||||||
|
SELECT a.item_id, a.available
|
||||||
|
FROM vn2008.availableTraslate a
|
||||||
|
WHERE a.available
|
||||||
|
ON DUPLICATE KEY UPDATE available = a.available;
|
||||||
|
|
||||||
|
CALL vn2008.availableTraslate(vWarehouseIn, vDateLanded, vWarehouseOut);
|
||||||
|
|
||||||
|
INSERT INTO tItem(itemFk, availableLanding)
|
||||||
|
SELECT a.item_id, a.available
|
||||||
|
FROM vn2008.availableTraslate a
|
||||||
|
WHERE a.available
|
||||||
|
ON DUPLICATE KEY UPDATE availableLanding = a.available;
|
||||||
|
ELSE
|
||||||
|
CALL vn.item_getStock(vWarehouseOut, vDateShipped, NULL);
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tItem
|
||||||
|
(UNIQUE INDEX i USING HASH (itemFk))
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT itemFk,
|
||||||
|
`visible`,
|
||||||
|
available,
|
||||||
|
0 visibleLanding,
|
||||||
|
0 availableLanding
|
||||||
|
FROM tmp.itemList;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CALL vn.buyUltimateFromInterval(vWarehouseIn,vInventoryDate, vDateLanded);
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tTransfer
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT it.categoryFk,
|
||||||
|
i.typeFk,
|
||||||
|
i.id itemFk,
|
||||||
|
i.name item,
|
||||||
|
i.`size`,
|
||||||
|
i.category,
|
||||||
|
i.inkFk,
|
||||||
|
o.code originCode,
|
||||||
|
b2.quantity,
|
||||||
|
i.stems,
|
||||||
|
CAST(ti.visible AS DECIMAL(10,0)) vis1,
|
||||||
|
CAST(ti.available AS DECIMAL(10,0)) ava1,
|
||||||
|
CAST(ti.visibleLanding AS DECIMAL(10,0)) vis2,
|
||||||
|
CAST(ti.availableLanding AS DECIMAL(10,0)) ava,
|
||||||
|
COALESCE(b2.`grouping`, b.`grouping`) `grouping`,
|
||||||
|
COALESCE(b2.packing, b.packing) packing,
|
||||||
|
COALESCE(b3.groupingMode, b2.groupingMode, b.groupingMode) package,
|
||||||
|
IFNULL(p.name, s.nickname) productor,
|
||||||
|
b.packagingFk,
|
||||||
|
b2.id buyFk,
|
||||||
|
b2.stickers,
|
||||||
|
b.ektFk,
|
||||||
|
it.workerFk,
|
||||||
|
pa.volume,
|
||||||
|
IFNULL(pa.width, 0) width,
|
||||||
|
IFNULL(pa.`depth`, 0) `depth`,
|
||||||
|
IFNULL(pa.height, 0) height,
|
||||||
|
IFNULL(b.buyingValue, 0) buyingValue,
|
||||||
|
IFNULL(b.comissionValue, 0) comissionValue,
|
||||||
|
IFNULL(b.freightValue, 0) freightValue,
|
||||||
|
am.m3,
|
||||||
|
e.commission,
|
||||||
|
pa.isPackageReturnable,
|
||||||
|
IFNULL(pa2.value, pa.value) `value`,
|
||||||
|
r.rate3,
|
||||||
|
r.rate2,
|
||||||
|
it.promo,
|
||||||
|
b.`grouping` groupingOrigin,
|
||||||
|
b.packing packingOrigin,
|
||||||
|
b.id buyFkOrigin,
|
||||||
|
pa.returnCost,
|
||||||
|
b.weight
|
||||||
|
FROM vn.item i
|
||||||
|
JOIN tItem ti ON ti.itemFk = i.id
|
||||||
|
LEFT JOIN vn.producer p ON p.id = i.producerFk
|
||||||
|
LEFT JOIN vn.itemType it ON it.id = i.typeFk
|
||||||
|
JOIN vn.itemCategory ic ON ic.id = it.categoryFk
|
||||||
|
LEFT JOIN vn.origin o ON o.id = i.originFk
|
||||||
|
LEFT JOIN tBuy lb ON lb.itemFk = i.id
|
||||||
|
LEFT JOIN vn.buy b ON b.id = lb.buyFk
|
||||||
|
LEFT JOIN vn.packaging pa ON pa.id = b.packagingFk
|
||||||
|
LEFT JOIN vn.entry e2 ON e2.id = b.entryFk
|
||||||
|
LEFT JOIN vn.supplier s ON s.id = e2.supplierFk
|
||||||
|
LEFT JOIN vn.entry e ON e.id = vSelf
|
||||||
|
LEFT JOIN vn.travel tr ON tr.id = e.travelFk
|
||||||
|
LEFT JOIN vn.agencyMode am ON am.id = tr.agencyModeFk
|
||||||
|
LEFT JOIN vn.buy b2 ON b2.itemFk = i.id
|
||||||
|
AND b2.entryFk = vSelf
|
||||||
|
LEFT JOIN vn.packaging pa2 ON pa2.id = b.packagingFk
|
||||||
|
LEFT JOIN tmp.rate r ON TRUE
|
||||||
|
LEFT JOIN tmp.buyUltimateFromInterval bufi ON bufi.itemFk = i.id
|
||||||
|
LEFT JOIN vn.buy b3 ON b3.id = bufi.buyFk
|
||||||
|
WHERE ic.display
|
||||||
|
AND NOT e.isRaid
|
||||||
|
AND (ti.visible != 0 OR ti.available != 0)
|
||||||
|
ORDER BY i.typeFk, i.name, i.id, i.size, i.category, o.name;
|
||||||
|
|
||||||
|
CREATE INDEX tIndex USING HASH ON tTransfer (itemFk);
|
||||||
|
|
||||||
|
SET @carriage := 0;
|
||||||
|
SET @comission := 0;
|
||||||
|
SET @packaging := 0;
|
||||||
|
SET @rate3 := 0;
|
||||||
|
SET @cost := 0;
|
||||||
|
SELECT *,
|
||||||
|
quantity - MOD(quantity , `grouping`) subQuantity,
|
||||||
|
MOD(quantity, `grouping`) soll,
|
||||||
|
ROUND((IF(volume > 0,volume, width * `depth` * IF(height = 0, `size` + 10, height))) / packing, 0) cm3,
|
||||||
|
buyingValue + comissionValue + freightValue Cost,
|
||||||
|
@carriage := ROUND((IF(volume > 0, volume, width * `depth` * IF(height = 0, `size` + 10, height))) * m3 / 1000000 / Packing, 3) carriage,
|
||||||
|
@comission := ROUND((buyingValue + comissionValue + freightValue) * commission / 100, 3) commission,
|
||||||
|
ROUND(@packaging := (returnCost + IF(isPackageReturnable != 0, 0, value)) / packing, 3) packaging,
|
||||||
|
@cost := IFNULL((buyingValue + comissionValue + freightValue), 0) +
|
||||||
|
IFNULL(@packaging, 0) +
|
||||||
|
IFNULL(@carriage, 0) +
|
||||||
|
IFNULL(@comission, 0) cost,
|
||||||
|
@rate3 := ROUND(@cost / ( (100 - rate3 - promo) / 100), 2) rate3,
|
||||||
|
ROUND(@rate3 * (1 + ((rate2 - rate3)/100)), 2) rate2,
|
||||||
|
FALSE selected
|
||||||
|
FROM tTransfer;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS
|
||||||
|
tTransfer,
|
||||||
|
tItem,
|
||||||
|
tBuy,
|
||||||
|
tmp.buyUltimateFromInterval,
|
||||||
|
tmp.rate,
|
||||||
|
tmp.itemList;
|
||||||
|
END$$
|
||||||
|
DELIMITER ;
|
||||||
|
|
||||||
GRANT EXECUTE ON PROCEDURE vn.entry_getTransfer TO claimManager, buyer;
|
GRANT EXECUTE ON PROCEDURE vn.entry_getTransfer TO claimManager, buyer;
|
Loading…
Reference in New Issue