From 9a0b487d2076e2ff4ba01b044644019fcaded28e Mon Sep 17 00:00:00 2001 From: Pako Date: Mon, 23 Sep 2024 13:12:53 +0200 Subject: [PATCH 1/5] feat: refs #8030 new table --- .../11258-silverTulip/00-firstScript.sql | 23 +++++++++++++++++++ 1 file changed, 23 insertions(+) create mode 100644 db/versions/11258-silverTulip/00-firstScript.sql diff --git a/db/versions/11258-silverTulip/00-firstScript.sql b/db/versions/11258-silverTulip/00-firstScript.sql new file mode 100644 index 000000000..6da8666a2 --- /dev/null +++ b/db/versions/11258-silverTulip/00-firstScript.sql @@ -0,0 +1,23 @@ +-- Place your SQL code here +-- Place your SQL code here + +CREATE TABLE `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', + PRIMARY KEY (`id`), + KEY `priceDelta_itemType_FK` (`itemTypeFk`), + KEY `priceDelta_ink_FK` (`inkFk`), + KEY `priceDelta_producer_FK` (`producerFk`), + 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 +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Defines the increasing o decreasing for ranges of items'; \ No newline at end of file -- 2.40.1 From acabd3e15448ae97ab524e8fd8bd8a5e24b7a313 Mon Sep 17 00:00:00 2001 From: Pako Date: Tue, 24 Sep 2024 08:50:34 +0200 Subject: [PATCH 2/5] feat(catalog_componentCalculate): refs #8030 new component improved The procedure has now the component "bonus", a special price increasing for a group of items Refs: #8030 --- .../procedures/catalog_componentCalculate.sql | 55 +++++++++++++++---- .../11258-silverTulip/00-firstScript.sql | 8 +-- 2 files changed, 48 insertions(+), 15 deletions(-) diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index 7ac383e8f..0b131d7a9 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -25,18 +25,39 @@ 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 + FROM vn.item i + JOIN cache.last_buy lb ON lb.item_id = i.id AND lb.warehouse_id = vWarehouseFk + JOIN buy b ON b.id = lb.buy_id + JOIN tmp.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 +129,17 @@ BEGIN JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk GROUP BY tc.itemFk, warehouseFk; + -- priceDelta Bonus del comprador a un rango de productos Refs: #8030 + INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) + SELECT + tcb.warehouseFk, + tcb.itemFk, + c.id, + tcb.base * (1 + IFNULL(tpd.ratIncreasing,0)) + IFNULL(tpd.absIncreasing,0) + FROM tmp.ticketComponentBase tcb + JOIN component c ON c.code = 'bonus' + JOIN tPriceDelta tpd ON tpd.itemFk = tcb.itemFk; + -- RECOBRO INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) SELECT tcb.warehouseFk, tcb.itemFk, c2.id, @@ -303,6 +335,7 @@ BEGIN tmp.ticketComponentBase, tmp.ticketComponentRate, tmp.ticketComponentCopy, - tSpecialPrice; + tPriceDelta, + tSpecialPrice; END$$ DELIMITER ; diff --git a/db/versions/11258-silverTulip/00-firstScript.sql b/db/versions/11258-silverTulip/00-firstScript.sql index 6da8666a2..753c279c0 100644 --- a/db/versions/11258-silverTulip/00-firstScript.sql +++ b/db/versions/11258-silverTulip/00-firstScript.sql @@ -1,7 +1,6 @@ --- Place your SQL code here --- Place your SQL code here +-- vn.priceDelta definition -CREATE TABLE `priceDelta` ( +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', @@ -13,6 +12,7 @@ CREATE TABLE `priceDelta` ( `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 DEFAULT NULL, PRIMARY KEY (`id`), KEY `priceDelta_itemType_FK` (`itemTypeFk`), KEY `priceDelta_ink_FK` (`inkFk`), @@ -20,4 +20,4 @@ CREATE TABLE `priceDelta` ( 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 -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Defines the increasing o decreasing for ranges of items'; \ No newline at end of file +) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_unicode_ci COMMENT='Defines the increasing o decreasing for ranges of items'; \ No newline at end of file -- 2.40.1 From fb7208d898278a5e6806b04d51512e26ad19f8b9 Mon Sep 17 00:00:00 2001 From: Pako Date: Tue, 24 Sep 2024 09:05:30 +0200 Subject: [PATCH 3/5] fix: refs #8030 warehouse filter Warehouse is also needed to make the filter Refs: #8030 --- .../vn/procedures/catalog_componentCalculate.sql | 9 +++++---- db/versions/11258-silverTulip/00-firstScript.sql | 10 +++++++--- 2 files changed, 12 insertions(+), 7 deletions(-) diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index 0b131d7a9..f13675e4b 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -30,10 +30,9 @@ BEGIN ENGINE = MEMORY SELECT i.id itemFk, SUM(IFNULL(pd.absIncreasing,0)) absIncreasing, - SUM(IFNULL(pd.ratIncreasing,0)) ratIncreasing + SUM(IFNULL(pd.ratIncreasing,0)) ratIncreasing, + pd.warehouseFk FROM vn.item i - JOIN cache.last_buy lb ON lb.item_id = i.id AND lb.warehouse_id = vWarehouseFk - JOIN buy b ON b.id = lb.buy_id JOIN tmp.priceDelta pd ON pd.itemTypeFk = i.typeFk AND (pd.minSize IS NULL OR pd.minSize <= i.`size`) @@ -138,7 +137,9 @@ BEGIN tcb.base * (1 + IFNULL(tpd.ratIncreasing,0)) + IFNULL(tpd.absIncreasing,0) FROM tmp.ticketComponentBase tcb JOIN component c ON c.code = 'bonus' - JOIN tPriceDelta tpd ON tpd.itemFk = tcb.itemFk; + JOIN tPriceDelta tpd + ON tpd.itemFk = tcb.itemFk + AND tpd.warehouseFk = tcb.warehouseFk; -- RECOBRO INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) diff --git a/db/versions/11258-silverTulip/00-firstScript.sql b/db/versions/11258-silverTulip/00-firstScript.sql index 753c279c0..6f0f1906a 100644 --- a/db/versions/11258-silverTulip/00-firstScript.sql +++ b/db/versions/11258-silverTulip/00-firstScript.sql @@ -1,6 +1,8 @@ -- vn.priceDelta definition -CREATE OR REPLACE TABLE vn.priceDelta ( +-- 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', @@ -12,12 +14,14 @@ CREATE OR REPLACE TABLE vn.priceDelta ( `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 DEFAULT NULL, + `warehouseFk` smallint(6) unsigned NOT NULL, PRIMARY KEY (`id`), KEY `priceDelta_itemType_FK` (`itemTypeFk`), KEY `priceDelta_ink_FK` (`inkFk`), KEY `priceDelta_producer_FK` (`producerFk`), + KEY `priceDelta_warehouse_FK` (`warehouseFk`), 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_producer_FK` FOREIGN KEY (`producerFk`) REFERENCES `producer` (`id`) ON UPDATE CASCADE, + CONSTRAINT `priceDelta_warehouse_FK` FOREIGN KEY (`warehouseFk`) REFERENCES `warehouse` (`id`) 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'; \ No newline at end of file -- 2.40.1 From 91801b19795b7dcc652ef6af87cc152bc5aba37d Mon Sep 17 00:00:00 2001 From: Pako Date: Tue, 24 Sep 2024 10:27:27 +0200 Subject: [PATCH 4/5] fix: refs #8030 redmine revision updates Changes recomended by the reviewer Refs: #8030 --- db/routines/vn/procedures/catalog_componentCalculate.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index f13675e4b..b1f8e3eea 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -128,7 +128,7 @@ BEGIN JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk GROUP BY tc.itemFk, warehouseFk; - -- priceDelta Bonus del comprador a un rango de productos Refs: #8030 + -- Bonus del comprador a un rango de productos INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) SELECT tcb.warehouseFk, -- 2.40.1 From 5c8f42a3aee541ac7d68aee2245c90daaa7ecd34 Mon Sep 17 00:00:00 2001 From: Pako Date: Tue, 24 Sep 2024 10:27:27 +0200 Subject: [PATCH 5/5] fix: refs #8030 redmine revision updates Changes recomended by the reviewer Refs: #8030 --- db/routines/vn/procedures/catalog_componentCalculate.sql | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/db/routines/vn/procedures/catalog_componentCalculate.sql b/db/routines/vn/procedures/catalog_componentCalculate.sql index f13675e4b..7d68661e1 100644 --- a/db/routines/vn/procedures/catalog_componentCalculate.sql +++ b/db/routines/vn/procedures/catalog_componentCalculate.sql @@ -32,8 +32,8 @@ BEGIN SUM(IFNULL(pd.absIncreasing,0)) absIncreasing, SUM(IFNULL(pd.ratIncreasing,0)) ratIncreasing, pd.warehouseFk - FROM vn.item i - JOIN tmp.priceDelta pd + 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`) @@ -128,7 +128,7 @@ BEGIN JOIN tmp.ticketComponentCalculate tcc ON tcc.itemFk = tc.itemFk AND tcc.warehouseFk = tc.warehouseFk GROUP BY tc.itemFk, warehouseFk; - -- priceDelta Bonus del comprador a un rango de productos Refs: #8030 + -- Bonus del comprador a un rango de productos INSERT INTO tmp.ticketComponent(warehouseFk, itemFk, componentFk, cost) SELECT tcb.warehouseFk, -- 2.40.1