Files
nxxmdata/create_tables.sql
2025-09-01 02:51:34 +08:00

270 lines
14 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 宁夏智慧养殖监管平台数据库表结构脚本
-- 基于Sequelize模型定义生成
-- 创建时间: 2024年
-- 设置字符集和排序规则
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- 创建数据库(如果不存在)
-- CREATE DATABASE IF NOT EXISTS nxxmdata CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- USE nxxmdata;
-- ============================================
-- 用户相关表
-- ============================================
-- 用户表
CREATE TABLE IF NOT EXISTS `users` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '用户唯一标识',
`username` varchar(50) NOT NULL COMMENT '用户名',
`email` varchar(100) NOT NULL COMMENT '邮箱',
`password` varchar(255) NOT NULL COMMENT '密码(加密后)',
`phone` varchar(20) DEFAULT NULL COMMENT '手机号',
`avatar` varchar(255) DEFAULT NULL COMMENT '头像URL',
`status` enum('active','inactive','banned') DEFAULT 'active' COMMENT '用户状态',
`last_login` datetime DEFAULT NULL COMMENT '最后登录时间',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
UNIQUE KEY `username` (`username`),
UNIQUE KEY `email` (`email`),
KEY `idx_status` (`status`),
KEY `idx_created_at` (`created_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户表';
-- 角色表
CREATE TABLE IF NOT EXISTS `roles` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '角色唯一标识',
`name` varchar(50) NOT NULL COMMENT '角色名称',
`description` text DEFAULT NULL COMMENT '角色描述',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='角色表';
-- 用户角色关联表
CREATE TABLE IF NOT EXISTS `user_roles` (
`user_id` int(11) NOT NULL COMMENT '用户ID',
`role_id` int(11) NOT NULL COMMENT '角色ID',
`assigned_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '分配时间',
PRIMARY KEY (`user_id`, `role_id`),
KEY `fk_user_roles_role_id` (`role_id`),
CONSTRAINT `fk_user_roles_user_id` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_user_roles_role_id` FOREIGN KEY (`role_id`) REFERENCES `roles` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户角色关联表';
-- ============================================
-- 养殖场相关表
-- ============================================
-- 养殖场表
CREATE TABLE IF NOT EXISTS `farms` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '养殖场唯一标识',
`name` varchar(100) NOT NULL COMMENT '养殖场名称',
`type` varchar(50) NOT NULL COMMENT '养殖场类型',
`location` json NOT NULL COMMENT '地理位置信息(经纬度等)',
`address` varchar(255) DEFAULT NULL COMMENT '详细地址',
`contact` varchar(50) DEFAULT NULL COMMENT '联系人',
`phone` varchar(20) DEFAULT NULL COMMENT '联系电话',
`status` enum('active','inactive','maintenance') DEFAULT 'active' COMMENT '养殖场状态',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `idx_type` (`type`),
KEY `idx_status` (`status`),
KEY `idx_created_at` (`created_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='养殖场表';
-- 动物表
CREATE TABLE IF NOT EXISTS `animals` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '动物记录唯一标识',
`type` varchar(50) NOT NULL COMMENT '动物类型',
`count` int(11) NOT NULL DEFAULT 0 COMMENT '数量',
`farm_id` int(11) NOT NULL COMMENT '所属养殖场ID',
`health_status` enum('healthy','sick','quarantine') DEFAULT 'healthy' COMMENT '健康状态',
`last_inspection` datetime DEFAULT NULL COMMENT '最后检查时间',
`notes` text DEFAULT NULL COMMENT '备注信息',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `fk_animals_farm_id` (`farm_id`),
KEY `idx_type` (`type`),
KEY `idx_health_status` (`health_status`),
CONSTRAINT `fk_animals_farm_id` FOREIGN KEY (`farm_id`) REFERENCES `farms` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='动物表';
-- 设备表
CREATE TABLE IF NOT EXISTS `devices` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '设备唯一标识',
`name` varchar(100) NOT NULL COMMENT '设备名称',
`type` varchar(50) NOT NULL COMMENT '设备类型',
`status` enum('online','offline','maintenance') DEFAULT 'offline' COMMENT '设备状态',
`farm_id` int(11) NOT NULL COMMENT '所属养殖场ID',
`last_maintenance` datetime DEFAULT NULL COMMENT '最后维护时间',
`installation_date` datetime DEFAULT NULL COMMENT '安装日期',
`metrics` json DEFAULT NULL COMMENT '设备指标数据',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `fk_devices_farm_id` (`farm_id`),
KEY `idx_type` (`type`),
KEY `idx_status` (`status`),
CONSTRAINT `fk_devices_farm_id` FOREIGN KEY (`farm_id`) REFERENCES `farms` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='设备表';
-- 预警表
CREATE TABLE IF NOT EXISTS `alerts` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '预警唯一标识',
`type` varchar(50) NOT NULL COMMENT '预警类型',
`level` enum('low','medium','high','critical') DEFAULT 'medium' COMMENT '预警级别',
`message` text NOT NULL COMMENT '预警消息',
`status` enum('active','acknowledged','resolved') DEFAULT 'active' COMMENT '预警状态',
`farm_id` int(11) NOT NULL COMMENT '所属养殖场ID',
`device_id` int(11) DEFAULT NULL COMMENT '关联设备ID',
`resolved_at` datetime DEFAULT NULL COMMENT '解决时间',
`resolved_by` int(11) DEFAULT NULL COMMENT '解决人ID',
`resolution_notes` text DEFAULT NULL COMMENT '解决说明',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `fk_alerts_farm_id` (`farm_id`),
KEY `fk_alerts_device_id` (`device_id`),
KEY `fk_alerts_resolved_by` (`resolved_by`),
KEY `idx_type` (`type`),
KEY `idx_level` (`level`),
KEY `idx_status` (`status`),
KEY `idx_created_at` (`created_at`),
CONSTRAINT `fk_alerts_farm_id` FOREIGN KEY (`farm_id`) REFERENCES `farms` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_alerts_device_id` FOREIGN KEY (`device_id`) REFERENCES `devices` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_alerts_resolved_by` FOREIGN KEY (`resolved_by`) REFERENCES `users` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='预警表';
-- ============================================
-- 商品订单相关表
-- ============================================
-- 产品表
CREATE TABLE IF NOT EXISTS `products` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '产品唯一标识',
`name` varchar(100) NOT NULL COMMENT '产品名称',
`description` text DEFAULT NULL COMMENT '产品描述',
`price` int(11) NOT NULL COMMENT '产品价格(单位:分)',
`stock` int(11) NOT NULL DEFAULT 0 COMMENT '库存数量',
`image_url` varchar(255) DEFAULT NULL COMMENT '产品图片URL',
`is_active` tinyint(1) NOT NULL DEFAULT 1 COMMENT '是否激活',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `idx_name` (`name`),
KEY `idx_is_active` (`is_active`),
KEY `idx_created_at` (`created_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='产品表';
-- 订单表
CREATE TABLE IF NOT EXISTS `orders` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '订单唯一标识',
`user_id` int(11) NOT NULL COMMENT '用户ID',
`total_amount` int(11) NOT NULL DEFAULT 0 COMMENT '订单总金额(单位:分)',
`status` enum('pending','processing','shipped','delivered','cancelled') NOT NULL DEFAULT 'pending' COMMENT '订单状态',
`payment_status` enum('unpaid','paid','refunded') NOT NULL DEFAULT 'unpaid' COMMENT '支付状态',
`shipping_address` text DEFAULT NULL COMMENT '收货地址',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
KEY `fk_orders_user_id` (`user_id`),
KEY `idx_status` (`status`),
KEY `idx_payment_status` (`payment_status`),
KEY `idx_created_at` (`created_at`),
CONSTRAINT `fk_orders_user_id` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单表';
-- 订单项表
CREATE TABLE IF NOT EXISTS `order_items` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '订单项唯一标识',
`order_id` int(11) NOT NULL COMMENT '订单ID',
`product_id` int(11) NOT NULL COMMENT '产品ID',
`quantity` int(11) NOT NULL DEFAULT 1 COMMENT '数量',
`price` int(11) NOT NULL COMMENT '单价(单位:分)',
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
PRIMARY KEY (`id`),
KEY `fk_order_items_order_id` (`order_id`),
KEY `fk_order_items_product_id` (`product_id`),
CONSTRAINT `fk_order_items_order_id` FOREIGN KEY (`order_id`) REFERENCES `orders` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_order_items_product_id` FOREIGN KEY (`product_id`) REFERENCES `products` (`id`) ON DELETE RESTRICT ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单项表';
-- ============================================
-- 初始化数据
-- ============================================
-- 插入默认角色
INSERT IGNORE INTO `roles` (`name`, `description`) VALUES
('admin', '系统管理员'),
('manager', '养殖场管理员'),
('operator', '操作员'),
('viewer', '查看者');
-- 插入默认管理员用户(密码: admin123使用bcrypt加密
INSERT IGNORE INTO `users` (`username`, `email`, `password`, `phone`, `avatar`, `status`) VALUES
('admin', 'admin@nxxmdata.com', '$2b$10$kWV4BQk3P4iSn79kQEEoduByeVo8kv41r7FI04mON1/zcrpF7.kn6', '13800138000', '/uploads/avatars/default.png', 'active'),
('manager', 'manager@nxxmdata.com', '$2b$10$kWV4BQk3P4iSn79kQEEoduByeVo8kv41r7FI04mON1/zcrpF7.kn6', '13800138001', '/uploads/avatars/default.png', 'active'),
('user', 'user@nxxmdata.com', '$2b$10$kWV4BQk3P4iSn79kQEEoduByeVo8kv41r7FI04mON1/zcrpF7.kn6', '13800138002', '/uploads/avatars/default.png', 'active');
-- 为用户分配角色
INSERT IGNORE INTO `user_roles` (`user_id`, `role_id`)
SELECT u.id, r.id
FROM `users` u, `roles` r
WHERE (u.username = 'admin' AND r.name = 'admin')
OR (u.username = 'manager' AND r.name = 'manager')
OR (u.username = 'user' AND r.name = 'viewer');
-- 插入示例养殖场数据
INSERT IGNORE INTO `farms` (`name`, `type`, `location`, `address`, `contact`, `phone`, `status`) VALUES
('宁夏示范养殖场', '奶牛养殖', '{"latitude": 38.46667, "longitude": 106.26667}', '宁夏回族自治区银川市金凤区', '张经理', '13800138000', 'active'),
('银川现代化养殖基地', '肉牛养殖', '{"latitude": 38.48779, "longitude": 106.22541}', '宁夏回族自治区银川市兴庆区', '李主任', '13800138001', 'active'),
('吴忠生态养殖园', '综合养殖', '{"latitude": 37.98629, "longitude": 106.19273}', '宁夏回族自治区吴忠市利通区', '王场长', '13800138002', 'active');
-- 插入示例动物数据
INSERT IGNORE INTO `animals` (`type`, `count`, `farm_id`, `health_status`, `last_inspection`) VALUES
('奶牛', 500, 1, 'healthy', '2025-01-18 10:00:00'),
('肉牛', 300, 2, 'healthy', '2025-01-18 09:30:00'),
('绵羊', 1000, 3, 'healthy', '2025-01-18 11:00:00');
-- 插入示例设备数据
INSERT IGNORE INTO `devices` (`name`, `type`, `status`, `farm_id`, `installation_date`, `metrics`) VALUES
('温度传感器001', '温度传感器', 'online', 1, '2024-01-01', '{"temperature": 25.5, "humidity": 60}'),
('湿度传感器001', '湿度传感器', 'online', 1, '2024-01-01', '{"temperature": 25.3, "humidity": 62}'),
('监控摄像头001', '摄像头', 'online', 2, '2024-02-01', '{"status": "normal", "resolution": "1080p"}');
-- 插入示例产品数据
INSERT IGNORE INTO `products` (`name`, `description`, `price`, `stock`, `image_url`) VALUES
('优质鲜牛奶', '新鲜优质牛奶,富含营养', 5000, 1000, '/uploads/products/milk.jpg'),
('有机牛肉', '无添加有机牛肉', 12000, 500, '/uploads/products/beef.jpg'),
('纯羊毛制品', '100%纯羊毛制品', 8000, 300, '/uploads/products/wool.jpg');
-- ============================================
-- 索引优化建议
-- ============================================
-- 复合索引
CREATE INDEX `idx_farms_type_status` ON `farms` (`type`, `status`);
CREATE INDEX `idx_animals_farm_type` ON `animals` (`farm_id`, `type`);
CREATE INDEX `idx_devices_farm_status` ON `devices` (`farm_id`, `status`);
CREATE INDEX `idx_alerts_farm_status_level` ON `alerts` (`farm_id`, `status`, `level`);
CREATE INDEX `idx_orders_user_status` ON `orders` (`user_id`, `status`);
CREATE INDEX `idx_order_items_order_product` ON `order_items` (`order_id`, `product_id`);
-- 时间范围查询索引
CREATE INDEX `idx_alerts_created_status` ON `alerts` (`created_at`, `status`);
CREATE INDEX `idx_orders_created_status` ON `orders` (`created_at`, `status`);
SET FOREIGN_KEY_CHECKS = 1;
-- 脚本执行完成
-- 注意:
-- 1. 请根据实际需求调整字段长度和约束
-- 2. 密码字段需要在应用层进行加密处理
-- 3. JSON字段需要MySQL 5.7+版本支持
-- 4. 建议定期备份数据库
-- 5. 生产环境请根据实际情况调整索引策略