123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121 |
- -- lawe.v_bi_alm_all_alarm_month source
- CREATE OR REPLACE
- ALGORITHM = UNDEFINED VIEW `v_bi_alm_all_alarm_month` AS
- select
- `m`.`alarm_object_ip` AS `alarm_object_ip`,
- `m`.`alarm_object_id` AS `alarm_object_id`,
- `m`.`alarm_object_type` AS `alarm_object_type`,
- `m`.`alarm_object_name` AS `alarm_object_name`,
- `m`.`severity_id` AS `severity_id`,
- `m`.`title` AS `title`,
- `m`.`alarm_text` AS `alarm_text`,
- `m`.`clr_status` AS `clr_status`,
- `m`.`alarm_count` AS `alarm_count`,
- `m`.`bg_time` AS `bg_time`,
- `m`.`ed_time` AS `ed_time`,
- `m`.`months` AS `months`,
- `m`.`dtype` AS `dtype`,
- `m`.`thedvalue` AS `thedvalue`,
- `m`.`is_active_alarm` AS `is_active_alarm`,
- floor((`m`.`alarm_count` / `m`.`months`)) AS `avg_alarm_count`,
- if((`m`.`alarm_source` = '性能告警'),
- (((60 / 5) * 24) * `m`.`days_in_month`),
- (((60 * 2) * 24) * `m`.`days_in_month`)) AS `collection_frequency`,
- (case
- when ((`m`.`occur_time` <= `m`.`thedvalue_b`)
- and (`m`.`update_time` >= `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
- str_to_date(`m`.`thedvalue_b`,
- '%Y%m%d%H%m'),
- str_to_date(`m`.`thedvalue_e`,
- '%Y%m%d%H%m'))
- when ((`m`.`occur_time` > `m`.`thedvalue_b`)
- and (`m`.`update_time` >= `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
- str_to_date(`m`.`occur_time`,
- '%Y%m%d%H%m'),
- str_to_date(`m`.`thedvalue_e`,
- '%Y%m%d%H%m'))
- when ((`m`.`occur_time` <= `m`.`thedvalue_b`)
- and (`m`.`update_time` < `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
- str_to_date(`m`.`thedvalue_b`,
- '%Y%m%d%H%m'),
- str_to_date(`m`.`update_time`,
- '%Y%m%d%H%m'))
- when ((`m`.`occur_time` > `m`.`thedvalue_b`)
- and (`m`.`update_time` < `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
- str_to_date(`m`.`occur_time`,
- '%Y%m%d%H%m'),
- str_to_date(`m`.`update_time`,
- '%Y%m%d%H%m'))
- end) AS `alarm_duration`
- from
- (
- select
- `aa`.`alarm_object_ip` AS `alarm_object_ip`,
- `aa`.`alarm_object_id` AS `alarm_object_id`,
- `aa`.`alarm_object_type` AS `alarm_object_type`,
- `aa`.`alarm_object_name` AS `alarm_object_name`,
- `aa`.`severity_id` AS `severity_id`,
- `aa`.`title` AS `title`,
- `aa`.`alarm_text` AS `alarm_text`,
- `aa`.`clr_status` AS `clr_status`,
- `aa`.`alarm_count` AS `alarm_count`,
- cast(date_format(`aa`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
- cast(date_format(`aa`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
- (timestampdiff(MONTH,
- `aa`.`occur_time`,
- `aa`.`update_time`) + 1) AS `months`,
- 'MONTH' AS `dtype`,
- `dates`.`thedvalue` AS `thedvalue`,
- 1 AS `is_active_alarm`,
- `aa`.`alarm_source` AS `alarm_source`,
- dayofmonth(last_day((makedate((`dates`.`thedvalue` / 100), 1) + interval ((`dates`.`thedvalue` % 100) - 1) month))) AS `days_in_month`,
- date_format(str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
- date_format((str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d') + interval 1 month), '%Y%m%d%H00') AS `thedvalue_e`,
- date_format(`aa`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
- date_format(`aa`.`update_time`, '%Y%m%d%H%m') AS `update_time`
- from
- (`t_alm_active_alarm` `aa`
- join (
- select
- distinct floor((`dd`.`YYYYMMDD` / 100)) AS `thedvalue`
- from
- `dim_date` `dd`
- where
- (`dd`.`YYYYMMDD` between 20230101 and 20241231)) `dates`)
- union all
- select
- `ha`.`alarm_object_ip` AS `alarm_object_ip`,
- `ha`.`alarm_object_id` AS `alarm_object_id`,
- `ha`.`alarm_object_type` AS `alarm_object_type`,
- `ha`.`alarm_object_name` AS `alarm_object_name`,
- `ha`.`severity_id` AS `severity_id`,
- `ha`.`title` AS `title`,
- `ha`.`alarm_text` AS `alarm_text`,
- `ha`.`clr_status` AS `clr_status`,
- `ha`.`alarm_count` AS `alarm_count`,
- cast(date_format(`ha`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
- cast(date_format(`ha`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
- (timestampdiff(MONTH,
- `ha`.`occur_time`,
- `ha`.`update_time`) + 1) AS `months`,
- 'MONTH' AS `dtype`,
- `dates`.`thedvalue` AS `thedvalue`,
- 0 AS `is_active_alarm`,
- `ha`.`alarm_source` AS `alarm_source`,
- dayofmonth(last_day((makedate((`dates`.`thedvalue` / 100), 1) + interval ((`dates`.`thedvalue` % 100) - 1) month))) AS `days_in_month`,
- date_format(str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
- date_format((str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d%H%m') + interval 1 month), '%Y%m%d%H00') AS `thedvalue_e`,
- date_format(`ha`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
- date_format(`ha`.`update_time`, '%Y%m%d%H%m') AS `update_time`
- from
- (`t_alm_history_alarm` `ha`
- join (
- select
- distinct floor((`dd`.`YYYYMMDD` / 100)) AS `thedvalue`
- from
- `dim_date` `dd`
- where
- (`dd`.`YYYYMMDD` between 20230101 and 20241231)) `dates`)) `m`
- where
- (`m`.`thedvalue` between `m`.`bg_time` and `m`.`ed_time`);
|