salix/db/dump/fixtures.local--.sql

1111 lines
30 KiB
SQL

-- Semillero
SET @item = 100000;
SET @isTriggerDisabled := TRUE;
SET @buyNumMaxPerENtry := 25;
SET @buyingValueMax := 1;
SET @packagingValueMax := 0.2;
SET @comissionValueMax := 0.1;
SET @freightValueMax := 0.15;
SET @groupingMax := 20;
SET @packingMax := 150;
SET @stemsStep := 1;
SET @stickersMax := 40;
SET @weightMax := 20;
SET @margin := 25;
SET @marginGap := 5;
SET @landed := CURDATE();
SET @warehouseFk := 1;
SET @entryNumberPerDayMax := 4;
SET @entryScopeDaysMax := 10;
SET @allEntryReceived := TRUE;
SET @ticketNumberMaxByDay = 100;
SET @saleNumberMaxByTicket = 25;
SET @company := 442;
SET @deliveryRatio := 0.10;
SET @itemPackingTypeCount := 4;
SET @itemPackingTypeNullRate := 0.5;
-- Vaciado de tablas
USE vn;
DELETE FROM bs.waste;
DELETE FROM hedera.orderRow;
DELETE FROM itemShelving;
DELETE FROM buy;
DELETE FROM sale;
DELETE FROM expedition;
DELETE FROM packagingConfig;
DELETE FROM ticketPackaging;
DELETE FROM packaging;
DELETE FROM expeditionBoxVol;
DELETE FROM item;
DELETE FROM origin;
DELETE FROM entryDms;
DELETE FROM entry;
DELETE FROM travelThermograph;
DELETE FROM travel;
DELETE FROM cache.stock;
DELETE FROM claim;
DELETE FROM ticketRefund;
DELETE FROM ticket;
DELETE FROM itemPackingType;
INSERT INTO vn.origin
(code, name, warehouseFk)
VALUES
('RU', 'Rusia', @warehouseFk),
('ES', 'España', @warehouseFk),
('CH', 'China', @warehouseFk);
REPLACE vn.packaging
(id, volume, width, `depth`, height,base,isPackageReturnable,upload)
VALUES
('577',48000,40,30,40,4, TRUE,TRUE),
('566',30000,30,25,40,3, TRUE,TRUE),
('94',150000,100,50,30,1.1, FALSE, FALSE);
-- Generación de items
CREATE OR REPLACE TEMPORARY TABLE tGenero
(name VARCHAR(50) PRIMARY KEY)
ENGINE = MEMORY;
INSERT INTO tGenero
VALUES
("Amuleto"),
("Casco"),
("Cetro"),
("Colgante"),
("Escudo"),
("Mandoble"),
("Fáser"),
("Látigo"),
("Guantelete"),
("Martillo"),
("Maletín"),
("Peto"),
("Puño"),
("Yelmo");
CREATE OR REPLACE TEMPORARY TABLE tVariedad
(name VARCHAR(50) PRIMARY KEY)
ENGINE = MEMORY;
INSERT INTO tVariedad
VALUES
("cósmico"),
("de Ablación"),
("de Adamantium"),
("extremis"),
("inhibidor"),
("maldito"),
("místico"),
("Muramasa"),
("Nega"),
("borgiano"),
("terrígeno");
CREATE OR REPLACE TEMPORARY TABLE tSize
(value INT PRIMARY KEY)
ENGINE = MEMORY;
INSERT INTO tSize
VALUES(45),(50),(65),(70),(80),(90);
-- IPT
DROP PROCEDURE IF EXISTS vn.itemPackingType_add;
DELIMITER $$
$$
CREATE PROCEDURE vn.itemPackingType_add(vItemPackingTypeCount INT)
BEGIN
/** Create records for itemPackingType table
*/
DECLARE vCounter INT DEFAULT 0;
WHILE vCounter < vItemPackingTypeCount DO
INSERT INTO vn.itemPackingType
SET code = CHR(65 + vCounter),
isActive = TRUE,
description = CONCAT('Tipo ',code);
SET vCounter = vCounter + 1;
END WHILE;
END;$$
DELIMITER ;
CALL vn.itemPackingType_add(@itemPackingTypeCount);
UPDATE itemConfig
JOIN (SELECT code FROM itemPackingType ORDER BY RAND() LIMIT 1) ipt
SET defaultPackingTypeFk = ipt.code;
REPLACE vn.item(
id,
name,
longName,
`size`,
originFk,
intrastatFk,
typeFk,
inkFk,
itemPackingTypeFk
)
SELECT
@item := @item + 1,
CONCAT(tg.name,' ',tv.name),
CONCAT(tg.name,' ',tv.name),
ts.value,
(SELECT id FROM origin ORDER BY RAND() LIMIT 1),
(SELECT id FROM intrastat i ORDER BY RAND() LIMIT 1),
(SELECT it.id FROM itemType it
JOIN itemCategory ic ON ic.id = it.categoryFk
WHERE ic.code = 'flower' ORDER BY RAND() LIMIT 1),
(SELECT id FROM ink ORDER BY RAND() LIMIT 1),
(SELECT IF(RAND() > @itemPackingTypeNullRate,code, NULL) FROM itemPackingType ORDER BY RAND() LIMIT 1)
FROM tGenero tg
JOIN tVariedad tv
JOIN tSize ts;
CREATE OR REPLACE TEMPORARY TABLE tItem
SELECT i.id, tg.name
FROM item i
JOIN tGenero tg ON i.name LIKE CONCAT(tg.name,'%');
REPLACE vn.itemTag
(
itemFk,
tagFk,
value,
priority
)
SELECT
ti.id,
t.id,
ti.name,
1
FROM tItem ti
JOIN tag t ON t.name = 'Genero'
;
CREATE OR REPLACE TEMPORARY TABLE tItem
SELECT i.id, tv.name
FROM item i
JOIN tVariedad tv ON i.name LIKE CONCAT('%',tv.name);
REPLACE vn.itemTag
(
itemFk,
tagFk,
value,
priority
)
SELECT
ti.id,
t.id,
ti.name,
2
FROM tItem ti
JOIN tag t ON t.name = 'Variedad'
;
CREATE OR REPLACE TEMPORARY TABLE tItem
SELECT i.id, i.`size`
FROM item i;
REPLACE vn.itemTag
(
itemFk,
tagFk,
value,
priority
)
SELECT
ti.id,
t.id,
ti.`size`,
3
FROM tItem ti
JOIN tag t ON t.name = 'Longitud'
;
CREATE OR REPLACE TEMPORARY TABLE tItem
SELECT i.id, inkFk value
FROM item i;
REPLACE vn.itemTag
(
itemFk,
tagFk,
value,
priority
)
SELECT
ti.id,
t.id,
ti.value,
5
FROM tItem ti
JOIN tag t ON t.name = 'Color'
;
CREATE OR REPLACE TEMPORARY TABLE tmp.item
SELECT id FROM item;
-- CALL item_refreshTags();
SET @isTriggerDisabled := FALSE;
DROP TEMPORARY TABLE IF EXISTS tmp.item, tGenero, tVariedad, tSize;
-- Entradas
DROP PROCEDURE IF EXISTS vn.buy_creation;
DELIMITER $$
$$
CREATE PROCEDURE vn.buy_creation()
BEGIN
/** Create records and all related ecosystem for random purchases.
*/
DECLARE vEntryNumber INT;
DECLARE vEntryScopeDays INT;
DECLARE vLanded DATE;
DECLARE vIsReceived BOOL;
DECLARE vDone INT DEFAULT FALSE;
DECLARE trv CURSOR FOR SELECT * FROM tTravel;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
CREATE OR REPLACE TEMPORARY TABLE tTravel
(landed DATE,
received BOOL)
ENGINE = MEMORY;
-- Today arrivals, not received yet
SET vEntryNumber = CEIL(RAND() * @entryNumberPerDayMax);
WHILE vEntryNumber > 0 DO
SET vEntryNumber = vEntryNumber - 1;
INSERT INTO tTravel(landed,received)
VALUES(@landed,@allEntryReceived);
END WHILE;
-- Today arrivals, received
SET vEntryNumber = CEIL(RAND() * @entryNumberPerDayMax);
WHILE vEntryNumber > 0 DO
SET vEntryNumber = vEntryNumber - 1;
INSERT INTO tTravel(landed,received)
VALUES(@landed,TRUE);
END WHILE;
-- Past arrivals
SET vEntryNumber = CEIL(RAND() * @entryNumberPerDayMax);
SET vEntryScopeDays = CEIL(RAND() * @entryScopeDaysMax);
WHILE vEntryNumber > 0 DO
SET vEntryNumber = vEntryNumber - 1;
SET @dated = @landed - INTERVAL (CEIL(RAND() * vEntryScopeDays)) DAY;
INSERT INTO tTravel(landed,received)
VALUES(@dated,TRUE);
END WHILE;
-- Future arrivals
SET vEntryNumber = FLOOR(RAND() * @entryNumberPerDayMax);
SET vEntryScopeDays = CEIL(RAND() * @entryScopeDaysMax);
WHILE vEntryNumber > 0 DO
SET vEntryNumber = vEntryNumber - 1;
SET @dated = @landed + INTERVAL (CEIL(RAND() * vEntryScopeDays)) DAY;
INSERT INTO tTravel(landed,received)
VALUES(@dated,FALSE);
END WHILE;
OPEN trv;
read_loop:LOOP
SET vDone = FALSE;
FETCH trv INTO vLanded, vIsReceived;
IF vDone THEN
LEAVE read_loop;
END IF;
INSERT INTO
travel(
shipped,
landed,
warehouseOutFk,
warehouseInFk,
isReceived
)
SELECT
vLanded - INTERVAL 1 DAY,
vlanded,
(SELECT id FROM warehouse WHERE NOT code <=> 'ALG' ORDER BY RAND() LIMIT 1),
id,
vIsReceived
FROM warehouse
WHERE code = 'ALG';
SELECT LAST_INSERT_ID() INTO @travel;
INSERT INTO
entry(
travelFk,
supplierFk,
dated
)
SELECT
@travel,
id,
CURDATE()
FROM supplier
ORDER BY RAND()
LIMIT 1;
CREATE OR REPLACE TEMPORARY TABLE tItem
SELECT ROW_NUMBER() OVER(ORDER BY random DESC) random2,
sub.*
FROM (
SELECT
RAND() random,
id itemFk
FROM item
LIMIT 1000000000000
) sub;
SELECT LAST_INSERT_ID() INTO @entry;
INSERT INTO buy(
entryFk,
itemFk,
buyingValue,
freightValue,
stickers,
`grouping`,
packing,
packagingFk,
comissionValue,
packageValue,
price2,
price1,
price3,
weight,
quantity
)
SELECT
@entry,
itemFk,
@bv := ROUND(RAND()*@buyingValueMax,3),
@fv := ROUND(RAND()*@freightValueMax,3),
@stickers := CEIL(RAND() * @stickersMax),
@grouping := CEIL(RAND() * @groupingMax / @stemsStep) * @stemsStep,
@packing := CEIL(RAND() * @packingMax / @grouping) * @grouping,
(SELECT id FROM packaging ORDER BY RAND() LIMIT 1),
@cv := ROUND(RAND()*@comissionValueMax,3),
@pv := ROUND(RAND()*@packagingValueMax,3),
@p2 := (@bv + @fv + @cv + @pv) * (100 + @margin) / 100,
@p2 * (100 + @margingGap) / 100,
@p2 * (100 - @margingGap) / 100,
CEIL(RAND() * @weightMax),
@stickers * @packing
FROM tItem
WHERE random2 < CEIL(RAND() * @buyNumMaxPerENtry);
END LOOP;
DROP TEMPORARY TABLE tItem;
END;$$
DELIMITER ;
CALL vn.buy_creation();
-- Ubicacion
DELETE FROM shelving;
DROP PROCEDURE IF EXISTS vn.shelving_creation;
DELIMITER $$
$$
CREATE PROCEDURE vn.shelving_creation(vWarehouseFk INT)
BEGIN
/** Create random shelves.
*/
DECLARE vShelvingNumMin INT DEFAULT 30;
DECLARE vShelvingNumMax INT DEFAULT 100;
DECLARE vShelvingNum INT;
SET vShelvingNum = vShelvingNumMin + FLOOR(RAND() * (vShelvingNumMax - vShelvingNumMin));
WHILE vShelvingNum > 0 DO
SET vShelvingNum = vShelvingNum - 1;
REPLACE shelving(code,priority)
VALUES(CONCAT(
CHAR(65 + FLOOR(RAND() * 26)),
CHAR(65 + FLOOR(RAND() * 26)),
CHAR(65 + FLOOR(RAND() * 26))),
CEIL(RAND() * 99));
END WHILE;
UPDATE shelving sh
SET parkingFk =
(
SELECT p.id
FROM parking p
JOIN sector s ON s.id = p.sectorFk
WHERE s.warehouseFk = vWarehouseFk
ORDER BY RAND() LIMIT 1);
END$$
DELIMITER ;
CALL vn.shelving_creation(@warehouseFk);
/******************************************************************************
Ubicación y parkineado
*****************************************************************************/
DROP PROCEDURE IF EXISTS vn.shelving_location;
DELIMITER $$
$$
CREATE PROCEDURE vn.shelving_location()
BEGIN
/** Locate items in random shelves.
*/
DECLARE vShelvingFk INT;
DECLARE vDone INT DEFAULT FALSE;
DECLARE vItemFk INT;
DECLARE vQuantity INT;
DECLARE vGrouping INT;
DECLARE vPacking INT;
DECLARE vPackagingFk INT;
DECLARE vLanded DATE;
DECLARE vRemainingQuantity INT;
DECLARE cur1 CURSOR FOR
SELECT
b.itemFk,
b.quantity,
b.`grouping`,
b.packing,
b.packagingFk,
tr.landed
FROM buy b
JOIN entry e ON e.id = b.entryFk
JOIN travel tr ON tr.id = e.travelFk
WHERE tr.isReceived;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
OPEN cur1;
read_loop: LOOP
SET vDone = FALSE;
FETCH cur1 INTO
vItemFk,
vQuantity,
vGrouping,
vPacking,
vPackagingFk,
vLanded;
IF vDone THEN
LEAVE read_loop;
END IF;
SET vRemainingQuantity = vQuantity;
WHILE vRemainingQuantity > 0 DO
SET vQuantity = vGrouping * CEIL((vRemainingQuantity / vGrouping / CEIL(RAND() * 3)));
SELECT id INTO vShelvingFk
FROM shelving s
ORDER BY RAND() LIMIT 1;
INSERT INTO itemShelving(
itemFk,
shelvingFk,
visible,
`grouping`,
packing,
packagingFk,
created
)
VALUES(
vItemFk,
vShelvingFk,
vQuantity,
vGrouping,
vPacking,
vPackagingFk,
vLanded);
SET vRemainingQuantity = vRemainingQuantity - vQuantity;
END WHILE;
END LOOP;
CLOSE cur1;
END$$
DELIMITER ;
CALL shelving_location();
DROP FUNCTION IF EXISTS util.mockTime;
DELIMITER $$
$$
CREATE DEFINER=`root`@`localhost` FUNCTION `util`.`mockTime`() RETURNS datetime
DETERMINISTIC
BEGIN
RETURN CURDATE();
END$$
DELIMITER ;
CALL cache.stock_refresh(TRUE);
/******************************************************************************
Clientes, consignatarios y tickets
*****************************************************************************/
UPDATE vn.client c SET c.isTaxDataChecked = TRUE;
UPDATE vn.client
SET isRelevant = TRUE
WHERE id BETWEEN 1101 AND 1110;
DELIMITER $$
$$
CREATE OR REPLACE PROCEDURE vn.ticket_creation()
BEGIN
/** Create tickets and sales for current items
*
*/
DECLARE vAddressFk INT;
DECLARE vClientMaxId INT;
DECLARE vClientMinId INT;
DECLARE vDated DATE;
DECLARE vEndDated DATE;
DECLARE vItemMaxRowNumber INT;
DECLARE vNewTicket INT;
DECLARE vRowNumber INT;
DECLARE vSaleFk INT;
DECLARE vSaleNumber INT;
DECLARE vStartDated DATE;
DECLARE vTicketNumber INT;
DECLARE vZone INT;
SELECT
MIN(landed),
MAX(landed)
INTO
vStartDated,
vEndDated
FROM
travel;
SELECT
MIN(id),
MAX(id)
INTO
vClientMinId,
vClientMaxId
FROM client
WHERE isRelevant;
SET vDated = vStartDated;
WHILE DATEDIFF(vEndDated,vDated) >= 0 DO
SET vTicketNumber = FLOOR(RAND() * (@ticketNumberMaxByDay + 1));
CALL cache.available_refresh(@calc, TRUE, @warehouseFk, vDated);
CREATE OR REPLACE TEMPORARY TABLE tAvailable
SELECT
ROW_NUMBER() OVER() rn,
a.item_id itemFk,
a.available,
b.`grouping`,
b.price2 price,
b.buyingValue
FROM cache.available a
JOIN buy b ON b.itemFk = a.item_id
WHERE a.calc_id = @calc
AND a.available > 0
GROUP BY a.item_id;
SELECT MAX(rn) INTO vItemMaxRowNumber
FROM tAvailable;
WHILE vTicketNumber > 0 DO
SELECT a.id INTO vAddressFk
FROM address a
WHERE a.clientFk BETWEEN vClientMinId AND vClientMaxId
AND a.isDefaultAddress
ORDER BY RAND()
LIMIT 1;
INSERT INTO ticket (
clientFk,
shipped,
addressFk,
agencyModeFk,
nickname,
warehouseFk,
companyFk,
landed,
zoneFk
)
SELECT
a.clientFk,
vDated,
a.id,
a.agencyModeFk,
a.nickname,
@warehouseFk,
@company,
vDated + INTERVAL 1 DAY,
9
FROM address a
WHERE a.id = vAddressFk;
SET vNewTicket = LAST_INSERT_ID();
SET vSaleNumber = CEIL(RAND() * @saleNumberMaxByTicket);
WHILE vSaleNumber > 0 DO
SELECT rn INTO vRowNumber
FROM tAvailable
WHERE available > 0
ORDER BY RAND()
LIMIT 1;
INSERT INTO sale(
ticketFk,
itemFk,
concept,
quantity)
SELECT
vNewTicket,
ta.itemFk,
i.name,
@quantity := CEIL(LOG(RAND() * ta.available )) * ta.`grouping`
FROM tAvailable ta
JOIN item i ON i.id = ta.itemFk
WHERE ta.rn = vRowNumber;
SELECT LAST_INSERT_ID() INTO vSaleFk;
INSERT INTO saleComponent(
saleFk,
componentFk,
value)
SELECT
vSaleFk,
c.id,
ta.buyingValue
FROM tAvailable ta
JOIN component c ON c.code = 'purchaseValue'
WHERE ta.rn = vRowNumber;
INSERT INTO saleComponent(
saleFk,
componentFk,
value)
SELECT
vSaleFk,
c.id,
ta.price - ta.buyingValue
FROM tAvailable ta
JOIN component c ON c.code = 'margin'
WHERE ta.rn = vRowNumber;
INSERT INTO saleComponent(
saleFk,
componentFk,
value)
SELECT
vSaleFk,
c.id,
ta.price * @deliveryRatio
FROM tAvailable ta
JOIN component c ON c.code = 'delivery'
WHERE ta.rn = vRowNumber;
UPDATE tAvailable
SET available = available - @quantity
WHERE rn = vRowNumber;
SET vSaleNumber = vSaleNumber - 1;
END WHILE;
SET vTicketNumber = vTicketNumber - 1;
END WHILE;
SET vDated = vDated + INTERVAL 1 DAY;
END WHILE;
UPDATE sale s
JOIN (
SELECT saleFk, SUM(value) price
FROM saleComponent
GROUP BY saleFk
) sub ON sub.saleFk = s.id
SET s.price = sub.price;
END$$
DELIMITER ;
CALL ticket_creation();
CALL cache.visible_refresh(@calc, TRUE, 1);
CALL cache.available_refresh(@calc, TRUE, @warehouseFk, @landed);
CALL cache.last_buy_refresh(@warehouseFk);
/******************************************************************************
Rutas, camiones y gateControl
*****************************************************************************/
/*UPDATE IGNORE ticket t
SET t.routeFk = t.id MOD 10;*/
REPLACE vn.supplier (id, name, account, street, city, provinceFk, countryFk, nif, isOfficial, retAccount, phone, commission, nickname, payMethodFk, payDay, payDemFk, created, isReal, note, postcodeFk, postCode, isActive, taxTypeSageFk, withholdingSageFk, transactionTypeSageFk, isTrucker, workerFk, supplierActivityFk, healthRegister, isPayMethodChecked, isVies, stamp, companySize, geoFk, editorFk)
VALUES(1382, 'TRIDENT INTERCONTINENTAL SHIPPING', '4100021382', 'Gotham Docklands, s/n', 'GOTHAM', 2, 1, '11223344T', 1, NULL, NULL, 0.0, 'TRIDENT', 1, 10, 2, '2001-01-01 00:00:00.000', 0, NULL, NULL, '46000', 1, 93, 2, 8, 1, 18, 'flowerPlants', '400664487V', 1, 0, NULL, NULL, NULL, 100),
(1383, 'BARBARA KEAN MONSTER TRUCK', '4100021383', 'East Apple Street, 6', 'GOTHAM', 2, 1, '10203040B', 1, NULL, NULL, 0.0, 'MONSTER TRUCK', 1, 10, 2, '2001-01-01 00:00:00.000', 0, NULL, NULL, '46000', 1, 93, 2, 8, 1, 18, 'flowerPlants', '400664487V', 1, 0, NULL, NULL, NULL, 100),
(1384, 'GOTHAM TRANSIT AUTHORITY', '4100021384', 'Grundy Street, 1552', 'GOTHAM', 2, 1, '12233445G', 1, NULL, NULL, 0.0, 'GTA', 1, 10, 2, '2001-01-01 00:00:00.000', 0, NULL, NULL, '46000', 1, 93, 2, 8, 1, 18, 'flowerPlants', '400664487V', 1, 0, NULL, NULL, NULL, 100);
INSERT INTO vn.roadmap (name, tractorPlate, trailerPlate, phone, supplierFk, etd, observations, created, userFk, price, driverName, kmStart, kmEnd, started, finished, m3, driver2Fk, driver1Fk)
VALUES
('NORTHWEST', '1111-AAA', NULL, NULL, 442, CURDATE() + INTERVAL 9 HOUR, NULL, '2024-11-26 07:53:06.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 40, NULL, NULL),
('NORTH', '2222-BBB', NULL, NULL, 442, CURDATE() + INTERVAL 9 HOUR, NULL, '2024-11-26 07:53:31.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 40, NULL, NULL),
('CENTER 1', '3333-CCC', NULL, NULL, 442, CURDATE() + INTERVAL 10 HOUR, NULL, '2024-11-26 07:54:04.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 40, NULL, NULL),
('SOUTH', '4444-DDD', NULL, NULL, 442, CURDATE() + INTERVAL 11 HOUR, NULL, '2024-11-26 07:54:28.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 40, NULL, NULL),
('MRW', NULL, NULL, NULL, NULL, CURDATE() + INTERVAL 12 HOUR, NULL, '2024-11-26 07:55:28.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL),
('NORTHEAST', '5555-EEE', NULL, NULL, 442, CURDATE() + INTERVAL 17 HOUR, NULL, '2024-11-26 07:56:01.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 40, NULL, NULL),
('CENTER DUO', '6666-FFF', NULL, NULL, 442, CURDATE() + INTERVAL 18 HOUR, NULL, '2024-11-26 07:56:22.0', NULL, NULL, NULL, NULL, NULL, NULL, NULL, 70, NULL, NULL);
UPDATE roadmapStop
SET eta = CURDATE() + INTERVAL FLOOR(RAND() * 24) HOUR;
REPLACE routesMonitor( routeFk,
name,
beachFk,
dated,
etd,
roadmapStopFk,
bufferFk,
isPickingAllowed)
SELECT r.id,
z.name,
(SELECT code FROM beach ORDER BY RAND() LIMIT 1),
CURDATE() + INTERVAL 1 DAY,
TIME(CURDATE()) + INTERVAL FLOOR(24 * RAND()) HOUR,
(SELECT id FROM roadmapStop ORDER BY RAND() LIMIT 1),
(SELECT id FROM srt.buffer WHERE isActive ORDER BY RAND() LIMIT 1),
(RAND() > 0.5)
FROM route r
JOIN `zone` z ON z.id = r.zoneFk;
-- Recuentos
WITH tBuy AS
(SELECT
MIN(tr.landed) dateFrom,
MAX(tr.landed) dateTo,
COUNT(DISTINCT tr.id) travelCount,
COUNT(DISTINCT e.id) entryCount,
COUNT(DISTINCT b.id) buyCount,
COUNT(DISTINCT b.itemFk) itemCount
FROM travel tr
JOIN entry e ON e.travelFk = tr.id
JOIN buy b ON b.entryFk = e.id
),
tSale AS
(SELECT
MIN(t.shipped) dateFrom,
MAX(t.shipped) dateTo,
COUNT(DISTINCT t.id) ticketCount,
COUNT(DISTINCT s.id) saleCount,
COUNT(DISTINCT sc.componentFk) saleComponentCount,
COUNT(DISTINCT s.itemFk) itemCount
FROM ticket t
JOIN sale s ON s.ticketFk = t.id
JOIN saleComponent sc ON sc.saleFk = s.id
),
tShelving AS
(SELECT
MIN(ish.created) dateFrom,
MAX(ish.created) dateTo,
COUNT(DISTINCT p.id) parkingCount,
COUNT(DISTINCT sh.id) shelvingCount,
COUNT(DISTINCT ish.id) itemShelvingCount,
COUNT(DISTINCT ish.itemFk) itemCount
FROM parking p
JOIN shelving sh ON sh.parkingFk = p.id
JOIN itemShelving ish ON ish.shelvingFk = sh.id
),
tRoutes AS
(SELECT
MIN(r.created) dateFrom,
MAX(r.created) dateTo,
COUNT(DISTINCT r.id) routesCount,
COUNT(DISTINCT rms.id) rmsCount,
SUM(rm.isPickingAllowed = TRUE) allowedCount
FROM route r
JOIN routesMonitor rm ON rm.routeFk = r.id
JOIN roadmapStop rms ON rms.id = rm.roadMapStopFk
)
SELECT '==========' Variable,'== COMPRAS ==' Total,'==========' Media
UNION ALL
SELECT 'Starting date ' ,dateFrom , NULL FROM tSale
UNION ALL
SELECT 'Last date ',dateTo, NULL FROM tBuy
UNION ALL
SELECT 'Travels ',travelCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM vn.travel tr
GROUP BY tr.landed
) sub
) FROM tBuy
UNION ALL
SELECT 'Entries ' ,entryCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM vn.entry e
GROUP BY e.travelFk
) sub
) FROM tBuy
UNION ALL
SELECT 'Buys ' ,buyCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM vn.buy b
GROUP BY b.entryFk
) sub
) FROM tBuy
UNION ALL
SELECT 'Items ' ,itemCount, (
SELECT floor(avg(num))
FROM
(SELECT count(DISTINCT itemFk) num
FROM vn.buy b
GROUP BY b.entryFk
) sub
) FROM tBuy
UNION ALL
SELECT '==========','== VENTAS ==','=========='
UNION ALL
SELECT 'Starting date ',dateFrom, NULL Media FROM tSale
UNION ALL
SELECT 'Last date ',dateTo, NULL FROM tSale
UNION ALL
SELECT 'Tickets ',ticketCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM ticket t
GROUP BY t.shipped
) sub
) FROM tSale
UNION ALL
SELECT 'Sales ' ,saleCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM sale s
GROUP BY s.ticketFk
) sub
) FROM tSale
UNION ALL
SELECT 'SaleComponents ' ,saleComponentCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM saleComponent sc
GROUP BY sc.saleFk
) sub
) FROM tSale
UNION ALL
SELECT 'Items ' ,itemCount, (
SELECT floor(avg(num))
FROM
(SELECT count(DISTINCT itemFk) num
FROM sale s
GROUP BY s.ticketFk
) sub
) FROM tSale
UNION ALL
SELECT '==========','== PARKING ==','=========='
UNION ALL
SELECT 'Starting date ',dateFrom, NULL Media FROM tShelving
UNION ALL
SELECT 'Last date ',dateTo, NULL FROM tShelving
UNION ALL
SELECT 'Parkings ',parkingCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM parking p
GROUP BY p.sectorFk
) sub
) FROM tShelving
UNION ALL
SELECT 'Shelvings ' ,shelvingCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM shelving sh
GROUP BY sh.parkingFk
) sub
) FROM tShelving
UNION ALL
SELECT 'ItemShelvings ' ,itemShelvingCount, (
SELECT floor(avg(num))
FROM
(SELECT count(*) num
FROM itemShelving ish
GROUP BY ish.shelvingFk
) sub
) FROM tShelving
UNION ALL
SELECT 'Items ' ,itemCount, (
SELECT floor(avg(num))
FROM
(SELECT count(DISTINCT itemFk) num
FROM itemShelving ish
GROUP BY ish.shelvingFk
) sub
) FROM tShelving
UNION ALL
SELECT '==========','== RUTAS ==','=========='
UNION ALL
SELECT 'Starting date ',dateFrom, NULL Media
FROM tRoutes
UNION ALL
SELECT 'Last date ',dateTo, NULL
FROM tRoutes
UNION ALL
SELECT 'routesCount ',routesCount, NULL
FROM tRoutes
UNION ALL
SELECT 'roadmapStopCount ',rmsCount, NULL
FROM tRoutes
UNION ALL
SELECT 'allowedCount ',allowedCount, NULL
FROM tRoutes;