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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Claudem
Frequent Visitor

Create flag based on any value from first column and filter on date column

Hello all, 

 

I'm not sure to know how to describe properly my need but I'll try to be clear with a specific example:

 

partvalid fromflag
A24/02/2024N
A25/12/2023Y
A26/11/2023N
B24/02/2024N
B25/12/2023Y
B26/11/2023N
C24/02/2024N
C25/12/2023Y
C26/11/2023N

 

Here is the final result. I want to create the flag column based on part and valid from column.
I want to flag to Y this new column the max(valid from) before 01/01/2024 for each part.
Do you guys know how to achieve a such dax formula ?

1 ACCEPTED SOLUTION
fahadqadir3
Super User
Super User

@Claudem Review the following screenshot and  Column and Measure. 

fahadqadir3_0-1731694895609.png

Flag Measure = 

VAR MaxValidFromBefore2024 =
    CALCULATE(
        MAX('Table'[valid from]),

        FILTER(
            ALL('Table'),

            'Table'[part] = MAX('Table'[part]) &&
            'Table'[valid from] < DATE(2024, 1, 1)
        )

    )
RETURN
IF(

    MAX('Table'[valid from]) = MaxValidFromBefore2024,
    "Y",
    "N"
)

Did I answer your question? Mark my post as a solution! This will help others on the forum!
Appreciate your Kudos!!

View solution in original post

3 REPLIES 3
Claudem
Frequent Visitor

ll, thanks for your help. The solutions looks nice but seems to not work in my case. I'm trying to do it on a semantic model connected in direct query. I have a cirular depandancy error when I'm trying the column, and for the measure it seems to duplicate my values with date from other part. The data are not ordered as in the example also.
Any other suggestions ?

v-xuxinyi-msft
Community Support
Community Support

Hi @Claudem 

 

Thanks for the reply from fahadqadir3 .

 

You can also try the following:

 

Measure:

FlagM = 
VAR _date = DATE(2024, 1, 1)
VAR _maxDate = CALCULATE(MAX([valid from]), FILTER(ALLEXCEPT('Table', 'Table'[part]), [valid from] < _date))
RETURN
IF(MAX('Table'[valid from]) = _maxDate, "Y", "N")

 

Column:

FlagC = 
VAR _date = DATE(2024, 1, 1)
VAR _maxDate = CALCULATE(MAX([valid from]), FILTER(ALLEXCEPT('Table', 'Table'[part]), [valid from] < _date))
RETURN
IF('Table'[valid from] = _maxDate, "Y", "N")

 

Output:

vxuxinyimsft_0-1731912148896.png

 

Best Regards,
Yulia Xu

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

fahadqadir3
Super User
Super User

@Claudem Review the following screenshot and  Column and Measure. 

fahadqadir3_0-1731694895609.png

Flag Measure = 

VAR MaxValidFromBefore2024 =
    CALCULATE(
        MAX('Table'[valid from]),

        FILTER(
            ALL('Table'),

            'Table'[part] = MAX('Table'[part]) &&
            'Table'[valid from] < DATE(2024, 1, 1)
        )

    )
RETURN
IF(

    MAX('Table'[valid from]) = MaxValidFromBefore2024,
    "Y",
    "N"
)

Did I answer your question? Mark my post as a solution! This will help others on the forum!
Appreciate your Kudos!!

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.