Procedure: Use the .Ordinal Function as a Basis
for Conditionally Displaying a Value
Recall that, in addition to the need to support parameters,
the client representatives have asked that we craft a query to generate a
dataset that shows an already existing cube measure, Internet Sales Amount
in one column, with a calculation, "Monthly Moving Avg,"
(based upon a rolling six months' activity) alongside it. With the levels of
the Calendar Year dimension (for 2003 only, in our example)
that is months, quarters, half-years and year - as the "Y" axis,
the business need is to show total Internet Sales Amount for each Date
dimension level, but to show the rolling average only on rows representing
months, as the average is (at least to the management audience) only relevant
at the monthly level. Finally, recall that, instead of displaying a blank
space or a zero within the rows where Monthly Moving Avg does not
appear, the specification expresses a preference for the display to be "N/A."
The
report authors / developers express appreciation for the fact that "showing
different values at different levels" might be a useful capability in a
wide range of (potentially much more sophisticated) scenarios arising within
their environment. They listen as we emphasize that the conceptual mechanics
to support such conditional presentations might, indeed, be extrapolated well
beyond the dimensions and values we are currently using, as well as beyond the
use of the .Ordinal function itself within this context.
Having obtained consensus on the proposed target dataset, we
are ready to set about constructing the query.
1.
Select File
---> New from the main menu.
2.
Select Query
with Current Connection from the cascading menu that appears next, as we
did to begin the query in the last section.
Another
new tab again appears, with a connection to the Adventure Works cube, in
the Query pane.
3.
Type (or cut
and paste) the following query into the Query pane:
--MDX047-003 Conditional presentation of a calculation, based upon an
-- existing measure and the MDX .Ordinal function
WITH
MEMBER
[MEASURES].[Monthly Moving Avg]
AS
'IIF(
[Date].[Calendar].CURRENTMEMBER.LEVEL.ORDINAL =
[Date].[Calendar].[Month].ORDINAL,
AVG(LASTPERIODS (6, [Date].[Calendar].CURRENTMEMBER),
[Measures].[Internet Sales Amount]),
NULL)',
FORMAT_STRING = "$#,##0;0;0;\N\\\A\"
SELECT
{[Measures].[Internet Sales Amount], [MEASURES].[Monthly Moving Avg]}
ON AXIS (0),
{DESCENDANTS([Date].[Calendar].[Calendar Year].&[2003],
[Date].[Calendar].[Month], SELF_AND_BEFORE )}
ON AXIS(1)
FROM
[Adventure Works]
The Query pane appears, with our input, as shown in Illustration
13.
Illustration 13: Our Final Query in the Query Pane ...
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 depicted in Illustration
14 appears.
Illustration 14: Results Dataset Conditional Generation
and Display of Calculation
In the returned dataset, we see that the moving average
appears only at the monthly levels, thanks to the comparison we perform through
the use of the .Ordinal function. We suggest to our client colleagues
that the year might be parameterized, that we might build in the
capability to switch from Calendar to Fiscal Year, and that we
might add myriad other capabilities within the ultimate reporting dataset
query. Suffice it to say that, assuming a thorough 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.
5.
Select File
--> Save MDXQuery3.mdx As ..., name the file MDX047-003.mdx,
and place it in the same location accessed to store the earlier query files.
6.
Select File
--> Exit to leave the SQL Server Management Studio, when ready.
The
client representatives inform us that their immediate goals have been met, and
that the examples we have shared illustrate the principles of operation behind .Ordinal,
as a part of helping them to support the expressed business requirements.
Summary ...
In
this article, we explored the MDX .Ordinal function, which can be called
upon in activities that range from generating simple lists and supporting parameter
picklists to constructing a basis upon which we can drive conditional
generation and display of calculations and other values. We introduced the
function, commenting upon its operation and touching upon the creative effects
we can deliver through its use.
We
examined the syntax involved with .Ordinal, and then undertook
illustrative practice examples of business 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.