Convert Julian dates to the Gregorian calendar

Livin404

Active Member
Joined
Jan 7, 2019
Messages
393
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Greetings, I managed to get the proper five digit Julian Dates for Columns E & G both beginning on Row 2. I know the formula
Excel Formula:
=DATE(IF(0+(LEFT(E2,2))<30,2000,1900)+LEFT(E2,2),1,RIGHT(E2,3))
does work, but I'm going to need the days difference, which I already have, but I just need the conversion and the Calendar dates displayed to make it more understandable for the reader.

Thank you,

Days in Reg.JPG
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.

Livin404

Active Member
Joined
Jan 7, 2019
Messages
393
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
some research, if I include
VBA Code:
Function aDate(jDate As String)
NormDateYear = CInt(Mid(jDate, 1, 2))
If NormDateYear < 30 Then
NormDateYear = NormDateYear + 2000
Else
NormDateYear = NormDateYear + 1900
End If
NormDateDay = CInt(Mid(jDate, 3, 3))
aDate = DateSerial(NormDateYear, _
1, NormDateDay)
End Function
In my module will that convert for me though I didn’t specify the columns. I’m away from my computer now. Thank you.
 

Bo_Ry

Board Regular
Joined
Oct 27, 2018
Messages
150
Office Version
  1. 365
Platform
  1. Windows
Please try

Book1.xlsx
EFGHIJ
2201241200646060
3210601203557171
4210231203375252
5210151203423939
Sheet1
Cell Formulas
RangeFormula
I2:I5I2=DATE((19+(LEFT(E2)>"3"))&LEFT(E2,2),1,RIGHT(E2,3))-DATE((19+(LEFT(G2)>"3"))&LEFT(G2,2),1,RIGHT(G2,3))
J2:J5J2=MMULT(DATE((20-(LEFT(E2:G2)>"3"))&LEFT(E2:G2,2),1,RIGHT(E2:G2,3)),{1;0;-1})
 

Livin404

Active Member
Joined
Jan 7, 2019
Messages
393
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Please try

Book1.xlsx
EFGHIJ
2201241200646060
3210601203557171
4210231203375252
5210151203423939
Sheet1
Cell Formulas
RangeFormula
I2:I5I2=DATE((19+(LEFT(E2)>"3"))&LEFT(E2,2),1,RIGHT(E2,3))-DATE((19+(LEFT(G2)>"3"))&LEFT(G2,2),1,RIGHT(G2,3))
J2:J5J2=MMULT(DATE((20-(LEFT(E2:G2)>"3"))&LEFT(E2:G2,2),1,RIGHT(E2:G2,3)),{1;0;-1})
That looks great; however, if I can get that to a VBA would be brilliant? This thing will be updated regularly and the user will have no idea about these formulas. This is only a small part of a rather larger advanced filter VBA. This workbook will be cleared after each time the macro is run. However, at least I know that is not necessary to covert first. Thank you.
 

Bo_Ry

Board Regular
Joined
Oct 27, 2018
Messages
150
Office Version
  1. 365
Platform
  1. Windows
Try

VBA Code:
Sub DifJdate()
Dim rn As Range
    Set rn = Range("E2", Cells(Rows.Count, "E").End(xlUp))
    rn.Offset(, 4).Value = Evaluate(Replace("MMULT(DATE((20-(LEFT(#)>""3""))&LEFT(#,2),1,RIGHT(#,3)),{1;0;-1})", "#", rn.Resize(, 3).Address))
End Sub
 

Livin404

Active Member
Joined
Jan 7, 2019
Messages
393
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Try

VBA Code:
Sub DifJdate()
Dim rn As Range
    Set rn = Range("E2", Cells(Rows.Count, "E").End(xlUp))
    rn.Offset(, 4).Value = Evaluate(Replace("MMULT(DATE((20-(LEFT(#)>""3""))&LEFT(#,2),1,RIGHT(#,3)),{1;0;-1})", "#", rn.Resize(, 3).Address))
End Sub
Beautiful job thank you. Exactly what I needed. In fact better spared me a couple macros.
 

Watch MrExcel Video

Forum statistics

Threads
1,130,119
Messages
5,640,226
Members
417,130
Latest member
Seanr19871

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
Top