x

Structuring SSRS Query / Stored Procedure

Hi,

I have been given the task of updating some of our older reports from our task system now that we have access to SSRS 2008 and the database has been migrated to SQL Server 2008 R2. I have found one that pulls data in the format shown below (You select a specific month for a specific year)

  • Name - Staff members name
  • YTD Total - Total requests raised from Jan 01 to end of parameter month
  • YTD Outstanding - Total outstanding requests from Jan 01 to end of parameter month
  • Total Requests - Total requests raised for parameter month
  • Oustanding 0-14 - Outstanding requests for parameter month 0 to 14 days old
  • Oustanding 14-28 - Outstanding requests for parameter month 14 to 28 days old
  • Oustanding 28+ - Outstanding requests for parameter month more than 28 days old
  • Oustanding Total - Total outstanding requests for parameter month

The two tables the data is pulled from are:

[Staff]

  • ID (int)
  • Name (varchar)

[Tickets]

  • ID (int)
  • Staff_ID (int)
  • Start_Date (datetime)
  • End_Date (datetime)
  • Status (varchar, "O" is default for outstanding, rest are considered actioned)

To clarify, in the above "for a parameter month" means any that were raised in that month and fit the other criteria. Also by "parameter" I mean a param passed to the existing stored procedure.

Currently the stored procedure generates each of the above into a temp table then LEFT JOINs them against the officer list to produce the data for the report.

The end result of the SP where it selects the data from the temp tables is shown below

SELECT #TempYTDReqTable.*,
  ISNULL(#TempYTDOutTable.OutstandingYTD,0) AS OutstandingYTD,
  ISNULL(#TempOutTable.Outstanding,0) AS Outstanding,
  ISNULL(#TempReqTable.Requests,0) AS Requests,
  ISNULL(#TempOut014Table.Outstanding014,0) AS Outstanding014,
  ISNULL(#TempOut1428Table.Outstanding1428,0) AS Outstanding1428,
  ISNULL(#TempOut28Table.Outstanding28,'0') AS Outstanding28
FROM #TempYTDReqTable
  LEFT JOIN #TempYTDOutTable ON #TempYTDReqTable.Officer = #TempYTDOutTable.Officer
  LEFT JOIN #TempOutTable ON #TempYTDReqTable.Officer = #TempOutTable.Officer
  LEFT JOIN #TempReqTable ON #TempYTDReqTable.Officer = #TempReqTable.Officer
  LEFT JOIN #TempOut014Table ON #TempYTDReqTable.Officer = #TempOut014Table.Officer
  LEFT JOIN #TempOut1428Table ON #TempYTDReqTable.Officer = #TempOut1428Table.Officer
  LEFT JOIN #TempOut28Table ON #TempYTDReqTable.Officer = #TempOut28Table.Officer
ORDER BY #TempYTDReqTable.Officer

My question is: How can I do this more efficiently?

Can I get more out of SSRS and have it doing more for me? Can I reformat the SP to use less or no temp tables? It just doesn't feel like a temp table for every field in the report is the best way to go about it, but trying to reformat it has resulted in nothing even close each time I have tried.

Let me know if any further information is required.
more ▼

asked Jul 19, 2012 at 06:22 AM in Default

Alex.Ritna gravatar image

Alex.Ritna
40 2 2 4

(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

Can I get more out of SSRS and have it doing more for me?

Yes, definitely. I generally prefer formatting, Running Totals, SUM etc. to be done in Reporting Services. Since there is not much information I have and to work on Reporting Services is not possible for me at the moment. I cannot help much in this regard.

Can I reformat the SP to use less or no temp tables?

Again Yes. Seems like you can handle it all in one SELECT with the trick of using COUNT with CASE statements

Something like

DECLARE @Staff TABLE
(

    ID INT,
    Name VARCHAR
)
DECLARE @Tickets TABLE
(
    ID INT,
    Staff_ID INT,
    Start_Date DATETIME,
    End_Date DATETIME,
    Status varchar--, "O" is default for outstanding, rest are considered actioned)
)

DECLARE @DateParam DATETIME

SELECT S.[Name] StaffName
,    COUNT(*) YTDTotal
,    COUNT(CASE WHEN [Start_Date] >= CONVERT(VARCHAR,DATEADD(dd,-(DAY(@DateParam)-1),@DateParam),112)
 THEN 1 ELSE NULL END) Requests
,    COUNT(CASE WHEN [Start_Date] >= CONVERT(VARCHAR, DATEADD(dd, -13, @DateParam), 112)
 AND Status = 'O'
 THEN 1 ELSE NULL END) Outstanding014
,    COUNT(CASE WHEN [Start_Date] >= CONVERT(VARCHAR, DATEADD(dd, -27, @DateParam), 112)
 AND [Start_Date] < CONVERT(VARCHAR, DATEADD(dd, -13, @DateParam), 112)
 AND Status = 'O'
 THEN 1 ELSE NULL END) Outstanding1428
,    COUNT(CASE WHEN [Start_Date] < CONVERT(VARCHAR, DATEADD(dd, -27, @DateParam), 112)
 AND Status = 'O'
 THEN 1 ELSE NULL END) Outstanding28
,    COUNT(CASE WHEN [Start_Date] >= CONVERT(VARCHAR,DATEADD(dd,-(DAY(@DateParam)-1),@DateParam),112)
 AND Status = 'O'
 THEN 1 ELSE NULL END) OustandingTotalForTheMonth
FROM @Staff S JOIN @Tickets AS T
ON [S].[ID] = [T].[Staff_ID]
WHERE [Start_Date] BETWEEN CONVERT(DATETIME,CONVERT(CHAR(4), YEAR(GETDATE()))+ '0101')
 AND @DateParam
GROUP BY S.[ID], [S].[Name]
more ▼

answered Jul 19, 2012 at 07:28 AM

Usman Butt gravatar image

Usman Butt
13.9k 6 8 14

Perfect thank you, I was unaware I could use the CASE expression inside COUNT() or other aggregate functions. This opens up a whole new world!

I have reformatted the query using COUNT with CASE and it's not only more readable and easier to maintain but significantly faster.

I will also look into getting some more power out of sorting, filtering and so forth with in my reports as well.
Jul 20, 2012 at 01:04 AM Alex.Ritna
(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

New code box

There's a new way to format code on the site - the red speech bubble logo will automatically format T-SQL for you. The original code box is still there for XML, etc. More details here.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x986
x547

asked: Jul 19, 2012 at 06:22 AM

Seen: 846 times

Last Updated: Jul 20, 2012 at 10:20 AM