Match Multiple Ranges & Criteria

chlin

Board Regular
Joined
Feb 4, 2009
Messages
54
<TABLE style="WIDTH: 543pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=724 border=0 x:str><COLGROUP><COL style="WIDTH: 80pt; mso-width-source: userset; mso-width-alt: 3913" width=107><COL style="WIDTH: 68pt; mso-width-source: userset; mso-width-alt: 3291" width=90><COL style="WIDTH: 48pt" span=3 width=64><COL style="WIDTH: 57pt; mso-width-source: userset; mso-width-alt: 2779" width=76><COL style="WIDTH: 50pt; mso-width-source: userset; mso-width-alt: 2450" width=67><COL style="WIDTH: 48pt" span=3 width=64><TBODY><TR style="HEIGHT: 39pt; mso-height-source: userset" height=52><TD class=xl25 style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 543pt; BORDER-BOTTOM: #ece9d8; HEIGHT: 39pt; BACKGROUND-COLOR: transparent" width=724 colSpan=10 height=52>Hi,



I need some help with the below data. I need to find out if the value in G4 match the range in Column C. There are multiple ranges for the same cost centre and customer. For example, If the value in G4 is within any of the ranges in Column C that matches its cost centre and customer no, the result should be "TRUE" in H4


<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Sheet 1</TD><TD></TD><TD></TD><TD></TD><TD>Sheet 2</TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>Cost centre</TD><TD>Customer </TD><TD>Range</TD><TD></TD><TD>Cost Centre</TD><TD>Customer </TD><TD>Value</TD><TD>MATCH range in Sheet 1</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD>2% to 3%</TD><TD></TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">5%</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>1.5% to 2.3%</TD><TD></TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">1.60%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>4% to 4.3%</TD><TD></TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">7%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>4.8% to 5.1%</TD><TD></TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.5</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>6% to 6.3%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD>2.5% to 3%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD>1.1% to 1.5%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD>1.8% to 2.2%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD>5% to 6.5%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR></TBODY></TABLE>

Any help is appreciated ;)

</TD></TR></TBODY></TABLE>
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
<TABLE style="WIDTH: 543pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=724 border=0 x:str><COLGROUP><COL style="WIDTH: 80pt; mso-width-source: userset; mso-width-alt: 3913" width=107><COL style="WIDTH: 68pt; mso-width-source: userset; mso-width-alt: 3291" width=90><COL style="WIDTH: 48pt" span=3 width=64><COL style="WIDTH: 57pt; mso-width-source: userset; mso-width-alt: 2779" width=76><COL style="WIDTH: 50pt; mso-width-source: userset; mso-width-alt: 2450" width=67><COL style="WIDTH: 48pt" span=3 width=64><TBODY><TR style="HEIGHT: 39pt; mso-height-source: userset" height=52><TD class=xl25 style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 543pt; BORDER-BOTTOM: #ece9d8; HEIGHT: 39pt; BACKGROUND-COLOR: transparent" width=724 colSpan=10 height=52>Hi,



I need some help with the below data. I need to find out if the value in G4 match the range in Column C. There are multiple ranges for the same cost centre and customer. For example, If the value in G4 is within any of the ranges in Column C that matches its cost centre and customer no, the result should be "TRUE" in H4


<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Sheet 1</TD><TD></TD><TD></TD><TD></TD><TD>Sheet 2</TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>Cost centre</TD><TD>Customer </TD><TD>Range</TD><TD></TD><TD>Cost Centre</TD><TD>Customer </TD><TD>Value</TD><TD>MATCH range in Sheet 1</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD>2% to 3%</TD><TD></TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">5%</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>1.5% to 2.3%</TD><TD></TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">1.60%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>4% to 4.3%</TD><TD></TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">7%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>4.8% to 5.1%</TD><TD></TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.5</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD>6% to 6.3%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD>2.5% to 3%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD>1.1% to 1.5%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD>1.8% to 2.2%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD>5% to 6.5%</TD><TD></TD><TD></TD><TD></TD><TD></TD><TD></TD></TR></TBODY></TABLE>

Any help is appreciated ;)


</TD></TR></TBODY></TABLE>
The data in column C should be in 2 columns otherwise this will be a "nightmare" to do! ;)

It looks like column D is empty...

Book1
CD
1Range
22.0%3.0%
31.5%2.3%
44.0%4.3%
54.8%5.1%
66.0%6.3%
72.5%3.0%
81.1%1.5%
91.8%2.2%
105.0%6.5%
Sheet1
 
Upvote 0
Try this:-
Code:
[COLOR=navy]Sub[/COLOR] MG23Aug21
[COLOR=navy]Dim[/COLOR] Rng1    [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Dn      [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Rng2    [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] R       [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] ray
[COLOR=navy]Dim[/COLOR] Q
With Sheets("Sheet1") '[COLOR=green][B]sht1[/B][/COLOR]
    [COLOR=navy]Set[/COLOR] Rng1 = .Range(.Range("A4"), .Range("A" & Rows.Count).End(xlUp))
[COLOR=navy]End[/COLOR] With
With Sheets("Sheet2") '[COLOR=green][B]sht2[/B][/COLOR]
    [COLOR=navy]Set[/COLOR] Rng2 = .Range(.Range("E4"), .Range("E" & Rows.Count).End(xlUp))
[COLOR=navy]End[/COLOR] With
    ray = Array(Rng1, Rng2)
[COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
.CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] R = 0 To UBound(ray)
    [COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] ray(R)
        [COLOR=navy]If[/COLOR] Not .Exists(Dn.Value) [COLOR=navy]Then[/COLOR]
            [COLOR=navy]If[/COLOR] R = 0 [COLOR=navy]Then[/COLOR]
                .Add Dn.Value, Array(Trim(Split(Dn.Offset(, 2), "to")(0)), Trim(Split(Dn.Offset(, 2), "to")(1)))
            [COLOR=navy]End[/COLOR] If
        [COLOR=navy]Else[/COLOR]
              Q = .Item(Dn.Value)
                [COLOR=navy]If[/COLOR] R = 0 [COLOR=navy]Then[/COLOR]
                    [COLOR=navy]If[/COLOR] Trim(Split(Dn.Offset(, 2), "to")(0)) < Q(0) [COLOR=navy]Then[/COLOR]
                        Q(0) = Trim(Split(Dn.Offset(, 2), "to")(0))
                    [COLOR=navy]End[/COLOR] If
                    [COLOR=navy]If[/COLOR] Trim(Split(Dn.Offset(, 2), "to")(1)) > Q(1) [COLOR=navy]Then[/COLOR]
                         Q(1) = Trim(Split(Dn.Offset(, 2), "to")(1))
                    [COLOR=navy]End[/COLOR] If
                [COLOR=navy]End[/COLOR] If
               .Item(Dn.Value) = Q
 
                [COLOR=navy]If[/COLOR] R = 1 [COLOR=navy]Then[/COLOR]
                   [COLOR=navy]If[/COLOR] Dn.Offset(, 2) < Q(0) Or Dn.Offset(, 2) > Q(1) [COLOR=navy]Then[/COLOR]
                        Dn.Offset(, 3) = False
                    [COLOR=navy]Else[/COLOR]
                        Dn.Offset(, 3) = True
                    [COLOR=navy]End[/COLOR] If
                [COLOR=navy]End[/COLOR] If
        [COLOR=navy]End[/COLOR] If
    [COLOR=navy]Next[/COLOR] Dn
[COLOR=navy]Next[/COLOR] R
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Upvote 0
Thanks Mick and Biff. However, I got an error at this line

.Add Dn.Value, Array(Trim(Split(Dn.Offset(, 2), "to")(0)), Trim(Split(Dn.Offset(, 2), "to")(1)))
 
Upvote 0
The code expects the percentages in each line in column "C" to be deliminated by "to" (Not "TO", or anything else) if this is not the case then you will get this error.
As "Biff" explained you would actually be better off to have each Percentage in differnt columns.
Anyway to start with, I should check column "C" for incorrect delimination of percentages .
Mick
 
Upvote 0
I have made some changes to the worksheet. Does anyone has an alternative to get the results on Sheet2 Column D?

Sheet1

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 74px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost centre</TD><TD>Customer </TD><TD>Range</TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.00%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100055</TD><TD style="TEXT-ALIGN: right">1.50%</TD><TD style="TEXT-ALIGN: right">2.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.00%</TD><TD style="TEXT-ALIGN: right">4.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.80%</TD><TD style="TEXT-ALIGN: right">5.10%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">6.00%</TD><TD style="TEXT-ALIGN: right">6.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">2.50%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.10%</TD><TD style="TEXT-ALIGN: right">1.50%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.80%</TD><TD style="TEXT-ALIGN: right">2.20%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">5.00%</TD><TD style="TEXT-ALIGN: right">6.50%</TD></TR></TBODY></TABLE>



Sheet2

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 76px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost Centre</TD><TD>Customer </TD><TD>Value</TD><TD>MATCH range in Sheet 1</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">5%</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">1.60%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">7%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.5</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR></TBODY></TABLE>
 
Upvote 0
I have made some changes to the worksheet. Does anyone has an alternative to get the results on Sheet2 Column D?

Sheet1

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 74px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost centre</TD><TD>Customer </TD><TD>Range</TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.00%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100055</TD><TD style="TEXT-ALIGN: right">1.50%</TD><TD style="TEXT-ALIGN: right">2.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.00%</TD><TD style="TEXT-ALIGN: right">4.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.80%</TD><TD style="TEXT-ALIGN: right">5.10%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">6.00%</TD><TD style="TEXT-ALIGN: right">6.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">2.50%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.10%</TD><TD style="TEXT-ALIGN: right">1.50%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.80%</TD><TD style="TEXT-ALIGN: right">2.20%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">5.00%</TD><TD style="TEXT-ALIGN: right">6.50%</TD></TR></TBODY></TABLE>



Sheet2

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 76px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost Centre</TD><TD>Customer </TD><TD>Value</TD><TD>MATCH range in Sheet 1</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">5%</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">1.60%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">7%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.5</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR></TBODY></TABLE>
Sheet2, D2, control+shift+enter, not just enter, and copy down:
Code:
=ISNUMBER(MATCH(1,IF(Sheet1!$A$2:$A$10=A2,IF(Sheet1!$B$2:$B$10=B2,
    IF(C2>=Sheet1!$C$2:$C$10,IF(Sheet1!$D$2:$D$10<=C2,1)))),0))
 
Upvote 0
I have made some changes to the worksheet. Does anyone has an alternative to get the results on Sheet2 Column D?

Sheet1

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 74px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost centre</TD><TD>Customer </TD><TD>Range</TD><TD></TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.00%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100055</TD><TD style="TEXT-ALIGN: right">1.50%</TD><TD style="TEXT-ALIGN: right">2.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.00%</TD><TD style="TEXT-ALIGN: right">4.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">4.80%</TD><TD style="TEXT-ALIGN: right">5.10%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">6.00%</TD><TD style="TEXT-ALIGN: right">6.30%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">2.50%</TD><TD style="TEXT-ALIGN: right">3.00%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.10%</TD><TD style="TEXT-ALIGN: right">1.50%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100034</TD><TD style="TEXT-ALIGN: right">1.80%</TD><TD style="TEXT-ALIGN: right">2.20%</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">5.00%</TD><TD style="TEXT-ALIGN: right">6.50%</TD></TR></TBODY></TABLE>



Sheet2

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 76px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD>Cost Centre</TD><TD>Customer </TD><TD>Value</TD><TD>MATCH range in Sheet 1</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD>7BBC</TD><TD style="TEXT-ALIGN: right">100022</TD><TD style="TEXT-ALIGN: right">5%</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD>7CUJ</TD><TD style="TEXT-ALIGN: right">100003</TD><TD style="TEXT-ALIGN: right">1.60%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>7DFI</TD><TD style="TEXT-ALIGN: right">100005</TD><TD style="TEXT-ALIGN: right">7%</TD><TD style="TEXT-ALIGN: right">FALSE</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>7ABC</TD><TD style="TEXT-ALIGN: right">100001</TD><TD style="TEXT-ALIGN: right">2.5</TD><TD style="TEXT-ALIGN: right">TRUE</TD></TR></TBODY></TABLE>
One way...

Book1
ABCD
1CenterCustomerRange
27ABC1000012.00%3.00%
37BBC1000551.50%2.30%
47BBC1000224.00%4.30%
57BBC1000224.80%5.10%
67BBC1000226.00%6.30%
77CUJ1000032.50%3.00%
87CUJ1000341.10%1.50%
97CUJ1000341.80%2.20%
107DFI1000055.00%6.50%
Sheet1

Book1
ABCD
1CenterCustomerValueMatch
27BBC1000225.00%TRUE
37CUJ1000031.60%FALSE
47DFI1000057.00%FALSE
57ABC1000012.50%TRUE
Sheet2

This formula entered in D2 and copied down:

=SUMPRODUCT(--(Sheet1!A$2:A$10=A2),--(Sheet1!B$2:B$10=B2),--(C2>=Sheet1!C$2:C$10),--(C2<=Sheet1!D$2:D$10))>0
 
Upvote 0
Aladin Akyurek said:
Sheet2, D2, control+shift+enter, not just enter, and copy down:

=ISNUMBER(MATCH(1,IF(Sheet1!$A$2:$A$10=A2,IF(Sheet1!$B$2:$B$10=B2,
IF(C2>=Sheet1!$C$2:$C$10,IF(Sheet1!$D$2:$D$10<=C2,1)))),0))
That formula will return incorrect results.

Try it like this...(still array entered)

=ISNUMBER(MATCH(1,IF(Sheet1!$A$2:$A$10=A2,IF(Sheet1!$B$2:$B$10=B2,IF(C2>=Sheet1!$C$2:$C$10,IF(C2<=Sheet1!$D$2:$D$10,1)))),0))
 
Upvote 0

Forum statistics

Threads
1,224,586
Messages
6,179,729
Members
452,939
Latest member
WCrawford

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