Using CROSS APPLY to calculate an aggregate across a single row.
2May 28, 2013 by Kenneth Fisher
I’ve had CROSS APPLY on the mind recently. You could probably tell since its been the subject of my last two posts. Since it’s been on my mind a lot I started to wonder if I could use it to solve some problems I’ve run across in the past. In this particular case running an aggregate, say a max, over multiple columns in a row.
For example let’s say I have a table as follows.
CREATE TABLE QuarterlyAverages ( [Year] smallint, [Q1Average] money, [Q2Average] money, [Q3Average] money, [Q4Average] money)
Yes I realize it’s denormalized, but first it’s an example and second I’ve seen tables similar to this in the real world.
Given that table, I am tasked to produce the highest quarterly average per year. Previously I would have written something complicated and annoying using lots of cases. Using CROSS APPLY however I can do this.
SELECT [Year], MAX(Quarters.Average) FROM QuarterlyAverages CROSS APPLY (VALUES (1, [Q1Average]), (2, [Q2Average]), (3, [Q3Average]), (4, [Q4Average]) ) Quarters (Q, Average) GROUP BY [Year]
I have to admit I love it when I find a smooth solution for problems I’ve struggled with in the past!
What we are doing here is turning the columns that we want to MAX into rows and then doing a MAX grouped by year. The cross apply creates a column called q which numbers the rows 1,2,3 and 4, its not needed for the solution to work.
Its an elegant solution and I think more intuitive than PIVOT.
It’s very true that the Q column was unneeded. I just put it in there because I thought it looked cleaner for the demonstration.
I have to admit I’ve never been terribly comfortable with pivot or unpivot and was thrilled when I learned the CROSS APPLY method. I felt that this was an interesting application of the method. It certainly is a much easier solution than any I’ve seen before.