salix/db/changes/10320-monitors/00-sale_getProblems.sql

187 lines
7.3 KiB
SQL

DROP PROCEDURE IF EXISTS `vn`.`sale_getProblems`;
DELIMITER $$
$$
CREATE
DEFINER = root@`%` PROCEDURE `vn`.`sale_getProblems`(IN vIsTodayRelative TINYINT(1))
BEGIN
DECLARE vWarehouse INT;
DECLARE vDate DATE;
DECLARE vAvailableCache INT;
DECLARE vDone INT DEFAULT 0;
DECLARE vComponentCount INT;
DECLARE vCursor CURSOR FOR
SELECT DISTINCT tt.warehouseFk, IF(vIsTodayRelative, CURDATE(), date(tt.shipped))
FROM tmp.sale_getProblems tt
WHERE DATE(tt.shipped) BETWEEN CURDATE()
AND TIMESTAMPADD(DAY, IF(vIsTodayRelative, 9.9, 1.9), CURDATE());
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = 1;
DROP TEMPORARY TABLE IF EXISTS tmp.sale_problems;
CREATE TEMPORARY TABLE tmp.sale_problems (
ticketFk INT(11),
saleFk INT(11),
isFreezed INTEGER(1) DEFAULT 0,
risk DECIMAL(10,2) DEFAULT 0,
hasTicketRequest INTEGER(1) DEFAULT 0,
isAvailable INTEGER(1) DEFAULT 1,
itemShortage VARCHAR(250),
isTaxDataChecked INTEGER(1) DEFAULT 1,
itemDelay VARCHAR(250),
hasComponentLack INTEGER(1),
PRIMARY KEY (ticketFk, saleFk)
) ENGINE = MEMORY;
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_list;
CREATE TEMPORARY TABLE tmp.ticket_list
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT tp.ticketFk, c.id clientFk
FROM tmp.sale_getProblems tp
JOIN vn.client c ON c.id = tp.clientFk;
SELECT COUNT(*) INTO vComponentCount
FROM vn.component c
WHERE c.isRequired;
INSERT INTO tmp.sale_problems(ticketFk, hasComponentLack, saleFk)
SELECT tl.ticketFk, (COUNT(DISTINCT s.id) * vComponentCount > COUNT(c.id)), s.id
FROM tmp.ticket_list tl
JOIN vn.sale s ON s.ticketFk = tl.ticketFk
LEFT JOIN vn.saleComponent sc ON sc.saleFk = s.id
LEFT JOIN vn.component c ON c.id = sc.componentFk AND c.isRequired
GROUP BY tl.ticketFk, s.id;
INSERT INTO tmp.sale_problems(ticketFk, isFreezed)
SELECT DISTINCT tl.ticketFk, TRUE
FROM tmp.ticket_list tl
JOIN vn.client c ON c.id = tl.clientFk
WHERE c.isFreezed
ON DUPLICATE KEY UPDATE
isFreezed = c.isFreezed;
DROP TEMPORARY TABLE IF EXISTS tmp.clientGetDebt;
CREATE TEMPORARY TABLE tmp.clientGetDebt
(PRIMARY KEY (clientFk))
ENGINE = MEMORY
SELECT DISTINCT clientFk
FROM tmp.ticket_list;
CALL clientGetDebt(CURDATE());
INSERT INTO tmp.sale_problems(ticketFk, risk)
SELECT DISTINCT tl.ticketFk, r.risk
FROM tmp.ticket_list tl
JOIN vn.ticket t ON t.id = tl.ticketFk
JOIN vn.agencyMode a ON t.agencyModeFk = a.id
JOIN tmp.risk r ON r.clientFk = t.clientFk
JOIN vn.client c ON c.id = t.clientFk
JOIN vn.clientConfig cc
WHERE r.risk - cc.riskTolerance > c.credit + 10
AND a.isRiskFree = FALSE
ON DUPLICATE KEY UPDATE
risk = r.risk;
INSERT INTO tmp.sale_problems(ticketFk, hasTicketRequest)
SELECT DISTINCT tl.ticketFk, TRUE
FROM tmp.ticket_list tl
JOIN vn.ticketRequest tr ON tr.ticketFk = tl.ticketFk
WHERE tr.isOK IS NULL
ON DUPLICATE KEY UPDATE
hasTicketRequest = TRUE;
OPEN vCursor;
WHILE NOT vDone
DO
FETCH vCursor INTO vWarehouse, vDate;
CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouse, vDate);
INSERT INTO tmp.sale_problems(ticketFk, isAvailable, saleFk)
SELECT tl.ticketFk, FALSE, s.id
FROM tmp.ticket_list tl
JOIN vn.ticket t ON t.id = tl.ticketFk
JOIN vn.sale s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = s.itemFk
JOIN vn.itemType it on it.id = i.typeFk
LEFT JOIN cache.available av ON av.item_id = i.id
AND av.calc_id = vAvailableCache
WHERE date(t.shipped) = vDate
AND it.categoryFk != 6
AND IFNULL(av.available, 0) < 0
AND s.isPicked = FALSE
AND NOT i.generic
AND vWarehouse = t.warehouseFk
GROUP BY tl.ticketFk
ON DUPLICATE KEY UPDATE
isAvailable = FALSE, saleFk = VALUE(saleFk);
INSERT INTO tmp.sale_problems(ticketFk, itemShortage, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
SELECT tl.ticketFk, CONCAT('F: ',GROUP_CONCAT(i.id, ' ', i.longName, ' ')) problem, s.id AS saleFk
FROM tmp.ticket_list tl
JOIN vn.ticket t ON t.id = tl.ticketFk
JOIN vn.sale s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = s.itemFk
JOIN vn.itemType it on it.id = i.typeFk
LEFT JOIN vn.itemShelvingStock_byWarehouse issw ON issw.itemFk = i.id AND issw.warehouseFk = t.warehouseFk
LEFT JOIN cache.available av ON av.item_id = i.id AND av.calc_id = vAvailableCache
WHERE IFNULL(av.available, 0) < 0
AND s.quantity > IFNULL(issw.visible, 0)
AND s.quantity > 0
AND s.isPicked = FALSE
AND s.reserved = FALSE
AND it.categoryFk != 6
AND IF(vIsTodayRelative, TRUE, date(t.shipped) = vDate)
AND NOT i.generic
AND CURDATE() = vDate
AND t.warehouseFk = vWarehouse
GROUP BY tl.ticketFk) sub
ON DUPLICATE KEY UPDATE
itemShortage = sub.problem, saleFk = sub.saleFk;
INSERT INTO tmp.sale_problems(ticketFk, itemDelay, saleFk)
SELECT ticketFk, problem, saleFk
FROM (
SELECT tl.ticketFk, GROUP_CONCAT('I: ',i.id, ' ', i.longName, ' ') problem, s.id AS saleFk
FROM tmp.ticket_list tl
JOIN vn.ticket t ON t.id = tl.ticketFk
JOIN vn.sale s ON s.ticketFk = t.id
JOIN vn.item i ON i.id = s.itemFk
JOIN vn.itemType it on it.id = i.typeFk
LEFT JOIN vn.itemShelvingStock_byWarehouse issw ON issw.itemFk = i.id AND issw.warehouseFk = t.warehouseFk
WHERE s.quantity > IFNULL(issw.visible, 0)
AND s.quantity > 0
AND s.isPicked = FALSE
AND s.reserved = FALSE
AND it.categoryFk != 6
AND IF(vIsTodayRelative, TRUE, date(t.shipped) = vDate)
AND NOT i.generic
AND CURDATE() = vDate
AND t.warehouseFk = vWarehouse
GROUP BY tl.ticketFk) sub
ON DUPLICATE KEY UPDATE
itemDelay = sub.problem, saleFk = sub.saleFk;
END WHILE;
CLOSE vCursor;
INSERT INTO tmp.sale_problems(ticketFk, isTaxDataChecked)
SELECT DISTINCT tl.ticketFk, FALSE
FROM tmp.ticket_list tl
JOIN vn.client c ON c.id = tl.clientFk
WHERE c.isTaxDataChecked = FALSE
ON DUPLICATE KEY UPDATE
isTaxDataChecked = FALSE;
DROP TEMPORARY TABLE
tmp.clientGetDebt,
tmp.ticket_list;
END;;$$
DELIMITER ;