The Last Non Empty Dilemma


The quantity of stock on hand is a common reporting requirement for inventory systems where quantity of stock on hand at aggregate time levels is shown as the last value that was recorded. When time is aggregated, (eg the year as a parent of months), the value shown refers to the last recorded value and not the sum of months. In this post we look at the use of LastNonEmpty aggregation, and the implications that it has.

The data used in this post assumes the leaf data for the diagram above (products [a], [b], [c], [d] with moths [Oct], [Nov], [Dec]). When the November stock take is done, the year value for stock holding should display 19, and when December stock take is done the year value should show 12. Showing the year value as the sum of its children will give incorrect results because, (after Novembers stocktake) the stock holiding is not equal to October quantity plus November (45=26+19), only the last known value (Nov) 19.

Last Non Empty Aggregation

The SSAS aggregation function ‘LastNonEmpty’ can solve this issue automatically by showing the time aggregates as the last recorded value. By default aggregation is set to sum but it can be set on the properties tab for the measure (as below).

The higher levels of time now inherit the last known quantity for a given product which may seem a reasonable solution (below). However, this can cause an issue when stock values are not present for all stock items in the last period. When an stock item (sku) is excluded, the LastNonEmpty inherits the last known period value. In this situation, the LastNonEmpty can bypass the last known (or input) period and aggregate values across inconsistent periods. This is shown in the diagram below where the last recorded period is December and the yearly counts include November balances.

Furthermore, total balances are calcualted as the total for the LastNonEmpty period and so the total for the time aggregate doesnot equal the sum of its children. We can see that;

  1. [CY 2010] values at the product level inherits the last known value.
  2. [CY 2010] [Grand Total] inherits the [Grand Total] for [CY 2010 Dec] (so that 12=12) and
  3. The [Grand Total] for [CY 2010] does not equal the sum of each product ([a],[b],[c],[d]) for [CY 2010] (ie 12 is not the sum of 8+3+4+1). If we are to assume that the values for [CY 2010] for each product will aggregate to the [Grand Total] for the product, we should see 16 as the [Grand Total] for [CY 2010].

Clearly, the use of the LastNonEmpty as an aggregate function comes with some caveats.

Solution 1 (Fact Based)

One way to solve this issue is to include zero balances for inventory items where the value is zero (or would otherwise be null). This can be done by appending the a zero quantity products that are not counted (have zero balances or are null). In this case, a view which automatically derives missing data based on the theroitical space of (date x prodcut less non zero values).

As expected, the values for all products are known for a month and the time aggregate inherits the last materialised period amount.

Solution 2 (Script Based)

A different approach is to scipt a measure that satisifys the aggregation function and answers the LastNonEmpty based on the last non empty date period for all products. Leaving the existing LastNonEmpty measure inplace and using a calcualte member [Stock On Hand] to calculate time aggregates based on the [Prod Count] value. Essentially, we are looking for the [Prod Count] values on the last [date] member where any product had a value. In this context, the last date member refers to the last (maximum) date for any product that had stock.

The solution follows the following logic;

  1. What was the last date that products had value
  2. What was the value of product on this date?

The last date (that any product was sold) can be determined by the snippet below

TAIL(FILTER([Date].[Calander Years].[Cal Month], ([Measures].[Prod Count], ROOT([Product]))<>0), 1)

And the sum aggregates these values (for the last time period)

SUM(  TAIL(FILTER([Date].[Calander Years].[Cal Month], ([Measures].[Prod Count], ROOT([Product]))<>0), 1) 
 , [Measures].[Prod Count] 
 )

Other Calculation Considerations

Introducing the [Stock On Hand] calcualted member solves the aggregate time issues and [CY 2010] values will show correct (as below). The [Stock On Hand] value for [CY 2010] will show the stock as at the last recorded period ([CY 2010 Dec]).

One side-effect for this calcualtion (asis) is that preceeding periods will show values for post dated periods. For example (below), [CY 2010 Sep] values will be displayed on the basis of [CY 2010 Dec]. Clearly this is also not correct as the values for [Sep] should be null.

This behaviour can be corrected by only displaying the calcualted value when a LastNonEmpty value would have otherwise been shown. The calcuation becomes;

IIF([Measures].[Prod Count]=0  , NULL  , SUM(TAIL(FILTER([Date].[Calander Years].[Cal Month], ([Measures].[Prod Count], ROOT([Product]))<>0), 1)  , [Measures].[Prod Count]  ) 

And this satisfies all requirements

Conculsion

The use of LastNonEmpty aggregation offers a convenient way to aggregate measures such as product count across time hierarchies. However, there are some assumptions included with the use of the function that may cause output not to show as expected. This output can be controlled by either by including zero values on for products that are not counted or by scripting a calculated measure to manually aggregate across time.

 

Improving the performance of the sum:

As Chris has pointed out, the sum function will perform poorly in a large environment.  This can be greatly improved by defining the LNE over the tuple for the last date that has values.  That is, we derive the last date member (as below)

TAIL(Filter([Date].[Calander
Years].[Cal Month], (ROOT([Product]),[Measures].[Prod
Count] )> 0)

,1).ITEM(0)

Other methods of defining the last posting date may use attributes of the date dimension (see http://www.artisconsulting.com/blogs/greggalloway/Lists/Posts/Post.aspx?List=83c71d76-a4d8-4197-9257-38d6b857634f&ID=16)
per Boyans post.

The stock on hand value is then defined as the tuple of the
member and our materialised value;

MEMBER
[Measures].[Stock Count] as

(

[Measures].[Prod Count]

,[Date].[Calander Years].LAST_MONTH_VALUE

)

Advertisements

12 thoughts on “The Last Non Empty Dilemma

    • Thanks Chris.

      The sum is not the most efficient way to do it. We are much better off scripting the last time member and using that in the calc;

      // [Stock on Hand] is derived
      // [Prod Count] is materialised LastNonEmpty
      WITH MEMBER [Date].[Calander Years].LastMember as
      TAIL(FILTER([Date].[Calander Years].[Cal Month], ([Measures].[Prod Count], ROOT([Product]))0), 1).ITEM(0)

      MEMBER [Measures].[Stock On Hand] as
      (
      [Date].[Calander Years].LastMember
      , [Measures].[Prod Count]
      )

    • Hi Boyan,

      Certainly If the LastNonEmpty hits each partition then the performance of the calculation will suffer in the SE (this is not the case in this example).
      I think I have essentially used the same principle of last date determination in the later example except that I filter for the value and Gregs example explicitly defines yesterday.

      Regards,

      Paul

  1. Pingback: The Last Non-Empty Dilemma TABULAR Style « Paul te Braak

  2. Sorry if this is ancient history, but fantastic as Grey Galloways approach is (and it is fantastic), the assignment ([Date].[Calendar].[All] = [Yesterday].Item(0).Item(0); ) of the All member to being yesterday leads to some very confusing results if filtering the Date dimension to some period in the past and looking at Sales and Inventory side-by-side. In effect you wind up with the inventory at the all level of Date and the Sales for the selected time periods… Totally stumped as to what the alternative is though.

    Cheers,
    Mark

  3. Pingback: Thinknook | SSAS LastNonEmpty Aggregation Function

  4. Hello,

    Thank you for this article. I tried this solution but I’ve found that [Measures].[Stock on Hand] IS NOT aware of the current member of the Time dimension. Any suggestion about this?

    Thanks,
    Amine

  5. Do you mean defining the measure like this ?
    IIF([Measures].[Prod Count]=0 , NULL , SUM(TAIL(FILTER([Date].[Calander Years].CurrentMember, ([Measures].[Prod Count], ROOT([Product]))0), 1) , [Measures].[Prod Count] )

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s