INDEX/MATCH & SUMIF (with one and/or two comma separated reference numbers)

Morey

New Member
Joined
Sep 24, 2018
Messages
37
Hello All,

The following formulas work with a single reference number in a cell. The issue is that some cells contain two reference numbers separated by a comma (example: 123, 345). How can I modify formulas to account for one and/or both reference numbers?. Any help would be greatly appreciated.

INDEX/MATCH:

Code:
=IFERROR(INDEX('Report'!C:C,MATCH(N31+0,'Report'!F:F,0))&"", "Pending")

SUMIF:

Code:
=SUMIFS('Report'!I:I,'Report'!C:C,P31)

Trying to avoid using something like:

Code:
=SUMIF('Report'!C:C,"123",'Report'!H:H)+SUMIF('Report'!C:C,"345",'Report'!H:H)



Regards,

Morey
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
The following formula considers whether the cell contains "123" or "345" or "123,345" or "345,123". That part could be solved with this formula
=SUM(IF(--ISNUMBER(SEARCH({123,"345"},C2:C9)),H2:H9))


But the problem with the formula is that it sum 2 times the same value because the numbers are 2 times.
Therefore, it should be subtracted when the cell contains the two values.


Try the following array formula.


<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:15.21px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:26.61px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >C</td><td >H</td><td >I</td><td >J</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td > </td><td style="text-align:right; ">123</td><td style="background-color:#92d050; text-align:right; ">5</td><td > </td><td style="text-align:right; ">34</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td > </td><td style="text-align:right; ">345</td><td style="background-color:#92d050; text-align:right; ">7</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td >123, 345</td><td style="background-color:#92d050; text-align:right; ">8</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td > </td><td >123, 789</td><td style="background-color:#92d050; text-align:right; ">3</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td > </td><td >345, 789</td><td style="background-color:#92d050; text-align:right; ">2</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td > </td><td >643, 789</td><td style="text-align:right; ">4</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td > </td><td >877, 654</td><td style="text-align:right; ">6</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td > </td><td >345, 123</td><td style="background-color:#92d050; text-align:right; ">9</td><td > </td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >J2</td><td >{=SUM(IF(--ISNUMBER(SEARCH({123,"345"},C2:C9)),H2:H9)) - SUMPRODUCT((ISNUMBER(SEARCH("123",C2:C9)))*(ISNUMBER(SEARCH("345",C2:C9)))*(H2:H9))}</td></tr></table></td></tr></table>

Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

Note:
Maybe someone can propose a simpler formula.
 
Upvote 0
Hello All,

The following formulas work with a single reference number in a cell. The issue is that some cells contain two reference numbers separated by a comma (example: 123, 345). How can I modify formulas to account for one and/or both reference numbers?. Any help would be greatly appreciated.

Maybe this...

A
B
C
D
E
1
Code​
Value​
Criteria​
Result​
2
111​
10​
123,345​
62​
3
123​
12​
111,456​
32​
4
345​
14​
5
123​
16​
6
12​
18​
7
345​
20​
8
456​
22​

Formula in E2 copied down
=SUMPRODUCT(--ISNUMBER(SEARCH(","&A$2:A$8&",",","&D2&",")),B$2:B$8)

M.
 
Upvote 0
Maybe this...

A
B
C
D
E
1
Code​
Value​
Criteria​
Result​
2
111​
10​
123,345
62​
3
123​
12​
111,456​
32​
4
345​
14​
5
123​
16​
6
12​
18​
7
345​
20​
8
456​
22​

<tbody>
</tbody>


Formula in E2 copied down
=SUMPRODUCT(--ISNUMBER(SEARCH(","&A$2:A$8&",",","&D2&",")),B$2:B$8)

M.


My mistake, I understood that the "123,345" was in the data and not in the criteria :oops:
 
Upvote 0
All,

To clarify, below is what I'm looking to do (if possible). Unfortunately, I could not find a way to upload the file.

Return Values Tab:

PR#PRR
20106310, 20110661#N/A<---- This should return 770, 1652
20106310770

<tbody>
</tbody>

Data Tab:

PRRPR #
77020106310
165220110661

<tbody>
</tbody>



Regards,

Morey
 
Last edited:
Upvote 0
This is a completely different question.
I thought you are asking about SUMIF or a similar formula..

Trying to avoid using something like:

Code:
=SUMIF('Report'!C:C,"123",'Report'!H:H)+SUMIF('Report'!C:C,"345",'Report'!H:H)

If you do want the results in a single cell (a comma separated list) you'll need TEXTJOIN (available only in Excel 365) or VBA.

If results on different cells is acceptable, maybe an array formula. Something like


A
B
C
D
1
PR#​
PRR1​
PRR2​
PRR3​
2
20106310, 20110661​
770​
1652​
3
20106310​
770​
4
5
6
7
PRR​
PR #​
8
770​
20106310​
9
1652​
20110661​

<tbody>
</tbody>


Array formula in B2 copied across and down
=IFERROR(INDEX($A$8:$A$9,SMALL(IF(ISNUMBER(SEARCH($B$8:$B$9,$A2)),ROW($B$8:$B$9)-ROW($B$8)+1),COLUMNS($B2:B2))),"")
confirmed with Ctrl+Shift+Enter, not just Enter

M.
 
Upvote 0
All,

To clarify, below is what I'm looking to do (if possible). Unfortunately, I could not find a way to upload the file.

Return Values Tab:

PR#PRR
20106310, 20110661#N/A<---- This should return 770, 1652
20106310770

<tbody>
</tbody>

Data Tab:

PRRPR #
77020106310
165220110661

<tbody>
</tbody>

Regards,

Morey


Use this UDF

<b>Sheet1</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:157.78px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >PR#</td><td >PRR</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >20106310, 20110661</td><td >770, 1652</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; text-align:left; ">20106310</td><td style="text-align:right; ">770</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>UDF</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=return_prr(A2)</td></tr></table></td></tr></table>


------

<b>Sheet Data</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >PRR</td><td >PR #</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">770</td><td style="text-align:right; ">20106310</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">1652</td><td style="text-align:right; ">20110661</td></tr></table>

-----

UDF, Put the following code in a module. Use the udf as shown in the example

Code:
Function return_prr(r As Range)
    Dim c As Variant, f As Range
    For Each c In Split(r, ",")
        Set f = Sheets("Data").Range("B:B").Find(Trim(c), LookIn:=xlValues, lookat:=xlWhole)
        If Not f Is Nothing Then
            cad = cad & f.Offset(0, -1) & ", "
        End If
    Next
    return_prr = Left(cad, Len(cad) - 2)
End Function
 
Upvote 0
Use this UDF

Sheet1

AB
1PR#PRR
220106310, 20110661770, 1652
320106310770

<tbody>
</tbody>

UDF
CellFormula
B2=return_prr(A2)

<tbody>
</tbody>

<tbody>
</tbody>



------

Sheet Data

AB
1PRRPR #
277020106310
3165220110661

<tbody>
</tbody>


-----

UDF, Put the following code in a module. Use the udf as shown in the example

Code:
Function return_prr(r As Range)
    Dim c As Variant, f As Range
    For Each c In Split(r, ",")
        Set f = Sheets("Data").Range("B:B").Find(Trim(c), LookIn:=xlValues, lookat:=xlWhole)
        If Not f Is Nothing Then
            cad = cad & f.Offset(0, -1) & ", "
        End If
    Next
    return_prr = Left(cad, Len(cad) - 2)
End Function

Dante,

First off, thanks for your help. The UDF works with one minor issue. Data Return Value is not found when Sheet "Data" is filter sorted. Sheet "Data" needs to be unsorted to find Values. Is there a way to ignore filter sorting under the UDF Code?


Regards,

Morey
 
Last edited:
Upvote 0
Dante,
First off, thanks for your help. The UDF works with one minor issue. Data Return Value is not found when Sheet "Data" is filter sorted. Sheet "Data" needs to be unsorted to find Values. Is there a way to ignore filter sorting under the UDF Code?
Regards,
Morey

TRy this

Code:
Function return_prr(r As Range)
    Dim c As Variant, sh As Worksheet, lr As Long
    Set sh = Sheets("Data")
    lr = sh.UsedRange.Rows(sh.UsedRange.Rows.Count).Row
    For Each c In Split(r, ",")
        For i = 1 To lr
            If LCase(sh.Cells(i, "B").Value) = LCase(Trim(c)) Then
                cad = cad & sh.Cells(i, "A").Value & ", "
                Exit For
            End If
        Next
    Next
    If cad = "" Then
        return_prr = "No data"
    Else
        return_prr = Left(cad, Len(cad) - 2)
    End If
End Function
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,693
Members
448,979
Latest member
DET4492

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