feat: Turn issues into calculated columns refs#7213 #2646
|
@ -0,0 +1,27 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`ticket_isProblemCalcNeeded`(
|
||||
vSelf INT
|
||||
)
|
||||
RETURNS BOOL
|
||||
DETERMINISTIC
|
||||
BEGIN
|
||||
/**
|
||||
* Check if the ticket requires to update column vn.ticket.problem
|
||||
*
|
||||
* @param vSelf Id ticket
|
||||
* @return BOOL
|
||||
*/
|
||||
DECLARE vIsProblemCalcNeeded BOOL;
|
||||
|
||||
SELECT COUNT(*) INTO vIsProblemCalcNeeded
|
||||
FROM ticket t
|
||||
JOIN client c ON c.id = t.clientFk
|
||||
JOIN agencyMode am ON am.id = t.agencyModeFk
|
||||
JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk
|
||||
WHERE t.id = vSelf
|
||||
AND dm.code IN ('AGENCY','DELIVERY','PICKUP')
|
||||
AND c.typeFk = 'normal';
|
||||
|
||||
RETURN vIsProblemCalcNeeded;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -1,5 +1,8 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buyUltimate`(vWarehouseFk SMALLINT, vDated DATE)
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buyUltimate`(
|
||||
vWarehouseFk SMALLINT,
|
||||
vDated DATE
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Calcula las últimas compras realizadas hasta una fecha
|
||||
|
@ -19,6 +22,7 @@ BEGIN
|
|||
FROM cache.last_buy
|
||||
WHERE warehouse_id = vWarehouseFk OR vWarehouseFk IS NULL;
|
||||
|
||||
IF vDated >= util.VN_CURDATE() THEN
|
||||
CALL buyUltimateFromInterval(vWarehouseFk, util.VN_CURDATE(), vDated);
|
||||
|
||||
REPLACE INTO tmp.buyUltimate
|
||||
|
@ -34,6 +38,6 @@ BEGIN
|
|||
WHERE (warehouseFk = vWarehouseFk OR vWarehouseFk IS NULL)
|
||||
AND landed > vDated
|
||||
ORDER BY isIgnored = FALSE DESC;
|
||||
|
||||
END IF;
|
||||
END$$
|
||||
DELIMITER ;
|
||||
|
|
|
@ -1,5 +1,9 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buyUltimateFromInterval`(vWarehouseFk SMALLINT, vStarted DATE, vEnded DATE)
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buyUltimateFromInterval`(
|
||||
vWarehouseFk SMALLINT,
|
||||
vStarted DATE,
|
||||
vEnded DATE
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Calcula las últimas compras realizadas
|
||||
|
@ -21,12 +25,13 @@ BEGIN
|
|||
-- Item
|
||||
DROP TEMPORARY TABLE IF EXISTS tmp.buyUltimateFromInterval;
|
||||
CREATE TEMPORARY TABLE tmp.buyUltimateFromInterval
|
||||
(PRIMARY KEY (itemFk, warehouseFk), INDEX(buyFk), INDEX(landed), INDEX(warehouseFk), INDEX(itemFk))
|
||||
(PRIMARY KEY (itemFk, warehouseFk),
|
||||
INDEX(buyFk), INDEX(landed), INDEX(warehouseFk), INDEX(itemFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
MAX(landed) landed,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM (SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
|
@ -45,8 +50,12 @@ BEGIN
|
|||
|
||||
|
||||
INSERT IGNORE INTO tmp.buyUltimateFromInterval(itemFk, warehouseFk, buyFk, landed, isIgnored)
|
||||
SELECT
|
||||
b.itemFk,
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM (SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
b.id buyFk,
|
||||
t.landed,
|
||||
|
@ -58,11 +67,17 @@ BEGIN
|
|||
AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk)
|
||||
AND b.price2 > 0
|
||||
AND NOT b.isIgnored
|
||||
GROUP BY itemFk, warehouseInFk;
|
||||
ORDER BY NOT b.isIgnored DESC, t.landed DESC, b.id DESC
|
||||
LIMIT 10000000000000000000) sub
|
||||
GROUP BY itemFk, warehouseFk;
|
||||
|
||||
INSERT IGNORE INTO tmp.buyUltimateFromInterval(itemFk, warehouseFk, buyFk, landed, isIgnored)
|
||||
SELECT
|
||||
b.itemFk,
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM (SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
b.id buyFk,
|
||||
t.landed,
|
||||
|
@ -73,14 +88,16 @@ BEGIN
|
|||
WHERE t.landed BETWEEN vStarted AND vEnded
|
||||
AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk)
|
||||
AND b.quantity = 0
|
||||
GROUP BY itemFk, warehouseInFk;
|
||||
ORDER BY NOT b.isIgnored DESC, t.landed DESC, b.id DESC
|
||||
LIMIT 10000000000000000000) sub
|
||||
GROUP BY itemFk, warehouseFk;
|
||||
|
||||
-- ItemOriginal
|
||||
INSERT IGNORE INTO tmp.buyUltimateFromInterval(itemFk, warehouseFk, buyFk, landed, isIgnored)
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
MAX(landed) landed,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM (SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
|
@ -99,11 +116,14 @@ BEGIN
|
|||
AND itemOriginalFk
|
||||
ORDER BY t.landed DESC, b.id DESC
|
||||
LIMIT 10000000000000000000) sub
|
||||
GROUP BY itemOriginalFk, warehouseFk;
|
||||
|
||||
GROUP BY itemFk, warehouseFk;
|
||||
INSERT IGNORE INTO tmp.buyUltimateFromInterval(itemFk, warehouseFk, buyFk, landed, isIgnored)
|
||||
SELECT
|
||||
b.itemFk,
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM (SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
b.id buyFk,
|
||||
t.landed,
|
||||
|
@ -116,11 +136,18 @@ BEGIN
|
|||
AND b.price2 > 0
|
||||
AND NOT b.isIgnored
|
||||
AND itemOriginalFk
|
||||
GROUP BY itemOriginalFk, warehouseInFk;
|
||||
ORDER BY t.landed DESC, b.id DESC
|
||||
LIMIT 10000000000000000000) sub
|
||||
GROUP BY itemFk, warehouseFk;
|
||||
|
||||
INSERT IGNORE INTO tmp.buyUltimateFromInterval(itemFk, warehouseFk, buyFk, landed, isIgnored)
|
||||
SELECT
|
||||
b.itemFk,
|
||||
SELECT itemFk,
|
||||
warehouseFk,
|
||||
buyFk,
|
||||
landed,
|
||||
isIgnored
|
||||
FROM
|
||||
(SELECT b.itemFk,
|
||||
t.warehouseInFk warehouseFk,
|
||||
b.id buyFk,
|
||||
t.landed,
|
||||
|
@ -132,6 +159,8 @@ BEGIN
|
|||
AND (vWarehouseFk IS NULL OR t.warehouseInFk = vWarehouseFk)
|
||||
AND b.quantity = 0
|
||||
AND itemOriginalFk
|
||||
GROUP BY itemOriginalFk, warehouseInFk;
|
||||
ORDER BY t.landed DESC, b.id DESC
|
||||
LIMIT 10000000000000000000) sub
|
||||
GROUP BY itemFk, warehouseFk;
|
||||
END$$
|
||||
DELIMITER ;
|
||||
|
|
|
@ -7,7 +7,7 @@ BEGIN
|
|||
* Update column sale.problem with a problem code
|
||||
*
|
||||
* @param vProblemCode Code to set or unset
|
||||
* @table tmp.sale(saleFk, hasProblem)
|
||||
* @table tmp.sale(saleFk, hasProblem, isProblemCalcNeeded)
|
||||
*/
|
||||
DECLARE vSaleFk INT;
|
||||
DECLARE vHasProblem INT;
|
||||
|
|
|
@ -10,9 +10,13 @@ BEGIN
|
|||
* @param vSelf Id del sale
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
(INDEX(saleFk))
|
||||
(INDEX(saleFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf saleFk, sale_hasComponentLack(vSelf) hasProblem;
|
||||
SELECT vSelf saleFk,
|
||||
sale_hasComponentLack(vSelf) hasProblem,
|
||||
ticket_isProblemCalcNeeded(ticketFk) isProblemCalcNeeded
|
||||
FROM sale
|
||||
WHERE id = vSelf;
|
||||
|
||||
CALL sale_setProblem('hasComponentLack');
|
||||
|
||||
|
|
|
@ -10,11 +10,13 @@ BEGIN
|
|||
* @param vComponentFk Id component
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
(INDEX(saleFk))
|
||||
(INDEX(saleFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT saleFk, sale_hasComponentLack(saleFk)hasProblem
|
||||
SELECT saleFk,
|
||||
sale_hasComponentLack(saleFk) hasProblem,
|
||||
ticket_isProblemCalcNeeded(ticketFk) isProblemCalcNeeded
|
||||
FROM (
|
||||
SELECT s.id saleFk
|
||||
SELECT s.id saleFk, s.ticketFk
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = t.id
|
||||
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
||||
|
|
|
@ -11,9 +11,10 @@ BEGIN
|
|||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vShipped DATE;
|
||||
DECLARE vQuantity INT;
|
||||
DECLARE vIsProblemCalcNeeded BOOL;
|
||||
|
||||
SELECT s.itemFk, t.warehouseFk, t.shipped, s.quantity
|
||||
INTO vItemFk, vWarehouseFk, vShipped, vQuantity
|
||||
SELECT s.itemFk, t.warehouseFk, t.shipped, s.quantity, ticket_isProblemCalcNeeded(t.id)
|
||||
INTO vItemFk, vWarehouseFk, vShipped, vQuantity, vIsProblemCalcNeeded
|
||||
FROM sale s
|
||||
JOIN ticket t ON t.id = s.ticketFk
|
||||
WHERE s.id = vSelf;
|
||||
|
@ -21,7 +22,9 @@ BEGIN
|
|||
CALL buyUltimate(vWarehouseFk, vShipped);
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
SELECT vSelf saleFk, MOD(vQuantity, b.`grouping`) hasProblem
|
||||
SELECT vSelf saleFk,
|
||||
MOD(vQuantity, b.`grouping`) hasProblem,
|
||||
vIsProblemCalcNeeded isProblemCalcNeeded
|
||||
FROM tmp.buyUltimate bu
|
||||
JOIN buy b ON b.id = bu.buyFk
|
||||
WHERE bu.itemFk = vItemFk;
|
||||
|
|
|
@ -4,10 +4,11 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setProblem`(
|
|||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Update column ticket.problem with a problem code
|
||||
* Update column ticket.problem with a problem code and SET NULL when
|
||||
* the problem is not requiered
|
||||
*
|
||||
* @param vProblemCode Code to set or unset
|
||||
* @table tmp.ticket(ticketFk, hasProblem)
|
||||
* @table tmp.ticket(ticketFk, hasProblem, isProblemCalcNeeded)
|
||||
*/
|
||||
DECLARE vTicketFk INT;
|
||||
DECLARE vHasProblem INT;
|
||||
|
|
|
@ -9,9 +9,11 @@ BEGIN
|
|||
* @param vClientFk Id Cliente, if NULL all clients
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
(INDEX(ticketFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, FALSE hasProblem
|
||||
SELECT t.id ticketFk,
|
||||
FALSE hasProblem,
|
||||
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
||||
FROM ticket t
|
||||
WHERE t.shipped >= util.VN_CURDATE()
|
||||
AND (vClientFk IS NULL OR t.clientFk = vClientFk);
|
||||
|
|
|
@ -9,9 +9,11 @@ BEGIN
|
|||
* @param vSelf Id ticket, if NULL ALL tickets
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
(INDEX(ticketFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, FALSE hasProblem
|
||||
SELECT t.id ticketFk,
|
||||
FALSE hasProblem,
|
||||
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
||||
FROM ticket t
|
||||
WHERE t.shipped >= util.VN_CURDATE()
|
||||
AND (vSelf IS NULL OR t.id = vSelf);
|
||||
|
|
|
@ -10,21 +10,30 @@ BEGIN
|
|||
*/
|
||||
DECLARE vHasRisk BOOL;
|
||||
DECLARE vHasHighRisk BOOL;
|
||||
DECLARE vIsProblemCalcNeeded BOOL;
|
||||
|
||||
SELECT t.risk > (c.credit + 10), ((t.risk - cc.riskTolerance) > (c.credit + 10))
|
||||
INTO vHasRisk, vHasHighRisk
|
||||
SELECT t.risk > (c.credit + 10),
|
||||
(t.risk - cc.riskTolerance) > (c.credit + 10),
|
||||
ticket_isProblemCalcNeeded(t.id)
|
||||
INTO vHasRisk, vHasHighRisk, vIsProblemCalcNeeded
|
||||
FROM client c
|
||||
JOIN ticket t ON t.clientFk = c.id
|
||||
JOIN clientConfig cc
|
||||
WHERE t.id = vSelf;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT vSelf ticketFk, vHasRisk hasProblem;
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf ticketFk,
|
||||
vHasRisk hasProblem,
|
||||
vIsProblemCalcNeeded isProblemCalcNeeded;
|
||||
|
||||
CALL ticket_setProblem('hasRisk');
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT vSelf ticketFk, vHasHighRisk hasProblem;
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf ticketFk,
|
||||
vHasHighRisk hasProblem,
|
||||
vIsProblemCalcNeeded isProblemCalcNeeded;
|
||||
|
||||
CALL ticket_setProblem('hasHighRisk');
|
||||
|
||||
|
|
|
@ -19,7 +19,10 @@ BEGIN
|
|||
CALL buyUltimate(vWarehouseFk, vDated);
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
SELECT s.id saleFk , MOD(s.quantity, b.`grouping`) hasProblem
|
||||
(INDEX(saleFk, isProblemCalcNeeded))
|
||||
SELECT s.id saleFk ,
|
||||
MOD(s.quantity, b.`grouping`) hasProblem,
|
||||
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = t.id
|
||||
JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
||||
|
|
|
@ -9,9 +9,11 @@ BEGIN
|
|||
* @param vClientFk Id cliente, if NULL all clients
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
(INDEX(ticketFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, IF(c.isTaxDataChecked, FALSE, TRUE) hasProblem
|
||||
SELECT t.id ticketFk,
|
||||
IF(c.isTaxDataChecked, FALSE, TRUE) hasProblem,
|
||||
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
||||
|
||||
FROM ticket t
|
||||
JOIN client c ON c.id = t.clientFk
|
||||
WHERE t.shipped >= util.VN_CURDATE()
|
||||
|
|
|
@ -8,13 +8,17 @@ BEGIN
|
|||
*
|
||||
* @param vSelf Id del ticket
|
||||
*/
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
(INDEX(ticketFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf ticketFk, ticket_isTooLittle(vSelf) hasProblem;
|
||||
SELECT vSelf ticketFk,
|
||||
ticket_isTooLittle(vSelf) hasProblem,
|
||||
ticket_isProblemCalcNeeded(vSelf) isProblemCalcNeeded;
|
||||
|
||||
CALL ticket_setProblem('isTooLittle');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -10,7 +10,7 @@ BEGIN
|
|||
* @param vItemFk Id del item, NULL ALL items
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
(INDEX(ticketFk, isProblemCalcNeeded))
|
||||
ENGINE = MEMORY
|
||||
WITH tickets AS(
|
||||
SELECT t.id ticketFk
|
||||
|
@ -19,7 +19,9 @@ BEGIN
|
|||
WHERE t.shipped >= util.VN_CURDATE()
|
||||
AND (s.itemFk = vItemFk OR vItemFk IS NULL)
|
||||
GROUP BY t.id
|
||||
)SELECT ticketFk, ticket_isTooLittle(ticketFk) hasProblem
|
||||
)SELECT ticketFk,
|
||||
ticket_isTooLittle(ticketFk) hasProblem,
|
||||
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
||||
FROM tickets;
|
||||
|
||||
CALL ticket_setProblem('isTooLittle');
|
||||
|
|
|
@ -8,6 +8,7 @@ BEGIN
|
|||
* @param vClientFk Id cliente
|
||||
*/
|
||||
DECLARE vHasDebt BOOL;
|
||||
DECLARE vStarted DATETIME;
|
||||
|
||||
SELECT COUNT(*) INTO vHasDebt
|
||||
FROM `client`
|
||||
|
@ -16,22 +17,24 @@ BEGIN
|
|||
|
||||
IF vHasDebt THEN
|
||||
|
||||
SELECT util.VN_CURDATE() - INTERVAL riskScope MONTH INTO vStarted
|
||||
FROM clientConfig;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tTicketRisk
|
||||
(KEY (ticketFk))
|
||||
ENGINE = MEMORY
|
||||
WITH ticket AS(
|
||||
SELECT id ticketFk, companyFk, DATE(shipped) dated
|
||||
FROM vn.ticket t
|
||||
SELECT id ticketFk,
|
||||
companyFk,
|
||||
DATE(shipped) dated,
|
||||
totalWithVat,
|
||||
ticket_isProblemCalcNeeded(id) isProblemCalcNeeded
|
||||
FROM vn.ticket
|
||||
WHERE clientFk = vClientFk
|
||||
AND refFk IS NULL
|
||||
AND NOT isDeleted
|
||||
AND totalWithoutVat <> 0
|
||||
), dated AS(
|
||||
SELECT t.companyFk, MIN(DATE(t.dated) - INTERVAL cc.riskScope MONTH) started,
|
||||
MAX(DATE(t.dated)) ended
|
||||
FROM ticket t
|
||||
JOIN vn.clientConfig cc
|
||||
GROUP BY t.companyFk
|
||||
AND IFNULL(totalWithVat, 0) <> 0
|
||||
AND shipped > vStarted
|
||||
), balance AS(
|
||||
SELECT SUM(amount)amount, companyFk
|
||||
FROM (
|
||||
|
@ -49,13 +52,9 @@ BEGIN
|
|||
WHERE companyFk
|
||||
GROUP BY companyFk
|
||||
), uninvoiced AS(
|
||||
SELECT t.companyFk, DATE(t.shipped) dated, SUM(IFNULL(t.totalWithVat, 0)) amount
|
||||
FROM vn.ticket t
|
||||
JOIN dated d
|
||||
WHERE t.clientFk = vClientFk
|
||||
AND t.refFk IS NULL
|
||||
AND t.shipped BETWEEN d.started AND d.ended
|
||||
GROUP BY t.companyFk, DATE(t.shipped)
|
||||
SELECT companyFk, dated, SUM(totalWithVat) amount
|
||||
FROM ticket
|
||||
GROUP BY companyFk, dated
|
||||
), receipt AS(
|
||||
SELECT companyFk, DATE(payed) dated, SUM(amountPaid) amount
|
||||
FROM vn.receipt
|
||||
|
@ -79,7 +78,15 @@ BEGIN
|
|||
|
||||
UPDATE ticket t
|
||||
JOIN tTicketRisk tr ON tr.ticketFk = t.id
|
||||
SET t.risk = tr.amount;
|
||||
SET t.risk = tr.amount
|
||||
WHERE tr.isProblemCalcNeeded
|
||||
ORDER BY t.id;
|
||||
|
||||
UPDATE ticket t
|
||||
JOIN tTicketRisk tr ON tr.ticketFk = t.id
|
||||
SET t.risk = NULL
|
||||
WHERE tr.isProblemCalcNeeded
|
||||
ORDER BY t.id;
|
||||
|
||||
DROP TEMPORARY TABLE tTicketRisk;
|
||||
END IF;
|
||||
|
|
Loading…
Reference in New Issue
si posem ticket_isProblemCalcNeeded en el WHERE ens evitem tant la insercio en la taula temporal, com la posterior eliminació en el procediment, y la columna isProblemCalcNeeded ja no seria necesaria, simplement el fet d'estar la linea es que hi ha que calcular-ho.
es tenen que posar a NULL