feat(monitor): Sort by amount of problems on a ticket list #723

Merged
carlosjr merged 8 commits from 3041-monitor_sort_problems into dev 2021-09-08 07:53:10 +00:00
9 changed files with 317 additions and 35 deletions

View File

@ -0,0 +1,197 @@
drop procedure `vn`.`sale_getProblems`;
DELIMITER $$
$$
create
definer = root@`%` procedure `vn`.`sale_getProblems`(IN vIsTodayRelative tinyint(1))
BEGIN
/**
* Calcula los problemas de cada venta
* para un conjunto de tickets.
*
* @table tmp.sale_getProblems(ticketFk, clientFk, warehouseFk, shipped) Identificadores de los tickets a calcular
* @return tmp.sale_problems
*/
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,
hasHighRisk TINYINT(1) 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
JOIN vn.ticket t ON t.id = tl.ticketFk
JOIN vn.agencyMode am ON am.id = t.agencyModeFk
JOIN vn.deliveryMethod dm ON dm.id = am.deliveryMethodFk
WHERE dm.code IN('AGENCY','DELIVERY','PICKUP')
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, hasHighRisk)
SELECT DISTINCT tl.ticketFk, r.risk, ((r.risk - cc.riskTolerance) > c.credit + 10)
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 > c.credit + 10
AND a.isRiskFree = FALSE
ON DUPLICATE KEY UPDATE
risk = r.risk, hasHighRisk = ((r.risk - cc.riskTolerance) > c.credit + 10);
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 = VALUES(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 LIMIT 1) 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 LIMIT 1) 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 ;

View File

@ -0,0 +1,48 @@
drop procedure `vn`.`ticket_getProblems`;
DELIMITER $$
$$
create
definer = root@`%` procedure `vn`.`ticket_getProblems`(IN vIsTodayRelative tinyint(1))
BEGIN
/**
* Calcula los problemas para un conjunto de tickets.
* Agrupados por ticket
*
* @table tmp.sale_getProblems(ticketFk, clientFk, warehouseFk, shipped) Identificadores de los tickets a calcular
* @return tmp.ticket_problems
*/
CALL sale_getProblems(vIsTodayRelative);
DROP TEMPORARY TABLE IF EXISTS tmp.ticket_problems;
CREATE TEMPORARY TABLE tmp.ticket_problems
(INDEX (ticketFk))
ENGINE = MEMORY
SELECT
ticketFk,
MAX(p.isFreezed) AS isFreezed,
MAX(p.risk) AS risk,
MAX(p.hasHighRisk) AS hasHighRisk,
MAX(p.hasTicketRequest) AS hasTicketRequest,
MIN(p.isAvailable) AS isAvailable,
MAX(p.itemShortage) AS itemShortage,
MIN(p.isTaxDataChecked) AS isTaxDataChecked,
MAX(p.hasComponentLack) AS hasComponentLack,
0 AS totalProblems
FROM tmp.sale_problems p
GROUP BY ticketFk;
UPDATE tmp.ticket_problems tp
SET tp.totalProblems = (
(tp.isFreezed) +
IF(tp.risk, TRUE, FALSE) +
(tp.hasTicketRequest) +
(tp.isAvailable = 0) +
(tp.isTaxDataChecked = 0) +
(tp.hasComponentLack)
);
DROP TEMPORARY TABLE
tmp.sale_problems;
END;;$$
DELIMITER ;

View File

@ -80,7 +80,7 @@
<vn-horizontal>
<vn-autocomplete
ng-model="$ctrl.client.transferorFk"
url="Clients/isActive"
url="Clients"
search-function="$ctrl.transferorSearchFunction($search)"
where="{id: {neq: $ctrl.client.id}}"
show-field="name"

View File

@ -348,7 +348,7 @@
</span>
</vn-td>
<vn-td shrink>
<span class="chip {{$ctrl.totalPriceColor(ticket)}}">
<span class="chip {{::$ctrl.totalPriceColor(ticket)}}">
{{::(ticket.totalWithVat ? ticket.totalWithVat : 0) | currency: 'EUR': 2}}
</span>
</vn-td>

View File

@ -264,38 +264,33 @@ module.exports = Self => {
FROM tmp.filter f
LEFT JOIN tmp.ticket_problems tp ON tp.ticketFk = f.id`);
if (args.problems != undefined && (!args.from && !args.to))
const hasProblems = args.problems;
if (hasProblems != undefined && (!args.from && !args.to))
throw new UserError('Choose a date range or days forward');
let condition;
let hasProblem;
let range;
let hasWhere;
switch (args.problems) {
case true:
condition = `or`;
hasProblem = true;
range = 0;
hasWhere = true;
break;
case false:
condition = `and`;
hasProblem = null;
range = null;
hasWhere = true;
break;
let problemsFilter;
if (hasProblems === true) {
problemsFilter = {or: [
{'tp.isFreezed': true},
{'tp.risk': {gt: 0}},
{'tp.hasTicketRequest': true},
{'tp.hasComponentLack': true},
{'tp.isTaxDataChecked': false},
{'tp.isAvailable': false}
]};
} else if (hasProblems === false) {
problemsFilter = {and: [
{'tp.isFreezed': false},
{'tp.risk': 0},
{'tp.hasTicketRequest': false},
{'tp.hasComponentLack': false},
{'tp.isTaxDataChecked': true},
{'tp.isAvailable': true}
]};
}
let problems = {[condition]: [
{'tp.isFreezed': hasProblem},
{'tp.risk': hasProblem},
{'tp.hasTicketRequest': hasProblem},
{'tp.isAvailable': range}
]};
if (hasWhere)
stmt.merge(conn.makeWhere(problems));
if (problemsFilter)
stmt.merge(conn.makeWhere(problemsFilter));
stmt.merge(conn.makeOrderBy(filter.order));
stmt.merge(conn.makeLimit(filter));

View File

@ -23,7 +23,7 @@ describe('SalesMonitor salesFilter()', () => {
const filter = {};
const result = await app.models.SalesMonitor.salesFilter(ctx, filter);
expect(result.length).toEqual(4);
expect(result.length).toEqual(9);
});
it('should return the tickets matching the problems on false', async() => {
@ -41,7 +41,7 @@ describe('SalesMonitor salesFilter()', () => {
const filter = {};
const result = await app.models.SalesMonitor.salesFilter(ctx, filter);
expect(result.length).toEqual(6);
expect(result.length).toEqual(0);
});
it('should return the tickets matching the problems on null', async() => {
@ -103,4 +103,40 @@ describe('SalesMonitor salesFilter()', () => {
expect(result.length).toEqual(4);
});
it('should return the tickets sorted by problems descendant', async() => {
const yesterday = new Date();
yesterday.setDate(yesterday.getDate() - 1);
yesterday.setHours(0, 0, 0, 0);
const today = new Date();
today.setHours(23, 59, 59, 59);
const ctx = {req: {accessToken: {userId: 18}}, args: {}};
const filter = {order: 'totalProblems DESC'};
const result = await app.models.SalesMonitor.salesFilter(ctx, filter);
const firstTicket = result.shift();
const secondTicket = result.shift();
expect(firstTicket.totalProblems).toEqual(3);
expect(secondTicket.totalProblems).toEqual(2);
});
it('should return the tickets sorted by problems ascendant', async() => {
const yesterday = new Date();
yesterday.setDate(yesterday.getDate() - 1);
yesterday.setHours(0, 0, 0, 0);
const today = new Date();
today.setHours(23, 59, 59, 59);
const ctx = {req: {accessToken: {userId: 18}}, args: {}};
const filter = {order: 'totalProblems ASC'};
const result = await app.models.SalesMonitor.salesFilter(ctx, filter);
const firstTicket = result.shift();
const secondTicket = result.shift();
expect(firstTicket.totalProblems).toEqual(null);
expect(secondTicket.totalProblems).toEqual(null);
});
});

View File

@ -6,3 +6,4 @@ Delete selected elements: Eliminar los elementos seleccionados
All the selected elements will be deleted. Are you sure you want to continue?: Todos los elementos seleccionados serán eliminados. ¿Seguro que quieres continuar?
Component lack: Faltan componentes
Minimize/Maximize: Minimizar/Maximizar
Problems: Problemas

View File

@ -33,7 +33,7 @@
<vn-table model="model">
<vn-thead>
<vn-tr>
<vn-th class="icon-field"></vn-th>
<vn-th field="totalProblems" menu-enabled="false">Problems</vn-th>
<vn-th field="nickname">Client</vn-th>
<vn-th field="salesPersonFk" class="expendable" shrink>Salesperson</vn-th>
<vn-th field="shipped" shrink-date>Date</vn-th>
@ -77,6 +77,7 @@
</vn-icon>
<vn-icon
ng-show="::ticket.risk"
ng-class="::{'highRisk': ticket.hasHighRisk}"
title="{{::$ctrl.$t('Risk')}}: {{ticket.risk}}"
class="bright"
icon="icon-risk">
@ -135,7 +136,7 @@
</span>
</vn-td>
<vn-td shrink>
<span class="chip {{$ctrl.totalPriceColor(ticket)}}">
<span class="chip {{::$ctrl.totalPriceColor(ticket)}}">
{{::(ticket.totalWithVat ? ticket.totalWithVat : 0) | currency: 'EUR': 2}}
</span>
</vn-td>

View File

@ -32,4 +32,8 @@ vn-monitor-sales-tickets {
vn-tbody a[ng-repeat].vn-tr:focus {
background-color: $color-primary-light
}
.highRisk i {
color: $color-alert
}
}