Database Journal
MS SQL Oracle DB2 Access MySQL PostgreSQL Sybase PHP SQL Etc SQL Scripts & Samples Links Database Forum

» Database Journal Home
» Database Articles
» Database Tutorials
MS SQL
Oracle
DB2
MS Access
MySQL
» RESOURCES
Database Tools
SQL Scripts & Samples
Links
» Database Forum
» Sitemap
Free Newsletters:
DatabaseDaily  
News Via RSS Feed


follow us on Twitter
Database Journal |DBA Support |SQLCourse |SQLCourse2
 

Featured Database Articles

MS SQL

Posted Nov 7, 2005

MDX Essentials : Set Functions: The DRILLDOWNMEMBER() Function - Page 5

By William Pearson

Our report author colleagues have expressed satisfaction with the example we have presented. They present a similar request at this point for assistance in crafting another drilldown scenario. This example will further activate what we have discussed and seen thus far, employing DRILLDOWNMEMBER() in a simple scenario somewhat like our first example, initially, and then adding the RECURSIVE keyword. This will give us a hands-on, "before and after" look at how DRILLDOWNMEMBER() behaves with and without RECURSIVE.

The report authors outline the next drilldown scenario as follows: using the Adventure Works cube, once again, as a data source, they wish to create a query that returns information surrounding the composition of select sales from the perspective of certain customer locations. Specifically, they wish to present Calendar Year 2003 Internet Sales for United States customers, in such a way that the states within which sales took place are summarized. The drilldown requirement in this case consists in the need to present the total sales for the United States, drilled down to the sales totals for the states, which make up the U.S. total that appears. The report authors are convinced that, once they achieve this objective, the capability to perform ad hoc drilldowns on a given state (or a group of states) at runtime will become a matter of parameterizing the key component of the row axis specification within the MDX query involved, a mechanism that can be leveraged, as one example, in a summary / target report pairing within Reporting Services such as we have discussed earlier.

To outline the requirement further, our "confirmation of understanding draft," again in MS Excel, is depicted in Illustration 12.


Illustration 12: "Confirmation Draft" of the Proposed Dataset

We obtain consensus on the dataset, and set about constructing the query.

4.  Replace the syntax from our initial query in the Query pane by typing (or cutting and pasting) the following in its place:


-- MDX037-002 DrillDown With Selected Members - Basic
SELECT
   {[Measures].[Internet Sales Amount]} ON COLUMNS,
   
NON EMPTY(DRILLDOWNMEMBER( {
   [Customer].[Customer Geography].[Country].[United States]}, 
      {[Customer].[Customer Geography].[Country].[United States] 
    })) ON ROWS
FROM 
   [Adventure Works]
WHERE
   ([Date].[Calendar Year].[CY 2003])

The Query pane appears, with our input, as shown in Illustration 13.


Illustration 13: Second Query in the Query Pane ...

5.  Select File -> Save MDX037-001 As..., name the file MDX037-002, and place it in a meaningful location, to protect the former query.

6.  Execute the query by clicking the Execute button in the toolbar, as before.

The Results pane is populated by Analysis Services, and the dataset shown in Illustration 14 appears.


Illustration 14: Results Dataset - Another Basic Use of DrillDownMember() Function

In the returned dataset, we see that Country United States (the top row of the dataset) is presented in "rolled up" state. The states within which we have conducted Internet Sales transactions in Calendar Year 2003 appear underneath the USA summary line. The states represent the drilled down children of Country United States, whose values add up to the Country United States total.

7.  Select File -> Save MDX037-002.mdx to ensure that the file is saved. (Leave MDX037-002.mdx open for the next steps).

The report authors again express satisfaction with the results, and immediately ask for a further extension of the query: As an example of the process involved, they wish to see how they might easily make it possible to "automatically" drill further into the secondary set we have used in the DRILLDOWNMEMBER() function that we have placed within our query ( {[Customer].[Customer Geography].[Country].[United States] ). As an illustrative example, they wish to drill down into the state Illinois to further break out its children, cities, and display their sales contributions, in turn, to the Illinois total.

We explain that the RECURSIVE keyword exists specifically for this purpose, and take the following steps to demonstrate its operation.

8.  Modify the top line in the query (the commented line) to the following:

                   MDX037-003 DrillDown With Selected Members - RECURSIVE in Place

9.  Select File -> Save MDX037-002 As..., name the file MDX037-003, placing it with the previous to query files, to protect the former query.

10.  Place a comma (",") after the existing member of the secondary set of the ROWS axis specification ([Customer].[Customer Geography].[Country].[United States]).

11.  Insert the following member expression into the secondary set, between the newly added comma and the right curly brace ("}):

 [Customer].[Customer Geography].[Country].[United States].[Illinois] 

12.  Add a comma behind / to the immediate right of the right curly brace, and then follow the comma with the RECURSIVE keyword.

Our addition to the ROW axis specification thus becomes:

[Customer].[Customer Geography].[Country].[United States].[Illinois]}, RECURSIVE 

The Query pane appears, with the areas affected by our modifications circled, as depicted in Illustration 15.


Illustration 15: Our Second Query, with Modifications

13.  Execute the query by clicking the Execute button in the toolbar, as we did earlier.

The Results pane is populated by Analysis Services, and the dataset shown in Illustration 16 appears.


Illustration 16: Results Dataset - RECURSIVE Keyword at Work ...

Illinois is, indeed, drilled down to the two cities, Chicago and Carol Stream (enclosed in the red rectangle above), whose sales totals make up the summary Illinois total of $ 2,686.66. As we noted was generally the case with the secondary set in the ROWS axis specification in earlier examples, added set members, in combination with the RECURSIVE keyword, can also be subjected to parameterization within a reporting (or other) application, for far-reaching capabilities with regard to manipulation of the supporting dataset of a target report containing the DRILLDOWNMEMBER() function under consideration.

The report authors state that their immediate goals have been met. We agree to return at a later time to demonstrate approaches to implement the DRILLDOWNMEMBER() function in reporting services to leverage MDX to support interactive drilldown by organizational information consumers.

14.  Select File -> Save MDX037-003.mdx to save our work.

15.  Select File -> Exit to leave the SQL Server Management Studio, when ready.

Summary ...

In this article, we begin an extended examination of the MDX surrounding drilling up and down within our Analysis Services cubes, focusing upon the DrillDownMember() function. We noted that the DrillDownMember() function can be leveraged within and among the various "layers" of the Microsoft integrated Business Intelligence solution to support sophisticated presentations and features. We introduced the function, commenting upon its operation and touching upon examples of effects that we can employ it to deliver, to empower information consumers to maneuver between summarized and detailed levels of data.

We introduced DrillDownMember(), commenting upon its operation and touching upon the "extended" datasets we can deliver using the function with a specified primary and secondary set. Next, we examined the syntax involved with DrillDownMember(), and then undertook a couple of illustrative practice examples within which we met hypothetical business requirements with the function, generating queries that capitalized on its primary features. Further, we discussed points within our query where we might consider the insertion of parameterization in a reporting application (or other consumer application), such as Reporting Services, to leverage the function to support drilldown in an ad hoc manner. Throughout our practice session, we briefly discussed the results datasets we obtained from each of the queries we constructed.

» See All Articles by Columnist William E. Pearson, III

Discuss this article in the MSSQL Server 2000 Analysis Services and MDX Topics Forum.



MS SQL Archives

Comment and Contribute

 


(Maximum characters: 1200). You have characters left.

 

 




Latest Forum Threads
MS SQL Forum
Topic By Replies Updated
SQL 2005: SSIS: Error using SQL Server credentials poverty 3 August 17th, 07:43 AM
Need help changing table contents nkawtg 1 August 17th, 03:02 AM
SQL Server Memory confifuration bhosalenarayan 2 August 14th, 05:33 AM
SQL Server Primary Key and a Unique Key katty.jonh 2 July 25th, 10:36 AM


















Thanks for your registration, follow us on our social networks to keep up-to-date