시간대별 VDS-검지기 교통량 통계.SQL 5.4 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394
  1. SELECT LY.CTLR_MNGM_NMBR, LY.VDS_CTLR_ID, LY.LCTN, LY.DTCT_NMBR, LY.ISTL_LANE, LY.VDS_DTCT_NM,
  2. LX.TRFTYPE,
  3. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(TOTTFVL, 0, '-', TOTTFVL)) AS TOTTFVL,
  4. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(AVGTFVL, 0, '-', AVGTFVL)) AS AVGTFVL, CNT,
  5. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L00, NULL, '-', L00)) AS C00,
  6. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L01, NULL, '-', L01)) AS C01,
  7. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L02, NULL, '-', L02)) AS C02,
  8. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L03, NULL, '-', L03)) AS C03,
  9. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L04, NULL, '-', L04)) AS C04,
  10. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L05, NULL, '-', L05)) AS C05,
  11. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L06, NULL, '-', L06)) AS C06,
  12. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L07, NULL, '-', L07)) AS C07,
  13. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L08, NULL, '-', L08)) AS C08,
  14. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L09, NULL, '-', L09)) AS C09,
  15. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L10, NULL, '-', L10)) AS C10,
  16. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L11, NULL, '-', L11)) AS C11,
  17. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L12, NULL, '-', L12)) AS C12,
  18. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L13, NULL, '-', L13)) AS C13,
  19. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L14, NULL, '-', L14)) AS C14,
  20. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L15, NULL, '-', L15)) AS C15,
  21. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L16, NULL, '-', L16)) AS C16,
  22. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L17, NULL, '-', L17)) AS C17,
  23. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L18, NULL, '-', L18)) AS C18,
  24. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L19, NULL, '-', L19)) AS C19,
  25. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L20, NULL, '-', L20)) AS C20,
  26. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L21, NULL, '-', L21)) AS C21,
  27. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L22, NULL, '-', L22)) AS C22,
  28. DECODE(LX.DTCT_NMBR, NULL, '-', DECODE(L23, NULL, '-', L23)) AS C23
  29. FROM (
  30. SELECT GROUPING(DTCT_NMBR) AS GROUPING_DTCT_NMBR,
  31. GROUPING(ISTL_LANE) AS GROUPING_ISTL_LANE,
  32. GROUPING(TRFTYPE) AS GROUPING_TRFTYPE,
  33. CASE WHEN GROUPING(DTCT_NMBR ) = 1 THEN '°ËÁö±â' ELSE DTCT_NMBR END AS GROUP_DTCT_NMBR,
  34. CASE WHEN GROUPING(ISTL_LANE) = 1 THEN 'Â÷·Î' ELSE ISTL_LANE END AS GROUP_ISTL_LANE,
  35. CASE WHEN GROUPING(TRFTYPE) = 1 THEN '¼Ò°è' ELSE TRFTYPE END AS GROUP_TRFTYPE,
  36. DTCT_NMBR, ISTL_LANE, TRFTYPE,
  37. SUM(TFVL) TOTTFVL,
  38. ROUND(AVG(TFVL), 0) AVGTFVL,
  39. COUNT(1) AS CNT,
  40. SUM(DECODE(STATHOUR, '00', TFVL)) AS L00,
  41. SUM(DECODE(STATHOUR, '01', TFVL)) AS L01,
  42. SUM(DECODE(STATHOUR, '02', TFVL)) AS L02,
  43. SUM(DECODE(STATHOUR, '03', TFVL)) AS L03,
  44. SUM(DECODE(STATHOUR, '04', TFVL)) AS L04,
  45. SUM(DECODE(STATHOUR, '05', TFVL)) AS L05,
  46. SUM(DECODE(STATHOUR, '06', TFVL)) AS L06,
  47. SUM(DECODE(STATHOUR, '07', TFVL)) AS L07,
  48. SUM(DECODE(STATHOUR, '08', TFVL)) AS L08,
  49. SUM(DECODE(STATHOUR, '09', TFVL)) AS L09,
  50. SUM(DECODE(STATHOUR, '10', TFVL)) AS L10,
  51. SUM(DECODE(STATHOUR, '11', TFVL)) AS L11,
  52. SUM(DECODE(STATHOUR, '12', TFVL)) AS L12,
  53. SUM(DECODE(STATHOUR, '13', TFVL)) AS L13,
  54. SUM(DECODE(STATHOUR, '14', TFVL)) AS L14,
  55. SUM(DECODE(STATHOUR, '15', TFVL)) AS L15,
  56. SUM(DECODE(STATHOUR, '16', TFVL)) AS L16,
  57. SUM(DECODE(STATHOUR, '17', TFVL)) AS L17,
  58. SUM(DECODE(STATHOUR, '18', TFVL)) AS L18,
  59. SUM(DECODE(STATHOUR, '19', TFVL)) AS L19,
  60. SUM(DECODE(STATHOUR, '20', TFVL)) AS L20,
  61. SUM(DECODE(STATHOUR, '21', TFVL)) AS L21,
  62. SUM(DECODE(STATHOUR, '22', TFVL)) AS L22,
  63. SUM(DECODE(STATHOUR, '23', TFVL)) AS L23
  64. FROM (
  65. SELECT Y.DTCT_NMBR, Y.VDS_DTCT_NM, TO_CHAR(Y.ISTL_LANE) AS ISTL_LANE,
  66. X.TRFTYPE, X.STATHOUR, X.TFVL
  67. FROM (SELECT /*+ INDEX(A IX_VDS_DTCT_HH_STAT_PK) */
  68. 'DTCT' AS TRFTYPE,
  69. A.DTCT_NMBR AS DTCT_NMBR, SUBSTR(A.STAT_DT, 9, 2) AS STATHOUR, A.TFVL AS TFVL
  70. FROM TB_VDS_DTCT_HH_STAT A
  71. WHERE 1=1
  72. AND A.STAT_DT BETWEEN '20170201000000' AND '20170201235959'
  73. ) X,
  74. TB_VDS_DTCT_MSTR Y
  75. WHERE 1=1
  76. AND Y.DEL_YN = 'N'
  77. AND Y.DTCT_NMBR = X.DTCT_NMBR
  78. )
  79. GROUP BY ROLLUP (DTCT_NMBR, ISTL_LANE, TRFTYPE)
  80. HAVING GROUPING(TRFTYPE) = 0
  81. ) LX,
  82. (
  83. SELECT A.CTLR_MNGM_NMBR, A.VDS_CTLR_ID, A.LCTN, B.DTCT_NMBR, B.ISTL_LANE, B.VDS_DTCT_NM
  84. FROM TB_VDS_CTLR A,
  85. TB_VDS_DTCT_MSTR B
  86. WHERE 1=1
  87. AND A.DEL_YN = 'N'
  88. AND B.DEL_YN = 'N'
  89. AND A.CTLR_MNGM_NMBR = B.CTLR_MNGM_NMBR
  90. ) LY
  91. WHERE LY.DTCT_NMBR = LX.DTCT_NMBR(+)
  92. ORDER BY LY.LCTN, LY.ISTL_LANE