MTD values of a Measure...Help

MTtroy

New Member
Joined
Jul 7, 2018
Messages
9
Yet Another MTD Question.xlsx

I'm attempting to report a MTD value (BTZ Feed Ozs MTD). The daily value (BTZ Feed Ozs) is calculated by multiplying a row value (BTZ Tons) by a measure (BTZ 30day avg).


BTZ Feed Ozs MTD:=CALCULATE (
[BTZ Feed Ozs],
DATESMTD( 'Calendar'[Date] ),
Conccentrator_Final[Feed Oz's_2] > 0
)


BTZ Feed Ozs :=
SUM ( Conccentrator_Final[Blitz Tons] ) * [BTZ 30day avg]


BTZ 30day avg :=
CALCULATE (
AVERAGE ( 'Data input'[PtPd] ),
'Data input'[Region] = "BLITZ",
DATESINPERIOD (
'Calendar'[Date],
LASTDATE ( 'Calendar'[Date] ),
- [Days in Avg Calc],
DAY
)
)



Result Wanted:
The result I'm looking for is the additive value of each day's calculated value, so for example on 3/2 the individual values for 3/1 and 3/2 are 312 & 271 which would be 583 (312+271).

Result Currently returned:
The MTD value (BTZ Feed Ozs MTD) that is returned on 3/2 is 591 which is the sum of the daily values (BTZ Feed Ozs 692+587=1297) multiplied by the 3/2 value of the BTZ 30day avg measure (0.46), (692+587)*(0.46208)=590.

I've tried different approaches, but can't seem to get the result I require.

Thanks,
Troy
2020-03-24_6-27-13.png
 

Some videos you may like

Excel Facts

What does custom number format of ;;; mean?
Three semi-colons will hide the value in the cell. Although most people use white font instead.

JustynaMK

Well-known Member
Joined
Aug 28, 2016
Messages
578
Office Version
365, 2013
Platform
Windows
Hi Troy,

I hope I understood your request correctly (although everything is described very nicely!).
Note that my results are slightly different - I think it's a matter of rounding/decimal places. E.g. first row, 692 x 0.45 = 311.40, versus your table (312).

Here's one DAX formula you can try for cumulative values -
Rich (BB code):
BTZ Feed Ozs MTD =
    SUMX(
        FILTER(ALL(Conccentrator_Final),
            Conccentrator_Final[Row Labels] <= SELECTEDVALUE(Conccentrator_Final[Row Labels])),
        Conccentrator_Final[Blitz Tons] * Conccentrator_Final[BTZ 30day avg])
The second one, using a temporary table -
Rich (BB code):
BTZ Feed Ozs MTD =
    var t =
        ADDCOLUMNS(
            FILTER(ALL(Conccentrator_Final),
                Conccentrator_Final[Row Labels] <= SELECTEDVALUE(Conccentrator_Final[Row Labels])),
            "BTZ",
            [BTZ Feed Ozs])
return
    SUMX(t, [BTZ])
Both will give you the same results -

1585077421669.png
 

JustynaMK

Well-known Member
Joined
Aug 28, 2016
Messages
578
Office Version
365, 2013
Platform
Windows
Oh and just in case you have more months in your dataset, you'd need to change your filter expression to:

Rich (BB code):
           FILTER(ALL(Conccentrator_Final),
                Conccentrator_Final[Row Labels] <= SELECTEDVALUE(Conccentrator_Final[Row Labels]) &&
                MONTH(Conccentrator_Final[Row Labels]) = MONTH(SELECTEDVALUE(Conccentrator_Final[Row Labels])))
The final value, as you can see, is being recalculated for each month separately:

1585078085961.png
 

MTtroy

New Member
Joined
Jul 7, 2018
Messages
9
Hi JustynaMK,
Thanks for the answer. I have one issue at the outset, my version of Power Pivot doesn't support the SELECTEDVALUE command. Since it's a corporate controlled MS365 account it's not easily upgraded. My understanding is that the command HASONEVALUE is the alternative for my version.

The logic of SELECTEDVALUE makes sense to me, but I can't seem to wrap my head around HASONEVALUE. Would you mind translating your code using HASONEVALUE?
 

JustynaMK

Well-known Member
Joined
Aug 28, 2016
Messages
578
Office Version
365, 2013
Platform
Windows
Ahh right, it looks like SELECTEDVALUE is not available yet in Excel. You are absolutely correct in using HASONEVALUE as an alternative.

I'd try using it as follows, let me know if it worked:
Rich (BB code):
BTZ Feed Ozs MTD =
    SUMX(
        FILTER(ALL(Conccentrator_Final),
            Conccentrator_Final[Row Labels] <= IF(HASONEVALUE(Conccentrator_Final[Row Labels]), VALUES(Conccentrator_Final[Row Labels])),
        Conccentrator_Final[Blitz Tons] * Conccentrator_Final[BTZ 30day avg])
Otherwise, you can try using PowerBI, since you already have MS365 account (it is included in some packages).
 

MTtroy

New Member
Joined
Jul 7, 2018
Messages
9
I've updated the file in dropbox: Updated MTD xlsx

The result is still not what I'm looking for and I can't figure out how the value is arrived at. I'm suspecting it has something to do with the 30 day avg measure. Here's the formula I tried:

Rich (BB code):
BTZ Feed Ozs MTD alternative :=
VAR t =
    ADDCOLUMNS (
        FILTER (
            ALL ( Conccentrator_Final ),
            Conccentrator_Final[Date]
                <= IF (
                    HASONEVALUE ( Conccentrator_Final[Date] ),
                    VALUES ( Conccentrator_Final[Date] )
                )
                && MONTH ( Conccentrator_Final[Date] )
                    = MONTH (
                        IF (
                            HASONEVALUE ( Conccentrator_Final[Date] ),
                            VALUES ( Conccentrator_Final[Date] )
                        )
                    )
        ),
        "BTZ", [BTZ Feed Ozs]
    )
RETURN
    SUMX ( t, [BTZ] ) 
)
And the results filtered 3/1 through 3/18:
2020-03-25_17-52-11.png
 

JustynaMK

Well-known Member
Joined
Aug 28, 2016
Messages
578
Office Version
365, 2013
Platform
Windows
Hi Troy,

Your formula was actually correct, the only issue was with using incorrect Date field (your table is using 'Calendar'[Date]).

You can use the following DAX formula (I simplified it a little bit more):

Rich (BB code):
var sDate =
if(HASONEVALUE('Calendar'[Date]), VALUES('Calendar'[Date]))
var t =
        ADDCOLUMNS(
            FILTER(ALL('Calendar'),
                'Calendar'[Date] <= sDate &&
MONTH('Calendar'[Date]) = MONTH(sDate)),
            "BTZ",
            [BTZ Feed Ozs])
return
    SUMX(t, [BTZ])
1585253507383.png
 

MTtroy

New Member
Joined
Jul 7, 2018
Messages
9
Thank you soooo much JustynaMK for taking the time to help!!!! Not only does it work, but the "mysterious" method of adding a temporary table has become much clearer to me. I'll be returning to this example as a template to solving other problems that require a temporary table.

I added an if statement at the end so I can eliminate any leading values for my graph.

Rich (BB code):
BTZ RMO Alternative :=
VAR sDate =
    IF ( HASONEVALUE ( 'Calendar'[Date] ), VALUES ( 'Calendar'[Date] ) )
VAR t =
    ADDCOLUMNS (
        FILTER (
            ALL ( 'Calendar' ),
            'Calendar'[Date] <= sDate
                && MONTH ( 'Calendar'[Date] ) = MONTH ( sDate )
        ),
        "BTZ", [BTZ RMO]
    )
RETURN
    IF ( LASTDATE ( 'Calendar'[Date] ) > TODAY () - 2, BLANK (), SUMX ( t, [BTZ] ) )
 

JustynaMK

Well-known Member
Joined
Aug 28, 2016
Messages
578
Office Version
365, 2013
Platform
Windows
No problem at all! I also find temporary tables very useful so I'm glad you two become good friends :)
Take care & good luck with your model.
 

Forum statistics

Threads
1,089,220
Messages
5,406,927
Members
403,113
Latest member
ms_excel_recal_or_die

This Week's Hot Topics

Top