Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
Anonymous
Not applicable

DAX for Azure Cost Table - part 2

Hi everyone,


I have a previous thread/message from the below link.

https://community.powerbi.com/t5/Desktop/DAX-for-Azure-Cost-Table/m-p/1296381#M564798

 

Details are as follows:

I have a table visual which looks like this.

resourceGroupJanFebMarAprMayJunJul
RG1116578963736232115900
RG21389158472119521517137114
RG3269506165793719911491813
RG41377182736015686522261618
RG5171215811895032921128991
RG6129919598081489118882675
RG7146614021596586329931671
RG8550119318861138717381742
RG9370102215481400532103064
RG101961045540370116517611089

 

What I would like to do is -

Have a slicer for choosing a specific month (this is easily done).

Whenever a specific month is being chosen (from the slicer), the chosen month and the previous month relative to it have to be displayed, along with their costs.

And then display the cost difference between the two via a DAX or whatever you think is better/easier.

 

Example:

Chosen month in the slicer: July

Output:

resourceGroupJunJulDiff
RG11206208-998
RG287418981024
RG3347847500
RG412451084-161
RG572181897
RG6309838529
RG7711278-433
RG81893632-1261
RG91291137786
RG1017361894158


The solution I got was using time intelligence (MTD and PREVIOUSMONTH functions) and that requires a separate date table. My concern right now is, what would be the alternative if I have no (or cannot create) date table? I am trying to recreate my visualizations from an existing data set which I have no rights to modify. 

 

Thanks!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous,

I'd like to suggest you do unpivot columns on your month fields to convert them to attribute and value fields to calculate.

Unpivot columns (Power Query) 

Then you can create a sorting table to setting custom sort order of month fields and duplicate it as a selector table to use on the slicer. (sort table link to raw table month fields, selector table not has any relationship to other tables)

Sorting =
SELECTCOLUMNS (
    GENERATESERIES ( 1, 12, 1 ),
    "Index", [Value],
    "Month", FORMAT ( DATEVALUE ( [Value] & "/1" ), "mmm" )
)

Selector = Sorting

Custom Sorting in Power BI 

After these steps, you can design matrix visual with raw table resource Group, sort order table month, and write a measure to interact with slicer and calculated the selected diff. (name column subtotal as diff)

result = 
VAR selected =
    CALCULATE ( MAX ( 'Selector'[Index] ), ALLSELECTED ( 'Selector' ) )
VAR list =
    CALCULATETABLE (
        VALUES ( Sorting[Month] ),
        FILTER ( ALL ( Sorting ), [Index] IN { selected - 1, selected } )
    )
RETURN
    IF (
        ISINSCOPE ( Sorting[Month] ),
        IF ( SELECTEDVALUE ( Sorting[Month] ) IN list, SUM ( Test[Sales] ) ),
        CALCULATE (
            CALCULATE ( SUM ( Test[Sales] ), Sorting[Index] = selected - 1 )
                - CALCULATE ( SUM ( Test[Sales] ), Sorting[Index] = selected ),
            ALLSELECTED ( Test ),
            VALUES ( Test[resourceGroup] )
        )
    )

6.png

BTW, I also attached the sample pbix file below, you can check it if you still confused about how to do these.

Regards,

Xiaoxin Sheng

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @Anonymous,

I'd like to suggest you do unpivot columns on your month fields to convert them to attribute and value fields to calculate.

Unpivot columns (Power Query) 

Then you can create a sorting table to setting custom sort order of month fields and duplicate it as a selector table to use on the slicer. (sort table link to raw table month fields, selector table not has any relationship to other tables)

Sorting =
SELECTCOLUMNS (
    GENERATESERIES ( 1, 12, 1 ),
    "Index", [Value],
    "Month", FORMAT ( DATEVALUE ( [Value] & "/1" ), "mmm" )
)

Selector = Sorting

Custom Sorting in Power BI 

After these steps, you can design matrix visual with raw table resource Group, sort order table month, and write a measure to interact with slicer and calculated the selected diff. (name column subtotal as diff)

result = 
VAR selected =
    CALCULATE ( MAX ( 'Selector'[Index] ), ALLSELECTED ( 'Selector' ) )
VAR list =
    CALCULATETABLE (
        VALUES ( Sorting[Month] ),
        FILTER ( ALL ( Sorting ), [Index] IN { selected - 1, selected } )
    )
RETURN
    IF (
        ISINSCOPE ( Sorting[Month] ),
        IF ( SELECTEDVALUE ( Sorting[Month] ) IN list, SUM ( Test[Sales] ) ),
        CALCULATE (
            CALCULATE ( SUM ( Test[Sales] ), Sorting[Index] = selected - 1 )
                - CALCULATE ( SUM ( Test[Sales] ), Sorting[Index] = selected ),
            ALLSELECTED ( Test ),
            VALUES ( Test[resourceGroup] )
        )
    )

6.png

BTW, I also attached the sample pbix file below, you can check it if you still confused about how to do these.

Regards,

Xiaoxin Sheng

amitchandak
Super User
Super User

@Anonymous , Assume you need to display jun, jul as the legend and diff a column. Matrix does not support Hybrid display. so You need opt for some solution to do it.

2. When you select a one-month slicer and do not use time intelligence, The measure which you build will give you 2 months you will get rolling data. to avoid that and two display month you again need 2 tables

 

https://www.youtube.com/watch?v=duMSovyosXE

 

You can have MTD measure and diff measure and use that in the matrix with the month as legend or this month /last month and diff.  I thing time intelligence is best suited for your case

 

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-1,MONTH)))
last month Sales = CALCULATE(SUM(Sales[Sales Amount]),previousmonth('Date'[Date]))
last MTD (complete) Sales =  CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(ENDOFMONTH(dateadd('Date'[Date],-1,MONTH))))
previous month value =  CALCULATE(sum('table'[total hours value]),previousmonth('Date'[Date]))

diff = [MTD Sales]-[last MTD Sales]
diff % = divide([MTD Sales]-[last MTD Sales],[last MTD Sales])

I think time intelligence is best solution

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.