Kamixitong/init_mysql.sql
2025-12-12 11:35:14 +08:00

453 lines
22 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 数据库初始化脚本
-- =====================================================
-- 创建时间: 2025-12-11
-- 版本: v1.0
-- 描述: 创建所有数据表、索引、约束和初始数据
-- =====================================================
-- 设置字符集和排序规则
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- =====================================================
-- 1. 管理员表 (admin)
-- =====================================================
DROP TABLE IF EXISTS `admin`;
CREATE TABLE `admin` (
`admin_id` int(11) NOT NULL AUTO_INCREMENT COMMENT '管理员ID',
`username` varchar(32) NOT NULL COMMENT '用户名',
`password_hash` varchar(128) NOT NULL COMMENT '密码哈希',
`email` varchar(64) DEFAULT NULL COMMENT '邮箱',
`role` int(11) NOT NULL DEFAULT '0' COMMENT '角色: 0=普通管理员, 1=超级管理员',
`status` int(11) NOT NULL DEFAULT '1' COMMENT '状态: 0=禁用, 1=正常',
`is_deleted` int(11) NOT NULL DEFAULT '0' COMMENT '软删除标记: 0=未删除, 1=已删除',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`delete_time` datetime DEFAULT NULL COMMENT '删除时间',
`last_login_time` datetime DEFAULT NULL COMMENT '最后登录时间',
`last_login_ip` varchar(32) DEFAULT NULL COMMENT '最后登录IP',
PRIMARY KEY (`admin_id`),
UNIQUE KEY `uk_username` (`username`),
KEY `idx_status` (`status`),
KEY `idx_is_deleted` (`is_deleted`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='管理员表';
-- =====================================================
-- 2. 产品表 (product)
-- =====================================================
DROP TABLE IF EXISTS `product`;
CREATE TABLE `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) DEFAULT NULL COMMENT '产品图片路径',
`status` int(11) NOT NULL DEFAULT '1' COMMENT '状态: 0=禁用, 1=启用',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL 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='产品表';
-- =====================================================
-- 3. 套餐表 (package)
-- =====================================================
DROP TABLE IF EXISTS `package`;
CREATE TABLE `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` double NOT NULL COMMENT '价格',
`duration` int(11) NOT NULL COMMENT '时长(天)',
`max_devices` int(11) NOT NULL DEFAULT '1' COMMENT '最大设备数',
`stock` int(11) NOT NULL DEFAULT '-1' COMMENT '库存,-1表示无限',
`status` int(11) NOT NULL DEFAULT '1' COMMENT '状态: 0=禁用, 1=启用',
`sort_order` int(11) NOT NULL DEFAULT '0' COMMENT '排序',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL 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_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='产品套餐表';
-- =====================================================
-- 4. 许可证表 (license)
-- =====================================================
DROP TABLE IF EXISTS `license`;
CREATE TABLE `license` (
`license_id` int(11) NOT NULL AUTO_INCREMENT COMMENT '卡密ID',
`license_key` varchar(35) NOT NULL COMMENT '卡密格式XXXX-XXXX-XXXX-XXXX',
`product_id` varchar(32) NOT NULL COMMENT '关联产品ID',
`type` int(11) NOT NULL DEFAULT '1' COMMENT '类型: 0=试用, 1=正式',
`status` int(11) NOT NULL DEFAULT '0' COMMENT '状态: 0=未激活, 1=已激活, 2=已过期, 3=已禁用',
`valid_days` int(11) NOT NULL COMMENT '有效期(天,-1=永久)',
`bind_machine_code` varchar(64) DEFAULT NULL COMMENT '绑定的机器码',
`activate_time` datetime DEFAULT NULL COMMENT '激活时间',
`expire_time` datetime DEFAULT NULL COMMENT '过期时间',
`last_verify_time` datetime DEFAULT NULL COMMENT '最后验证时间',
`unbind_count` int(11) NOT NULL DEFAULT '0' COMMENT '解绑次数',
`remark` text COMMENT '备注',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`license_id`),
UNIQUE KEY `uk_license_key` (`license_key`),
KEY `idx_product_id` (`product_id`),
KEY `idx_status` (`status`),
KEY `idx_type` (`type`),
KEY `idx_bind_machine_code` (`bind_machine_code`),
CONSTRAINT `fk_license_product_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='许可证(卡密)表';
-- =====================================================
-- 5. 设备表 (device)
-- =====================================================
DROP TABLE IF EXISTS `device`;
CREATE TABLE `device` (
`device_id` int(11) NOT NULL AUTO_INCREMENT COMMENT '设备ID',
`machine_code` varchar(64) NOT NULL COMMENT '机器码',
`license_id` int(11) DEFAULT NULL COMMENT '关联卡密ID',
`product_id` varchar(32) NOT NULL COMMENT '关联产品ID',
`software_version` varchar(16) DEFAULT NULL COMMENT '软件版本',
`ip_address` varchar(45) DEFAULT NULL COMMENT 'IP地址支持IPv6',
`status` int(11) NOT NULL DEFAULT '1' COMMENT '状态: 0=禁用, 1=正常',
`activate_time` datetime DEFAULT NULL COMMENT '激活时间',
`last_verify_time` datetime DEFAULT NULL COMMENT '最后验证时间',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`device_id`),
UNIQUE KEY `uk_machine_code` (`machine_code`),
KEY `idx_license_id` (`license_id`),
KEY `idx_product_id` (`product_id`),
KEY `idx_status` (`status`),
KEY `idx_software_version` (`software_version`),
CONSTRAINT `fk_device_license_id` FOREIGN KEY (`license_id`) REFERENCES `license` (`license_id`) ON DELETE SET NULL,
CONSTRAINT `fk_device_product_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='设备表';
-- =====================================================
-- 6. 版本表 (version)
-- =====================================================
DROP TABLE IF EXISTS `version`;
CREATE TABLE `version` (
`version_id` int(11) NOT NULL AUTO_INCREMENT COMMENT '版本ID',
`product_id` varchar(32) NOT NULL COMMENT '关联产品ID',
`version_num` varchar(16) NOT NULL COMMENT '版本号',
`platform` varchar(32) DEFAULT NULL COMMENT '平台信息',
`description` text COMMENT '版本描述',
`update_log` text COMMENT '更新日志',
`download_url` varchar(255) DEFAULT NULL COMMENT '下载链接',
`min_license_version` varchar(16) DEFAULT NULL COMMENT '兼容最低卡密版本',
`force_update` int(11) NOT NULL DEFAULT '0' COMMENT '强制更新: 0=否, 1=是',
`download_status` int(11) NOT NULL DEFAULT '1' COMMENT '下载状态: 0=禁用, 1=启用',
`publish_status` int(11) NOT NULL DEFAULT '0' COMMENT '发布状态: 0=草稿, 1=已发布, 2=已回滚',
`file_hash` varchar(64) DEFAULT NULL COMMENT '文件SHA256哈希值',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL 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`),
KEY `idx_download_status` (`download_status`),
CONSTRAINT `fk_version_product_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='版本表';
-- =====================================================
-- 7. 订单表 (order)
-- =====================================================
DROP TABLE IF EXISTS `order`;
CREATE TABLE `order` (
`order_id` int(11) 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(11) NOT NULL DEFAULT '1' COMMENT '数量',
`amount` double NOT NULL COMMENT '金额',
`status` int(11) NOT NULL DEFAULT '0' COMMENT '状态: 0=待支付, 1=已支付, 2=已取消, 3=已完成',
`payment_method` varchar(20) DEFAULT NULL COMMENT '支付方式',
`payment_time` datetime DEFAULT NULL COMMENT '支付时间',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL 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_status` (`status`),
KEY `idx_package_id` (`package_id`),
CONSTRAINT `fk_order_product_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE,
CONSTRAINT `fk_order_package_id` FOREIGN KEY (`package_id`) REFERENCES `package` (`package_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单表';
-- =====================================================
-- 8. 工单表 (ticket)
-- =====================================================
DROP TABLE IF EXISTS `ticket`;
CREATE TABLE `ticket` (
`ticket_id` int(11) 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) DEFAULT NULL COMMENT '软件版本',
`machine_code` varchar(64) DEFAULT NULL COMMENT '机器码',
`license_key` varchar(35) DEFAULT NULL COMMENT '卡密',
`description` text NOT NULL COMMENT '问题描述',
`priority` int(11) NOT NULL DEFAULT '1' COMMENT '优先级: 0=低, 1=中, 2=高',
`status` int(11) NOT NULL DEFAULT '0' COMMENT '状态: 0=待处理, 1=处理中, 2=已解决, 3=已关闭',
`operator` varchar(32) DEFAULT NULL COMMENT '处理人(管理员账号)',
`remark` text COMMENT '处理备注',
`contact_person` varchar(64) DEFAULT NULL COMMENT '联系人姓名',
`phone` varchar(20) DEFAULT NULL COMMENT '联系电话',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`resolve_time` datetime DEFAULT NULL COMMENT '解决时间',
`close_time` datetime DEFAULT NULL 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`),
KEY `idx_operator` (`operator`),
CONSTRAINT `fk_ticket_product_id` FOREIGN KEY (`product_id`) REFERENCES `product` (`product_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='工单表';
-- =====================================================
-- 9. 审计日志表 (audit_log)
-- =====================================================
DROP TABLE IF EXISTS `audit_log`;
CREATE TABLE `audit_log` (
`log_id` int(11) NOT NULL AUTO_INCREMENT COMMENT '日志ID',
`admin_id` int(11) 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) DEFAULT NULL COMMENT '目标ID',
`details` text COMMENT '操作详情JSON格式',
`ip_address` varchar(32) DEFAULT NULL COMMENT '操作IP地址',
`user_agent` varchar(256) DEFAULT NULL 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_target_id` (`target_id`),
KEY `idx_create_time` (`create_time`),
CONSTRAINT `fk_audit_log_admin_id` FOREIGN KEY (`admin_id`) REFERENCES `admin` (`admin_id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='审计日志表';
-- =====================================================
-- 插入初始数据
-- =====================================================
-- 插入默认超级管理员账号
-- 用户名: admin
-- 密码: admin123 (首次登录后请立即修改)
-- 注意:此哈希值由 Werkzeug 的 generate_password_hash 生成,使用 PBKDF2-SHA256 算法
INSERT INTO `admin` (`username`, `password_hash`, `email`, `role`, `status`) VALUES
('admin', 'pbkdf2:sha256:600000$03EhhcMpfObidblD$e0f7de0e1028c8ab004c48ec28a3380950568080abd214055f67d02300e2786d', 'admin@example.com', 1, 1);
-- 插入示例产品
INSERT INTO `product` (`product_id`, `product_name`, `description`, `features`, `status`) VALUES
('PROD_EXAMPLE', '示例产品', '这是一个示例产品,用于演示系统功能', '功能1: 核心功能\n功能2: 高级功能\n功能3: 专业功能', 1);
-- 插入示例套餐
INSERT INTO `package` (`package_id`, `product_id`, `name`, `description`, `price`, `duration`, `max_devices`, `stock`, `status`, `sort_order`) VALUES
('PKG_DEMO_1', 'PROD_EXAMPLE', '试用版', '30天试用期可体验基础功能', 0.00, 30, 1, 100, 1, 1),
('PKG_DEMO_2', 'PROD_EXAMPLE', '标准版', '一年有效期支持3台设备', 299.00, 365, 3, 50, 1, 2),
('PKG_DEMO_3', 'PROD_EXAMPLE', '专业版', '永久授权支持10台设备', 999.00, -1, 10, -1, 1, 3);
-- 插入示例版本
INSERT INTO `version` (`product_id`, `version_num`, `platform`, `description`, `update_log`, `download_url`, `publish_status`, `download_status`) VALUES
('PROD_EXAMPLE', '1.0.0', 'Windows/Mac/Linux', '首个正式版本', '初始版本发布', '/downloads/product_v1.0.0.exe', 1, 1);
-- =====================================================
-- 创建视图(可选,用于简化查询)
-- =====================================================
-- 视图:产品统计信息
CREATE OR REPLACE VIEW `view_product_stats` AS
SELECT
p.product_id,
p.product_name,
COUNT(DISTINCT l.license_id) AS total_licenses,
COUNT(DISTINCT CASE WHEN l.status = 1 THEN l.license_id END) AS active_licenses,
COUNT(DISTINCT d.device_id) AS total_devices,
COUNT(DISTINCT CASE WHEN d.status = 1 THEN d.device_id END) AS active_devices,
(SELECT version_num FROM version v WHERE v.product_id = p.product_id AND v.publish_status = 1 ORDER BY v.create_time DESC LIMIT 1) AS latest_version
FROM product p
LEFT JOIN license l ON p.product_id = l.product_id
LEFT JOIN device d ON p.product_id = d.product_id
GROUP BY p.product_id, p.product_name;
-- 视图:卡密详细信息
CREATE OR REPLACE VIEW `view_license_detail` AS
SELECT
l.license_id,
l.license_key,
l.product_id,
p.product_name,
l.type,
CASE WHEN l.type = 0 THEN '试用' ELSE '正式' END AS type_name,
l.status,
CASE
WHEN l.status = 0 THEN '未激活'
WHEN l.status = 1 THEN '已激活'
WHEN l.status = 2 THEN '已过期'
WHEN l.status = 3 THEN '已禁用'
ELSE '未知'
END AS status_name,
l.valid_days,
l.bind_machine_code,
l.activate_time,
l.expire_time,
l.last_verify_time,
l.unbind_count,
CASE
WHEN l.valid_days = -1 THEN '永久'
WHEN l.expire_time IS NULL THEN CONCAT(l.valid_days, '')
WHEN l.expire_time < NOW() THEN CONCAT(TIMESTAMPDIFF(DAY, l.expire_time, NOW()), '天前过期')
ELSE CONCAT(TIMESTAMPDIFF(DAY, NOW(), l.expire_time), '')
END AS remaining_days_display,
l.create_time
FROM license l
LEFT JOIN product p ON l.product_id = p.product_id;
-- =====================================================
-- 创建存储过程(可选,用于常用操作)
-- =====================================================
DELIMITER //
-- 存储过程:清理过期卡密
CREATE PROCEDURE `CleanExpiredLicenses`()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE v_license_id INT;
DECLARE cur CURSOR FOR
SELECT license_id FROM license
WHERE status = 1 AND expire_time IS NOT NULL AND expire_time < NOW();
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop: LOOP
FETCH cur INTO v_license_id;
IF done THEN
LEAVE read_loop;
END IF;
UPDATE license
SET status = 2
WHERE license_id = v_license_id;
END LOOP;
CLOSE cur;
SELECT CONCAT('已清理 ', ROW_COUNT(), ' 个过期卡密') AS result;
END//
-- 存储过程:生成卡密
CREATE PROCEDURE `GenerateLicenses`(
IN p_product_id VARCHAR(32),
IN p_type INT,
IN p_valid_days INT,
IN p_count INT,
IN p_prefix VARCHAR(10)
)
BEGIN
DECLARE i INT DEFAULT 0;
DECLARE v_license_key VARCHAR(35);
DECLARE v_chars VARCHAR(36) DEFAULT 'ABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789';
WHILE i < p_count DO
SET v_license_key = CONCAT(
p_prefix,
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1), '-',
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1), '-',
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1), '-',
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1),
SUBSTRING(v_chars, FLOOR(RAND() * 36) + 1, 1)
);
INSERT INTO license (license_key, product_id, type, valid_days, status)
VALUES (v_license_key, p_product_id, p_type, p_valid_days, 0);
SET i = i + 1;
END WHILE;
SELECT CONCAT('成功生成 ', p_count, ' 个卡密') AS result;
END//
DELIMITER ;
-- =====================================================
-- 创建触发器(可选,用于自动操作)
-- =====================================================
DELIMITER //
-- 触发器:更新设备数量统计
CREATE TRIGGER `tr_license_activate`
AFTER UPDATE ON `license`
FOR EACH ROW
BEGIN
IF NEW.status = 1 AND OLD.status != 1 THEN
-- 卡密被激活时,记录审计日志
INSERT INTO audit_log (admin_id, action, target_type, target_id, details, ip_address)
VALUES (0, 'ACTIVATE', 'LICENSE', NEW.license_id, CONCAT('License activated: ', NEW.license_key), NULL);
END IF;
END//
-- 触发器:自动清理过期设备
CREATE TRIGGER `tr_device_cleanup`
BEFORE UPDATE ON `device`
FOR EACH ROW
BEGIN
IF NEW.status = 0 AND OLD.status != 0 THEN
-- 设备被禁用时,记录审计日志
INSERT INTO audit_log (admin_id, action, target_type, target_id, details, ip_address)
VALUES (0, 'DISABLE', 'DEVICE', NEW.device_id, CONCAT('Device disabled: ', NEW.machine_code), NULL);
END IF;
END//
DELIMITER ;
-- =====================================================
-- 设置外键检查
-- =====================================================
SET FOREIGN_KEY_CHECKS = 1;
-- =====================================================
-- 完成提示
-- =====================================================
SELECT 'MySQL 数据库初始化完成!' AS message;
SELECT '默认管理员账号: admin / admin123 (首次登录后请立即修改)' AS default_account;
SELECT '示例产品已创建: PROD_EXAMPLE' AS sample_data;