Concatenate Date as Date, not Number!

Desu Nota from Columbus

Well-known Member
Joined
Mar 17, 2011
Messages
556
I am trying to achieve the following format:

yyyy-mm-dd hh:mm:ss.000


In actuality I always want the time to be 07:00:00.000. I tried making a custom format as yyyy-mm-dd 07:00:00.000 and it didn't work.

Now I tried to input a date in C1, and concatenate it in A1 to 07:00:00.000, but instead of the date being concatenated, Excel is combining the number value (i.e 40704).

A1= C1& " 07:00:00.000"
B1=Start Date----->
C1=2011-06-10 (formatted as yyyy-mm-dd)


A1 Result: 40704 07:00:00.000

Desired Result: 2011-06-10 07:00:00.000
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Try using something like this in the custom format.

yyyy-mm-dd h:mm:ss

Sample below after entering date formula

Sheet4

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; WIDTH: 396px; PADDING-RIGHT: 2pt; FONT-FAMILY: Calibri,Arial; HEIGHT: 37px; FONT-SIZE: 11pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 128px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD> </TD><TD>G</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</TD><TD style="TEXT-ALIGN: right">2011-06-14 14:06:34</TD></TR></TBODY></TABLE>
<TABLE style="BORDER-BOTTOM-STYLE: groove; BORDER-BOTTOM-COLOR: #00ff00; BORDER-RIGHT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-TOP-STYLE: groove; COLOR: #000000; BORDER-RIGHT-COLOR: #00ff00; FONT-SIZE: 10pt; BORDER-LEFT-STYLE: groove; BORDER-LEFT-COLOR: #00ff00"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-FAMILY: Arial; FONT-SIZE: 9pt" border=1 cellSpacing=0 cellPadding=2><TBODY><TR style="BACKGROUND-COLOR: #cacaca; FONT-SIZE: 10pt"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>G1</TD><TD>=NOW()</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
 
Upvote 0
Hi,

Try:

=TEXT(E3,"yyyy/mm/dd") & " 07:00:00.000"

Personally though, I prefer =CONCATENATE although there is no real advantage to either.

=CONCATENATE(TEXT(E3,"yyyy/mm/dd")," 07:00:00.000")
 
Upvote 0
Trevor: Already used that custom format; as specified I wanted the time to always be 7 o'clock after inputting a date.

James: I didn't try your formula because Jonmo's was quicker and worked.

Jonmo1: This did the trick.


Thank you all for the help.
 
Upvote 0
Can you explain why using the plus sign returns the date from C1 instead of the Excel-prescribed number?

I just assumed that the plus sign wouldn't work because you "add" numbers. Is it because we used parenthesis around the time which makes it a string?
 
Upvote 0
When you concatenate (either with & or the concatenate function), excel returns a TEXT string..
So the concatenate doesn't see the date as a date, it sees it's underlying value which is the date's serial number(40704), and returns it as a text string..

When you ADD, it sees it as a date.
And when performing math functions (+ - * /) Excel tries to coerce text strings into numbers.. if it can.
Excel sees "07:00:00.000" as a numerical time value.
So it adds them together, the date+time.

Hope that clears it up.
 
Upvote 0

Forum statistics

Threads
1,224,544
Messages
6,179,430
Members
452,915
Latest member
hannnahheileen

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