-- Migration: Create custom fields tables -- Description: Enables custom field definitions per category and stores field values -- Custom field definitions CREATE TABLE IF NOT EXISTS custom_field_definitions ( field_id INT AUTO_INCREMENT PRIMARY KEY, field_name VARCHAR(100) NOT NULL, field_label VARCHAR(255) NOT NULL, field_type ENUM('text', 'textarea', 'select', 'checkbox', 'date', 'number') NOT NULL, field_options JSON NULL COMMENT 'Options for select fields: {"options": ["Option 1", "Option 2"]}', category VARCHAR(50) NULL COMMENT 'NULL = applies to all categories', is_required BOOLEAN DEFAULT FALSE, display_order INT DEFAULT 0, is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, INDEX idx_custom_fields_category (category, is_active), INDEX idx_custom_fields_order (display_order) ); -- Custom field values for tickets CREATE TABLE IF NOT EXISTS custom_field_values ( value_id INT AUTO_INCREMENT PRIMARY KEY, ticket_id VARCHAR(9) NOT NULL, field_id INT NOT NULL, field_value TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, UNIQUE KEY unique_ticket_field (ticket_id, field_id), FOREIGN KEY (field_id) REFERENCES custom_field_definitions(field_id) ON DELETE CASCADE, INDEX idx_custom_values_ticket (ticket_id) ); -- Sample custom field definitions (commented out) -- INSERT INTO custom_field_definitions (field_name, field_label, field_type, category, is_required) -- VALUES -- ('affected_server', 'Affected Server', 'text', 'Hardware', false), -- ('incident_date', 'Incident Date', 'date', 'Security', true), -- ('software_version', 'Software Version', 'text', 'Software', false);