HOW TO CALCULATE STUDENT AGGREGATE

peterappiahkubi

New Member
Joined
Jun 12, 2021
Messages
11
Office Version
  1. 2013
Platform
  1. Windows
In creating an excel app to calculate the aggregate for students in their exams as used by WAEC to determine the student aggregate in BECE . The Excel has to select Six Subjects from ine Subjects, with Four being compulsory and Two other best I want an excel formular that will add the grade value of four compulsory subjects : English, Maths, Science, Social. And then automatically select 2 other subjects from the rest with best grade value.

For Instance, If a student has the following result:
1. English - 2
2. Maths - 1
3. Science - 1
4. Social - 2
5. ICT - 3
6. BDT - 3
7. RME - 1
8. French - 2
9. Twi -

I want a formular for this calculation :
English(2)+Maths(1)+Science(1)+Social(2) and randomly select best other two subjects from the rest : RME(1)+French(2) = 10

Kindly help me.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Hi,

Welcome to MrExcel forum!

I have made a simple solution, which assumes that the four compulsory subjects always come at the top of the list. If this is not the case, please let me know.

Book1
ABC
1English29
2Maths1
3Science1
4Social2
5ICT3
6BDT3
7RME1
8French2
9Twi
Sheet1
Cell Formulas
RangeFormula
C1C1=SUM(B1:B4)+SMALL(B5:B9,1)+SMALL(B5:B9,2)
 
Upvote 0
randomly select best other two subjects from the rest : RME(1)+French(2) = 10
The BEST other 2 are ICT & BDT worth 3 each
English(2)+Maths(1)+Science(1)+Social(2) and randomly select best other two subjects from the rest : ICT(3)+BDT(3) = 6+ 6 = 12

Otherwise its just a random selection of the other subjects NOT the BEST other subjects

Not sure how you got 10
 
Upvote 0
Welcome to the board!

You're going to need a subject table that has listed all the subjects in the first column and the type ( ie. compulsory or voluntary) in the second. Once you've created this you can write the actual formula.
I've used named ranges in my formulas to make them easier to read / understand:
The subject table is named SubjectTable.
The Subject and Grade are the columns where the calculations data is found.
Excel Formula:
=SUMPRODUCT(--(VLOOKUP(Subject,SubjectTable,2,0)="Compulsory"),Grade)
+AGGREGATE(15,6,Grade/((VLOOKUP(Subject,SubjectTable,2,0)="Voluntary")*(Grade<>"")),1)
+AGGREGATE(15,6,Grade/((VLOOKUP(Subject,SubjectTable,2,0)="Voluntary")*(Grade<>"")),2)
The whole thing looks like a nightmare but it's quite simple once you break it down to parts:

The SUMPRODUCT totals the grades for the compulsory subjects. First the VLOOKUP goes through each subject row by row and checks if the subject is marked as "Compulsory" in the subject table. This same check is used in the other parts of this formula as well.

The two AGGREGATE functions are basically the same. The only difference is the "k" value in the "SMALL" part.

The first number (15) means you're using the AGGREGATE as a SMALL function. If you want to use it as a LARGE function, change the 15 to 14.
The second number (6) means you want the AGGREGATE to ignore error values.
We're going to create errors by dividing the grades with the double check:
First there's the same VLOOKUP checking that the subject is marked as "Voluntary" in the grade table. And the second check makes sure the grade is not blank.
Excel handles blanks as zeroes in calculations and we don't want that because we're trying to find the smallest (and second smallest) grade that's not a "blank zero".
The double checks return combinations of TRUEs and FALSEs and when they're used in calculations TRUEs become ones and FALSEs become zeroes.
The divider returns a one only when both checks return TRUE. This means we're going to get lots of zeroes in the divider and whenever a value is divided with a zero, the result is an error. We've told AGGREGATE to ignore errors so the resulting values in the calculation range are the ones where the subject is voluntary and the grade is not a blank cell.

The AGGREGATE is used twice to return the smallest and the second smallest values.
 
Upvote 0
N.B.
Your post did not define the terms "WAEC to determine the student aggregate in BECE"
Based on your example Best is lowest number.

2 alternatives that you can try.

Aggregate_a.xlsm
ABCD
1TypeSubjectGradeResult
2CompulsoryEnglish2
3CompulsoryMaths19
4CompulsoryScience1
5CompulsorySocial29
6OtherICT3
7OtherBDT3
8OtherRME1
9OtherFrench2
10OtherTwi
11
12
3b
Cell Formulas
RangeFormula
D3D3=SUMIFS(Grade,Type,"Compulsory")+MINIFS(Grade,Type,"Other")+MINIFS(Grade,Type,"Other",Grade,">"&MINIFS(Grade,Type,"Other"))
D5D5=AGGREGATE(15,6,Grade/((Type="Other")*(Grade<>"")),2)+AGGREGATE(15,6,Grade/((Type="Other")*(Grade<>"")),1)+SUMIFS(Grade,Type,"Compulsory")
Named Ranges
NameRefers ToCells
Grade='3b'!$C$2:$C$10D5, D3
Type='3b'!$A$2:$A$10D5, D3
 
Upvote 0
Thanks for the feedback.

Which suggestion did you decide to use?
 
Upvote 0

Forum statistics

Threads
1,223,239
Messages
6,170,947
Members
452,368
Latest member
jayp2104

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top