Sql where help

Hello i know this should be simple but i cannot work it out

I have this code

SELECT  td.the_date , td.staff_id
  FROM timesheet_details td

Open in new window


which provides me with  
2012-11-09	28
2014-11-14	28
2014-11-28	28
2015-01-09	28
2015-01-16	28
2011-08-20	97
2013-10-22	97
2014-01-21	97
2014-01-28	97
2014-02-11	97
2014-02-18	97
2014-02-25	97
2014-03-11	97
2014-03-18	97
2014-03-25	97
2014-04-01	97
2014-04-08	97
2014-04-15	97
2014-04-22	97
2014-05-06	97
2014-05-13	97
2014-05-20	97
2014-06-17	97
2014-06-24	97
2014-07-01	97
2014-07-08	97
2014-07-22	97
2014-07-29	97
2014-08-05	97
2014-08-12	97
2014-08-26	97
2014-09-02	97
2015-01-27	97
2014-05-10	190

Open in new window


what is need is help. I need to work out if staff_id has attended 5 days in a row....only so if staff_id did mon.tues, wed, thurs, fri then i need that but if they did mon.tues, wed, Sat then i don't want to count it...  again Sat sun mon tue wed thur is good but something like sum mon wed fri sat is not

hope you can help

James
LVL 31
James MurrellProduct SpecialistAsked:
Who is Participating?
I wear a lot of hats...

"The solutions and answers provided on Experts Exchange have been extremely helpful to me over the last few years. I wear a lot of hats - Developer, Database Administrator, Help Desk, etc., so I know a lot of things but not a lot about one thing. Experts Exchange gives me answers from people who do know a lot about one thing, in a easy to use platform." -Todd S.

sdstuberCommented:
something like this?
I do make the assumption that there will be at most one record per id per day.

  SELECT staff_id, grp, COUNT(*)
    FROM (SELECT the_date,
                 staff_id,
                 dateadd(d,-1 * ROW_NUMBER() OVER(PARTITION BY staff_id ORDER BY the_date),the_date) grp
            FROM timesheet_details) x
GROUP BY staff_id, grp
  HAVING COUNT(*) >= 5
0
James MurrellProduct SpecialistAuthor Commented:
Thanks for this can you explain?
 dateadd(d,-1 * ROW_NUMBER() OVER(PARTITION BY staff_id ORDER BY the_date),the_date) grp

and I cannot guarantee all days in the_date : that is why my brain has stopped i think
0
sdstuberCommented:
ROW_NUMBER() OVER(PARTITION BY staff_id ORDER BY the_date),

  this will number each row for each staff_id,  starting at 1 and incrementing for each date for that id.

So, if I have these dates for an id...

2015-07-01
2015-07-02
2015-07-03
2015-07-07
2015-07-08
2015-07-09

I'll get these results



2015-07-01  1
2015-07-02  2
2015-07-03  3
2015-07-07  4
2015-07-08  5
2015-07-09  6

we then multiply each by -1 because we want to subtract them

2015-07-01  -1
2015-07-02  -2
2015-07-03  -3
2015-07-07  -4
2015-07-08  -5
2015-07-09  -6

then subtract that many days from the date to produce a new date

2015-07-01  -1   2015-06-30
2015-07-02  -2   2015-06-30
2015-07-03  -3   2015-06-30
2015-07-07  -4   2015-07-03
2015-07-08  -5   2015-07-03
2015-07-09  -6   2015-07-03

Notice how the new dates produce groups of the same value when they are consecutive.
These group dates don't mean anything themselves, they are simply a way to identify sets of dates.

So, then grouping by those dates and counting will tell you how many consecutive days are in each group.
the HAVING clause will let you restrict to only those groups that have 5 or more consecutive days.

Since the group date itself doesn't represent anything meaningfull, you might want to include other aggregates like


 SELECT staff_id, COUNT(*), MIN(the_date), max(the_date)
     FROM (SELECT the_date,
                  staff_id,
                  dateadd(d,-1 * ROW_NUMBER() OVER(PARTITION BY staff_id ORDER BY the_date),the_date) grp
             FROM timesheet_details) x
 GROUP BY staff_id, grp
   HAVING COUNT(*) >= 5

This will tell you the first and last days of each consecutive range.
0
sdstuberCommented:
>>> and I cannot guarantee all days

it's ok if days are missing,  that's what the counting is checking for.

if it's possible to have duplicate dates for a single id,  then clean those up first with a DISTINCT


  SELECT staff_id,
         COUNT(*),
         MIN(the_date),
         MAX(the_date)
    FROM (SELECT the_date,
                 staff_id,
                 dateadd(
                     d,
                     -1 * ROW_NUMBER() OVER(PARTITION BY staff_id ORDER BY the_date),
                     the_date
                 )
                     grp
            FROM (SELECT DISTINCT the_date, staff_id
                    FROM timesheet_details) x) x
GROUP BY staff_id, grp
  HAVING COUNT(*) > 1
0

Experts Exchange Solution brought to you by

Your issues matter to us.

Facing a tech roadblock? Get the help and guidance you need from experienced professionals who care. Ask your question anytime, anywhere, with no hassle.

Start your 7-day free trial
James MurrellProduct SpecialistAuthor Commented:
Big thanks and thanks for the explanation:  as always it amazes me how quick people help others
0
It's more than this solution.Get answers and train to solve all your tech problems - anytime, anywhere.Try it for free Edge Out The Competitionfor your dream job with proven skills and certifications.Get started today Stand Outas the employee with proven skills.Start learning today for free Move Your Career Forwardwith certification training in the latest technologies.Start your trial today
Microsoft SQL Server 2008

From novice to tech pro — start learning today.

Question has a verified solution.

Are you are experiencing a similar issue? Get a personalized answer when you ask a related question.

Have a better answer? Share it in a comment.