OTView.sql 2.7 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990
  1. DROP VIEW IF EXISTS OTBranchTracking
  2. GO
  3. Create View OTBranchTracking
  4. as
  5. WITH AggregatedTime AS (
  6. SELECT
  7. ta.CompanyID,
  8. ta.OwnerID,
  9. ta.WeekID,
  10. b.BAccountID AS EmployeeBAccount,
  11. b.AcctCD AS EmployeeCD,
  12. branch.AcctCD AS BranchCD,
  13. branch.AcctName AS BranchName,
  14. SUM(ta.TimeSpent) AS TotalTimeSpent
  15. FROM PMTimeActivity ta
  16. JOIN EPTimeCard tc
  17. ON ta.CompanyID = tc.CompanyID AND ta.TimeCardCD = tc.TimeCardCD and tc.WeekID = ta.WeekID
  18. JOIN EPEmployee e
  19. ON tc.CompanyID = e.CompanyID AND tc.EmployeeID = e.BAccountID
  20. Join InventoryItem i
  21. on e.CompanyID = i.CompanyID and e.LabourItemID = i.inventoryID
  22. JOIN BAccount b
  23. ON e.CompanyID = b.CompanyID AND e.BAccountID = b.BAccountID
  24. JOIN BAccount branch
  25. ON b.CompanyID = branch.CompanyID AND branch.BAccountID = b.ParentBAccountID
  26. where ta.EarningTypeID not in ('HOL', 'PTO')
  27. and ta.IsCorrected = 0
  28. GROUP BY
  29. ta.CompanyID,
  30. ta.OwnerID,
  31. ta.WeekID,
  32. b.BAccountID,
  33. b.AcctCD,
  34. branch.AcctCD,
  35. branch.AcctName
  36. ),
  37. EmployeeTime AS (
  38. SELECT
  39. at.CompanyID,
  40. at.OwnerID,
  41. at.EmployeeBAccount,
  42. at.EmployeeCD,
  43. at.BranchCD,
  44. at.BranchName,
  45. at.WeekID,
  46. at.TotalTimeSpent,
  47. CASE
  48. WHEN at.TotalTimeSpent > 2400 THEN at.TotalTimeSpent - 2400
  49. ELSE 0
  50. END AS OverTimeInMinutes,
  51. CASE
  52. WHEN at.TotalTimeSpent > 2400 THEN 2400
  53. ELSE at.TotalTimeSpent
  54. END AS RegularTimeInMinutes
  55. FROM AggregatedTime at
  56. ),
  57. BranchTime AS (
  58. SELECT
  59. et.CompanyID,
  60. et.BranchCD,
  61. et.WeekID,
  62. SUM(et.TotalTimeSpent) AS TotalTimeSpent,
  63. SUM(et.OverTimeInMinutes) AS OverTimeInMinutes,
  64. SUM(et.RegularTimeInMinutes) AS RegularTimeInMinutes,
  65. CASE
  66. WHEN SUM(et.TotalTimeSpent) = 0 THEN NULL
  67. ELSE ROUND(
  68. CAST(SUM(et.OverTimeInMinutes) AS DECIMAL(10,2)) * 100.0 /
  69. CAST(SUM(et.TotalTimeSpent) AS DECIMAL(10,2)), 2
  70. ) END AS OvertimePercent,
  71. CASE
  72. WHEN SUM(et.TotalTimeSpent) = 0 THEN NULL
  73. ELSE ROUND(
  74. CAST(SUM(et.OverTimeInMinutes) AS DECIMAL(10,4)) /
  75. CAST(SUM(et.TotalTimeSpent) AS DECIMAL(10,4)), 4
  76. )
  77. END AS OvertimeRatio
  78. FROM EmployeeTime et
  79. GROUP BY et.CompanyID, et.BranchCD, et.WeekID
  80. )
  81. SELECT
  82. CompanyID,
  83. BranchCD,
  84. WeekID,
  85. TotalTimeSpent,
  86. RegularTimeInMinutes,
  87. OverTimeInMinutes,
  88. OvertimePercent,
  89. OvertimeRatio
  90. FROM BranchTime;