MDX Essentials: Enhancing CROSSJOIN() with Calculated Members - Page 8

April 4, 2005

Based upon what we know about the CROSSJOIN() function, we can readily see that the query above can be optimized. First, we note that the query as originally written creates, for the Bellmont Distributing Warehouse, every Store Country (four, including the new Non-Domestic calculated member) and Product Name (1,560 exist) combination. This is only 6,240 combinations, but we certainly must acknowledge that the query is time consuming.

3.  Scroll down in the viewer to ascertain that the Non-Domestic calculated member appears, as depicted in Illustration 17.

Click for larger image

Illustration 17: The Results Dataset (Top Section Only) - Original Approach

As we noted in our previous article, there are many "empties" that we might attempt to eliminate as a first step in enhancing query performance. The complication within our current enhancement effort lies in the expressed business requirement to return the calculated member. While we found the NONEMPTYCROSSJOIN() a helpful ally, in The CROSSJOIN() Function: Breaking Bottlenecks, in a scenario that was devoid of calculated member considerations, we will see that it tends to "scalp" the returned dataset of calculated members when they are present.

4.  Save the query as MDX30-01.

5.  Create the following new query, where we substitute the NONEMPTYCROSSJOIN() approach:


--MDX30-02: NONEMPTYCROSSJOIN() fails to recognize Calculated Members
SELECT 
    {[Measures].[Warehouse Sales]} ON COLUMNS,
    {NONEMPTYCROSSJOIN({[Warehouse].[All Warehouses].[Canada].[BC].[Vancouver].
        [Bellmont Distributing]}, [Store].[Store Country].AllMembers, 
             [Product].[Product Name].Members)} ON ROWS
FROM  
   [MDX30 Optimize CrossJoin]
WHERE
    ([Time].[1998])

6.  Execute the query using the Run Query button.

The query executes far more rapidly, and the empties are eliminated. We note, however, if we attempt to scroll to the Non-Domestic calculated member once again, that it no longer appears - even though we retain .AllMembers in our Store Country specification. This, as we have already intimated, is because the NONEMPTYCROSSJOIN() function strips the calculated member out of the returned results dataset. This eliminates the powerful NONEMPTYCROSSJOIN() option in the current scenario, not to mention the option to tune NONEMPTYCROSSJOIN() even further, with the addition of the set-count parameter that we witnessed in the final refinement of our solution in The CROSSJOIN() Function: Breaking Bottleneck.

Fortunately, as we have seen myriad times in the past, MDX offers alternative approaches to meeting our needs. To accomplish our ends, enhancement of the query with retrieval of the calculated member, we can employ a combination of the CROSSJOIN() and FILTER() functions, together with NOT ISEMPTY(), as we shall see in the next steps.

7.  Save the query as MDX30-02.

Fortunately, as we have seen myriad times in the past, MDX offers alternative approaches to meeting our needs. To accomplish our ends - enhancement of the query with retrieval of the calculated member - we can employ a combination of the CROSSJOIN() and FILTER() functions, together with NOT ISEMPTY(), as we shall see in the next steps.

8.  Create the following new query, where we substitute the new approach NONEMPTYCROSSJOIN() approach:


--MDX30-03: Using GENERATE() to enhance CROSSJOIN() performance when
--  Calculated Members are a consideration
SELECT 
    {[Measures].[Warehouse Sales]} ON COLUMNS,
    GENERATE({[Warehouse].[All Warehouses].[Canada].[BC].[Vancouver].
       [Bellmont Distributing]},
        CROSSJOIN({[Warehouse].CurrentMember},
            GENERATE([Store].[Store Country].AllMembers,
                CROSSJOIN({[Store].CurrentMember},
                    FILTER([Product].[Product Name].Members,
                        NOT ISEMPTY ([Measures].[Warehouse Sales])))))) ON ROWS
   FROM 
   [MDX30 Optimize CrossJoin]
WHERE
   ([Time].[1998])

9.  Execute the query using the Run Query button.

The query returns in far less time than in its original incarnation. In addition, the absence of empties is pronounced. Finally, we see, if we scroll once again to our calculated member Non-Domestic, that the calculated member does, indeed, appear. We note that the USA Store Country does not appear at all: the Canadian warehouse had no sales with US Stores in 1998. In contrast to the dataset, appearing in Illustration 17 above, our new query has eliminated the empty Store Country. The newly derived results dataset appears as partially depicted in Illustration 18.


Illustration 18: The Results Dataset (Portion Showing Non-Domestic Calculated Member)

The query we have constructed is faster than the original query, and is faster than would be the application of the filter to both CROSSJOINS(), another approach to the same end. While this approach is still slower than the NONEMPTYCROSSJOIN() solution, we obtain a palpable relief in processing time over the original query, while meeting the need to retain calculated members in the final presentation, as we can see in Illustration 18 above.

10.  Save the query as MDX30-03.

11.  Close the MDX Sample Application, when ready.

We report our success to the information consumers, detailing the steps we took and documenting the modifications to the query. We conclude by expressing our hopes that other disrupted development projects that were in the hands of the offshore organization meet with successful recoveries, as well.

Summary ...

In this article, we continued our examination of the enhancement of queries using the powerful CROSSJOIN() function. We reviewed CROSSJOIN() performance considerations introduced in earlier articles, and extended our exploration of enhancement approaches to scenarios where the presence of calculated members render ineffective the NONEMPTYCROSSJOIN() options we presented earlier. After preparing a copy of the Warehouse sample cube, and modifying it to include a calculated member contained in the hypothetical cube we intended to mirror, we processed the cube, and then set about deriving enhancements to a query whose performance had been impacted by the injudicious use of CROSSJOIN().

In a multi-step practice exercise, we determined that CROSSJOIN() was behind the suboptimal query performance suffered by a hypothetical group of information consumers. We demonstrated how a solution we employed in an earlier article, which relied upon substitution of NONEMPTYCROSSJOIN() for the original CROSSJOIN() to make significant performance gains, failed to retrieve calculated members, and thus rendered the approach ineffective to meet the current business requirement. We then provided an approach to enhancement of the CROSSJOIN() scenario with concomitant return of calculated members, using a combination of the CROSSJOIN() and FILTER() functions, together with NOT ISEMPTY(). Throughout our practice exercise we explained the results we obtained from the steps we took to accomplish the solution.

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

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

MDX Essentials Series
The LEVEL_NUMBER Member Property
The LEVEL_UNIQUE_NAME Intrinsic Member Property
Intrinsic Member Properties: The HIERARCHY_UNIQUE_NAME Property
Intrinsic Member Properties: The DIMENSION_UNIQUE_NAME Property
Further Combination of BottomCount() with Other MDX Functions
Combine BottomCount() with Other MDX Functions to Add Sophistication
Basic Set Functions: The BottomCount() Function, Part I
Intrinsic Member Properties: The MEMBER_VALUE Property
Intrinsic Member Properties: The MEMBER_UNIQUE_NAME Property
Intrinsic Member Properties: The MEMBER_NAME Property
Intrinsic Member Properties: The MEMBER_KEY Property
Intrinsic Member Properties: The MEMBER_CAPTION Property
Set Functions: The StripCalculatedMembers() Function
Set Functions: The AddCalculatedMembers() Function
MDX Numeric Functions: The Min() Function
MDX Numeric Functions: The Max() Function
Set Functions: The .AllMembers Function
MDX Essentials: Set Functions: The MeasureGroupMeasures() Function
String Functions: The .Properties Function, Part II
String Functions: The .Properties Function
Logical Functions: IsGeneration(): Conditional Logic within Filter Expressions
MDX Scripting Statements: Introducing the Simple CASE Statement
Logical Functions: IsGeneration(): Conditional Logic within Calculations
Logical Functions: IsAncestor(): Conditional Logic within Filter Expressions
MDX Clauses and Keywords: Use HAVING to Filter an Axis
Logical Functions: IsAncestor(): Conditional Logic within Calculations
Logical Functions: IsSibling(): Conditional Logic within Filter Expressions
Logical Functions: IsSibling(): Conditional Logic within Calculations
MDX Operators: The IsLeaf() Operator: Conditional Logic within Filter Expressions
MDX Operators: The IsLeaf() Operator: Conditional Logic within Calculations
MDX Numeric Functions: The .Ordinal Function
Other MDX Entities: Perspectives
MDX Operators: The IS Operator
MDX Set Functions: The Distinct() Function
MDX Set Functions: The ToggleDrillState() Function
Set Functions: The DrillUpLevel() Function
Set Functions: The DrillDownLevelTop() and DrillDownLevelBottom() Functions
MDX Set Functions: DrillDownLevel()
MDX Set Functions: The DRILLUPMEMBER() Function
MDX Essentials: Set Functions: The DRILLDOWNMEMBERTOP() and DRILLDOWNMEMBERBOTTOM() Functions
MDX Essentials : Set Functions: The DRILLDOWNMEMBER() Function
MDX Essentials: Drilling Through with MDX: The DRILLTHROUGH Statement
MDX Essentials: String Functions: The .UniqueName Function
MDX Essentials: String Functions: The .Name Function
MDX Essentials: String / Numeric Functions: The CoalesceEmpty() Function
MDX Essentials: Basic Set Functions: The TopCount() Function, Part II
MDX Essentials: Basic Set Functions: The TopCount() Function, Part I
MDX Essentials: Enhancing CROSSJOIN() with Calculated Members
MDX Essentials: Set and String Functions: The GENERATE() Function
MDX Essentials: The CROSSJOIN() Function: Breaking Bottlenecks
MDX Essentials: String / Numeric Functions: More on the IIF() Function
MDX Essentials: String / Numeric Functions: Introducing the IIF() Function
MDX Essentials: Logical Functions: The IsEmpty() Function
MDX Essentials: Basic Set Functions: The EXTRACT() Function
MDX Essentials: Numeric Functions: Introduction to the AVG() Function
MDX Essentials: Basic Member Functions: The .Item() Function
MDX Essentials: Basic Set Functions: Subset Functions: The Subset() Function
MDX Essentials: Basic Set Functions: Subset Functions: The Tail() Function
MDX Essentials: Basic Set Functions: Subset Functions: The Head() Function
MDX Essentials: Basic Set Functions: The CrossJoin() Function
MDX Essentials: Basic Numeric Functions: The Count() Function
MDX Essentials: Basic Set Functions: The Filter() Function
MDX Essentials: Basic Set Functions: The EXCEPT() Function
MDX Essentials: Basic Set Functions: The Intersect() Function
MDX Essentials: Basic Set Functions: The Union() Function
MDX Essentials: Basic Set Functions: The Order() Function
MDX Essentials - MDX Time Series Functions, Part III: The LastPeriods() and ParallelPeriod() Functions
MDX Time Series Functions, Part II: The OpeningPeriod () and ClosingPeriod() Functions
MDX Essentials - MDX Time Series Functions, Part I: PeriodsToDate() and Kindred Functions
MDX Essentials: MDX Member Functions: "Relative" Member Functions
MDX Member Functions: The Cousin () Function
MDX Essentials: Member Functions: More "Family" Functions
MDX Member Functions: The "Family" Functions
MDX Essentials: MDX Members: Introducing Members and Member
MDX Essentials : MDX Operators: The Basics
MDX Essentials: Structure of the MDX Data Model
MDX at First Glance: Introduction to SQL Server MDX Essentials








The Network for Technology Professionals

Search:

About Internet.com

Legal Notices, Licensing, Permissions, Privacy Policy.
Advertise | Newsletters | E-mail Offers