Working function won't insert with VBA

mharper90

Board Regular
Joined
May 28, 2013
Messages
117
Office Version
  1. 365
Platform
  1. MacOS
I'm trying to fill down two columns with a VLOOKUP function. The basic VLOOKUP function works, but when I try to use the TEXT function to ensure the date gets it is "looking up" is returned as m/dd/yyyy instead of a large integer, VBA won't even let me continue writing the code before it tells me that it is incorrect. It highlights the line in red, and then cursor highlights the m in m/dd/yyyy, stating that it's looking for an ending. The VLOOKUP without the TEXT function works with VBA, and the VLOOKUP with the TEXT function works when placed directing into the cell, but I just can't get VBA to put the formula there for me.

Code:
Lr = Range("A" & Rows.Count).End(xlUp).Row

With ws2.Range("C3:C" & Lr)
.Cells.Formula = "=&TEXT(VLOOKUP(A3, 'Main Data'!B:N,4,FALSE), "m/dd/yyyy")"
.Cells.FillDown
End With

With ws2.Range("D3:D" & Lr)
.Cells.Formula = "=&TEXT(VLOOKUP(A3, 'Main Data'!B:N,5,FALSE), "m/dd/yyyy")"
.Cells.FillDown
End With

Anyone have a resolution to fix this or somehow accomplish the same intent? Thanks!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
I'm trying to fill down two columns with a VLOOKUP function. The basic VLOOKUP function works, but when I try to use the TEXT function to ensure the date gets it is "looking up" is returned as m/dd/yyyy instead of a large integer, VBA won't even let me continue writing the code before it tells me that it is incorrect. It highlights the line in red, and then cursor highlights the m in m/dd/yyyy, stating that it's looking for an ending. The VLOOKUP without the TEXT function works with VBA, and the VLOOKUP with the TEXT function works when placed directing into the cell, but I just can't get VBA to put the formula there for me.

Code:
Lr = Range("A" & Rows.Count).End(xlUp).Row

With ws2.Range("C3:C" & Lr)
.Cells.Formula = "=&TEXT(VLOOKUP(A3, 'Main Data'!B:N,4,FALSE), "m/dd/yyyy")"
.Cells.FillDown
End With

With ws2.Range("D3:D" & Lr)
.Cells.Formula = "=&TEXT(VLOOKUP(A3, 'Main Data'!B:N,5,FALSE), "m/dd/yyyy")"
.Cells.FillDown
End With

Anyone have a resolution to fix this or somehow accomplish the same intent? Thanks!

Quote marks (not apostrophes) must be doubled up when they occur inside quote marks used to define a text constant. So change this...

"m/dd/yyyy"

to this...

""m/dd/yyyy""

inside the formula.
 
Upvote 0

Forum statistics

Threads
1,213,496
Messages
6,113,993
Members
448,539
Latest member
alex78

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