Dan English's BI Blog

Welcome to my random thoughts in regards to Business Intelligence, databases, and other technologies

SSAS MDX Round = Banker’s Rounding

Posted by denglishbi on April 19, 2008

A couple of weeks ago I was working on a project where I had to implement some Ranking calculations within an Analysis Service (SSAS) cube.  I went ahead and added in the calculations and then the client came back to me and stated that there was some additional business logic that we needed to implement.  At different levels of reporting they utilize some rounding into the calculation that is used to determine the Ranking.  When viewing the report at a store level then we need to round the calculation to two decimal places and at all other levels the value will be rounded to four decimal places to be used in the Ranking function.  I thought to myself ‘no problem’ and I went ahead and added in this additional logic and put the Round function into place to handle this logic.  Done.

Well was I wrong.  The client came back to me and said that stores were not being ranked properly and why if these had the same calculation score, 93%, did they not have the same rank.  I was like ‘what?  all i did was add the business logic you requested’.  So I went ahead and started digging into the issue and this opened up a whole can of worms that took me a couple of days to sort out and it was a nightmare — rounding is just plain bad.  What we were seeing on the report was a score of 93% and two scores would have values of say 92.75% and 92.50%.  Now back from my school days using the basic arithmetic round that we all used we would say that these should both be rounded up to 93%, well that ‘depends’.  It turns out that there are quite a few methods of rounding and unfortunately the Microsoft products all differ in how they use the round function and I found a good article explaining that here.  It turns out that in this case Banker’s Rounding was implemented where if the value is at say .5 it will simply round to the nearest even number.  And sure enough this is what was happening; here are some examples that show this (replace cube name with a valid cube name):

–this does not round 92.5 up to 93 as expected

with member measures.test1 as round(.923,2)

     member measures.test2 as round(.925,2)

     member measures.test3 as round(.927,2)

select {measures.test1, measures.test2, measures.test3} on columns

from [cube name]

This was not what we wanted, so now I was on a quest to resolve this.  I thought I could just try and utilize the vbamdx.round call, but that returned the same thing.  I went ahead and tried using the system.math.round call in .NET code to see what that returned to see if I could possibly just implement an SSAS stored procedure (functions are what I call them), but same thing.  I opened up my trusty Excel and tried the round function in there and it worked the way I expected it to.  I was like it is about time…so I thought I would simple use the excelmdx.round in my calculation, but it turns out you actually need to install Excel on the server (found reference to this in the MSDN forums here) for this to work and it will fire up an instance of the excel object when you use this.  So this was not a solution either since we were not going to do that.  I found another solution in the MSDN forums here that stated that you could just use the following logic -int(-(VALUE*100)) and sure it works for my .9250 value, but this logic is basically just returning the CEILING and this is not what I wanted for all of my values (like .9210 would display as 93 — not what we wanted).  What I ended up doing was implementing some crazy CASE logic that evaluated the value to determine if the last numeric value on the right was a 5 then use the CEILING function that I just listed, otherwise just go with the regular round function.

So now I was done, right?  Wrong.  Now we were still getting a few stores that were still not lining up where the report would show 93%, but what was being used by the Ranking was still 92%, so now what was the problem.  It turns out the calculation was returning .9250, but it was actually .92499999, so why was the calculation returning .9250?  I didn’t have any type of formatting in the calculation, this was just a straight calculation returning the underlying value.  This was driving me completely insane.  How did I go about resolving this additional rounding issue, good question.  I ended up doing the following: int(value*100000)/100000 and using this value instead of just value.

So now I was done, right? Wrong again.  Now we were still seeing some incorrect values.  This is what we ended up seeing and shows the different values returned by int and cint.

      value = .57549

                Incorrect calc: int(round(value),2)*100) = 57

                Fixed calc: cint(round(value),2)*100) = 58

I went ahead and changed my references of int to cint and finally I had victory!  I was actually done solving this crazy rounding issue.  It wouldn’t have been that bad if we were just rounding and displaying values; this could have basically been handled by using some formatting in the calculation, but when you need to actually use the result in a Ranking function it is a completely different story.  I am really hoping that there was an easier solution for this, but being under the gun and needing this implemented by the deadline this is what I came up with.  I was able to finally get a good night sleep.

UPDATE (10/12/2009): Additional SSAS Rounding information and workaround posted here – Custom Rounding and Truncation of Numbers in MDX.

 

4 Responses to “SSAS MDX Round = Banker’s Rounding”

  1. Brent said

    Use the overload which includes an argument for MidpointRounding in the System.Math.Round method (e.g.,  System.Math.Round(decmimal, MidpointRounding)) and use MidpointRounding.AwayFromZero. This will provide you with with rounding you are expecting.  Of course this is only available in .NET Framework 2.0 or greater.

  2. Dan said

    Thanks for the comment Brent.  I was in a pinch and needed something quick.  Client isn’t to crazy about installing DLLs on the server, so implementing this as an Analysis Service stored procedure probably wouldn’t have been an option unless that was my only option.  Thanks for the information.  Can’t stand rounding.  Thought this was something pretty straight forward.

  3. Brent said

    FYI, T-SQL uses normal (not Bankers) rounding.  Since I know nothing about mdx I do not know if you can call sprocs from an mdx querry.
     

    select round (.923, 2), round (.925, 2), round (.927, 2)

    ————————————— ————————————— —————————————
    0.920                                          0.930                                          0.930
    (1 row(s) affected)
     
     You gotta love floating-point arithmetic;)

  4. Dan said

    Yeah, I noticed that it worked as expected in T-SQL which was the crazy thing.  Too many products and inconsistencies like the MS KB article stated in the posting.  You can call MDX from a T-SQL stored procedure using a linked server and openquery or openrowset commands and I posted an entry in regards to using SSAS with SSRS where we did that.  We just need to do this within the cube so that we could utilize the value with the Ranking function that was being used in the cube referencing named sets and hierarchies within the dimensions.  The best bet would be to utilize an SSAS stored procedure if you can get away with installing the DLL on the server and making sure that this is well documented for the client and whoever will be maintaining the code going forward.  Thanks again for the feedback and input.  I really enjoy the community participation even though we may be competitors:)  I just want to share as much as I possibly can with the community.

Leave a comment