7213-Pasar-problemas-a-columnas-calculadas #2396
|
@ -0,0 +1,26 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE FUNCTION vn.sale_hasComponentLack(vSelf INT)
|
||||
RETURNS tinyint(1)
|
||||
READS SQL DATA
|
||||
BEGIN
|
||||
/**
|
||||
* Comprueba si la línea de sale tiene todos lo componentes obligatorios
|
||||
*
|
||||
* @return BOOL
|
||||
*/
|
||||
DECLARE vHasComponentLack TINYINT(1);
|
||||
|
||||
WITH componentRequired AS(
|
||||
SELECT COUNT(*)total
|
||||
FROM component
|
||||
WHERE isRequired
|
||||
)SELECT SUM(IF(c.isRequired, TRUE, FALSE)) <> cr.total INTO vHasComponentLack
|
||||
FROM vn.sale s
|
||||
JOIN componentRequired cr
|
||||
LEFT JOIN vn.saleComponent sc ON sc.saleFk = s.id
|
||||
LEFT JOIN vn.component c ON c.id = sc.componentFk
|
||||
WHERE s.id = vSelf;
|
||||
|
||||
RETURN vHasComponentLack;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,24 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `vn`.`ticket_isTooLittle`(vSelf INT)
|
||||
RETURNS tinyint(1)
|
||||
READS SQL DATA
|
||||
BEGIN
|
||||
/**
|
||||
* Comprueba si el ticket es pequeño en función de los parámtros de configuración
|
||||
* teniendo en cuenta el volumen y el importe
|
||||
*
|
||||
* @return BOOL
|
||||
*/
|
||||
DECLARE vIsTooLittle TINYINT(1);
|
||||
|
||||
SELECT (SUM(IFNULL(sv.litros, 0)) < vc.minTicketVolume
|
||||
OR IFNULL(t.totalWithoutVat, 0) < vc.minTicketValue) INTO vIsTooLittle
|
||||
FROM ticket t
|
||||
LEFT JOIN sale s ON s.ticketFk = t.id
|
||||
LEFT JOIN saleVolume sv ON sv.ticketFk = t.id
|
||||
carlosap marked this conversation as resolved
Outdated
|
||||
JOIN volumeConfig vc
|
||||
WHERE t.id = vSelf;
|
||||
|
||||
RETURN vIsTooLittle;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,33 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buy_getRoundingProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas de redondeo para las líneas de venta relacionadas con un buy
|
||||
*
|
||||
* @param vSelf Id de ticket
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
si el proc es diu buy_ sSelf no pot ser un ticket si el proc es diu buy_ sSelf no pot ser un ticket
carlosap
commented
Elimine el proc, no el gastaré Elimine el proc, no el gastaré
|
||||
*/
|
||||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vDated DATE;
|
||||
|
||||
SELECT warehouseFk, DATE(shipped)
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
si vDated es tipo DATE, et pots ahorrar la funcion DATE(shipped) si vDated es tipo DATE, et pots ahorrar la funcion DATE(shipped)
|
||||
INTO vWarehouseFk, vDated
|
||||
FROM ticket
|
||||
WHERE id = vSelf;
|
||||
|
||||
CALL buyUltimate(vWarehouseFk, vDated);
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT s.id saleFk , MOD(s.quantity, b.`grouping`) hasProblem
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = tl.ticketFk
|
||||
JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
||||
JOIN buy b ON b.id = bu.buyFk
|
||||
WHERE t.id = vSelf;
|
||||
|
||||
CALL sale_setProblem('hasRounding');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,21 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_getComponentLackProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas para las líneas de ventas que tienen o dejan de tener problemas
|
||||
* con los componentes, verifica que esten o no todos los componenetes obligatorios
|
||||
*
|
||||
* @param vSelf Id del sale
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
(INDEX(saleFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf saleFk, sale_hasComponentLack(vSelf) hasProblem;
|
||||
|
||||
CALL sale_setProblem('hasComponentLack');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.sale;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,25 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_getComponentLackProblemComponent`(
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
realment no es un get..seria mes un sale_setComponentLackProblemComponent realment no es un get..seria mes un sale_setComponentLackProblemComponent
|
||||
vComponentFk INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas para las líneas de ventas que tienen o dejan de tener problemas
|
||||
* con los componentes que derivan de cambios en la tabla vn.component
|
||||
*
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
||||
(INDEX(saleFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT s.id saleFk, sale_hasComponentLack(s.id) hasProblem
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = t.id
|
||||
LEFT JOIN saleComponent sc ON sc.saleFk = s.id
|
||||
WHERE t.shipped >= util.midnight()
|
||||
AND sc.componentFk = vComponentFk;
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
es codi repetit, fusional en el de dalt, si li pases vComponentFk fas una cosa y si pases NULL ho mira per a tots. es codi repetit, fusional en el de dalt, si li pases vComponentFk fas una cosa y si pases NULL ho mira per a tots.
|
||||
|
||||
CALL sale_setProblem('hasComponentLack');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.sale;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,34 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_getRoundingProblem`(
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
set set
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas de redondeo para las líneas de venta
|
||||
*
|
||||
* @param vSelf Id de sale
|
||||
*/
|
||||
DECLARE vItemFk INT;
|
||||
DECLARE vWarehouseFk INT;
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
vShipped es mes concret vShipped es mes concret
|
||||
DECLARE vDated DATE;
|
||||
DECLARE vQuantity INT;
|
||||
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
no cal DATE( no cal DATE(
|
||||
SELECT s.itemFk, t.warehouseFk, DATE(t.shipped), s.quantity
|
||||
INTO vItemFk, vWarehouseFk, vDated, vQuantity
|
||||
FROM sale s
|
||||
JOIN ticket t ON t.id = s.ticketFk
|
||||
WHERE s.id = vSelf;
|
||||
|
||||
CALL buyUltimate(vWarehouseFk, vDated);
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT vSelf saleFk, MOD(vQuantity, bu.`grouping`) hasProblem
|
||||
FROM tmp.buyUltimate bu
|
||||
JOIN buy b ON b.id = bu.buyFk
|
||||
WHERE bu.itemFk = vItemFk;
|
||||
|
||||
CALL sale_setProblem('hasRounding');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,17 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_setProblem`(
|
||||
vProblemCode VARCHAR(25)
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza en la tabla sale la columna problema
|
||||
* @table tmp.sale(saleFk, hasProblem) Identificadores de los sales a actualizar
|
||||
*/
|
||||
UPDATE sale s
|
||||
JOIN tmp.sale ts ON ts.saleFk = s.id
|
||||
SET s.problem = CONCAT(
|
||||
IF(ts.hasProblem,
|
||||
CONCAT(s.problem, ',', vProblemCode),
|
||||
REPLACE(s.problem, vProblemCode , '')));
|
||||
carlosap marked this conversation as resolved
jgallego
commented
explicam el objectiu d'esta linea explicam el objectiu d'esta linea
carlosap
commented
Està validat per Juan, de moment no em trobat manera de fer-ho diferent, marca o desmarca un valor de un camp SET Està validat per Juan, de moment no em trobat manera de fer-ho diferent, marca o desmarca un valor de un camp SET
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,25 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getFreezeProblem`(
|
||||
vClientFk INT
|
||||
)
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Actualiza los problemas de los ticket de hoy y a fututo cuyo cliente
|
||||
* se encuentra congelado o deja de estarlo
|
||||
*
|
||||
* @param vClientFk Id del cliente
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, NOT c.isFreezed hasProblem
|
||||
FROM ticket t
|
||||
JOIN client c ON c.id = t.clientFk
|
||||
WHERE t.shipped >= util.midnight()
|
||||
AND c.id = vClientFk;
|
||||
|
||||
CALL ticket_setProblem('isFreezed');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,26 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getRequestProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas cuando el ticket tiene una petición de compra pendiente o
|
||||
* deja de tenerla
|
||||
* @param vSelf Id del ticket de la petición de compra
|
||||
*/
|
||||
DECLARE vHasProblem BOOL;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, COUNT(tr.id) hasProblem
|
||||
FROM ticket t
|
||||
LEFT JOIN ticketRequest tr ON tr.ticketFk = t.id
|
||||
WHERE t.id = vSelf
|
||||
AND isOK IS NULL;
|
||||
|
||||
CALL ticket_setProblem('hasTicketRequest');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,33 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getRiskProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas para los tickets con riesgo
|
||||
*
|
||||
* @param vSelf Id del ticket
|
||||
*/
|
||||
DECLARE vHasRisk BOOL;
|
||||
DECLARE vHasHighRisk BOOL;
|
||||
|
||||
SELECT t.risk > (c.credit + 10), ((t.risk - cc.riskTolerance) > (c.credit + 10))
|
||||
INTO vHasRisk, vHasHighRisk
|
||||
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, vRisk hasProblem;
|
||||
|
||||
CALL ticket_setProblem('hasRisk');
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT vSelf ticketFk, vHasHighRisk hasProblem;
|
||||
|
||||
CALL ticket_setProblem('hasHighRisk');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,33 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getRoundingProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas de redondeo para las líneas de venta de un ticket
|
||||
*
|
||||
* @param vSelf Id de ticket
|
||||
*/
|
||||
DECLARE vWarehouseFk INT;
|
||||
DECLARE vDated DATE;
|
||||
|
||||
SELECT warehouseFk, DATE(shipped)
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
sense DATE sense DATE
|
||||
INTO vWarehouseFk, vDated
|
||||
FROM ticket
|
||||
WHERE id = vSelf;
|
||||
|
||||
CALL buyUltimate(vWarehouseFk, vDated);
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
SELECT s.id saleFk , MOD(s.quantity, b.`grouping`) hasProblem
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = tl.ticketFk
|
||||
JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk
|
||||
JOIN buy b ON b.id = bu.buyFk
|
||||
WHERE t.id = vSelf;
|
||||
|
||||
CALL sale_setProblem('hasRounding');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,26 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getTaxDataCheckedProblem`(
|
||||
vClientFk INT
|
||||
)
|
||||
proc: BEGIN
|
||||
/**
|
||||
* Actualiza los problemas de los ticket de hoy y a fututo
|
||||
* cuyo cliente tenga o no los datos comprobados
|
||||
*
|
||||
* @param vClientFk Id del cliente
|
||||
*/
|
||||
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
si actualices y despues la borres no val per a res, deuries actualizar la taula ticket en este cas ti si actualices y despues la borres no val per a res, deuries actualizar la taula ticket en este cas ti
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
esta condicio deu ser al revés, es un problema quan no te el datos comprovats esta condicio deu ser al revés, es un problema quan no te el datos comprovats
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, NOT c.isTaxDataChecked hasProblem
|
||||
FROM ticket t
|
||||
JOIN client c ON c.id = t.clientFk
|
||||
WHERE t.shipped >= util.midnight()
|
||||
AND c.id = vClientFk;
|
||||
|
||||
CALL ticket_setProblem('isTaxDataChecked');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,20 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getTooLittleProblem`(
|
||||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas cuando el ticket es demasiado pequeño o deja de serlo
|
||||
*
|
||||
* @param vSelf Id del ticket
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT vSelf ticketFk, ticket_isTooLittle(vSelf);
|
||||
|
||||
CALL ticket_setProblem('isTooLittle');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,21 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getTooLittleProblemConfig`()
|
||||
carlosap marked this conversation as resolved
Outdated
jgallego
commented
db/routines/vn/procedures/ticket_getTooLittleProblemConfig.sql db/routines/vn/procedures/ticket_getTooLittleProblemConfig.sql
y
db/routines/vn/procedures/ticket_getTooLittleProblemAll.sql
son igual llevem un?
carlosap
commented
Gastarem només la de ticket_getTooLittleProblemConfig.sql Gastarem només la de ticket_getTooLittleProblemConfig.sql
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas cuando el ticket es demasiado pequeño o deja de serlo, que derivan
|
||||
* del cambio en la tabla vn.volumeConfig
|
||||
*
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, ticket_isTooLittle(t.id) hasProblem
|
||||
FROM ticket t
|
||||
WHERE t.shipped >= util.midnight()
|
||||
GROUP BY t.id;
|
||||
|
||||
CALL ticket_setProblem('isTooLittle');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,26 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_getTooLittleProblemItemCost`(
|
||||
vItemFk INT
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza los problemas cuando el ticket es demasiado pequeño o deja de serlo, que derivan
|
||||
* del cambio en la tabla vn.itemCost
|
||||
*
|
||||
* @param vItemFk Id del item
|
||||
*/
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticket
|
||||
(INDEX(ticketFk))
|
||||
ENGINE = MEMORY
|
||||
SELECT t.id ticketFk, ticket_isTooLittle(t.id) hasProblem
|
||||
FROM ticket t
|
||||
JOIN sale s ON s.ticketFk = t.id
|
||||
WHERE s.itemFk = vItemFk
|
||||
AND t.shipped >= util.midnight()
|
||||
GROUP BY t.id;
|
||||
|
||||
CALL ticket_setProblem('isTooLittle');
|
||||
|
||||
DROP TEMPORARY TABLE tmp.ticket;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,82 @@
|
|||
DELIMITER $$
|
||||
$$
|
||||
CREATE OR REPLACE PROCEDURE vn.ticket_risk(vClientFk INT)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza el riesgo de los tickets pendientes de un cliente
|
||||
*
|
||||
* @param vClientFk Id del cliente
|
||||
*/
|
||||
DECLARE vHasDebt BOOL;
|
||||
|
||||
SELECT COUNT(*) INTO vHasDebt
|
||||
FROM `client`
|
||||
WHERE id = vClientFk
|
||||
AND typeFk = 'normal';
|
||||
|
||||
IF vHasDebt THEN
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tTicketRisk
|
||||
(KEY (ticketFk))
|
||||
ENGINE = MEMORY
|
||||
WITH ticket AS(
|
||||
SELECT id ticketFk, DATE(shipped) dated
|
||||
FROM vn.ticket t
|
||||
WHERE clientFk = vClientFk
|
||||
AND refFk IS NULL
|
||||
AND NOT isDeleted
|
||||
AND totalWithoutVat <> 0
|
||||
), dated AS(
|
||||
SELECT MIN(DATE(t.dated) - INTERVAL cc.riskScope MONTH) started,
|
||||
MAX(DATE(t.dated)) ended
|
||||
FROM ticket t
|
||||
JOIN vn.clientConfig cc
|
||||
), balance AS(
|
||||
SELECT SUM(amount)amount
|
||||
FROM (
|
||||
SELECT SUM(amount) amount
|
||||
FROM vn.clientRisk
|
||||
WHERE clientFk = vClientFk
|
||||
UNION ALL
|
||||
SELECT -(SUM(amount) / 100) amount
|
||||
FROM hedera.tpvTransaction t
|
||||
WHERE clientFk = vClientFk
|
||||
AND receiptFk IS NULL
|
||||
AND status = 'ok'
|
||||
) sub
|
||||
), uninvoiced AS(
|
||||
SELECT DATE(t.shipped) dated, SUM(t.totalWithVat)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 DATE(t.shipped)
|
||||
), receipt AS(
|
||||
SELECT DATE(payed) dated, SUM(amountPaid) amount
|
||||
FROM vn.receipt
|
||||
WHERE clientFk = vClientFk
|
||||
AND payed > util.VN_CURDATE()
|
||||
GROUP BY DATE(payed)
|
||||
), risk AS(
|
||||
SELECT ui.dated,
|
||||
SUM(ui.amount) OVER (ORDER BY ui.dated) +
|
||||
b.amount +
|
||||
SUM(IFNULL(r.amount, 0)) amount
|
||||
FROM balance b
|
||||
JOIN uninvoiced ui
|
||||
LEFT JOIN receipt r ON r.dated > ui.dated
|
||||
GROUP BY ui.dated
|
||||
)
|
||||
SELECT ti.ticketFk, r.amount
|
||||
FROM ticket ti
|
||||
JOIN risk r ON r.dated = ti.dated;
|
||||
|
||||
UPDATE ticket t
|
||||
JOIN tTicketRisk tr ON tr.ticketFk = t.id
|
||||
SET t.risk = tr.amount;
|
||||
|
||||
DROP TEMPORARY TABLE IF EXISTS tTicketRisk;
|
||||
END IF;
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,17 @@
|
|||
DELIMITER $$
|
||||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_setProblem`(
|
||||
vProblemCode VARCHAR(25)
|
||||
)
|
||||
BEGIN
|
||||
/**
|
||||
* Actualiza en la tabla ticket la columna problema
|
||||
* @table tmp.ticket(ticketFk, hasProblem) Identificadores de los tickets a actualizar
|
||||
*/
|
||||
UPDATE ticket t
|
||||
JOIN tmp.ticket tt ON tt.ticketFk = t.id
|
||||
SET t.problem = CONCAT(
|
||||
IF(tt.hasProblem,
|
||||
CONCAT(problem, ',', vProblemCode),
|
||||
REPLACE(problem, vProblemCode , '')));
|
||||
END$$
|
||||
DELIMITER ;
|
|
@ -0,0 +1,8 @@
|
|||
ALTER TABLE vn.ticket DROP COLUMN IF EXISTS problem;
|
||||
ALTER TABLE vn.sale DROP COLUMN IF EXISTS problem;
|
||||
ALTER TABLE vn.ticket DROP COLUMN IF EXISTS risk;
|
||||
|
||||
ALTER TABLE vn.ticket ADD IF NOT EXISTS problem SET('hasTicketRequest', 'isFreezed', 'hasRisk', 'hasHighRisk', 'isTaxDataChecked', 'isTooLittle')NOT NULL DEFAULT '';
|
||||
ALTER TABLE vn.sale ADD IF NOT EXISTS problem SET('hasItemShortage', 'hasComponentLack', 'hasItemDelay', 'hasRounding', 'hasItemLost')NOT NULL DEFAULT '';
|
||||
ALTER TABLE vn.ticket ADD IF NOT EXISTS risk DECIMAL(10,2) DEFAULT NULL NULL COMMENT 'cache calculada con el riesgo del cliente';
|
||||
|
la taula sale no es gasta, pots llevarla