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
Wouter_MK
Frequent Visitor

Finding monthly patterns for multiple different IDs.

I have a table with IDs and dates, which may look like the following:

 

IDDate
12327-12-2022
12326-01-2023
12320-11-2022
45601-01-2021
12320-10-2022
45601-02-2020

 

My goal is to add a calculated column to this table, which for each "ID" lets us know if the "Date" values for this "ID" follow a monthly pattern. Here I choose to define a montlhy pattern by looking at the MM part of the "DD-MM-YYYY" format of the "Date". A monthly pattern means that this MM part follows a pattern like ...,10,11,12,1,2,... where no month is skipped.

 

Since ID "123" follows a monthly pattern (from month 10 of 2022 until month 1 of 2023) I want a column that displays "monthly sequence" every time the corresponding value of ID is "123". Obviously 456 does not follow a monthly pattern (due to different years) so here I want to result to be "non-monthly sequence".

 

So far I found that I can use the MONTH() and YEAR() functions to extract the month and year from the date column. But I am stuck on how to compare multiple dates for a specific ID. How do I for instance make sure that dates are compared only within a certain "ID". And how can I guarantee that the comparison happens in the correct order?

 

If anyone can help me solve this problem or provide some hints, that'd be greatly appreciated.

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @Wouter_MK 

This would be probably best done in Power Query but here is an alternative for a calculated column in DAX. You might run into speed problems if the tables are large

See it all at work in the attached file.

PatternFlag = 
VAR auxT_ = CALCULATETABLE(DISTINCT(Table1[Date]), ALLEXCEPT(Table1, Table1[ID]))
VAR monthsT_ = ADDCOLUMNS(auxT_, "@YearMonth", YEAR([Date])*100 + MONTH([Date]))
VAR uniqueMonths_ = SUMMARIZE(monthsT_, [@YearMonth])
VAR numMonthsInSequence_ = COUNTROWS(uniqueMonths_)
VAR earliest_ = EOMONTH( CALCULATE(MIN(Table1[Date]), ALLEXCEPT(Table1, Table1[ID])), 0)
VAR latest_ = EOMONTH( CALCULATE(MAX(Table1[Date]), ALLEXCEPT(Table1, Table1[ID])), 0)
VAR numMonthsRequired_ = DATEDIFF(earliest_, latest_, MONTH) + 1
RETURN
    IF (
        numMonthsInSequence_ = numMonthsRequired_,
        "Monthly seq",
        "No monthly seq"
    )

 

SU18_powerbi_badge

Please accept the solution when done and consider giving a thumbs up if posts are helpful. 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

View solution in original post

5 REPLIES 5
AlB
Super User
Super User

Hi @Wouter_MK 

This would be probably best done in Power Query but here is an alternative for a calculated column in DAX. You might run into speed problems if the tables are large

See it all at work in the attached file.

PatternFlag = 
VAR auxT_ = CALCULATETABLE(DISTINCT(Table1[Date]), ALLEXCEPT(Table1, Table1[ID]))
VAR monthsT_ = ADDCOLUMNS(auxT_, "@YearMonth", YEAR([Date])*100 + MONTH([Date]))
VAR uniqueMonths_ = SUMMARIZE(monthsT_, [@YearMonth])
VAR numMonthsInSequence_ = COUNTROWS(uniqueMonths_)
VAR earliest_ = EOMONTH( CALCULATE(MIN(Table1[Date]), ALLEXCEPT(Table1, Table1[ID])), 0)
VAR latest_ = EOMONTH( CALCULATE(MAX(Table1[Date]), ALLEXCEPT(Table1, Table1[ID])), 0)
VAR numMonthsRequired_ = DATEDIFF(earliest_, latest_, MONTH) + 1
RETURN
    IF (
        numMonthsInSequence_ = numMonthsRequired_,
        "Monthly seq",
        "No monthly seq"
    )

 

SU18_powerbi_badge

Please accept the solution when done and consider giving a thumbs up if posts are helpful. 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

Wouter_MK
Frequent Visitor

Thank you very much, this seems to do what I want and within my usecase it still runs quite fast. Would you mind helping me understand exactly how the solutions works?

 

As far as I understand auxT_ and monthsT_ create a table with all distinct dates per ID, with an additional column "@YearMonth" with the Year*100 (why the *100?) and month.

 

uniqueMonths_ and numMonthsInSequence_ then determine the unique number of months in a sequence.

 

With earliest_, latest_ and numMonthsRequired_ we know the amount of months between the earliest and latests month (for a particular ID) so that with the final IF() we can check if the number of months in the actual sequence is equal to the number of months required

 

Could you provide additional comments/corrections? Thank you again, the solution really helped me.

@Wouter_MK 

Exactly. You got perfectly.

Year*100 + Month is just a common way on codifying Year-Month into numbers.

The 100 could be anything >= 12. The 100 just makes it easy to see the year and the month straight away when looking at the number

 

SU18_powerbi_badge

Please accept the solution when done and consider giving a thumbs up if posts are helpful. 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

ppm1
Solution Sage
Solution Sage

This is possible, but what do you plan to do with the column once your have it? There may be a simpler way to get the same outcome. And why not use a measure instead of a column, so it is dynamic when you use date slicers, etc.?

 

Pat

 

Microsoft Employee

Thanks for your response. Sorry if this reply is quite vague, but I'm not allowed to describe everything I'm working on in detail.

 

I'm planing to use the column within some other table. I'm working in a system with lots of different tables and keys (we use a STAR model). I need the table that has some columns like in my example above to perform the task that I described. Then I can use the results from this newly calculated column in some other table (I have different keys to join them together which will allow me to use the RELATED() function) to use it to easily solve some other problem.

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.