150 lines
5.4 KiB
SQL
150 lines
5.4 KiB
SQL
-- Bunks
|
|
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
|
|
);
|
|
-- 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,
|
|
FOREIGN KEY (bunk_id) REFERENCES bunks(id) ON DELETE SET NULL
|
|
);
|
|
-- Fuel Types
|
|
CREATE TABLE IF NOT EXISTS fuel_types (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
name VARCHAR(50) NOT NULL UNIQUE,
|
|
unit VARCHAR(20) DEFAULT 'Litre'
|
|
);
|
|
-- Tanks
|
|
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,
|
|
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)
|
|
);
|
|
-- Pumps
|
|
CREATE TABLE IF NOT EXISTS pumps (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
bunk_id INT NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (bunk_id) REFERENCES bunks(id) ON DELETE CASCADE
|
|
);
|
|
-- Nozzles (each nozzle belongs to a pump and draws from a tank)
|
|
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,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (pump_id) REFERENCES pumps(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (tank_id) REFERENCES tanks(id) ON DELETE CASCADE
|
|
);
|
|
-- Price History (fuel pricing)
|
|
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
|
|
);
|
|
-- Tank Readings (daily, per tank, unique per date)
|
|
CREATE TABLE IF NOT EXISTS tank_readings (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
tank_id INT NOT NULL,
|
|
date DATE NOT NULL,
|
|
opening DECIMAL(10,2) NOT NULL,
|
|
receipts DECIMAL(10,2) DEFAULT 0,
|
|
closing DECIMAL(10,2) DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE KEY tank_date_unique (tank_id, date),
|
|
FOREIGN KEY (tank_id) REFERENCES tanks(id) ON DELETE CASCADE
|
|
);
|
|
-- Daily Sales (per nozzle)
|
|
CREATE TABLE IF NOT EXISTS day_sales (
|
|
id INT AUTO_INCREMENT PRIMARY KEY,
|
|
nozzle_id INT NOT NULL,
|
|
bunk_id INT NOT NULL,
|
|
date DATE NOT NULL,
|
|
opening_reading DECIMAL(10,2) NOT NULL,
|
|
closing_reading DECIMAL(10,2) NOT NULL,
|
|
testing DECIMAL(10,2) DEFAULT 0,
|
|
net_sale DECIMAL(10,2) GENERATED ALWAYS AS (closing_reading - opening_reading - testing) STORED,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE KEY nozzle_date_unique (nozzle_id, date),
|
|
FOREIGN KEY (nozzle_id) REFERENCES nozzles(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (bunk_id) REFERENCES bunks(id) ON DELETE CASCADE
|
|
);
|
|
-- Fuel Purchases / Receipts
|
|
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)
|
|
);
|
|
-- Credit Customers
|
|
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
|
|
);
|
|
-- Credit Sales
|
|
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)
|
|
);
|
|
-- Expenses
|
|
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
|
|
);
|
|
-- 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 = "password"
|