v_bi_alm_all_alarm_year.sql 4.8 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394
  1. -- lawe.v_bi_alm_all_alarm_year source
  2. CREATE OR REPLACE
  3. ALGORITHM = UNDEFINED VIEW `v_bi_alm_all_alarm_year` 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`.`years` AS `years`,
  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`.`years`)) AS `avg_alarm_count`,
  21. if((`m`.`alarm_source` = '性能告警'),
  22. (((60 / 5) * 24) * 365),
  23. (((60 * 2) * 24) * 365)) AS `collection_frequency`,
  24. abs((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`
  25. from
  26. (
  27. select
  28. `aa`.`alarm_object_ip` AS `alarm_object_ip`,
  29. `aa`.`alarm_object_id` AS `alarm_object_id`,
  30. `aa`.`alarm_object_type` AS `alarm_object_type`,
  31. `aa`.`alarm_object_name` AS `alarm_object_name`,
  32. `aa`.`severity_id` AS `severity_id`,
  33. `aa`.`title` AS `title`,
  34. `aa`.`alarm_text` AS `alarm_text`,
  35. `aa`.`clr_status` AS `clr_status`,
  36. `aa`.`alarm_count` AS `alarm_count`,
  37. cast(date_format(`aa`.`occur_time`, '%Y') as unsigned) AS `bg_time`,
  38. cast(date_format(`aa`.`update_time`, '%Y') as unsigned) AS `ed_time`,
  39. (timestampdiff(YEAR,
  40. `aa`.`occur_time`,
  41. `aa`.`update_time`) + 1) AS `years`,
  42. 'YEAR' AS `dtype`,
  43. `dates`.`thedvalue` AS `thedvalue`,
  44. 1 AS `is_active_alarm`,
  45. `aa`.`alarm_source` AS `alarm_source`,
  46. date_format(str_to_date(concat(`dates`.`thedvalue`, '0101'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
  47. date_format((str_to_date(concat(`dates`.`thedvalue`, '0101'), '%Y%m%d') + interval 1 year), '%Y%m%d%H00') AS `thedvalue_e`,
  48. date_format(`aa`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
  49. date_format(`aa`.`update_time`, '%Y%m%d%H%m') AS `update_time`
  50. from
  51. (`t_alm_active_alarm` `aa`
  52. join (
  53. select
  54. distinct floor((`dd`.`YYYYMMDD` / 10000)) AS `thedvalue`
  55. from
  56. `dim_date` `dd`
  57. where
  58. (`dd`.`YYYYMMDD` between 20230101 and 20261231)) `dates`)
  59. union all
  60. select
  61. `ha`.`alarm_object_ip` AS `alarm_object_ip`,
  62. `ha`.`alarm_object_id` AS `alarm_object_id`,
  63. `ha`.`alarm_object_type` AS `alarm_object_type`,
  64. `ha`.`alarm_object_name` AS `alarm_object_name`,
  65. `ha`.`severity_id` AS `severity_id`,
  66. `ha`.`title` AS `title`,
  67. `ha`.`alarm_text` AS `alarm_text`,
  68. `ha`.`clr_status` AS `clr_status`,
  69. `ha`.`alarm_count` AS `alarm_count`,
  70. cast(date_format(`ha`.`occur_time`, '%Y') as unsigned) AS `bg_time`,
  71. cast(date_format(`ha`.`update_time`, '%Y') as unsigned) AS `ed_time`,
  72. (timestampdiff(YEAR,
  73. `ha`.`occur_time`,
  74. `ha`.`update_time`) + 1) AS `years`,
  75. 'YEAR' AS `dtype`,
  76. `dates`.`thedvalue` AS `thedvalue`,
  77. 0 AS `is_active_alarm`,
  78. `ha`.`alarm_source` AS `alarm_source`,
  79. date_format(str_to_date(concat(`dates`.`thedvalue`, '0101'), '%Y%m%d'), '%Y%m%d0000') AS `thedvalue_b`,
  80. date_format((str_to_date(concat(`dates`.`thedvalue`, '0101'), '%Y%m%d%H%m') + interval 1 year), '%Y%m%d%H00') AS `thedvalue_e`,
  81. date_format(`ha`.`occur_time`, '%Y%m%d%H%m') AS `occur_time`,
  82. date_format(`ha`.`update_time`, '%Y%m%d%H%m') AS `update_time`
  83. from
  84. (`t_alm_history_alarm` `ha`
  85. join (
  86. select
  87. distinct floor((`dd`.`YYYYMMDD` / 10000)) AS `thedvalue`
  88. from
  89. `dim_date` `dd`
  90. where
  91. (`dd`.`YYYYMMDD` between 20230101 and 20261231)) `dates`)) `m`
  92. where
  93. (`m`.`thedvalue` between `m`.`bg_time` and `m`.`ed_time`);