SQL Server 2008 Reporting Services and the “Select All” Parameter Issue

Note, before getting started with this lesson there are some prerequisites you should know about. Please read my post Getting Started with SQL Server 2008 to ensure you have everything setup correctly, otherwise you will be missing objects required to get the code here to work correctly.

In yesterday’s post, “Adding Query Parameters to SQL Server 2008 Reporting Services Reports”, we looked at how to add a Query Parameter to a report dataset. The steps hide a potentially fatal issue though: “Select All”. When you allow the user to select more than one parameter, they can also select all of them. Behind the scenes SSRS converts this to a long delimited list. Thus the query, when sent to the server, looks like:

SELECT [FiscalYear] 
     , [ProductCategoryName]
     , [ProductSubcategory]
     , [Region]
     , [TotalAmount]
  FROM [ContosoRetailDW].[Report].[V_SubcategoryRegionTotalsByYear]
 WHERE [Region] IN ('Armenia', 'Austrailia', 'Canada', 
                    --Rest of long list goes here

If you are certain beyond a doubt that you will only have a limited number of items in the list, then this is a nonissue and you can stop reading this now. However, what if you have a potentially unlimited or even just very large number of items in the list? Then you can easily exceed the buffer length SQL allows for a query string and cause a fatal error. Working around that requires several steps.

Step 1. Add a count dataset

First, we need an additional dataset, whose purpose is to count the number of items in the dataset used to supply values to the parameter list. In this example it will count the number of rows in the Region dataset.

Start by right clicking on the Contoso branch of the Report Data window and pick “Add Dataset”. Name it RegionCount, and give it a Query of:

SELECT COUNT(*) AS RegionCnt
  FROM [ContosoRetailDW].[Report].[V_Regions]

That’s all you need here, just click OK to close.

Step 2. Add an Internal Parameter

Next we need to add a parameter that will hold the result of the RegionCount Dataset. Right click on the parameters branch of the Report Data window and chose to add one. When the dialog appears start by giving it a good name, here we can use RegionCnt.

Now in the Data type, change it to an “Integer” since a count will always be an integer.

This parameter is one we never want the users to be able to see or change. Thus under parameter visibility “Visible” isn’t a good choice for us. That leaves us with “Hidden” and “Internal”. Hidden parameters are not visible in the user interface; however they can be updated when you call a report via its URL. Again, this is not a desirable option for us. Thus we will use Internal, which is similar to a private variable, only for use within the report.

clip_image002

Once you have the properties filled out click OK to close.

Step 3. Add the Query Parameters to the report dataset.

Now we fix our @pRegion parameter that we use in our SQL statement.

Right click on the main report dataset, pick dataset properties, and then go to the parameters area. If it already exists go to the @pRegion parameter (it should, but if not create it). Now we will need to change its value, and we’ll use an expression to do so. Click on the fx button to the right of the parameter value drop down and enter the follow text:

=iif(Parameters!Region.Count>=Parameters!RegionCnt.Value, "SELECTALL", Parameters!Region.Value)

The iif is pretty obvious. The RegionCnt.Value represents the number of items from the RegionCnt parameter, which came from the SELECT COUNT query. The Region.Count represents the number of items the user selected in the drop down. If they picked SELECT ALL, then all of them will be checked.

Thus, if the number of items checked is equal to or greater than the number of possible items it will return SELECTALL as the value (which we’ll use as a flag in just a moment). Otherwise it will simply return a list of the items selected.

Just to be clear, there’s nothing magical about “SELECTALL”, it’s just a string that makes it obvious what the purpose is. You could have used “ALL”, “allrows”, or “ArcaneCode”. Just as long as you use the same value here and in the SQL query, which you’ll see next.

Now we need to fix our SQL statement. While still in the Dataset Properties window, go back to the Query area and update your SQL Query to read:

SELECT [FiscalYear] 
     , [ProductCategoryName]
     , [ProductSubcategory]
     , [Region]
     , [TotalAmount]
  FROM [ContosoRetailDW].[Report].[V_SubcategoryRegionTotalsByYear]
 WHERE ( ('SELECTALL' IN (@pRegion)) OR ([Region] IN (@pRegion)) )

The first part of the WHERE clause will check to see if our SELECTALL is in the @pRegion parameter, which it will be if the user did a Select All in the parameter drop down in the user interface. If so that portion of the WHERE evaluates to true and all rows are returned. Otherwise it then checks the Region against the specific list returned in @pRegion.

Not Foolproof

Be aware that this solution is not foolproof. If the user has a long list of items and picks all but one item in the list the potential is still there to overflow the SQL query string buffer. In that situation you should reconsider the use of that column as a parameter, finding another means to limit the report. You could also use the expression language to check the length of the items selected (in this case Parameters!Region.Value) and if the length is too long either truncate it or replace it with the SELECTALL value.

Advertisement

9 thoughts on “SQL Server 2008 Reporting Services and the “Select All” Parameter Issue

  1. Wow, this is such a break-through! Those 1000-member “Select All” strings are such a pain; I’ve thought there SHOULD be a way to use a single value for them, but was not able to come up with a simple solution like this one. I’ll definitely use it many times, and wouldn’t it be great if this functionality would be included in SSRS?
    (BTW, “=iif(Parameters!Region.Count>=Parameters!RegionCnt.Value” gets truncated in your post, I think many reader would appreciate seeing the complete expression here…) Thank you very much!

  2. I tried getting this to work but when I try to run the report I get an error that says “The xxCount parameter is missing a value”

    Any ideas?

    Thanks!!!

  3. There is another simple solution.

    Use CountRows(“Data Set Name”)

    You don’t need to create an extra dataset. Please see the following example.

    =IIF(CountRows(“Data Set Name”) = Parameters!ColumnName.Count, “ALL”, Join(Parameters!ColumnName.Label,”,”))

    1. Thanks for this! Is the simpler solution as shown above also usable in SSRS 2005? I get an error: using that formula:

      [rsAggregateInQueryParameterExpression] The expression used for the parameter ‘@myParameter’ in the data set ‘@myParameterDS’ includes an aggregate function. Aggregate functions cannot be used in query parameter expressions.

  4. Does seem to work well. I have some 109 values in parameter. It still executes the OR part and take the same amount of time. There has to be a way like if else in the query, which doesnt execute the other section when the parameter retrieves “SELECTALL”… Any thoughts??!!

  5. That is brilliant Solution, The only thing i would say is to add another column as part of your Main dataset to pull the count using OVER function.

    ex. count(1) OVER (PARTITION BY 1) cnt

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s