I was working on a query recently and thought of sharing the solution with all my readers. Here’s the problem statement - An institute allows its students to appear for an exam twice, for each course they attend. While generating the report, the institute wanted that only the latest exam date should be shown, listing the CandidateID, CourseID and latest ExamDate for that Student in each Course. The query works on SQL Server 2005/2008.
SAMPLE DATA
DECLARE @TT TABLE (CandID int, CourseID smallint, DateOfExam datetime)
INSERT INTO @TT VALUES (1, 101, 'April 02, 2010 11:25am')
INSERT INTO @TT VALUES (3, 102, 'April 03, 2010 9:55am')
INSERT INTO @TT VALUES (5, 110, 'April 07, 2010 11:24am')
INSERT INTO @TT VALUES (3, 102, 'April 10, 2010 11:22am')
INSERT INTO @TT VALUES (4, 109, 'April 15, 2010 5:27am')
INSERT INTO @TT VALUES (2, 101, 'April 16, 2010 8:21am')
INSERT INTO @TT VALUES (1, 110, 'April 17, 2010 11:55am')
INSERT INTO @TT VALUES (4, 109, 'April 22, 2010 10:16am')
INSERT INTO @TT VALUES (6, 102, 'April 24, 2010 11:35am')
INSERT INTO @TT VALUES (1, 110, 'April 30, 2010 9:49pm')
INSERT INTO @TT VALUES (1, 101, 'May 01, 2010 9:49am')
INSERT INTO @TT VALUES (5, 110, 'May 02, 2010 10:43am')
INSERT INTO @TT VALUES (2, 101, 'May 03, 2010 11:29am')
INSERT INTO @TT VALUES (6, 102, 'May 03, 2010 11:29am')
QUERY
;WITH CTE
AS
(
SELECT
ROW_NUMBER() OVER (PARTITION BY CandID, CourseID order by DateOfExam DESC) as ord,
CandID, CourseID, DateOfExam
FROM @TT
)
SELECT CandID, CourseID, DateOfExam
FROM CTE
WHERE ord = 1;
GO
As you can see, we use the ROW_NUMBER() function to calculate the sequential number of a row within a partition of each CandidateID and CourseID and then use ord=1 to select the latest date
OUTPUT
2 comments:
Very Informative. What if there is no such restriction of 2 exams per course and instead i want to keep a count of how many times an exam was taken for each course?
-- Mazz
SELECT a.CandID, a.CourseID, a.DateOfExam
FROM @TT a
WHERE a.DateOfExam =
(SELECT MAX(b.DateOfExam)
FROM @TT b
WHERE a.CandID = b.CandID AND a.CourseID = b.CourseID)
ORDER BY a.CandID, a.CourseID
is another way to quickly select the latest or MAX date. For your test count query:
SELECT CourseID, COUNT(CourseID) AS TestCnt
FROM @TT
GROUP BY CourseID
ORDER BY CourseID
-- Bill
Post a Comment