refs #4823 Added procedure offerRefresh
This commit is contained in:
parent
2ccde9d624
commit
0a72bcdfa5
|
@ -171,8 +171,11 @@ try {
|
|||
const spinner = ora(`${actionMsg} models...`).start();
|
||||
await sequelize.sync(action);
|
||||
|
||||
// Views
|
||||
sequelize.query(fs.readFileSync('views//supplyOffer.sql', 'utf-8'));
|
||||
// Create views
|
||||
sequelize.query(fs.readFileSync('routines/views/supplyOffer.sql', 'utf-8'));
|
||||
|
||||
// Create procedures
|
||||
sequelize.query(fs.readFileSync('routines/procedures/offerRefresh.sql', 'utf-8'));
|
||||
|
||||
spinner.succeed();
|
||||
}
|
||||
|
@ -189,6 +192,7 @@ catch (err) {
|
|||
function createConn() {
|
||||
return new Sequelize(env.DB_SCHEMA, env.DB_USER, env.DB_PWD, {
|
||||
host: env.DB_HOST,
|
||||
port: env.DB_PORT,
|
||||
dialect: env.DB_DIALECT,
|
||||
logging: false,
|
||||
pool: {
|
||||
|
|
|
@ -0,0 +1,327 @@
|
|||
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `floriday`.`offerRefresh`()
|
||||
BEGIN
|
||||
DECLARE vLanded DATETIME;
|
||||
DECLARE vLastInserted DATETIME;
|
||||
DECLARE vDayRange INT;
|
||||
|
||||
SELECT dayRange INTO vDayRange
|
||||
FROM edi.offerRefreshConfig;
|
||||
|
||||
IF vDayRange IS NULL THEN
|
||||
CALL util.throw("Variable vDayRange not declared");
|
||||
END IF;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE offer
|
||||
SELECT * FROM supplyOffer;
|
||||
|
||||
DELETE o
|
||||
FROM offer o
|
||||
LEFT JOIN vn.tag t1 ON t1.ediTypeFk = o.tag1
|
||||
AND t1.overwrite = 'size'
|
||||
LEFT JOIN vn.tag t2 ON t2.ediTypeFk = o.tag2
|
||||
AND t2.overwrite = 'size'
|
||||
LEFT JOIN vn.tag t3 ON t3.ediTypeFk = o.tag3
|
||||
AND t3.overwrite = 'size'
|
||||
LEFT JOIN vn.tag t4 ON t4.ediTypeFk = o.tag4
|
||||
AND t4.overwrite = 'size'
|
||||
LEFT JOIN vn.tag t5 ON t5.ediTypeFk = o.tag5
|
||||
AND t5.overwrite = 'size'
|
||||
LEFT JOIN vn.tag t6 ON t6.ediTypeFk = o.tag6
|
||||
AND t6.overwrite = 'size'
|
||||
JOIN vn.floramondoConfig fc ON TRUE
|
||||
WHERE (t1.id IS NOT NULL AND CONVERT(o.value1, UNSIGNED) > fc.itemMaxSize)
|
||||
OR (t2.id IS NOT NULL AND CONVERT(o.value2, UNSIGNED) > fc.itemMaxSize)
|
||||
OR (t3.id IS NOT NULL AND CONVERT(o.value3, UNSIGNED) > fc.itemMaxSize)
|
||||
OR (t4.id IS NOT NULL AND CONVERT(o.value4, UNSIGNED) > fc.itemMaxSize)
|
||||
OR (t5.id IS NOT NULL AND CONVERT(o.value5, UNSIGNED) > fc.itemMaxSize)
|
||||
OR (t6.id IS NOT NULL AND CONVERT(o.value6, UNSIGNED) > fc.itemMaxSize);
|
||||
|
||||
UPDATE IGNORE offer o
|
||||
JOIN vn.item i
|
||||
ON i.name = o.vbnProductName
|
||||
AND i.subname <=> o.organizationName
|
||||
AND i.value5 <=> o.value1
|
||||
AND i.value6 <=> o.value2
|
||||
AND i.value7 <=> o.value3
|
||||
AND i.value8 <=> o.value4
|
||||
AND i.value9 <=> o.value5
|
||||
AND i.value10 <=> o.value6
|
||||
AND i.NumberOfItemsPerCask <=> o.piecesPerPackage
|
||||
AND i.EmbalageCode <=> o.packageVbnPackageCode
|
||||
# AND i.quality <=> o.Quality - Hasta el momento no tenemos quality
|
||||
JOIN vn.itemType it ON it.id = i.typeFk
|
||||
LEFT JOIN vn.sale s ON s.itemFk = i.id
|
||||
LEFT JOIN vn.ticket t ON t.id = s.ticketFk
|
||||
AND t.shipped > (util.VN_CURDATE() - INTERVAL 1 WEEK)
|
||||
LEFT JOIN supplyLine sl ON sl.supplyLineId = i.supplyLineFk
|
||||
#LEFT JOIN edi.putOrder po ON po.supplyResponseID = i.supplyResponseFk
|
||||
#AND po.OrderTradeLineDateTime > (util.VN_CURDATE() - INTERVAL 1 WEEK)
|
||||
SET i.supplyLineFk = o.supplyLineId
|
||||
WHERE (sl.supplyLineId IS NULL
|
||||
OR sl.numberOfPieces = 0
|
||||
OR sl.orderPeriodEndDateTime < util.VN_NOW())
|
||||
AND it.isInventory
|
||||
AND t.id IS NULL;
|
||||
#AND po.id IS NULL;
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE itemToInsert
|
||||
ENGINE = MEMORY
|
||||
SELECT o.*, CAST(NULL AS DECIMAL(6,0)) itemFk
|
||||
FROM offer o
|
||||
LEFT JOIN vn.item i ON i.supplyLineFk = o.supplyLineId
|
||||
WHERE i.id IS NULL;
|
||||
|
||||
INSERT INTO vn.item(id,
|
||||
`name`,
|
||||
longName,
|
||||
subName,
|
||||
expenceFk,
|
||||
typeFk,
|
||||
intrastatFk,
|
||||
originFk,
|
||||
supplyResponseFk,
|
||||
numberOfItemsPerCask,
|
||||
embalageCode,
|
||||
isFloriday) # NO le ponemos quality
|
||||
SELECT iti.itemFk,
|
||||
iti.vbnProductName,
|
||||
iti.vbnProductName,
|
||||
iti.organizationName,
|
||||
iti.expenseFk,
|
||||
iti.itemTypeFk,
|
||||
iti.intrastatFk,
|
||||
iti.originFk,
|
||||
iti.supplyLineId,
|
||||
iti.piecesPerPackage,
|
||||
iti.packageVbnPackageCode,
|
||||
TRUE
|
||||
FROM itemToInsert iti;
|
||||
|
||||
# Inserta la foto de los articulos nuevos (prioridad alta)
|
||||
INSERT IGNORE INTO vn.itemImageQueue(itemFk, url)
|
||||
SELECT i.id, ii.imageUrl
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.imageUrl IS NULL
|
||||
AND i.image IS NULL;
|
||||
|
||||
# Poner aquí insert en la supuesta tabla log
|
||||
|
||||
# Inserción de los tags nuevos
|
||||
INSERT IGNORE INTO vn.tag (name, ediTypeFk)
|
||||
SELECT description, type_id
|
||||
FROM edi.`type`;
|
||||
|
||||
# Desabilita el trigger para recalcular los tags al final
|
||||
SET @isTriggerDisabled = TRUE;
|
||||
|
||||
# Inserción de los tags sólo en los articulos nuevos
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id, ii.vbnProductName, 1
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.`name` = 'Producto'
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.vbnProductName IS NULL;
|
||||
|
||||
/* Por el momento, no disponemos de la quality
|
||||
*
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.Quality, 3
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.`name` = 'Calidad'
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.Quality IS NULL; */
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.organizationName, 4
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.name = 'Productor'
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.organizationName IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.value1, 5
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef1
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.value1 IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.value2, 6
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef2
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.value2 IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.value3, 7
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef3
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.value3 IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.value4, 8
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef4
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.value4 IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , s5Value, 9
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef5
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT s5Value IS NULL;
|
||||
|
||||
INSERT INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id , ii.value5, 10
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.tag t ON t.ediTypeFk = ii.ef6
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
WHERE NOT ii.value5 IS NULL;
|
||||
|
||||
INSERT IGNORE INTO vn.itemTag(itemFk, tagFk, value, priority)
|
||||
SELECT i.id, t.id, IFNULL(ink.name, ik.color), 11
|
||||
FROM itemToInsert ii
|
||||
JOIN vn.item i ON i.supplyLineFk = ii.supplyLineId
|
||||
JOIN vn.tag t ON t.`name` = 'Color'
|
||||
LEFT JOIN edi.feature f ON f.item_id = ii.vbnProductCode
|
||||
LEFT JOIN edi.`type` tp ON tp.type_id = f.feature_type_id
|
||||
AND tp.`description` = 'Hoofdkleur 1'
|
||||
LEFT JOIN vn.ink ON ink.dutchCode = f.feature_value
|
||||
LEFT JOIN vn.itemInk ik ON ik.longName = i.longName
|
||||
WHERE ink.name IS NOT NULL
|
||||
OR ik.color IS NOT NULL;
|
||||
|
||||
# Refresco de los tags
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.item
|
||||
(PRIMARY KEY (id))
|
||||
SELECT i.id FROM vn.item i
|
||||
JOIN itemToInsert ii ON i.supplyLineFk = ii.supplyLineId;
|
||||
|
||||
CALL vn.item_refreshTags();
|
||||
|
||||
DROP TEMPORARY TABLE tmp.item;
|
||||
|
||||
SELECT MIN(LatestDeliveryDateTime) INTO vLanded
|
||||
FROM supplyLine sl
|
||||
JOIN organization o ON o.organizationId = sl.organizationId
|
||||
JOIN edi.marketPlace mp ON mp.id = o.companyGln
|
||||
JOIN vn.floramondoConfig fc
|
||||
WHERE mp.isLatestOrderDateTimeRelevant
|
||||
AND di.LatestOrderDateTime > IF(
|
||||
fc.MaxLatestOrderHour > HOUR(util.VN_NOW()),
|
||||
util.VN_CURDATE(),
|
||||
util.VN_CURDATE() + INTERVAL 1 DAY
|
||||
);
|
||||
|
||||
# Valorar el crear floridayConfig
|
||||
UPDATE vn.floramondoConfig
|
||||
SET nextLanded = vLanded
|
||||
WHERE vLanded IS NOT NULL;
|
||||
|
||||
# Elimina la oferta obsoleta
|
||||
UPDATE vn.buy b
|
||||
JOIN vn.entry e ON e.id = b.entryFk
|
||||
JOIN vn.travel tr ON tr.id = e.travelFk
|
||||
JOIN vn.agencyMode am ON am.id = tr.agencyModeFk
|
||||
JOIN vn.item i ON i.id = b.itemFk
|
||||
LEFT JOIN supplyLine sl ON i.supplyLineFk = sl.supplyLineId
|
||||
SET b.quantity = 0
|
||||
WHERE (IFNULL(di.LatestOrderDateTime, util.VN_NOW()) <= util.VN_NOW()
|
||||
OR i.supplyLineFk IS NULL
|
||||
OR sl.numberOfPieces = 0)
|
||||
AND am.name = 'LOGIFLORA' # Crear agencia floriday
|
||||
AND e.isRaid;
|
||||
|
||||
# Localiza las entradas de cada almacen (Valorar si quitar)
|
||||
UPDATE edi.warehouseFloramondo # warehouseFloriday?
|
||||
SET entryFk = vn.entry_getForLogiflora(vLanded + INTERVAL travellingDays DAY, warehouseFk);
|
||||
|
||||
IF vLanded IS NOT NULL THEN
|
||||
# Actualiza la oferta existente
|
||||
UPDATE vn.buy b
|
||||
JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk # warehouseFloriday?
|
||||
JOIN vn.item i ON i.id = b.itemFk
|
||||
JOIN offer o ON i.supplyLineFk = o.supplyLineId
|
||||
SET b.quantity = o.numberOfPieces * o.piecesPerPackage,
|
||||
b.buyingValue = o.pricePerPiece
|
||||
WHERE (b.quantity <> o.numberOfPieces * o.piecesPerPackage
|
||||
OR b.buyingValue <> o.pricePerPiece);
|
||||
|
||||
# Inserta el resto
|
||||
SET vLastInserted := util.VN_NOW();
|
||||
|
||||
# Inserta la oferta
|
||||
INSERT INTO vn.buy( entryFk,
|
||||
itemFk,
|
||||
quantity,
|
||||
buyingValue,
|
||||
stickers,
|
||||
packing,
|
||||
`grouping`,
|
||||
groupingMode,
|
||||
packageFk,
|
||||
deliveryFk)
|
||||
SELECT wf.entryFk,
|
||||
i.id,
|
||||
o.numberOfPieces * o.piecesPerPackage,
|
||||
o.Price,
|
||||
o.numberOfPieces,
|
||||
o.pricePerPiece,
|
||||
o.piecesPerPackage, # MinimumQuantity NO está: GREATEST(1, IFNULL(o.MinimumQuantity, 0)) * o.piecesPerPackage,
|
||||
2, # Obliga al Packing
|
||||
o.packageVbnPackageCode,
|
||||
NULL # o.diId No tenemos delivery information
|
||||
FROM offer o
|
||||
JOIN vn.item i ON i.supplyResponseFk = o.srId
|
||||
JOIN edi.warehouseFloramondo wf # warehouseFloriday?
|
||||
JOIN vn.packaging p ON p.id
|
||||
LIKE o.packageVbnPackageCode
|
||||
LEFT JOIN vn.buy b ON b.itemFk = i.id
|
||||
AND b.entryFk = wf.entryFk
|
||||
WHERE b.id IS NULL; # Quitar esta linea y mirar de crear los packages a tiempo REAL
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tmp.buyRecalc
|
||||
SELECT b.id
|
||||
FROM vn.buy b
|
||||
JOIN edi.warehouseFloramondo wf ON wf.entryFk = b.entryFk # warehouseFloriday?
|
||||
WHERE b.created >= vLastInserted;
|
||||
|
||||
CALL vn.buy_recalcPrices();
|
||||
END IF;
|
||||
|
||||
DROP TEMPORARY TABLE offer, itemToInsert;
|
||||
SET @isTriggerDisabled = FALSE;
|
||||
|
||||
COMMIT;
|
||||
|
||||
# Esto habria que pasarlo a procesos programados o trabajar con tags y dejar las familias
|
||||
UPDATE vn.item i
|
||||
JOIN vn.itemType it ON it.id = i.typeFk
|
||||
SET typeFk = (SELECT id FROM vn.itemType WHERE code = 'GRS')
|
||||
WHERE i.longName LIKE 'Rosa Garden %'
|
||||
AND it.code = 'ROS';
|
||||
|
||||
UPDATE vn.item i
|
||||
JOIN vn.itemType it ON it.id = i.typeFk
|
||||
SET typeFk = (SELECT id FROM vn.itemType WHERE code = 'REC')
|
||||
WHERE i.longName LIKE 'Rosa ec %'
|
||||
AND it.code = 'ROS';
|
||||
|
||||
# Refresca las fotos de los items existentes que mostramos (prioridad baja)
|
||||
INSERT IGNORE INTO vn.itemImageQueue(itemFk, url, priority)
|
||||
SELECT i.id, tip.url, 100
|
||||
FROM tradeItem ti
|
||||
JOIN tradeItemPhoto tip ON tip.tradeItemId = ti.tradeItemId
|
||||
JOIN supplyLine sl ON sl.tradeItemId = ti.tradeItemId
|
||||
AND tip.`primary`
|
||||
JOIN vn.item i ON i.supplyLineFk = sl.supplyLineId
|
||||
JOIN hedera.image i2 ON i2.name = i.image
|
||||
AND i2.collectionFk = 'catalog'
|
||||
WHERE i2.updated <= (UNIX_TIMESTAMP(util.VN_NOW()) - vDayRange)
|
||||
AND sl.numberOfPieces;
|
||||
END
|
|
@ -0,0 +1,173 @@
|
|||
CREATE OR REPLACE VIEW supplyOffer AS
|
||||
SELECT sl.supplyLineId,
|
||||
ti.name tradeItemName,
|
||||
i.product_name vbnProductName,
|
||||
o.commercialName organizationName,
|
||||
sl.`type`,
|
||||
sl.salesUnit,
|
||||
CAST(slvp.pricePerPiece AS DECIMAL(10, 3)) pricePerPiece,
|
||||
sl.numberOfPieces,
|
||||
ti.vbnProductCode,
|
||||
slpc.packageVbnPackageCode,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 1
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag1,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 1
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value1,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 2
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag2,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 2
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value2,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 3
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag3,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 3
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value3,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 4
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag4,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 4
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value4,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 5
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag5,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 5
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value5,
|
||||
(
|
||||
SELECT tic.vbnCode
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 6
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) tag6,
|
||||
(
|
||||
SELECT v.type_description
|
||||
FROM tradeItemCharacteristic tic
|
||||
JOIN edi.item_feature it ON it.feature = tic.vbnCode
|
||||
JOIN edi.value v ON v.type_value = tic.vbnValueCode
|
||||
AND tic.vbnCode = v.type_id
|
||||
WHERE tic.tradeItemId = ti.tradeItemId
|
||||
AND it.presentation_order = 6
|
||||
AND it.`expiry_date` IS NULL
|
||||
LIMIT 1
|
||||
) value6,
|
||||
sl.deliveryPeriodStartDateTime,
|
||||
sl.deliveryPeriodEndDateTime,
|
||||
sl.orderPeriodStartDateTime,
|
||||
sl.orderPeriodEndDateTime,
|
||||
IF(slpc.supplyLineId IS NULL, FALSE, TRUE) hasPackingConfiguration,
|
||||
b.description bucketDescription,
|
||||
b.x_size,
|
||||
b.y_size,
|
||||
b.z_size,
|
||||
(b.x_size * b.y_size * b.z_size) / 1000000000 volume,
|
||||
slpc.piecesPerPackage,
|
||||
slpc.packagesPerLayer,
|
||||
slpc.layersPerLoadCarrier,
|
||||
slpc.transportHeightInCm,
|
||||
slpc.loadCarrierType,
|
||||
slpc.additionalPricePerPieceCurrency,
|
||||
slpc.additionalPricePerPieceValue,
|
||||
w.name warehouseName,
|
||||
tip.url imageUrl,
|
||||
igto.expenseFk,
|
||||
igto.intrastatFk,
|
||||
igto.originFk,
|
||||
IFNULL(idt.itemTypeFk, igto.itemTypeFk) itemTypeFk,
|
||||
sl.lastSync
|
||||
FROM supplyLine sl
|
||||
JOIN supplyLineVolumePrice slvp ON slvp.supplyLineId = sl.supplyLineId
|
||||
JOIN organization o ON o.organizationId = sl.organizationId
|
||||
JOIN tradeItem ti ON ti.tradeItemId = sl.tradeItemId
|
||||
LEFT JOIN tradeItemPhoto tip ON tip.tradeItemId = ti.tradeItemId
|
||||
AND tip.`primary`
|
||||
JOIN warehouse w ON w.warehouseId = sl.warehouseId
|
||||
JOIN supplyLinePackingConfiguration slpc ON slpc.supplyLineId = sl.supplyLineId
|
||||
LEFT JOIN edi.bucket b ON b.bucket_id = slpc.packageVbnPackageCode
|
||||
JOIN edi.item i ON i.id = ti.vbnProductCode
|
||||
LEFT JOIN edi.item_groupToOffer igto ON igto.group_code = i.group_id
|
||||
LEFT JOIN edi.item_defaultType idt ON idt.item_id = i.id
|
||||
WHERE sl.status = 'AVAILABLE'
|
||||
AND NOT sl.isDeleted
|
||||
AND NOT ti.isDeleted
|
||||
AND NOW() BETWEEN sl.orderPeriodStartDateTime AND sl.orderPeriodEndDateTime
|
||||
AND sl.numberOfPieces > 0
|
||||
GROUP BY sl.supplyLineId
|
35
utils.js
35
utils.js
|
@ -145,17 +145,12 @@ export async function syncOrganizations(){
|
|||
curSequenceNumber = response.maximumSequenceNumber;
|
||||
const orgs = response.results;
|
||||
for (let org of orgs) {
|
||||
spinner.text = `Syncing ${i} organizations, ${maxSequenceNumber - curSequenceNumber} missing...`
|
||||
if (JSON.parse(env.APPLY_ORG_FILTER) && org.companyGln && !org.endDate) { // Filtro
|
||||
await insertOrganization(org);
|
||||
spinner.text = `Syncing ${i++} organizations, ${maxSequenceNumber - curSequenceNumber} missing...`
|
||||
}
|
||||
await insertOrganization(org);
|
||||
spinner.text = `Syncing ${i++} organizations, ${maxSequenceNumber - curSequenceNumber} missing...`
|
||||
};
|
||||
await insertSequenceNumber('organization', curSequenceNumber)
|
||||
}
|
||||
await models.sequenceNumber.upsert({
|
||||
model: 'organization',
|
||||
maxSequenceNumber,
|
||||
});
|
||||
await insertSequenceNumber('organization', maxSequenceNumber)
|
||||
spinner.text = (i) ? `Syncing ${i} organizations...`
|
||||
: `Syncing organizations... (Not found)`
|
||||
spinner.succeed();
|
||||
|
@ -365,6 +360,26 @@ export async function syncClockPresaleSupply() {
|
|||
spinner.succeed()
|
||||
}
|
||||
|
||||
/**
|
||||
* Insert sequence number in the database.
|
||||
*
|
||||
* @param {String} model
|
||||
* @param {Number} sequenceNumber
|
||||
*/
|
||||
export async function insertSequenceNumber(model, sequenceNumber) {
|
||||
const tx = await models.sequelize.transaction();
|
||||
try {
|
||||
await models.sequenceNumber.upsert({
|
||||
model: model,
|
||||
maxSequenceNumber: sequenceNumber,
|
||||
}, { transaction: tx });
|
||||
await tx.commit();
|
||||
} catch (err) {
|
||||
await tx.rollback();
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
/**
|
||||
* Insert trade item and dependences in the database.
|
||||
*
|
||||
|
@ -470,7 +485,7 @@ export async function insertClockPresalesSupply(clockPresaleSupply) {
|
|||
pricePerPiece_currency: clockPresaleSupply.pricePerPiece.currency,
|
||||
pricePerPiece_value: clockPresaleSupply.pricePerPiece.value,
|
||||
organizationId: clockPresaleSupply.supplierOrganizationId,
|
||||
});
|
||||
}, { transaction: tx });
|
||||
await tx.commit();
|
||||
} catch (err) {
|
||||
await tx.rollback();
|
||||
|
|
|
@ -1,50 +0,0 @@
|
|||
CREATE OR REPLACE VIEW supplyOffer AS
|
||||
SELECT sl.supplyLineId,
|
||||
ti.name tradeItemName,
|
||||
o.commercialName organizationName,
|
||||
sl.`type`,
|
||||
sl.salesUnit,
|
||||
CAST(slvp.pricePerPiece AS DECIMAL(10, 3)) pricePerPiece,
|
||||
sl.numberOfPieces,
|
||||
ti.vbnProductCode,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 1 LIMIT 1) s1,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 2 LIMIT 1) s2,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 3 LIMIT 1) s3,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 4 LIMIT 1) s4,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 5 LIMIT 1) s5,
|
||||
(SELECT feature FROM edi.item_feature WHERE item_id = ti.vbnProductCode AND presentation_order = 6 LIMIT 1) s6,
|
||||
sl.deliveryPeriodStartDateTime,
|
||||
sl.deliveryPeriodEndDateTime,
|
||||
sl.orderPeriodStartDateTime,
|
||||
sl.orderPeriodEndDateTime,
|
||||
b.description bucketDescription,
|
||||
b.x_size,
|
||||
b.y_size,
|
||||
b.z_size,
|
||||
(b.x_size * b.y_size * b.z_size) / 1000000000 volume,
|
||||
slpc.piecesPerPackage,
|
||||
slpc.packagesPerLayer,
|
||||
slpc.layersPerLoadCarrier,
|
||||
slpc.transportHeightInCm,
|
||||
slpc.loadCarrierType,
|
||||
slpc.additionalPricePerPieceCurrency,
|
||||
slpc.additionalPricePerPieceValue,
|
||||
w.name warehouseName,
|
||||
tip.url,
|
||||
sl.lastSync
|
||||
FROM supplyLine sl
|
||||
JOIN supplyLineVolumePrice slvp ON slvp.supplyLineId = sl.supplyLineId
|
||||
JOIN organization o ON o.organizationId = sl.organizationId
|
||||
JOIN tradeItem ti ON ti.tradeItemId = sl.tradeItemId
|
||||
JOIN tradeItemPhoto tip ON tip.tradeItemId = ti.tradeItemId
|
||||
AND tip.`primary`
|
||||
JOIN tradeItemCharacteristic tic ON tic.tradeItemId = ti.tradeItemId
|
||||
JOIN warehouse w ON w.warehouseId = sl.warehouseId
|
||||
JOIN supplyLinePackingConfiguration slpc ON slpc.supplyLineId = sl.supplyLineId
|
||||
JOIN edi.bucket b ON b.bucket_id = slpc.packageVbnPackageCode
|
||||
WHERE sl.status = 'AVAILABLE'
|
||||
AND NOT sl.isDeleted
|
||||
AND NOT ti.isDeleted
|
||||
AND NOW() BETWEEN sl.orderPeriodStartDateTime AND sl.orderPeriodEndDateTime
|
||||
AND sl.numberOfPieces > 0
|
||||
GROUP BY sl.supplyLineId
|
Loading…
Reference in New Issue