Can an SSRS report be designed to drill-through to an Excel workbook in-context (showing only the same filtered detail data)? I have to admit that I have been chasing this solution for a few years now before I was motivated enough to work it through to a viable result. More than a few consulting clients have asked if it is possible to build a dashboard solution with the option to drill-through to transactional details in Excel. The answer has always been “well, sort of” …we could only drill-through to an SSRS report and then export the contents of that report to Excel. That answer usually wasn’t good enough for the Excel power users who need to create their own workbook formulas and calculations, and use other Excel formatting and features; like PivotTables, slicers and conditional visualizations. Over the past few years, I have used some clumsy work-around techniques and discovered things like: if the target workbook were published in SharePoint and managed in a web part, workbook parameters can be used with great effort to achieve this task. However, that option has not proven to be a practical solution in most cases. As my good friend Steve Eaton once said: “Anything is possible if you have a positive mental attitude, tons of money and supernatural powers.” I’ll admit that I’m short on two of the three but I do have persistence and I’m bull-headed enough to apply a little out-of-the-box thinking now and again. The technique I will demonstrate will work in a standard Reporting Services deployment with any edition of Excel on the desktop.

Solution Demo

I’ll start with a quick demonstration of the finished solution. The Order Details report, shown here in Internet Explorer, gets data from a data warehouse (AdventureWorksDW2014 in this example). The order details and line items are stored in our line-of-business transactional database (for this demo, AdventureWorks2014). As you can see, I choose a data range using the standard date parameter UI. I’ve also exposed a Product parameter using a set of cascading lists and custom actions in the report header (I’ll cover that technique in another post). The relevant point is that we’re selecting some parameters to get a filtered view of the report data. After choosing the date range, I use the Category, Subcategory and Product lists in the report header to select Clothing, then Socks and then the product: Racing Socks, L. The cascading list simplifies the selection from among several hundred products.

A list of orders is displayed for the selected data range and product. In the list, I click the Sales Order Number for which I want to see the order and line details in my Excel report.

This displays a link “button” in the table header with a summary of the order number I selected.

When I click this link, the web browser confirms that I want to open the Excel file. This existing file stored in a network file share contains a connection to the transactional database with the order detail information. When the report opens, it applies the filters and shows the order with line item details. Our business users are thrilled with this because they’re actually using Excel with any features and capabilities they want. Rather than dumping a copy of data into a static table, live data is presented in PivotTables or charts which contain their calculation formulas and custom formatted data. If the business user decides to add another column, calculation, chart or other item to their report; they simply save it with those changes and use that as their detail report going forward. The new drill-through data just magically shows up in their workbook file with those additions the next time they drill-through from the summary report.

How Does It Work?

Reporting Services allows us to use parameters to pass information between reports – and that’s awesome if you’re only using Reporting Services. It allows you to maintain the context of properties and filtering options. But, if you’re not using Reporting Services and don’t have some kind of mechanism to “pass” parameters (like QueryString parameters to send information to a web page), we need to put those values some place so the target “report” (i.e. Excel workbook in this case) can retrieve them and apply them as filters. So, where would be a reliable place to store parameter information? How about SQL Server! Novel, huh?

To get started, open SQL Server Management Studio and create a database named ReportStandards. Let’s add all of the objects at once and then I’ll step through the use of each one. For demonstration purposes, I have not taken time to optimize this database and adding a few indexes would be advisable in a production scenario. Execute this T-SQL script:

use [ReportStandards]

go

create
table ReportUserFilters

    (

        UserName nvarchar(100)
not
null,

        TableName varchar(100)
not
null,

        FilterKey varchar(100)
not
null,

        InsertDateTime datetime
not
null

    ,

    constraint pk_ReportUserFilters primary
key
clustered

        (UserName, TableName, FilterKey)

    )

;

go

create
proc InsertReportUserFilter

    @TableName varchar(100),

    @FilterKey varchar(100)

as

    insert
into ReportUserFilters
( UserName, TableName, FilterKey, InsertDateTime )

    select

        system_user,

        @TableName,

        @FilterKey,

        getdate()

;

go

create
proc ClearReportUserFilters

as

    delete
from ReportUserFilters where UserName =
SYSTEM_USER

;

go

create
function dbo.GetReportUserFilters( @TableName nvarchar(100)
)

    returns @TableOut table ( FilterKey varchar(100)
)

as

    begin

        insert
into @TableOut

        select FilterKey from ReportUserFilters where UserName =
system_user
and TableName = @TableName

    return;

    end

;

Go

create
proc PrepareReportSalesOrder

    @SalesOrderNumber varchar(100)

as

    if @SalesOrderNumber is
not
null
and @SalesOrderNumber <>
‘-1’

    begin

        execute ClearReportUserFilters

        execute InsertReportUserFilters
‘FactResellerSales’, ‘SalesOrderNumber’, @SalesOrderNumber

        select
‘Success’
as Result

    end

    ;

go

So, what did we create? Here’s a quick summary:

Object Purpose
ReportUserFilters table Stores sets of parameter values for a user running a report
InsertReportUserFilter stored procedure Inserts a parameter record into the ReportUserFilters table
including the current user, table name, key value and a time stamp
ClearReportUserFilters stored procedure Removes stored parameter records for the current user
GetReportUserFilters function Returns a set of filter parameters to be used in a SQL WHERE clause IN function
PrepareReportSalesOrder stored procedure An implementation for a specific report

I’ll open the finished SSRS report in Report Builder to show you the working solution.

There are several features of this report that aren’t directly related to the Excel drill-through action so I’ll fast-forward through those after a brief summary. This is like that scene in The Princess Bride where the masked swordsmen wakes up after being mostly dead and brought back to life by Miracle Max. Inigo says “let me e’splain… No. There is too much… let me sum up.” Here’s the summary:

The relevant report elements are circled in red and annotated with red numbers. Everything else is standard stuff that I would have designed into a report that doesn’t do this drill-through thing to Excel. The non-circled elements are parameters, datasets and other report elements that let the user interact with the report and filter a list of orders for a selected product and data range. I’ll refer to these numbers as I describe these report design elements.

Item 1 is a report parameter named SalesOrderNumber. A report action on the SalesOrderNumber textbox in the table (item 5) sets this parameter value. The parameter is defined as Text type, is hidden and has a default value of -1. The default value is a placeholder value that isn’t a valid SalesOrderNumber value.

The Orders dataset is just a plain old query that returns order records from the AdventureWordksDW2014 database filtered on the ProductKey, OrderDateFrom and OrderDateTo parameters. Nothing fancy here:

SELECT

rs.SalesOrderNumber


,rs.OrderDate


,rs.SalesAmount


,rs.ExtendedAmount


,rs.OrderQuantity

FROM

FactResellerSales rs

WHERE

rs.OrderDate BETWEEN @OrderDateFrom AND @OrderDateTo


and

ProductKey = @ProductKey

ORDER
BY

rs.OrderDate

The table (Item 5) is unsophisticated as well. The SalesOrderNumber textbox in the detail row has a report action defined. Open the textbox properties window and select the Action page which looks like this in the designer:

The target report expression (labelled “Specify a report”) just refers to the Globals!ReportName object. This target re-runs this report when the user clicks this textbox. All the parameters but the last one are simply used to maintain their current values when the report is re-rendered. Ignore the ShowParameters item as well. The SalesOrderNumber parameter is set to pass the SalesOrderNumber field value so we know which order the user selected.

Item 3 is a dataset named SetupSalesOrderReport which serves two purposes. Most importantly, it writes the selected SalesOrderNumber value to a table so it can be used to filter the result set in the Excel workbook. This dataset is a simple stored procedure that returns a flag value used to display the drill-through link. Item 4 is a textbox that serves this purpose and its Hidden property is set to the following expression:

=NOT(First(Fields!Result.Value, “SetupSalesOrderReport”)=”Success”)

This simply says “if the SetupSalesOrderReport Result field value is ‘Success’, show this textbox”.

The SetupSalesOrderReport dataset is references the PrepareReportSalesOrder stored procedure and passes the SalesOrderNumber report parameter. When the selected order number is passed to the parameter in this report action, the procedure stores the value and returns “Success”. This, in turn, displays the textbox showing the link. The Value of the textbox uses the following expression to display a dynamic instruction to the user:

=”Sales order ” & Parameters!SalesOrderNumber.Value & ” details in Excel”

..and the Action for this textbox uses a Go to URL link using this expression:

=”file:tsclientDProjectsExcel Drillthrough ReportsSales Order Details.xlsx”

Any valid UNC path will work here, prefixed with “file:”. This particular path is for a folder on my laptop that I am accessing from within a virtual machine I use for development and demonstrations. You will need to grant file system permission to the folder or share to be able to open this file.

The Excel “report” is a standard workbook. I’m using Excel 2013 but any supported version or edition of Excel will work. The important element of this solution component is the connection used to drive the PivotTables in the workbook. You can use a SQL statement to define a connection/query in Excel but it’s much easier to use a view. This report uses the following view which I created in the AdventureWorks2014 database:

create
view vReportSalesOrderDetail

as

    select

        soh.AccountNumber,

        soh.OrderDate,

        soh.DueDate,

        soh.Freight,

        soh.SalesOrderNumber,

        soh.PurchaseOrderNumber,

        soh.ShipDate,

        soh.Status,

        cp.FirstName CustomerFirstName,

        cp.LastName CustomerLastName,

        sod.OrderQty,

        sod.LineTotal,

        sod.UnitPrice,

        p.Name ProductName

    from

         Sales.SalesOrderHeader soh

        inner
join Sales.SalesOrderDetail sod on soh.SalesOrderID = sod.SalesOrderID

        inner
join Sales.Customer c on soh.CustomerID = c.CustomerID

        inner
join Person.Person cp on c.PersonID = cp.BusinessEntityID

        inner
join Sales.SalesPerson sp on soh.SalesPersonID = sp.BusinessEntityID

        inner
join HumanResources.Employee e on soh.SalesPersonID = e.BusinessEntityID

        inner
join Production.Product p on sod.ProductID = p.ProductID

    where

        soh.SalesOrderNumber in
(select * from
ReportStandards.
dbo.GetReportUserFilters(‘FactResellerSales’)
)

    ;

After selecting this view when defining the connection in Excel, the command text is simply:

“AdventureWorks2014″.”dbo”.”vReportSalesOrderDetail”

I’ve updated the connection properties to refresh the data when the workbook file is opened. This will run the query and return live sales order data and apply the filtering logic that was added from the Reporting Services report.

Two PivotTables are added to the worksheet along with a calculated field (just to demonstrate that calculations can be performed in Excel rather than externally). Several styling enhancements are added in Excel such as data bars, font and color changes, hiding the grids, etc.

Enhancements

There is a lot of opportunity to enhance this solution depending on specific business needs. For example, a report name column can be added to the ReportUserFilters table to store user/parameter values separately for each report. I haven’t used the InsertDateTime column in this example but this could be used to go back and run the detail report for a point-in-time.

The previous example only inserted one parameter value but the following enhancement could be used to pass multiple selected parameter values from SSRS so they would all be included in the detail report:

create
proc InsertReportUserFilters

    @TableName varchar(100),

    @KeyColumnName varchar(100),

    @FilterKeys varchar(500)

as

    declare @SQL nvarchar(1000)

    set @SQL =

        ‘insert into ReportUserFilters ( UserName, TableName, FilterKey, InsertDateTime ) ‘
+

        ‘select distinct system_user, ”’
+ @TableName +
”’, t.’
+ @KeyColumnName +
‘, getdate() ‘
+

        ‘from ‘
+ @TableName +
‘ t where cast(‘
+ @KeyColumnName +
‘ as varchar) in(”’
+


replace(@FilterKeys,
‘,’, ”’,”’)
+ ”’)’

    execute
sp_executesql
@SQL

;

go