v_bi_alm_all_alarm_month.sql 5.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121
  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) * `m`.`days_in_month`),
  23. (((60 * 2) * 24) * `m`.`days_in_month`)) AS `collection_frequency`,
  24. (case
  25. when ((`m`.`occur_time` <= `m`.`thedvalue_b`)
  26. and (`m`.`update_time` >= `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
  27. str_to_date(`m`.`thedvalue_b`,
  28. '%Y%m%d%H%m'),
  29. str_to_date(`m`.`thedvalue_e`,
  30. '%Y%m%d%H%m'))
  31. when ((`m`.`occur_time` > `m`.`thedvalue_b`)
  32. and (`m`.`update_time` >= `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
  33. str_to_date(`m`.`occur_time`,
  34. '%Y%m%d%H%m'),
  35. str_to_date(`m`.`thedvalue_e`,
  36. '%Y%m%d%H%m'))
  37. when ((`m`.`occur_time` <= `m`.`thedvalue_b`)
  38. and (`m`.`update_time` < `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
  39. str_to_date(`m`.`thedvalue_b`,
  40. '%Y%m%d%H%m'),
  41. str_to_date(`m`.`update_time`,
  42. '%Y%m%d%H%m'))
  43. when ((`m`.`occur_time` > `m`.`thedvalue_b`)
  44. and (`m`.`update_time` < `m`.`thedvalue_e`)) then timestampdiff(MINUTE,
  45. str_to_date(`m`.`occur_time`,
  46. '%Y%m%d%H%m'),
  47. str_to_date(`m`.`update_time`,
  48. '%Y%m%d%H%m'))
  49. end) AS `alarm_duration`
  50. from
  51. (
  52. select
  53. `aa`.`alarm_object_ip` AS `alarm_object_ip`,
  54. `aa`.`alarm_object_id` AS `alarm_object_id`,
  55. `aa`.`alarm_object_type` AS `alarm_object_type`,
  56. `aa`.`alarm_object_name` AS `alarm_object_name`,
  57. `aa`.`severity_id` AS `severity_id`,
  58. `aa`.`title` AS `title`,
  59. `aa`.`alarm_text` AS `alarm_text`,
  60. `aa`.`clr_status` AS `clr_status`,
  61. `aa`.`alarm_count` AS `alarm_count`,
  62. cast(date_format(`aa`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
  63. cast(date_format(`aa`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
  64. (timestampdiff(MONTH,
  65. `aa`.`occur_time`,
  66. `aa`.`update_time`) + 1) AS `months`,
  67. 'MONTH' AS `dtype`,
  68. `dates`.`thedvalue` AS `thedvalue`,
  69. 1 AS `is_active_alarm`,
  70. `aa`.`alarm_source` AS `alarm_source`,
  71. dayofmonth(last_day((makedate((`dates`.`thedvalue` / 100), 1) + interval ((`dates`.`thedvalue` % 100) - 1) month))) AS `days_in_month`,
  72. date_format(str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
  73. date_format((str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d') + interval 1 month), '%Y%m%d%H00') AS `thedvalue_e`,
  74. date_format(`aa`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
  75. date_format(`aa`.`update_time`, '%Y%m%d%H%m') AS `update_time`
  76. from
  77. (`t_alm_active_alarm` `aa`
  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`)
  85. union all
  86. select
  87. `ha`.`alarm_object_ip` AS `alarm_object_ip`,
  88. `ha`.`alarm_object_id` AS `alarm_object_id`,
  89. `ha`.`alarm_object_type` AS `alarm_object_type`,
  90. `ha`.`alarm_object_name` AS `alarm_object_name`,
  91. `ha`.`severity_id` AS `severity_id`,
  92. `ha`.`title` AS `title`,
  93. `ha`.`alarm_text` AS `alarm_text`,
  94. `ha`.`clr_status` AS `clr_status`,
  95. `ha`.`alarm_count` AS `alarm_count`,
  96. cast(date_format(`ha`.`occur_time`, '%Y%m') as unsigned) AS `bg_time`,
  97. cast(date_format(`ha`.`update_time`, '%Y%m') as unsigned) AS `ed_time`,
  98. (timestampdiff(MONTH,
  99. `ha`.`occur_time`,
  100. `ha`.`update_time`) + 1) AS `months`,
  101. 'MONTH' AS `dtype`,
  102. `dates`.`thedvalue` AS `thedvalue`,
  103. 0 AS `is_active_alarm`,
  104. `ha`.`alarm_source` AS `alarm_source`,
  105. dayofmonth(last_day((makedate((`dates`.`thedvalue` / 100), 1) + interval ((`dates`.`thedvalue` % 100) - 1) month))) AS `days_in_month`,
  106. date_format(str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
  107. date_format((str_to_date(concat(`dates`.`thedvalue`, '01'), '%Y%m%d%H%m') + interval 1 month), '%Y%m%d%H00') AS `thedvalue_e`,
  108. date_format(`ha`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
  109. date_format(`ha`.`update_time`, '%Y%m%d%H%m') AS `update_time`
  110. from
  111. (`t_alm_history_alarm` `ha`
  112. join (
  113. select
  114. distinct floor((`dd`.`YYYYMMDD` / 100)) AS `thedvalue`
  115. from
  116. `dim_date` `dd`
  117. where
  118. (`dd`.`YYYYMMDD` between 20230101 and 20241231)) `dates`)) `m`
  119. where
  120. (`m`.`thedvalue` between `m`.`bg_time` and `m`.`ed_time`);