MDX Numeric Functions: The Min() Function - Page 3

February 4, 2008

Procedure: Use the Min() Function to Select Least Sales

Having demonstrated the basic operation of Min(), we are ready to address another requirement that the client representatives describe. To detail the requirement, our colleagues have asked us to address a specific, immediate need, although they hope to be able to extrapolate the concepts we introduce to other, similar needs that commonly arise within the organization. Our colleagues have asked that we construct a query that presents a dataset similar to the one we have described above, in that it uses the Min() function to retrieve a minimum measure value for a specified set.

As we have noted, of course, Min() can be used in numerous ways that lie beyond the obvious selection of the ”least number” or “smallest amount” for a set we specify as a basis in the function. We often, for instance, use the function to select the “first” (or “least”) month (or other Date period), as an example, where we have conducted transactions or maintained a balance.

Our colleagues tell us that they wish to support the capability of Logistics users to report upon and analyze “least” sales of the Resellers, with which Adventure Works maintains relationships, to market and distribute its products. To begin, they wish to be able to generate a dataset that presents the lowest monthly sales values for Resellers who have completed sales within Calendar Year 2003. The client representatives make us aware that they wish to screen out Resellers who have no activity at all over the given Calendar Year, simply to streamline reports and make them more compact.

We explain that the Min() function promises to be useful in generating the desired presentation. We confirm our understanding of the foregoing requirement, as well as our conclusion that we have happened upon a great opportunity to both assist the client in meeting its immediate needs as well as to provide examples that leverage the MDX Min() function. We set out to craft a query that relies upon Min(), in conjunction with other MDX functions, to meet the business requirement.

The basic Min() function involved will be housed within a calculated member, which we will call Lowest Sales. We will then employ the calculated member within a core query that arranges the information it retrieves in the manner requested. Our query will be constructed as described in the following procedure.

1.  Select File --> New from the main menu.

2.  Select Query with Current Connection from the cascading menu that appears next, as depicted in Illustration 5.


Illustration 5: Create a New Query with the Current Connection ...

A new tab, with a connection to the Adventure Works cube (we can see it listed in the selector of the Metadata pane, once again) appears in the Query pane.

3.  Type (or cut and paste) the following query into the Query pane:


-- MDX063-2 Second Example of MIN() Function in Use
WITH
MEMBER
   [Measures].[Lowest Sales]
AS
   'MIN(DESCENDANTS( [Date].[Calendar].[Calendar Year].[CY 2003],
      [Date].[Calendar].[Month]),
          [Measures].[Reseller Sales Amount]
      )'

SELECT
    {[Measures].[Lowest Sales]} ON AXIS(0),
NON EMPTY
   {[Reseller].[Reseller Type].[Reseller].MEMBERS}
    ON AXIS(1)
FROM
   [Adventure Works]

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


Illustration 6: Our Second Query in the Query Pane ...

For those Resellers experiencing at least one sale within Calendar Year 2003, we derive a Lowest Sales value using the Min() function, specifying the members of the Month level of the Date dimension (Calendar hierarchy) as the Set Expression across which the Numeric Expression, representing the Reseller Sales Amount measure, is evaluated.

4.  Execute the query by clicking the Execute button in the toolbar.

The Results pane is, once again, populated by Analysis Services. This time, the dataset partially depicted in Illustration 7 appears.


Illustration 7: Results Dataset – Min() Leveraged to Deliver More Sophistication (Partial View)

In the returned dataset, we see the list of Resellers who have been evaluated as having sales activity in at least one period of Calendar Year 2003. Juxtaposed with these names, we observe the calculated member we have constructed, Lowest Sales (containing the primary use of the Min() function).

NOTE: For examples of the use of Non Empty and Descendants(), see various articles throughout this series. Moreover, for an introduction to the .Members function, see my article MDX Members: Introducing Members and Member.

5.  Select File -> Save MDXQuery2.mdx As ..., name the file MDX063-002.mdx, and place it in the same location used to store the earlier query.

To corroborate the operation of the solution we have proposed above, let’s examine the sales figures concerned for a given reseller over all periods in the year under examination. From this quick test dataset, we can see that our calculated members (each leveraging the Min() function) have served us as expected, both in selection of the appropriate value for Lowest Sales.

6.  Select File --> New from the main menu, as we did earlier.

7.  Select Query with Current Connection from the cascading menu that appears next, once again.

A new tab, with a connection to the Adventure Works cube appears in the Query pane, as before.

8.  Type (or cut and paste) the following query into the Query pane:


-- MDX063-3 "Check Query" to Ascertain Solution Effectiveness
SELECT
CROSSJOIN(
     {DESCENDANTS( [Date].[Calendar].[Calendar Year].[CY 2003],
        [Date].[Calendar].[Month])},
            {[Measures].[Reseller Sales Amount]} 
        )
     ON AXIS(0),
{[Reseller].[Reseller Type].[Reseller].[Best o' Bikes]: 
   [Reseller].[Reseller Type].[Reseller].[Bicycle Exporters]}
    ON AXIS(1)
FROM
  [Adventure Works]

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


Illustration 8: Verifying Our Results with a “Test Data” Query

We have simply constructed a query to generate the Calendar Year 2003 monthly values for Reseller Sales Amount for a small sample, consisting of a couple of the organization’s resellers, Best o’ Bikes and Bicycle Exporters. We will be able, thereby, to easily identify the “lowest value” of each that represents Lowest Sales value among the months. We can then also see, at a moment’s glance, the month in which these sales took place. We can then compare the results of our sample to the value delivered by our Lowest Sales calculated member in the dataset retrieved by the last query, to determine accuracy – and thereby verify the effectiveness of our approach.

NOTE: For more detail surrounding the CrossJoin() function, see Basic Set Functions: The CrossJoin() Function, another member of my MDX Essentials series at Database Journal.

9.  Execute the query by clicking the Execute button in the toolbar.

The Results pane is, as before, populated by Analysis Services. The dataset partially depicted - only the months July and October 2003 are non-nulls - in Illustration 9 appears.


Illustration 9: Results Dataset – Confirmation Query

In the returned dataset, we see the values we have discussed appearing for each month in Calendar Year 2003 for each of the two sample Resellers (Lowest Sales values are enclosed in red). We also note that the value presented by the Lowest Sales calculated member in our solution for each of the two Resellers agrees to what we can easily see is the smallest value within the confirmation dataset, and that the month within which the “lowest month’s sales” took place in the confirmation dataset agrees to the Lowest Period month returned in our solution. The comparisons appear as shown in composite Illustration 10.


Illustration 10: Results Datasets Composite – Indicating That Our Solution is Effective

The Logistics department representatives express satisfaction with the results, and confirm their understanding of the operation of the Min() function within the context we have presented, among other uses we have discussed in earlier sections. We suggest to our client colleagues that, among numerous possibilities, the Resellers (single, multiple, or ranged, etc.), as well as various components of the Date dimension (Calendar or Fiscal Hierarchy, Year, Semesters, Quarters, Months, etc.) and other components of our query might be parameterized, within their Reporting Services environment. Moreover, we emphasize, we might add other capabilities within the ultimate reporting dataset query.

Suffice it to say that, assuming an “above ordinary” knowledge of the various layers of the Microsoft integrated BI solution, one can obtain many powerful capabilities and features, and knowing “where to put the intelligence” within the sometimes multiple choices can mean highly tuned performance and effective solutions for consumers throughout our organizations. For more of my observations on this subject see Multi-Layered Business Solutions ... Require Multi-Layered Architects.

10.  Experiment with the “test query,” as desired, to examine and compare the values for other Resellers to those delivered by the previous query via the Min() function.

11.  Select File -> Save MDXQuery3.mdx As ..., name the file MDX063-003.mdx, and place it in the same location used to store the earlier query, if and when desired.

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

Summary...

In this article, we introduced and explored the MDX Min() function, one of several aggregate functions available within the MDX toolset, whose general purpose is to deliver a minimum value of a numeric expression that is evaluated over a set. We emphasized that Min() can be leveraged in a wide range of activities, from the simple “generation of minimums” from simple sets of dimensional members to multidimensional juxtapositions we can compose to deliver even more sophisticated results. Moreover, we learned that Min() can serve as an excellent tool to support sophisticated conditional logic, as well as other calculations, to deliver exactly the analysis and reporting presentations required by our clients and employers.

We examined the syntax involved with Min(), and then undertook a couple of illustrative practice examples of uses for the function, generating queries that capitalized upon its capabilities. Throughout our practice session, we briefly discussed the results datasets we obtained from each of the queries we constructed, as well as extending our discussion to other possible options and uses for the concepts we exposed.

» 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