Convert number to date and calcuate total days

Pumpk1n

Board Regular
Joined
Jan 31, 2017
Messages
86
Office Version
  1. 365
Platform
  1. Windows
Field1 is coming in from ACCESS (copy/paste) formatted as "General" displays as yyyymmdd (20110425).
Field 2 is coming in as a date mm/dd/yyyy (5/5/2020)

I would like to know the number of days between field 1 and field 2. How do I write a formula to do that?
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
T202005b.xlsm
ABC
22011042505-May-20203299
32011042505-May-20203299
3c
Cell Formulas
RangeFormula
C2C2=B2-DATE(LEFT(A2,4),MID(A2,5,2),RIGHT(A2,2))+1
C3C3=B3-(LEFT(A3,4)&"-"&MID(A3,5,2)&"-"&RIGHT(A3,2))+1
 
Upvote 0
an alternative solution if you have lots of data is to use Power Query

VBA Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column2", type date}}),
    #"Split Column by Position" = Table.SplitColumn(Table.TransformColumnTypes(#"Changed Type", {{"Column1", type text}}, "en-US"), "Column1", Splitter.SplitTextByPositions({0, 4}, false), {"Column1.1", "Column1.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Position",{{"Column1.1", Int64.Type}, {"Column1.2", Int64.Type}}),
    #"Split Column by Position1" = Table.SplitColumn(Table.TransformColumnTypes(#"Changed Type1", {{"Column1.2", type text}}, "en-US"), "Column1.2", Splitter.SplitTextByPositions({0, 1}, false), {"Column1.2.1", "Column1.2.2"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Position1",{{"Column1.2.1", Int64.Type}, {"Column1.2.2", Int64.Type}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Changed Type2",{"Column1.2.1", "Column1.2.2", "Column1.1", "Column2"}),
    #"Inserted Merged Column" = Table.AddColumn(#"Reordered Columns", "Merged", each Text.Combine({Text.From([Column1.2.1], "en-US"), Text.From([Column1.2.2], "en-US"), Text.From([Column1.1], "en-US")}, "/"), type text),
    #"Removed Columns" = Table.RemoveColumns(#"Inserted Merged Column",{"Column1.2.1", "Column1.2.2", "Column1.1"}),
    #"Reordered Columns1" = Table.ReorderColumns(#"Removed Columns",{"Merged", "Column2"}),
    #"Changed Type3" = Table.TransformColumnTypes(#"Reordered Columns1",{{"Merged", type date}}),
    #"Inserted Date Subtraction" = Table.AddColumn(#"Changed Type3", "Subtraction", each Duration.Days([Column2] - [Merged]), Int64.Type)
in
    #"Inserted Date Subtraction"
 
Upvote 0
And here is an alternate formula (produces same result as Dave's)...

=B1-TEXT(A1,"0000-00-00")+1

Note: More than likely you will have to format the cell as General or Number since Excel will probably try to be "helpful" and return the number in the form of a date.
 
Last edited:
Upvote 0
Rick =B1-TEXT(A1,"0000-00-00")+1

I like it! I am sure Rick knows but for some reading the message.
The arithmetic coerces the Text to a number to yield a real date.
The Text part alone will yield a Date with either of the following:
=--TEXT(A1,"0000-00-00") or =TEXT(A1,"0000-00-00")+0
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,215
Members
448,554
Latest member
Gleisner2

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