-- Royal Enfield Workflow Management System Database Schema -- PostgreSQL 16.x -- Generated from ERD_Mermaid.txt -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Create custom types CREATE TYPE priority_type AS ENUM ('STANDARD', 'EXPRESS'); CREATE TYPE workflow_status AS ENUM ('DRAFT', 'PENDING', 'IN_PROGRESS', 'APPROVED', 'REJECTED', 'CLOSED'); CREATE TYPE approval_status AS ENUM ('PENDING', 'IN_PROGRESS', 'APPROVED', 'REJECTED', 'SKIPPED'); CREATE TYPE participant_type AS ENUM ('SPECTATOR', 'INITIATOR', 'APPROVER', 'CONSULTATION'); CREATE TYPE tat_status AS ENUM ('ON_TRACK', 'APPROACHING', 'BREACHED'); CREATE TYPE notification_priority AS ENUM ('LOW', 'MEDIUM', 'HIGH', 'URGENT'); CREATE TYPE document_category AS ENUM ('SUPPORTING', 'APPROVAL', 'REFERENCE', 'FINAL', 'OTHER'); CREATE TYPE work_note_type AS ENUM ('COMMENT', 'QUESTION', 'CLARIFICATION', 'UPDATE', 'SYSTEM'); CREATE TYPE activity_severity AS ENUM ('INFO', 'WARNING', 'ERROR', 'CRITICAL'); CREATE TYPE setting_type AS ENUM ('STRING', 'NUMBER', 'BOOLEAN', 'JSON', 'ARRAY'); -- Users table CREATE TABLE users ( user_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), employee_id VARCHAR(50), -- Optional - HR System Employee ID okta_sub VARCHAR(100) UNIQUE NOT NULL, -- Okta subject identifier (unique) email VARCHAR(255) UNIQUE NOT NULL, -- Primary identifier for user lookup first_name VARCHAR(100), -- Optional last_name VARCHAR(100), -- Optional display_name VARCHAR(200), -- Optional department VARCHAR(100), designation VARCHAR(100), phone VARCHAR(20), location JSONB, is_active BOOLEAN DEFAULT true, is_admin BOOLEAN DEFAULT false, last_login TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Workflow Requests table CREATE TABLE workflow_requests ( request_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_number VARCHAR(20) UNIQUE NOT NULL, initiator_id UUID NOT NULL REFERENCES users(user_id), template_type VARCHAR(20) DEFAULT 'CUSTOM', title VARCHAR(500) NOT NULL, description TEXT NOT NULL, priority priority_type DEFAULT 'STANDARD', status workflow_status DEFAULT 'DRAFT', current_level INTEGER DEFAULT 1, total_levels INTEGER DEFAULT 1 CHECK (total_levels <= 10), total_tat_hours DECIMAL(10,2) DEFAULT 0, submission_date TIMESTAMP WITH TIME ZONE, closure_date TIMESTAMP WITH TIME ZONE, conclusion_remark TEXT, ai_generated_conclusion TEXT, is_draft BOOLEAN DEFAULT true, is_deleted BOOLEAN DEFAULT false, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Approval Levels table CREATE TABLE approval_levels ( level_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, level_number INTEGER NOT NULL, level_name VARCHAR(100), approver_id UUID NOT NULL REFERENCES users(user_id), approver_email VARCHAR(255) NOT NULL, approver_name VARCHAR(200) NOT NULL, tat_hours DECIMAL(10,2) NOT NULL, tat_days INTEGER GENERATED ALWAYS AS (CEIL(tat_hours / 24)) STORED, status approval_status DEFAULT 'PENDING', level_start_time TIMESTAMP WITH TIME ZONE, level_end_time TIMESTAMP WITH TIME ZONE, action_date TIMESTAMP WITH TIME ZONE, comments TEXT, rejection_reason TEXT, is_final_approver BOOLEAN DEFAULT false, elapsed_hours DECIMAL(10,2) DEFAULT 0, remaining_hours DECIMAL(10,2) GENERATED ALWAYS AS (GREATEST(0, tat_hours - elapsed_hours)) STORED, tat_percentage_used DECIMAL(5,2) GENERATED ALWAYS AS (LEAST(100, (elapsed_hours / NULLIF(tat_hours, 0)) * 100)) STORED, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, UNIQUE(request_id, level_number) ); -- Participants table CREATE TABLE participants ( participant_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(user_id), user_email VARCHAR(255) NOT NULL, user_name VARCHAR(200) NOT NULL, participant_type participant_type NOT NULL, can_comment BOOLEAN DEFAULT true, can_view_documents BOOLEAN DEFAULT true, can_download_documents BOOLEAN DEFAULT false, notification_enabled BOOLEAN DEFAULT true, added_by UUID NOT NULL REFERENCES users(user_id), added_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT true, UNIQUE(request_id, user_id) ); -- Documents table CREATE TABLE documents ( document_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, uploaded_by UUID NOT NULL REFERENCES users(user_id), file_name VARCHAR(255) NOT NULL, original_file_name VARCHAR(255) NOT NULL, file_type VARCHAR(100) NOT NULL, file_extension VARCHAR(10) NOT NULL, file_size BIGINT NOT NULL CHECK (file_size <= 10485760), -- 10MB limit file_path VARCHAR(500) NOT NULL, storage_url VARCHAR(500), mime_type VARCHAR(100) NOT NULL, checksum VARCHAR(64) NOT NULL, is_google_doc BOOLEAN DEFAULT false, google_doc_url VARCHAR(500), category document_category DEFAULT 'OTHER', version INTEGER DEFAULT 1, parent_document_id UUID REFERENCES documents(document_id), is_deleted BOOLEAN DEFAULT false, download_count INTEGER DEFAULT 0, uploaded_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Work Notes table CREATE TABLE work_notes ( note_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(user_id), user_name VARCHAR(200) NOT NULL, user_role VARCHAR(50) NOT NULL, message TEXT NOT NULL CHECK (LENGTH(message) <= 2000), message_type work_note_type DEFAULT 'COMMENT', is_priority BOOLEAN DEFAULT false, has_attachment BOOLEAN DEFAULT false, parent_note_id UUID REFERENCES work_notes(note_id), mentioned_users UUID[], reactions JSONB DEFAULT '{}', is_edited BOOLEAN DEFAULT false, is_deleted BOOLEAN DEFAULT false, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Work Note Attachments table CREATE TABLE work_note_attachments ( attachment_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), note_id UUID NOT NULL REFERENCES work_notes(note_id) ON DELETE CASCADE, file_name VARCHAR(255) NOT NULL, file_type VARCHAR(100) NOT NULL, file_size BIGINT NOT NULL, file_path VARCHAR(500) NOT NULL, storage_url VARCHAR(500), is_downloadable BOOLEAN DEFAULT true, download_count INTEGER DEFAULT 0, uploaded_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Activities table CREATE TABLE activities ( activity_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID REFERENCES workflow_requests(request_id) ON DELETE CASCADE, user_id UUID REFERENCES users(user_id), user_name VARCHAR(200), activity_type VARCHAR(100) NOT NULL, activity_description TEXT NOT NULL, activity_category VARCHAR(50), severity activity_severity DEFAULT 'INFO', metadata JSONB DEFAULT '{}', is_system_event BOOLEAN DEFAULT false, ip_address INET, user_agent TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Notifications table CREATE TABLE notifications ( notification_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(user_id), request_id UUID REFERENCES workflow_requests(request_id) ON DELETE CASCADE, notification_type VARCHAR(100) NOT NULL, title VARCHAR(200) NOT NULL, message TEXT NOT NULL, is_read BOOLEAN DEFAULT false, priority notification_priority DEFAULT 'MEDIUM', action_url VARCHAR(500), action_required BOOLEAN DEFAULT false, metadata JSONB DEFAULT '{}', sent_via VARCHAR(20)[] DEFAULT '{"IN_APP"}', email_sent BOOLEAN DEFAULT false, sms_sent BOOLEAN DEFAULT false, push_sent BOOLEAN DEFAULT false, read_at TIMESTAMP WITH TIME ZONE, expires_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- TAT Tracking table CREATE TABLE tat_tracking ( tracking_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, level_id UUID REFERENCES approval_levels(level_id) ON DELETE CASCADE, tracking_type VARCHAR(20) NOT NULL CHECK (tracking_type IN ('REQUEST', 'LEVEL')), tat_status tat_status DEFAULT 'ON_TRACK', total_tat_hours DECIMAL(10,2) NOT NULL, elapsed_hours DECIMAL(10,2) DEFAULT 0, remaining_hours DECIMAL(10,2) GENERATED ALWAYS AS (GREATEST(0, total_tat_hours - elapsed_hours)) STORED, percentage_used DECIMAL(5,2) GENERATED ALWAYS AS (LEAST(100, (elapsed_hours / NULLIF(total_tat_hours, 0)) * 100)) STORED, threshold_50_breached BOOLEAN DEFAULT false, threshold_50_alerted_at TIMESTAMP WITH TIME ZONE, threshold_80_breached BOOLEAN DEFAULT false, threshold_80_alerted_at TIMESTAMP WITH TIME ZONE, threshold_100_breached BOOLEAN DEFAULT false, threshold_100_alerted_at TIMESTAMP WITH TIME ZONE, alert_count INTEGER DEFAULT 0, last_calculated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Conclusion Remarks table CREATE TABLE conclusion_remarks ( conclusion_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID NOT NULL REFERENCES workflow_requests(request_id) ON DELETE CASCADE, ai_generated_remark TEXT, ai_model_used VARCHAR(50), ai_confidence_score DECIMAL(3,2) CHECK (ai_confidence_score >= 0 AND ai_confidence_score <= 1), final_remark TEXT, edited_by UUID REFERENCES users(user_id), is_edited BOOLEAN DEFAULT false, edit_count INTEGER DEFAULT 0, approval_summary JSONB DEFAULT '{}', document_summary JSONB DEFAULT '{}', key_discussion_points TEXT[], generated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, finalized_at TIMESTAMP WITH TIME ZONE ); -- Audit Logs table CREATE TABLE audit_logs ( audit_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(user_id), entity_type VARCHAR(100) NOT NULL, entity_id UUID NOT NULL, action VARCHAR(50) NOT NULL, action_category VARCHAR(50), old_values JSONB, new_values JSONB, changes_summary TEXT, ip_address INET, user_agent TEXT, session_id VARCHAR(255), request_method VARCHAR(10), request_url VARCHAR(500), response_status INTEGER, execution_time_ms INTEGER, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- User Sessions table CREATE TABLE user_sessions ( session_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(user_id), session_token VARCHAR(500) UNIQUE NOT NULL, refresh_token VARCHAR(500) UNIQUE, ip_address INET, user_agent TEXT, device_type VARCHAR(20) DEFAULT 'WEB', browser VARCHAR(50), os VARCHAR(50), login_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_activity_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, logout_at TIMESTAMP WITH TIME ZONE, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, is_active BOOLEAN DEFAULT true, logout_reason VARCHAR(100) ); -- Email Logs table CREATE TABLE email_logs ( email_log_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID REFERENCES workflow_requests(request_id) ON DELETE CASCADE, notification_id UUID REFERENCES notifications(notification_id) ON DELETE CASCADE, recipient_email VARCHAR(255) NOT NULL, recipient_user_id UUID REFERENCES users(user_id), cc_emails TEXT[], bcc_emails TEXT[], subject VARCHAR(500) NOT NULL, body TEXT NOT NULL, email_type VARCHAR(50), status VARCHAR(20) DEFAULT 'QUEUED', send_attempts INTEGER DEFAULT 0, sent_at TIMESTAMP WITH TIME ZONE, failed_at TIMESTAMP WITH TIME ZONE, failure_reason TEXT, opened_at TIMESTAMP WITH TIME ZONE, clicked_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- SMS Logs table CREATE TABLE sms_logs ( sms_log_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), request_id UUID REFERENCES workflow_requests(request_id) ON DELETE CASCADE, notification_id UUID REFERENCES notifications(notification_id) ON DELETE CASCADE, recipient_phone VARCHAR(20) NOT NULL, recipient_user_id UUID REFERENCES users(user_id), message TEXT NOT NULL, sms_type VARCHAR(50), status VARCHAR(20) DEFAULT 'QUEUED', send_attempts INTEGER DEFAULT 0, sent_at TIMESTAMP WITH TIME ZONE, delivered_at TIMESTAMP WITH TIME ZONE, failed_at TIMESTAMP WITH TIME ZONE, failure_reason TEXT, sms_provider VARCHAR(50), sms_provider_message_id VARCHAR(100), cost DECIMAL(10,4), created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- System Settings table CREATE TABLE system_settings ( setting_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), setting_key VARCHAR(100) UNIQUE NOT NULL, setting_value TEXT NOT NULL, setting_type setting_type NOT NULL, setting_category VARCHAR(50), description TEXT, is_editable BOOLEAN DEFAULT true, is_sensitive BOOLEAN DEFAULT false, validation_rules JSONB, default_value TEXT, updated_by UUID REFERENCES users(user_id), created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Workflow Templates table CREATE TABLE workflow_templates ( template_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), template_name VARCHAR(200) NOT NULL, template_description TEXT, template_category VARCHAR(100), approval_levels_config JSONB NOT NULL, default_tat_hours DECIMAL(10,2) DEFAULT 24, is_active BOOLEAN DEFAULT true, usage_count INTEGER DEFAULT 0, created_by UUID NOT NULL REFERENCES users(user_id), created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Report Cache table CREATE TABLE report_cache ( cache_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), report_type VARCHAR(100) NOT NULL, report_params JSONB NOT NULL, report_data JSONB NOT NULL, generated_by UUID NOT NULL REFERENCES users(user_id), generated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, access_count INTEGER DEFAULT 0, last_accessed_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for better performance CREATE INDEX idx_users_employee_id ON users(employee_id); CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_users_active ON users(is_active); CREATE INDEX idx_workflow_requests_initiator ON workflow_requests(initiator_id); CREATE INDEX idx_workflow_requests_status ON workflow_requests(status); CREATE INDEX idx_workflow_requests_number ON workflow_requests(request_number); CREATE INDEX idx_workflow_requests_created ON workflow_requests(created_at); CREATE INDEX idx_approval_levels_request ON approval_levels(request_id); CREATE INDEX idx_approval_levels_approver ON approval_levels(approver_id); CREATE INDEX idx_approval_levels_status ON approval_levels(status); CREATE INDEX idx_participants_request ON participants(request_id); CREATE INDEX idx_participants_user ON participants(user_id); CREATE INDEX idx_participants_type ON participants(participant_type); CREATE INDEX idx_documents_request ON documents(request_id); CREATE INDEX idx_documents_uploader ON documents(uploaded_by); CREATE INDEX idx_documents_category ON documents(category); CREATE INDEX idx_work_notes_request ON work_notes(request_id); CREATE INDEX idx_work_notes_user ON work_notes(user_id); CREATE INDEX idx_work_notes_parent ON work_notes(parent_note_id); CREATE INDEX idx_activities_request ON activities(request_id); CREATE INDEX idx_activities_user ON activities(user_id); CREATE INDEX idx_activities_type ON activities(activity_type); CREATE INDEX idx_activities_created ON activities(created_at); CREATE INDEX idx_notifications_user ON notifications(user_id); CREATE INDEX idx_notifications_request ON notifications(request_id); CREATE INDEX idx_notifications_read ON notifications(is_read); CREATE INDEX idx_notifications_type ON notifications(notification_type); CREATE INDEX idx_tat_tracking_request ON tat_tracking(request_id); CREATE INDEX idx_tat_tracking_level ON tat_tracking(level_id); CREATE INDEX idx_tat_tracking_status ON tat_tracking(tat_status); CREATE INDEX idx_audit_logs_user ON audit_logs(user_id); CREATE INDEX idx_audit_logs_entity ON audit_logs(entity_type, entity_id); CREATE INDEX idx_audit_logs_created ON audit_logs(created_at); CREATE INDEX idx_user_sessions_user ON user_sessions(user_id); CREATE INDEX idx_user_sessions_token ON user_sessions(session_token); CREATE INDEX idx_user_sessions_active ON user_sessions(is_active); -- Create triggers for updated_at timestamps CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_workflow_requests_updated_at BEFORE UPDATE ON workflow_requests FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_approval_levels_updated_at BEFORE UPDATE ON approval_levels FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_work_notes_updated_at BEFORE UPDATE ON work_notes FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_system_settings_updated_at BEFORE UPDATE ON system_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_workflow_templates_updated_at BEFORE UPDATE ON workflow_templates FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();