cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Koen_Zamia
Frequent Visitor

determine the row for subtotals and totals in a matrix and calculating subtotals

Hello,

 

Another issue with subtotals.

I have been reading a lot of these posts about subtotals, but did not came across what i was looking for.

 

I have a matrix with rows (StateID and SubStateID) and colums (Year & Month).

The value is a calculated average based on those columns and rows.

Example of the data.

Koen_Zamia_0-1633449815534.png

 

To test my DAX syntax, I first put a "1" for the value, a "2" for subtotal and a "3" for total

For some reason, i have a 1 on subtotals

Koen_Zamia_0-1633448039340.png

I use this DAX syntax to populate the matrix.

 

t_Average3 =
Var MyAvgTime = divide([t_AgeInDays],[t_CountInterventions])
Var Subtotal =
SWITCH(
TRUE(),
HASONEVALUE(StateBE[StateSequence]) && HASONEVALUE(StateBE[SubStateSequence]) , 1,
HASONEVALUE(StateBE[StateSequence]) , 2,
3)
Return Subtotal

 

So when completing the calculation, my subtotals which must be a sum of the values, are not correct when i have more then one substate row.

Koen_Zamia_1-1633448446133.png

This is the formula i use.

 

t_Average =
Var MyAvgTime = divide([t_AgeInDays],[t_CountInterventions])

Var Subtotal =

SWITCH(
TRUE(),
HASONEVALUE(StateBE[StateSequence]) && HASONEVALUE(StateBE[SubStateSequence]) , MyAvgTime,
HASONEVALUE(StateBE[StateSequence]) , SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ),
SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ))

Return Subtotal

 

Who can help me with this. Any guidance is very welcome.

 

Thanks in advance.

Koen

 
2 ACCEPTED SOLUTIONS
MFelix
Super User
Super User

Hi @Koen_Zamia ,

 

This is related with the fact that you are using HASONEVALUE, if you look at your matrix the lines where you have 1 on the subtotals you only have 1's on the lines where the substate ID is only 1 row try to change the measure to use ISINSCOPE instead of HASONEVALUE something similar to this:

 

t_Average =
Var MyAvgTime = divide([t_AgeInDays],[t_CountInterventions])
Var Subtotal =

SWITCH(
TRUE(),
ISINSCOPE(StateBE[StateSequence]) && ISINSCOPE(StateBE[SubStateSequence]) , MyAvgTime,
ISINSCOPE(StateBE[StateSequence]) , SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ),
SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ))
Return Subtotal

 


Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



View solution in original post

v-yalanwu-msft
Community Support
Community Support

Hi, @Koen_Zamia ;

You could use ISINSCOPE() not HASONEVALUE(), such as:

t_Average3 = SWITCH(TRUE(),ISINSCOPE(StateBE[SubStateld]),1,ISINSCOPE(StateBE[Stateld]),2,3)

The final output is shown below:

vyalanwumsft_0-1633659915615.png

If in your case , you could try it:

t_Average =
VAR MyAvgTime =
    DIVIDE ( [t_AgeInDays], [t_CountInterventions] )
VAR Subtotal =
    SWITCH (
        TRUE (),
        ISINSCOPE ( StateBE[SubStateld] ), MyAvgTime,
        ISINSCOPE ( StateBE[Stateld] ), SUMX ( VALUES ( StateBE[SubStateSequence] ), MyAvgTime ),
        SUMX ( VALUES ( StateBE[SubStateSequence] ), MyAvgTime )
    )
RETURN
    Subtotal

Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

2 REPLIES 2
v-yalanwu-msft
Community Support
Community Support

Hi, @Koen_Zamia ;

You could use ISINSCOPE() not HASONEVALUE(), such as:

t_Average3 = SWITCH(TRUE(),ISINSCOPE(StateBE[SubStateld]),1,ISINSCOPE(StateBE[Stateld]),2,3)

The final output is shown below:

vyalanwumsft_0-1633659915615.png

If in your case , you could try it:

t_Average =
VAR MyAvgTime =
    DIVIDE ( [t_AgeInDays], [t_CountInterventions] )
VAR Subtotal =
    SWITCH (
        TRUE (),
        ISINSCOPE ( StateBE[SubStateld] ), MyAvgTime,
        ISINSCOPE ( StateBE[Stateld] ), SUMX ( VALUES ( StateBE[SubStateSequence] ), MyAvgTime ),
        SUMX ( VALUES ( StateBE[SubStateSequence] ), MyAvgTime )
    )
RETURN
    Subtotal

Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

MFelix
Super User
Super User

Hi @Koen_Zamia ,

 

This is related with the fact that you are using HASONEVALUE, if you look at your matrix the lines where you have 1 on the subtotals you only have 1's on the lines where the substate ID is only 1 row try to change the measure to use ISINSCOPE instead of HASONEVALUE something similar to this:

 

t_Average =
Var MyAvgTime = divide([t_AgeInDays],[t_CountInterventions])
Var Subtotal =

SWITCH(
TRUE(),
ISINSCOPE(StateBE[StateSequence]) && ISINSCOPE(StateBE[SubStateSequence]) , MyAvgTime,
ISINSCOPE(StateBE[StateSequence]) , SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ),
SUMX( VALUES(StateBE[SubStateSequence]) , MyAvgTime ))
Return Subtotal

 


Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



Helpful resources

Announcements
Microsoft Build 768x460.png

Microsoft Build is May 24-26. Have you registered yet?

Come together to explore latest innovations in code and application development—and gain insights from experts from around the world.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through May 31st!

May UG Leader Call Carousel 768x460.png

What difference can a User Group make for you?

At the monthly call, connect with other leaders and find out how community makes your experience even better.

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!