Still Struggling with VBA Formatting Of Values In Cells

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,562
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
I have this line of code:
Code:
.Cells(drow, 14) = Format(Application.WorksheetFunction.VLookup(luVal, .Range("U3:X60"), 3, False), "h:mm AM/PM dd-mmm")
The value found with the vlookup is 44764.29167, representing a date/time of July22, 2022 7:00 AM.
When I apply this formatting to cell(drow,14), the result is 2022-07-22, not 7:00 AM 22-Jul as desired.

Thoughts?
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
You are not applying formatting. The function Format creates a text string, it does not format the cell. You are jamming the resulting string "7:00 AM 22-Jul" into the cell. Excel sees this text string as a date/time and since the year is missing it assumes the current year.

You need to do this:

VBA Code:
.Cells(drow, 14) = Application.WorksheetFunction.VLookup(luVal, .Range("U3:X60"), 3, False)
.Cells(drow, 14).NumberFormat = "h:mm AM/PM dd-mmm"
 
Upvote 0
Solution
Thank you Jeff ... I certainly did not know that about the "Format" function. My lack of understanding was indeed the problem.
Just out of curiosity, when might one want to use "Format"?
 
Upvote 0
You would use Format whenever you need a text string, such as showing a date/time in a text box.
 
Upvote 0

Forum statistics

Threads
1,214,378
Messages
6,119,188
Members
448,873
Latest member
jacksonashleigh99

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