INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

T-SQL Hints and Tips

How Do I Count Business or Work Days Between Two Dates? by tlbroadbent
Posted: 2 Jan 03 (Edited 29 Jul 09)

A common business need is to count the number of business or work days between two dates. The temptation is to create a function or stored procedure that counts the days based on an algorithm. This procedural process usually involves looping though the code.
 
Looping through code is usually a poor choice in SQL. The best solution in SQL is to create a calendar table with each date and a date type (i.e., 0=Weekend or not worked, 1=Business, 2=Holiday). This allows you account not only for the five working days but for holidays, also. Generally, SQL will handle the table access more efficiently than it does a looping process. This solution is also simpler to implement than most procedural solutions.

Here is one possible method of implementing this solution.
    [li]Create the calendar table:

    Create Table BusinessCalendar
     (BDate smalldatetime Primary Key, BType tinyint)
    Go

    [li]Load dates into table:

    --This will handle business dates and weekends but not holidays. Change date range as needed.

    Declare @dt smalldatetime
    Set @dt='Jan 1 1990'
    While @dt<='Dec 31 2010'
     Begin
      Insert BusinessCalendar Values
       (@dt,
        Case
         When datepart(dw,@dt) Between 2 and 6
          Then 1 Else 0
        End)
      SET @dt = @dt + 1
     End

    [li]Add holiday dates:

    You will need to update the table to mark the holidays. You could write a script to update standard holidays or manually update the table. If you don't need to account for holidays then omit this update.

    [li]Create script to count days:

    After you have finished it will be easy to count business (or work) days with a simple query. This query could be included in a stored procedure or, if running SQL 2000, in a user-defined function.

    Declare @startdate smalldatetime, @enddate smalldatetime
    Set @startdate='dec 12 2002'
    Set @enddate='jan 7 2003'

    Select BDays=Count(*)
    From BusinessCalendar
    Where BType=1
      And BDate Between @startdate And @enddate

Back to Microsoft SQL Server: Programming FAQ Index
Back to Microsoft SQL Server: Programming Forum

My Archive

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close