Page 1 of 2 12 LastLast
Results 1 to 15 of 18
  1. #1
    Join Date
    Jan 2007
    Location
    UK
    Posts
    11,434
    Provided Answers: 10

    Unanswered: Absences between a date range...

    Ok guys and gals I have a logic-scratcher for you!

    Employees(employee_number, surname, forename, etc)
    Absences(employee_number, date_from, date_to, etc)

    I know, not the best design but it's what I've got to work with!

    So here comes the tricky part; given a user-defined date range I need to return who has been off sick!

    Here's some sample data
    Code:
    +-----------------+-----------+
    | employee_number | forename  |
    +-----------------+-----------+
    | 1		  | Aaron     |
    | 2               | Ben       |
    | 3               | Charlotte |
    | 4               | Dawn      |
    | 5               | Edward    |
    | 6               | Frank     |
    +-----------------+-----------+
    
    +-----------------+-----------+----------+
    | employee_number | date_from | date_to  |
    +-----------------+-----------+----------+
    | 1               | 01/01/08  | 03/01/08 |
    | 2               | 02/01/08  | NULL     |
    | 3               | 01/01/08  | 15/01/08 |
    | 4               | 08/01/08  | 10/01/08 |
    | 6               | 05/01/08  | 07/01/08 |
    +-----------------+-----------+----------+
    So, who was off sick between 04/01/2008 and 09/01/2008?
    red indicates the people we want to return in our resultset


    Aaron was not off sick during this date range.
    Ben is still of sick and his sickness started in this date range.
    Charlotte was off sick during the entirety of this date range.
    Dawn's sickness started between these dates.
    Edwards hasn't been off sick at all
    and finally; Frank was off sick between these two dates.

    Unfortunately I can't get my head round the logic needed here... Any suggestions? I hope my noddy example gives you enough insight to help, if not; let me know and I'll try answer any questions you fire at me!

    -George
    George
    Home | Blog

  2. #2
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    I'm sure you can do this in one expression.

    BTW - DDL & DML prefered if poss.

    Code:
    ...
    WHERE @date_start BETWEEN date_from AND COALESCE(date_to, @date_start) 
    OR @date_end BETWEEN date_from AND COALESCE(date_to, @date_end)
    Best I can do at the end of the day.

  3. #3
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    No that's wrong. Sorry - I'm too tired. Celko has great examples of these. Where's that book?

  4. #4
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    You can extend it and check if the from or to dates are betwen the parameters but it is a bit brute force - there are more elegant ways.

  5. #5
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    if you can give me 30 to 60 minutes I have this in a book in my book bag I think but I am on the phone with someone.

    i know I saw Itzik Ben-Gan do this.
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  6. #6
    Join Date
    Jan 2003
    Location
    Massachusetts
    Posts
    5,800
    Provided Answers: 11
    I don't know. Sounds fishy to me. Were all of your employees really hired in alphabetical order? Smells like an RFH to me.

  7. #7
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    do you have T-SQL Querying By Itzik Ben-Gan. Chapter 4. Section on existing and missing ranges.

    I am sorry. no time to retype it.
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  8. #8
    Join Date
    Nov 2002
    Posts
    272
    WHERE date_from <= @date_end AND
    (date_to >= @date_start OR date_to IS NULL)

    That last bit is probably possible with COALESCE, but I'm not sure how COALESCE works (and too lazy to look it up right now).

  9. #9
    Join Date
    Jan 2007
    Location
    UK
    Posts
    11,434
    Provided Answers: 10
    Quote Originally Posted by pootle flump
    I'm sure you can do this in one expression.
    Agreed; it should be possible, I just haven't got my head round the logic yet
    Quote Originally Posted by pootle flump
    BTW - DDL & DML prefered if poss.
    Well, I simplified the problem a lot (the absence table has about 35 fields!) but kept all the relevant information there for you. If you'd like some create table statements for testing purposes I'll happily knock something up!
    Quote Originally Posted by MCrowley
    I don't know. Sounds fishy to me. Were all of your employees really hired in alphabetical order? Smells like an RFH to me.
    conveniently yes we do. I was hired shortly after Frank (the job description for the position of trainee developer stated that the applicants name must begin with the letter G. We're a rare breed )
    Quote Originally Posted by Thrasymachus
    do you have T-SQL Querying By Itzik Ben-Gan. Chapter 4. Section on existing and missing ranges.

    I am sorry. no time to retype it.
    I'm afraid my access to SQL literacy is sorely limited... But thank you for taking the time to look it up for me
    George
    Home | Blog

  10. #10
    Join Date
    Jan 2007
    Location
    UK
    Posts
    11,434
    Provided Answers: 10
    Thanks for everyones contributions so far...
    Here's a quick mock up to produce the results; I think I might have a solution, but I'm not convinced yet...
    Code:
    /*----------------+-----------+
    | employee_number | forename  |
    +-----------------+-----------+
    | 1	          | Aaron     |
    | 2               | Ben       |
    | 3               | Charlotte |
    | 4               | Dawn      |
    | 5               | Edward    |
    | 6               | Frank     |
    +-----------------+-----------+
    +-----------------+-----------+----------+
    | employee_number | date_from | date_to  |
    +-----------------+-----------+----------+
    | 1               | 01/01/08  | 03/01/08 |
    | 2               | 02/01/08  | NULL     |
    | 3               | 01/01/08  | 15/01/08 |
    | 4               | 08/01/08  | 10/01/08 |
    | 6               | 05/01/08  | 07/01/08 |
    +-----------------+-----------+---------*/
    DECLARE @employee table (
       employee_number int      NOT NULL
     , forename        char(10) NOT NULL
    )
    
    DECLARE @absence table (
       employee_number int      NOT NULL
     , date_from       datetime NOT NULL
     , date_to         datetime     NULL
    )
    
    INSERT INTO @employee (employee_number, forename)
    SELECT 1, 'Aaron'     UNION
    SELECT 2, 'Ben'       UNION
    SELECT 3, 'Charlotte' UNION
    SELECT 4, 'Dawn'      UNION
    SELECT 5, 'Edward'    UNION
    SELECT 6, 'Frank'
    
    INSERT INTO @absence (employee_number, date_from, date_to)
    SELECT 1, '20080101', '20080103' UNION
    SELECT 2, '20080102',  NULL      UNION
    SELECT 3, '20080101', '20080115' UNION
    SELECT 4, '20080108', '20080110' UNION
    SELECT 6, '20080105', '20080107'
    
    DECLARE @lowerDate datetime
          , @upperDate datetime
    
    SELECT @lowerDate='20080104'
         , @upperDate='20080109'
    
    SELECT e.forename
         , a.*
    FROM   @employee e
     INNER
      JOIN @absence a
        ON a.employee_number = e.employee_number
    WHERE  @lowerDate BETWEEN date_from  AND Coalesce(date_to, @upperDate)
     OR    date_from  BETWEEN @lowerDate AND @upperDate
    
    /*
    --Aaron was not off sick during this date range.
    Ben is still of sick and his sickness started in this date range.
    Charlotte was off sick during the entirety of this date range.
    Dawn's sickness started between these dates.
    --Edwards hasn't been off sick at all
    and finally; Frank was off sick between these two dates.
    */
    George
    Home | Blog

  11. #11
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    Knock up some DDL if mine & Vich's logic don't get it. Remember mine is half an answer and can defo be more elegant.

  12. #12
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    Your answer looks good to me.

  13. #13
    Join Date
    Jan 2007
    Location
    UK
    Posts
    11,434
    Provided Answers: 10
    3 examples that appear to be working. The secondis Ivon's - right off the bat and the third is his suggestion using Coalesce
    Code:
    WHERE @lowerDate BETWEEN date_from  AND Coalesce(date_to, @upperDate)
     OR   date_from  BETWEEN @lowerDate AND @upperDate
    
    WHERE date_from <= @upperDate
    AND  (date_to >= @lowerDate
     OR   date_to IS NULL)
    
    WHERE date_from <= @upperDate
    AND   Coalesce(date_to, @lowerDate) >= @lowerDate


    Thanks to everyone!
    George
    Home | Blog

  14. #14
    Join Date
    Apr 2002
    Location
    Toronto, Canada
    Posts
    20,002
    let's draw a quick timeline diagram

    we'll let @start and @end be the date range we're interested in

    let's show all the possible employee absences, using FR and TO to represent the date_from and date_to columns
    Code:
              @start     @end            
                 |         |               
    1   FR---TO  |         |               
                 |         |               
    2         FR-|-TO      |               
                 |         |               
    3            | FR---TO |               
                 |         |               
    4         FR-|---------|-TO       
                 |         |               
    5            |      FR-|-TO 
                 |         |               
    6            |         |  FR---TO
    with me so far?

    okay, so to pull all the employees which had an absence anywhere in the selected range, all we have to do is eliminate cases 1 and 6, right?

    there are many ways to set up the WHERE clause, but here's the easiest --
    Code:
    ... where TO >= @start  /* eliminates case 1 */
          and FR <= @end    /* eliminates case 6 */
    vwalah!!
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL

  15. #15
    Join Date
    Feb 2004
    Location
    One Flump in One Place
    Posts
    14,912
    Great example Rudy - and shows how 95% of the solution is getting a proper understanding the problem. I knew there was a really simple, elegant answer lol.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •