StudentForTeacherSchedulingView.sql 9.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176
  1. SELECT distinct ct.CoursesTimeID
  2. ,ct.StartTimes
  3. ,ct.Times
  4. ,ct.TimeDesc
  5. ,w.Weekday
  6. ,w.WeekdayDesc
  7. ,s.SchoolyearID
  8. ,s.Code
  9. ,es.ClassroomID
  10. ,es.EducationSchedulingClassID
  11. ,es.TaskGroupName
  12. ,es.EducationMissionClassID
  13. ,es.OrderNo
  14. ,es.Name
  15. ,es.TeachingModeID
  16. ,es.EducationMissionID
  17. ,es.CourseCode
  18. ,es.CourseName
  19. ,es.StartWeeklyNum
  20. ,es.EndWeeklyNum
  21. ,es.ClassroomName
  22. ,es.DepartmentID
  23. ,es.TeacherName
  24. ,es.WeekNums
  25. ,es.MinWeekNum
  26. ,c.ClassmajorID
  27. ,c.Name as ClassmajorName
  28. ,es.StopWeekNumStr
  29. FROM (select ct.CoursesTimeID,ct.StartTimes,convert(varchar(10),ct.StartTimes)+'-'+CONVERT(varchar(10),ct.EndTimes) as Times,
  30. REPLICATE('0',2-len(convert(varchar(10),ct.StartHour)))+convert(varchar(10),ct.StartHour)
  31. +':'+REPLICATE('0',2-len(convert(varchar(10),ct.StartMinutes)))+convert(varchar(10),ct.StartMinutes)
  32. +'-'+REPLICATE('0',2-len(convert(varchar(10),ct.EndHour)))+convert(varchar(10),ct.EndHour)
  33. +':'+REPLICATE('0',2-len(convert(varchar(10),ct.EndMinutes)))+convert(varchar(10),ct.EndMinutes) as TimeDesc
  34. from EM_CoursesTime ct
  35. where ct.RecordStatus>0
  36. ) ct
  37. full join (
  38. select 1 as Weekday,'星期一' as WeekdayDesc
  39. union all
  40. select 2 as Weekday,'星期二' as WeekdayDesc
  41. union all
  42. select 3 as Weekday,'星期三' as WeekdayDesc
  43. union all
  44. select 4 as Weekday,'星期四' as WeekdayDesc
  45. union all
  46. select 5 as Weekday,'星期五' as WeekdayDesc
  47. union all
  48. select 6 as Weekday,'星期六' as WeekdayDesc
  49. union all
  50. select 0 as Weekday,'星期日' as WeekdayDesc
  51. ) w on 1 =1
  52. inner join CF_Schoolyear s on 1=1
  53. inner join Sys_User u on 1=1
  54. inner join CF_Student stu on u.UserID=stu.UserID
  55. inner join CF_Classmajor c on stu.ClassmajorID=c.ClassmajorID
  56. left join (
  57. select distinct x.*,wn.MinWeekNum,case when right(wn.WeekNums,1)=',' then substring(wn.WeekNums,0,LEN(wn.WeekNums)) else wn.WeekNums end as WeekNums
  58. from (
  59. SELECT
  60. ES_EducationScheduling.Weekday
  61. ,ES_EducationScheduling.CoursesTimeID
  62. ,ES_EducationScheduling.ClassroomID
  63. ,EM_EducationSchedulingClass.EducationSchedulingClassID
  64. ,EM_EducationSchedulingClass.TaskGroupName
  65. ,EM_EducationMissionClass.EducationMissionClassID
  66. ,EM_EducationMissionClass.OrderNo
  67. ,EM_EducationMissionClass.Name
  68. ,EM_EducationMissionClass.TeachingModeID
  69. ,EM_EducationMission.EducationMissionID
  70. ,EM_EducationMission.CollegeID
  71. ,EM_EducationMission.SchoolyearID
  72. ,EM_Coursematerial.CourseCode
  73. ,EM_Coursematerial.CourseName
  74. ,EM_EducationMissionClassTeachingSetting.StartWeeklyNum
  75. ,EM_EducationMissionClassTeachingSetting.EndWeeklyNum
  76. ,CF_Classroom.Name AS ClassroomName
  77. ,EM_EducationSchedulingClass_CF_Student.UserID
  78. ,EM_EducationMission.DepartmentID
  79. ,mct.TeacherName
  80. ,ess.StopWeekNumStr
  81. FROM
  82. ES_EducationScheduling
  83. INNER JOIN EM_EducationSchedulingClass
  84. ON EM_EducationSchedulingClass.EducationSchedulingClassID = ES_EducationScheduling.EducationSchedulingClassID
  85. INNER JOIN EM_EducationMissionClass
  86. ON EM_EducationSchedulingClass.EducationMissionClassID = EM_EducationMissionClass.EducationMissionClassID
  87. INNER JOIN EM_EducationMission
  88. ON EM_EducationMissionClass.EducationMissionID = EM_EducationMission.EducationMissionID
  89. INNER JOIN EM_EducationMissionClassTeachingSetting
  90. ON EM_EducationMissionClass.EducationMissionClassID = EM_EducationMissionClassTeachingSetting.EducationMissionClassID
  91. INNER JOIN EM_Coursematerial
  92. ON EM_EducationMissionClass.CoursematerialID = EM_Coursematerial.CoursematerialID
  93. INNER JOIN CF_Classroom
  94. ON ES_EducationScheduling.ClassroomID = CF_Classroom.ClassroomID
  95. INNER JOIN EM_EducationSchedulingClass_CF_Student
  96. ON EM_EducationSchedulingClass.EducationSchedulingClassID = EM_EducationSchedulingClass_CF_Student.EducationSchedulingClassID
  97. LEFT JOIN (select es.EducationSchedulingID, STUFF((select ','+tu.Name
  98. from ES_EducationSchedulingTeacher tescs
  99. inner join ES_EducationScheduling tes on tescs.EducationSchedulingID=tes.EducationSchedulingID
  100. inner join EM_EducationSchedulingClass tesc on tes.EducationSchedulingClassID=tesc.EducationSchedulingClassID
  101. inner join Sys_User tu on tescs.UserID=tu.UserID
  102. where tescs.EducationSchedulingID=es.EducationSchedulingID
  103. order by ISNULL(tescs.TeachingMethod,0),tu.Name
  104. for xml path('')), 1, 1, '') as TeacherName
  105. from ES_EducationSchedulingTeacher escs
  106. inner join ES_EducationScheduling es on escs.EducationSchedulingID=es.EducationSchedulingID
  107. inner join EM_EducationSchedulingClass esc on es.EducationSchedulingClassID=esc.EducationSchedulingClassID
  108. inner join Sys_User u on escs.UserID=u.UserID
  109. group by es.EducationSchedulingID
  110. ) mct ON ES_EducationScheduling.EducationSchedulingID = mct.EducationSchedulingID
  111. LEFT JOIN (
  112. select es.EducationSchedulingID,STUFF((select ','+Convert(varchar(10),ISNULL(tess.WeekNum,0))
  113. from ES_EducationSchedulingStop tess
  114. inner join ES_EducationSchedulingStopTeacher tesst on tess.EducationSchedulingStopID=tesst.EducationSchedulingStopID
  115. inner join Sys_DictionaryItem ttm on ttm.DictionaryCode='EM_TeachingMethod' and ttm.Code='Lecturer' and tesst.TeachingMethod=ttm.Value
  116. inner join EM_EducationMissionClass temc on tess.EducationMissionClassID=temc.EducationMissionClassID
  117. inner join EM_EducationSchedulingClass tesc on temc.EducationMissionClassID=tesc.EducationMissionClassID
  118. inner join ES_EducationScheduling tes on tesc.EducationSchedulingClassID=tes.EducationSchedulingClassID
  119. and tes.Weekday=tess.Weekday and tes.CoursesTimeID=tess.CoursesTimeID and tes.ClassroomID=tess.ClassroomID
  120. where tes.EducationSchedulingID=es.EducationSchedulingID
  121. and tess.RecordStatus=3
  122. order by ISNULL(tess.WeekNum,0)
  123. for xml path('')), 1, 1, '') as StopWeekNumStr
  124. from ES_EducationSchedulingStop ess
  125. inner join ES_EducationSchedulingStopTeacher esst on ess.EducationSchedulingStopID=esst.EducationSchedulingStopID
  126. inner join Sys_DictionaryItem tm on tm.DictionaryCode='EM_TeachingMethod' and tm.Code='Lecturer' and esst.TeachingMethod=tm.Value
  127. inner join EM_EducationMissionClass emc on ess.EducationMissionClassID=emc.EducationMissionClassID
  128. inner join EM_EducationSchedulingClass esc on emc.EducationMissionClassID=esc.EducationMissionClassID
  129. inner join ES_EducationScheduling es on esc.EducationSchedulingClassID=es.EducationSchedulingClassID
  130. and es.Weekday=ess.Weekday and es.CoursesTimeID=ess.CoursesTimeID and es.ClassroomID=ess.ClassroomID
  131. inner join ES_EducationSchedulingWeekNum esw on es.EducationSchedulingID=esw.EducationSchedulingID and ess.WeekNum=esw.WeekNum
  132. where ess.RecordStatus=3
  133. group by es.EducationSchedulingID
  134. ) ess on ES_EducationScheduling.EducationSchedulingID=ess.EducationSchedulingID
  135. ) x
  136. left join (
  137. select x.EducationSchedulingClassID,x.Weekday,x.CoursesTimeID,x.ClassroomID,x.TeacherName,
  138. MIN(x.WeekNum) as MinWeekNum,
  139. STUFF((select convert(varchar(10),esw.WeekNum)+','
  140. from ES_EducationScheduling es
  141. inner join ES_EducationSchedulingWeekNum esw on es.EducationSchedulingID=esw.EducationSchedulingID
  142. group by es.EducationSchedulingID,es.EducationSchedulingClassID,es.Weekday,es.CoursesTimeID,es.ClassroomID,esw.WeekNum
  143. having es.EducationSchedulingClassID=x.EducationSchedulingClassID and es.Weekday=x.Weekday
  144. and es.CoursesTimeID=x.CoursesTimeID and es.ClassroomID=x.ClassroomID
  145. and STUFF((select ','+tu.Name
  146. from ES_EducationSchedulingTeacher tescs
  147. inner join ES_EducationScheduling tes on tescs.EducationSchedulingID=tes.EducationSchedulingID
  148. inner join Sys_User tu on tescs.UserID=tu.UserID
  149. where tescs.EducationSchedulingID=es.EducationSchedulingID
  150. order by ISNULL(tescs.TeachingMethod,0),tu.Name
  151. for xml path('')), 1, 1, '')=x.TeacherName
  152. order by esw.WeekNum
  153. for xml path('')
  154. ), 1, 0, '') as WeekNums
  155. from (
  156. select es.EducationSchedulingID,es.EducationSchedulingClassID,es.Weekday,es.CoursesTimeID,es.ClassroomID,STUFF((select ','+tu.Name
  157. from ES_EducationSchedulingTeacher tescs
  158. inner join ES_EducationScheduling tes on tescs.EducationSchedulingID=tes.EducationSchedulingID
  159. inner join Sys_User tu on tescs.UserID=tu.UserID
  160. where tescs.EducationSchedulingID=es.EducationSchedulingID
  161. order by ISNULL(tescs.TeachingMethod,0),tu.Name
  162. for xml path('')), 1, 1, '') as TeacherName,esw.WeekNum
  163. from ES_EducationScheduling es
  164. inner join ES_EducationSchedulingWeekNum esw on es.EducationSchedulingID=esw.EducationSchedulingID
  165. group by es.EducationSchedulingID,es.EducationSchedulingClassID,es.Weekday,es.CoursesTimeID,es.ClassroomID,esw.WeekNum
  166. ) x
  167. group by x.EducationSchedulingClassID,x.Weekday,x.CoursesTimeID,x.ClassroomID,x.TeacherName
  168. ) wn on x.EducationSchedulingClassID=wn.EducationSchedulingClassID and x.Weekday=wn.Weekday
  169. and x.CoursesTimeID=wn.CoursesTimeID and x.ClassroomID=wn.ClassroomID and x.TeacherName=wn.TeacherName
  170. ) es
  171. on ct.CoursesTimeID=es.CoursesTimeID
  172. and w.Weekday=es.Weekday
  173. and s.SchoolyearID=es.SchoolyearID
  174. and u.UserID=es.UserID
  175. where s.SchoolyearID=@SchoolyearID
  176. and u.UserID=@StudentNo