USE `data_center_new`; /*Table structure for table `device_alert_template` */ DROP TABLE IF EXISTS `device_alert_template`; CREATE TABLE `device_alert_template` ( `id` bigint NOT NULL AUTO_INCREMENT, `company_id` bigint DEFAULT NULL, `tmpl_name` varchar(100) DEFAULT NULL, `level` varchar(20) DEFAULT NULL COMMENT '告警级别', `message` varchar(999) DEFAULT NULL COMMENT '告警信息', `flag` int DEFAULT '0' COMMENT '0 开启,1关闭', `template_defs` varchar(999) DEFAULT NULL COMMENT '模板定义', `forward_type` varchar(20) CHARACTER SET utf8 COLLATE utf8_general_ci DEFAULT NULL COMMENT '转发类型api, mail, sms', `alert_cancel_template_defs` varchar(999) DEFAULT '' COMMENT '告警解除模板定义', `alert_cancel_message` varchar(999) DEFAULT '' COMMENT '告警解除模板初步填充后内容', `alert_title` varchar(999) DEFAULT NULL, `alert_cancel_title` varchar(999) DEFAULT NULL, `alert_recipient_mail` varchar(1000) DEFAULT NULL COMMENT '邮件通知对象', `alert_recipient_sms` varchar(1000) DEFAULT NULL COMMENT '短信通知对象', PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COMMENT='设备告警信息'; /*Table structure for table `device_alert_template_bind` */ DROP TABLE IF EXISTS `device_alert_template_bind`; CREATE TABLE `device_alert_template_bind` ( `device_info_id` int NOT NULL COMMENT 'device_info表里的id', `device_alert_template_id` bigint NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3; /** 旧的设备的告警配置,插入到模板去 **/ USE `data_center_new`; DROP procedure IF EXISTS `data_center_new`.`add_tmpl`; DELIMITER $$ CREATE PROCEDURE add_tmpl() BEGIN DECLARE done INT DEFAULT 0; DECLARE config_id , new_template_id INT; DECLARE alert_name_val VARCHAR(999); DECLARE template_defs_val VARCHAR(999); DECLARE message_val VARCHAR(999); DECLARE alert_cancel_template_defs_val VARCHAR(999); DECLARE alert_cancel_message_val VARCHAR(999); DECLARE alert_title_val VARCHAR(255); DECLARE alert_cancel_title_val VARCHAR(255); DECLARE forward_type_val VARCHAR(255); DECLARE company_id_val INT; DECLARE config_cursor CURSOR FOR SELECT dac.device_config_id, dac.alert_name, dac.template_defs, dac.message, dac.alert_cancel_template_defs, dac.alert_cancel_message, dac.alert_title, dac.alert_cancel_title, dac.forward_type, di.company_id FROM device_alert_config dac INNER JOIN device_info di ON dac.device_config_id = di.id WHERE dac.flag != 1 AND di.flag != 1; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; OPEN config_cursor; config_loop: LOOP FETCH config_cursor INTO config_id, alert_name_val, template_defs_val, message_val, alert_cancel_template_defs_val, alert_cancel_message_val, alert_title_val, alert_cancel_title_val, forward_type_val, company_id_val; IF done THEN LEAVE config_loop; END IF; -- 检查是否已存在相同的记录 IF NOT EXISTS ( SELECT 1 FROM device_alert_template WHERE template_defs = template_defs_val AND alert_cancel_template_defs = alert_cancel_template_defs_val AND alert_title = alert_title_val AND alert_cancel_title = alert_cancel_title_val AND forward_type = forward_type_val AND company_id = company_id_val ) THEN -- 插入新记录 INSERT INTO device_alert_template ( tmpl_name, template_defs, message, alert_cancel_template_defs, alert_cancel_message, alert_title, alert_cancel_title, forward_type, company_id ) VALUES ( alert_name_val, template_defs_val, message_val, alert_cancel_template_defs_val, alert_cancel_message_val, alert_title_val, alert_cancel_title_val, forward_type_val, company_id_val ); -- 获取刚插入的记录的自增主键值 SET new_template_id = LAST_INSERT_ID(); -- 向device_alert_template_bind表插入对应关系 INSERT INTO device_alert_template_bind (device_info_id, device_alert_template_id) SELECT dac.device_config_id, new_template_id FROM device_alert_config dac INNER JOIN device_info di ON dac.device_config_id = di.id WHERE dac.flag != 1 AND di.flag != 1 AND dac.template_defs = template_defs_val AND dac.alert_cancel_template_defs = alert_cancel_template_defs_val AND dac.alert_title = alert_title_val AND dac.alert_cancel_title = alert_cancel_title_val AND dac.forward_type = forward_type_val AND di.company_id = company_id_val; END IF; END LOOP; CLOSE config_cursor; END $$ DELIMITER ; CALL add_tmpl(); DROP procedure IF EXISTS `data_center_new`.`add_tmpl`;