Converting to (and from) Julian Date (YYDDD) format in T-SQL

March 25, 2009

I often get asked how to convert a datetime into Julian Date format in T-SQL. People have differing opinions about what Julian means, but the one I got asked about most recently meant YYDDD, as often used by mainframe systems (I think this is Julian Date, as opposed to Julian Day which is the number of days since 4713BC). SQL Server doesn’t have a TO_JULIAN function, but we can make one easily enough.

So we’re wanting to express a date as YYDDD, where YY is the two-digit form of the year, and DDD is the number of days since Dec 31st of the previous year (ie, the DDDth day of the year).

Using the DATEPART function can get each part. YY for the year, and DY for the day of the year. I’m going to use @date as a variable here, of type datetime. Using the date type in SQL 2008 would work just the same.

SELECT DATEPART(yy, @date), DATEPART(dy, @date)

However, to make sure that we have the year in two-digits only, we should convert this to a string and get the rightmost two characters.

SELECT RIGHT(CAST(DATEPART(yy, @date) AS char(4)),2)

We also need to pad the DDD with zeroes – which I’ll do by putting three zeroes in front of the number and getting the three rightmost characters.

SELECT RIGHT(‘000’ + CAST(DATEPART(dy, @date) AS varchar(3)),3)

Concatenating the YY and the DDD, we now have a TO_JULIAN function.

SELECT RIGHT(CAST(YEAR(@date) AS CHAR(4)),2) + RIGHT(‘000’ + CAST(DATEPART(dy, @date) AS varchar(3)),3)

Converting back again isn’t too hard – it’s just a matter of pulling the numbers out of the 5-character string. I’m going to assume we have a char(5) called @julian.

We need to split the string up first.

SELECT LEFT(@julian,2), RIGHT(@julian,3)

The first bit becomes the year easily enough

SELECT CONVERT(datetime, LEFT(@julian,2) + ‘0101’, 112)

The second half can be cast to a number, and then added back (subtracting one to get the maths right) using DATEADD.

SELECT DATEADD(day, CAST(RIGHT(@julian,3) AS int) – 1, CONVERT(datetime, LEFT(@julian,2) + ‘0101’, 112))

So now we have a FROM_JULIAN function:

SELECT DATEADD(day, CAST(RIGHT(@julian,3) AS int) – 1, CONVERT(datetime, LEFT(@julian,2) + ‘0101’, 112))

Easy stuff really, just a matter of thinking about what we mean by a particular format.

This Post Has 5 Comments

  1. Matt

    How does this account for leap-year in the serial count?

  2. robfarley

    Matt,

    In a leap year, the days from March onwards are one number further. For example, consecutive March 1s might be 08061, 09060.

    Rob

  3. jason wong

    It’s better to use integer arithematic than string manipulations for performance reasons.

    set @standardDate = DATEADD (day , @julianDate%1000-1, DATEADD(year,@julianDate/1000-1900, 0 ) )

  4. robfarley

    True, but this particular client needed char(5) for other reasons.

Leave a Reply

LobsterPot Blogs

Blog posts by Rob Farley and other LobsterPot Solutions team members.

Search