Reference Problem in a Formula used in VBA

zaska

Well-known Member
Joined
Oct 24, 2010
Messages
1,046
Hi,

Formula used in VBA code

Range("I2:I" & LR).Formula = "=G2*LOOKUP(9.99999999999999E+307,SEARCH(""#""&'[NSE Converter.xls]Sheet1'!$A$1:$A$236,""#""&SUBSTITUTE(TRIM(A2),CHAR(160),"""")),'[NSE Converter.xls]Sheet1'!$B$1:$B$236)"

In the above formula the No.of Rows in Sheet1 of Nseconverter.xls are dynamic I.e $A$1:$A$236 the next month the no of cells may be 237 or 239 etc..same is the case with Column B.

I thought of using named reference for both Column A and B.

Can anyone help me as to what changes should be made in the above formula if columnA values are named as Data1 and ColumnB values are named as Data2.

Or is it possible to find the last cells in column A and Column B and accordingly refer the same in the above formula instead of $A$1:$A$236

Thank you
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
You can try
Code:
Dim lrA As Long, lrB As Long
With Workbooks("NSE Converter.xls").Sheets("Sheet1")
    lrA = .Cells(Rows.Count, "A").End(xlup).Row
    lrB = .Cells(Rows.Count, "B").End(xlup).Row
    Range("I2:I" & LR).Formula = "=G2*LOOKUP(9.99999999999999E+307,SEARCH(""#""&'[NSE Converter.xls]Sheet1'!$A$1:$A$" & lrA & ",""#""&SUBSTITUTE(TRIM(A2),CHAR(160),"""")),'[NSE Converter.xls]Sheet1'!$B$1:$B$" & lrB & ")"
End With


Or presumeably both columns A and B end at the same row, so you could just use 1 variable for both A and B.
Hope that helps.
 
Upvote 0
Hi,

Thank you verymuch i have been looking for the same since a long time.

Have a nice day
 
Upvote 0

Forum statistics

Threads
1,224,884
Messages
6,181,566
Members
453,053
Latest member
Kiranm13

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