Kamixitong/init_mysql.sql
2025-12-28 16:34:34 +08:00

230 lines
13 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.

-- KaMiXiTong 系统 MySQL 数据库初始化脚本
-- 包含所有表结构定义和初始数据
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- 管理员表
CREATE TABLE IF NOT EXISTS `admin` (
`admin_id` int NOT NULL AUTO_INCREMENT COMMENT '管理员ID',
`username` varchar(32) NOT NULL COMMENT '用户名',
`password_hash` varchar(256) NOT NULL COMMENT '密码哈希',
`email` varchar(64) COMMENT '邮箱',
`role` int NOT NULL DEFAULT 0 COMMENT '角色0=普通管理员, 1=超级管理员',
`status` int NOT NULL DEFAULT 1 COMMENT '状态0=禁用, 1=正常',
`is_deleted` int NOT NULL DEFAULT 0 COMMENT '软删除0=未删除, 1=已删除',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`delete_time` datetime COMMENT '删除时间',
`last_login_time` datetime COMMENT '最后登录时间',
`last_login_ip` varchar(32) COMMENT '最后登录IP',
PRIMARY KEY (`admin_id`),
UNIQUE KEY `uk_username` (`username`),
KEY `idx_username` (`username`),
KEY `idx_status` (`status`),
KEY `idx_is_deleted` (`is_deleted`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='管理员表';
-- 产品表
CREATE TABLE IF NOT EXISTS `product` (
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`product_name` varchar(64) NOT NULL COMMENT '产品名称',
`description` text COMMENT '产品描述',
`features` text COMMENT '产品功能特性',
`image_path` varchar(255) COMMENT '产品图片路径',
`status` int NOT NULL DEFAULT 1 COMMENT '状态0=禁用, 1=启用',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`product_id`),
KEY `idx_status` (`status`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='产品表';
-- 版本表
CREATE TABLE IF NOT EXISTS `version` (
`version_id` int NOT NULL AUTO_INCREMENT COMMENT '版本ID',
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`version_num` varchar(16) NOT NULL COMMENT '版本号',
`platform` varchar(32) COMMENT '平台信息',
`description` text COMMENT '版本描述',
`update_log` text COMMENT '更新日志',
`download_url` varchar(255) COMMENT '下载地址',
`min_license_version` varchar(16) COMMENT '兼容最低卡密版本',
`force_update` int NOT NULL DEFAULT 0 COMMENT '强制更新0=否, 1=是',
`download_status` int NOT NULL DEFAULT 1 COMMENT '下载状态0=禁用, 1=启用',
`publish_status` int NOT NULL DEFAULT 0 COMMENT '发布状态0=草稿, 1=已发布, 2=已回滚',
`file_hash` varchar(64) COMMENT '文件SHA256哈希值',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`version_id`),
UNIQUE KEY `uk_product_version` (`product_id`, `version_num`),
KEY `idx_product_id` (`product_id`),
KEY `idx_publish_status` (`publish_status`),
CONSTRAINT `fk_version_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='版本表';
-- 套餐表
CREATE TABLE IF NOT EXISTS `package` (
`package_id` varchar(64) NOT NULL COMMENT '套餐ID',
`product_id` varchar(32) NOT NULL COMMENT '关联产品ID',
`name` varchar(64) NOT NULL COMMENT '套餐名称',
`description` text COMMENT '套餐描述',
`price` decimal(10,2) NOT NULL COMMENT '价格',
`duration` int NOT NULL COMMENT '时长(天)',
`max_devices` int NOT NULL DEFAULT 1 COMMENT '最大设备数',
`stock` int NOT NULL DEFAULT -1 COMMENT '库存,-1表示无限',
`status` int NOT NULL DEFAULT 1 COMMENT '状态0=禁用, 1=启用',
`sort_order` int NOT NULL DEFAULT 0 COMMENT '排序',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`package_id`),
KEY `idx_product_id` (`product_id`),
KEY `idx_status` (`status`),
CONSTRAINT `fk_package_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='产品套餐表';
-- 许可证(卡密)表
CREATE TABLE IF NOT EXISTS `license` (
`license_id` int NOT NULL AUTO_INCREMENT COMMENT '许可证ID',
`license_key` varchar(35) NOT NULL COMMENT '许可证密钥',
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`type` int NOT NULL DEFAULT 1 COMMENT '类型0=试用, 1=正式',
`status` int NOT NULL DEFAULT 0 COMMENT '状态0=未激活, 1=已激活, 2=已过期, 3=已禁用',
`valid_days` int NOT NULL COMMENT '有效期(天,-1=永久)',
`bind_machine_code` varchar(64) COMMENT '绑定机器码',
`activate_time` datetime COMMENT '激活时间',
`expire_time` datetime COMMENT '过期时间',
`last_verify_time` datetime COMMENT '最后验证时间',
`unbind_count` int DEFAULT 0 COMMENT '解绑次数',
`remark` text COMMENT '备注',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`license_id`),
UNIQUE KEY `uk_license_key` (`license_key`),
KEY `idx_license_key` (`license_key`),
KEY `idx_product_id` (`product_id`),
KEY `idx_status` (`status`),
KEY `idx_bind_machine_code` (`bind_machine_code`),
CONSTRAINT `fk_license_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='许可证(卡密)表';
-- 设备表
CREATE TABLE IF NOT EXISTS `device` (
`device_id` int NOT NULL AUTO_INCREMENT COMMENT '设备ID',
`machine_code` varchar(64) NOT NULL COMMENT '机器码',
`license_id` int COMMENT '关联许可证ID',
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`software_version` varchar(16) COMMENT '软件版本',
`ip_address` varchar(45) COMMENT 'IP地址',
`status` int NOT NULL DEFAULT 1 COMMENT '状态0=禁用, 1=正常',
`activate_time` datetime COMMENT '激活时间',
`last_verify_time` datetime COMMENT '最后验证时间',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`device_id`),
KEY `idx_machine_code` (`machine_code`),
KEY `idx_product_id` (`product_id`),
KEY `idx_license_id` (`license_id`),
CONSTRAINT `fk_device_license` FOREIGN KEY (`license_id`) REFERENCES `license` (`license_id`) ON DELETE SET NULL,
CONSTRAINT `fk_device_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='设备表';
-- 工单表
CREATE TABLE IF NOT EXISTS `ticket` (
`ticket_id` int NOT NULL AUTO_INCREMENT COMMENT '工单ID',
`ticket_number` varchar(32) NOT NULL COMMENT '工单编号',
`title` varchar(128) NOT NULL COMMENT '工单标题',
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`software_version` varchar(16) COMMENT '软件版本',
`machine_code` varchar(64) COMMENT '机器码',
`license_key` varchar(32) COMMENT '许可证密钥',
`description` text NOT NULL COMMENT '问题描述',
`priority` int NOT NULL DEFAULT 1 COMMENT '优先级0=低, 1=中, 2=高',
`status` int NOT NULL DEFAULT 0 COMMENT '状态0=待处理, 1=处理中, 2=已解决, 3=已关闭',
`operator` varchar(32) COMMENT '处理人(管理员账号)',
`remark` text COMMENT '处理备注',
`contact_person` varchar(64) COMMENT '联系人姓名',
`phone` varchar(20) COMMENT '联系电话',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`resolve_time` datetime COMMENT '解决时间',
`close_time` datetime COMMENT '关闭时间',
PRIMARY KEY (`ticket_id`),
UNIQUE KEY `uk_ticket_number` (`ticket_number`),
KEY `idx_product_id` (`product_id`),
KEY `idx_status` (`status`),
KEY `idx_priority` (`priority`),
CONSTRAINT `fk_ticket_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='工单表';
-- 订单表
CREATE TABLE IF NOT EXISTS `order` (
`order_id` int NOT NULL AUTO_INCREMENT COMMENT '订单ID',
`order_number` varchar(32) NOT NULL COMMENT '订单号',
`product_id` varchar(32) NOT NULL COMMENT '产品ID',
`package_id` varchar(64) NOT NULL COMMENT '套餐ID',
`contact_person` varchar(64) NOT NULL COMMENT '联系人',
`phone` varchar(20) NOT NULL COMMENT '手机号',
`quantity` int NOT NULL DEFAULT 1 COMMENT '数量',
`amount` decimal(10,2) NOT NULL COMMENT '金额',
`status` int NOT NULL DEFAULT 0 COMMENT '状态0=待支付, 1=已支付, 2=已取消, 3=已完成',
`payment_method` varchar(20) COMMENT '支付方式',
`payment_time` datetime COMMENT '支付时间',
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`order_id`),
UNIQUE KEY `uk_order_number` (`order_number`),
KEY `idx_product_id` (`product_id`),
KEY `idx_package_id` (`package_id`),
KEY `idx_status` (`status`),
KEY `idx_create_time` (`create_time`),
CONSTRAINT `fk_order_product` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE,
CONSTRAINT `fk_order_package` FOREIGN KEY (`package_id`) REFERENCES `package` (`package_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单表';
-- 审计日志表
CREATE TABLE IF NOT EXISTS `audit_log` (
`log_id` int NOT NULL AUTO_INCREMENT COMMENT '日志ID',
`admin_id` int NOT NULL COMMENT '管理员ID',
`action` varchar(32) NOT NULL COMMENT '操作类型CREATE, UPDATE, DELETE, LOGIN, LOGOUT, TOGGLE_STATUS',
`target_type` varchar(32) NOT NULL COMMENT '目标类型ADMIN, PRODUCT, LICENSE等',
`target_id` varchar(32) COMMENT '目标ID修改为字符串类型以支持不同类型的ID',
`details` text COMMENT '操作详情JSON格式',
`ip_address` varchar(32) COMMENT '操作IP地址',
`user_agent` varchar(256) COMMENT '用户代理',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
PRIMARY KEY (`log_id`),
KEY `idx_admin_id` (`admin_id`),
KEY `idx_action` (`action`),
KEY `idx_target_type` (`target_type`),
KEY `idx_create_time` (`create_time`),
CONSTRAINT `fk_audit_log_admin` FOREIGN KEY (`admin_id`) REFERENCES `admin` (`admin_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='审计日志表';
-- 插入默认管理员账户
INSERT INTO `admin` (`username`, `password_hash`, `email`, `role`, `status`, `create_time`)
SELECT 'admin', 'pbkdf2:sha256:1000000$fqZbUWPviYXPN90W$b06d43201e93d26a62a1f87c86c0ba79bff7737158fa7d6a62db708b5876bb6d', 'admin@example.com', 1, 1, NOW()
WHERE NOT EXISTS (SELECT 1 FROM `admin` WHERE `username` = 'admin');
-- 插入示例产品
INSERT INTO `product` (`product_id`, `product_name`, `description`, `features`, `status`, `create_time`)
SELECT 'PROD_001', '示例软件产品', '这是一个示例软件产品,用于演示系统功能', '功能1: 用户管理\n功能2: 许可证管理\n功能3: 设备绑定', 1, NOW()
WHERE NOT EXISTS (SELECT 1 FROM `product` WHERE `product_id` = 'PROD_001');
-- 插入示例套餐
INSERT INTO `package` (`package_id`, `product_id`, `name`, `description`, `price`, `duration`, `max_devices`, `stock`, `status`, `create_time`)
SELECT 'PKG_001', 'PROD_001', '月套餐', '一个月使用权限', 29.90, 30, 1, -1, 1, NOW()
WHERE NOT EXISTS (SELECT 1 FROM `package` WHERE `package_id` = 'PKG_001');
INSERT INTO `package` (`package_id`, `product_id`, `name`, `description`, `price`, `duration`, `max_devices`, `stock`, `status`, `create_time`)
SELECT 'PKG_002', 'PROD_001', '年套餐', '一年使用权限', 199.00, 365, 1, -1, 1, NOW()
WHERE NOT EXISTS (SELECT 1 FROM `package` WHERE `package_id` = 'PKG_002');
-- 插入示例版本
INSERT INTO `version` (`product_id`, `version_num`, `platform`, `description`, `update_log`, `publish_status`, `create_time`)
SELECT 'PROD_001', '1.0.0', 'Windows', '初始版本', '初始发布版本', 1, NOW()
WHERE NOT EXISTS (SELECT 1 FROM `version` WHERE `product_id` = 'PROD_001' AND `version_num` = '1.0.0');
SET FOREIGN_KEY_CHECKS = 1;
-- 显示创建的表
SHOW TABLES;