a_pm_4g_cu_share_day.sql 5.7 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219
  1. CREATE OR REPLACE FUNCTION app_screen.a_pm_4g_cu_share_day(vi_date character varying)
  2. RETURNS text
  3. LANGUAGE plpgsql
  4. AS $function$
  5. DECLARE
  6. v_date timestamp;
  7. v_next_day timestamp;
  8. v_begin_time timestamp;
  9. v_sql text;
  10. BEGIN
  11. v_date := vi_date::timestamp;
  12. v_next_day := vi_date::timestamp + '1 day'::interval;
  13. v_begin_time := clock_timestamp();
  14. -- 取自忙时
  15. v_sql := 'drop table if exists a_pm_4g_cu_share_day_tmp00';
  16. execute v_sql;
  17. v_sql := 'create temporary table a_pm_4g_cu_share_day_tmp00
  18. (
  19. eci varchar
  20. ,total_tra_mb numeric
  21. )';
  22. execute v_sql;
  23. v_sql := 'insert into a_pm_4g_cu_share_day_tmp00
  24. select
  25. eci,max(total_tra_mb)
  26. from pm_parse.pm_4g_hour_'|| vi_date ||'
  27. group by eci';
  28. execute v_sql;
  29. v_sql := 'drop table if exists a_pm_4g_cu_share_day_tmp01';
  30. execute v_sql;
  31. v_sql := 'create temporary table a_pm_4g_cu_share_day_tmp01
  32. (
  33. eci varchar
  34. ,dl_prb_utilization numeric
  35. )';
  36. execute v_sql;
  37. v_sql := 'insert into a_pm_4g_cu_share_day_tmp01
  38. select
  39. coalesce(c.end_eci,a.eci),max(dl_prb_utilization)
  40. from pm_parse.pm_4g_hour_'|| vi_date ||' a
  41. join a_pm_4g_cu_share_day_tmp00 b
  42. on a.eci = b.eci and a.total_tra_mb = b.total_tra_mb
  43. left join app_screen.nokia_eci_conf c --添加诺基亚eci映射关系表
  44. on a.eci = c.eci
  45. where a.isp = ''联通'' and a.share = ''是''
  46. group by coalesce(c.end_eci,a.eci)';
  47. execute v_sql;
  48. v_sql := 'drop table if exists a_pm_4g_cu_share_day_tmp02';
  49. execute v_sql;
  50. v_sql := 'create temporary table a_pm_4g_cu_share_day_tmp02
  51. (
  52. eci varchar
  53. ,total_tra_mb numeric
  54. ,rrc_max numeric
  55. ,erab_suc numeric
  56. ,erab_req numeric
  57. ,rrc_suc numeric
  58. ,rrc_req numeric
  59. ,erab_abnormal_release numeric
  60. ,lte_drop numeric
  61. ,x2_ho_out_suc numeric
  62. ,s1_ho_out_suc numeric
  63. ,x2_ho_out_req numeric
  64. ,s1_ho_out_req numeric
  65. ,dl_speed_mbps numeric
  66. ,erab_suc_qci1 numeric
  67. ,erab_req_qci1 numeric
  68. ,erab_abnormal_qci1 numeric
  69. ,erab_normal_qci1 numeric
  70. ,ul_pdcp_package_drop numeric
  71. ,ul_pdcp_package_total numeric
  72. ,dl_pdcp_package_drop numeric
  73. ,dl_pdcp_package_total numeric
  74. )';
  75. execute v_sql;
  76. v_sql := 'insert into a_pm_4g_cu_share_day_tmp02
  77. select
  78. coalesce(c.end_eci,a.eci)
  79. ,PDCP_SDU_VOL_UL_plmn1 + PDCP_SDU_VOL_DL_plmn1 total_tra_mb
  80. ,effectiveconnmean_plmn1 rrc_max
  81. ,erab_suc
  82. ,erab_req
  83. ,rrc_suc
  84. ,rrc_req
  85. ,erab_abnormal_release
  86. ,lte_drop
  87. ,x2_ho_out_suc
  88. ,s1_ho_out_suc
  89. ,x2_ho_out_req
  90. ,s1_ho_out_req
  91. ,round(dl_speed_mbps,2)
  92. ,erab_suc_qci1
  93. ,erab_req_qci1
  94. ,erab_abnormal_qci1
  95. ,erab_normal_qci1
  96. ,ul_pdcp_package_drop
  97. ,ul_pdcp_package_total
  98. ,dl_pdcp_package_drop
  99. ,dl_pdcp_package_total
  100. from pm_parse.pm_4g_day_'|| vi_date ||' a
  101. left join app_screen.nokia_eci_conf c --添加诺基亚eci映射关系表
  102. on a.eci = c.eci
  103. where isp = ''联通'' and share = ''是''';
  104. execute v_sql;
  105. -- 删除当前时间数据
  106. v_sql := 'delete from app_screen.a_pm_4g_cu_share_day where sdate = '''|| v_date ||'''';
  107. execute v_sql;
  108. -- 插入目标数据
  109. v_sql := 'insert into app_screen.a_pm_4g_cu_share_day
  110. (
  111. sdate
  112. ,city
  113. ,county
  114. ,cell_number
  115. ,dl_prb_utilization
  116. ,busy_avg_dl_prb_utilization
  117. ,total_tra_mb
  118. ,rrc_max
  119. ,radio_conn_suc_r
  120. ,lte_drop_r
  121. ,ho_out_suc_r
  122. ,dl_speed_mbps_avg_d
  123. ,erab_suc_r_qci1
  124. ,lte_drop_r_qci1
  125. ,ul_pdcp_package_drop_ratio_qci1
  126. ,dl_pdcp_package_drop_ratio_qci1
  127. )
  128. select
  129. '''|| v_date ||'''
  130. ,COALESCE(a.city,''合计'') city
  131. ,COALESCE(a.county,''合计'') county
  132. ,count(distinct d.eci) cell_number
  133. ,avg(c.dl_prb_utilization)*100 dl_prb_utilization
  134. ,case when count(distinct d.eci) = 0 then 0 else sum(case when c.dl_prb_utilization*100 > 65 then 1 else 0 end)*1.0/count(distinct d.eci)*100 end busy_avg_dl_prb_utilization
  135. ,sum(d.total_tra_mb) total_tra_mb
  136. ,round(avg(d.rrc_max),0) rrc_max
  137. ,round((case when sum(d.erab_req)=0 then 0 else (sum(d.erab_suc)/sum(d.erab_req)) end) *100,2) radio_conn_suc_r
  138. ,round((case when sum(d.lte_drop) = 0 then 0 else sum(d.erab_abnormal_release)/sum(d.lte_drop) end) *100,2) lte_drop_r
  139. ,round((case when sum(d.x2_ho_out_req+d.s1_ho_out_req) = 0 then 0 else sum(d.x2_ho_out_suc+d.s1_ho_out_suc)/sum(d.x2_ho_out_req+d.s1_ho_out_req) end) *100,2) ho_out_suc_r
  140. ,round(avg(d.dl_speed_mbps),2) dl_speed_mbps_avg_d
  141. ,round((case when sum(d.erab_req_qci1) = 0 then 0 else sum(d.erab_suc_qci1)/sum(d.erab_req_qci1) end) *100,2) erab_suc_r_qci1
  142. ,round((case when sum(d.erab_abnormal_qci1+d.erab_normal_qci1) = 0 then 0 else sum(d.erab_abnormal_qci1)/sum(d.erab_abnormal_qci1+d.erab_normal_qci1) end) *100,2) lte_drop_r_qci1
  143. ,round((case when sum(d.ul_pdcp_package_total) = 0 then 0 else sum(d.ul_pdcp_package_drop)/sum(d.ul_pdcp_package_total) end)*100,2) ul_pdcp_package_drop_ratio_qci1
  144. ,round((case when sum(d.dl_pdcp_package_total) = 0 then 0 else sum(d.dl_pdcp_package_drop)/sum(d.dl_pdcp_package_total) end)*100,2) dl_pdcp_package_drop_ratio_qci1
  145. from app_screen.county a
  146. left join pm_parse.per_cfg_cell b
  147. on a.city = replace(b.city,''市'','''') and a.county = b.quxian
  148. left join a_pm_4g_cu_share_day_tmp01 c
  149. on b.eci = c.eci
  150. left join a_pm_4g_cu_share_day_tmp02 d
  151. on b.eci = d.eci
  152. group by
  153. grouping sets((),(a.city),(a.city,a.county))';
  154. execute v_sql;
  155. -- 更新质差小区数量和占比
  156. v_sql := 'update app_screen.a_pm_4g_cu_share_day a
  157. set poor_cell_num = b.poor_cell_num,poor_cell_ratio = b.poor_cell_ratio
  158. from(
  159. select
  160. city
  161. ,county
  162. ,poor_cell_num
  163. ,poor_cell_ratio
  164. from app_screen.a_pm_4g_poor_cell_day
  165. where sdate = '''|| v_date ||'''
  166. and operators = ''联通''
  167. ) b
  168. where a.sdate = '''|| v_date ||'''
  169. and a.city = b.city
  170. and a.county = b.county';
  171. execute v_sql;
  172. -- 更新mr
  173. v_sql := 'update app_screen.a_pm_4g_cu_share_day a
  174. set poor_samples_110 = b.poor_samples_110,rsrp_samples = b.rsrp_samples,cove_rage = b.cove_rage
  175. from app_screen.a_pm_4g_mr_cu_share_day b
  176. where a.county = ''合计''
  177. and a.sdate = '''|| v_date ||'''
  178. and b.sdate = (select max(sdate) from app_screen.a_pm_4g_mr_cu_share_day)
  179. and a.city = b.city';
  180. execute v_sql;
  181. return '0';
  182. END;
  183. $function$
  184. ;