-- 解班客数据库完整结构创建脚本 -- 创建时间: 2024年 -- 数据库: jbkdata -- 设置字符集 SET NAMES utf8mb4; SET FOREIGN_KEY_CHECKS = 0; -- 使用数据库 USE jbkdata; -- ================================ -- 1. 管理员表 -- ================================ CREATE TABLE IF NOT EXISTS `admins` ( `id` int(11) NOT NULL AUTO_INCREMENT, `username` varchar(50) NOT NULL COMMENT '用户名', `password` varchar(255) NOT NULL COMMENT '密码', `email` varchar(100) DEFAULT NULL COMMENT '邮箱', `nickname` varchar(50) DEFAULT NULL COMMENT '昵称', `avatar` varchar(255) DEFAULT NULL COMMENT '头像', `role` enum('super_admin','admin','operator') DEFAULT 'admin' COMMENT '角色', `status` tinyint(1) DEFAULT 1 COMMENT '状态 1:启用 0:禁用', `last_login` timestamp NULL DEFAULT NULL COMMENT '最后登录时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `username` (`username`), KEY `idx_email` (`email`), KEY `idx_status` (`status`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='管理员表'; -- ================================ -- 2. 用户表 -- ================================ CREATE TABLE IF NOT EXISTS `users` ( `id` int(11) NOT NULL AUTO_INCREMENT, `username` varchar(50) NOT NULL COMMENT '用户名', `password_hash` varchar(255) NOT NULL COMMENT '密码哈希', `email` varchar(100) DEFAULT NULL COMMENT '邮箱', `phone` varchar(20) DEFAULT NULL COMMENT '手机号', `real_name` varchar(50) DEFAULT NULL COMMENT '真实姓名', `avatar_url` varchar(255) DEFAULT NULL COMMENT '头像URL', `user_type` enum('farmer','tourist','merchant','admin') DEFAULT 'tourist' COMMENT '用户类型', `status` enum('active','inactive','banned') DEFAULT 'active' COMMENT '状态', `balance` decimal(15,2) DEFAULT 0.00 COMMENT '余额', `points` int(11) DEFAULT 0 COMMENT '积分', `level` tinyint(4) DEFAULT 1 COMMENT '用户等级', `last_login_at` timestamp NULL DEFAULT NULL COMMENT '最后登录时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `username` (`username`), UNIQUE KEY `email` (`email`), UNIQUE KEY `phone` (`phone`), KEY `idx_user_type` (`user_type`), KEY `idx_status` (`status`), KEY `idx_created_at` (`created_at`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户表'; -- ================================ -- 3. 商家表 -- ================================ CREATE TABLE IF NOT EXISTS `merchants` ( `id` int(11) NOT NULL AUTO_INCREMENT, `user_id` int(11) NOT NULL COMMENT '关联用户ID', `business_name` varchar(100) NOT NULL COMMENT '商家名称', `business_type` enum('restaurant','hotel','farm','attraction','transport') NOT NULL COMMENT '商家类型', `description` text COMMENT '商家描述', `address` varchar(255) DEFAULT NULL COMMENT '地址', `latitude` decimal(10,8) DEFAULT NULL COMMENT '纬度', `longitude` decimal(11,8) DEFAULT NULL COMMENT '经度', `contact_phone` varchar(20) DEFAULT NULL COMMENT '联系电话', `business_hours` json DEFAULT NULL COMMENT '营业时间', `images` json DEFAULT NULL COMMENT '商家图片', `rating` decimal(3,2) DEFAULT 0.00 COMMENT '评分', `review_count` int(11) DEFAULT 0 COMMENT '评价数量', `status` enum('pending','approved','rejected','suspended') DEFAULT 'pending' COMMENT '状态', `verified_at` timestamp NULL DEFAULT NULL COMMENT '认证时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `user_id` (`user_id`), KEY `idx_business_type` (`business_type`), KEY `idx_status` (`status`), KEY `idx_location` (`latitude`,`longitude`), CONSTRAINT `merchants_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='商家表'; -- ================================ -- 4. 动物表 -- ================================ CREATE TABLE IF NOT EXISTS `animals` ( `id` int(11) NOT NULL AUTO_INCREMENT, `name` varchar(50) NOT NULL COMMENT '动物名称', `type` enum('chicken','duck','pig','cow','sheep','rabbit','fish') NOT NULL COMMENT '动物类型', `breed` varchar(50) DEFAULT NULL COMMENT '品种', `age` int(11) DEFAULT NULL COMMENT '年龄(月)', `weight` decimal(8,2) DEFAULT NULL COMMENT '重量(kg)', `gender` enum('male','female','unknown') DEFAULT 'unknown' COMMENT '性别', `description` text COMMENT '描述', `image` varchar(255) DEFAULT NULL COMMENT '图片URL', `images` json DEFAULT NULL COMMENT '多张图片', `price` decimal(10,2) NOT NULL COMMENT '认领价格', `daily_cost` decimal(8,2) DEFAULT 0.00 COMMENT '每日费用', `location` varchar(100) DEFAULT NULL COMMENT '所在位置', `farmer_id` int(11) DEFAULT NULL COMMENT '农户ID', `status` enum('available','claimed','sold','deceased') DEFAULT 'available' COMMENT '状态', `health_status` enum('healthy','sick','recovering') DEFAULT 'healthy' COMMENT '健康状态', `vaccination_records` json DEFAULT NULL COMMENT '疫苗记录', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `idx_type` (`type`), KEY `idx_status` (`status`), KEY `idx_farmer_id` (`farmer_id`), KEY `idx_price` (`price`), CONSTRAINT `animals_ibfk_1` FOREIGN KEY (`farmer_id`) REFERENCES `users` (`id`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='动物表'; -- ================================ -- 5. 动物认领表 -- ================================ CREATE TABLE IF NOT EXISTS `animal_claims` ( `id` int(11) NOT NULL AUTO_INCREMENT, `claim_no` varchar(50) NOT NULL COMMENT '认领订单号', `animal_id` int(11) NOT NULL COMMENT '动物ID', `user_id` int(11) NOT NULL COMMENT '认领用户ID', `claim_reason` text COMMENT '认领原因', `claim_duration` int(11) NOT NULL COMMENT '认领时长(天)', `total_amount` decimal(10,2) NOT NULL COMMENT '总费用', `contact_info` json DEFAULT NULL COMMENT '联系信息', `status` enum('pending','approved','rejected','cancelled','completed') DEFAULT 'pending' COMMENT '状态', `reviewed_by` int(11) DEFAULT NULL COMMENT '审核人ID', `reviewed_at` timestamp NULL DEFAULT NULL COMMENT '审核时间', `review_note` text COMMENT '审核备注', `start_date` date DEFAULT NULL COMMENT '开始日期', `end_date` date DEFAULT NULL COMMENT '结束日期', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', `deleted_at` timestamp NULL DEFAULT NULL COMMENT '删除时间', PRIMARY KEY (`id`), UNIQUE KEY `claim_no` (`claim_no`), KEY `animal_id` (`animal_id`), KEY `user_id` (`user_id`), KEY `idx_status` (`status`), KEY `idx_created_at` (`created_at`), CONSTRAINT `animal_claims_ibfk_1` FOREIGN KEY (`animal_id`) REFERENCES `animals` (`id`) ON DELETE CASCADE, CONSTRAINT `animal_claims_ibfk_2` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='动物认领表'; -- ================================ -- 6. 旅行计划表 -- ================================ CREATE TABLE IF NOT EXISTS `travel_plans` ( `id` int(11) NOT NULL AUTO_INCREMENT, `title` varchar(100) NOT NULL COMMENT '标题', `description` text COMMENT '描述', `destination` varchar(100) NOT NULL COMMENT '目的地', `start_date` date NOT NULL COMMENT '开始日期', `end_date` date NOT NULL COMMENT '结束日期', `max_participants` int(11) DEFAULT 20 COMMENT '最大参与人数', `current_participants` int(11) DEFAULT 0 COMMENT '当前参与人数', `price_per_person` decimal(10,2) NOT NULL COMMENT '每人价格', `includes` json DEFAULT NULL COMMENT '包含项目', `excludes` json DEFAULT NULL COMMENT '不包含项目', `itinerary` json DEFAULT NULL COMMENT '行程安排', `images` json DEFAULT NULL COMMENT '图片', `requirements` text COMMENT '参与要求', `created_by` int(11) NOT NULL COMMENT '创建者ID', `status` enum('draft','published','cancelled','completed') DEFAULT 'draft' COMMENT '状态', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `created_by` (`created_by`), KEY `idx_status` (`status`), KEY `idx_start_date` (`start_date`), KEY `idx_destination` (`destination`), CONSTRAINT `travel_plans_ibfk_1` FOREIGN KEY (`created_by`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='旅行计划表'; -- ================================ -- 7. 旅行报名表 -- ================================ CREATE TABLE IF NOT EXISTS `travel_registrations` ( `id` int(11) NOT NULL AUTO_INCREMENT, `travel_plan_id` int(11) NOT NULL COMMENT '旅行计划ID', `user_id` int(11) NOT NULL COMMENT '用户ID', `participants` int(11) DEFAULT 1 COMMENT '参与人数', `message` text COMMENT '留言', `emergency_contact` varchar(50) DEFAULT NULL COMMENT '紧急联系人', `emergency_phone` varchar(20) DEFAULT NULL COMMENT '紧急联系电话', `status` enum('pending','approved','rejected','cancelled') DEFAULT 'pending' COMMENT '状态', `reject_reason` text COMMENT '拒绝原因', `applied_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '申请时间', `responded_at` timestamp NULL DEFAULT NULL COMMENT '响应时间', PRIMARY KEY (`id`), UNIQUE KEY `unique_registration` (`travel_plan_id`,`user_id`), KEY `user_id` (`user_id`), KEY `idx_status` (`status`), CONSTRAINT `travel_registrations_ibfk_1` FOREIGN KEY (`travel_plan_id`) REFERENCES `travel_plans` (`id`) ON DELETE CASCADE, CONSTRAINT `travel_registrations_ibfk_2` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='旅行报名表'; -- ================================ -- 8. 鲜花表 -- ================================ CREATE TABLE IF NOT EXISTS `flowers` ( `id` int(11) NOT NULL AUTO_INCREMENT, `name` varchar(50) NOT NULL COMMENT '花卉名称', `scientific_name` varchar(100) DEFAULT NULL COMMENT '学名', `category` enum('rose','lily','tulip','sunflower','orchid','carnation','other') NOT NULL COMMENT '花卉类别', `color` varchar(30) DEFAULT NULL COMMENT '颜色', `description` text COMMENT '描述', `care_instructions` text COMMENT '养护说明', `image` varchar(255) DEFAULT NULL COMMENT '主图片', `images` json DEFAULT NULL COMMENT '多张图片', `price` decimal(8,2) NOT NULL COMMENT '价格', `stock_quantity` int(11) DEFAULT 0 COMMENT '库存数量', `farmer_id` int(11) DEFAULT NULL COMMENT '农户ID', `status` enum('available','out_of_stock','discontinued') DEFAULT 'available' COMMENT '状态', `seasonal_availability` json DEFAULT NULL COMMENT '季节性供应', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `idx_category` (`category`), KEY `idx_status` (`status`), KEY `idx_farmer_id` (`farmer_id`), KEY `idx_price` (`price`), CONSTRAINT `flowers_ibfk_1` FOREIGN KEY (`farmer_id`) REFERENCES `users` (`id`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='鲜花表'; -- ================================ -- 9. 订单表 -- ================================ CREATE TABLE IF NOT EXISTS `orders` ( `id` int(11) NOT NULL AUTO_INCREMENT, `order_no` varchar(50) NOT NULL COMMENT '订单号', `user_id` int(11) NOT NULL COMMENT '用户ID', `type` enum('animal_claim','travel','flower','service') NOT NULL COMMENT '订单类型', `related_id` int(11) DEFAULT NULL COMMENT '关联ID', `title` varchar(200) NOT NULL COMMENT '订单标题', `description` text COMMENT '订单描述', `total_amount` decimal(15,2) NOT NULL COMMENT '总金额', `discount_amount` decimal(15,2) DEFAULT 0.00 COMMENT '优惠金额', `final_amount` decimal(15,2) NOT NULL COMMENT '实付金额', `status` enum('pending','paid','processing','shipped','completed','cancelled','refunded') DEFAULT 'pending' COMMENT '订单状态', `payment_status` enum('unpaid','paid','refunded','partial_refund') DEFAULT 'unpaid' COMMENT '支付状态', `payment_method` varchar(50) DEFAULT NULL COMMENT '支付方式', `payment_time` timestamp NULL DEFAULT NULL COMMENT '支付时间', `shipping_address` json DEFAULT NULL COMMENT '收货地址', `contact_info` json DEFAULT NULL COMMENT '联系信息', `notes` text COMMENT '备注', `ordered_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '下单时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `order_no` (`order_no`), KEY `user_id` (`user_id`), KEY `idx_type` (`type`), KEY `idx_status` (`status`), KEY `idx_payment_status` (`payment_status`), KEY `idx_ordered_at` (`ordered_at`), CONSTRAINT `orders_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单表'; -- ================================ -- 10. 支付表 -- ================================ CREATE TABLE IF NOT EXISTS `payments` ( `id` int(11) NOT NULL AUTO_INCREMENT, `payment_no` varchar(50) NOT NULL COMMENT '支付订单号', `order_id` int(11) NOT NULL COMMENT '订单ID', `user_id` int(11) NOT NULL COMMENT '用户ID', `amount` decimal(15,2) NOT NULL COMMENT '支付金额', `payment_method` enum('wechat','alipay','bank_card','balance') NOT NULL COMMENT '支付方式', `status` enum('pending','paid','failed','cancelled','refunded') DEFAULT 'pending' COMMENT '支付状态', `transaction_id` varchar(100) DEFAULT NULL COMMENT '第三方交易号', `paid_amount` decimal(15,2) DEFAULT NULL COMMENT '实际支付金额', `paid_at` timestamp NULL DEFAULT NULL COMMENT '支付时间', `failure_reason` varchar(255) DEFAULT NULL COMMENT '失败原因', `return_url` varchar(255) DEFAULT NULL COMMENT '返回URL', `notify_url` varchar(255) DEFAULT NULL COMMENT '通知URL', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', `deleted_at` timestamp NULL DEFAULT NULL COMMENT '删除时间', PRIMARY KEY (`id`), UNIQUE KEY `payment_no` (`payment_no`), KEY `order_id` (`order_id`), KEY `user_id` (`user_id`), KEY `idx_status` (`status`), KEY `idx_payment_method` (`payment_method`), KEY `idx_created_at` (`created_at`), CONSTRAINT `payments_ibfk_1` FOREIGN KEY (`order_id`) REFERENCES `orders` (`id`) ON DELETE CASCADE, CONSTRAINT `payments_ibfk_2` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='支付表'; -- ================================ -- 11. 退款表 -- ================================ CREATE TABLE IF NOT EXISTS `refunds` ( `id` int(11) NOT NULL AUTO_INCREMENT, `refund_no` varchar(50) NOT NULL COMMENT '退款订单号', `payment_id` int(11) NOT NULL COMMENT '支付ID', `user_id` int(11) NOT NULL COMMENT '用户ID', `refund_amount` decimal(15,2) NOT NULL COMMENT '退款金额', `refund_reason` varchar(255) NOT NULL COMMENT '退款原因', `status` enum('pending','processing','completed','rejected') DEFAULT 'pending' COMMENT '退款状态', `processed_by` int(11) DEFAULT NULL COMMENT '处理人ID', `processed_at` timestamp NULL DEFAULT NULL COMMENT '处理时间', `process_remark` text COMMENT '处理备注', `refund_transaction_id` varchar(100) DEFAULT NULL COMMENT '退款交易号', `refunded_at` timestamp NULL DEFAULT NULL COMMENT '退款完成时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `updated_at` timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', `deleted_at` timestamp NULL DEFAULT NULL COMMENT '删除时间', PRIMARY KEY (`id`), UNIQUE KEY `refund_no` (`refund_no`), KEY `payment_id` (`payment_id`), KEY `user_id` (`user_id`), KEY `idx_status` (`status`), CONSTRAINT `refunds_ibfk_1` FOREIGN KEY (`payment_id`) REFERENCES `payments` (`id`) ON DELETE CASCADE, CONSTRAINT `refunds_ibfk_2` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='退款表'; -- ================================ -- 12. 辅助表 -- ================================ -- 邮箱验证表 CREATE TABLE IF NOT EXISTS `email_verifications` ( `id` int(11) NOT NULL AUTO_INCREMENT, `email` varchar(100) NOT NULL COMMENT '邮箱', `code` varchar(10) NOT NULL COMMENT '验证码', `expires_at` timestamp NOT NULL COMMENT '过期时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', PRIMARY KEY (`id`), UNIQUE KEY `email` (`email`), KEY `idx_expires_at` (`expires_at`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='邮箱验证表'; -- 密码重置表 CREATE TABLE IF NOT EXISTS `password_resets` ( `id` int(11) NOT NULL AUTO_INCREMENT, `user_id` int(11) NOT NULL COMMENT '用户ID', `token` varchar(255) NOT NULL COMMENT '重置令牌', `expires_at` timestamp NOT NULL COMMENT '过期时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', PRIMARY KEY (`id`), UNIQUE KEY `user_id` (`user_id`), UNIQUE KEY `token` (`token`), KEY `idx_expires_at` (`expires_at`), CONSTRAINT `password_resets_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='密码重置表'; -- 登录尝试表 CREATE TABLE IF NOT EXISTS `login_attempts` ( `id` int(11) NOT NULL AUTO_INCREMENT, `identifier` varchar(100) NOT NULL COMMENT '标识符(用户名/邮箱/IP)', `attempts` int(11) DEFAULT 1 COMMENT '尝试次数', `last_attempt` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '最后尝试时间', `created_at` timestamp DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', PRIMARY KEY (`id`), UNIQUE KEY `identifier` (`identifier`), KEY `idx_last_attempt` (`last_attempt`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='登录尝试表'; SET FOREIGN_KEY_CHECKS = 1; -- 创建完成提示 SELECT '数据库表结构创建完成!' as message;