Archive for SSRS

Questions Answered From Presentation: SSRS 101 Creating Reports for Diagnostic Data

On Tuesday, July 7th, 2015, I had the privilege of speaking for the DBA Fundamentals Virtual Chapter. Thanks to the 375 who attended and to all who will be watching the recording. While I can’t read the comments during my presentation (way too distracting), I did enjoy reading the questions and comments that were sent to me. Below you will find answers to the questions I was sent.

Questions Answered

1. Are you talking about SSRS 2016 or 2014?

I was presenting using SSRS 2012, but the demos and discussions applied to versions 2008 through 2014.

2. When should you use SSRS RDL vs. RDLC (Remote Definition Language Client-side)?  Should you be able to invoke RDL from a web app (say web forms, asp.net) just as easily as RDLC?

The difference is RDLC reports will run on the client side. They don’t need to access the report server. RDL reports can be invoked on the client side, but they are rendered on the report server then delivered to the client. The RDLC reports would be part of an application and will take up client resources to generate.

3a. What is the difference between SSRS and Reports Application in Visual Studio 2010 (full version)?

3b.Why use SSDT over Visual Studio?

I liked both of these questions, and they have the same answer, so I wanted to group them together.

SSRS (SQL Server Reporting Services) files are generated in two applications, Report Builder and Visual Studio. Report Builder exists on the Reporting Server called Report Manager. Visual Studio is the Integrated development environment (IDE) that you write code in. Microsoft created (at least) two distributables for Visual Studio. The one that Application Developers, is only known as Visual Studio and the one that comes with SQL Server called SQL Server Data Tools (SSDT). The IDE is the same for both of them. When they co-exist on the same computer, they will be integrated. If you only have the SSDT version, then you can only create SSRS, SSIS, and SSAS projects. You can also download over project types for Visual Studio, such as PowerShell projects.

Note: For SQL Server 2008 it was called Business Intelligence Development Studio (BIDS). It was renamed to SSDT in version 2012.

3a. Is it better to use SSDT or Report Builder? I have been using Report Builder for my reports so far…

The answer to this depends on your comfort level for creating reports. Report Builder is meant for the power users in the business. SSDT is meant for developers. I’ve personally never used report builder, but that’s because I’ve been writing reports since before Report Builder was introduced. If you continue to create reports in Report Builder, then take a look into generating Report Parts. Those were introduced in SQL 2012 and are supposed to be “building blocks” to help create more complicated reports within Report Builder.

4. If you don’t have the source of the report can you get it back from the web

I am happy to tell you, yes! (and there was much rejoicing!)

In the Report Manager, pull down the menu to the right of the report and select download. You can also go into the properties of the report and see the download option in the toolbar for that report.

Answers201507_01

5. How did you link the two datasets?

The two datasets weren’t linked like you would see writing a JOIN statement. They were filtered using the same parameter. Datasets can’t be joined together within the report. There are a couple of functions introduced in SQL 2008 R2 that allow you to reference a single value from another data set, but that is as close as they have gotten.

6. How is the security configured within the data sources ? How can the double-hop authentication issue be avoided when accessing data from multiple servers ?

You have 4 different security options that you can use. Books online can tell you the details on each of them.

Answers201507_02

I personally use a SQL Server login, only used for reports to access the data. I then use windows authentication to access the reports themselves. Each data source can connect to a different server and even use a different SQL Server account.

I’m not sure I’m answering your question adequately since it can be read a couple of different ways. If you are looking for a solution to a double-hop authentication problem, then take a look at this article. I’ve faced this once, but it was about 5 years ago. The Double-Hop Authentication Problem

Send me an email if you still have questions on this topic.

7. I saw that you saved the password for the data source (during development). How can we ensure that it is encrypted when deployed to the server?

I would have to do some research to see how the password is sent during the publishing event, but I do know it is stored encrypted.  In fact, the Connection String, UserName, and Password are all encrypted. Go into the ReportServer database and run this query: SELECT * FROM ReportServer.dbo.DataSource.

If you are still concerned about the Data Source during the publishing event, then you can create the data source manually in Report Manager. As long as the SSRS project has the property “OverwriteDataSources” set to false, the data source will remain the one you manually created.

8. What if you want to show multiple databases (in your report)?

You can create as many data sources as you need and they can each point to a different database on a different SQL Server.

If you are gathering diagnostic data, like we were doing in the demo, then you might want to consider a two step approach. The first step would be to have an SSIS package or a PowerShell script retrieve the diagnostic data from each server on a schedule and save the data to a central database. Then you can have the report pull the diagnostic data from that central database.

9. Can hidden parameters have values passed to them, for example: can a hidden parameter list containing state names have “CA” passed to it when the report is opened?

Yes. That would be done in the parameter properties on the report in the Report Manager, from code, or from another report. You can also create Linked Reports in the Report Manager and change the values of the hidden parameters.

10. Is there any difference between previewing the report than just running it by r-clicking on the report?

Not really.

11. Can you set border style in your template? So it’s not there at all?

Yes. If you were to save a new tablix in the template with the borders set to None for each row. Then you would copy that tablix for each tablix you need. Unfortunately you can’t modify the actual tools in the toolbox.

12. Any strategy to fine tune multiple drop down option/filter in SSRS report.

Yes.

1. Make sure that the Queries that are populating the drop down lists are FAST.

2. If the drop down lists are filtering each other, known as cascading parameters, then have them filter within the report, instead of making a round trip back to SQL Server for the filtering. This would be done by applying the filter to the 2nd parameter in the filter property instead of attaching it to the parameter property.

3. Make sure that the predicates of each of the queries and the final data set have proper indexes.

4. If the queries that the drop down lists are using are really slow due to too many JOINs, then consider using an SSIS package to create a static table that is updated every X minutes/hours with the latest data. Then use that table for the parameter lists.

13. This is not the question you are looking for. Move along. Move along.

14. How to display a message in the report if the dataset doesn’t return any records ?

This is an excellent question and the answer is not used enough.

Set the NoRowsMessage property on the tablix (Table/Matrix/List) control. You can get to it through the property window. The value of this property is displayed when there is no data to show. The value can even be an expression.

15. How to get a big report to limit to 4000 records but well distributed in terms of days in a month?

I would love to have more information on why you have this requirement. It is an interesting one. Here is what you can do. Note: It will slow the query down though, so make sure you have good indexes on the predicates.

1. I have 1 million rows of random dates and numbers. This happens to be a very narrow table.

Answers201507_03

2. I use the ROW_NUMBER() function. It will give a sequential number to each row based on the partition. I partitioned the data based on Year, Month, Day. If your date field does not have time, then you can partition based on the date field. Within each partition, the data is sorted by Date then TestDataID (the PK). This will help guarantee the same order each time.

3. I determined how many days were in the range of dates I’m selecting from, divided 4000 by that number, and select only those row number values per date. This will provide an even distribution across days.

4. Since you can’t guarantee that the number of days will divide evenly into 4000, you need to either have less than 4000 rows returned, or more than 4000 returned by adding 1 to the number created in step 3.

Answers201507_04


–1 million rows
DECLARE @StartDate AS DATE = ‘1/1/1972’;
DECLARE @EndDate AS DATE = ‘1/1/1973’;

SELECT DATEDIFF(DAY,@StartDate, @EndDate) AS NumberOfDays;
WITH cte_ranking
AS
(
SELECT TOP 100 PERCENT
TestDataID
,SomeDate
,SomeTextNumber AS SomeNumber
,ROW_NUMBER() OVER (PARTITION BY dateyear, datemonth, dateday ORDER BY datevalue, TestDataID) AS RN
FROM
DemoProgramming.dbo.TestData AS td
JOIN dbo.DimDate AS dd ON td.SomeDate = dd.DateValue
WHERE
td.SomeDate >= @StartDate
AND td.SomeDate <= @EndDate
ORDER BY datevalue
)
SELECT
cte.TestDataID
,cte.SomeDate
,cte.SomeNumber
FROM
cte_ranking AS cte
WHERE
cte.RN <= (4000/DATEDIFF(DAY,@StartDate, @EndDate)) + 1;

–Returned 4038 rows

[\SQL]

16. With subscriptions is it possible to make one subscription to use the current fiscal month to generate report vs. creating 12 subscriptions for each fiscal month?

Unfortunately no. You can do it based on calendar months, but not based on fiscal months where the first day of the fiscal month may not be the 1st day of the calendar month. I would love to see this feature.  If this is a must have requirement, then email me and we can talk about some “creative” solutions.

17. What are the different security roles on report server side?

The SSRS development team were kind enough to add the definitions on the security screen.

Answers201507_05

 

18. Can you append the date/time to the file name that gets created with a subscription that saves to a fileshare?

Yes. Add the @ExecutionTime parameter to the filename.

19. How do you set-up the email option for the subscription?

First your Report Manager needs to be setup to send email. I usually have my Sys Admin help me with that.

After that, it’s a matter of populating fields (and there was much rejoicing.)

If you use the standard subscription, then the setup screen will look like figure A below. If you are creating a data driven subscription, then the setup screen will look like figure B below. Either way, you need to set all the properties. Then select a schedule for the emails to go out on.

I would highly suggest using Active Directory groups for the To list. This make is easier to manage when people change jobs. You may also want the email to go to yourself for a few days or weeks to make sure it is going out as predicted.

figure A

Answers201507_06

figure B

Answers201507_07

 

Thanks for all the fish

I wanted to give a shout out to Glenn Berry for letting me use his diagnostic queries for my demos. You can find the full diagnostic script, per SQL Version here on Glenn’s website.

The downloads for this presentation are available on the DBA Fundamentals Meeting Archives page and will be available on my website under Resources shortly.

T-SQL Tuesday #66: Monitor ALL Reports

Catherine Wilhelmsen (b|t) is hosting this month’s T-SQL Tuesday blog party. The party was started by Adam Machanic (b|t) in December of 2009.

This month’s invitation is about monitoring.

This topic is a tough one. I didn’t want to pick just one topic. Especially since I just installed SQL Sentry’s Performance Advisor in production and the Redgate’s DLM Dashboard in Dev. Both products are helping me see my environments clearer.

But what about the need to monitor other items that don’t have a cool tool you can buy off the shelf? Or products like SSRS that have built in metrics collection?

That is when you need to roll your own code to capture metrics to help monitor your own, unique environment.  Take Excel reports as an example, or really any application that is used for reporting. It would be wonderful if you could capture metrics and monitor usage of ALL reports across your environment in a consistent manner. Let’s take a look at a way that can be accomplished.

In the beginning

The first thing you need to do is some planning. You need to know what kind of data you want to capture, and how you are going to update the existing reports to capture that data.

I happen to really like the way that SSRS collects usage metrics. So, for my Excel reports, I wanted to collect similar data. This will allow me to have one report to show how all my reports are performing. Maybe my top 10 slowest reports are from 3 different reporting platforms.

I created a couple of tables to hold the non-SSRS report metrics and meta data. I then created a stored procedure to insert the data into the tables. Finally, I added the stored procedure to the bottom of the stored procedures used by the Excel reports I wanted to keep track of.

Step 1

I created a table that held the information I wanted to collect.


CREATE TABLE dbo.ReportType
(ReportTypeID INT IDENTITY PRIMARY KEY
,ReportTypeName AS varchar(20) NOT NULL
)

INSERT INTO dbo.ReportType(ReportTypeName) VALUES ('Excel');
INSERT INTO dbo.ReportType(ReportTypeName) VALUES ('PowerPoint');

CREATE TABLE dbo.ReportLog
(ReportLogID INT IDENTITY PRIMARY KEY
,ReportTypeID INT NOT NULL
,ReportPath VARCHAR(255) NOT NULL
,ReportName VARCHAR(255) NOT NULL
,UserName NVARCHAR(255) NOT NULL
,SprocName VARCHAR(255) NOT NULL
,ReportParameters VARCHAR(500) NULL
,TimeStart DATETIME NOT NULL
,TimeEnd DATETIME NOT NULL
,Row_Count INT NOT NULL
)

Step 2

I created a stored procedure that I could have at the bottom of the stored procedures the reports are using.


CREATE PROCEDURE dbo.InsertReportUsage
(
@ReportTypeID INT
,@ReportPath VARCHAR(255)
,@ReportName VARCHAR(255)
,@UserName NVARCHAR(255)
,@SprocName VARCHAR(255)
,@ReportParameters VARCHAR(500)
,@TimeStart DATETIME
,@TimeEnd DATETIME
,@Row_Count int
)
AS
BEGIN TRY
SET NOCOUNT ON

INSERT INTO ReportLog
(
ReportTypeID
,ReportPath
,ReportName
,UserName
,SprocName
,ReportParameters
,TimeStart
,TimeEnd
,Row_Count
)
VALUES
(
@ReportTypeID
,@ReportPath
,@ReportName
,@UserName
,@SprocName
,@ReportParameters
,@TimeStart
,@TimeEnd
,@Row_Count
)
END TRY
BEGIN CATCH

DECLARE
@ErrorMessage AS nvarchar(3000)
,@ErrorSeverity AS int

SET @ErrorMessage = ISNULL(DB_NAME(DB_ID()) + N'.' + SCHEMA_NAME(SCHEMA_ID()) + N'.' + OBJECT_NAME(@@PROCID, DB_ID()),
N'SQL Object Name Not Available') + N': Error: ' + CONVERT(nvarchar(10), ERROR_NUMBER()) + N' Line: '
+ CONVERT(nvarchar(5), ERROR_LINE()) + N' - ' + ERROR_MESSAGE()

SET @ErrorSeverity = ERROR_SEVERITY()
RAISERROR(@ErrorMessage, @ErrorSeverity, 1)
END CATCH

SET NOCOUNT OFF
GO

Step 3

I added some common fields at the top of the stored procedure for my report. Then, at the bottom I called the stored procedure that will record the report usage metrics.

Since I didn’t want to hard code the report path or the report name in the stored procedure, I passed those values from Excel.

I was also able to dynamically capture the stored procedure name, and the system user’s credentials.

Here is an example of a report that lists the names of employees.


CREATE PROCEDURE dbo.PersonReport
(
@LastName varchar(100)
,@ReportPath VARCHAR(255)
,@ReportName VARCHAR(255)
)
AS
BEGIN TRY
--SET NOCOUNT ON  (Don't set)

--------------Excel Log Block--------------
DECLARE    @SprocName VARCHAR(255) = DB_NAME(DB_ID()) + '.' + SCHEMA_NAME(SCHEMA_ID()) + '.' + OBJECT_NAME(@@PROCID, DB_ID())
DECLARE    @ReportParameters VARCHAR(8000) = 'LastName=' + @LastName
DECLARE    @TimeStart DATETIME = GETDATE()
--------------Excel Log Block--------------

SELECT
p.BusinessEntityID
,p.Title
,p.FirstName
,p.MiddleName
,p.LastName
FROM
Person.Person AS p
WHERE
p.LastName LIKE @LastName + '%';

--------------Excel Log Block--------------
EXEC ReportManagement.dbo.InsertReportUsage 1, @ReportPath, @ReportName, SUSER_NAME(), @SprocName
,@ReportParameters, @TimeStart, Get_date(), @@RowCount
--------------Excel Log Block--------------
END TRY
BEGIN CATCH

DECLARE
@ErrorMessage AS nvarchar(3000)
,@ErrorSeverity AS int

SET @ErrorMessage = ISNULL(DB_NAME(DB_ID()) + N'.' + SCHEMA_NAME(SCHEMA_ID()) + N'.' + OBJECT_NAME(@@PROCID, DB_ID()),
N'SQL Object Name Not Available') + N': Error: ' + CONVERT(nvarchar(10), ERROR_NUMBER()) + N' Line: '
+ CONVERT(nvarchar(5), ERROR_LINE()) + N' - ' + ERROR_MESSAGE()

SET @ErrorSeverity = ERROR_SEVERITY()
RAISERROR(@ErrorMessage, @ErrorSeverity, 1)
END CATCH

SET NOCOUNT OFF
GO

Last Step

Finally, I created a stored procedure that joined the metrics from the ExecutionLog3 View that is provided in the ReportServer database for SSRS report usage metrics with the metrics I captured in the ReportLog table.

Now I can generate an overarching report for all reports in my environment.

Thanks for all the fish

Thanks go out to Catherine Wilhelmsen for hosting this month’s T-SQL Tuesday blog party. She is one of my favorite people to catch up with during PASS Summit. I hope you spend some time catching up with her on her blog.

Questions Answered From Presentation (Part 2): Creating SSRS Reports Efficiently Through Best Practices

On Tuesday, March 3rd, 2015, I had the privilege of speaking for Pragmatic Works. For the month of March, they are highlighting Women in Tech and have the whole month lined up with female speakers on each Tuesday and Thursday. I was the first in the line up for the month and it ended up being my largest audience to date. There were 419 people listening in. I even saw some comments about there being others who couldn’t make it. Wow

Thanks to everyone who came to listen to my session. While I couldn’t hear anyone, I enjoyed reading the questions and comments that were sent to me afterwards, and let me tell you there were quite a few. Below you can find the answers to SECOND HALF of the questions that were asked. The first half of the questions can be found here.

Questions Answered

1. How do you make the report to see test database or production db or development db?

This is done by changing the data source properties. Say I have a database server called Monkey. I would create a shared data source called Monkey that each of the reports would share. On the Development SSRS Server, I would have the Monkey data source point to the development database. On the QA server, I would have the Monkey data source point to the QA database. And on the Production server, I would have the Monkey data source point to the production database. Each time the report is loaded into the new environment, it would automatically point to the correct database server.

If you are in a situation, where environments have to share a SSRS report manager (and I’m sorry if you are in that situation), then I would create a separate parent folder for each environment. For instance a parent folder called Development and a parent folder called QA. In each of these parent folders, I would create a folder for all your shared data sources for that environment. Each parent folder would have its own copy of the report and its own shared data source called Monkey pointing to the correct database.

2. When copyrighting, does your company need to be registered with the copyright office?

The answer to this question should come from your legal department. Through my experience, the answer is no. Copyright laws are different than patent laws. When I was an artist, the fact I made the artwork first, meant I owned the copyright. Even in another country.

3. Query for getting reports that have not been run.


SELECT

c.ItemID

,c.Path

,c.Name

FROM

ReportServer.dbo.Catalog AS c

LEFT JOIN [ReportServer].[dbo].[ExecutionLog3] AS e ON c.[Path] = e.ItemPath

WHERE

e.ItemPath IS NULL

AND Path NOT LIKE '/Decommisioned Reports%' --Ignore folders I don't care about.

AND c.Type NOT IN (1, 5, 8) -- Ignore Folders, Data Sources, and Data Sets

ORDER BY

c.Path

,c.Name

4. How did you add the template file in Visual studio?

For SSRS 2012, I put the RDL, RSD, and RDS files in the following directory: C:\Program Files (x86)\Microsoft Visual Studio 10.0\Common7\IDE\PrivateAssemblies\ ProjectItems\ReportProject. The directory will be different for 2008 and 2014.

5. What if a company doesn’t have any procedure for gathering requirements and creating/keeping documentation?

This puts you in the driver position. I would suggest meeting with your manager to discuss the benefits of having requirements documentation and a standard way of maintaining the documentation. I would then outline a plan for starting on this new path. I would start with new reports, and slowly add in existing reports as they get modified.

Awesome quote from one of the attendees:
I ask “what the decision is going to be taken with the data from the report”

6. How do you know the width to fit on landscape and portrait nicely?

I like half inch margins. So I subtract the two half inch margins from the width of the landscape or portrait paper. That becomes the width of the base report. I also set the half inch margins in the Margin property of the Report.

7. Could you show an example of a Tracking Number?

Sure! If I were using an Excel spreadsheet to keep track of my reports, I would number all my reports starting with 1000. (Why 1000? I like starting with 4 digits. No other reason.) If I were using a product like Team Foundation Server (TFS), then I would have each report represented by a work item. In either case, say the report named National Sales Revenue was represented by the number 1500. 1500 would always represent the report National Sales Revenue.

The first time this report is successfully published to production, it would be given a “release number” of 00. So the tracking number would look like 01500.00. After modifications were made to the report and republished to production, it would get a new release number of 01. The new tracking number would look like 01500.01.

In the location where I store all my documents for my reports, the report National Sales Revenue, will be stored under the number 01500. I usually add the name of the report to the folder name so that it looks something like 01500 – National Sales Revenue. This allows for two things. One, you can create the folder before you have a permanent title. (The temporary folder name would just be 01500.) Two, if the title changes later for some reason, you don’t lose the documentation location. It’s still under 01500.

8. What methodology do you use to create the Tracking Number or is it automatically generated from TFS?

When I’m using TFS, it is automatically generated for me. TFS uses a single sequential string of numbers across all the work item types (task, bug, custom work item, etc.), so you may have a report with number 1500, and then the next report will be number 1583. I do put a leading zero or two in front of the number so that when it goes two 5 digits, my folders are still in the correct order.

9. How do you put in the watermark?

a. Click on the base report.

b. Go to the properties window.

c. Click and open the BackgroundImage property.

d. Set the BackgroundRepeat property to repeat.

e. Set the MIMEType property to the correct format.

f. If you are using an Embedded image, set the following properties.

i. Source = Embedded

ii. Value = iif(First(Fields!EnvironmentID.Value, “GetReportStandards”) <3,”DRAFT”,””)

g. If you are using an image from the database, set the following properties.

i. Source = Database

ii. Value =iif(First(Fields!EnvironmentID.Value, “GetReportStandards”) <3,First(Fields!Draft.Value, “GetReportStandards”),””)

h. If you are using an image from a server location, set the following properties.

i. Source = External

ii. Value =iif(First(Fields!EnvironmentID.Value, “GetReportStandards”) <3,”location of your image”,””)

10. If a report is setup as a subscription, how can I tell if the subscribers are actually using/accessing the report?

This is an excellent question. The ReportServer Database will tell us which reports were executed through a subscription, but it cannot tell us if they were used. I have some ideas on ways to still capture the information, but they would require research and extra layers of complexity. If you want to hear about these ideas, send me an email.

Awesome idea from one of the attendees:
Maybe we should add a “pixel tag” to the report so that hits a web server which can track access.

11. This is not the question you are looking for. Move along. Move along.

12. Is there any way to handle the row hight dynamically in Excel output where include the merged cells? (Can grow does work with merged cells)

I don’t know a definitive answer to this question, but my inclination is to say no. Dynamically changing row height/width outside of the auto grow properties, is usually not possible. I have found ways around this by providing multiple layouts of columns/rows and hiding the ones I don’t want.

13. How can you use a business glossary to develop your label and be consistent across reports?

This question is a big one. The simple answer, is you need buy in from the business to make it happen and discipline from the entire team to make it successful. I would suggest you look into the topics for Data Governance, Business Semantics glossary, and Conceptual Data Modeling. These areas are what would help create and drive the business glossary from the very beginning, so that by the time you are ready to create a report, the terms already exist.

If you can’t get buy in yet, or ever, then I would suggest creating your own business glossary. Excel would work and is easily searchable. Make sure it is stored where your whole team can update it and use it.

14. Any major changes to SSRS 2014?

No. You can see the changes from version to version here. Just select the version you want to look at from the “other versions” drop down at the top of the article.

15. Can you tell what format they placed it in? PDf Excel

The Format Field in the ExecutionLog3 view will give you that information. Here is an example looking at the rendered format of a subscription.


SELECT

ItemPath

,UserName

,RequestType

,[Format]

,ItemAction

,TimeStart

,TimeEnd

FROM

ReportServer.dbo.ExecutionLog3

WHERE

RequestType = 'subscription'

AND ItemAction = 'Render'

16. How long did it take you to build this framework?

It took me a couple of years. I started by tracking down all the reports and entering them in an Excel spreadsheet. My manager wanted a more permanent solution that could be shared with others, so I was given time to create a custom Report Work Item in TFS. I then moved the whole catalog there and decommissioned the Excel based catalog.

For the requirements and design document, I slowly saw a pattern of questions that I kept asking, so I designed a requirements document and tweaked it over time.

For my report templates, I looked at existing reports. I took the consistent layouts I found, filled in some things I felt were missing like showing the parameters, and created the templates. They stayed pretty consistent over the years.

17. Is there a way to find out the limit of data export to Excel? We used to have reports which we can view, but time out when exporting to Excel. The limit is per size of other Excel or number of rows?

The limit will be how long it takes to do the export. There is a time limit and it if the export is not accomplished in that time frame, then it will time out. This can be changed with settings in the Report Manager. As far as the amount of data Excel can take, I would Google that, since different versions have different limits.

18. What’s better to use stored procedure or embedded SQL query and how to determine that?

This is an excellent question. This is also a highly debatable discussion, so this is my stance on the topic.

I prefer stored procedures for the following reasons:

  • Stored procedures are easier to modify when they need to be optimized. It is easier to track down a stored procedure in the cache plan than an inline SQL Statement in a report. You also only need to deploy the updated stored procedure back to production, not the report.
  • Dynamic queries are more likely to be classified as an “Adhoc query” by SQL Server. Depending how your SQL Server properties are set, the Execution Plan may never be kept in the cache, which means you will always have the overhead of creating the best Execution Plan.
  • On the reverse, if your SQL Server properties are set to handle Adhoc queries, then you can cause unnecessary bloating in your cache plan since every embedded query with different parameter values will be seen as a different query. That is not true of Stored Procedures….unless they have dynamic SQL inside them.

19. Would you recommend some sort of standards for Data Source Names?

I’m in favor of standards for everything. It satisfies my OCD needs. I keep all my data sources in one folder called either “Data Sources” or “DataSources”, depending if you like spaces in names. For the names, my data source names are the same name as the database they represent. If you have multiple databases with the same name in your production environment, then I would suggest adding the server name to the data source name. You want the Data Source names to represent what they are pointing to.

Name data sets the same way. I use the name of the stored procedure as the name of the data set. If you have the same stored procedure name in different Schemas, then I would include the Schema name in the data set name.

20. How to deploy the SSRS reports using TFS auto build?

I haven’t had the pleasure of using this feature. I unfortunately had to write a deployment document so that the report(s) could be deployed manually.

21. Can you mention the bug again with 2008 R2 with concatenated fields in excel prints?

Sure. In the footer of the report, I had a single textbox that had multiple fields in it. When the report was exported as an Excel document, the textbox was created in the footer of the Excel document, but the font size had been increased to 72 PT font. This bug did not occur on all of our servers.

22. All these best practices are good. I would like to see some more of practical on how to create hierarchies and links and other stuff, maybe in next webinar.

Please, please, please email me what you would like to see in sessions. I am always looking for ideas.

I have an example of a way to handle a hierarchy in my other Pragmatic Works session called: Scalable SSRS Reports Achieved Through the Powerful Tablix.

You can look at my recorded presentations page to see a list of presentations that have been recorded.

You can also look on my 2015 Speaking Engagements to see where I will be speaking or hope to be speaking this year.

23. No Russian Thank you? 🙁

Спасибо

Thanks for all the fish

Thanks go out to everyone who attended the presentation and for the patience of those who waited two weeks for me to answer the second half of the questions.

This is me sitting at a local café with my oldest daughter while I write, she studies, and we both drink flat white coffee. (This week she was working on an essay about Frankenstein and an exegetical essay for another class.  I’ll stick to SQL and SSRS.)
Mar 2015 Victoria and Me at Cafe

Questions Answered From Presentation (Part 1): Creating SSRS Reports Efficiently Through Best Practices

This past Tuesday, March 3rd, 2015, I had the privilege of speaking for Pragmatic Works. For the month of March, they are highlighting Women in Tech and have the whole month lined up with female speakers on each Tuesday and Thursday. I was the first in the line up for the month and it ended up being my largest audience to date. There were 419 people listening in. I even saw some comments about there being others who couldn’t make it. Wow

Thanks to everyone who came to listen to my session. While I couldn’t hear anyone, I enjoyed reading the questions and comments that were sent to me afterwards, and let me tell you there were quite a few. Below you can find the answers to HALF the questions that were asked. The other half of the questions will be answered next weekend.

Questions Answered

1. The number one question that was asked was: Will your documents, like your requirements document, be available?

Yes! You can find all the assets to the presentation under the Resources\Presentation menu on my website. I list all my presentation on this page, so just scroll to the correct presentation title.

I did get some comments about my SSRS templates missing. That has been fixed. Here are the three separate downloads:

If you missed the presentation, don’t worry. Pragmatic Works will be adding it to their catalog of past presentations here.

2. Hey, can you please share us that sample database?

I’m not sure which sample database this was pertaining to. Please email me.

3.  Would you give that mock up tool again?

It’s called Balsamiq. They are a wonderful company with a great user support forum. You can find tons of templates on their website and get your feet wet with a trial version.

4. Do you have any scripting that can be used to see what subscriptions are set up using all the various parameters?

I broke this question up into two questions because I wasn’t clear if you wanted existing subscriptions or executed subscriptions.

Executed

The ExecutionLog3 view in the report server database will have this information for you. You can filter the data on the RequestType field to show you only subscriptions. The Format field will tell you how it was rendered and the Parameters field will tell you what all the parameters were set too. The down side, is they use special escape characters, so you’ll have to decipher it.


DECLARE
@StartDate DATETIME = '03/1/2015'
,@EndDate DATETIME = '04/5/2015'

SELECT
InstanceName
,ItemPath
,UserName
,RequestType
,ItemAction
,TimeStart
,Status
,Format
,Parameters
FROM
ReportServer.dbo.ExecutionLog3
WHERE
ItemPath NOT LIKE '/DataSets/%'
AND TimeStart >= @StartDate
AND TimeStart <= @EndDate
AND RequestType = 'Subscription'
AND ItemPath <> 'Unknown'

Existing  

For existing subscriptions, you can look in the Subscriptions table in the ReportServer database. This lists the subscriptions that are set up, how they will be rendered, and the parameter values that will be used as well as other information.

5. Is there is way to bulk change the owner of a subscription? We have people leave and then when their account is deleted, the subscriptions stop working.

I’ve been asked this before. The information is stored in the ReportServer database, but I am always cautious about directly modifying this database. So , if you change it, then test it heavily  in development before applying the changes to production.

To help with this problem in the future, I would recommend a new standard. All subscriptions should be directed to Active Directory distribution lists. Even if the distribution list has only one person in it. I try to use existing distribution lists, but when I can’t, then I work with the Active Directory Admin (or whoever wears that hat). You could make a distribution list for a specific title, position, or category of people. I also made sure the description on the distribution list was filled out and included something like, “Do not delete this distribution list. It is used for subscriptions.”

6. What tool do you use for your report catalog?

There are several ways to create a report catalog. I started with an Excel document. After I outgrew that, I ended up creating a custom work item in TFS (Team Foundation Server). This allowed me to catalog the report, keep track of the workflow as the report went through its life cycle, and associate work items and bugs to the report.

Here is a blog post by Ted Gustaf on creating custom Workflows in TFS 2010.

7. Don’t you think that its better to get the Requirements and have them sign off on That ?? Prior to a Mock Up ?

Yes, it would save us some work too. Unfortunately, I found that the end users have a hard time verbalizing what they actually want. I find that the changes they request after seeing the mock-ups are not normally based on scope creep, but on the way they verbalized their needs when they initially gave them. This can be due to them not understanding what they really want, to them, assuming we know their data as well as they do. By creating the mockup, they have something tangible to look at. It’s analogous to telling a realtor that you want a three bedroom house, but the first one they show you is not what you were looking for. Now that you’ve seen the house, you can better articulate what you really want in a house.

8. Did you discuss the data quality requirements with your customers?

This is a very good question, and a delicate one. Some customers are very glad you bring this question up, and some customers assume all the data is accurate and will become concerned with past reports if they think the data is “dirty”.

Here are some scenarios and how I handled them. 

  • I was replacing an existing report that had bad data. This is an example of a delicate situation. My manager ended up coming with me to the meeting and backing me up. I showed samples of raw data under both reports and explained why the data was inaccurate before. Always save the explanation and data in an easy to locate place because they will be back asking again why a previous report is so different than a current report.
  • I had to aggregate data based on key phrases in a text field. This is an example where the customer is expecting to have a dialog about the quality of the data found. I spent some time looking at the raw data that did not match her phrases exactly and provided recommendations on additional phrases.
  • One of the requirements I was given for a report was based on ranges of numbers. For this report, I approached my client about the data I found that did not fall into the ranges he was expecting. In this case, it uncovered the need to validate the data when it was entered, so the client was grateful.

The bottom line is, be careful how and to whom you bring this question up to. It is a very important question and should always be addressed. It just may need to be addressed by your team instead of with the client, directly with the client, or in a very subtle manner with the client.

9. How do you place the Tablix color palette in the template form? And, could you provide, in your blog, info about Microsoft’s suggested methods of maintaining tracking info.

Below are the steps for creating a “color palette” on a new template. For your second question, I don’t know if there is an article from Microsoft for best practices on tracking info. In next weeks post, I have examples of how I did it.

Steps for adding your own color palette to a template

  • Add a table control (Tablix) to the body of a new report.
  • Remove the header row.
  • Make sure there is a column for each color in your color palate.
  • Make the width of each cell 0.2 in.
  • Change the background property of each cell to the name or hexadecimal value of your colors.

DeGraeve.com is a really cool website that can be used to create a color palette from an image.

Awesome quote from one of the attendees:
A formal report request process gives the requestor an opportunity to think closely about what is really wanted. Does not force it to happen, but increases the likelihood that a good and complete request will be done.

10. What do you use for Version Control?

I have used both Team Foundation Server (TFS) by Microsoft and Subversion, which is an open source product. There are a few versions of Subversion out there. I used the Tortoise version.

For maintaining my SQL source code easily, I also use Redgate’s SQL Source Control product. It’s like a bridge between your repository (TFS, Subversion, etc.) and SSMS. I am happy to talk to anyone on Redgate’s products. Just send me an email. (No, I don’t work for them. I’m just addicted to their products.)

11. Is it better to use Visual Studios of Report Builder?

Better is not the word I would use. More Powerful is the adjective I would use. Report Builder only has a subset of features that you have in Visual Studio. It was designed to empower “power users” and to provide “self service BI solutions”. If you are designing reports all the time, I would highly recommend using Visual Studio. To see the power of what you can do in Visual Studio, take a look at my Scalable SSRS Reports Achieved Through the Powerful Tablix. It’s recorded on Pragmatic Works website.

Here’s some additional terminology for you with regards to the different versions of Visual Studio. The version that comes with SQL Server is all that you need to design reports. For SQL Server 2012 and 2014 it’s called SQL Server Data Tools and commonly referred to as SSDT. For SQL Server 2008 and 2008R2 it was called Business Intelligence Development Studio and commonly referred to as BIDS.

12. What’s the major difference of standalone SSRS and the SSRS on SharePoint server?

I have never worked with the SharePoint version of SSRS. From what I know, the major difference is how the metadata for the management of the reports is stored in SQL Server. The SharePoint tables are used instead of the ReportServer database. I don’t think the creation of the reports is any different.

13. Can excel templates be imported or easily developed so that if I export to excel it looks like the data came from excel?

I’m not aware of the ability to bring in an Excel templates as an SSRS template. If the user exports the report using the Excel render type instead of the CSV render type, then the report should look like it came from Excel. You might need to email me an image of what you are trying to accomplish for me to answer this question better.

Next weekend I will answer the rest of the questions from this presentation.

Thanks for all the fish

Thanks go out to Liz Hamilton at Pragmatic Works for moderating my presentation. She is wonderful to work with and I loved the movie trivia that she did prior to the presentation.

This is me sitting at a local café with my oldest daughter sorting, compiling, and answering questions. (I think she’s doing Latin homework. I’ll stick to SQL andSSRS.)Cafe201503

Demos Available For Techniques For Dyanice SSRS Reports Presentation from PASS Summit 2014

Thank you for all the attendees who choose my presentation at Summit 2014. I was really happy to see such a full and interactive class. You can find three downloads here.

  • The PowerPoint presentation is provided as a PDF
  • The two databases I used in conjunction with the AdventureWorks2008R2 database are provided in the SQL Server 2012 version.
  • The demos plus all the database and data scripts needed to create my demo databases.

Please send me an email if you have any questions.

I’m Speaking at PASS Summit This November

MickeyFedora2014I’m very excited to share that my abstract was one of the 144 abstracts selected for PASS Summit 2014. This will be my first time speaking at PASS Summit and I just can’t take the grin off my face.

My presentation is called Techniques for Dynamic SSRS Reports and can be found in the BI track. In my presentation we’ll go over ways to add navigation to your reports, as well as how to make a single report satisfy different users needs.

I hope to see you all at Summit in Seattle this year!

Questions and Answers for Pragmatic Work’s Presentation on the Tablix Control

ChalkBoardThursday, January 23rd I had the opportunity to present for Pragmatic Works as part of their “Training on the T’s” where they provide free one-hour training every week on Tuesdays and Thursdays. I gave my presentation entitled, Scalable SSRS Reports Achieved Through the Powerful Tablix. Below are the questions (and answers) that the attendees asked during my presentation.

View Presentation
Slide deck and demos downloads

Questions and Answers for Demo 1

Q: In the first presentation, the 1st tablix, do territory group and country region has the same datasets, meaning does country region have territory?

A: A tablix or a set of nested tablix can only use 1 dataset. My dataset joined several tables, two of which were Sales.SalesTerritory and PersonCountryRegion. (I’m using the Adventureworks2008R2 database.)
Here is how they are related:
SELECT
cr.Name AS CountryRegion
,st.Name AS Territory
FROM
sales.SalesTerritory AS st
JOIN Person.CountryRegion AS cr ON st.CountryRegionCode = cr.CountryRegionCode

Q: When you add a Row Group with that new column that doesn’t let you merge with the other cells to the right… what you can do is split that column, and then you’ll be able to merge.

A: Yes. This is true, but you still can’t merge across the dotted lines that are introduced into the Matrix.

Q: I always supposed that group levels had to be to the left of the dashed line. But you showed that you can delete those columns/rows but keep the grouping. Does this have any effect on the data in the columns on the left or the right of the dashed line?

A: No, it does not. If the GUI asks If you want to delete only the row/column or the row/column and the group, make sure to indicate that you only want to delete the row/column. This will keep the group, which is what we were after.

Q: Did you have to create the row groups (lower left corner), or were they available dimensions?

A: I’m not sure about this question, please email me some more information so that I can answer the question better.

 

Questions and Answers for Demo 2

Q: Could you have added the expression on the image itself and not add the extra row?

A: Not for this technique. If I would have added the expression to the image to show/hide it, then it would have left “white space” where the image would normally go when the image was hidden. By repeating the row with a different layout, we can reclaim the ‘white space” for the comment field to use.

Questions and Answers for Demo 3

Q: For creating the Emp Phone list, is there a reason why you used a table and created the group as opposed to using a matrix? Thanks!

A: This is a great question. You can use either controls and end up with the same result. I had been demonstrating the matrix control in the other demos, so I wanted my viewers to see how you could start with a table. This becomes handy if they requirements of the layout change. It’s important that you know that you don’t have to start all over, but you can change one control into the other because all three controls (table, matrix, and list) are all based on the Tablix template.

Q: For you last demo where you had dynamic columns for phone numbers, what did you have to change in the detail row?

A: In the detail row, I had to change the detail row to a group. I did this by going into the Detail group properties and adding a group on BusinessEntityID. I then added Last Name, First Name, and BusinessEntitty ID as the fields to sort by. This step is needed because the employee names are repeated once for each address type and each phone number type.

 

General Questions and Answers

Q: How did you make your color palette?

A: This is a great question. Here are the steps.

    1. Add a table to a blank report that will become your template report
    2. Create a cell for each color in your color pallet.
    3. Change the dimensions of each cell to have a height of 0.15 and a width of 0.15.
    4. Change the background property of each cell to a different color in your color pallet.

Now you can make the other changes to the report to create a template report and save it in the template folder for BIDS/SSDT.

Q: How to avoid the columns getting merged on exporting to an excel

A: This is one of those questions that is helpful to also explain to all your end users since they ask the same question. The answer is not the best answer, but it is better than what we had 10 years ago. If you save your report as a CSV file, Excel will still automatically open it and the columns will not be merged. The downside is you lose charts and any formatting. The upside is the columns are no longer merged and the end user can use more functionality of Excel. They do need to be reminded that they will have to save it as an Excel file after opening it in order to save any formatting features that they have added to the file.

Q: Is there a way to fix the tablix to a set number of rows, and an exact amount of vertical space for the tablix? It seems that the tablix ‘reserves’ some additional space below the tablix which interferes when placing report items below the tablix.

A: This can be a challenging problem and it requires a lot of testing if different results set sizes to get the layout to work out the way you want. I will be creating a blog post soon on how to mimic a “fixed row” layout. You can contact me to get the the blog post early if you want.

I haven’t noticed the tablix control “reserving” space. To best figure out what is causing this extra white space do the following. Show the lines on the outside of the tablix and the control that you want to “butt up” against the tablix control You may find that the extra space is on the inside of the control instead of the outside of the control. A couple of properties to look at as are padding and Borderwidth. By changing them, you will reduce white space.

I have noticed that it can be difficult to drag and drop another control right up against another control. In those cases I do some math. By adding the Top and Height properties of the tablix you get the location of the end of the control. Then add 1 or 2 more to that value to have the Top value for the next control.

Q: Is there a way to link one tablix to multiple Datasets?

A: Unfortunately no, but there are some workarounds. There are a couple of functions that were introduced in 2008 R2 that will allow you to reference a value in another dataset, but it won’t allow you to show multiple values. A second way is to use a subreport within the tablix. I try to minimize this, since it can add ALOT of overhead. The third way, would be to create a larger dataset with repeating data that can be grouped. This is what I did in my third demo in order to create multiple addresses and multiple phone numbers for each employee. Again, you have to weigh the benefit of the technique against how much data will be used in the report.

Q: This is a great presentation. How can I get a copy of the RDLs, and the datasets?

A: You can go to my resource page to download the presentation and the demos. Pragmatics has the recording so that you can watch the presentation again. I’ve also provided the links at the top of this post.

Q: Will a transcript or summary of this demo be available for review?

A: You can go to my resource page to download the presentation and the demos. Pragmatics has the recording so that you can watch the presentation again. I’ve also provided the links at the top of this post.

Q: Will you be sharing your ‘Knowledge Based Document’ with us?

A: Unfortunately I can’t, because I don’t have references in it for code I found on the internet or in books. I will however be spending time writing short posts with tips this year, so keep an eye on my blog and on mssqltips.com for posts.

 Q: Thanks – this was a great presentation.

A: Thank you. I’m glad everyone enjoyed it and that everyone had so many questions. 🙂

T-SQL Tuesday #50 – Automation Equates To Saved Time

SqlTuesday50Hemanth D (b|t) is hosting this month’s T-SQL Tuesday blog party. The party was started by Adam Machanic (b|t) in December of 2009 and we hit the 50th “episode” this month. Could this be coincidentaly occurring during the 50th anniversary of Doctor Who?? I think not…

Anyhow, the topic this month is automation.

I can play that in 3 notes

There used to be a game show called Name That Tune. A contestant had to underbid the other contestant on what the minimum number of (musical) notes they needed in order to recognize a piece of music. Automating tasks remind me of this game show. First, you automate step one, then step two. Each time you tweak it and tune your automated process, you’re seeing just how far you can go… and how little manual work you are left with.

The first step

I’m going to talk about automating the first step of creating an SSRS report. I’ll be working with SSRS 2012, but the steps are the same for 2008 and 2008R2. The only difference is WHERE you store the templates so that they can be easily leveraged. Since that is the last thing you do, you’ll have to wait for the end of this post. So, hold on to your Tardis, and let’s go!

The first thing you need to know, is what are all the common elements to all of your reports. Here is a list of the elements I found to be the same on my reports:TSQL Tuesday 50 - Image 1

  • The location of the title: While my title was different each time, the font, font color, font size, and location remained static. So I created a placeholder for my title.
  • The company logo: The company logo was static as well as its location.
  • The color scheme: Since I used the same five colors, I created a temporary “pallet” for my colors. This was a mini Tablix control, with each of the five cell’s background color set to a different color in my pallet. I left it on the report until I was done setting all the properties of the report, then I deleted the Tablix. (No more looking up the colors in my documentation. Win!)
  • The location of the parameters: I personally think that the parameters should always be displayed on the report. This helps when troubleshooting a paper/pdf copy of a report. It also lets the users know the boundaries of the data they are looking at. (Note: While not depicted in my image, I put my parameters under the logo.)
  • The company address: Static location.
  • The confidentiality notice: Static location.
  • The page numbers: Static location.
  • The report identifier: This is a special number that helps you identify your report. Mine always has three parts.
    • TX or DW to mark the report as having transactional or data warehouse based data. This allows me to speak intelligently about a report that someone shows me in a meeting, especially since our data warehouse data was always older than our transactional data.
    • A number that corresponded to the documentation for the report. In our case, it was the TFS (Team Foundation Server) number.
    • An iteration number. This iteration number was specific to how many times the report was re-introduced into production. This allowed me to verify that the user was looking at the latest copy of the report, and it allowed me to document how many times the owner had requested changes to the report.
Creating the templates

A template is an RDL file saved in the templates folder. I created three templates for my team. Each template was identical to the others, except for two things. The paper size and orientation. I needed to make different templates to accommodate these attributes so that the controls that were centered or right aligned ended up in the correct location for viewing and printing.

  • SSRS 2008(R2) Location: C:\Program Files (x86)\Microsoft Visual Studio 9.0\Common7\IDE\PrivateAssemblies\ProjectItems\ReportProject
  • SSRS 2012 Location: C:\Program Files (x86)\Microsoft Visual Studio 10.0\Common7\IDE\PrivateAssemblies\ProjectItems\ReportProject
But wait! There’s more

If you want to go a bit further with your templates, you can add a watermark that can be leveraged during development all the way through user acceptance testing. The watermark will then be suppressed in production. The watermark says DRAFT. I found it helped with certain end users, who were getting caught up in the data (even though it was fake) and they weren’t focusing on the design and algorithms present in the report.

Here are the steps to add the dynamic watermark:

  1. Create a table in the database that contains the name and ID of the environment you are in, plus a parameter that dictates whether to show or hide the watermark. Note: You can also use this table to point to development file locations for documents and development URLs referenced in your reports.
  2. Add an image to the background of the report body that says DRAFT.
  3. Set the Background Repeat property to Repeat
  4. Create a data source in the report that points to the environment table you created in step 1 (preferably through a stored procedure).
  5. Use the data source to hide or show the background image of the report.

If you use shared data sources, then add the data source to the template directory so that it can be added to new projects the same way report templates are.

There you have it! You just automated quite a few (initial) steps for creating SSRS reports.

Thanks for all the fish

Thanks go out to Hemanth for hosting this month’s T-SQL Tuesday blog party. Please visit his website at http://sqlchow.wordpress.com/.

I Will Be Speaking This Month for Pragmatics

Microphone_YetiThis month I will be sharing my popular presentation, Scalable SSRS Reports Achieved Through the Powerful Tablix on Pragmatic’s webinar series, “Free Training on the T’s”. I will be going over different ways to use the Tablix control in this one hour presentation and it will be aired live, on 1/23/2014, 11:00 AM EST / 8:00 am PST. Click here to sign up.

Dev Connections – Demos and Slides Are Available

Thanks to all the Dev Connection attendees who came to my class. I have posted the slides, demos, and demo database on my Resources page.

%d bloggers like this: