-- Auto-generated consolidated deployment SQL based on candidb_dump1 DROP DATABASE IF EXISTS candidb_main; CREATE DATABASE IF NOT EXISTS `candidb_main` CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; USE `candidb_main`; -- Core tables (ordered by dependencies) -- users CREATE TABLE `users` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `email` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, `password_hash` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, `first_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `last_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `role` enum('admin','recruiter') COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'recruiter', `company_name` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `avatar_url` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `is_active` tinyint(1) DEFAULT '1', `last_login_at` timestamp NULL DEFAULT NULL, `email_verified_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, PRIMARY KEY (`id`), UNIQUE KEY `email` (`email`), KEY `idx_email` (`email`), KEY `idx_role` (`role`), KEY `idx_active` (`is_active`), KEY `idx_role_active` (`role`,`is_active`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- token_packages CREATE TABLE `token_packages` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `description` text COLLATE utf8mb4_unicode_ci, `quantity` int NOT NULL, `price_per_token` decimal(10,2) NOT NULL, `total_price` decimal(10,2) NOT NULL, `discount_percentage` decimal(5,2) DEFAULT '0.00', `is_popular` tinyint(1) DEFAULT '0', `is_active` tinyint(1) DEFAULT '1', `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), CONSTRAINT `chk_token_packages_discount_valid` CHECK (((`discount_percentage` >= 0) and (`discount_percentage` <= 100))), CONSTRAINT `chk_token_packages_price_positive` CHECK ((`price_per_token` > 0)), CONSTRAINT `chk_token_packages_quantity_positive` CHECK ((`quantity` > 0)) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- jobs CREATE TABLE `jobs` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `title` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, `description` text COLLATE utf8mb4_unicode_ci NOT NULL, `requirements` text COLLATE utf8mb4_unicode_ci NOT NULL, `skills_required` json DEFAULT NULL, `location` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `employment_type` enum('full_time','part_time','contract','internship') COLLATE utf8mb4_unicode_ci DEFAULT 'full_time', `experience_level` enum('entry','mid','senior','lead','executive') COLLATE utf8mb4_unicode_ci DEFAULT 'mid', `salary_min` decimal(10,2) DEFAULT NULL, `salary_max` decimal(10,2) DEFAULT NULL, `currency` varchar(3) COLLATE utf8mb4_unicode_ci DEFAULT 'USD', `status` enum('draft','active','paused','closed') COLLATE utf8mb4_unicode_ci DEFAULT 'draft', `evaluation_criteria` json DEFAULT NULL, `interview_questions` json DEFAULT NULL, `interview_style` enum('personal','balanced','technical') COLLATE utf8mb4_unicode_ci DEFAULT 'balanced', `application_deadline` timestamp NULL DEFAULT NULL, `icon` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT 'briefcase', `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, `deleted_at` timestamp NULL DEFAULT NULL, PRIMARY KEY (`id`), KEY `idx_user_status` (`user_id`,`status`), KEY `idx_created_at` (`created_at`), KEY `idx_jobs_user_status_created` (`user_id`,`status`,`created_at` DESC), CONSTRAINT `jobs_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- candidates CREATE TABLE `candidates` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `job_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `email` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, `first_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `last_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `phone` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `resume_url` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `cover_letter` text COLLATE utf8mb4_unicode_ci, `source` varchar(100) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `status` enum('applied','interviewing','evaluated','hired','rejected') COLLATE utf8mb4_unicode_ci DEFAULT 'applied', `applied_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `last_activity_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, `deleted_at` timestamp NULL DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE KEY `unique_candidate_per_job` (`job_id`,`email`), KEY `idx_user_job` (`user_id`,`job_id`), KEY `idx_status` (`status`), KEY `idx_candidates_user_job_status` (`user_id`,`job_id`,`status`), CONSTRAINT `candidates_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `candidates_ibfk_2` FOREIGN KEY (`job_id`) REFERENCES `jobs` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- interviews CREATE TABLE `interviews` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `candidate_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `job_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `token` varchar(64) COLLATE utf8mb4_unicode_ci NOT NULL, `status` enum('scheduled','in_progress','completed','abandoned') COLLATE utf8mb4_unicode_ci DEFAULT 'scheduled', `started_at` timestamp NULL DEFAULT NULL, `completed_at` timestamp NULL DEFAULT NULL, `duration_minutes` int DEFAULT '0', `ai_questions` json DEFAULT NULL, `candidate_responses` json DEFAULT NULL, `ai_evaluation` json DEFAULT NULL, `overall_score` decimal(5,2) DEFAULT NULL, `technical_score` decimal(5,2) DEFAULT NULL, `communication_score` decimal(5,2) DEFAULT NULL, `culture_fit_score` decimal(5,2) DEFAULT NULL, `ai_feedback` text COLLATE utf8mb4_unicode_ci, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), UNIQUE KEY `token` (`token`), KEY `candidate_id` (`candidate_id`), KEY `job_id` (`job_id`), KEY `idx_token` (`token`), KEY `idx_user_candidate` (`user_id`,`candidate_id`), KEY `idx_status` (`status`), KEY `idx_interviews_user_status` (`user_id`,`status`), KEY `idx_interviews_token_status` (`token`,`status`), CONSTRAINT `interviews_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `interviews_ibfk_2` FOREIGN KEY (`candidate_id`) REFERENCES `candidates` (`id`) ON DELETE CASCADE, CONSTRAINT `interviews_ibfk_3` FOREIGN KEY (`job_id`) REFERENCES `jobs` (`id`) ON DELETE CASCADE, CONSTRAINT `chk_scores_valid` CHECK ((((`overall_score` is null) or ((`overall_score` >= 0) and (`overall_score` <= 100))) and ((`technical_score` is null) or ((`technical_score` >= 0) and (`technical_score` <= 100))) and ((`communication_score` is null) or ((`communication_score` >= 0) and (`communication_score` <= 100))) and ((`culture_fit_score` is null) or ((`culture_fit_score` >= 0) and (`culture_fit_score` <= 100))))) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- interview_questions CREATE TABLE `interview_questions` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `interview_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `question_text` text COLLATE utf8mb4_unicode_ci NOT NULL, `question_type` enum('technical','behavioral','situational','culture_fit') COLLATE utf8mb4_unicode_ci NOT NULL, `difficulty_level` enum('easy','medium','hard') COLLATE utf8mb4_unicode_ci DEFAULT 'medium', `expected_answer` text COLLATE utf8mb4_unicode_ci, `evaluation_criteria` json DEFAULT NULL, `order_index` int NOT NULL, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_interview_order` (`interview_id`,`order_index`), CONSTRAINT `interview_questions_ibfk_1` FOREIGN KEY (`interview_id`) REFERENCES `interviews` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- candidate_responses CREATE TABLE `candidate_responses` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `interview_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `question_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `response_text` text COLLATE utf8mb4_unicode_ci NOT NULL, `response_audio_url` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `ai_score` decimal(5,2) DEFAULT NULL, `ai_feedback` text COLLATE utf8mb4_unicode_ci, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), UNIQUE KEY `unique_response_per_question` (`interview_id`,`question_id`), KEY `question_id` (`question_id`), CONSTRAINT `candidate_responses_ibfk_1` FOREIGN KEY (`interview_id`) REFERENCES `interviews` (`id`) ON DELETE CASCADE, CONSTRAINT `candidate_responses_ibfk_2` FOREIGN KEY (`question_id`) REFERENCES `interview_questions` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- interview_tokens CREATE TABLE `interview_tokens` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `token_type` enum('single','bulk') COLLATE utf8mb4_unicode_ci NOT NULL, `quantity` int NOT NULL DEFAULT '1', `price_per_token` decimal(10,2) NOT NULL, `total_price` decimal(10,2) NOT NULL, `tokens_used` int DEFAULT '0', `tokens_remaining` int GENERATED ALWAYS AS ((`quantity` - `tokens_used`)) STORED, `status` enum('active','exhausted','expired') COLLATE utf8mb4_unicode_ci DEFAULT 'active', `expires_at` timestamp NULL DEFAULT NULL, `purchased_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_user_status` (`user_id`,`status`), KEY `idx_expires_at` (`expires_at`), KEY `idx_interview_tokens_user_active` (`user_id`,`status`), CONSTRAINT `interview_tokens_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `chk_interview_tokens_quantity_positive` CHECK ((`quantity` > 0)), CONSTRAINT `chk_interview_tokens_used_valid` CHECK (((`tokens_used` >= 0) and (`tokens_used` <= `quantity`))) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- payment_records CREATE TABLE `payment_records` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `token_package_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `amount` decimal(10,2) NOT NULL, `currency` varchar(3) COLLATE utf8mb4_unicode_ci DEFAULT 'USD', `status` enum('pending','paid','failed','refunded','cancelled') COLLATE utf8mb4_unicode_ci DEFAULT 'pending', `payment_method` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `payment_reference` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `invoice_url` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `paid_at` timestamp NULL DEFAULT NULL, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `token_package_id` (`token_package_id`), KEY `idx_user_status` (`user_id`,`status`), KEY `idx_payment_reference` (`payment_reference`), KEY `idx_payment_records_user_created` (`user_id`,`created_at` DESC), CONSTRAINT `payment_records_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `payment_records_ibfk_2` FOREIGN KEY (`token_package_id`) REFERENCES `token_packages` (`id`) ON DELETE RESTRICT ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- user_usage CREATE TABLE `user_usage` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `jobs_created` int DEFAULT '0', `interviews_completed` int DEFAULT '0', `tokens_purchased` int DEFAULT '0', `tokens_used` int DEFAULT '0', `last_reset_date` date DEFAULT (curdate()), `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), UNIQUE KEY `unique_user_usage` (`user_id`), CONSTRAINT `user_usage_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE, CONSTRAINT `chk_usage_positive` CHECK (((`jobs_created` >= 0) and (`interviews_completed` >= 0) and (`tokens_purchased` >= 0) and (`tokens_used` >= 0))) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- audit_logs CREATE TABLE `audit_logs` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `user_id` varchar(36) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `action` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, `resource_type` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL, `resource_id` varchar(36) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `old_values` json DEFAULT NULL, `new_values` json DEFAULT NULL, `ip_address` varchar(45) COLLATE utf8mb4_unicode_ci DEFAULT NULL, `user_agent` text COLLATE utf8mb4_unicode_ci, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_user_action` (`user_id`,`action`), KEY `idx_resource` (`resource_type`,`resource_id`), KEY `idx_created_at` (`created_at`), CONSTRAINT `audit_logs_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- job_links CREATE TABLE `job_links` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `job_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `url_slug` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL, `tokens_available` int DEFAULT '0', `tokens_used` int DEFAULT '0', `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, `updated_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`), UNIQUE KEY `url_slug` (`url_slug`), KEY `idx_job_id` (`job_id`), KEY `idx_url_slug` (`url_slug`), CONSTRAINT `job_links_ibfk_1` FOREIGN KEY (`job_id`) REFERENCES `jobs` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- conversation_messages CREATE TABLE `conversation_messages` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT (uuid()), `interview_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `link_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `sender` enum('candidate','ai') COLLATE utf8mb4_unicode_ci NOT NULL, `message` text COLLATE utf8mb4_unicode_ci NOT NULL, `message_data` json DEFAULT NULL, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_interview_id` (`interview_id`), KEY `idx_link_id` (`link_id`), KEY `idx_created_at` (`created_at`), CONSTRAINT `conversation_messages_ibfk_1` FOREIGN KEY (`interview_id`) REFERENCES `interviews` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- interview_events CREATE TABLE `interview_events` ( `id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `job_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `link_id` varchar(36) COLLATE utf8mb4_unicode_ci NOT NULL, `event_type` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL, `event_data` json DEFAULT NULL, `created_at` timestamp NULL DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (`id`), KEY `idx_job_id` (`job_id`), KEY `idx_link_id` (`link_id`), KEY `idx_event_type` (`event_type`), KEY `idx_created_at` (`created_at`), CONSTRAINT `interview_events_ibfk_1` FOREIGN KEY (`job_id`) REFERENCES `jobs` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Triggers DELIMITER $$ CREATE TRIGGER `update_job_usage_after_insert` AFTER INSERT ON `jobs` FOR EACH ROW BEGIN INSERT INTO user_usage (user_id, jobs_created) VALUES (NEW.user_id, 1) ON DUPLICATE KEY UPDATE jobs_created = jobs_created + 1; END$$ DELIMITER ; DELIMITER $$ CREATE TRIGGER `update_token_usage_after_purchase` AFTER INSERT ON `interview_tokens` FOR EACH ROW BEGIN INSERT INTO user_usage (user_id, tokens_purchased) VALUES (NEW.user_id, NEW.quantity) ON DUPLICATE KEY UPDATE tokens_purchased = tokens_purchased + NEW.quantity; END$$ DELIMITER ; DELIMITER $$ CREATE TRIGGER `update_interview_usage_after_complete` AFTER UPDATE ON `interviews` FOR EACH ROW BEGIN IF OLD.status != 'completed' AND NEW.status = 'completed' THEN INSERT INTO user_usage (user_id, interviews_completed, tokens_used) VALUES (NEW.user_id, 1, 1) ON DUPLICATE KEY UPDATE interviews_completed = interviews_completed + 1, tokens_used = tokens_used + 1; END IF; END$$ DELIMITER ; -- Functions DELIMITER $$ CREATE FUNCTION `can_create_job`(user_uuid VARCHAR(36)) RETURNS tinyint(1) READS SQL DATA DETERMINISTIC BEGIN DECLARE current_jobs INT DEFAULT 0; DECLARE max_jobs INT DEFAULT 100; SELECT COALESCE(jobs_created, 0) INTO current_jobs FROM user_usage WHERE user_id = user_uuid; RETURN current_jobs < max_jobs; END$$ DELIMITER ; DELIMITER $$ CREATE FUNCTION `get_all_users`() RETURNS json READS SQL DATA DETERMINISTIC BEGIN DECLARE result JSON; SELECT JSON_ARRAYAGG( JSON_OBJECT( 'id', id, 'email', email, 'first_name', first_name, 'last_name', last_name, 'role', role, 'company_name', company_name, 'is_active', is_active, 'last_login_at', last_login_at, 'email_verified_at', email_verified_at, 'created_at', created_at ) ) INTO result FROM users WHERE deleted_at IS NULL ORDER BY created_at DESC; RETURN result; END$$ DELIMITER ; DELIMITER $$ CREATE FUNCTION `get_token_usage_summary`(user_uuid VARCHAR(36)) RETURNS json READS SQL DATA DETERMINISTIC BEGIN DECLARE total_purchased INT DEFAULT 0; DECLARE total_used INT DEFAULT 0; DECLARE total_available INT DEFAULT 0; DECLARE result JSON; SELECT COALESCE(SUM(quantity), 0) INTO total_purchased FROM interview_tokens WHERE user_id = user_uuid; SELECT COALESCE(SUM(tokens_used), 0) INTO total_used FROM interview_tokens WHERE user_id = user_uuid; SELECT COALESCE(SUM(tokens_remaining), 0) INTO total_available FROM interview_tokens WHERE user_id = user_uuid AND status = 'active' AND (expires_at IS NULL OR expires_at > NOW()); SET result = JSON_OBJECT( 'total_purchased', total_purchased, 'total_used', total_used, 'total_available', total_available, 'utilization_percentage', CASE WHEN total_purchased > 0 THEN ROUND((total_used / total_purchased) * 100, 2) ELSE 0 END ); RETURN result; END$$ DELIMITER ; DELIMITER $$ CREATE FUNCTION `get_user_statistics`(user_uuid VARCHAR(36)) RETURNS json READS SQL DATA DETERMINISTIC BEGIN DECLARE result JSON; DECLARE user_usage_data JSON; DECLARE token_summary JSON; SELECT JSON_OBJECT( 'jobs_created', COALESCE(jobs_created, 0), 'interviews_completed', COALESCE(interviews_completed, 0), 'tokens_purchased', COALESCE(tokens_purchased, 0), 'tokens_used', COALESCE(tokens_used, 0) ) INTO user_usage_data FROM user_usage WHERE user_id = user_uuid; SELECT get_token_usage_summary(user_uuid) INTO token_summary; SET result = JSON_OBJECT('usage', user_usage_data, 'tokens', token_summary); RETURN result; END$$ DELIMITER ; DELIMITER $$ CREATE FUNCTION `has_available_tokens`(user_uuid VARCHAR(36)) RETURNS tinyint(1) READS SQL DATA DETERMINISTIC BEGIN DECLARE available_tokens INT DEFAULT 0; SELECT COALESCE(SUM(tokens_remaining), 0) INTO available_tokens FROM interview_tokens WHERE user_id = user_uuid AND status = 'active' AND (expires_at IS NULL OR expires_at > NOW()); RETURN available_tokens > 0; END$$ DELIMITER ; DELIMITER $$ CREATE FUNCTION `is_admin`(user_uuid VARCHAR(36)) RETURNS tinyint(1) READS SQL DATA DETERMINISTIC BEGIN DECLARE user_role VARCHAR(20) DEFAULT NULL; SELECT role INTO user_role FROM users WHERE id = user_uuid AND is_active = TRUE; RETURN user_role = 'admin'; END$$ DELIMITER ; -- Procedures (from dump routines) DELIMITER $$ CREATE PROCEDURE `add_tokens_to_user`( IN p_user_id VARCHAR(36), IN p_quantity INT, IN p_price_per_token DECIMAL(10,2), IN p_admin_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255) ) BEGIN DECLARE v_total_price DECIMAL(10,2); DECLARE v_token_id VARCHAR(36); DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while adding tokens'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE IF NOT EXISTS (SELECT 1 FROM users WHERE id = p_user_id AND deleted_at IS NULL) THEN SET p_success = FALSE; SET p_message = 'User not found'; ELSE SET v_total_price = p_quantity * p_price_per_token; SET v_token_id = UUID(); INSERT INTO interview_tokens ( id, user_id, token_type, quantity, price_per_token, total_price, status, purchased_at ) VALUES ( v_token_id, p_user_id, CASE WHEN p_quantity = 1 THEN 'single' ELSE 'bulk' END, p_quantity, p_price_per_token, v_total_price, 'active', NOW() ); -- NOTE: routines in dump referenced interview_token_id; schema doesn't have it. Keeping minimal insert INSERT INTO payment_records ( user_id, token_package_id, amount, status, payment_method, payment_reference ) VALUES ( p_user_id, NULL, v_total_price, 'paid', 'admin_granted', CONCAT('ADMIN_', p_admin_id, '_', NOW()) ); SET p_success = TRUE; SET p_message = CONCAT('Successfully added ', p_quantity, ' tokens to user'); END IF; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE PROCEDURE `change_user_password`( IN p_user_id VARCHAR(36), IN p_new_password_hash VARCHAR(255), IN p_admin_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255) ) BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while changing password'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE IF NOT EXISTS (SELECT 1 FROM users WHERE id = p_user_id AND deleted_at IS NULL) THEN SET p_success = FALSE; SET p_message = 'User not found'; ELSE UPDATE users SET password_hash = p_new_password_hash, updated_at = NOW() WHERE id = p_user_id; SET p_success = TRUE; SET p_message = 'Password changed successfully'; END IF; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE PROCEDURE `create_user`( IN p_email VARCHAR(255), IN p_password_hash VARCHAR(255), IN p_first_name VARCHAR(100), IN p_last_name VARCHAR(100), IN p_role ENUM('admin', 'recruiter'), IN p_company_name VARCHAR(255), IN p_admin_id VARCHAR(36), OUT p_user_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255) ) BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while creating user'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE IF EXISTS (SELECT 1 FROM users WHERE email = p_email AND deleted_at IS NULL) THEN SET p_success = FALSE; SET p_message = 'Email already exists'; ELSE SET p_user_id = UUID(); INSERT INTO users ( id, email, password_hash, first_name, last_name, role, company_name, is_active, email_verified_at ) VALUES ( p_user_id, p_email, p_password_hash, p_first_name, p_last_name, p_role, p_company_name, TRUE, NOW() ); INSERT INTO user_usage (user_id) VALUES (p_user_id); SET p_success = TRUE; SET p_message = 'User created successfully'; END IF; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE PROCEDURE `deactivate_user`( IN p_user_id VARCHAR(36), IN p_admin_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255) ) BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while deactivating user'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE IF NOT EXISTS (SELECT 1 FROM users WHERE id = p_user_id AND deleted_at IS NULL) THEN SET p_success = FALSE; SET p_message = 'User not found'; ELSE UPDATE users SET is_active = FALSE, updated_at = NOW() WHERE id = p_user_id; SET p_success = TRUE; SET p_message = 'User deactivated successfully'; END IF; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE PROCEDURE `get_system_statistics`( IN p_admin_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255), OUT p_statistics JSON ) BEGIN DECLARE v_total_users INT DEFAULT 0; DECLARE v_active_users INT DEFAULT 0; DECLARE v_total_jobs INT DEFAULT 0; DECLARE v_total_interviews INT DEFAULT 0; DECLARE v_total_tokens_purchased INT DEFAULT 0; DECLARE v_total_tokens_used INT DEFAULT 0; DECLARE v_total_revenue DECIMAL(10,2) DEFAULT 0; DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while getting statistics'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE SELECT COUNT(*) INTO v_total_users FROM users WHERE deleted_at IS NULL; SELECT COUNT(*) INTO v_active_users FROM users WHERE is_active = TRUE AND deleted_at IS NULL; SELECT COALESCE(SUM(jobs_created), 0) INTO v_total_jobs FROM user_usage; SELECT COALESCE(SUM(interviews_completed), 0) INTO v_total_interviews FROM user_usage; SELECT COALESCE(SUM(tokens_purchased), 0) INTO v_total_tokens_purchased FROM user_usage; SELECT COALESCE(SUM(tokens_used), 0) INTO v_total_tokens_used FROM user_usage; SELECT COALESCE(SUM(amount), 0) INTO v_total_revenue FROM payment_records WHERE status = 'paid'; SET p_statistics = JSON_OBJECT( 'total_users', v_total_users, 'active_users', v_active_users, 'total_jobs', v_total_jobs, 'total_interviews', v_total_interviews, 'total_tokens_purchased', v_total_tokens_purchased, 'total_tokens_used', v_total_tokens_used, 'total_revenue', v_total_revenue, 'generated_at', NOW() ); SET p_success = TRUE; SET p_message = 'Statistics retrieved successfully'; END IF; END$$ DELIMITER ; DELIMITER $$ CREATE PROCEDURE `update_user`( IN p_user_id VARCHAR(36), IN p_email VARCHAR(255), IN p_first_name VARCHAR(100), IN p_last_name VARCHAR(100), IN p_role ENUM('admin', 'recruiter'), IN p_company_name VARCHAR(255), IN p_is_active BOOLEAN, IN p_admin_id VARCHAR(36), OUT p_success BOOLEAN, OUT p_message VARCHAR(255) ) BEGIN DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN ROLLBACK; SET p_success = FALSE; SET p_message = 'An error occurred while updating user'; END; IF NOT is_admin(p_admin_id) THEN SET p_success = FALSE; SET p_message = 'Access denied: Admin privileges required'; ELSE IF NOT EXISTS (SELECT 1 FROM users WHERE id = p_user_id AND deleted_at IS NULL) THEN SET p_success = FALSE; SET p_message = 'User not found'; ELSE UPDATE users SET email = p_email, first_name = p_first_name, last_name = p_last_name, role = p_role, company_name = p_company_name, is_active = p_is_active, updated_at = NOW() WHERE id = p_user_id; SET p_success = TRUE; SET p_message = 'User updated successfully'; END IF; END IF; END$$ DELIMITER ; -- Insert default admin user (password: admin123 - CHANGE THIS!) INSERT INTO users (id, email, password_hash, first_name, last_name, role, is_active, email_verified_at) VALUES (UUID(), 'admin@candivista.com', '$2b$10$rcKrXbkDjjjT3vA3kMH78OkyUFNTn6nuCsqK90JEA2.S2p0dVjFUi', 'Admin', 'User', 'admin', TRUE, NOW());