I just need a starting point on how to move variables from the rows into columns and how to avoid duplicates due to NULLs.
It seems you need Aggregate calculation to turn rows to columns.
Here is a sample to query the minimum score for each course. You can also change MIN to MAX to query the maximum score per course for each student.
CREATE TABLE #Sample (StudentID INT,Course_Name VARCHAR(50),Course_Grade FLOAT)
INSERT INTO #Sample VALUES
(1,'Instruction',2),
(1,'Classroom Culture',2.799999952),
(1,'Assessing Student Learning',3),
(1,'Instruction',3),
(1,'Lesson Planning',3),
(1,'Instruction',4),
(2,'Instruction',1.299999952),
(2,'Assessing Student Learning',2),
(2,'Lesson Planning',2.5),
(2,'Classroom Culture',2.700000048)
--DROP TABLE #Sample
--Use Aggregate Function along with CASE WHEN
SELECT StudentID,
MIN(CASE WHEN Course_Name='Assessing Student Learning' THEN Course_Grade ELSE NULL END)AS [Assessing Student Learning],
MIN(CASE WHEN Course_Name='Classroom Culture' THEN Course_Grade ELSE NULL END)AS [Classroom Culture],
MIN(CASE WHEN Course_Name='Instruction' THEN Course_Grade ELSE NULL END)AS [Instruction],
MIN(CASE WHEN Course_Name='Lesson Planning' THEN Course_Grade ELSE NULL END)AS [Lesson Planning]
FROM #Sample
GROUP BY StudentID
--Use PIVOT
SELECT StudentID,[Assessing Student Learning],[Classroom Culture],[Instruction],[Lesson Planning]
FROM #Sample
PIVOT(MIN(Course_Grade)FOR Course_Name IN ([Assessing Student Learning],[Classroom Culture],[Instruction],[Lesson Planning]))P
Best regards,
LiHong
If the answer is the right solution, please click "Accept Answer" and kindly upvote it. If you have extra questions about this answer, please click "Comment".
Note: Please follow the steps in our Documentation to enable e-mail notifications if you want to receive the related email notification for this thread.