38348-vm/db/schema.sql
2026-02-11 01:46:33 +00:00

138 lines
6.1 KiB
SQL

-- CRM Database Schema - Migration Ready for Laravel 10
-- Charset: utf8mb4, Engine: InnoDB
-- Users Table
CREATE TABLE IF NOT EXISTS users (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
username VARCHAR(50) NOT NULL UNIQUE,
password VARCHAR(255) NOT NULL,
full_name VARCHAR(100) NOT NULL,
role ENUM('Admin', 'Sales', 'Finance') NOT NULL DEFAULT 'Sales',
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL DEFAULT NULL,
INDEX idx_users_username (username),
INDEX idx_users_role (role)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Customers Table
CREATE TABLE IF NOT EXISTS customers (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(255) NOT NULL,
email VARCHAR(255),
phone VARCHAR(50),
address TEXT,
category VARCHAR(100),
status ENUM('Prospect', 'Active', 'Inactive') NOT NULL DEFAULT 'Prospect',
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL DEFAULT NULL,
INDEX idx_customers_email (email),
INDEX idx_customers_status (status),
INDEX idx_customers_deleted_at (deleted_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Products Table
CREATE TABLE IF NOT EXISTS products (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(255) NOT NULL,
description TEXT,
price DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL DEFAULT NULL,
INDEX idx_products_name (name),
INDEX idx_products_deleted_at (deleted_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Quotations Table
CREATE TABLE IF NOT EXISTS quotations (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
quotation_number VARCHAR(50) NOT NULL UNIQUE,
customer_id BIGINT UNSIGNED NOT NULL,
user_id BIGINT UNSIGNED NOT NULL,
issue_date DATE NOT NULL,
expiry_date DATE NOT NULL,
status ENUM('Draft', 'Sent', 'Approved', 'Rejected') NOT NULL DEFAULT 'Draft',
subtotal DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
tax_amount DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
total_amount DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
notes TEXT,
last_reminded_at TIMESTAMP NULL DEFAULT NULL,
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL DEFAULT NULL,
INDEX idx_quotations_customer_id (customer_id),
INDEX idx_quotations_user_id (user_id),
INDEX idx_quotations_status (status),
INDEX idx_quotations_expiry_date (expiry_date),
FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE CASCADE,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Quotation Items Table
CREATE TABLE IF NOT EXISTS quotation_items (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
quotation_id BIGINT UNSIGNED NOT NULL,
product_id BIGINT UNSIGNED NOT NULL,
quantity DECIMAL(10, 2) NOT NULL DEFAULT 1.00,
unit_price DECIMAL(15, 2) NOT NULL,
discount_amount DECIMAL(15, 2) DEFAULT 0.00,
total_price DECIMAL(15, 2) NOT NULL,
FOREIGN KEY (quotation_id) REFERENCES quotations(id) ON DELETE CASCADE,
FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Invoices Table
CREATE TABLE IF NOT EXISTS invoices (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
invoice_number VARCHAR(50) NOT NULL UNIQUE,
quotation_id BIGINT UNSIGNED DEFAULT NULL,
customer_id BIGINT UNSIGNED NOT NULL,
user_id BIGINT UNSIGNED NOT NULL,
issue_date DATE NOT NULL,
due_date DATE NOT NULL,
status ENUM('Unpaid', 'Partial', 'Paid', 'Overdue') NOT NULL DEFAULT 'Unpaid',
subtotal DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
tax_amount DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
total_amount DECIMAL(15, 2) NOT NULL DEFAULT 0.00,
payment_proof VARCHAR(255) DEFAULT NULL,
notes TEXT,
last_reminded_at TIMESTAMP NULL DEFAULT NULL,
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
deleted_at TIMESTAMP NULL DEFAULT NULL,
INDEX idx_invoices_customer_id (customer_id),
INDEX idx_invoices_status (status),
INDEX idx_invoices_due_date (due_date),
FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE CASCADE,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY (quotation_id) REFERENCES quotations(id) ON DELETE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Invoice Items Table
CREATE TABLE IF NOT EXISTS invoice_items (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
invoice_id BIGINT UNSIGNED NOT NULL,
product_id BIGINT UNSIGNED NOT NULL,
quantity DECIMAL(10, 2) NOT NULL DEFAULT 1.00,
unit_price DECIMAL(15, 2) NOT NULL,
discount_amount DECIMAL(15, 2) DEFAULT 0.00,
total_price DECIMAL(15, 2) NOT NULL,
FOREIGN KEY (invoice_id) REFERENCES invoices(id) ON DELETE CASCADE,
FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Audit Logs Table
CREATE TABLE IF NOT EXISTS audit_logs (
id BIGINT UNSIGNED AUTO_INCREMENT PRIMARY KEY,
user_id BIGINT UNSIGNED,
action VARCHAR(100) NOT NULL,
entity_type VARCHAR(50) NOT NULL,
entity_id BIGINT UNSIGNED NOT NULL,
details TEXT,
created_at TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
INDEX idx_audit_logs_user_id (user_id),
INDEX idx_audit_logs_entity (entity_type, entity_id),
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;