Guide To Design Database For Inventory Management System In MySQL

By bhagwatchouhan
Guide To Design Database For Inventory Management System In MySQL

This tutorial provides the complete steps to design a database schema of the Inventory Management System to manage the suppliers, salespersons, items, item stock, purchase orders, and customer orders.

Notes: Commonly, businesses in retail and manufacturing employ inventory systems.  Among widespread use cases in other industries, this database schema can be used, for instance, for hospital inventory management to increase the efficiency of healthcare supply chains and reduce medication waste.

The Entity Relationship Diagram or visual database design is shown below.

 

Inventory Management Database Design

Inventory Management Database

You can also visit the popular tutorials including How To Install MySQL 8 on Ubuntu 20.04 LTS, How To Install MySQL 8 on Windows, How To Install MySQL Workbench On Ubuntu, How To Install MySQL 8 With Workbench On Windows 10, RBAC Database in MySql, Blog Database in MySql, Quiz Database in MySQL, Poll & Survey Database in MySQL, Online Shopping Cart Database in MySQL, and Learn Basic SQL Queries In MySQL.

Inventory Database

The very first step is to create the Inventory Database. It can be created using the query as shown below.

CREATE SCHEMA `inventory` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;

I have used the character set utf8mb4 to support a wide range of characters.

User Table

In this section, we will design the User Table to store user information. Users can manage their own profiles. Also, the users can use the application according to the roles assigned to them. You can also refer to the tutorial RBAC Database in MySql to implement a complete RBAC system for managing roles and permissions. Below mentioned is the description of all the columns of the User Table.

IdThe unique id to identify the user.
Role IdThe role of the user. It can be Admin, Supplier, Salesperson, and Customer.
First NameThe first name of the user.
Middle NameThe middle name of the user.
Last NameThe last name of the user.
MobileThe mobile number of the user. It can be used for login and registration purposes.
EmailThe email of the user. It can be used for login and registration purposes.
Password HashThe password hash generated by the appropriate algorithm. We must avoid storing plain or encrypted passwords.
Registered AtThis column can be used to calculate the life of the user with the application.
Last LoginIt can be used to identify the last login of the user.
IntroA brief introduction of the User.
ProfileUser details.

The User Table with the appropriate constraints is shown below.

CREATE TABLE `inventory`.`user` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`roleId` SMALLINT NOT NULL,
`firstName` VARCHAR(50) NULL DEFAULT NULL,
`middleName` VARCHAR(50) NULL DEFAULT NULL,
`lastName` VARCHAR(50) NULL DEFAULT NULL,
`username` VARCHAR(50) NULL DEFAULT NULL,
`mobile` VARCHAR(15) NULL,
`email` VARCHAR(50) NULL,
`passwordHash` VARCHAR(32) NOT NULL,
`registeredAt` DATETIME NOT NULL,
`lastLogin` DATETIME NULL DEFAULT NULL,
`intro` TINYTEXT NULL DEFAULT NULL,
`profile` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE INDEX `uq_username` (`username` ASC),
UNIQUE INDEX `uq_mobile` (`mobile` ASC),
UNIQUE INDEX `uq_email` (`email` ASC) );

Product Table

In this section, we will design the Product Table to store the product data. Below mentioned is the description of all the columns of the Product Table.

IdThe unique id to identify the product.
TitleThe product title to be displayed on the Inventory.
SummaryThe summary to mention the key highlights.
TypeThe type to distinguish between the different product types.
Created AtIt stores the date and time at which the product is created.
Updated AtIt stores the date and time at which the product is updated.
ContentThe column used to store the additional details of the product.

The Product Table with the appropriate constraints is shown below.

CREATE TABLE `inventory`.`product` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`title` VARCHAR(75) NOT NULL,
`summary` TINYTEXT NULL,
`type` SMALLINT(6) NOT NULL DEFAULT 0,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`)
);

Product Meta

The Product Meta Table can be used to store additional information about products including the product banner URL etc. Below mentioned is the description of all the columns of the Product Meta Table.

IdThe unique id to identify the product meta.
Product IdThe product id to identify the parent product.
KeyThe key identifying the meta.
ContentThe column used to store the product metadata.

The Product Meta Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`product_meta` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`productId` BIGINT NOT NULL,
`key` VARCHAR(50) NOT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_meta_product` (`productId` ASC),
UNIQUE INDEX `uq_product_meta` (`productId` ASC, `key` ASC),
CONSTRAINT `fk_meta_product`
FOREIGN KEY (`productId`)
REFERENCES `inventory`.`product` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION)
ENGINE = InnoDB;

Category Table and Product Category Table

In this section, we will design the Category Table and Product Category Table to store the product categories and their mappings. Below mentioned is the description of all the columns of the Category Table.

IdThe unique id to identify the category.
Parent IdThe parent id to identify the parent category.
TitleThe category title.
Meta TitleThe meta title to be used for browser title and SEO.
SlugThe category slug to form the URL.
ContentThe column used to store the category details.

The Category Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`category` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`parentId` BIGINT NULL DEFAULT NULL,
`title` VARCHAR(75) NOT NULL,
`metaTitle` VARCHAR(100) NULL DEFAULT NULL,
`slug` VARCHAR(100) NOT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`));

ALTER TABLE `inventory`.`category`
ADD INDEX `idx_category_parent` (`parentId` ASC);
ALTER TABLE `inventory`.`category`
ADD CONSTRAINT `fk_category_parent`
FOREIGN KEY (`parentId`)
REFERENCES `inventory`.`category` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

Below mentioned is the description of all the columns of the Product Category Table.

Product IdThe product id to identify the product.
Category IdThe category id to identify the category.

The Product Category Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`product_category` (
`productId` BIGINT NOT NULL,
`categoryId` BIGINT NOT NULL,
PRIMARY KEY (`productId`, `categoryId`),
INDEX `idx_pc_category` (`categoryId` ASC),
INDEX `idx_pc_product` (`productId` ASC),
CONSTRAINT `fk_pc_product`
FOREIGN KEY (`productId`)
REFERENCES `inventory`.`product` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION,
CONSTRAINT `fk_pc_category`
FOREIGN KEY (`categoryId`)
REFERENCES `inventory`.`category` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

Brand Table

In this section, we will design the Brand Table to store the brand data. Below mentioned is the description of all the columns of the Brand Table.

IdThe unique id to identify the brand.
TitleThe brand title to be displayed on the Inventory.
SummaryThe summary mentions the key highlights.
Created AtIt stores the date and time at which the product is created.
Updated AtIt stores the date and time at which the product is updated.
ContentThe column used to store the additional details of the brand.

The Brand Table with the appropriate constraints is shown below.

CREATE TABLE `inventory`.`brand` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`title` VARCHAR(75) NOT NULL,
`summary` TINYTEXT NULL,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`)
);

Order Table Table

This section provides the table to manage the inventory orders. The order can be associated with either Supplier or the Customer. Below mentioned is the description of all the columns of the Order Table.

IdThe unique id to identify the order.
User IdThe user id to identify the Supplier or Customer associated with the order.
TypeThe order type to distinguish among Purchase Order or Customer Order.
StatusThe status of the order can be New, Checkout, Paid, Failed, Shipped, Delivered, Returned, and Complete.
Sub TotalThe total price of the Order Items.
Item DiscountThe total discount of the Order Items.
TaxThe tax on the Order Items.
ShippingThe shipping charges of the Order Items.
TotalThe total price of the Order including tax and shipping. It excludes the items discount.
PromoThe promo code of the Order.
DiscountThe total discount of the Order based on the promo code or store discount.
Grand TotalThe grand total of the order to be paid by the buyer.
Created AtIt stores the date and time at which the order is created.
Updated AtIt stores the date and time at which the order is updated.
ContentThe column used to store the additional details of the order.

The Order Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`order` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`userId` BIGINT NOT NULL,
`type` SMALLINT(6) NOT NULL DEFAULT 0,
`status` SMALLINT(6) NOT NULL DEFAULT 0,
`subTotal` FLOAT NOT NULL DEFAULT 0,
`itemDiscount` FLOAT NOT NULL DEFAULT 0,
`tax` FLOAT NOT NULL DEFAULT 0,
`shipping` FLOAT NOT NULL DEFAULT 0,
`total` FLOAT NOT NULL DEFAULT 0,
`promo` VARCHAR(50) NULL DEFAULT NULL,
`discount` FLOAT NOT NULL DEFAULT 0,
`grandTotal` FLOAT NOT NULL DEFAULT 0,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_order_user` (`userId` ASC),
CONSTRAINT `fk_order_user`
FOREIGN KEY (`userId`)
REFERENCES `inventory`.`user` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

Address Table

This section provides the table to manage the address of either the user or the order. The user address can be used to store the address associated with the user. The order address can be used to store the delivery address for the home delivery orders. Below mentioned is the description of all the columns of the Address Table.

IdThe unique id to identify the address.
User IdThe user id to identify the user associated with the address.
Order IdThe order id to identify the order associated with the address.
First NameThe first name of the user.
Middle NameThe middle name of the user.
Last NameThe last name of the user.
MobileThe mobile number of the user.
EmailThe email of the user.
Line 1The first line to store address.
Line 2The second line to store address.
CityThe city of the address.
ProvinceThe province of the address.
CountryThe country of the address.
Created AtIt stores the date and time at which the order is created.
Updated AtIt stores the date and time at which the order is updated.

The Address Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`address` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`userId` BIGINT NULL DEFAULT NULL,
`orderId` BIGINT NULL DEFAULT NULL,
`firstName` VARCHAR(50) NULL DEFAULT NULL,
`middleName` VARCHAR(50) NULL DEFAULT NULL,
`lastName` VARCHAR(50) NULL DEFAULT NULL,
`mobile` VARCHAR(15) NULL,
`email` VARCHAR(50) NULL,
`line1` VARCHAR(50) NULL DEFAULT NULL,
`line2` VARCHAR(50) NULL DEFAULT NULL,
`city` VARCHAR(50) NULL DEFAULT NULL,
`province` VARCHAR(50) NULL DEFAULT NULL,
`country` VARCHAR(50) NULL DEFAULT NULL,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_address_user` (`userId` ASC),
CONSTRAINT `fk_address_user`
FOREIGN KEY (`userId`)
REFERENCES `inventory`.`user` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

ALTER TABLE `inventory`.`address`
ADD INDEX `idx_address_order` (`orderId` ASC);
ALTER TABLE `inventory`.`address`
ADD CONSTRAINT `fk_address_order`
FOREIGN KEY (`orderId`)
REFERENCES `inventory`.`order` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

Item Table

In this section, we will design the Item Table to store the item details. The Item represents the items stocked in the inventory and purchased from the suppliers. Below mentioned is the description of all the columns of the Item Table.

IdThe unique id to identify the item.
Product IdThe product id to identify the product associated with the inventory item.
Brand IdThe brand id to identify the brand associated with the inventory item.
Supplier IdThe supplier id to identify the supplier associated with the inventory item.
Order IdThe order id to identify the order associated with the inventory item.
Created ByThe user id to identify the user who added the inventory item.
Updated ByThe user id to identify the user who updated the inventory item.
Stock Keeping UnitThe id to identify the item on stock.
Maximum Retail PriceThe printed price of the product associated with the item.
DiscountThe discount is given by the supplier.
PriceThe price at which the product was purchased.
QuantityThe total quantity received at the inventory.
SoldThe total quantity sold to the customers.
AvailableThe quantity that is available on the stock.
DefectiveThe total defective items either received at the inventory or returned by the customers.
Created AtIt stores the date and time at which the order is created.
Updated AtIt stores the date and time at which the order is updated.

The Item Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`item` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`productId` BIGINT NOT NULL,
`brandId` BIGINT NOT NULL,
`supplierId` BIGINT NOT NULL,
`orderId` BIGINT NOT NULL,
`sku` VARCHAR(100) NOT NULL,
`mrp` FLOAT NOT NULL DEFAULT 0,
`discount` FLOAT NOT NULL DEFAULT 0,
`price` FLOAT NOT NULL DEFAULT 0,
`quantity` SMALLINT(6) NOT NULL DEFAULT 0,
`sold` SMALLINT(6) NOT NULL DEFAULT 0,
`available` SMALLINT(6) NOT NULL DEFAULT 0,
`defective` SMALLINT(6) NOT NULL DEFAULT 0,
`createdBy` BIGINT NOT NULL,
`updatedBy` BIGINT DEFAULT NULL,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_item_product` (`productId` ASC),
CONSTRAINT `fk_item_product`
FOREIGN KEY (`productId`)
REFERENCES `inventory`.`product` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

ALTER TABLE `inventory`.`item`
ADD INDEX `idx_item_brand` (`brandId` ASC);
ALTER TABLE `inventory`.`item`
ADD CONSTRAINT `fk_item_brand`
FOREIGN KEY (`brandId`)
REFERENCES `inventory`.`brand` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

ALTER TABLE `inventory`.`item`
ADD INDEX `idx_item_user` (`supplierId` ASC);
ALTER TABLE `inventory`.`item`
ADD CONSTRAINT `fk_item_user`
FOREIGN KEY (`supplierId`)
REFERENCES `inventory`.`user` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

ALTER TABLE `inventory`.`item`
ADD INDEX `idx_item_order` (`orderId` ASC);
ALTER TABLE `inventory`.`item`
ADD CONSTRAINT `fk_item_order`
FOREIGN KEY (`orderId`)
REFERENCES `inventory`.`order` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

Order Item Table

This section provides the table to manage the order items purchased by the customers. Below mentioned is the description of all the columns of the Order Item Table.

IdThe unique id to identify the ordered item.
Product IdThe product id to identify the product associated with the ordered item.
Item IdThe item id to identify the item associated with the ordered item.
Order IdThe order id to identify the order associated with the ordered item.
SKUThe SKU of the product while purchasing it.
PriceThe price of the product while purchasing it.
DiscountThe discount of the product while purchasing it.
QuantityThe quantity of the product selected by the user.
Created AtIt stores the date and time at which the ordered item is created.
Updated AtIt stores the date and time at which the ordered item is updated.
ContentThe column used to store the additional details of the ordered item.

The Order Item Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`order_item` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`productId` BIGINT NOT NULL,
`itemId` BIGINT NOT NULL,
`orderId` BIGINT NOT NULL,
`sku` VARCHAR(100) NOT NULL,
`price` FLOAT NOT NULL DEFAULT 0,
`discount` FLOAT NOT NULL DEFAULT 0,
`quantity` SMALLINT(6) NOT NULL DEFAULT 0,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_order_item_product` (`productId` ASC),
CONSTRAINT `fk_order_item_product`
FOREIGN KEY (`productId`)
REFERENCES `inventory`.`product` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

ALTER TABLE `inventory`.`order_item`
ADD INDEX `idx_order_item_item` (`itemId` ASC);
ALTER TABLE `inventory`.`order_item`
ADD CONSTRAINT `fk_order_item_item`
FOREIGN KEY (`itemId`)
REFERENCES `inventory`.`item` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

ALTER TABLE `inventory`.`order_item`
ADD INDEX `idx_order_item_order` (`orderId` ASC);
ALTER TABLE `inventory`.`order_item`
ADD CONSTRAINT `fk_order_item_order`
FOREIGN KEY (`orderId`)
REFERENCES `inventory`.`order` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

Transaction Table

We also need a transaction table to track the order payments made by the buyer and for bookkeeping. We can also use the same table to record the partial or full refund of the order. Below mentioned is the description of all the columns of the Transaction Table.

IdThe unique id to identify the transaction.
User IdThe user id to identify the user associated with the transaction.
Order IdThe order id to identify the order associated with the transaction.
CodeThe payment id provided by the payment gateway.
TypeThe type of order transaction can be either Credit or Debit.
ModeThe mode of the order transaction can be Offline, Cash On Delivery, Cheque, Draft, Wired, and Online.
StatusThe status of the order transaction can be New, Cancelled, Failed, Pending, Declined, Rejected, and Success.
Created AtIt stores the date and time at which the order transaction is created.
Updated AtIt stores the date and time at which the order transaction is updated.
ContentThe column used to store the additional details of the transaction.

The Transaction Table with the appropriate constraints is as shown below.

CREATE TABLE `inventory`.`transaction` (
`id` BIGINT NOT NULL AUTO_INCREMENT,
`userId` BIGINT NOT NULL,
`orderId` BIGINT NOT NULL,
`code` VARCHAR(100) NOT NULL,
`type` SMALLINT(6) NOT NULL DEFAULT 0,
`mode` SMALLINT(6) NOT NULL DEFAULT 0,
`status` SMALLINT(6) NOT NULL DEFAULT 0,
`createdAt` DATETIME NOT NULL,
`updatedAt` DATETIME NULL DEFAULT NULL,
`content` TEXT NULL DEFAULT NULL,
PRIMARY KEY (`id`),
INDEX `idx_transaction_user` (`userId` ASC),
CONSTRAINT `fk_transaction_user`
FOREIGN KEY (`userId`)
REFERENCES `inventory`.`user` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION);

ALTER TABLE `inventory`.`transaction`
ADD INDEX `idx_transaction_order` (`orderId` ASC);
ALTER TABLE `inventory`.`transaction`
ADD CONSTRAINT `fk_transaction_order`
FOREIGN KEY (`orderId`)
REFERENCES `inventory`.`order` (`id`)
ON DELETE NO ACTION
ON UPDATE NO ACTION;

Summary

In this tutorial, we have discussed the database design of an Inventory Management System to store the users and manage product inventory. It also provided the database design to manage the purchase orders and customer orders.

You may submit your comments to join the discussion. You may also be interested in designing the database of the Blog and Poll & Survey applications. The complete database schema is also available on GitHub.

share on :

Profile picture for user bhagwatchouhan
bhagwatchouhan