Match criteria in Column A and sum all rows below in Column D

Addictions

Board Regular
Joined
May 27, 2018
Messages
60
Office Version
  1. 365
Hello,

I am trying to find week number in C1 and match it in column A. Then sum all cells below to the end in column D. In this example it is sum of D8:D11.
Is this possible to do?. The week number is going to be changing and would want to know the remaining amount for remaining weeks basically.
It is basically a vlookup but how to do it to include a sum of all cells below also?,

Please help


[TABLE="width: 279"]
<tbody>[TR]
[TD]
[/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD="colspan: 2"]Current Week[/TD]
[TD="colspan: 2"]29[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]Week[/TD]
[TD]Data 1[/TD]
[TD]Data 2[/TD]
[TD]Data 3[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]24[/TD]
[TD]1[/TD]
[TD]1[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]25[/TD]
[TD]2[/TD]
[TD]2[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]26[/TD]
[TD]3[/TD]
[TD]3[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]27[/TD]
[TD]4[/TD]
[TD]4[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]28[/TD]
[TD]5[/TD]
[TD]5[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]29[/TD]
[TD]6[/TD]
[TD]6[/TD]
[TD]6[/TD]
[/TR]
[TR]
[TD]9[/TD]
[TD]30[/TD]
[TD]7[/TD]
[TD]7[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD]10[/TD]
[TD]31[/TD]
[TD]8[/TD]
[TD]8[/TD]
[TD]8[/TD]
[/TR]
[TR]
[TD]11[/TD]
[TD]32[/TD]
[TD]9[/TD]
[TD]9[/TD]
[TD]9[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
If
F2 = week number as criteria
and
G2 = Column header as criteria
try
Code:
=SUMIF($A$3:$A$11,">="&F2,INDEX($B$3:$D$11,0,MATCH(G2,$B$2:$D$2,0)))

in your case
Code:
=SUMIF($A$3:$A$11,">="&29,INDEX($B$3:$D$11,0,MATCH("Data 3",$B$2:$D$2,0)))
 
Last edited:
Upvote 0
VBA solution:

Code:
Option Explicit


Sub WeekSum()
    Dim lr As Long, crit As Integer, i As Long, x As Long
    lr = Range("A" & Rows.Count).End(xlUp).Row
    crit = Range("C1").Value2
    For i = 3 To lr
        If Range("A" & i) = crit Then
            x = Application.WorksheetFunction.Sum(Range(Cells(i, 4), Cells(lr, 4)))
        End If
    Next i
    MsgBox ("Results of Sum equals " & x)
End Sub
 
Upvote 0
Wow, Thank you so much for helping out on this one.
I need to break it down now and analyse how this exactly works.
Thank you again for your help!
 
Upvote 0
I also really much appreciate VBA solution for this.
Thank you awesome people to help me out!.
 
Upvote 0
If
F2 = week number as criteria
and
G2 = Column header as criteria
try
Code:
=SUMIF($A$3:$A$11,">="&F2,INDEX($B$3:$D$11,0,MATCH(G2,$B$2:$D$2,0)))

in your case
Code:
=SUMIF($A$3:$A$11,">="&29,INDEX($B$3:$D$11,0,MATCH("Data 3",$B$2:$D$2,0)))

Please could you possibly explain what ">="&29 really does in this formula?
Especially this bit ">="&. Why greater and equal is in quotes and it follows with and symbol afterwards.

Also how could I implement here COOUNTA to know the number of weeks calculated instead of having a total of numbers.
 
Last edited:
Upvote 0
Please could you possibly explain.
I'll try to explain the formula, but keep in mind that English is not my mother tongue.

To be clearer you need to know the arguments of the SUMIF function.
Code:
=SUMIF(range,criteria,sum_range)
Functions arguments are separated by delimiter (,) or (; ).

"range" argument, in this case is '$A$3:$A$11'. It contains the first condition ie. Row header (week number 29).

"criteria" argument in this case week number 29 as condition. Since you want to add up the value of belonging to a number of week, the number 29 is set.
If you want to add up all the below number 29, therefore we want to add multiple conditions or numbers, ie. all the numbers more than 29.

This criterion consists of three parts.
The first part is text string ">="
Second part concatenate. For this purpose, you can use the '&' character (ampersand) that concatenate two or more values from multiple cells to produce one continuous text value.
The third part is the value from cell 'F2'.

So the results for these two terms are the same.
Code:
">="&F2
or
Code:
CONCATENATE(">=",F2)
If you use the 'F9' key when evaluating the formula, then you will see that the result is
Code:
">=29"

"sum_range" argument
When a formula finds a condition, using the INDEX function as a result it returns a value from the same row but from a specified column that has a specified header. In this case, it is 'Data 3' located in the 'G2' cell as a condition.
Code:
INDEX($B$3:$D$11,0,MATCH(G2,$B$2:$D$2,0)
The result of the INDEX function is a value of 10, from the column with the header 'Data 3'.
Nested MATCH function returns the number of column for the condition (in this case 3).
So the SUMIF formula will return the SUM of all cells from the third column, which in column 'A' have number 29 and higher.
So, the SUM of values in the rows of 8 to 11.

I hope I have explained to you. If I'm not, then somebody on the forum will do it for me instead.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,705
Messages
6,173,989
Members
452,541
Latest member
haasro02

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