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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
johnmelbourne
Helper V
Helper V

Calculate the sum of services, as at the MAX LastDate

Hi,

 

This is my data

Capture.PNG

I want to be able to calculate two measures.

  1. Calculate the sum of services, as at the MAX LastDate for each customer. (Total Services)
  2. The sum of errors, by month. (Total Errors)

then I want to to chart the error rate over time (Total Errors / Total Services), so if I filtered by say Feb, the Jan services would still be included, but not the Jan errors.

It is a little weird and doing my head in.

Total errors / Total services by month is easy, but I need to include services even if they are not present in the month, but only the services as of the MAX LastDate.

My example shows the calculations for February which has the ‘missing month’ of January for Customer A, where the errors need to be ignored, and the services need to be included.

Any guidance would be most appreciated.

regards
John

2 ACCEPTED SOLUTIONS
Arklur
Resolver II
Resolver II

Using the sample data you provided:

// Data
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fc5NCoQwDAXgq0jWpbykpuBSe4zS5SxlYH7ur40gHTu4CYF8vJecKX3fn+f6eA0zORLFPmPdwJNn8QIq7qICqlJTAg/20F+1VGVZjCYsoGcjGnakyZ+0jvWvJbsZ05vSdP4md6WVqaWFtpQjlbIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Services = _t, Error = _t, LastDate = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer", type text}, {"Services", Int64.Type}, {"Error", Int64.Type}, {"LastDate", type date}})
in
    #"Changed Type"

 

And this measure:

SumServicesLastDateByCustomer = 
SUMX (
    ALLSELECTED ( Data[Customer] ),
    VAR vCurrentMaxDate = 
        MAX ( DataLastDate[Date] )
    VAR vLastDate =
        CALCULATE ( 
            MAX ( Data[LastDate] ),
            ALL ( DataLastDate ),
            DataLastDate[Date] <= vCurrentMaxDate
        )
    VAR vRetval = 
        CALCULATE ( 
            SUM ( Data[Services] ),
            ALL ( DataLastDate ),
            Data[LastDate] = vLastDate
        )
    RETURN
        IF ( 
            NOT ( ISBLANK ( SUM ( Data[Services] ) ) ),
            vRetval,
            BLANK()
        )
)

 

Will do the job. You just need to create a date table for the "LastDate" column, there is plenty of resources how you can do that.

image.png

View solution in original post

Greg_Deckler
Super User
Super User

@johnmelbourne - For the first one, you should be able to use Lookup Min/Max - https://community.powerbi.com/t5/Quick-Measures-Gallery/Lookup-Min-Max/m-p/985814#M434

 

Your second one should be a simple SUM aggregation. You might need to add a column where you do MONTH([LastDate])


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

4 REPLIES 4
Greg_Deckler
Super User
Super User

@johnmelbourne - For the first one, you should be able to use Lookup Min/Max - https://community.powerbi.com/t5/Quick-Measures-Gallery/Lookup-Min-Max/m-p/985814#M434

 

Your second one should be a simple SUM aggregation. You might need to add a column where you do MONTH([LastDate])


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
Arklur
Resolver II
Resolver II

Using the sample data you provided:

// Data
let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fc5NCoQwDAXgq0jWpbykpuBSe4zS5SxlYH7ur40gHTu4CYF8vJecKX3fn+f6eA0zORLFPmPdwJNn8QIq7qICqlJTAg/20F+1VGVZjCYsoGcjGnakyZ+0jvWvJbsZ05vSdP4md6WVqaWFtpQjlbIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Services = _t, Error = _t, LastDate = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer", type text}, {"Services", Int64.Type}, {"Error", Int64.Type}, {"LastDate", type date}})
in
    #"Changed Type"

 

And this measure:

SumServicesLastDateByCustomer = 
SUMX (
    ALLSELECTED ( Data[Customer] ),
    VAR vCurrentMaxDate = 
        MAX ( DataLastDate[Date] )
    VAR vLastDate =
        CALCULATE ( 
            MAX ( Data[LastDate] ),
            ALL ( DataLastDate ),
            DataLastDate[Date] <= vCurrentMaxDate
        )
    VAR vRetval = 
        CALCULATE ( 
            SUM ( Data[Services] ),
            ALL ( DataLastDate ),
            Data[LastDate] = vLastDate
        )
    RETURN
        IF ( 
            NOT ( ISBLANK ( SUM ( Data[Services] ) ) ),
            vRetval,
            BLANK()
        )
)

 

Will do the job. You just need to create a date table for the "LastDate" column, there is plenty of resources how you can do that.

image.png

Amazing. Thanks @Arklur for the effort you have put in. I really appreciate it.  Superstar.

Thanks also to @Greg_Deckler , most appreciated information.

Kinds regards

John

 

Fowmy
Super User
Super User

@johnmelbourne 

Not getting it clearly,

Can you share some sample data and the expected result to have a clear understanding of your question?
You can save your files in OneDrive, Google Drive, or any other cloud sharing platforms and share the link here.
____________________________________
How to paste sample data with your question?
How to get your questions answered quickly?

_____________________________________
Did I answer your question? Mark this post as a solution, this will help others!.

Click on the Thumbs-Up icon on the right if you like this reply 🙂

YouTube, LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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