salix/db/routines/stock/procedures/log_refreshSale.sql

67 lines
1.5 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `stock`.`log_refreshSale`(
`vTableName` VARCHAR(255),
`vTableId` INT)
BEGIN
DROP TEMPORARY TABLE IF EXISTS tValues;
CREATE TEMPORARY TABLE tValues
ENGINE = MEMORY
SELECT
m.id saleFk,
m.ticketFk,
m.itemFk,
t.warehouseFk,
t.shipped,
ABS(m.quantity) quantity,
m.created,
TIMESTAMPADD(DAY, tp.life, t.shipped) expired,
m.quantity < 0 isIn,
m.isPicked OR s.alertLevel > al.id isPicked
FROM vn.sale m
JOIN vn.ticket t ON t.id = m.ticketFk
JOIN vn.ticketState s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = m.itemFk
JOIN vn.itemType tp ON tp.id = i.typeFk
JOIN vn.alertLevel al ON al.code = 'ON_PREPARATION'
WHERE (
vTableId IS NULL
OR (vTableName = 'ticket' AND t.id = vTableId)
OR (vTableName = 'sale' AND m.id = vTableId)
)
AND t.shipped >= vn.getInventoryDate()
AND m.quantity != 0;
REPLACE INTO inbound (
tableName, tableId, warehouseFk, dated,
itemFk, expired, quantity, isPicked
)
SELECT 'sale',
saleFk,
warehouseFk,
shipped,
itemFk,
expired,
quantity,
isPicked
FROM tValues
WHERE isIn;
REPLACE INTO outbound (
tableName, tableId, warehouseFk, dated,
itemFk, created, quantity, isPicked
)
SELECT 'sale',
saleFk,
warehouseFk,
shipped,
itemFk,
created,
quantity,
isPicked
FROM tValues
WHERE !isIn;
DROP TEMPORARY TABLE tValues;
END$$
DELIMITER ;