Compare commits

...

12 Commits

Author SHA1 Message Date
Robert Ferrús acd422d48f Merge pull request 'feat: refs #7150' (!2224) from 7150-greuge_dif_porte_add into dev
gitea/salix/pipeline/head This commit looks good Details
gitea/salix/pipeline/pr-dev This commit looks good Details
Reviewed-on: #2224
Reviewed-by: Carlos Andrés <carlosap@verdnatura.es>
2024-04-10 07:01:13 +00:00
Robert Ferrús 2c91385e62 Merge branch '7150-greuge_dif_porte_add' of https://gitea.verdnatura.es/verdnatura/salix into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-10 08:09:57 +02:00
Robert Ferrús c30c0de92c feat: refs #7150 2024-04-10 08:09:54 +02:00
Robert Ferrús 3420667ae5 Merge branch 'dev' into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-10 06:05:03 +00:00
Robert Ferrús 4a31fe29b8 Merge branch 'dev' into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-09 05:40:01 +00:00
Robert Ferrús 6ba43a3c6d Merge branch 'dev' into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-08 11:29:09 +00:00
Robert Ferrús 0c5b9e3544 Merge branch 'dev' into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-08 10:28:02 +00:00
Robert Ferrús 657150a9a7 feat: refs #7150 greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-08 08:57:56 +02:00
Robert Ferrús 1e8e6a67a3 Merge branch 'dev' into 7150-greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-08 06:39:22 +00:00
Robert Ferrús 5517c29c1c fet: refs #7150 greuge_dif_porte_add
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-04-08 08:37:37 +02:00
Robert Ferrús ed1bc06301 feat: refs #7150
gitea/salix/pipeline/pr-dev This commit looks good Details
2024-03-27 17:30:52 +01:00
Robert Ferrús 9667d31441 feat: refs #7150
gitea/salix/pipeline/pr-dev There was a failure building this commit Details
2024-03-27 17:00:27 +01:00
2 changed files with 66 additions and 50 deletions

View File

@ -1,8 +1,19 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`greuge_dif_porte_add`()
BEGIN
DECLARE datSTART DATETIME DEFAULT TIMESTAMPADD(DAY,-60,util.VN_CURDATE()); -- '2019-07-01'
DECLARE datEND DATETIME DEFAULT TIMESTAMPADD(DAY,-1,util.VN_CURDATE());
/**
* Calculates the greuge based on a specific date in the 'grievanceConfig' table
*/
DECLARE vDateStarted DATETIME;
DECLARE vDateEnded DATETIME DEFAULT (util.VN_CURDATE() - INTERVAL 1 DAY);
DECLARE vDaysAgoOffset INT;
SELECT daysAgoOffset INTO vDaysAgoOffset
FROM vn.greugeConfig;
SET vDateStarted = util.VN_CURDATE() - INTERVAL vDaysAgoOffset DAY;
DROP TEMPORARY TABLE IF EXISTS tmp.dp;
@ -10,53 +21,53 @@ BEGIN
CREATE TEMPORARY TABLE tmp.dp
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT t.id ticketFk,
SUM((t.zonePrice - t.zoneBonus) * ebv.ratio) AS teorico,
00000.00 as practico,
00000.00 as greuge,
t.clientFk,
t.shipped
FROM
vn.ticket t
JOIN vn2008.Clientes cli ON cli.Id_cliente = t.clientFk
LEFT JOIN vn.expedition e ON e.ticketFk = t.id
JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = e.freightItemFk
JOIN vn.zone z ON t.zoneFk = z.id
WHERE
t.shipped between datSTART AND datEND
AND cli.`real`
AND t.companyFk IN (442 , 567)
AND z.isVolumetric = FALSE
GROUP BY t.id;
SELECT t.id ticketFk,
SUM((t.zonePrice - t.zoneBonus) * ebv.ratio) teorico,
00000.00 practico,
00000.00 greuge,
t.clientFk,
t.shipped
FROM vn.ticket t
JOIN vn.client c ON c.id = t.clientFk
LEFT JOIN vn.expedition e ON e.ticketFk = t.id
JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = e.freightItemFk
JOIN vn.zone z ON t.zoneFk = z.id
JOIN vn.company cp ON cp.id = t.companyFk
WHERE t.shipped BETWEEN vDateStarted AND vDateEnded
AND c.isRelevant
AND cp.code IN ('VNL', 'VNH')
AND NOT z.isVolumetric
GROUP BY t.id;
-- Agencias que cobran por volumen
INSERT INTO tmp.dp
SELECT sv.ticketFk,
SUM(IFNULL(sv.freight,0)) AS teorico,
00000.00 as practico,
00000.00 as greuge,
sv.clientFk,
sv.shipped
FROM vn.saleVolume sv
JOIN vn.zone z ON z.id = sv.zoneFk
AND sv.shipped BETWEEN datSTART AND datEND
AND z.isVolumetric != FALSE
GROUP BY sv.ticketFk;
SUM(IFNULL(sv.freight,0)) teorico,
00000.00 practico,
00000.00 greuge,
sv.clientFk,
sv.shipped
FROM vn.saleVolume sv
JOIN vn.zone z ON z.id = sv.zoneFk
AND sv.shipped BETWEEN vDateStarted AND vDateEnded
AND z.isVolumetric != FALSE
GROUP BY sv.ticketFk;
DROP TEMPORARY TABLE IF EXISTS tmp.dp_aux;
CREATE TEMPORARY TABLE tmp.dp_aux
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT dp.ticketFk, sum(Cantidad * Valor) as valor
FROM tmp.dp
JOIN vn2008.Movimientos m ON m.Id_Ticket = dp.ticketFk
JOIN vn2008.Movimientos_componentes mc using(Id_Movimiento)
WHERE mc.Id_Componente = 15
GROUP BY dp.ticketFk;
SELECT dp.ticketFk, SUM(s.quantity * sc.value) valor
FROM tmp.dp
JOIN vn.sale s ON s.ticketFk = dp.ticketFk
JOIN vn.saleComponent sc ON sc.saleFk = s.id
JOIN vn.component c ON c.id = sc.componentFk
WHERE c.code = 'delivery'
GROUP BY dp.ticketFk;
UPDATE tmp.dp
JOIN tmp.dp_aux USING(ticketFk)
JOIN tmp.dp_aux USING(ticketFk)
SET practico = IFNULL(valor,0);
DROP TEMPORARY TABLE tmp.dp_aux;
@ -64,28 +75,29 @@ BEGIN
CREATE TEMPORARY TABLE tmp.dp_aux
(PRIMARY KEY (ticketFk))
ENGINE = MEMORY
SELECT dp.ticketFk, sum(g.amount) Importe
SELECT dp.ticketFk, SUM(g.amount) Importe
FROM tmp.dp
JOIN vn.greuge g ON g.ticketFk = dp.ticketFk
WHERE g.greugeTypeFk = 1 -- dif_porte
GROUP BY dp.ticketFk;
JOIN vn.greuge g ON g.ticketFk = dp.ticketFk
JOIN vn.greugeType gt ON gt.id = g.greugeTypeFk
WHERE gt.code = 'freightDifference' -- dif_porte
GROUP BY dp.ticketFk;
UPDATE tmp.dp
JOIN tmp.dp_aux USING(ticketFk)
JOIN tmp.dp_aux USING(ticketFk)
SET greuge = IFNULL(Importe,0);
INSERT INTO vn.greuge (clientFk,description,amount,shipped,greugeTypeFk,ticketFk)
SELECT dp.clientFk
, concat('dif_porte ', dp.ticketFk)
, round(IFNULL(dp.teorico,0) - IFNULL(dp.practico,0) - IFNULL(dp.greuge,0),2) as Importe
, date(dp.shipped)
, 1
,dp.ticketFk
SELECT dp.clientFk,
CONCAT('dif_porte ', dp.ticketFk),
ROUND(IFNULL(dp.teorico,0) - IFNULL(dp.practico,0) - IFNULL(dp.greuge,0),2) Importe,
date(dp.shipped),
1,
dp.ticketFk
FROM tmp.dp
JOIN vn.client c ON c.id = dp.clientFk
JOIN vn.client c ON c.id = dp.clientFk
WHERE ABS(IFNULL(dp.teorico,0) - IFNULL(dp.practico,0) - IFNULL(dp.greuge,0)) > 1
AND c.isRelevant;
DROP TEMPORARY TABLE
tmp.dp,
tmp.dp_aux;

View File

@ -0,0 +1,4 @@
ALTER TABLE IF EXISTS `vn`.`greugeConfig`
ADD COLUMN IF NOT EXISTS `daysAgoOffset` int(11) NOT NULL;
UPDATE vn.greugeConfig SET daysAgoOffset=15;