v_bi_alm_all_alarm_month.sql 3.4 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687
  1. -- lawe.v_bi_alm_all_alarm_month source
  2. CREATE OR REPLACE
  3. ALGORITHM = UNDEFINED VIEW `v_bi_alm_all_alarm_month` AS
  4. select
  5. `m`.`alarm_object_ip` AS `alarm_object_ip`,
  6. `m`.`alarm_object_id` AS `alarm_object_id`,
  7. `m`.`alarm_object_type` AS `alarm_object_type`,
  8. `m`.`alarm_object_name` AS `alarm_object_name`,
  9. `m`.`severity_id` AS `severity_id`,
  10. `m`.`title` AS `title`,
  11. `m`.`alarm_text` AS `alarm_text`,
  12. `m`.`clr_status` AS `clr_status`,
  13. `m`.`alarm_count` AS `alarm_count`,
  14. `m`.`bg_time` AS `bg_time`,
  15. `m`.`ed_time` AS `ed_time`,
  16. `m`.`months` AS `months`,
  17. `m`.`dtype` AS `dtype`,
  18. `m`.`thedvalue` AS `thedvalue`,
  19. `m`.`is_active_alarm` AS `is_active_alarm`,
  20. floor((`m`.`alarm_count` / `m`.`months`)) AS `avg_alarm_count`,
  21. if((`m`.`alarm_source` = '性能告警'),
  22. ((60 / 5) * 24 * days_in_month),
  23. ((60 * 2) * 24 * days_in_month)) AS `collection_frequency`
  24. from
  25. (
  26. select
  27. `aa`.`alarm_object_ip` AS `alarm_object_ip`,
  28. `aa`.`alarm_object_id` AS `alarm_object_id`,
  29. `aa`.`alarm_object_type` AS `alarm_object_type`,
  30. `aa`.`alarm_object_name` AS `alarm_object_name`,
  31. `aa`.`severity_id` AS `severity_id`,
  32. `aa`.`title` AS `title`,
  33. `aa`.`alarm_text` AS `alarm_text`,
  34. `aa`.`clr_status` AS `clr_status`,
  35. `aa`.`alarm_count` AS `alarm_count`,
  36. cast(date_format(`aa`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
  37. cast(date_format(`aa`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
  38. (timestampdiff(MONTH,
  39. `aa`.`occur_time`,
  40. `aa`.`update_time`) + 1) AS `months`,
  41. 'MONTH' AS `dtype`,
  42. `dates`.`thedvalue` AS `thedvalue`,
  43. 1 AS `is_active_alarm`,
  44. alarm_source,
  45. DAYOFMONTH(last_day(DATE_ADD(MAKEDATE(`dates`.`thedvalue`/100, 1), INTERVAL MOD(`dates`.`thedvalue`,100)-1 MONTH))) days_in_month
  46. from
  47. (`t_alm_active_alarm` `aa`
  48. join (
  49. select
  50. distinct floor((`dd`.`YYYYMMDD` / 100)) AS `thedvalue`
  51. from
  52. `dim_date` `dd`
  53. where
  54. (`dd`.`YYYYMMDD` between 20230101 and 20241231)) `dates`)
  55. union all
  56. select
  57. `ha`.`alarm_object_ip` AS `alarm_object_ip`,
  58. `ha`.`alarm_object_id` AS `alarm_object_id`,
  59. `ha`.`alarm_object_type` AS `alarm_object_type`,
  60. `ha`.`alarm_object_name` AS `alarm_object_name`,
  61. `ha`.`severity_id` AS `severity_id`,
  62. `ha`.`title` AS `title`,
  63. `ha`.`alarm_text` AS `alarm_text`,
  64. `ha`.`clr_status` AS `clr_status`,
  65. `ha`.`alarm_count` AS `alarm_count`,
  66. cast(date_format(`ha`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
  67. cast(date_format(`ha`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
  68. (timestampdiff(MONTH,
  69. `ha`.`occur_time`,
  70. `ha`.`update_time`) + 1) AS `months`,
  71. 'MONTH' AS `dtype`,
  72. `dates`.`thedvalue` AS `thedvalue`,
  73. 0 AS `is_active_alarm`,
  74. alarm_source,
  75. DAYOFMONTH(last_day(DATE_ADD(MAKEDATE(`dates`.`thedvalue`/100, 1), INTERVAL MOD(`dates`.`thedvalue`,100)-1 MONTH))) days_in_month
  76. from
  77. (`t_alm_history_alarm` `ha`
  78. join (
  79. select
  80. distinct floor((`dd`.`YYYYMMDD` / 100)) AS `thedvalue`
  81. from
  82. `dim_date` `dd`
  83. where
  84. (`dd`.`YYYYMMDD` between 20230101 and 20241231)) `dates`)) `m`
  85. where
  86. (`m`.`thedvalue` between `m`.`bg_time` and `m`.`ed_time`);