Excel Sumproducts with Row Number returned

Biz

Well-known Member
Joined
May 18, 2009
Messages
1,773
Office Version
  1. 2021
Platform
  1. Windows

Dear All,

I have very hard question.

Criteria's
  • Cell G2 I'm looking for Sales Agent named 'A'
  • Cell K2 looking contract status of 'Settlement'.
  • Cell L2 $500,000

I'm trying find out row number when the Sales Agent named, 'A', first
surpasses cumulative settlement sales of $500,000. I have manually highlighted
in Column B what amounts cumulatively add up to $500,000. My formula in Cell H2
is incorrect as should be return row number 14 as per cell I2.

Please note I’m looking for solutions without VBA or formula arrays.
Your help regarding this matter would be greatly appreciated.


<title>Excel Jeanie HTML</title><title>Excel Jeanie HTML</title><!-- ######### Start Created Html Code To Copy ########## -->


Sheet1

ABCDEFGHIJKL
1Sales AgentValueContract Status Sales AgentRow NumberShould Be Contract StatusSales Amount
2A 240,681.00 Settlement A44 14.00 Settlement500,000
3B 243,173.00 Settlement Qualifed
4C 201,350.00 Settlement
5D 259,721.00 Settlement
6A 116,111.00 Qualified
7B 120,828.00 Settlement
8C 207,966.00 Settlement
9D 273,373.00 Settlement
10A 126,762.00 Settlement
11B 133,826.00 Settlement
12C 186,833.00 Settlement
13D 265,714.00 Settlement
14A 152,705.00 Settlement
15B 206,310.00 Settlement
16C 120,429.00 Settlement
17D 205,981.00 Settlement
18A 191,144.00 Settlement
19B 162,691.00 Settlement
20C 274,247.00 Settlement
21D 223,136.00 Settlement

<colgroup><col style="width: 30px; font-weight: bold;"><col style="width: 79px;"><col style="width: 81px;"><col style="width: 101px;"><col style="width: 9px;"><col style="width: 9px;"><col style="width: 11px;"><col style="width: 79px;"><col style="width: 88px;"><col style="width: 69px;"><col style="width: 9px;"><col style="width: 101px;"><col style="width: 93px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
H2=SUMPRODUCT(($A$2:$A$21=$G2)*($C$2:$C$21=$K2)*(SUMIFS($B$2:$B$21,$A$2:$A$21,$G2,$C$2:$C$21,$K2)>=$L2)*ROW(($B$2:$B$21)))

<tbody>
</tbody>

<tbody>
</tbody>


Excel tables to the web >> Excel Jeanie HTML 4


 

 

<!-- ######### End Created Html Code To Copy ########## -->




<!-- ######### Start Created Html Code To Copy ########## -->




Kind Regards,

Biz

 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Here is a custom function that will do the trick.

Code:
Function GetRowNum(Agent As String, cStatus As String, Amount As Double, r As Range) As Variant
Dim AR()
Dim Agg As Double
AR = r.Value
For i = 1 To UBound(AR)
    If AR(i, 1) = Agent And AR(i, 3) = cStatus Then
        Agg = Agg + AR(i, 2)
        If Agg >= Amount Then
            GetRowNum = i
            Exit Function
        End If
    End If
Next i
GetRowNum = CVErr(xlErrValue)
End Function

I used sample data so you'll need to adjust the ranges, but the formula would then look like this... =GetRowNum(G2,K2,L2,A1:C12)
 
  • Like
Reactions: Biz
Upvote 0
I can only think of a simple way using a helper column. As for not using arrays, you cant avoid that but this way at least doesnt require CSE entry. Put this in D2:

=SUMIFS($B$2:B2,$A$2:A2,A2,$C$2:C2,C2)

Copy down. Then your formula to produce the 14 could be:

=AGGREGATE(15,6,1/((A2:A21=G2)*(C2:C21=K2)*(D2:D21>=L2))*(ROW(A2:A21)),1)
 
  • Like
Reactions: Biz
Upvote 0
Hi lrobbo314 & steve the fish,

Both solutions work. Steve your formula solution with AGGREGATE was awesome. I never anything about AGGREGATE function. I have used IFerror as wrapper to avoid errors.

=IFERROR(AGGREGATE(15,6,1/(($A$2:$A$21=$G2)*($C$2:$C$21=$K2)*($D$2:$D$21>=$L2))*(ROW($A$2:$A$21)),1),0)


Irobbo314 I have modified your UDF to give zero when it errors out.
Code:
Function GetRowNum(Agent As String, cStatus As String, Amount As Double, r As Range) As Variant
Dim AR()
Dim Agg As Double
Dim i As Long
Application.Volatile
On Error GoTo Whoa
AR = r.Value
For i = 1 To UBound(AR)
    If AR(i, 1) = Agent And AR(i, 3) = cStatus Then
        Agg = Agg + AR(i, 2)
        If Agg >= Amount Then
            GetRowNum = i
            Exit Function
        End If
    End If
Next i
Exit Function
Whoa:
    GetRowNum = 0
    Resume Next
End Function

Thank you very much to both of yours for your help.

Kind Regards

Biz
 
Upvote 0
Hi,

I have put in the notes regarding what the function is doing.

Code:
Function GetRowNum(Agent As String, cStatus As String, Amount As Double, r As Range) As Variant
Dim AR()
Dim Agg As Double
Dim i As Long
Application.Volatile
On Error GoTo Whoa
'~~> Loads entire range into Array
AR = r.Value
'~~> Let's Loop thru Array
For i = 1 To UBound(AR)
   '~~> AR(i, 1) has Agent Name and AR(i, 3) has Contract Status are true
    If AR(i, 1) = Agent And AR(i, 3) = cStatus Then
        '~~> Create cumulative amount
        Agg = Agg + AR(i, 2)
        '~~> Cumulative amount>= Amount Criteria
        If Agg >= Amount Then
        '~~> Grab the row number
            GetRowNum = i
            Exit Function
        End If
    End If
Next i
Exit Function
Whoa:
    GetRowNum = 0
    Resume Next
End Function

Biz
 
Upvote 0

Forum statistics

Threads
1,214,832
Messages
6,121,847
Members
449,051
Latest member
excelquestion515

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