From 2a03faf50fc169a72be289b8524a90bcd39e41cf Mon Sep 17 00:00:00 2001 From: Rotem Tamir Date: Thu, 7 Mar 2024 13:45:18 +0200 Subject: [PATCH] projects/inventory: track regional inventory --- .../migrations/20240307113646_add_items.sql | 12 ++ .../20240307114027_add_orders_shipments.sql | 25 +++ .../20240307114116_region_inventory.sql | 10 + ...40307114304_inventory_tracking_trigger.sql | 26 +++ .../estore/inventory/migrations/atlas.sum | 6 +- projects/estore/inventory/schema.hcl | 202 ++++++++++++++++++ 6 files changed, 280 insertions(+), 1 deletion(-) create mode 100644 projects/estore/inventory/migrations/20240307113646_add_items.sql create mode 100644 projects/estore/inventory/migrations/20240307114027_add_orders_shipments.sql create mode 100644 projects/estore/inventory/migrations/20240307114116_region_inventory.sql create mode 100644 projects/estore/inventory/migrations/20240307114304_inventory_tracking_trigger.sql diff --git a/projects/estore/inventory/migrations/20240307113646_add_items.sql b/projects/estore/inventory/migrations/20240307113646_add_items.sql new file mode 100644 index 0000000..14d6a66 --- /dev/null +++ b/projects/estore/inventory/migrations/20240307113646_add_items.sql @@ -0,0 +1,12 @@ +-- Create "inventory_items" table +CREATE TABLE `inventory_items` ( + `inventory_id` int NOT NULL AUTO_INCREMENT, + `product_id` int NULL, + `warehouse_id` int NULL, + `quantity` int NULL DEFAULT 0, + PRIMARY KEY (`inventory_id`), + INDEX `product_id` (`product_id`), + INDEX `warehouse_id` (`warehouse_id`), + CONSTRAINT `inventory_items_ibfk_1` FOREIGN KEY (`product_id`) REFERENCES `products` (`product_id`) ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT `inventory_items_ibfk_2` FOREIGN KEY (`warehouse_id`) REFERENCES `warehouses` (`warehouse_id`) ON UPDATE NO ACTION ON DELETE NO ACTION +) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci; diff --git a/projects/estore/inventory/migrations/20240307114027_add_orders_shipments.sql b/projects/estore/inventory/migrations/20240307114027_add_orders_shipments.sql new file mode 100644 index 0000000..23f6405 --- /dev/null +++ b/projects/estore/inventory/migrations/20240307114027_add_orders_shipments.sql @@ -0,0 +1,25 @@ +-- Create "orders" table +CREATE TABLE `orders` ( + `order_id` int NOT NULL AUTO_INCREMENT, + `product_id` int NULL, + `quantity` int NOT NULL, + `order_date` timestamp NULL DEFAULT CURRENT_TIMESTAMP, + `customer_info` text NULL, + `status` varchar(100) NULL, + PRIMARY KEY (`order_id`), + INDEX `product_id` (`product_id`), + CONSTRAINT `orders_ibfk_1` FOREIGN KEY (`product_id`) REFERENCES `products` (`product_id`) ON UPDATE NO ACTION ON DELETE NO ACTION +) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci; +-- Create "shipments" table +CREATE TABLE `shipments` ( + `shipment_id` int NOT NULL AUTO_INCREMENT, + `product_id` int NULL, + `warehouse_id` int NULL, + `quantity` int NOT NULL, + `shipment_date` timestamp NULL DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (`shipment_id`), + INDEX `product_id` (`product_id`), + INDEX `warehouse_id` (`warehouse_id`), + CONSTRAINT `shipments_ibfk_1` FOREIGN KEY (`product_id`) REFERENCES `products` (`product_id`) ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT `shipments_ibfk_2` FOREIGN KEY (`warehouse_id`) REFERENCES `warehouses` (`warehouse_id`) ON UPDATE NO ACTION ON DELETE NO ACTION +) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci; diff --git a/projects/estore/inventory/migrations/20240307114116_region_inventory.sql b/projects/estore/inventory/migrations/20240307114116_region_inventory.sql new file mode 100644 index 0000000..f10c5c5 --- /dev/null +++ b/projects/estore/inventory/migrations/20240307114116_region_inventory.sql @@ -0,0 +1,10 @@ +-- Create "inventory_by_region" table +CREATE TABLE `inventory_by_region` ( + `region_id` int NOT NULL, + `product_id` int NOT NULL, + `total_quantity` int NULL, + PRIMARY KEY (`region_id`, `product_id`), + INDEX `product_id` (`product_id`), + CONSTRAINT `inventory_by_region_ibfk_1` FOREIGN KEY (`region_id`) REFERENCES `regions` (`region_id`) ON UPDATE NO ACTION ON DELETE NO ACTION, + CONSTRAINT `inventory_by_region_ibfk_2` FOREIGN KEY (`product_id`) REFERENCES `products` (`product_id`) ON UPDATE NO ACTION ON DELETE NO ACTION +) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci; diff --git a/projects/estore/inventory/migrations/20240307114304_inventory_tracking_trigger.sql b/projects/estore/inventory/migrations/20240307114304_inventory_tracking_trigger.sql new file mode 100644 index 0000000..6ae130d --- /dev/null +++ b/projects/estore/inventory/migrations/20240307114304_inventory_tracking_trigger.sql @@ -0,0 +1,26 @@ +-- Create trigger "after_order_insert" +CREATE TRIGGER `after_order_insert` AFTER INSERT ON `orders` FOR EACH ROW BEGIN + DECLARE regionId INT; + + -- Assuming each product is linked to a single warehouse, which is a simplification. + -- This might need a more complex logic based on how your warehouses and orders are structured. + SELECT w.region_id INTO regionId + FROM warehouses w + JOIN inventory_items ii ON w.warehouse_id = ii.warehouse_id + WHERE ii.product_id = NEW.product_id + LIMIT 1; -- This is a simplification and might need adjustment. + + UPDATE inventory_by_region + SET total_quantity = total_quantity - NEW.quantity + WHERE region_id = regionId AND product_id = NEW.product_id; +END; +-- Create trigger "after_shipment_insert" +CREATE TRIGGER `after_shipment_insert` AFTER INSERT ON `shipments` FOR EACH ROW BEGIN + DECLARE regionId INT; + + SELECT region_id INTO regionId FROM warehouses WHERE warehouse_id = NEW.warehouse_id; + + INSERT INTO inventory_by_region (region_id, product_id, total_quantity) + VALUES (regionId, NEW.product_id, NEW.quantity) + ON DUPLICATE KEY UPDATE total_quantity = total_quantity + NEW.quantity; +END; diff --git a/projects/estore/inventory/migrations/atlas.sum b/projects/estore/inventory/migrations/atlas.sum index 6e7cf79..acd87a9 100644 --- a/projects/estore/inventory/migrations/atlas.sum +++ b/projects/estore/inventory/migrations/atlas.sum @@ -1,3 +1,7 @@ -h1:OD80uv7vCyCGr2x6dS4rLVaCkoj7JyydbcT6gxQAShI= +h1:TXS4jLbko59JU5wbXzE89sr5uGQvxCMAm+oMEdtAnmU= 20240307092728.sql h1:BEXRAbglZQlUqXHRy4fvsEVsu7FlSfKcJ/JAkH2XgMY= 20240307104354_add_warehouses.sql h1:heT56DSu6Ka8TJo8K4F92rVxinZmt+7tbMX+y3vaJKo= +20240307113646_add_items.sql h1:T6WAjSdbbQiI3RmiM7amcNZGjsNy6re8QjYkWXKCJXw= +20240307114027_add_orders_shipments.sql h1:j6t5n5vZ8dSHHvd1HcR3ObFC1+e1I1X5Zmt/EsryURc= +20240307114116_region_inventory.sql h1:pCnxwZ1bw8sn4v+G0gyhot1Hs+i4BaPr4EbGUugkS3M= +20240307114304_inventory_tracking_trigger.sql h1:iiEGHpZYWyR5jsW44pLcEt7cU3VfSrFC61Te0aPQLNk= diff --git a/projects/estore/inventory/schema.hcl b/projects/estore/inventory/schema.hcl index ede22d2..705e436 100644 --- a/projects/estore/inventory/schema.hcl +++ b/projects/estore/inventory/schema.hcl @@ -17,6 +17,122 @@ table "categories" { columns = [column.category_id] } } +table "inventory_by_region" { + schema = schema.default + column "region_id" { + null = false + type = int + } + column "product_id" { + null = false + type = int + } + column "total_quantity" { + null = true + type = int + } + primary_key { + columns = [column.region_id, column.product_id] + } + foreign_key "inventory_by_region_ibfk_1" { + columns = [column.region_id] + ref_columns = [table.regions.column.region_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + foreign_key "inventory_by_region_ibfk_2" { + columns = [column.product_id] + ref_columns = [table.products.column.product_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + index "product_id" { + columns = [column.product_id] + } +} +table "inventory_items" { + schema = schema.default + column "inventory_id" { + null = false + type = int + auto_increment = true + } + column "product_id" { + null = true + type = int + } + column "warehouse_id" { + null = true + type = int + } + column "quantity" { + null = true + type = int + default = 0 + } + primary_key { + columns = [column.inventory_id] + } + foreign_key "inventory_items_ibfk_1" { + columns = [column.product_id] + ref_columns = [table.products.column.product_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + foreign_key "inventory_items_ibfk_2" { + columns = [column.warehouse_id] + ref_columns = [table.warehouses.column.warehouse_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + index "product_id" { + columns = [column.product_id] + } + index "warehouse_id" { + columns = [column.warehouse_id] + } +} +table "orders" { + schema = schema.default + column "order_id" { + null = false + type = int + auto_increment = true + } + column "product_id" { + null = true + type = int + } + column "quantity" { + null = false + type = int + } + column "order_date" { + null = true + type = timestamp + default = sql("CURRENT_TIMESTAMP") + } + column "customer_info" { + null = true + type = text + } + column "status" { + null = true + type = varchar(100) + } + primary_key { + columns = [column.order_id] + } + foreign_key "orders_ibfk_1" { + columns = [column.product_id] + ref_columns = [table.products.column.product_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + index "product_id" { + columns = [column.product_id] + } +} table "products" { schema = schema.default column "product_id" { @@ -82,6 +198,52 @@ table "regions" { columns = [column.region_id] } } +table "shipments" { + schema = schema.default + column "shipment_id" { + null = false + type = int + auto_increment = true + } + column "product_id" { + null = true + type = int + } + column "warehouse_id" { + null = true + type = int + } + column "quantity" { + null = false + type = int + } + column "shipment_date" { + null = true + type = timestamp + default = sql("CURRENT_TIMESTAMP") + } + primary_key { + columns = [column.shipment_id] + } + foreign_key "shipments_ibfk_1" { + columns = [column.product_id] + ref_columns = [table.products.column.product_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + foreign_key "shipments_ibfk_2" { + columns = [column.warehouse_id] + ref_columns = [table.warehouses.column.warehouse_id] + on_update = NO_ACTION + on_delete = NO_ACTION + } + index "product_id" { + columns = [column.product_id] + } + index "warehouse_id" { + columns = [column.warehouse_id] + } +} table "suppliers" { schema = schema.default column "supplier_id" { @@ -133,6 +295,46 @@ table "warehouses" { columns = [column.region_id] } } +trigger "after_order_insert" { + on = table.orders + after { + insert = true + } + as = <<-SQL + BEGIN + DECLARE regionId INT; + + -- Assuming each product is linked to a single warehouse, which is a simplification. + -- This might need a more complex logic based on how your warehouses and orders are structured. + SELECT w.region_id INTO regionId + FROM warehouses w + JOIN inventory_items ii ON w.warehouse_id = ii.warehouse_id + WHERE ii.product_id = NEW.product_id + LIMIT 1; -- This is a simplification and might need adjustment. + + UPDATE inventory_by_region + SET total_quantity = total_quantity - NEW.quantity + WHERE region_id = regionId AND product_id = NEW.product_id; + END + SQL +} +trigger "after_shipment_insert" { + on = table.shipments + after { + insert = true + } + as = <<-SQL + BEGIN + DECLARE regionId INT; + + SELECT region_id INTO regionId FROM warehouses WHERE warehouse_id = NEW.warehouse_id; + + INSERT INTO inventory_by_region (region_id, product_id, total_quantity) + VALUES (regionId, NEW.product_id, NEW.quantity) + ON DUPLICATE KEY UPDATE total_quantity = total_quantity + NEW.quantity; + END + SQL +} schema "default" { charset = "utf8mb4" collate = "utf8mb4_0900_ai_ci"