-- Initial Schema for Petrol Bunk Management System -- Users and Roles CREATE TABLE IF NOT EXISTS `users` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(100) NOT NULL, `email` VARCHAR(100) NOT NULL UNIQUE, `password` VARCHAR(255) NOT NULL, `role` ENUM('Superadmin', 'Manager', 'Attendant', 'Accountant') NOT NULL, `bunk_id` INT, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Master Data CREATE TABLE IF NOT EXISTS `bunks` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, `owner` VARCHAR(255), `contact` VARCHAR(50), `location` TEXT, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS `fuel_types` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(50) NOT NULL UNIQUE, `unit` VARCHAR(20) DEFAULT 'Litre' ); CREATE TABLE IF NOT EXISTS `tanks` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(100) NOT NULL, `bunk_id` INT NOT NULL, `fuel_type_id` INT NOT NULL, `capacity` DECIMAL(10, 2) NOT NULL, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE, FOREIGN KEY (`fuel_type_id`) REFERENCES `fuel_types`(`id`) ); CREATE TABLE IF NOT EXISTS `pumps` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(100) NOT NULL, `bunk_id` INT NOT NULL, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS `nozzles` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(100) NOT NULL, `pump_id` INT NOT NULL, `tank_id` INT NOT NULL, FOREIGN KEY (`pump_id`) REFERENCES `pumps`(`id`) ON DELETE CASCADE, FOREIGN KEY (`tank_id`) REFERENCES `tanks`(`id`) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS `price_history` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `fuel_type_id` INT NOT NULL, `bunk_id` INT NOT NULL, `price` DECIMAL(10, 2) NOT NULL, `date` DATE NOT NULL, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE KEY `bunk_fuel_date` (`bunk_id`, `fuel_type_id`, `date`), FOREIGN KEY (`fuel_type_id`) REFERENCES `fuel_types`(`id`), FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); -- Daily Operations CREATE TABLE IF NOT EXISTS `daybook` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `bunk_id` INT NOT NULL, `nozzle_id` INT NOT NULL, `date` DATE NOT NULL, `opening_reading` DECIMAL(10, 2) NOT NULL, `closing_reading` DECIMAL(10, 2), `testing` DECIMAL(10, 2) DEFAULT 0, `sale` DECIMAL(10, 2) GENERATED ALWAYS AS (closing_reading - opening_reading - testing) STORED, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE KEY `bunk_nozzle_date` (`bunk_id`, `nozzle_id`, `date`), FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE, FOREIGN KEY (`nozzle_id`) REFERENCES `nozzles`(`id`) ON DELETE CASCADE ); -- Credit Sales CREATE TABLE IF NOT EXISTS `credit_customers` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, `contact` VARCHAR(50), `bunk_id` INT NOT NULL, `credit_limit` DECIMAL(10, 2) DEFAULT 0, `outstanding_balance` DECIMAL(10, 2) DEFAULT 0, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS `credit_sales` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `bunk_id` INT NOT NULL, `customer_id` INT NOT NULL, `date` DATE NOT NULL, `fuel_type_id` INT NOT NULL, `quantity` DECIMAL(10, 2) NOT NULL, `rate` DECIMAL(10, 2) NOT NULL, `amount` DECIMAL(10, 2) NOT NULL, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE, FOREIGN KEY (`customer_id`) REFERENCES `credit_customers`(`id`), FOREIGN KEY (`fuel_type_id`) REFERENCES `fuel_types`(`id`) ); -- Receipts and Expenses CREATE TABLE IF NOT EXISTS `fuel_receipts` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `bunk_id` INT NOT NULL, `supplier` VARCHAR(255), `invoice_number` VARCHAR(100), `fuel_type_id` INT NOT NULL, `quantity` DECIMAL(10, 2) NOT NULL, `rate` DECIMAL(10, 2) NOT NULL, `amount` DECIMAL(10, 2) NOT NULL, `date` DATE NOT NULL, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE, FOREIGN KEY (`fuel_type_id`) REFERENCES `fuel_types`(`id`) ); CREATE TABLE IF NOT EXISTS `expenses` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `bunk_id` INT NOT NULL, `category` VARCHAR(100) NOT NULL, `amount` DECIMAL(10, 2) NOT NULL, `description` TEXT, `payment_mode` VARCHAR(50), `date` DATE NOT NULL, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); -- Product & Stock CREATE TABLE IF NOT EXISTS `products` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, `category` VARCHAR(100), `price` DECIMAL(10, 2) NOT NULL, `bunk_id` INT NOT NULL, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS `stock` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `product_id` INT NOT NULL, `date` DATE NOT NULL, `opening_stock` INT NOT NULL, `sales` INT DEFAULT 0, `closing_stock` INT GENERATED ALWAYS AS (opening_stock - sales) STORED, `bunk_id` INT NOT NULL, UNIQUE KEY `bunk_product_date` (`bunk_id`, `product_id`, `date`), FOREIGN KEY (`product_id`) REFERENCES `products`(`id`) ON DELETE CASCADE, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); -- Accounts CREATE TABLE IF NOT EXISTS `accounts` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `name` VARCHAR(255) NOT NULL, `type` ENUM('Owner', 'Bank', 'OD', 'Supplier', 'Customer', 'Cash') NOT NULL, `bunk_id` INT NOT NULL, `balance` DECIMAL(12, 2) DEFAULT 0, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS `transactions` ( `id` INT AUTO_INCREMENT PRIMARY KEY, `bunk_id` INT NOT NULL, `date` DATE NOT NULL, `account_id` INT NOT NULL, `type` ENUM('Debit', 'Credit') NOT NULL, `amount` DECIMAL(10, 2) NOT NULL, `description` TEXT, `related_entity_type` VARCHAR(50), -- e.g., 'credit_sale', 'expense', 'fuel_receipt' `related_entity_id` INT, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`bunk_id`) REFERENCES `bunks`(`id`) ON DELETE CASCADE, FOREIGN KEY (`account_id`) REFERENCES `accounts`(`id`) ); -- Add a superadmin user INSERT IGNORE INTO `users` (`name`, `email`, `password`, `role`) VALUES ('Superadmin', 'admin@example.com', '$2y$10$92IXUNpkjO0rOQ5byMi.Ye4oKoEa3Ro9llC/.og/at2.uheWG/igi', 'Superadmin'); -- password is "password"