View Single Post
  #2   Report Post  
Posted to microsoft.public.excel.misc
Lars-Åke Aspelin[_2_] Lars-Åke Aspelin[_2_] is offline
external usenet poster
 
Posts: 913
Default Array Function to do a Sum of VLookUps that translate a letter gra

On Sun, 7 Feb 2010 12:33:01 -0800, David Morris <David
wrote:

Suppose I have letter grade data in a range of cells, B12:D12 as follows
A-, B-, B+/A-

I have another range of cells, named GradeList that gives numerical
equivalents for each of these letter grades. I want a function that will look
up each of these grades in the table, and return their sum, average etc.

I tried the following as an array formula:

{=SUM(VLOOKUP(B12:D12,GradeList,2,FALSE))}

And it didn't work; looks like it just returns the value of the lookup of B12.

Actually, I want this formula to sum the highest N grade values; I know how
to use an array formula to do this with numerical data in cells. But figuring
out how to do the VLookup on each letter grade cell, without having to use
separate cells to contain the numbers, and then sum on numerical equivalents
would be really helpful.



If you name the first column of your GradeList as Grades and the
second column of your GradeList as Scores, try this formula:

=SUM(MMULT(TRANSPOSE(Scores),--(B12:D12=Grades)))

Note: This is an array formula that should be confirmed by
CTRL+SHIFT+ENTER rather than just ENTER.

Replace SUM with AVERAGE if that is what you want.

To get the sum of the highest N grade values try this:

=SUMPRODUCT(LARGE(MMULT(TRANSPOSE(Scores),--(B12:D12=Grades)),ROW(A1:A3)),--(ROW(A1:A3)<=N))

Note: This is an array formula that should be confirmed by
CTRL+SHIFT+ENTER rather than just ENTER.

Replace the N with 1,2 or 3 depending on what you need.
If you have a higher value of N than 3, and thus have a wider range of
grades than B12:D12, then you have to change the A1:A3 in two places
to be the same size as N.

Hope this helps / Lars-Åke