-- Initialize company setup (companies, statuses, folders) and core user management. -- Designed for multi-tenant applications where each company has isolated data. -- Companies Table: Stores information about each client company. CREATE TABLE IF NOT EXISTS companies ( id INT AUTO_INCREMENT PRIMARY KEY, name VARCHAR(255) NOT NULL UNIQUE, uprn_required BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Job Statuses Table: Stores custom job statuses defined by each company. CREATE TABLE IF NOT EXISTS job_statuses ( id INT AUTO_INCREMENT PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, is_default BOOLEAN DEFAULT FALSE, sort_order INT DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE CASCADE, UNIQUE KEY (company_id, name) ); -- Required Folders Table: Stores mandatory folder structures defined by each company. CREATE TABLE IF NOT EXISTS required_folders ( id INT AUTO_INCREMENT PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE CASCADE, UNIQUE KEY (company_id, name) ); -- Users Table: Stores user accounts. Each user belongs to a specific company. CREATE TABLE IF NOT EXISTS users ( id INT AUTO_INCREMENT PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, email VARCHAR(255) NOT NULL UNIQUE, password VARCHAR(255) NOT NULL, role ENUM('admin', 'standard') DEFAULT 'standard', -- Admin can manage company settings, standard users manage jobs. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE CASCADE ); -- Clients Table: Stores clients for each company. Clients can be added, edited, but not deleted. CREATE TABLE IF NOT EXISTS clients ( id INT AUTO_INCREMENT PRIMARY KEY, company_id INT NOT NULL, name VARCHAR(255) NOT NULL, contact_person VARCHAR(255) DEFAULT NULL, email VARCHAR(255) DEFAULT NULL, phone VARCHAR(255) DEFAULT NULL, is_active BOOLEAN DEFAULT TRUE, -- Clients can be marked inactive instead of deleted. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE CASCADE, UNIQUE KEY (company_id, name) -- Ensure client names are unique per company ); -- Jobs Table: Core entity for the application. CREATE TABLE IF NOT EXISTS jobs ( id INT AUTO_INCREMENT PRIMARY KEY, company_id INT NOT NULL, client_id INT NOT NULL, status_id INT NOT NULL, uprn VARCHAR(255) DEFAULT NULL, -- Unique Property Reference Number address TEXT NOT NULL, description TEXT, works_approved BOOLEAN DEFAULT FALSE, is_completed BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE CASCADE, FOREIGN KEY (client_id) REFERENCES clients(id), FOREIGN KEY (status_id) REFERENCES job_statuses(id) ); -- Job Folders Table: Mandatory and custom folders for each job. CREATE TABLE IF NOT EXISTS job_folders ( id INT AUTO_INCREMENT PRIMARY KEY, job_id INT NOT NULL, name VARCHAR(255) NOT NULL, is_required BOOLEAN DEFAULT FALSE, -- If true, it's a company-wide mandatory folder. is_completed BOOLEAN DEFAULT FALSE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (job_id) REFERENCES jobs(id) ON DELETE CASCADE ); -- Job Files Table: Files uploaded to job folders. CREATE TABLE IF NOT EXISTS job_files ( id INT AUTO_INCREMENT PRIMARY KEY, folder_id INT NOT NULL, user_id INT NOT NULL, filename VARCHAR(255) NOT NULL, file_path VARCHAR(255) NOT NULL, file_size INT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (folder_id) REFERENCES job_folders(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) ); -- Job Logs Table: Server-side logging for all job activities. CREATE TABLE IF NOT EXISTS job_logs ( id INT AUTO_INCREMENT PRIMARY KEY, job_id INT NOT NULL, user_id INT NOT NULL, action VARCHAR(255) NOT NULL, -- e.g., 'created', 'status_updated', 'file_uploaded' details TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (job_id) REFERENCES jobs(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) );