SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Counting weekdays within a date range and grouping them by month


Counting weekdays within a date range and grouping them by month

Author
Message
m_kanjalkar
m_kanjalkar
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 5
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.

FROM TO Event1 Event2 Event3 Event4 Event5 Event6 Event7
29-Apr-13 01-May-13 1 0 1 0 0 0 0
30-Apr-13 25-Oct-13 1 1 0 1 1 1 1
08-May-13 11-Sep-13 0 0 1 0 0 0 0
18-Sep-13 18-Sep-13 0 0 1 0 0 0 0
25-Sep-13 23-Oct-13 0 0 1 0 0 0 0
26-Oct-13 26-Oct-13 0 0 0 0 0 1 0
27-Oct-13 28-Mar-14 1 1 1 1 1 1 1
29-Mar-14 29-Mar-14 0 0 0 0 0 1 0
30-Mar-14 24-Oct-14 1 1 1 1 1 0 1
05-Apr-14 18-Oct-14 0 0 0 0 0 1 0

The results I am expecting are as per the attachment.

Is anyone able to help.
Attachments
image.png (19 views, 26.00 KB)
Sean Lange
Sean Lange
SSC Guru
SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)

Group: General Forum Members
Points: 64678 Visits: 17979
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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
J Livingston SQL
J Livingston SQL
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12554 Visits: 37669
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

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search