Business Intelligence Blogs

View blogs by industry experts on topics such as SSAS, SSIS, SSRS, Power BI, Performance Tuning, Azure, Big Data and much more! You can also sign up to post your own business intelligence blog.

NON EMPTY vs Nonempty(): To the Death!

  • 10 August 2012
  • Author: DustinRyan
  • Number of views: 8108
  • 0 Comments

So what is the difference between NON EMPTY and Nonempty()? I've had this question asked several times and have been meaning to blog it for a little while but here's me just getting around to it. So let's jump right in.

We have two queries we're going to take a look at it in order for us to better understand the difference between NON EMPTY and Nonempty(). Behold our first very boring query:

SELECT 
([Date].[Calendar Year].&[2005]) ON 0,
NON EMPTY([Date].[Calendar Quarter of Year].members) ON 1
FROM  [Adventure Works]
WHERE [Measures].[Reseller Sales Amount];

Fig. 1a

Now here are the results:

image

Fig. 1b

As you can see, Q1 and Q2 are excluded from the results because the cells are empty. The NONEMPTY keyword essentially says, "After we decide which members go where and which cells are going to be returned, get rid of the empty cells." If we take a look at the execution tree using MDX Studio, we can see the 2005 partition is the only partition being hit because NON EMPTY is being applied at the top level. The 0 axis is taken into account before evaluating which cells are empty.

image

Fig. 1c

Also, its important to note that the NONEMPTY keyword can only be used at the axis level. I used it on the 1 axis, but I could have used it on each axis in my query. I must also mention that the Nonempty function accepts a second argument and its very important that you specify this second argument even though it is not absolutely necessary for you to use the function.

Now lets take a look at our second query:

SELECT 
([Date].[Calendar Year].&[2005]) ON 0,
Nonempty([Date].[Calendar Quarter of Year].members,[Measures].[Reseller Sales Amount]) ON 1
FROM  [Adventure Works]
WHERE [Measures].[Reseller Sales Amount];

Fig. 2a

This time I'm using the Nonempty function. Because the Nonempty function is in fact a function, we can use it anywhere in the query. We could use it in a sub-select or the Where clause. I just happen to be using it in the set defined on the 1 axis. Anyways, check out the results:

image

Fig. 2b

What's this?! Empty cells! You may be asking yourself, "Self, what gives?". I'll give you a hint. Take a look at the query results if we execute the same query across all years rather than just for 2005. Here's the query:

SELECT 
([Date].[Calendar Year].children) ON 0,
nonempty([Date].[Calendar Quarter of Year].members) ON 1
FROM  [Adventure Works]
WHERE [Measures].[Reseller Sales Amount];

Fig. 2c

And the results:

image

Fig. 2d

Because there are cells for other years outside of 2005, Nonempty() does not eliminate Q1 and Q2, as seen in Fig. 2b. The Nonempty() is not evaluated at the top level like the NONEMPTY keyword is. So before it knows that the query is only limited to 2005, Nonempty() has already determined which cells are going to be excluded, which are the rows that do not have measures. In this case, no rows are eliminated. Just take a look at the execution tree:

image

Fig. 2e

We can see all partitions are hit because of the Nonempty() function even though our results only display 2005.

With these facts in mind, its important to use the NONEMPTY keyword and the Nonempty() function because they could get you into trouble. In the case of the query shown above, the NONEMPTY keyword is probably the best bet because only the necessary partition is scanned and less cells are evaluated. But what about in the case of the following query?

Here's the query:

SELECT
  {[Measures].[Internet Sales Amount]} ON COLUMNS
,{
    Filter
    (
      CrossJoin
      (
        [Customer].[City].MEMBERS
       ,[Date].[Calendar].[Date].MEMBERS
      )
     ,
      [Measures].[Internet Sales Amount] > 10000
    )
  } ON ROWS
FROM [Adventure Works];

Fig. 3a

Here's the count of cells returned:

image

Fig. 3b

Should we use the NONEMPTY keyword or the Nonempty() function? Let's try NONEMPTY first.

SELECT
  {[Measures].[Internet Sales Amount]} ON COLUMNS
,NON EMPTY
    {
      Filter
      (
        CrossJoin
        (
          [Customer].[City].MEMBERS
         ,[Date].[Calendar].[Date].MEMBERS
        )
       ,
        [Measures].[Internet Sales Amount] > 10000
      )
    } ON ROWS
FROM [Adventure Works];

Fig. 3c

And the cell count:

image

Fig. 3d

You can see the exact same cell set was returned. In this case, NON EMPTY didn't do anything for us. This is because our Filter clause is still evaluating empty cells because NON EMPTY has not been applied yet. But let's try the Nonempty() function. Here's the query:

SELECT
  {[Measures].[Internet Sales Amount]} ON COLUMNS
,{
    Filter
    (
      NonEmpty
      (
        CrossJoin
        (
          [Customer].[City].MEMBERS
         ,[Date].[Calendar].[Date].MEMBERS
        )

,[Measures].[Internet Sales Amount]
      )
     ,
      [Measures].[Internet Sales Amount] > 10000
    )
  } ON ROWS
FROM [Adventure Works];

Fig. 3e

But take a look at the cell count:

image

Fig. 3f

Only 40 rows this time! In the case of the query in Fig. 3a, the Nonempty() function was the optimum solution. My point is that its important to understand the differences between the NONEMPTY keyword and the Nonempty() function and to use them properly. I hope you found this useful.

Print
Rate this article:
5.0
DustinRyan

DustinRyanDustinRyan

Other posts by DustinRyan

Please login or register to post comments.