diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index 7ac383e8f..d4ce88ca7 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -7,7 +7,7 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`catalog_componentCalc ) BEGIN /** - * Calcula los componentes de los articulos de tmp.ticketLot + * Calcula los componentes de los articulos de la tabla tmp.ticketLot * * @param vZoneFk para calcular el transporte * @param vAddressFk Consignatario @@ -25,18 +25,38 @@ BEGIN FROM address WHERE id = vAddressFk; - CREATE OR REPLACE TEMPORARY TABLE tSpecialPrice + CREATE OR REPLACE TEMPORARY TABLE tPriceDelta (INDEX (itemFk)) - ENGINE = MEMORY - SELECT * FROM ( + ENGINE = MEMORY + SELECT i.id itemFk, + SUM(IFNULL(pd.absIncreasing,0)) absIncreasing, + SUM(IFNULL(pd.ratIncreasing,0)) ratIncreasing, + pd.warehouseFk + FROM item i + JOIN priceDelta pd + ON pd.itemTypeFk = i.typeFk + AND (pd.minSize IS NULL OR pd.minSize <= i.`size`) + AND (pd.maxSize IS NULL OR pd.maxSize >= i.`size`) + AND (pd.inkFk IS NULL OR pd.inkFk = i.inkFk) + AND (pd.originFk IS NULL OR pd.originFk = i.originFk) + AND (pd.producerFk IS NULL OR pd.producerFk = i.producerFk) + AND (pd.warehouseFk IS NULL OR pd.warehouseFk = vWarehouseFk) + WHERE (pd.fromDated IS NULL OR pd.fromDated <= vShipped) + AND (pd.toDated IS NULL OR pd.toDated >= vShipped) + GROUP BY i.id; + + CREATE OR REPLACE TEMPORARY TABLE tSpecialPrice + (INDEX (itemFk)) + ENGINE = MEMORY + SELECT * FROM ( SELECT * - FROM specialPrice - WHERE (clientFk = vClientFk OR clientFk IS NULL) - AND started <= vShipped - AND (ended >= vShipped OR ended IS NULL) - ORDER BY (clientFk = vClientFk) DESC, id DESC - LIMIT 10000000000000000000) t - GROUP BY itemFk; + FROM specialPrice + WHERE (clientFk = vClientFk OR clientFk IS NULL) + AND started <= vShipped + AND (ended >= vShipped OR ended IS NULL) + ORDER BY (clientFk = vClientFk) DESC, id DESC + LIMIT 10000000000000000000) t + GROUP BY itemFk; CREATE OR REPLACE TEMPORARY TABLE tmp.ticketComponentCalculate (PRIMARY KEY (itemFk, warehouseFk)) @@ -108,6 +128,19 @@ BEGIN JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk GROUP BY tc.itemFk, warehouseFk; + -- Bonus del comprador a un rango de productos + INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) + SELECT + tcb.warehouseFk, + tcb.itemFk, + c.id, + IFNULL(tcb.base * tpd.ratIncreasing / 100,0) + IFNULL(tpd.absIncreasing,0) + FROM tmp.ticketComponentBase tcb + JOIN component c ON c.code = 'bonus' + JOIN tPriceDelta tpd + ON tpd.itemFk = tcb.itemFk + AND tpd.warehouseFk = tcb.warehouseFk; + -- RECOBRO INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) SELECT tcb.warehouseFk, tcb.itemFk, c2.id, @@ -303,6 +336,7 @@ BEGIN tmp.ticketComponentBase, tmp.ticketComponentRate, tmp.ticketComponentCopy, - tSpecialPrice; + tPriceDelta, + tSpecialPrice; END$$ DELIMITER ; diff --git a/db/versions/11263-brownAnthurium/00-firstScript.sql b/db/versions/11263-brownAnthurium/00-firstScript.sql new file mode 100644 index 000000000..0824ea5f7 --- /dev/null +++ b/db/versions/11263-brownAnthurium/00-firstScript.sql @@ -0,0 +1,32 @@ +-- Place your SQL code here +-- vn.priceDelta definition + +CREATE OR REPLACE TABLE vn.priceDelta ( + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `itemTypeFk` smallint(5) unsigned NOT NULL, + `minSize` int(10) unsigned DEFAULT NULL COMMENT 'Minimum item.size', + `maxSize` int(10) unsigned DEFAULT NULL COMMENT 'Maximum item.size', + `inkFk` varchar(3) DEFAULT NULL, + `originFk` tinyint(2) unsigned DEFAULT NULL, + `producerFk` mediumint(3) unsigned DEFAULT NULL, + `fromDated` date DEFAULT NULL, + `toDated` date DEFAULT NULL, + `absIncreasing` decimal(10,3) DEFAULT NULL COMMENT 'Absolute increasing of final price', + `ratIncreasing` int(11) DEFAULT NULL COMMENT 'Increasing ratio for the cost price', + `warehouseFk` smallint(6) unsigned NOT NULL, + `created` timestamp NOT NULL DEFAULT current_timestamp(), + `editorFk` int(10) unsigned DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `priceDelta_itemType_FK` (`itemTypeFk`), + KEY `priceDelta_ink_FK` (`inkFk`), + KEY `priceDelta_producer_FK` (`producerFk`), + KEY `priceDelta_warehouse_FK` (`warehouseFk`), + KEY `priceDelta_worker_FK` (`editorFk`), + CONSTRAINT `priceDelta_ink_FK` FOREIGN KEY (`inkFk`) REFERENCES `ink` (`id`) ON UPDATE CASCADE, + CONSTRAINT `priceDelta_itemType_FK` FOREIGN KEY (`itemTypeFk`) REFERENCES `itemType` (`id`) ON UPDATE CASCADE, + CONSTRAINT `priceDelta_producer_FK` FOREIGN KEY (`producerFk`) REFERENCES `producer` (`id`) ON UPDATE CASCADE, + CONSTRAINT `priceDelta_warehouse_FK` FOREIGN KEY (`warehouseFk`) REFERENCES `warehouse` (`id`) ON UPDATE CASCADE, + CONSTRAINT `priceDelta_worker_FK` FOREIGN KEY (`editorFk`) REFERENCES `worker` (`id`) ON DELETE SET NULL ON UPDATE CASCADE +) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Defines the increasing o decreasing for ranges of items'; + +GRANT INSERT, SELECT, UPDATE, DELETE ON TABLE vn.priceDelta TO buyer; \ No newline at end of file