Returning the cell address in a range

thisisthebear

New Member
Joined
Aug 3, 2007
Messages
6
Heres the challenge;

I need to return the cell address on the first occasion that the following two conditions are met;

When Column A = 100
And
Column B is equal to or greater than 13

Column A Column B
101 --------- 10
102 --------- 10
103 --------- 11
104 --------- 13
100 --------- 10
101 --------- 10
102 --------- 11
103 --------- 11
104 --------- 11
100 --------- 13
101 --------- 11
102 --------- 11
103 --------- 10
104 --------- 12
100 --------- 14
101 --------- 11
102 --------- 11
103 --------- 10
104 --------- 12



In the above example I want to return the answer B10.

(Please ignore the ---------)
 

Some videos you may like

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.

facethegod

Well-known Member
Joined
Aug 1, 2006
Messages
767
Welcome to the Board

Try this in C1 and confirm with Ctr+ Shift + Enter, not just Enter


Code:
=ADDRESS(SMALL(IF(A1:A19=100,IF(B1:B19>=13,ROW(A1:A19),""),""),1),2)
 

lenze

Legend
Joined
Feb 18, 2002
Messages
13,690
Try this:
Code:
Sub FindMe()
    Dim cl As Range
    For Each cl In Range("$A$2:$A" & Range("$A$65536").End(xlUp).Row)
    If cl = 100 Then
         If cl.Offset(O, 1) >= 13 Then
         MsgBox cl.Address
         Range("$D$2") = cl.Address
         Exit Sub
         End If
    End If
    Next cl
End Sub

lenze
 

Beate Schmitz

Active Member
Joined
May 20, 2007
Messages
392

ADVERTISEMENT

Hello,

I'm late, as I see.
My solution needs helpcolumn C.
The formula of C2 can be copied down.

<table border="1" cellspacing="0" cellpadding="0" style="font-family:Arial,Arial; font-size:10pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:80px;" /><col style="width:80px;" /><col style="width:80px;" /><col style="width:80px;" /><col style="width:80px;" /><col style="width:80px;" /><col style="width:80px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td></tr><tr style="height:17px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="font-weight:bold; "> </td><td style="font-weight:bold; "> </td><td style="font-weight:bold; ">Helpcolumn</td><td style="font-weight:bold; "> </td><td style="background-color:#ff9900; font-weight:bold; text-align:center; ">A=</td><td style="background-color:#ff9900; font-weight:bold; text-align:center; ">B>=</td><td style="background-color:#ff9900; font-weight:bold; text-align:center; ">Cell</td></tr><tr style="height:17px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">101</td><td style="text-align:right; ">10</td><td > </td><td > </td><td style="text-align:center; ">100</td><td style="text-align:center; ">13</td><td style="text-align:center; ">B11</td></tr><tr style="height:17px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">102</td><td style="text-align:right; ">10</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; " >4</td><td style="text-align:right; ">103</td><td style="text-align:right; ">11</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; " >5</td><td style="text-align:right; ">104</td><td style="text-align:right; ">13</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; " >6</td><td style="text-align:right; ">100</td><td style="text-align:right; ">10</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; " >7</td><td style="text-align:right; ">101</td><td style="text-align:right; ">10</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; " >8</td><td style="text-align:right; ">102</td><td style="text-align:right; ">11</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 style="text-align:right; ">103</td><td style="text-align:right; ">11</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 style="text-align:right; ">104</td><td style="text-align:right; ">11</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 style="text-align:right; ">100</td><td style="text-align:right; ">13</td><td style="text-align:right; ">11</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 style="text-align:right; ">101</td><td style="text-align:right; ">11</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; " >13</td><td style="text-align:right; ">102</td><td style="text-align:right; ">11</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; " >14</td><td style="text-align:right; ">103</td><td style="text-align:right; ">10</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; " >15</td><td style="text-align:right; ">104</td><td style="text-align:right; ">12</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; " >16</td><td style="text-align:right; ">100</td><td style="text-align:right; ">14</td><td style="text-align:right; ">16</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; " >17</td><td style="text-align:right; ">101</td><td style="text-align:right; ">11</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; " >18</td><td style="text-align:right; ">102</td><td style="text-align:right; ">11</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; " >19</td><td style="text-align:right; ">103</td><td style="text-align:right; ">10</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; " >20</td><td style="text-align:right; ">104</td><td style="text-align:right; ">12</td><td > </td><td > </td><td > </td><td > </td><td > </td></tr></table>
<table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td >Spreadsheet Formulas</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 >C2</td><td >=IF(AND<span style=' color:008000; '>(A2=E$2,B2>=F$2)</span>,ROW<span style=' color:008000; '>()</span>,"")</td></tr><tr><td >G2</td><td >="B"&MIN(C:C)</td></tr></table></td></tr></table>
 

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,958
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Here's another possibility:
=CELL("address",INDEX(B1:B19,MATCH(1,(A1:A19=100)*(B1:B19>=13),0)))

Confirm with CTRL-SHIFT-ENTER rather than just Enter.
 

dave3009

Well-known Member
Joined
Jun 23, 2006
Messages
7,002
Office Version
  1. 365
  2. 2016
Thank you, two working solutions in 20 mins that I've spent all day trying to solve.

You'll find that you can sometimes get it quicker too.

Welcome to the Board

Dave
 

thisisthebear

New Member
Joined
Aug 3, 2007
Messages
6
Hi,

Thanks for the code supplied previously, I have modified it slightly as the a new requirement has come along (See Below). However can anyone advise how this could be tweaked again to repeat this same code but for a range of cells.

For Example I start by looing for a value in H59 and returing the cell address to AN59, I then want to check the value in H60 and return the address to AN60 etc until cells H100 and AN100. I can do this with formulas but due to the number of rows it takes a long time. I am hoping that VB code wll be quicker.

Cheers.

Code:
Sub FindMe()
    Dim cl As Range
    For Each cl In Range("$G$60:$G" & Range("$G$65536").End(xlUp).Row)
    If cl = Range("H59") Then
         Range("$AN$59") = cl.Address
         Exit Sub
        End If
    Next cl
End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,123,100
Messages
5,599,727
Members
414,330
Latest member
Rich920

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
Top