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


Need some help please - trying to create a weekly calendar report in SSRS


Need some help please - trying to create a weekly calendar report in SSRS

Author
Message
BarbD
BarbD
SSC Rookie
SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)

Group: General Forum Members
Points: 25 Visits: 92
I need to create a weekly calendar report showing activities for each sales rep in a particular location. It should have the days of the week (M-F) horizontally across the top, and hours in the day (7am-5pm) vertically along the left hand side. Each day column should show activities scheduled for that rep for that day next to the appropriate time interval. Can anyone help me with an example of code you used to do this? I would really appreciate it. Thanks!
Jack Corbett
  Jack Corbett
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18458 Visits: 14894
We need to know more about the schema you are getting the data from so we can write a query that returns the data you need to produce the report you want. I think I'd do something like this and then pivot the data in the report:


DECLARE @people TABLE (ID INT, name VARCHAR(10));
DECLARE @appointments TABLE
(
ID INT,
PeopleID INT,
AppointmentTime DATETIME
);

/* Calendar table down to the hour as it'll be needed to make sure you have a block for each hour */
DECLARE @calendar TABLE
(
ID INT IDENTITY(1, 1),
theDateStart DATETIME,
theDateEnd DATETIME,
theYear SMALLINT,
theMonth TINYINT,
theDay TINYINT,
theHour TINYINT
);

WITH N AS (
SELECT TOP 1000
ROW_NUMBER() OVER (ORDER BY (
SELECT
NULL
)) AS n
FROM
sys.all_columns AS AC
)
INSERT INTO @calendar
(
theDateStart,
theDateEnd,
theYear,
theMonth,
theDay,
theHour
)
SELECT
DATEADD(HOUR, -N.n,
CONVERT(DATETIME, CONVERT(DATE, GETDATE()))) AS theDateStart,
DATEADD(HOUR, -N.n + 1,
CONVERT(DATETIME, CONVERT(DATE, GETDATE()))) AS theDateEnd,
YEAR(DATEADD(HOUR, -N.n,
CONVERT(DATETIME, CONVERT(DATE, GETDATE())))) AS theYear,
MONTH(DATEADD(HOUR, -N.n,
CONVERT(DATETIME, CONVERT(DATE, GETDATE())))) AS theMonth,
DAY(DATEADD(HOUR, -N.n,
CONVERT(DATETIME, CONVERT(DATE, GETDATE())))) AS theDay,
DATEPART(HOUR,
(DATEADD(HOUR, -N.n,
CONVERT(DATETIME, CONVERT(DATE, GETDATE()))))) AS theHour
FROM
N

INSERT INTO @people
(ID, name)
VALUES
(0, -- ID - int
'Jack' -- name - varchar(10)
),
(1, -- ID - int
'Steve' -- name - varchar(10)
)

INSERT INTO @appointments
(ID, PeopleID, AppointmentTime)
VALUES
(0, -- ID - int
0, -- PeopleID - int
DATEADD(DAY, -7, GETDATE()) -- AppointmentTime - datetime
),
(2, -- ID - int
0, -- PeopleID - int
DATEADD(HOUR, -4, DATEADD(DAY, -7, GETDATE())) -- AppointmentTime - datetime
),
(3, -- ID - int
1, -- PeopleID - int
DATEADD(DAY, -6, GETDATE()) -- AppointmentTime - datetime
),
(4, -- ID - int
1, -- PeopleID - int
DATEADD(HOUR, 2, DATEADD(DAY, -3, GETDATE())) -- AppointmentTime - datetime
)


SELECT
C.ID,
C.theDateStart,
C.theDateEnd,
P.ID,
P.name,
A.ID,
A.PeopleID,
A.AppointmentTime,
DATENAME(WEEKDAY, C.theDateStart) AS theWeekDay
FROM
@calendar AS C
LEFT JOIN @people AS P
JOIN @appointments AS A
ON P.ID = A.PeopleID
ON A.AppointmentTime >= C.theDateStart AND
A.AppointmentTime < C.theDateEnd
WHERE
C.theDateStart >= DATEADD(DAY, -7, CONVERT(DATE, GETDATE()))
ORDER BY
C.theDateStart;



That's the best I can do with the little information you provided.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
BarbD
BarbD
SSC Rookie
SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)

Group: General Forum Members
Points: 25 Visits: 92
It is a SQL Server 2005 database. The activity record contains a startdate (datetime) field as well as an activity type and description. It joins to the employee table by activity.userid = employee.userid. The employee table also contains a location code, so you can select all employees for a particular location. They want the report to have 1 page for each employee within the selected location showing the activities for the upcoming week (date range parms) in the calendar format specified above. Not sure what other information you need. I've never used a matrix in a SSRS report before - is that what I need to use? If so, how do I set it up?
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