Counting weekdays within a date range and grouping them by month

  • Hi Folks,

    I was hoping I can get some help and your expertise on below reuirement.

    I have this data where first two columns represent the date range and next seven (event1, event2 etc) represent the incidence occurance by day monday thru sunday. which is represented as values 0 and 1. (1 being the event occuring and 0 no event). I need to count event occurance and group them by month.

    FROMTOEvent1Event2Event3Event4Event5Event6Event7

    29-Apr-1301-May-131010000

    30-Apr-1325-Oct-131101111

    08-May-1311-Sep-130010000

    18-Sep-1318-Sep-130010000

    25-Sep-1323-Oct-130010000

    26-Oct-1326-Oct-130000010

    27-Oct-1328-Mar-141111111

    29-Mar-1429-Mar-140000010

    30-Mar-1424-Oct-141111101

    05-Apr-1418-Oct-140000010

    The results I am expecting are as per the attachment.

    Is anyone able to help.

  • Hi and welcome to the forums. It is very unclear what you are trying to do here.

    In order to help we will need a few things:

    1. Sample DDL in the form of CREATE TABLE statements

    2. Sample data in the form of INSERT INTO statements

    3. Expected results based on the sample data

    Please take a few minutes and read the first article in my signature for best practices when posting questions.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • may be this will get you started....

    you will also need a "Tally" table...search this site for guides

    suggest you read up on dynamic pivot/cross tabs as well

    CREATE TABLE [dbo].[TransData](

    [Fromdate] [datetime] NOT NULL,

    [ToDate] [datetime] NOT NULL,

    [Event1] [smallint] NOT NULL,

    [Event2] [smallint] NOT NULL,

    [Event3] [smallint] NOT NULL,

    [Event4] [smallint] NOT NULL,

    [Event5] [smallint] NOT NULL,

    [Event6] [smallint] NOT NULL,

    [Event7] [smallint] NOT NULL

    ) ON [PRIMARY]

    GO

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Apr 29 2013 12:00:00:000AM','May 1 2013 12:00:00:000AM',1,0,1,0,0,0,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Apr 30 2013 12:00:00:000AM','Oct 25 2013 12:00:00:000AM',1,1,0,1,1,1,1)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('May 8 2013 12:00:00:000AM','Sep 11 2013 12:00:00:000AM',0,0,1,0,0,0,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Sep 18 2013 12:00:00:000AM','Sep 18 2013 12:00:00:000AM',0,0,1,0,0,0,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Sep 25 2013 12:00:00:000AM','Oct 23 2013 12:00:00:000AM',0,0,1,0,0,0,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Oct 26 2013 12:00:00:000AM','Oct 26 2013 12:00:00:000AM',0,0,0,0,0,1,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Oct 27 2013 12:00:00:000AM','Mar 28 2014 12:00:00:000AM',1,1,1,1,1,1,1)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Mar 29 2014 12:00:00:000AM','Mar 29 2014 12:00:00:000AM',0,0,0,0,0,1,0)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Mar 30 2014 12:00:00:000AM','Oct 24 2014 12:00:00:000AM',1,1,1,1,1,0,1)

    INSERT INTO [transdata] ([Fromdate],[ToDate],[Event1],[Event2],[Event3],[Event4],[Event5],[Event6],[Event7])VALUES('Apr 5 2014 12:00:00:000AM','Oct 18 2014 12:00:00:000AM',0,0,0,0,0,1,0)

    SET DATEFORMAT DMY;

    SET DATEFIRST 1 -- Monday = 1

    DECLARE @Date_Start AS DATETIME

    DECLARE @Date_End AS DATETIME

    SELECT @Date_Start = MIN ( Fromdate )

    FROM TransData;

    SELECT @Date_End = MAX ( Todate )

    FROM TransData;

    with ctedates as

    (

    SELECT N

    , DATEADD ( d , N - 1 , @Date_Start ) AS calendar_date

    , Datepart (WEEKDAY,DATEADD ( d , N - 1 , @Date_Start )) as day_of_week

    ,STUFF(CONVERT(CHAR(11),DATEADD(d, N-1, @Date_Start),100),4,3,'') AS MonthName

    FROM Tally

    WHERE (N <= DATEDIFF ( d , @Date_Start , @Date_End ))

    ),

    cteresults as

    (

    SELECT fromdate,

    todate,

    MonthName,

    event

    FROM

    (

    SELECT td.Event1 as event , td.Fromdate, td.ToDate,c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event1 = 1) AND (c.day_of_week = 1)

    UNION ALL

    SELECT td.Event2 , td.Fromdate, td.ToDate,c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event2 = 1) AND (c.day_of_week = 2)

    UNION ALL

    SELECT td.Event3 , td.Fromdate, td.ToDate, c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event3 = 1) AND (c.day_of_week = 3)

    UNION ALL

    SELECT td.Event4 , td.Fromdate, td.ToDate, c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event4 = 1) AND (c.day_of_week = 4)

    UNION ALL

    SELECT td.Event5 , td.Fromdate, td.ToDate,c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event5 = 1) AND (c.day_of_week = 5)

    UNION ALL

    SELECT td.Event6 , td.Fromdate, td.ToDate, c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event6 = 1) AND (c.day_of_week = 6)

    UNION ALL

    SELECT td.Event7 , td.Fromdate, td.ToDate, c.MonthName

    FROM

    cteDates AS c INNER JOIN TransData AS td

    ON c.calendar_date >= td.Fromdate

    AND c.calendar_date <= td.ToDate

    WHERE(td.Event7 = 1) AND (c.day_of_week = 7)

    ) d

    )

    select

    fromdate,todate,

    sum(case when monthname = 'apr 2013' then event else 0 end) as 'apr 2013',

    sum(case when monthname = 'may 2013' then event else 0 end) as 'may 2013',

    sum(case when monthname = 'jun 2013' then event else 0 end) as 'jun 2013',

    sum(case when monthname = 'jul 2013' then event else 0 end) as 'jul 2013',

    sum(case when monthname = 'aug 2013' then event else 0 end) as 'aug 2013',

    sum(case when monthname = 'sep 2013' then event else 0 end) as 'sep 2013',

    sum(case when monthname = 'oct 2013' then event else 0 end) as 'oct 2013',

    sum(case when monthname = 'nov 2013' then event else 0 end) as 'nov 2013',

    sum(case when monthname = 'dec 2013' then event else 0 end) as 'dec 2013',

    sum(case when monthname = 'jan 2014' then event else 0 end) as 'jan 2014',

    sum(case when monthname = 'feb 2014' then event else 0 end) as 'feb 2014',

    sum(case when monthname = 'mar 2014' then event else 0 end) as 'mar 2014'

    from cteresults

    GROUP BY

    fromdate, todate

    ORDER BY

    fromdate, todate

    ________________________________________________________________
    you can lead a user to data....but you cannot make them think
    and remember....every day is a school day

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply